Fixed-format and ILE RPG programs can benefit from the use of SQL statements to improve IBM i database access
Editor’s Note: This article is excerpted from chapter 11 of Evolve Your RPG Coding: Move from OPM to ILE ... and Beyond, by Rafael Victória-Pereira.
It’s possible to embed SQL code in your RPG programs, allowing them to interact with massive quantities of data at a time, breaking the “process-a-record-at-a-time” RPG traditional approach. Don’t get me wrong—I’m not saying that you should change the way your programs interact with every single data interaction—but some of them could probably have their performance, readability, and reliability improved by SQL. SQL statements can be placed in detail calculations, in total calculations, and in RPG subroutines.
The SQL statements are executed based on the logic of the RPG statements. For instance, when you place an SQL statement inside an RPG IF statement, the SQL statement will be executed if the condition of the RPG IF statement is met. Both uppercase and lowercase letters are acceptable in SQL statements.
By now you’re anxious to begin, right? First, you need to learn how to embed SQL code in your code.
How to Embed SQL Code in Fixed-Format RPG
In order for the compiler to recognize the SQL statement as such, you need to signal it appropriately, by using compiler directives that indicate where the SQL statement starts and ends. Those compiler directives are /EXEC SQL and /END SQL.
The /EXEC SQL directive must occupy positions seven through 16 of the source statement. The SQL statement may start in position 17 and continue through position 80. The same applies to /END SQL: it must occupy positions seven through 16 of the source statement, and you must leave the rest of the line blank.
Here’s a simple SELECT example:
C* Some RPG code here ...
C/EXEC SQL SELECT COUNT(*)
C+ FROM InvMst
C/END-SQL
C* And some more here ...
Notice the indentation? It’s not really necessary, but it improves readability. What’s really needed is the plus sign (+) in each line other than the /EXEC SQL line. You can write the whole statement on the same line (assuming it fits between positions 17 and 80), but that will hamper readability and future maintainability of the code. Anyway, the code looks simple enough, doesn’t it? Well, you’ll see that it’s even simpler in free format.
How to Embed SQL Code in Free-Format RPG
You’re probably thinking, “This is really simple! How can it get even simpler?” As you know by now, free-format statements must end with the semicolon character (;). For embedded SQL statements, that means that you can do without the /END SQL directive. You also know that a free-format statement can span multiple lines without any special indication. For SQL statements, this means no more plus sign in each line of the statement. Finally, you can simply write EXEC SQL as if it were an ordinary RPG operation code. The only requirement is that you write the words “EXEC” and “SQL” on the same line. Putting all of that together, here’s the same simple SELECT in free format:
EXEC SQL
SELECT COUNT(*)
FROM InvMst;
This allows you to seamlessly integrate a SQL statement with your code, in a way that likens RPG to the so-called “modern programming languages.” There’s only one small flaw in these two examples: they don’t actually work! While in interactive SQL or the i Navigator, you have a way to “see” the output. That’s not the case here. You need something to communicate with the SQL statements. In other words, you need something to get data in and out, thus allowing you to perform, for instance, surgical updates or deletes over massive amounts of data. The easiest way to establish this two-way communication is by using host variables.
How to Get RPG and SQL to Talk to One Another in Your Programs
Let’s modify the sample SELECT statement from the previous example so that it passes table InvMst’s total number of rows back to the (imaginary) RPG program in which the statement is embedded. I didn’t mention this before, but the SELECT SQL instruction has another optional clause, which only makes sense when you’re using the instruction in a programming environment. You’re not simply querying the database with a SELECT statement; instead, the SELECT statement is part of a stored procedure or an embedded statement, like the case at hand. Here’s the “new” syntax:
SELECT <column 1>
[, <column 2>, <column 3>...., <column n>]
[INTO host-variable 1, host-variable 2 ..., host-variable n]
FROM <table name>
[WHERE <condition 1> <logical operator> <condition 2>, etc.]
The INTO clause directs the output of the SELECT clause to one or more host variables. These variables must be compatible with the data types of the respective columns in the SELECT clause. In other words, if column1 is a string, then host-variable1 should, ideally, be a string.
It’s now time to revisit the SELECT sample and change it, so that its output is directed to host variable W_TotReg:
EXEC SQL
SELECT COUNT(*)
INTO :W_TotReg
FROM InvMst;
Notice the semicolon character (:) before the host variable name. That’s the way to tell the compiler that the variable is not an SQL field, but a program field instead. After this code is executed, W_TotReg is going to hold the total number of records of table InvMst.
You can also use host variables in the WHERE clause, to define conditions for any DML instruction. Imagine that you want to reduce the expiration date of all the items in warehouse 24’s inventory by one day. Using only RPG, this would mean reading the InvMst table in a loop, making sure that you only affected items where the WHID column contained '24', calculating the new expiration date (using the BIFs from chapter 6, for instance), and updating each record. It’s not difficult to do (after all, we’ve been doing stuff like this for years), but it takes a while to build. Now let’s do it in six lines of code:
/FREE
K_WHID = 24; // key to the warehouse Id
W_Exp_Reduction = 1; // nbr of days to cut in the exp. dates
EXEC SQL
Update InvMst
Set ExpDate = ExpDate – :W_Exp_Reduction DAYS
Where WHID = :K_WHID;
/END-FREE
Technically, that’s eight lines of code, but if you read chapter 10, you know that after installing a certain PTF, you can do without the /FREE and /END FREE compiler directives.
There are a few new things in this code, so let’s dissect it line by line:
- The first two lines assume that variables K_WHID and W_Exp_Reduction have been defined somewhere else, and simply serve to assign values to them.
- The SQL statement begins with the EXEC SQL line, just like in the previous examples.
- The UPDATE INVMST line shouldn’t be a surprise—you saw the UPDATE statement a few sections ago, and this is part of the typical syntax of the SQL instruction.
- The fun begins with the next line. When I discussed the date-related functions, I didn’t mention, quite intentionally, this way of performing calculations involving dates. It’s nothing special, but it has to follow some rules: the variables involved (the ExpDate in this case) have to be of the date, time, or timestamp data type. However, you need to be reasonable, because it doesn’t make sense to subtract a day from a time field.
Speaking of reasonability, it doesn’t make sense to multiply dates or times, only to add or subtract them, so the only operators that you can use are the plus and minus signs. Finally, you need to use one of the date-related reserved words (YEARS, MONTHS, DAYS, HOURS, MINUTES, SECONDS, and MICROSECONDS) to define the unit of the quantity that you’re adding or subtracting.
All of this is to explain that the SET line will simply subtract one day from ExpDate and assign the result of the operation back to ExpDate. If W_Exp_Reduction had the value 2, then this would reduce the expiration date in two days, and so on. Note that W_Exp_Reduction is not an SQL column or variable—it comes from the RPG code. That’s the reason for the semicolon character that precedes it. If, instead of reducing the expiration date by one day, I wanted to increase it by three months, I’d just change W_Exp_Reduction’s value appropriately and adjust the SET line to the following:
Set ExpDate = ExpDate + :W_Exp_Reduction MONTHS
- In the last line, K_WHID is being used to restrict the UPDATE’s scope to the lines that contain WHID = 24, because K_WHID contains 24.
While the SELECT example showed how to use a host variable to receive data from the embedded SQL statement, this UPDATE example showed how to use host variables to send data to the embedded SQL statement. Naturally, if you have a SELECT statement that uses host variables in the INTO and WHERE clauses, you’ll be receiving data (in the INTO clause) and sending data (in the WHERE clause) simultaneously.
This is a great way to extend what RPG can do with the awesome power of SQL, but (as always) there are a few restrictions:
- The host variable names can’t start with the characters “DSN,” “RDI,” “SQ,” or “SQL.” These names are reserved for the database manager.
- The length of the host variable names can’t exceed 64 characters.
- Some data types can’t be used as host variables. The list below includes the most common:
- Unsigned integers
- Pointers
- Tables
- UDATE
- UDAY
- UMONTH
- UYEAR
- Look-ahead fields
- Named constants
- Multiple-dimension arrays
- Definitions requiring the resolution of %SIZE or %ELEM
- Definitions requiring the resolution of constants, unless the constant is used in OCCURS, DIM, OVERLAY, or POS and is declared before it is used in the OCCURS, DIM, OVERLAY, or POS
As you might imagine, the RPG compiler doesn’t know how to handle SQL. Additionally, your editor of choice (SEU, RDi, or some other editor) might not recognize the SQL in the source, so you also need to change the source member type from RPGLE to SQLRPGLE. As you might have gathered, all of this means that you can’t simply compile an RPG source that has embedded SQL statements with the CRTRPGMOD or CRTBNDRPG commands. You need to use something that transforms the SQL statements into a language the RPG compiler understands: you need new compilation commands.
How to Compile SQL-Infused RPG Code
I explained (way) back in chapter 2 how to compile modules, programs, and service programs. The only source that is compiled is the module’s, so I only need one new command, which will allow me to call the SQL precompiler (a nice little thing that turns the embedded SQL statements into something the RPG compiler understands) before calling the familiar CRTRPGMOD. After the module is created, binding it to a program or service program follows the usual process.
The command is CRTSQLRPGI (Create SQL ILE RPG object), and it’s similar to CRTRPGMOD. However, CRTSQLRPGI can be used to create modules, service programs, or programs.
Let’s say I want to compile a module named SQLOPS. All I need to do is issue the following command:
CRTSQLRPGI OBJ(MYLIB/SQLOPS) SRCFILE(MYLIB/QRPGLESRC) SRCMBR(*OBJ) COMMIT(*NONE) OBJTYPE(*MODULE) DBGVIEW(*SOURCE) USRPRF(*OWNER) DYNUSRPRF(*OWNER)
It’s important to remember the parameter OBJTYPE(*MODULE) because that’s what indicates you’ll be creating a module, instead of a program or service program. Note that you can also create a program by specifying *PGM, or a service program (*SRVPGM) in this parameter. I usually create a module and then bind it to a program or service program, along with other modules, as needed. This command has several other parameters, but a deep knowledge of them is not required for most situations. (If you really want to know, check out the CRTSQLRPGI full description at https://www.ibm.com/support/knowledgecenter/ssw_ibm_i_71/cl/crtsqlrpgi.htm.)
I suggest that you create a user-defined PDM option for this command, similar to the ones mentioned in chapter 2. Because BS and BM are already taken (Build Service program and Build Module, respectively), your Build SQL module can be option BQ, for instance:
CRTSQLRPGI OBJ(&L/&N) SRCFILE(&L/&F) OBJTYPE(*MODULE)
This will save you some time and a lot of typing.
LATEST COMMENTS
MC Press Online