Now that you can tell SPs from UDFs, let’s find out how to create RPG-infused stored procedures, step by step.
In the previous TechTip, I (very briefly) introduced Persistent Storage Modules and explained the differences between stored procedures (SPs), user-defined functions (UDFs), and triggers. Now let’s go deeper into the creation process of SPs. How do you build them? The answer is kind of funny—you already have! Almost any existing program or procedure can be made available as an SP, you just need to register it in SQL as such. This includes, naturally, yourRPG programs and procedures.
Converting an Existing RPG Procedure into an SQL Stored Procedure
Let’s take a simple item availability procedure as an example. This procedure takes an item ID and a quantity as input parameters and returns the expected availability date as an output parameter. Note that this is just a procedure, a small modular part of the much bigger order entry process, but you can also declare a full-blown program as an SP—it’s just a matter of more or less parameters, from SQL’s point of view.
Registering a procedure as an SP is simple. SQL provides the CREATE PROCEDURE instruction for that. Let’s start by looking at the item availability’s procedure interface:
*----------------------------------------------------------------------*
* Item availability (returns the expected availability date for *
* given item id and quantity) *
*----------------------------------------------------------------------*
P Rtv_ItemAvail B Export
D Rtv_ItemAvail PI
* Input parameters
D P_ItemID 15A 0 VALUE
D P_ItemQty 9P 2 VALUE
* Output parameters
D P_AvailDate D
This is a typical procedure interface, and it should be self-explanatory. Sorry for the fixed-format code, but that’s actually irrelevant for this explanation. Actually, it serves to show that existing, “unmodernized” code can be used in this process. Now let’s write the corresponding CREATE PROCEDURE statement:
CREATE PROCEDURE RetrieveItemAvailability
(IN ItemID CHAR(15), IN ItemQTY DEC(9,2)
OUT AvailDate DATE)
EXTERNAL NAME ‘MyLib/BRItm(Rtv_ItemAvail)’
LANGUAGE RPGLE
PARAMETER STYLE General
Let’s analyze this line by line:
- The first line contains the necessary SQL instruction and the SQL name of the SP, which can, as it is in this case, be different from the RPG name.
- The second and third lines define the SP’s parameters, using the reserved words IN and OUT to clearly identify parameters as input or output. Just a couple of notes regarding the parameters: there’s a third option, INOUT, that declares the parameter as both input and output, which is RPG’s default for parameters. Unless you use the VALUE or CONST keywords, all RPG parameters are both input and output parameters. The SP parameter names don’t have to match the RPG procedure parameter names; they are only placeholders for the parameters and their data types and lengths.
- The next line provides the necessary link between the SQL name and the RPG name for the procedure, using the EXTERNAL NAME keyword, followed by the structure <library name>/<service program name>(<RPG procedure name>). If I wanted to use a *PGM object as an SP, the last part (<RPG procedure name>) would not be necessary. In other words, if my SP is going to be linked to a program called ITMAVB, this line would become this:
EXTERNAL NAME MyLib/ITMAVB
- The fifth line indicates the language in which the procedure is written. If the object already exists, SQL can figure out the language on its own; however, for documentation and clarity purposes, it’s a good practice to include this line here. Finally, the PARAMETER STYLE General line indicates which parameter “working model” will be used. Note that even though GENERAL is the most used and will probably be enough for most situations, other options exist, such as SQL, DB2GENERAL, GENERAL WITH NULLS, and JAVA. I won’t explain them here, so after you get some practice with SPs and UDFs, please refer to the DB2 for i SQL Reference manual for details.
This is the simplest possible CREATE PROCEDURE statement I can issue for the Rtv_ItemAvail procedure. There are two more lines that I didn’t include here because SQL provides default values for them, allowing you to bypass them. The DETERMINISTIC or NOT DETERMINISTIC specification determines whether the procedure returns the same results each time the SP is called with the same IN and INOUT arguments. The default is NOT DETERMINISTIC, which means the SP may not return the same result each time the procedure is called with the same IN and INOUT arguments, even when the referenced data in the database has not changed.
DETERMINISTIC means that the SP always returns the same results each time the procedure is called with the same IN and INOUT arguments, assuming the referenced data in the database hasn’t changed. In other words, it means SQL doesn’t have to call the procedure repeatedly if the parameters’ values don’t change, because it can “remember” the last answer and not call your procedure, thus improving performance. Keep in mind that the default is NOT DETERMINISTIC, so in most cases, there’s a performance gain in specifying DETERMINISTIC in the CREATE PROCEDURE statement.
The other specification is related to RPG’s code itself. It specifies the classification of SQL statements that this procedure, or any code called by it, can execute. The database manager verifies that the SQL statements issued by the procedure and all code it calls are consistent with this specification. The default is MODIFIES SQL DATA, but there are other options:
- NO SQL—The procedure (and any other code it calls) doesn’t use any SQL whatsoever. If it tries to use SQL, an error will occur.
- CONTAINS SQL—Only a few SQL instructions, like COMMIT, ROLLBACK, and SET, are allowed. Note that the SQL statements used in the procedure can’t include DML instructions.
- READS SQL DATA—Reading data using SELECT or FETCH statements is allowed, but updates via SQL are not.
- MODIFIES SQL DATA—All SQL statements that are supported in procedures are allowed, including DML and DDL instructions.
After issuing this SQL statement, the RPG procedure is linked to the database, which means that every time you recompile the module where it resides, you must also recreate the SP. How do you do that? You need to issue a DROP PROCEDURE statement, like this one:
DROP PROCEDURE RetrieveItemAvailability
This is followed by a new CREATE PROCEDURE, similar to the one you used before, unless the procedure’s parameters have changed. In that case, you need to adapt the SP’s parameters to match the RPG procedure’s parameters’ type and length.
It’s a good practice to save your CREATE PROCEDURE statements, which can get pretty huge when the number of parameters grows, in a separate source member. I personally like to use QSQLSRC and execute them with the RUNSQLSTM CL command, but I’ve seen folks save them in the IFS and execute them in the i Navigator Run SQL Scripts tool.
Even with all this, stored procedures are only half of how you can reuse your RPG code (the less interesting half, in my opinion). User-defined functions have a broader scope, as you’ll discover in the next TechTip!
LATEST COMMENTS
MC Press Online