When RPG programmers begin to use SQL, one of the more difficult things for them to adjust to is that the SQL statements do not issue escape messages if an error occurs. They simply set a few status codes and return control to the next line of code in the program. Combating this problem requires a new methodology for handling SQL errors within our RPG programs. This article explores using the Communications Area to get more information about how the previous SQL statement performed.
The SQL Communications Area, or SQL CA, is automatically inserted into a program containing embedded SQL during the compile process. It consists of a number of fields and arrays:
D SQLAID 1 8A
D SQLABC 9 12B 0
D SQLCOD 13 16B 0
D SQLERL 17 18B 0
D SQLERM 19 88A
D SQLERP 89 96A
D SQLERRD 97 120B 0 DIM(6)
D SQLERR 97 120A
D SQLER1 97 100B 0
D SQLER2 101 104B 0
D SQLER3 105 108B 0
D SQLER4 109 112B 0
D SQLER5 113 116B 0
D SQLER6 117 120B 0
D SQLWRN 121 131A
D SQLWN0 121 121A
D SQLWN1 122 122A
D SQLWN2 123 123A
D SQLWN3 124 124A
D SQLWN4 125 125A
D SQLWN5 126 126A
D SQLWN6 127 127A
D SQLWN7 128 128A
D SQLWN8 129 129A
D SQLWN9 130 130A
D SQLWNA 131 131A
D SQLSTT 132 136A
Rather than try to explain every field in the SQL CA, I'll just review some of the more useful ones:
SQLERM contains message data text for the SQLCOD value.
SQLERP contains the name of the product and module returning an error.
SQLERRD is an array containing six diagnostic codes:
(1) The last four digits of the CPF message if SQLCOD is negative.
(2) The last four digits of the CPD message if SQLCOD is negative.
(3) For INSERT, UPDATE, DELETE, and FETCH, the number of rows affected. For PREPARE, the estimated number of rows returned.
(4) For PREPARE, the estimated cost of execution. For CALL, the message key of the error that caused the call to fail. For trigger errors during INSERT, UPDATE, or DELETE, the message key of the error. For FETCH, the length of the row.
(5) For DELETE, the number of rows affected by referential constraints. For PREPARE or EXECUTE IMMEDIATE, the position of a syntax error. For multi-row FETCH, +100 if the last record was read. For CONNECT and SET CONNECTION, -1 if not connected, 0 if local, 1 if remote. For PREPARE, the number of parameter markers.
(6) SQL completion code when SQLCOD is 0.
SQLWN4 is loaded with "W" if an UPDATE or DELETE statement does not contain a WHERE clause.
SQLWN6 is loaded with "W" if arithmetic caused an end-of-month adjustment.
SQLCOD contains the SQL Return Code. As of V5R3, this field may also be spelled SQLCODE.
SQLSTT contains the SQL Status Code. As of V5R3, this field may also be spelled SQLSTATE.
IBM provides a PDF document on SQL messages and codes.
The simplest rule of thumb is that you should check the value of SQLCOD after every SQL statement. If it is zero, the statement completed normally. If it's negative, a serious error occurred. If it's equal to 100, the previous FETCH reached end-of-file. Any other positive value indicates a warning of some sort. Below are two examples of error-handling with SQL embedded inside RPG IV. The first is prior to V5R4:
C+ PREPARE SQLSTMT FROM :W_SQL
C/END-EXEC
/FREE
IF SQLCOD <> *zero;
ErrCod = 'SQL' + %SUBST(%EDITC(SQLCOD:'X'):6:4);
SendMsg(ErrCod:SQLERM:'QSQLMSG');
ENDIF;
/END-FREE
The second is V5R4 or later:
EXEC SQL PREPARE SQLSTMT FROM :W_SQL;
IF SQLCOD <> *zero;
ErrCod = 'SQL' + %SUBST(%EDITC(SQLCOD:'X'):6:4);
SendMsg(ErrCod:SQLERM:'QSQLMSG');
ENDIF;
/END-FREE
Both examples perform identically, but you can see that the new EXEC SQL syntax available in V5R4 leads to much more readable code when mixing with free-format RPG. In this example, if any error occurs, SQLCOD is set to a non-zero value. The appropriate error message ID is assembled by taking the last four digits from SQLCOD, prefixing them with SQL, and then using SENDMSG to send that error message to the calling program. SENDMSG is a procedure I wrote that simplifies access to IBM's message-sending APIs. You can replace my SENDMSG with any message-handling technique you like.
The most important thing to remember is that you must test SQLCOD after each statement. If a statement fails, the program continues to run, which could lead to serious errors in your database. More documentation on embedded SQL, the Communications Area, and error handling is available at IBM's embedded SQL programming Web page.
Kevin Forsythe has worked on IBM midrange systems for more than 20 years. With many years of experience in programming, analysis, consulting, and instruction, he is uniquely skilled at making difficult material more easily understood. As the lead instructor for DMC Consulting’s AS/Credentials training classes, Kevin is responsible for developing up-to-date courseware as well as providing instruction on a wide range of topics. This comprehensive background includes practical application, education, and research and provides a perspective that allows him to help others steer their way through the technical maze that surrounds them.
Kevin speaks regularly at conferences and user group meetings, volunteers as a Subject Matter Expert for COMMON, has written numerous articles on a variety of iSeries topics, and authored the bestselling book SQL for eServer i5 and iSeries.
LATEST COMMENTS
MC Press Online