Create work files in SQL, but update them with ILE RPG—the 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.
LATEST COMMENTS
MC Press Online