This first article on combining the strengths of RPG and SQL focuses on defining and testing stored procedures.
SQL and RPG are powerful and complementary tools. SQL does things well that are difficult or nearly impossible in RPG and vice versa. The trick is to develop programming strategies that take advantage of both. IBM recognized this and created the potent embedded RPG tooling, which allows you to easily take advantage of SQL from within RPG programs. This article is going to focus on the related technique of calling RPG from within SQL.
Stored Procedures and User-Defined Functions
Let me set the stage just a little. SQL defines two mechanisms for extending the language: stored procedures and user-defined functions (UDFs). Stored procedures were originally designed to execute external code, usually written in C. DB2 on the IBM i extends that capability to execute code written in any language, including RPG. UDFs, on the other hand, are encapsulated pieces of SQL logic that can be used by other SQL statements.
The clearest difference is where each can be used. A call to a stored procedure tends to be a standalone operation. You invoke the stored procedure typically to update a variable, which you can then use in another discrete statement. You cannot, for example, use the result of a stored procedure in a WHERE clause of another SELECT statement. Instead, you invoke the stored procedure, store the result somewhere, and then execute the SELECT statement. Thus, stored procedures are limited to programmatic SQL environments, such as embedded SQL, or within other SQL functions.
A UDF on the other hand is designed specifically to be used within another SQL statement. It can be used just as easily in an ad hoc query as in a complex SELECT statement. In many ways, this parallels the difference between a program call and a procedure call.
A specific example would probably help. Here's a simple program, STP001. It returns a price for an item. The example code is trivial; it determines the price based on the first character of the item number. You'd obviously have far-more-involved business logic in a production application, but this is adequate for the purposes of this article.
d STP001 pr extpgm('STP001')
d iItem 15
d oPrice 9p 4
d STP001 pi
d iItem 15
d oPrice 9p 4
/free
select;
when %subst(iItem:1:1) = 'A';
oPrice = 123.456;
when %subst(iItem:1:1) = 'B';
oPrice = 9.999;
other;
oPrice = .0235;
endsl;
return;
/end-free
My next step is to create a stored procedure that invokes this program. I can do this in iSeries Navigator, in STRSQL, or even with the command RUNSQLSTM. There are slight syntax differences, especially if you use iSeries Navigator, which defaults to dot notation for qualifying objects, rather than the slash we're accustomed to on the IBM i. That difference aside, I recommend using iSeries Navigator because you can test a stored procedure there, which is something you can't do in STRSQL.
Let's take a look at the required SQL:
create procedure MCP.GETPRICE
(in iItem char (15),
out oPrice decimal(9, 4))
language rpgle deterministic no sql
external name MCP.STP001
parameter style general
Note my personal preference on naming conventions: I use lowercase for everything except IBM i definitions, such as program names or database file and field names. I use mixed case for variables. Also, in this case, I created a procedure whose name is different from the name of the program it calls. In other environments, I have named the procedure the same as the program. This is one of those shop standards decisions you'll have to make. If you don't keep them the same, you can use longer, more descriptive names for the procedures, at which point I'd probably switch to mixed case. This procedure would become GetPrice. The only fly in that ointment is that if you need to qualify the stored procedure, you'll need to use the schema name. Since schema names are limited to the traditional 10-character library name, you might see something like this: call MYLIB001.GetAvailableInventory. Not horrible, by any means, but something to think about.
After you execute that statement in iSeries Navigator, you'll now be able to call your new procedure. The syntax looks like this:
call MCP.GETPRICE ('ABCD', 0)
If you execute that statement in STRSQL, you'll get an SQL0409 error telling you that the second parameter is invalid because it's defined as an output parameter (the "out" keyword on the oPrice parameter in the CREATE PROCEDURE statement). You can, though, execute the statement in iSeries Navigator, where you'll see something like this:
> call MCP.GETPRICE ('ABCD', 0)
Return Code = 0
Output Parameter #2 = 123.4560
Statement ran successfully (2 ms)
As you can see, iSeries Navigator returns the result of the output-capable parameter as well as tells you the return code of the statement and even the time it took to execute. Subsequent tests showed me that the procedure was working as expected:
> call MCP.GETPRICE ('BCDA', 0)
Return Code = 0
Output Parameter #2 = 9.999
Statement ran successfully (2 ms)
> call MCP.GETPRICE ('CDBA', 0)
Return Code = 0
Output Parameter #2 = 0.0235
Statement ran successfully (2 ms)
So, as you can see, the CREATE PROCEDURE command has effectively extended our SQL environment by enabling access to our ILE program. This can be used to make any program available as a stored procedure. Now you can call STP001 from any SQL environment and return the price. However, you will have to call it with an input/output variable, which limits you to either embedded SQL or an SQL procedure of some type.
At this point, you may have noticed a tiny flaw in my architecture: if you're calling the stored procedure from embedded SQL, you could just call the program directly and avoid the whole SQL complexity entirely. So what's the point of the stored procedure? Well, certainly in a pure i environment, the best use for a stored procedure that calls an IBM i program is as the root of a UDF, which I'll cover in the next article. However, note that stored procedures also make these programs available to external applications through ODBC and JDBC, which includes both Java and .NET, which in turn makes your RPG (or COBOL or CL or whatever) available to Windows, Linux, Android, and with a few hoops, even Apple environments. Not a bad return on your programming investment!
A Note on Functions
Just a little note: for the purposes of this article, I've specifically stuck to procedures and functions that return or update a single value. Over the years, both stored procedures and UDFs have been enhanced to be able to return result sets rather than single values, but that's an entirely different discussion and one I hope to address in future articles.
That's it for stored procedures. I've shown you how to create and run a stored procedure that invokes an IBM i program. I've also demonstrated the shortcomings of stored procedures, particularly that you can't use a stored procedure in a SELECT statement. For that you need a UDF. Part II of this article will show you how to embed this same stored procedure into a UDF for just that purpose.
as/400, os/400, iseries, system i, i5/os, ibm i, power systems, 6.1, 7.1, V7, V6R1
LATEST COMMENTS
MC Press Online