21
Sat, Dec
3 New Articles

Practical RPG: Using Work Files with SQL

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

Create work files in SQL, but update them with ILE RPGthe best of both worlds.

 

In a previous article, I went into some detail on using work files in ILE RPG. Next came an article that demonstrated how to build a work file using SQL. Here, I show you how to combine those two techniques in applications where you want to use SQL as much possible but you still need to use RPG to perform some in-depth calculations that SQL doesn't handle particularly well. The good news is that you can do that quite easily by using SQL to build a work file and then use ILE RPG to update the file with more complex calculations. After you're done, you can use SQL again to access the data, and everyone is happy!

 

You Want to Do WHAT with SQL?

I know that some people might consider me a heretic for even considering the idea of using SQL to build a work file. But anyone who has read what I've written on the subject over the years knows that I consider RPG to be the assembly language of the database, the tool you go to when you just can't get it done with anything else. So how best to make SQL and RPG work together? Work files happen to fit the bill quite nicely.

 

In the first work files article, I suggested a report that sorts orders by their price variance. The requirement is to compare the price for each line of the order with the expected price for that order, calculate a percent variance, and then build a report ordered by that variance. Such a report would require the expected price for each line for comparison. Being a cagey reader, you may have already considered that the best idea might be to store the expected price in the order line record at the time of the order, but let's assume for the moment that the original application designers aren't quite as prescient as you and have to deal with this situation after the fact. How can they do it?

 

The second article showed how to do it in a simple case, in which the item price is static and stored in the item master record. That's not likely to be the case in any but the simplest environments. More likely, you'll need to sift through a whole sequence of files.

 

Work Files to the Rescue!

We can use a work file to solve this particular dilemma. The critical field, the price variance, will be calculated in an RPG program, but that RPG logic will be sandwiched between two different SQL queries. The first query will build a work file with the records we may want to include in our report. This, by the way, is one of the reasons we use SQL on both the front and back ends: with SQL, we can easily select only those records that match certain criteria, and those criteria can be very flexible. This cuts down the number of records for which we need to perform the potentially expensive RPG logic. Next, we use traditional RPG code to process the work file, retrieving the expected cost for each line and then using that to calculate the variance. Both those values are stored in the work file. Finally, we use a second query to select data from the file and create the report.

 

It sounds pretty simple, and really it is, but it does take a little bit of thought.

 

QTEMP or Not QTEMP, That Is the Question

The only real question that needs to be addressed first is whether to put this file into QTEMP. There are cases when it might be better to use a file in a non-transient library. This is especially true when the build is particularly lengthy and you might want to reuse the data for more than one reporting run. You might, for example, run a nightly summary that users then query against during the day. But in the case where we're simply building an ad hoc table for a one-time report, I find QTEMP to be a much better choice.

 

If you read the previous article, you might recognize the following file specification:

 

      dcl-f WORKFILE keyed extfile('QTEMP/WORKFILE');

 

This tells the program to look in QTEMP for the file, regardless of your library list. This of course means that you need to have that file in QTEMP. There are a number of ways to do this. The traditional approach would be to execute a couple of OS commands: DLTF followed by CRTDUPOBJ is probably the most common method. You execute an SQL to fill the file with only those records that match your primary inclusion criteria. Next, you read through the file and perform your updates using RPG business logic. Finally, you can use SQL again to read through the file. The program might look something like this:

 

// Insert desired order lines into work file

exec sql insert into QTEMP.WORKFILE    

(XXORNO, XXORLN, XXITEM, XXITPR)        

(select OHORNO, ODORLN, ODITEM, ODITPR        

   from ORDHDR join ORDDTL on ODORNO = OHORNO  

   where OHREGN = :Region                      

     and OHORDT between :StartDate and :EndDate

     and OHSTAT = '90');                        

                                                

// Read through work file and update expected price

open WORKFILE;                                  

read WORKFILE;                                  

dow not %eof(WORKFILE);                        

exsr CheckPrice;                              

read WORKFILE;                                

enddo;                                          

close WORKFILE;                                  

                                                

// Process all orders with at least one underpriced line

exec sql declare c cursor for                  

   select * from WORKFILE where OHORNO in      

   (select OHORNO from WORKFILE where XXUNDER = 'Y');

                                                

exec sql open c; ...                           

 

Refer to the comments as I explain how this works. First, we have to select all the lines that meet the initial selection criteria, which in this case consist of a region and a date range. The orders also have to be complete, with a status of 90. The INSERT statement sets only those fields that are needed. Now that the file is filled with potential records, the next step is to run through all of those records and check the price. You'll note a call to subroutine CheckPrice. It's not important what that routine does; for all we know, it calls another program to get the expected price. The logic could be 5 lines or 50; we don't care. All we need to know is that it will update the expected price in the record and also set the flag XXUNDER to a Y if the price is low enough to trigger an exception. This brings us to the third section of code, which then selects only those lines that belong to orders having at least one underpriced line. What happens after that depends on what the application needs to do, but this is the code that gets the correct lines.

 

All SQL All the Time

The biggest shortcoming of this approach is that you have to create the file ahead of time. The file WORKFILE must be a traditional externally described file and consequently would need to be changed every time we need a new field. This is not a huge deal, but it can be annoying.

 

If you're willing to embrace SQL just a little more, we can fix that. Building on our code from the previous article, we can change the first two sections of code to instead look like this:

 

// Insert desired order lines into work file      

exec sql drop table QTEMP.WorkFile;                

exec sql create table QTEMP.WorkFile as            

(select OHORNO, ODORLN, ODITEM, ODITPR,          

          cast (0 as decimal(11,5)) XXFILE,        

         cast (' ' as char(1)) XXUNDER            

   from ORDHDR join ORDDTL on ODORNO = OHORNO      

   where OHREGN = :Region                          

     and OHORDT between :StartDate and :EndDate  

     and ODSTAT = '90') with data;                          

                                                  

// Read through work file and update expected price

exec sql declare upd cursor for                    

   select * from QTEMP.WorkFile for update;              

exec sql open upd;                                

exec sql fetch next from upd;                      

dow SQLCOD = *zeros;                              

exsr CheckPrice;                                

exec sql fetch next from upd;                    

enddo;                                            

 

So in this case you should notice two primary differences. First is that the work file is deleted and recreated using the SQL DROP TABLE and CREATE TABLE statements. Also, in addition to defining the data points we retrieve from other files in the SELECT statement, we also have to carefully define the work fields as well as their default values. Other than that, though, the initial selection stays the same. The second difference is bigger and more fundamental. Because we have no idea what the layout of the file might be, we can't use a traditional RPG file specification. Once again, SQL comes to the rescue, allowing us to update the records by using a cursor. No matter the actual layout of the file, this cursor will still work. We just have to make sure that the CheckPrice routine updates the file using the cursor (you use the UPDATE … WHERE CURRENT syntax).

 

That covers the use of work files in SQL. We might revisit this again to talk a little more about CREATE TABLE and how to define files on the fly, but for now this should give you what you need.

 

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: