23
Tue, Apr
1 New Articles

The CL Corner: Enhancing WRKQRY Reports the Easy Way

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

Let's look more uses of the RUNSQL CL command.

 

I recently received a note asking if there was a way to add the day of week to query reports generated by the IBM Query for i (5770-QU1) product. That is, take a current report containing dates as shown below:

PROJECT     TASK        CONTACT     TSKSTRDAT   TSKENDDAT    

ABC         Some task   JDOE        2015-03-09  2015-04-01   

ABC         Diff task   JSMITH      2015-03-24  2015-04-10   

ABC         Testing     QAMGR       2015-04-02  2015-05-28               

And start showing the day of week as in the following:

PROJECT     TASK        CONTACT     TSKSTRDAT   TSKSTRDOW   TSKENDDAT   TSKENDDOW

ABC         Some task   JDOE        2015-03-09  Monday      2015-04-01  Wednesday

ABC         Diff task   JSMITH      2015-03-24  Tuesday     2015-04-10  Friday   

ABC         Testing     QAMGR       2015-04-02  Thursday    2015-05-28  Thursday 

This can certainly be done using the query product and a non-trivial set of result fields, but it's…well…ugly. My preference is to have the database of the IBM i determine the day of week and then provide it to the query product. This article goes over one way to accomplish this.

For background, let's assume we have a physical file on the system, named PROJECTS, with the following DDS definition:

A          R PROJRCD            

A            PROJECT       10A  

A            TASK          10A  

A            CONTACT       10A  

A            TSKSTRDAT       L  

A            TSKENDDAT       L  

A          K PROJECT  

The fields being defined are:

  1. ProjectA 10-character alphanumeric value representing a project that is being tracked
  2. TaskA 10-character alphanumeric value representing a task within a project
  3. ContactA 10-character alphanumeric value representing a user ID identifying a contact for the task
  4. TskStrDatA date value representing the starting date of a task within a project
  5. TskEndDatA date value representing the ending date of a task within a project

PROJECTS might have been created using the Create Physical File (CRTPF) command:

CRTPF FILE(BVINING/PROJECTS) SRCFILE(BVINING/QDDSSRC) 

To create the first report shown, the PROJECTS file would have three records, which might have been entered using an application program, a utility such as DFU, or (for our purposes) the following three RUNSQL CL commands.

RUNSQL SQL('INSERT INTO BVINING/PROJECTS

VALUES(''ABC'', ''Some task'', ''JDOE'', ''2015-03-09'', ''2015-04-01'')')

COMMIT(*NONE)  

RUNSQL SQL('INSERT INTO BVINING/PROJECTS

VALUES(''ABC'', ''Diff task'', ''JSMITH'', ''2015-03-24'', ''2015-04-10'')')

COMMIT(*NONE)  

RUNSQL SQL('INSERT INTO BVINING/PROJECTS

VALUES(''ABC'', ''Testing'', ''QAMGR'', ''2015-04-02'', ''2015-05-28'')')

COMMIT(*NONE)  

If you're not familiar with the Run SQL (RUNSQL) command, it's a CL command that allows you to run most SQL statements from either a command line or a CL program. Previous articles introducing the command include Introducing the New Run SQL Command, Using the SQL Select Statement with RUNSQL, and More on the RUNSQL CL Command.

To have the i database determine the day of week for the task start date (TskStrDat) and the task end date (TskEndDat), we'll create a view of the database that adds two fields: task start day of week (TskStrDoW) and task end day of week (TskEndDoW). The following CL program, named PROJVIEW, will create this view, which will also be named PROJVIEW in library BVINING.

Pgm                                                               

                                                                  

RunSQL    SQL('Create View BVINING/ProjView +                     

                  (Project, Task, Contact, +                      

                   TskStrDat, TskStrDoW, +                        

                   TskEndDat, TskEndDoW) +                        

                as Select +                                       

                     Project, Task, Contact, +                    

                     TskStrDat, Varchar(DayName(TskStrDat), 10), +   

                     TskEndDat, Varchar(DayName(TskEndDat), 10) +    

                    from BVINING/Projects') +                     

          Commit(*None)                                           

                                                                  

EndPgm                                                            

The RunSQL command is running an SQL Create View statement. The seven field names listed within parentheses represent the fields defined within the view. The Select clause identifies where the values associated with the seven fields defined within the view come from, with Project, Task, Contact, TskStrDat, and TskEndDat simply being the values found in the physical file BVINING/PROJECTS. The values for the two new fields that are defined within the view, TskStrDoW and TskEndDoW, are defined as coming from Varchar(DayName(TskStrDat), 10) and Varchar(DayName(TskEndDat), 10), respectively.

DayName is an SQL function that returns a mixed-case character string containing the name of the day (for example, Friday, though the actual value returned will depend on the National Language Version in use by your job) associated with the parameter passed to it. The parameter can be a constant or a variable of the type date, timestamp, character, or graphic. In our case, we're using the date fields of the PROJECTS physical file. The character string returned is defined as being a variable-length string of up to 100 characters. Query, when displaying or printing this string, will allocate the full 100 characters, which is probably not what we want.

Varchar is an SQL function that returns a character string associated with the parameter passed to it. The parameter can be integer, decimal, floating point, character, graphic, date, time, or timestamp. In our case, we're passing it the variable-length string returned by the DayName function. The Varchar function also supports optional parameters, with the first optional parameter allowing us to specify the length of the string we want returned. The value we're using for this optional parameter is 10, indicating that the view should truncate the output of DayName to only the first 10 characters.

To create the PROJVIEW CL program into library BVINING and then run it, you can use the following two commands.

CRTBNDCL PGM(BVINING/PROJVIEW) SRCFILE(BVINING/QCLSRC)

CALL PGM(BVINING/PROJVIEW)

To test the PROJVIEW view, we need to go into the current query definition and make two changes:

  1. Using the "Specify file selections" option, specify that the file to be used is now PROJVIEW.
  2. Using the "Select and sequence fields" option, specify that the fields TskStrDow and TskEndDow are to be included in the query output following TskStrDat and TskEndDat, respectively.

That's it! Use F5 to run the query, and you should now get something like this:

PROJECT     TASK        CONTACT     TSKSTRDAT   TSKSTRDOW   TSKENDDAT   TSKENDDOW

ABC         Some task   JDOE        2015-03-09  Monday      2015-04-01  Wednesday

ABC         Diff task   JSMITH      2015-03-24  Tuesday     2015-04-10  Friday   

ABC         Testing     QAMGR       2015-04-02  Thursday    2015-05-28  Thursday 

While the RunSQL command is running a SQL statement creating the view BVINING/PROJVIEW, you'll notice if you run a Display File Description (DSPFD) command using BVINING/PROJVIEW that the command shows that it's an externally described logical file with an SQL type of view. Likewise, the Display File Field Description (DSPFFD) command shows that PROJVIEW is a logical file with seven fields defined. As long as you declare (DCLF) PROJVIEW within a CL program with Allow variable-length fields (ALWVARLEN) *YES, you'll find you can use it within a CL program in the same way you would any other file.

In the case of the PROJECTS file, per the original email I received, there will always be "real" dates for TskStrDat and TskEndDat, so our initial task is done. Some databases, however, may have associated special meanings to specific datesfor example, I find that January 1 of year 0001 is commonly used to indicate that there is no known date (at least at this time). The PROJVIEW view will handle this just fine, and you'll find out quickly enough that the date 0001-01-01 is considered to be a Monday. But do you really want all of these spurious Mondays to show up in the output?

The previous Create View statement barely touches what can be done in a view, with the following changed RunSQL command showing a bit more of what's possible.

RunSQL    SQL('Create View BVINING/ProjView +                          

                  (Project, Task, Contact, +                           

                   TskStrDat, TskStrDoW, +                             

                   TskEndDat, TskEndDoW) +                             

                as Select +                                            

                     Project, Task, Contact, +                         

                     TskStrDat, +                                      

                     case when TskStrDat = ''0001-01-01'' then '' '' + 

                          else Varchar(DayName(TskStrDat), 10)  +         

                          end, +                                       

                     TskEndDat, +                                      

                     case when TskEndDat = ''0001-01-01'' then NULL + 

                          else Varchar(DayName(TskEndDat), 10) +         

                          end +                                       

                    from BVINING/Projects') +                        

          Commit(*None)                                

Rather than simply using the Varchar and DayName SQL functions, we're now also using the SQL Case expression to enable different processing based on the evaluation of one of more conditions.

The elements of the Case expression, while using different terminology, are essentially those of a CL Select control structure where Case is the equivalent of Select, When is When, Else is Otherwise, and End is EndSelect. So what we're doing with the first Case expression in the new PROJVIEW is checking whether the value of TskStrDat is January 1, 0001 and, if so, setting TskStrDow to blanks. If TskStrDat is not 1/1/0001, we're then using the same Varchar(DayName(TskStrDat), 10) solution as before. To demonstrate some flexibility in how we want to handle dates, we're processing TskEndDat in a slightly different manner. If TskEndDat is 1/1/0001, we're setting TskEndDow to the NULL value, otherwise to the name of the day.

As the previous query output would have included dates of 1/1/0001, we'll simply continue to show those values (though we don't have to if we don't want to).

To test this change to PROJVIEW, let's update two of our PROJECTS date values to January 1, 0001, with the following two RUNSQL commands.

RUNSQL SQL('Update Projects set TskStrDat = ''0001-01-01''

where Project = ''ABC'' and Task = ''Diff task''') COMMIT(*NONE)                       

                                                         

RUNSQL SQL('Update Projects set TskEndDat = ''0001-01-01''

where Project = ''ABC'' and Task = ''Testing''') COMMIT(*NONE)   

Delete the previous PROJVIEW view with this:

RunSQL    SQL('Drop View BVINING/ProjView') Commit(*None)  

Then recompile and call the updated PROJVIEW CL program.

CRTBNDCL PGM(BVINING/PROJVIEW) SRCFILE(BVINING/QCLSRC)

CALL PGM(BVINING/PROJVIEW)

Running the previous query over the PROJVIEW view now results in output similar to this:

PROJECT     TASK        CONTACT     TSKSTRDAT   TSKSTRDOW   TSKENDDAT   TSKENDDOW

ABC         Some task   JDOE        2015-03-09  Monday      2015-04-01  Wednesday

ABC         Diff task   JSMITH      0001-01-01              2015-04-10  Friday   

ABC         Testing     QAMGR       2015-04-02  Thursday    0001-01-01  -        

This output shows blanks for the starting day of week for task "Diff task" and a dash (reflecting a NULL value) for the ending day of week for task "Testing"and without having touched the query definition.

As mentioned before, you can process this view not just with the query product but also in a CL program. Note, though, that due to the introduction of NULL values for TskEndDow, you'll also need to specify Allow field value of null (ALWNULL) *YES on the CL Declare File (DCLF) command.

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

$0.00 Raised:
$

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: