The CL Corner: Introducing the New Run SQL Command PDF Print E-mail
Programming - CL
Written by Bruce Vining   
Friday, 30 March 2012 00:00

Support MC Press - Visit Our Sponsors

 

Forums Sponsor

POPULAR FORUMS

Forums

 

 

Search Sponsor

 

Search

Would you like some SQL with your CL?

 

It would appear that thank-you cards to family members of the IBM CL SQL development teams might be in order as these IBM developers seem to be putting in lots of overtime—and not getting home very often.

 

Last month, in "New Support for CL Commands Lets You Know When a Command Ends," we reviewed how IBM has provided PTFs to V5R4, 6.1, and 7.1, allowing an exit program to be called when the command processing program (CPP) of a CL command completes. IBM is now providing new CL support for SQL as part of the next DB2 PTF groups. The planned availability for 6.1 is May 4 and for 7.1 is May 11. These PTFs provide a new CL command: Run SQL (RUNSQL).

 

The RUNSQL command allows you to run a Structured Query Language (SQL) statement directly from a CL program (or, if you want, interactively from a command line). And, as the PTFs are provided as part of the operating system, you do not need to have the DB2 Query Manager and SQL Development Kit installed on your system in order to run the SQL statements.

 

The RUNSQL command provides several parameters. These parameters include the ability for you to specify attributes such as the naming convention (NAMING) being used (*SYS or *SQL); your date format (DATFMT), such as *JOB, *USA, *ISO, etc; the type of commitment control (COMMIT) to be used; and, what I consider to be the primary parameter of interest, the SQL statement to be run (SQL). The SQL parameter is a character parameter, with a maximum length of 5,000 characters, used to specify a single SQL statement to be run. Full documentation for the various RUNSQL command parameters can be found in the previously referenced PTF cover letters.

 

With the RUNSQL command, you can define new files (also known as tables) using a CREATE TABLE statement or manipulate data within files/tables with statements such as UPDATE, INSERT, DELETE, and SELECT. For demonstration purposes, let's say we want file/table, named SAMPLE, with three fields (also known as columns): Class, Status, and EffDate (effective date). The file could be defined using DDS as shown below.

 

R RECORD                   

  CLASS          5A        

  STATUS         1S 0      

  EFFDATE         L        

 

To create the SAMPLE file, you can enter the DDS shown above into source member SAMPLE of file QDDSSRC and use the command CRTPF SAMPLE QDDSSRC. Alternatively, you could run the following RUNSQL command to create the equivalent SQL table.

 

RUNSQL SQL('Create Table SAMPLE (         

              Class   Char(5),         

              Status  Numeric(1,0),      

              EffDate Date)            

 

Having created the SAMPLE file using either DDS or RUNSQL, we'll now add a record to it. The record should have a Class value of 'FIRST', a Status of 1, and an Effective date of April 13, 2012. In the past, we might have added this record using one of many approaches. Some possible implementations would be creating a DFU application program, writing a program using a high-level language such as RPG, or using interactive SQL. Using the RUNSQL command, we now also have the option to add the record using the following CL command.

 

RUNSQL SQL('Insert into SAMPLE                 

  Values('FIRST', 1, '2012-04-13') 

 

Note that, depending on your system environment, this RUNQRY command may fail with escape message CPF4328 (Member SAMPLE not journaled…). If you encounter this error, then add the command parameter COMMIT(*NONE) to the above RUNSQL command. You will also need to add COMMIT(*NONE) to later RUNSQL examples, demonstrating the SQL UPDATE and DELETE statements, within this article.

 

The previous record addition, in addition to being hardcoded in terms of the SQL parameter value being run, could also be accomplished using CL program variables as shown below.

 

DCL        VAR(&CLASS)    TYPE(*CHAR) LEN(5)    

DCL        VAR(&STATUS)   TYPE(*CHAR) LEN(1)   

DCL        VAR(&EFFDATE)  TYPE(*CHAR) LEN(10)

 

DCL        VAR(&SQL_STMT) TYPE(*CHAR) LEN(5000)  

 

CHGVAR     VAR(&CLASS) VALUE('FIRST')       

CHGVAR     VAR(&STATUS) VALUE('1')          

CHGVAR     VAR(&EFFDATE) VALUE('2012-04-13')

 

CHGVAR     VAR(&SQL_STMT) VALUE( +                 

             'Insert into SAMPLE +                 

              Values(''' *Cat &Class *Cat ''', ' + 

              *Cat &Status *Cat +                  

              ',''2012-04-13'')')                  

RUNSQL SQL(&SQL_STMT)

 

 Admittedly, the above CHGVAR command to set variable &SQL_STMT isn't the easiest to read, but it also isn't anything above and beyond what you've always had to do when using quotes within a CL character variable. If you imagine that the previous CL program declares a display file, where the values of &Class, &Status, and &EffDate are provided interactively from an end-user rather than the three hardcoded CHGVAR commands, then you have a rather flexible CL application program that can be up and running in no time at all.

 

Let's say we have written several records in the SAMPLE file with various &Class, &Status, and &EffDate values and that one or more of these records have a status value of 1 and an effective date of April 13, 2012. We're now told that the Effective date for all Status 1 records that currently have an effective date of April 13, 2012 need to have their effective date changed to 10 days later. What might be required to change these records (and not others) to have this new effective date? One approach would be to use the following RUNSQL command (interactively or imbedded within a CL program).

 

RUNSQL SQL('Update  SAMPLE                     

              set   EffDate = EffDate + 10 Days    

              where Status = 1 and                 

                    EffDate = ''2012-04-13''')       

 

As with the previous INSERT example using character variable &SQL_STMT, any one or more parts of the above UPDATE statement could be specified using CL variables if the RUNSQL command is run within a CL application program. And just as easily as we updated all Status 1 records with an Effective date of April 13, we could also use DELETE to remove records where the Effective date was, say, more than one year in the past with a command such as this:

 

RUNSQL SQL('Delete SAMPLE

             where EffDate < Current Date – 1 Year')

 

Next month, we'll look at the RUNSQL command's ability to run a SELECT statement to query data. Due to CL command limitations, the SELECT support isn't as direct as the preceding examples of CREATE TABLE, INSERT, UPDATE, and DELETE, but it is a significant addition to our CL development toolkit.

 

The IBM i CL and SQL development teams, with the introduction of the RUNSQL command, have really expanded what it is possible to do with SQL within a CL application program.

More CL Questions?

Wondering how to accomplish a function in CL? Send your CL-related questions to me at bvining@brucevining.com. I'll try to answer your burning questions in future columns.

 


Bruce Vining
About the Author:

Bruce Vining is president and co-founder of Bruce Vining Services, L.L.C., a firm providing contract programming and consulting services to the System i community (www.brucevining.com). He began his career in1979 as an IBM Systems Engineer in St. Louis, Missouri, and then transferred to Rochester, Minnesota, in 1985, where he continues to reside. From 1992 until leaving IBM in 2007, Bruce was a member of the System Design Control Group responsible for OS/400 and i5/OS areas such as System APIs, Globalization, and Software Serviceability. He is also the designer of Control Language for Files (CLF).

 

A frequent speaker and writer, Bruce can be reached at bvining@brucevining.com.

 

MC Press books written by Bruce Vining available now on the MC Press Bookstore.

 

IBM System i APIs at Work IBM System i APIs at Work

Master APIs with this in-depth, example-rich exploration into these powerful tools.

List Price $89.95
Now On Sale
 
Read More >>
Last Updated on Thursday, 29 March 2012 15:57
 
User Rating: / 5
PoorBest 
   MC-STORE.COM