22
Sun, Dec
3 New Articles

Practical SQL: Calling RPG from SQL, Part I

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

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

BLOG COMMENTS POWERED BY DISQUS

LATEST COMMENTS

Support MC Press Online

$

Book Reviews

Resource Center

  • SB Profound WC 5536 Have you been wondering about Node.js? Our free Node.js Webinar Series takes you from total beginner to creating a fully-functional IBM i Node.js business application. You can find Part 1 here. In Part 2 of our free Node.js Webinar Series, Brian May teaches you the different tooling options available for writing code, debugging, and using Git for version control. Brian will briefly discuss the different tools available, and demonstrate his preferred setup for Node development on IBM i or any platform. Attend this webinar to learn:

  • SB Profound WP 5539More than ever, there is a demand for IT to deliver innovation. Your IBM i has been an essential part of your business operations for years. However, your organization may struggle to maintain the current system and implement new projects. The thousands of customers we've worked with and surveyed state that expectations regarding the digital footprint and vision of the company are not aligned with the current IT environment.

  • SB HelpSystems ROBOT Generic IBM announced the E1080 servers using the latest Power10 processor in September 2021. The most powerful processor from IBM to date, Power10 is designed to handle the demands of doing business in today’s high-tech atmosphere, including running cloud applications, supporting big data, and managing AI workloads. But what does Power10 mean for your data center? In this recorded webinar, IBMers Dan Sundt and Dylan Boday join IBM Power Champion Tom Huntington for a discussion on why Power10 technology is the right strategic investment if you run IBM i, AIX, or Linux. In this action-packed hour, Tom will share trends from the IBM i and AIX user communities while Dan and Dylan dive into the tech specs for key hardware, including:

  • Magic MarkTRY the one package that solves all your document design and printing challenges on all your platforms. Produce bar code labels, electronic forms, ad hoc reports, and RFID tags – without programming! MarkMagic is the only document design and print solution that combines report writing, WYSIWYG label and forms design, and conditional printing in one integrated product. Make sure your data survives when catastrophe hits. Request your trial now!  Request Now.

  • SB HelpSystems ROBOT GenericForms of ransomware has been around for over 30 years, and with more and more organizations suffering attacks each year, it continues to endure. What has made ransomware such a durable threat and what is the best way to combat it? In order to prevent ransomware, organizations must first understand how it works.

  • SB HelpSystems ROBOT GenericIT security is a top priority for businesses around the world, but most IBM i pros don’t know where to begin—and most cybersecurity experts don’t know IBM i. In this session, Robin Tatam explores the business impact of lax IBM i security, the top vulnerabilities putting IBM i at risk, and the steps you can take to protect your organization. If you’re looking to avoid unexpected downtime or corrupted data, you don’t want to miss this session.

  • SB HelpSystems ROBOT GenericCan you trust all of your users all of the time? A typical end user receives 16 malicious emails each month, but only 17 percent of these phishing campaigns are reported to IT. Once an attack is underway, most organizations won’t discover the breach until six months later. A staggering amount of damage can occur in that time. Despite these risks, 93 percent of organizations are leaving their IBM i systems vulnerable to cybercrime. In this on-demand webinar, IBM i security experts Robin Tatam and Sandi Moore will reveal:

  • FORTRA Disaster protection is vital to every business. Yet, it often consists of patched together procedures that are prone to error. From automatic backups to data encryption to media management, Robot automates the routine (yet often complex) tasks of iSeries backup and recovery, saving you time and money and making the process safer and more reliable. Automate your backups with the Robot Backup and Recovery Solution. Key features include:

  • FORTRAManaging messages on your IBM i can be more than a full-time job if you have to do it manually. Messages need a response and resources must be monitored—often over multiple systems and across platforms. How can you be sure you won’t miss important system events? Automate your message center with the Robot Message Management Solution. Key features include:

  • FORTRAThe thought of printing, distributing, and storing iSeries reports manually may reduce you to tears. Paper and labor costs associated with report generation can spiral out of control. Mountains of paper threaten to swamp your files. Robot automates report bursting, distribution, bundling, and archiving, and offers secure, selective online report viewing. Manage your reports with the Robot Report Management Solution. Key features include:

  • FORTRAFor over 30 years, Robot has been a leader in systems management for IBM i. With batch job creation and scheduling at its core, the Robot Job Scheduling Solution reduces the opportunity for human error and helps you maintain service levels, automating even the biggest, most complex runbooks. Manage your job schedule with the Robot Job Scheduling Solution. Key features include:

  • 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.

  • LANSAWhen it comes to creating your business applications, there are hundreds of coding platforms and programming languages to choose from. These options range from very complex traditional programming languages to Low-Code platforms where sometimes no traditional coding experience is needed. Download our whitepaper, The Power of Writing Code in a Low-Code Solution, and:

  • LANSASupply Chain is becoming increasingly complex and unpredictable. From raw materials for manufacturing to food supply chains, the journey from source to production to delivery to consumers is marred with inefficiencies, manual processes, shortages, recalls, counterfeits, and scandals. In this webinar, we discuss how:

  • 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

  • Profound Logic Have you been wondering about Node.js? Our free Node.js Webinar Series takes you from total beginner to creating a fully-functional IBM i Node.js business application.

  • 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: