23
Mon, Dec
1 New Articles

The CL Corner: More on View Flexibility

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

Let's review of some of the SQL functions available.

 

In the February 2015 CL Corner, A More Flexible Interface to the RUNSQL CL Command, we saw how to create a command of our own, CRTSQLVIEW, to create views by utilizing some of the built-in functions provided by the SQL language. The CRTSQLVIEW command removed the need for us to write a custom program per view (which was covered in the January 2015 article Enhancing WRKQRY Reports the Easy Way. These previous articles used the SQL built-in functions of VarChar and DayName to return the mixed-case name of the day for a date field. This month, using CRTSQLVIEW, we'll be looking at additional built-ins that are available to you.

 

Deciding which built-in to start with today turned out to be quite easy. I have received quite a few notes from readers who have a little problemnamely, that the previous articles used date fields while their production databases store dates in a combination of alphanumeric and packed-decimal fields. To look at what's available using a view approach, we'll first create a new physical file where we're storing date values using a variety of formats and data types. This file will be called TESTDATA, and here's the DDS definition for the file.

 

R RECORD                    

  DATFLD          L         

  MDYALPHA       6A         

  YMDALPHA       6A         

  MDYNBR         6P 0       

 

The first field, DatFld, is defined as a date field, which is similar to how we defined TskStrDat in the previous articles. The second field, MDYAlpha, is defined as a 6-byte character field and will be used to store date values using a MDY format. The third field, YMDAlpha, is defined as a 6-byte character field and will be used to store date values using a YMD format. The fourth field, MDYNbr, is defined as a 6-digit packed-decimal field and will be used to store date values using a MDY format.

 

Assuming that the previous source is stored in member TESTDATA of QDDSSRC, then you can create the file using this command:

 

CRTPF FILE(TESTDATA)

 

To write two test records to the file, prompt and then run the following RUNSQL commands:

 

                           Run SQL Statements (RUNSQL)                          

                                                                                

 Type choices, press Enter.                                                     

                                                                                

 SQL  . . . . . . . . . . . . . . > Insert into TESTDATA Values('2015-03-21', '0

32115', '150321', 032115)                                                       

                                                                     ...        

 Commitment control . . . . . . . > *NONE         *CHG, *UR, *CS, *ALL, *RS...  

 Naming . . . . . . . . . . . . .   *SYS          *SYS, *SQL                    

 

 

                           Run SQL Statements (RUNSQL)                          

                                                                                

 Type choices, press Enter.                                                     

                                                                                

 SQL  . . . . . . . . . . . . . . > Insert into TESTDATA Values('2015-12-25', '1

22515', '151225', 122515)                                                       

                                                                     ...        

 Commitment control . . . . . . . > *NONE         *CHG, *UR, *CS, *ALL, *RS...  

 Naming . . . . . . . . . . . . .   *SYS          *SYS, *SQL                    

 

The first command writes one record with the date March 21 2015 stored in each of the four fields defined to TESTDATA. The second command writes a second record using the date December 25 2015.

 

Now let's see what we can do to get those non-date data type fields MDYAlpha, YMDAlpha, and MDYNbr to become "true" date fields.

 

We'll first tackle the alphanumeric fields MDYAlpha and YMDAlpha. SQL provides the built-in TIMESTAMP_FORMAT, which returns a timestamp that's based on a string definition of how to interpret an input character value. This string definition allows you to indicate where in the input character value to find, among other things, a 2-digit year (YY), a 4-digit year (YYYY), a 2-digit month (MM), and a 2-digit day (DD). For instance, using TIMESTAMP_FORMAT as in

 

TIMESTAMP_FORMAT(MDYAlpha, 'MMDDYY')

 

indicates that the field MDYAlpha contains a formatted value that should be converted to a timestamp, where the first two bytes identify a 2-digit month, the next two bytes a 2-digit day, and the last two bytes a 2-digit year. So a MDYAlpha value such as '032115' (like the first record we wrote to TESTDATA) would be converted to a timestamp value of '2015-03-21-00.00.00.00000'.

 

Along the same lines, using TIMESTAMP_FORMAT as in

 

TIMESTAMP_FORMAT(YMDAlpha, 'YYMMDD')

 

indicates that the field YMDAlpha contains a YMD formatted value that should be converted to a timestamp. A YMDAlpha value such as '151225' (like the second record we wrote to TESTDATA) would then be converted to a timestamp value of '2015-12-25-00.00.00.000000'.

 

With that introduction let's now use CRTSQLVIEW to create a view, using the fields MDYAlpha and YMDAlpha, to again determine the name of the day they represent. Prompt and fill in the CRTSQLVIEW command as shown below:

 

                          Create SQL View (CRTSQLVIEW)                  

                                                                        

 Type choices, press Enter.                                             

                                                                        

 View . . . . . . . . . . . . . . > TESTVIEW      Name                  

   Library  . . . . . . . . . . .     *CURLIB     Name, *CURLIB         

 Table  . . . . . . . . . . . . . > TESTDATA      Name                  

   Library  . . . . . . . . . . .     *LIBL       Name, *LIBL, *CURLIB  

                                                                                

 Columns:                                                                       

   To column  . . . . . . . . . . > DATFLD        Name                          

   From . . . . . . . . . . . . .   *SAME                                       

                                                                                

   To column  . . . . . . . . . . > DATFLDDOW     Name                          

   From . . . . . . . . . . . . . > Varchar(DayName(DatFld), 10)              

                                                                                

   To column  . . . . . . . . . . > MDYDOW        Name                          

   From . . . . . . . . . . . . . > Varchar(DayName(Timestamp_Format(MDYAlpha, 

'MMDDYY')), 10)                                                              

                                                                                

   To column  . . . . . . . . . . > YMDDOW        Name                          

   From . . . . . . . . . . . . . > Varchar(DayName(Timestamp_Format(YMDAlpha, 

'YYMMDD')), 10)                            

 

 

The previous command creates a view named TESTVIEW. If you now go into WRKQRY, select the file TESTVIEW, and use F5 to run the query, you should see this:

 

        DATFLD      DATFLDDOW   MDYDOW      YMDDOW     

 000001 2015-03-21  Saturday    Saturday    Saturday   

 000002 2015-12-25  Friday      Friday      Friday     

 

As with the two earlier articles, the first column (titled DATFLD) is simply the value of the DatFld field followed by the day of the week (DATFLDDOW). What's new is that now we also see the day of the week for the alphanumeric fields MDYAlpha (MDYDOW) and YMDAlpha (YMDDOW).

 

Before handling the packed-decimal field MDYNbr, let's also see how we might be able to simplify existing queries that have been working with alphanumeric "date" fields such as MDYAlpha and YMDAlpha. Some of you may in the past have constructed date fields within WRKQRY such as the MyDate field shown below.

 

Field       Expression                         Column Heading        Len   Dec

MYDATE      Date(Substr(MDYAlpha, 1, 2) || '/                                 

            ' || Substr(MDYAlpha, 3, 2) || '/                                 

            ' || Substr(MDYAlpha, 5, 2))                                      

 

 

While you can continue to construct date fields in this manner, you could also have CRTSQLVIEW do it using the SQL DATE built-in. For instance, adding the following COLUMNS entry to our previous command will create the field MyDate in TESTVIEW, allowing you to eliminate the construction shown above.

 

Columns:                                                                       

   To column  . . . . . . . . . . > MYDATE        Name                          

   From . . . . . . . . . . . . . > Date(Timestamp_Format(MDYAlpha, 'MMDDYY'))

 

 

Returning to the handling of "date" values being stored in numeric fields, the TIMESTAMP_FORMAT built-in only supports an input character value for the "date" to be interpreted. So what we need to do is convert the numeric field MDYNbr to a character string. There are several SQL built-ins that can accomplish this, with each of them having slightly different characteristics. There is, for instance, the built-in CHAR, which is often used as it returns a fixed-length character string representation of a number. This built-in, however, has a definite consideration when it comes to handling numeric valuesnamely, that it removes leading zeroes. So if we have a numeric value such as 032115 (the value of MDYNbr for the first record we wrote to TESTDATA), the CHAR built-in will return a character value of '32115' rather than a value of '032115'. This will be a problem as TIMESTAMP_FORMAT is looking for a 2-digit month (though a MDYNbr value of 122515 would work just fine). As the number of significant digits in a numeric date can vary, we will want to use the DIGITS built-in. DIGITS returns the character-string representation of the absolute value of a number and retains leading zeroes.

 

With this knowledge, we can now get the day of the week for MDYNbr by adding another column definition to our CRTSQLVIEW command. This addition will be:

 

 Columns:                                                                       

   To column  . . . . . . . . . . > MDYNBRDOW     Name                          

   From . . . . . . . . . . . . . > Varchar(DayName(Timestamp_Format(Digits(MDYN

br), 'MMDDYY')), 10)                                       

 

This 'From' parameter value is a nesting of several SQL built-ins that result in:

  1. Getting the absolute value of MDYNbr, with leading zeroes, using DIGITS
  2. Converting the value obtained in step 1 to a date using TIMESTAMP_FORMAT, interpreting this value as being MMDDYY
  3. Obtaining the date portion of the value obtained in step 2 and getting the name of that day using DAYNAME
  4. Truncating the name of day value obtained in step 3 to the first 10 characters using VARCHAR

 

Today, we have reviewed several additional built-ins that can used from CL to create views over data, views that can in turn be used by utilities such as WRKQRY or processed as an input file by a CL program. The built-ins introduced were TIMESTAMP_FORMAT (which can also be accessed using the name TO_DATE if you prefer less typing, though note that all of the Information Center documentation is found under the name TIMESTAMP_FORMAT), DATE, CHAR, and DIGITS. We have only touched on what all could be used, though in terms of the built-ins found here, so I encourage you to review what's possible.

 

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.. I'll try to answer your burning questions in future columns.

 

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: