Practical SQL: Calling RPG from SQL, Part II

SQL
Typography
  • Smaller Small Medium Big Bigger
  • Default Helvetica Segoe Georgia Times

This second article on combining the strengths of RPG and SQL shows how to turn a stored procedure into a user-defined function (UDF).

 

In my previous article, I showed you how to create a stored procedure that will invoke an RPG program (or COBOL or CL or any other program, ILE or non-ILE). I also showed you how to test it and even explained the primary shortcoming of stored procedures: they can't be used in SELECT statements. I explained that in order to use external business logic inside of a SELECT statement, you need to use the other SQL extension technique, the user-defined function (UDF). This article shows how to create a UDF that uses your stored procedure.

A Quick Recap

In the previous article, I started with a program, STP001, that returns the price for an item. It's a very simple program that takes two parameters: the item number and the price. The first parameter is an input field that is used to calculate the price, which is then return in the second parameter. The program has no real business logic; it determines the price by checking the first character of the item number.

 

For the SQL part of my presentation, I then created a stored procedure using a CREATE PROCEDURE statement and showed how to test that stored procedure. Because stored procedures are primarily meant to be used within other programs (for example, via embedded SQL or ODBC), they aren't easy to test using some traditional ad hoc query tools. STRSQL doesn't like calling procedures with output parameters, so instead I suggested using iSeries Navigator, which is very friendly to all things SQL, including stored procedures.

Moving On to the UDF

In this article, I'm going to create a UDF to wrap the stored procedure in a way that will make it much more accessible to various tools, including the old tried and true STRSQL. Let me start, though, by introducing the concept of the UDF.

 

The primary mechanical difference between UDFs and stored procedures is how they interact with the caller. A call to a stored procedure is very much like a call to a program in RPG. The call consists of a fixed number of parameters of predetermined type and length. This includes the return value; if you want to return something, you provide a parameter. The called program will update the parameter with the resulting value.

 

One of the unique features of the program call architecture is that you can return multiple discrete result values, simply by adding more bidirectional parameters. This is very different from a UDF, which can return only a single value. All parameters to the UDF are defined to be input-only and cannot be changed. The only way to return data to the caller is through the (single) return value. It is this syntactical restriction, however, that allows the UDF to be used within SELECT statements. Let me demonstrate.

 

The first thing to do is to create the UDF. This UDF requires that the stored procedure GETPRICE be available. If you haven't already done so, please refer to the previous article and follow the steps there to create the GETPRICE stored procedure. Once you have the GETPRICE stored procedure in place, you can execute the following SQL.

 

create function MCP.GETPRICE

  (iItem char (15))

  returns decimal(9, 4)

  language sql deterministic

begin

  declare oPrice numeric (9,4);

  set price = 0;

  call MCP.GETPRICE (iItem, oPrice);

  return oPrice;

end;

 

This SQL statement creates a procedure named MCP.GETPRICE, which calls the stored procedure also named MCP.GETPRICE (one of my conventions is that if I'm wrapping a stored procedure in a UDF, I name them both the same). The primary purpose of the UDF is to act as an adapter between the bidirectional parameter list of the stored procedure and the input parameter/return value architecture used in SELECT statements. This parameter impedance mismatch is common in SQL, and the technique above can be used for other instances of the problem.

 

The concept is very straightforward:

 

  1. Create a temporary variable.
  2. Call the stored procedure passing the input values and the temporary variable.
  3. The stored procedure updates the temporary variable.
  4. After calling the stored procedure, return the contents of the temporary variable.

 

In the example above, the UDF creates a temporary variable oPrice, which is used as a bidirectional parameter to the stored procedure GETPRICE. Note that the UDF has only a single input parameter for the item number; it doesn't include the price in the parameter list. Instead, the price is going to be sent to the caller as the UDF's return value. This works for any number of input parameters; if the stored procedure had three input parameters and one output parameter, the UDF would have three parameters (all input by definition) and the return value would take the place of the output parameter. This works for any configuration, as long as the stored procedure has only one output parameter. If the stored procedure has multiple output parameters, you'll have to be more creative. For example, you might consider combining the return values into a delimited string. But let's continue with our scenario in which we have only a single return value.

 

The UDF is created, so now we can use it in pretty much any SQL statement. Let me illustrate with a simple example.

 

with Items (Item) as

  (select 'ABCD' from SYSIBM.SYSDUMMY1

   union select 'BCDA' from SYSIBM.SYSDUMMY1

   union select 'CDAB' from SYSIBM.SYSDUMMY1)

select Item, MCP.GETPRICE(cast(Item as char(15))) from Items;

 

The result looks like this:

 

Item   Price

ABCD   123.4560

BCDA   9.9990

CDAB   0.0235

 

This example looks a little complex, but really the first four lines of the statement are superfluous. They exist only to create the temporary table named Items with the three item numbers. In a production environment, you'd be using an existing Items table. I just wanted to show you an easy way to create a little temporary data. The actual meat of the statement is the SELECT statement in line 5, which invokes the GETPRICE UDF passing in the item number and returning the price. Effectively, you're calling RPG program STP001 for every line in the result set. Very nice indeed!

 

You may have noticed the CAST keyword; it converts the variable string 'ABCD' into a fixed-character field. This illustrates one important point: you have to be very careful that your parameter types match exactly what the UDF is expecting. If you don't, the system doesn't find the UDF and the statement fails, typically with an SQL0204 error.

Special Note for When Invoking Service Program Procedures

If you're an ILE programmer, you realize that procedures in ILE not only have a return value, but can also have bidirectional parameters. Neither stored procedures nor UDFs support both capabilities, so you lose certain functionality when wrapping procedures within SQL. Stored procedures support bidirectional parameters when invoking a service program procedure but will discard any returned value. On the other hand, UDFs honor the return value but have no way to handle any updates to the input parameters.

 

So, SQL can be used to provide access to service programs, but limitations exist and you may find yourself doing some creative programming to get around those limitations. Either that, or you can design your service programs in such a way that those procedures that will be called by SQL conform to the appropriate architecture (no return values for stored procedures and input-only parameters for UDFs).

 

This two-part article has given you the tools you need to integrate your natively programmed business logic into your SQL. We're not done yet, though; in a future article, I'll investigate the use of table procedures and functions that can return result sets rather than single values. Until then, good luck with your adventures in SQL integration!

as/400, os/400, iseries, system i, i5/os, ibm i, power systems, 6.1, 7.1, V7, V6R1

Joe Pluta

Joe Pluta is the founder and chief architect of Pluta Brothers Design, Inc. He has been extending the IBM midrange since the days of the IBM System/3. Joe uses WebSphere extensively, especially as the base for PSC/400, the only product that can move your legacy systems to the Web using simple green-screen commands. He has written several books, including Developing Web 2.0 Applications with EGL for IBM i, E-Deployment: The Fastest Path to the Web, Eclipse: Step by Step, and WDSC: Step by Step. Joe performs onsite mentoring and speaks at user groups around the country. You can reach him at This email address is being protected from spambots. You need JavaScript enabled to view it..


MC Press books written by Joe Pluta available now on the MC Press Bookstore.

Developing Web 2.0 Applications with EGL for IBM i Developing Web 2.0 Applications with EGL for IBM i
Joe Pluta introduces you to EGL Rich UI and IBM’s Rational Developer for the IBM i platform.
List Price $39.95

Now On Sale

WDSC: Step by Step WDSC: Step by Step
Discover incredibly powerful WDSC with this easy-to-understand yet thorough introduction.
List Price $74.95

Now On Sale

Eclipse: Step by Step Eclipse: Step by Step
Quickly get up to speed and productivity using Eclipse.
List Price $59.00

Now On Sale

BLOG COMMENTS POWERED BY DISQUS

LATEST COMMENTS

Support MC Press Online

$

Book Reviews

Resource Center

  •  

  • LANSA Business users want new applications now. Market and regulatory pressures require faster application updates and delivery into production. Your IBM i developers may be approaching retirement, and you see no sure way to fill their positions with experienced developers. In addition, you may be caught between maintaining your existing applications and the uncertainty of moving to something new.

  • The MC Resource Centers bring you the widest selection of white papers, trial software, and on-demand webcasts for you to choose from. >> Review the list of White Papers, Trial Software or On-Demand Webcast at the MC Press Resource Center. >> Add the items to yru Cart and complet he checkout process and submit

  • SB Profound WC 5536Join us for this hour-long webcast that will explore:

  • Fortra IT managers hoping to find new IBM i talent are discovering that the pool of experienced RPG programmers and operators or administrators with intimate knowledge of the operating system and the applications that run on it is small. This begs the question: How will you manage the platform that supports such a big part of your business? This guide offers strategies and software suggestions to help you plan IT staffing and resources and smooth the transition after your AS/400 talent retires. Read on to learn: