SQL 101: Ultra-Flexible Cursors—The Beauty of PREPARE

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

SQL’s PREPARE statement, combined with ILE RPG, can bring unmatched flexibility to your application’s code. Read on to find how you can do it. It’s easier than you think!

Using thePREPARE SQL instruction, you can have a single cursor and use it according to conditions defined by user input, for instance. I’ve seen subfiles with different columns, selections, and sorting being managed with a single cursor. How, you might ask? The PREPARESQL instruction allows you to define a cursor loosely:

/Free

   Exec SQL

     DECLARE mainCursor CURSOR

     FOR MY_SELECT;

MY_SELECT is, or rather, will be the SELECT statement that the cursor will use, but at declaration time, MY_SELECT is only a placeholder. You need to define its “variable” content with a PREPARE statement before the DECLARE statement, but you’re free to compose it in any way that you want, as long as you specify a valid SELECT statement. Here’s how you do it:

/Free

   W_My_SQL_Stmt = ‘SELECT * FROM InvMst WHERE WHID = ‘ +

                   %CHAR(K_WHID) + ‘ AND ExpDate < CurDate’;

   Exec SQL

     PREPARE MY_SELECT FROM :W_MySQL_Stmt;

These two statements will assign a dynamic statement to the W_My_SQL_Stmt variable. Note that it can be even more dynamic; I could change the columns, the sort, or any other part of the SELECT statement. The resulting string is then transformed into an SQL “thing” that I’ll use in the DECLARE statement to define my cursor. After this operation, the usual OPEN, FETCH, CLOSE cursor procedure is used.

Here’s a practical example: Imagine you want a function that returns the total number of records of a given table or table join. The function is abstract, in the sense that the statement describing the table or table join is not known beforehand and neither are the conditions (the WHERE part of the statement) in which it’ll be run. This is the perfect example of PREPARE’s flexibility. As usual, let’s start with the function’s prototype interface:

*-------------------------------------------------------------------*

* Procedure: RowCounter - return a row count from a select statement*

*-------------------------------------------------------------------*

PRowCounter       B                   EXPORT

DRowCounter       PI                 Like(W_Out)

* Input Parms

DP_Stm                       1000A   Value

* Work variables

DW_Out           S             12 0

Yes, I know, it should be a /FREE definition. It’s not because I’m reusing an actual piece of production code that hasn’t been converted to free-format.

Anyway, there’s nothing really new here; just notice that the input parameter is a regular string. This string will hold a complete (and preferably valid) SELECT statement with an aggregation function in the SELECT clause. Although this is designed to use a SELECT COUNT(*) statement, you can use it with other aggregation functions as well, such as SUM, for instance.

Note that the string’s size (1,000 characters) should be enough for most SQL statements, but if you plan to use complex (or simply very long) SELECT statements, it might not be enough. If you get strange “invalid SQL statement” errors at runtime, you should look into this variable’s size and compare it with the value you’re trying to pass it. There’s only one work variable, W_Out, which will be used to return the output of the SELECT statement, as you’ll see in a minute:

/FREE

     EXEC SQL

       PREPARE S1 FROM :P_Stm;

     EXEC SQL

       DECLARE C1 CURSOR FOR S1;

     EXEC SQL

       OPEN C1;

     EXEC SQL

       FETCH C1 INTO :W_Out;

     EXEC SQL

       CLOSE C1;

This is the main body of the function. This is an RPG function, but there’s only SQL in it. Let’s analyze the code. The input parameter, P_Stm, is used to create an “SQL thing” named S1 that is going to be used by the C1 cursor’s DECLARE statement as its SELECT part. From here, the code follows the usual cursor operation sequence: OPEN, FETCH, and CLOSE. All that is left to do is return W_Out to the outside world and end the function:

     Return W_Out;

/END-FREE

PRowCounter       E

Note that the function doesn’t know (and doesn’t care) what the SELECT statement looks like, as long as it’s a valid SELECT statement that returns a number—the typical result of an aggregation function. PREPARE allows you to create this type of “hollow function” with dynamic SELECT statements, but it can also be used for other dynamic statements, as you’ll see later.

This is a simple example, but I believe it gets the point across. With the PREPARE statement, you can write generic RPG functions that can be reused in several different situations within the same type of scenario (for instance, quickly returning the maximum value that fulfills certain very specific conditions for a variety of different files/variations within the same file) or even fully dynamic Open Query File replacements, as mentioned in the previous TechTip.

That’s all the time we have this time around. In the next article, I’ll be discussing how to embed other SQL statements in RPG…and why you should do it.

Rafael Victoria-Pereira

Rafael Victória-Pereira has more than 20 years of IBM i experience as a programmer, analyst, and manager. Over that period, he has been an active voice in the IBM i community, encouraging and helping programmers transition to ILE and free-format RPG. Rafael has written more than 100 technical articles about topics ranging from interfaces (the topic for his first book, Flexible Input, Dazzling Output with IBM i) to modern RPG and SQL in his popular RPG Academy and SQL 101 series on mcpressonline.com and in his books Evolve Your RPG Coding and SQL for IBM i: A Database Modernization Guide. Rafael writes in an easy-to-read, practical style that is highly popular with his audience of IBM technology professionals.

Rafael is the Deputy IT Director - Infrastructures and Services at the Luis Simões Group in Portugal. His areas of expertise include programming in the IBM i native languages (RPG, CL, and DB2 SQL) and in "modern" programming languages, such as Java, C#, and Python, as well as project management and consultancy.


MC Press books written by Rafael Victória-Pereira available now on the MC Press Bookstore.

Evolve Your RPG Coding: Move from OPM to ILE...and Beyond Evolve Your RPG Coding: Move from OPM to ILE...and Beyond
Transition to modern RPG programming with this step-by-step guide through ILE and free-format RPG, SQL, and modernization techniques.
List Price $79.95

Now On Sale

Flexible Input, Dazzling Output with IBM i Flexible Input, Dazzling Output with IBM i
Uncover easier, more flexible ways to get data into your system, plus some methods for exporting and presenting the vital business data it contains.
List Price $79.95

Now On Sale

SQL for IBM i: A Database Modernization Guide SQL for IBM i: A Database Modernization Guide
Learn how to use SQL’s capabilities to modernize and enhance your IBM i database.
List Price $79.95

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: