25
Wed, Dec
0 New Articles

SQL 101: Using ILE RPG Programs and Procedures as SQL Stored Procedures, Part 2

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

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 SQLThe procedure (and any other code it calls) doesn’t use any SQL whatsoever. If it tries to use SQL, an error will occur.
  • CONTAINS SQLOnly 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 DATAReading data using SELECT or FETCH statements is allowed, but updates via SQL are not.
  • MODIFIES SQL DATAAll 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!

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: