02
Sat, Nov
2 New Articles

The CL Corner: Run-Time Selection Using the RUNSQL CL Command

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

Build the RUNSQL SQL statement on the fly.

Last month, in "More on the RUNSQL CL Command," we saw how to select specific records from the SAMPLE database using the RUNSQL command. In that article, we hardcoded the selection criteria of Effective date (EffDate) being earlier than May 1, 2012. This month, we'll look at how to allow a user to interactively specify the Class, Status, and EffDate year values that the user is interested in. This will include the ability for the user to also ignore (that is, not select on) any one or more of these three fields/columns.

To prompt the user for the field values they are interested in, we'll create a display file named MyDSPF. The source for this display file is provided below. To create the display file, you can use the command CRTDSPF FILE(MYDSPF) SRCFILE(QDDSSRC).

A         R RPT_PROMPT                                        

A                                     CA03(03 'Exit')          

A                                 2 2DATE(*SYS *YY) EDTCDE(Y)

A                                 2 31'RUN MY SAMPLE REPORT'  

A                                 2 70TIME                    

A                                 4 2'Class:'                

A           RQS_CLASS      5   B 4 20                        

A                                 5 2'Status:'                

A           RQS_STATUS     1Y 0B 5 20EDTCDE(Z)                

A                                 6 2'Effective year:'        

A           RQS_YEAR       4Y 0B 6 20EDTCDE(Z)                

A                                 23 2'F3=Exit'                

The display file MyDSPF contains one record format, RPT_PROMPT, which prompts the user for the class, status, and effective year values of interest (variables Rqs_Class, Rqs_Status, and Rqs_Year, respectively). Command key 3 is enabled and can be used to exit the program when all of the desired reports have been spooled.

The program generating the report(s) is based on the RPTSAMPLE program introduced last month. As the actual creation of the report has not changed—only the records to be included or excluded in the report—we will not be changing the subroutine ReadFile. If you need a refresher on the processing of the ReadFile subroutine, refer to last month's column.

The new version of the RPTSAMPLE program is shown below, with the changes in bold.

Pgm                                                    

                                                        

DclF       File(MyDSPF)                                

DclF       File(Sample) OpnID(MyResults)                

Dcl       Var(&EOF)       Type(*Lgl)                  

                                                        

Dcl       Var(&RptLine)   Type(*Char) Len(16)        

Dcl       Var(&Class)     Type(*Char) Len(5) +        

               Stg(*Defined) DefVar(&RptLine 1)        

Dcl       Var(&Status)   Type(*Char) Len(1) +        

               Stg(*Defined) DefVar(&RptLine 6)        

Dcl      Var(&EffDate)   Type(*Char) Len(10) +      

               Stg(*Defined) DefVar(&RptLine 7)        

                                                        

Dcl       Var(&NoDtaToWrt) Type(*Char) Len(1)          

Dcl       Var(&OvrFlwLin) Type(*Dec) Len(3 0)        

Dcl       Var(&CurPrtLin) Type(*Dec) Len(3 0)            

                                                            

Dcl       Var(&SQLText)   Type(*Char) Len(1024)          

Dcl       Var(&Where)     Type(*Lgl)                      

Dcl       Var(&Status_Chr) Type(*Char) Len(1)              

Dcl       Var(&Year_Chr)   Type(*Char) Len(4)              

                                                            

DoWhile   Cond(*not &IN03)                                  

           SndRcvF RcdFmt(Rpt_Prompt)                      

                                                            

           If Cond(&IN03) Then(Leave)                      

                                                            

           ChkObj Obj(QTemp/MyResults) ObjType(*File)      

           MonMsg MsgID(CPF9801) Exec( +                    

             CrtDupObj Obj(Sample) FromLib(*Libl) +        

                       ObjType(*File) ToLib(QTemp) +      

                      NewObj(MyResults))                  

                                                    

           ChgVar Var(&SQLText) Value( +            

                   'Insert into QTemp/MyResults +    

                     (Select * +                    

                       from Sample')                

                                                    

           ChgVar Var(&Where) Value('0')            

                                                    

         If Cond(&Rqs_Class *NE ' ') Then(Do)      

             CallSubr Subr(ChkWhere)                

             ChgVar Var(&SQLText) +                

                     Value(&SQLText *BCat +          

                           'Class like(''' *TCat +  

                           &Rqs_Class *TCat +        

                           '%'')')                  

             EndDo                                  

                                                    

           If Cond(&Rqs_Status *NE 0) Then(Do)            

             CallSubr Subr(ChkWhere)                      

             ChgVar Var(&Status_Chr) Value(&Rqs_Status)  

             ChgVar Var(&SQLText) +                      

                     Value(&SQLText *BCat +                

                           'Status = ' *BCat +            

                           &Status_Chr)                    

             EndDo                                        

                                                            

           If Cond(&Rqs_Year *NE 0) Then(Do)              

             CallSubr Subr(ChkWhere)                      

             ChgVar Var(&Year_Chr) Value(&Rqs_Year)      

             ChgVar Var(&SQLText) +                        

                     Value(&SQLText *BCat +                

                           'Year(EffDate) = ' *BCat +      

                           &Year_Chr)                      

             EndDo                                        

                                                              

           ChgVar Var(&SQLText) +                            

                 Value(&SQLText *BCat +                      

                 'order by Class, EffDate)')                

                                                              

           RunSQL SQL(&SQLText) Commit(*None)                

                                                              

           CallSubr Subr(ReadFile)                          

           ClrPFM File(QTemp/MyResults)                      

EndDo                                                        

                                                              

Return                                                      

                                                              

Subr       Subr(ChkWhere)                                    

If         Cond(*not &Where) Then(Do)                      

               ChgVar Var(&SQLText) +                        

                     Value(&SQLText *BCat 'Where')          

               ChgVar Var(&Where) Value('1')                

               EndDo                                        

Else       Cmd(ChgVar Var(&SQLText) +                    

                       Value(&SQLText *BCat 'and'))        

EndSubr                                                    

                                                            

Subr       Subr(ReadFile)                                  

OvrDBF     File(Sample) ToFile(QTemp/MyResults)          

ChgVar     Var(&EOF) Value('0')                          

                                                            

OpnFCLF   FileID(MyReport) Usage(*Output) +              

           LvlChk(*No)                                    

WrtRcdCLF FileID(MyReport) RcdFmt(Heading) +            

             RcdBuf(&NoDtaToWrt)                            

                                                            

DoUntil   Cond(&EOF = '1')                              

                                                            

             RcvF OpnID(MyResults)                      

             MonMsg MsgID(CPF0864) Exec( +              

               ChgVar Var(&EOF) Value('1'))              

                                                        

             If Cond(&EOF *EQ '0') Then(Do)              

               ChgVar Var(&Class) +                    

                       Value(&MyResults_Class)          

               ChgVar Var(&Status) +                    

                       Value(&MyResults_Status)          

               ChgVar Var(&EffDate) +                  

                       Value(&MyResults_EffDate)        

                WrtRcdCLF FileID(MyReport) +            

                         RcdFmt(Detail) +              

                         RcdBuf(&RptLine)              

               RtvFInfCLF FileID(MyReport) +            

                           CurPrtLine(&CurPrtLin) +      

                           PrtFOvrFlw(&OvrFlwLin)        

                                                            

               If Cond(&CurPrtLin *GE &OvrFlwLin) +        

                   Then(WrtRcdCLF FileID(MyReport) +        

                                 RcdFmt(Heading) +          

                                 RcdBuf(&NoDtaToWrt))      

               EndDo                                        

             Else Cmd( +                                      

                 WrtRcdCLF FileID(MyReport) +              

                           RcdFmt(End_Of_Rpt) +            

                           RcdBuf(&NoDtaToWrt))            

EndDo                                                      

                                                            

CloFCLF   FileID(MyReport)                                

Close     OpnID(MyResults)                                

DltOvr     File(Sample)                                    

EndSubr                                                      

                                                            

EndPgm    

Assuming that the preceding CL source is stored in member RPTSAMPLE of source file QCLSRC, you can create the program using the command CRTBNDCL PGM(RPTSAMPLE). To run the program, use the command CALL PGM(RPTSAMPLE). Now let's look at what the RPTSAMPLE program is doing.

The first change to the program is related to declaring, and then using, the display file MyDSPF, which was created at the start of this column. RPTSAMPLE declares MyDSPF using the DCLF command and, in terms of processing, enters into a DOWHILE loop, which is conditioned by indicator 03 being off. Indicator 03 is "on" when the user presses command key 3. Within the DOWHILE loop, RPTSAMPLE writes and then reads record format RPT_PROMPT. If command key 3 is pressed, the program leaves the DOWHILE; otherwise, a report is generated.

Report Creation

When a report is being created, the following processing is done:

Using the command CHKOBJ, a check is made to determine whether the file MyResults in library QTemp already exists. If it doesn't exist, which will be the case for the first report created within the current job, the CHKOBJ command will send message CPF9801 – Object in library not found. Monitoring for this message, RPTSAMPLE will create MyResults in QTemp using the command CRTDUPOBJ. This is the same CRTDUPOBJ command that was used in last month's column. In running subsequent reports, within the same job, MyResults will exist in QTemp and RPTSAMPLE will re-use the current file.

Variable &SQLText is set to the value 'Insert into QTemp/MyResults (Select * from Sample'. This text, when later passed to the RUNSQL command, causes all fields of the Sample database to be written to MyResults in QTemp. This variable was previously declared as Type(*Char) with a (decidedly arbitrary) length of 1024 bytes.

Variable &Where is set to the value '0' where a value of '0' indicates that no selection criteria have (yet) been processed by RPTSAMPLE. This variable was previously declared as Type(*Lgl), where a value of '0' represents "off" and the value '1' "on."

Variable &Rqs_Class is examined to determine whether only a specific Class value is to be included in the report. If &Rqs_Class is blank, all classes are to be included. If &Rqs_Class is non-blank, a call to subroutine ChkWhere is made.

Subroutine ChkWhere has one purpose in life: to determine whether any previous selections have been processed for the current report. This is done by checking the value of logical variable &Where. If &Where is "off," indicating that the caller of the subroutine represents the first selection criteria encounter for the current report, then ChkWhere concatenates the string 'Where' (with one leading blank due to the use of the *BCat operator) to the current value of &SQLText and sets the variable &Where to "on."

If variable &Where is "on" when entering ChkWhere, indicating that previous selection criteria have been encountered for the current report, then ChkWhere concatenates the string 'and' (with again one leading blank using *BCat) to the current value of &SQLText

Returning from the ChkWhere subroutine,

  1. 1.the string 'Class like( ''' is concatenated (with one leading blank) to &SQLText,
  2. 2.the value of the &Rqs_Class variable is concatenated (with no leading blank using *TCat) to &SQLText,
  3. 3.and the value '%)''' is concatenated (with no leading blank using *TCat) to &SQLText.

Assuming that the user-specified value of variable &Rqs_Class is 'A', then the value of &SQLText, after the previous processing has completed, would be 'Insert into QTemp/MyResults (Select * from Sample Where Class like('A%')'.

This SQL Select statement would cause all records in the SAMPLE database that have a Class value starting with the capital letter 'A' to be included in the report. Using the SAMPLE database from last month, and making no additional selection criteria, would then result in the following report:

CLASS STATUS EFF. DATE                                                

A         1   2012-05-01                                                

ABC       2   2012-04-15                        

If you preferred that the report only include exact matches (that is, only class 'A' and not class 'ABC' in the previous report), you can change the concatenation of string 'Class like (''' to 'Class = ''' and the concatenation of string '%)''' to ''''.

Having completed the processing of &Rqs_Class, variable &Rqs_Status is examined to determine whether only a specific Status value is to be included in the report. As with the previous handling of a non-blank &Rqs_Class value, the processing of a non-0 &Rqs_Status value is done by calling the subroutine ChkWhere and then concatenating the desired value to &SQLText. The only new consideration here is the need to convert the numeric value of &Rqs_Status to character form (using variable &Status_Chr) due to CL's requirement that concatenation be done with like data types.

After processing &Rqs_Status, variable &Rqs_Year is then processed in the same manner as &Rqs_Status, determining whether a non-0 value was specified and, if so, calling subroutine ChkWhere, converting &Rqs_Year to character format using &Year_Chr, and then concatenating the appropriate string (in this case, the string is using SQL's built-in function YEAR) to &SQLText so that the year component of &EffDate is compared for equality to the user-requested year.

Having finished checking for all request variable values that might impact the records of SAMPLE that are to be included in the report, the variable &SQLText is now completed by concatenating the string 'order by Class, EffDate)'.

Using the command RUNSQL, the SQL statement found in variable &SQLText is run.

The report is generated by calling the subroutine ReadFile.

The current contents of file QTemp/MyResults are cleared in anticipation of the user wanting to run another report with new selection criteria.

The command ENDDO for the controlling DOWHILE is run, causing the user to be prompted for the next report's selection criteria.

Just One Example

This month's RPTSAMPLE program provides one example of what can be accomplished when you combine CL and SQL. The program, though simple, provides a framework that can be very easily maintained in terms of adding or removing user selection criteria; just add or remove request variable checks such as was done with &Rqs_Class, &Rqs_Status, and &Rqs_Year.

Next month, we'll look at some additional changes that can be made to the RPTSAMPLE program.

More CL Questions?

Wondering how to accomplish a function in CL? Send your CL-related questions to me at This email address is being protected from spambots. You need JavaScript enabled to view it..

                      

Bruce Vining

Bruce Vining is president and co-founder of Bruce Vining Services, LLC, a firm providing contract programming and consulting services to the System i community. He began his career in 1979 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 This email address is being protected from spambots. You need JavaScript enabled to view it.. 


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
Leverage the power of APIs with this definitive resource.
List Price $89.95

Now On Sale

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: