23
Sat, Nov
1 New Articles

Practical SQL: Embedding SQL in Free-Format RPG

SQL
Typography
  • Smaller Small Medium Big Bigger
  • Default Helvetica Segoe Georgia Times

SQL is a great tool when used properly, and this article gives you a simple, practical example to get you started.

 

Welcome to the wonderful world of practical SQL for RPG programmers. Over the coming months, I hope to bring you a whole host of practical techniques that you can use to become more productive using SQL in your daily programming efforts. I know it may seem odd to some to hear me giving advice on SQL, since over the years I've been very steadfast in my opinion that SQL should not replace native I/O for business logic. But really, there is no conflict here; I have always believed in the best tool for the job, and there are times when SQL is definitely the best tool.

 

One of my favorite uses of SQL is in reporting. Because I can create a single joined query over multiple files, I can take advantage of a standard skeleton to write many of my reports. In today's example, I'm going to show you a simple, basic report that takes advantage of SQL's flexibility and its integration with RPG, particularly with free-format RPG IV.

So What Are We Going to Do?

In simplest terms, we're going to create a query over a few files and then output that data to a report. I went back and forth a little bit over how I was going to accomplish this. In the end, I decided to use an internally described print file. I know that using an internally described printer puts this article a bit behind the technology curve. (Although, to be honest, I'm not sure just how many people have gotten rid of all their O-specs; I'd be interested to hear how many of you use internally described vs. externally described printer files.) An externally described printer file would make some of this work easier, but I think an internally described printer file will keep the example simpler and a little more cohesive.

 

And in the end, it doesn't matter: internal or external--the basic concepts are still the same. The single most important piece of this particular discussion is going to be how to build the data structure, which will then be used as the target of the FETCH operation. That's how we communicate between the SQL engine and the RPG code. If you know me, you know I'm all about messages and inter-tier communications, and my focus is no different when working with embedded SQL.

How Does Embedded SQL Work?

Let me take just a moment to explain the basics. Traditional modern (I hope that's not too much of an oxymoron) RPG programs use File specifications (F-specs) to identify externally described database files. Those specifications in turn automatically define all the fields in the file and make them globally available to the program. You'll hear arguments rising to the level of political rhetoric or religious fervor when it comes to the pros and cons of this concept, but nobody disputes the actual mechanics: you don't have to manually define the individual fields, and reading a record from a file brings all those fields in automatically. The biggest minus (besides the architectural issue of global fields) is that adding a field to a file requires a recompile; forget that and you have to deal with the dreaded CPF4131 level-check message.

 

With SQL, it's a little different. There are no F-specs and thus no automatic fields defined or read magically. You have to explicitly identify each field that you want to read from the file, and although defining fields is second nature to most SQL developers, it can mean quite a bit of typing. Not only that, but for embedded SQL programs, you then have to explicitly tell the SQL precompiler where in your program you want those retrieved fields to go. And since you don't have the externally described file in your program, that means you have to define those work fields as well.

 

But let's walk through it. I'm going to create a simple program that will print the results of a nice little SELECT statement. Let's just execute the basics in this example. First, we need an SQL statement. Whenever I'm creating a report, I start out by testing my SQL in STRSQL. In this case, I ended up with the following:

 

    select CMCUST, CMNAME, ADCITY, ADSTATE

      from CUSMAS join ADRMAS on (CMCUST,CMSAID) = (ADCUST,ADID)

 

I have two files: the customer master and the address master. The customer master has a couple of fields in it: the ship-to address ID and the bill-to address ID. The combination of the customer number and one of those IDs is the key used to get to the address master. By the way, you may notice that on the join I don't have to compare each field individually; I can compare them all at one time using what is known as a "row expression." This is a truly handy technique. Anyway, now that I have the basic SELECT working, it's time to deck it out a little.

A Little Formatting Goes a Long Way

I want to have a nicely formatted city and state, and also I need to add some order to the equation. Here's a more complete version:

 

    select CMCUST, CMNAME,

           TRIM(ADCITY) CONCAT ', ' CONCAT ADSTATE

      from CUSMAS join ADRMAS on (CMCUST,CMSAID) = (ADCUST,ADID)

      order by ADSTATE, ADCITY, CMCUST    

 

So I trim the city and then add the state with a comma in between. Note, by the way, that I am using a simple JOIN rather than an OUTER JOIN. Because of that, I don't have to worry about NULL values, but I will lose any customer records that don't have matches. Such is the tradeoff between INNER and OUTER JOINs, and that's a subject we can cover in detail another day. I also added an ORDER BY clause that will order my selections by state and then city within state. My SQL statement returns this:

 

 CMCUST   CMNAME                                              String Expression

510,002   Mazda North American Operations                     Irvine, CA       

100,250   Costco - Bloomingdale                               Bloomingdale, IL

100,150   Costco - Glenview                                   Glenview, IL    

302,001   Kraft Foods                                         Glenview, IL    

100,100   Costco - Lake Zurich                                Lake Zurich, IL 

 

So, as you can see, I've created a nice little query. The trick is to then take that query and turn it into a report. Let me show you how it's done!

From Interactive to Embedded in 12 Easy Steps

I couldn't decide whether to give you the whole listing at the end of the article and then refer to it step by step in the text, or to intersperse the explanation each step of the way. I'm going to try the latter and see how it works. I've got 12 portions of the program, and I'll explain each one as I go along (alphabetically from "A" to "L").

 

A    H DEBUG OPTION(*SRCSTMT:*NODEBUGIO)

A    H DFTACTGRP(*NO) ACTGRP(*NEW)

 

First, a few compiler settings. Back in the old days, these would be specified on the compile command. I really like that nowadays you can put these settings in the header, because reusing them becomes very convenient: just copy a line or two from another program rather than try to remember the setting when you compile the program. The easier it is to add these settings, the better life is. For example, *SRCSTMT makes post-mortem debugging a lot easier because any error messages will indicate the actual source line where the error occurred, as opposed to a compiler-generated internal statement number that only appears on the compile listing.

 

B    FQSYSPRT   O    F  132        PRINTER OFLIND(OverFlow)

B    d Overflow        s               n

 

This is a standard printer file. Remember, I'm going with an internally described file here, so I just specify the width and an overflow indicator. A little trick here: I always put my printer file at the end of my F-specs so that I can immediately specify a D-spec that defines the overflow indicator. Yeah, it's a little cheesy, but it works out just fine most of the time.

 

      *

      * These externally defined data structures are only used

      * to get field definitions into the program.

      *

C    d CUSMAS        e ds

C    d ADRMAS        e ds

 

Here you see the first piece of code needed to support embedded SQL as opposed to native file I/O. Because we don't have any F-specs for database files, we need to define the fields somehow. I'll do that in the next section using the LIKE keyword, but I still need to bring in the external definitions so that I can use LIKE. That's where externally described data structures come into play. In this case, I define one externally described data structure for each file. This, by the way, is one of the reasons that I prefer to have unique field names in my database. If I had the same field name in two files and I tried to define both in data structures, I would get a compiler error. I would have to qualify the field in the LIKE keyword (more on that in a moment). One additional point about these data structures: they take up space. Since I don't really use them for storage, I could have made them based data structures by specifying basing pointers, but that's a little beyond the scope of today's article.

 

      *

      * This is the data structure used in the SQL fetch.

      * The field definitions here must match exactly the

      * fields in the SELECT clause of the cursor.

      *

D    d dsCursor        ds

D    d  p_CMCUST                           like(CMCUST)

D    d  p_CMNAME                           like(CMNAME)

D    d  pw_ADCITY                    +4    like(ADCITY)

Next I define the actual cursor--or more specifically, the data structure that contains the fields that will be fetched by the cursor. The fields in this data structure must match the fields in the SELECT statement. In order to do that, I define them LIKE the corresponding fields in the externally defined data structures. My SQL statement (coming up in section H) selects CMCUST, CMNAME, and then a formatted city. I use a simple naming convention: the name of the work field is the name of the database field with the prefix "p_". You may notice that I did a little extra magic with the city field. I named it pw_ADCITY; take note of the extra "w." That stands for "work" and indicates that, for whatever reason, it's not an exact replica of the database field. In this case, I want to append the state onto the city, so I need as many as four extra characters (comma, space, and two letters for the state code). That being the case, you'll notice the "+4" in the definition; this makes the field pw_ADCITY like the ADCITY field, except that it's four characters longer.

 

E    d Done            s               n   inz(*off)

E    d Count           s              5u 0 inz(0)

E    d Now             s               

Joe Pluta

Joe Pluta is the founder and chief architect of Pluta Brothers Design, Inc. He has been extending the IBM midrange since the days of the IBM System/3. Joe uses WebSphere extensively, especially as the base for PSC/400, the only product that can move your legacy systems to the Web using simple green-screen commands. He has written several books, including Developing Web 2.0 Applications with EGL for IBM i, E-Deployment: The Fastest Path to the Web, Eclipse: Step by Step, and WDSC: Step by Step. Joe performs onsite mentoring and speaks at user groups around the country. You can reach him at This email address is being protected from spambots. You need JavaScript enabled to view it..


MC Press books written by Joe Pluta available now on the MC Press Bookstore.

Developing Web 2.0 Applications with EGL for IBM i Developing Web 2.0 Applications with EGL for IBM i
Joe Pluta introduces you to EGL Rich UI and IBM’s Rational Developer for the IBM i platform.
List Price $39.95

Now On Sale

WDSC: Step by Step WDSC: Step by Step
Discover incredibly powerful WDSC with this easy-to-understand yet thorough introduction.
List Price $74.95

Now On Sale

Eclipse: Step by Step Eclipse: Step by Step
Quickly get up to speed and productivity using Eclipse.
List Price $59.00

Now On Sale

BLOG COMMENTS POWERED BY DISQUS

LATEST COMMENTS

Support MC Press Online

$

Book Reviews

Resource Center

  • SB Profound WC 5536 Have you been wondering about Node.js? Our free Node.js Webinar Series takes you from total beginner to creating a fully-functional IBM i Node.js business application. You can find Part 1 here. In Part 2 of our free Node.js Webinar Series, Brian May teaches you the different tooling options available for writing code, debugging, and using Git for version control. Brian will briefly discuss the different tools available, and demonstrate his preferred setup for Node development on IBM i or any platform. Attend this webinar to learn:

  • SB Profound WP 5539More than ever, there is a demand for IT to deliver innovation. Your IBM i has been an essential part of your business operations for years. However, your organization may struggle to maintain the current system and implement new projects. The thousands of customers we've worked with and surveyed state that expectations regarding the digital footprint and vision of the company are not aligned with the current IT environment.

  • SB HelpSystems ROBOT Generic IBM announced the E1080 servers using the latest Power10 processor in September 2021. The most powerful processor from IBM to date, Power10 is designed to handle the demands of doing business in today’s high-tech atmosphere, including running cloud applications, supporting big data, and managing AI workloads. But what does Power10 mean for your data center? In this recorded webinar, IBMers Dan Sundt and Dylan Boday join IBM Power Champion Tom Huntington for a discussion on why Power10 technology is the right strategic investment if you run IBM i, AIX, or Linux. In this action-packed hour, Tom will share trends from the IBM i and AIX user communities while Dan and Dylan dive into the tech specs for key hardware, including:

  • Magic MarkTRY the one package that solves all your document design and printing challenges on all your platforms. Produce bar code labels, electronic forms, ad hoc reports, and RFID tags – without programming! MarkMagic is the only document design and print solution that combines report writing, WYSIWYG label and forms design, and conditional printing in one integrated product. Make sure your data survives when catastrophe hits. Request your trial now!  Request Now.

  • SB HelpSystems ROBOT GenericForms of ransomware has been around for over 30 years, and with more and more organizations suffering attacks each year, it continues to endure. What has made ransomware such a durable threat and what is the best way to combat it? In order to prevent ransomware, organizations must first understand how it works.

  • SB HelpSystems ROBOT GenericIT security is a top priority for businesses around the world, but most IBM i pros don’t know where to begin—and most cybersecurity experts don’t know IBM i. In this session, Robin Tatam explores the business impact of lax IBM i security, the top vulnerabilities putting IBM i at risk, and the steps you can take to protect your organization. If you’re looking to avoid unexpected downtime or corrupted data, you don’t want to miss this session.

  • SB HelpSystems ROBOT GenericCan you trust all of your users all of the time? A typical end user receives 16 malicious emails each month, but only 17 percent of these phishing campaigns are reported to IT. Once an attack is underway, most organizations won’t discover the breach until six months later. A staggering amount of damage can occur in that time. Despite these risks, 93 percent of organizations are leaving their IBM i systems vulnerable to cybercrime. In this on-demand webinar, IBM i security experts Robin Tatam and Sandi Moore will reveal:

  • FORTRA Disaster protection is vital to every business. Yet, it often consists of patched together procedures that are prone to error. From automatic backups to data encryption to media management, Robot automates the routine (yet often complex) tasks of iSeries backup and recovery, saving you time and money and making the process safer and more reliable. Automate your backups with the Robot Backup and Recovery Solution. Key features include:

  • FORTRAManaging messages on your IBM i can be more than a full-time job if you have to do it manually. Messages need a response and resources must be monitored—often over multiple systems and across platforms. How can you be sure you won’t miss important system events? Automate your message center with the Robot Message Management Solution. Key features include:

  • FORTRAThe thought of printing, distributing, and storing iSeries reports manually may reduce you to tears. Paper and labor costs associated with report generation can spiral out of control. Mountains of paper threaten to swamp your files. Robot automates report bursting, distribution, bundling, and archiving, and offers secure, selective online report viewing. Manage your reports with the Robot Report Management Solution. Key features include:

  • FORTRAFor over 30 years, Robot has been a leader in systems management for IBM i. With batch job creation and scheduling at its core, the Robot Job Scheduling Solution reduces the opportunity for human error and helps you maintain service levels, automating even the biggest, most complex runbooks. Manage your job schedule with the Robot Job Scheduling Solution. Key features include:

  • LANSA Business users want new applications now. Market and regulatory pressures require faster application updates and delivery into production. Your IBM i developers may be approaching retirement, and you see no sure way to fill their positions with experienced developers. In addition, you may be caught between maintaining your existing applications and the uncertainty of moving to something new.

  • LANSAWhen it comes to creating your business applications, there are hundreds of coding platforms and programming languages to choose from. These options range from very complex traditional programming languages to Low-Code platforms where sometimes no traditional coding experience is needed. Download our whitepaper, The Power of Writing Code in a Low-Code Solution, and:

  • LANSASupply Chain is becoming increasingly complex and unpredictable. From raw materials for manufacturing to food supply chains, the journey from source to production to delivery to consumers is marred with inefficiencies, manual processes, shortages, recalls, counterfeits, and scandals. In this webinar, we discuss how:

  • The MC Resource Centers bring you the widest selection of white papers, trial software, and on-demand webcasts for you to choose from. >> Review the list of White Papers, Trial Software or On-Demand Webcast at the MC Press Resource Center. >> Add the items to yru Cart and complet he checkout process and submit

  • Profound Logic Have you been wondering about Node.js? Our free Node.js Webinar Series takes you from total beginner to creating a fully-functional IBM i Node.js business application.

  • SB Profound WC 5536Join us for this hour-long webcast that will explore:

  • Fortra IT managers hoping to find new IBM i talent are discovering that the pool of experienced RPG programmers and operators or administrators with intimate knowledge of the operating system and the applications that run on it is small. This begs the question: How will you manage the platform that supports such a big part of your business? This guide offers strategies and software suggestions to help you plan IT staffing and resources and smooth the transition after your AS/400 talent retires. Read on to learn: