This article compares SQLCOD and SQLSTT and shows you how to avoid one of the primary gotchas you face when using SQLSTT.
Embedded SQL programming is one of the most productive additions ever made to the IBM i development environment. But it's rarely used to run the traditional example statements you see in the SQL programming books: statements that increase the price of every item by 15 percent. Instead, the most often used construct in the embedded SQL toolkit is the cursor, which essentially provides a dynamically built logical file to your RPG program. And like any logical file, an essential part of using the file is knowing when you've hit the end. RPG provides two variables: SQLCOD and SQLSTT. SQLSTT is the more standard technique, but its improved accuracy does not come without some cost. Fortunately, that cost is pretty low, and I'll even pick up the tab!
SQLCOD vs. SQLSTT
You can do your own research on which of these is better. SQLCOD and SQLSTT are the RPG variables that represent the standard SQL variables SQLCODE and SQLSTATE. A nice discussion of the topic can be found on the PostgreSQL site. If you do decide to move to SQLSTT, you will find that in nearly every case you can replace references to SQLCOD with very similar references to SQLSTT. Let's look at an example.
exec sql declare c cursor for
select CUCUST, CUNAME from CUSMAS
order by CUNAME;
exec sql open c;
dow SQLCOD = 0;
exec sql fetch next from c into :wCust, :wName;
if SQLCOD = 0;
exsr processCustomer;
endif;
enddo;
exec sql close c;
Let me briefly review the code. First, I create a cursor over the customer master, retrieving the customer ID and name for every record order by customer name. I then open the cursor and start a loop in which I fetch data from the cursor into local variables wCust and wName. If the variable SQLCOD is zero, I process the values (in this case, by calling a subroutine). The code will loop as long as SQLCOD is zero, jumping up to fetch the next row. SQLCOD will return a value of 100 when there are no more rows to be fetched, and we drop out of the loop and close the cursor. Nothing to it. (Note that using a DOW checks for an error on the open cursor.)
The only change to this routine to get functionally (almost) equivalent code would be to change the SQLCOD = 0 to SQLSTT = *ZEROS. I use the figurative constant *ZEROS because SQLSTT is a character field, and I have to either use *ZEROS or else spell it out with '00000'. The better option of course is to define a named constant up in my D-specs, but I want you to see the actual values, and it's easier if I just hardcode them into the code. Don't you hardcode it, though; do as I say, not as I do!
This technique is pretty slick. It does ignore something, though, which is an SQL error. SQL errors tend to be silent; they return a value, but they don't send an exception message to the calling program, which in turn means they don't cause a hard halt to the user or the system operator. Whereas a record lock or a decimal data error makes itself known in native I/O, such things can kind of slide by under the radar unless you check for them.
So, you need to have a little additional code at the end of your loop. My code usually looks something like this:
if SQLSTT <> '02000';
exsr fatalError;
endif;
An SQLSTT of '02000' means normal end of file. If I get out of my loop and I don't get that value, it's time to execute my fatal error logic. What sort of processing do I do? It depends on the situation. For an interactive program, it might be as simple as sending a message to the user and continuing on. In a batch job, I might dump the program and send a message to the system operator. This will happen whenever SQLSTT returns something that is not '00000' or '02000', and therein lies the problem.
SQL and Warning Messages
Let me illustrate the problem using a real-world example. Let's say I want to figure out the first order date for a customer. I want to process all customers, even those without orders. For customers that have no orders, I want the query to return a default date, say 12/31/2099. The SQL statement is easy:
select CUCUST, ifnull(min(OHDATE),'2099-12-31')
from CUSMAS left outer join ORDHDR on CUCUST = OHCUST
order by CUCUST;
It uses a left outer join to return every row from the CUSMAS file, whether or not it finds a matching record in the ORDHDR file. If no matching records are found, the min(OHDATE) will return null. The code tests for this condition by using the ifnull function to replace null values with a default value of 2099-12-31. You can slip this into an RPG program and run it, and it will run fine. Fine, that is, right up until the point where it runs into a customer master without an associated order. And then suddenly your program will go BOOM!
Well, whether it goes boom or not depends on how you coded it. If you didn't include an end-of-loop test like the one above, the program will just think it hit end of file and will end normally—except that it didn't process all the records! Why is that? Well, a review of SQLSTT will be your first clue. As it turns out, SQLSTT returns the value '01003'. If you look up this error, you'll see something like this: "Null values were eliminated from the argument of a column function." Well, we know that! That's why we coded the ifnull function! But DB2 wants to be absolutely sure we know that something went awry, and so it gives us this little extra nudge by returning a warning value in SQLSTT.
How do you handle this situation? First off, you have to know that you can get a warning error and that it's OK. You usually only know this after you get the error, so there is some level of empirical work involved, but as time goes on, you recognize potential problems. For example, this specific warning usually involves aggregate functions on left outer joins. Once you identify the potential problem, you can add a check to your program to not exit when a warning occurs. You might do something like this:
if %subst(SQLSTT:1:2) <> '00'
and %subst(SQLSTT:1:2) <> '01';
iter;
endif;
exsr processCustomer;
Do you see how this works? We check the first two characters to be either 00, which indicates a successful fetch, or 01, which identifies a warning condition. This might be too forgiving; there are a lot of warning conditions and many may not be as benign as the 01003 error. Click to see a list of the SQLSTT values. You may need to narrow down your check to specific values rather than just test the class (the first two digits).
To wrap this one up, let me give you very specific code for this situation, in which I check for either success or a null column:
exec sql declare c cursor for
select CUCUST, ifnull(min(OHDATE),'2099-12-31')
from CUSMAS left outer join ORDHDR on CUCUST = OHCUST
order by CUCUST;
exec sql open c;
dow SQLSTT = '00000'
or SQLSTT = '01003';
exec sql fetch next from c into :wCust, :wDate;
if SQLSTT = '00000'
or SQLSTT = '01003';
exsr processCustomer;
endif;
enddo;
if SQLSTT <> '02000';
exsr fatalError;
endif;
exec sql close c;
That's it for this session. I hope it lets you unlock a little more of the power of SQL in your shop!
as/400, os/400, iseries, system i, i5/os, ibm i, power systems, 6.1, 7.1, V7,
LATEST COMMENTS
MC Press Online