23
Mon, Dec
3 New Articles

Simplify SQL "With" Common Table Expressions

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

 

Use the WITH keyword to make your SQL statements easier to code and maintain.

 

Common table expressions (CTEs) allow you to break down complex SQL logic into smaller pieces. This makes development and testing easier, and when you come back to the code next year you'll understand it more quickly. That can't be bad, and a CTE is not hard to use. In this article, I'll provide working examples of CTEs that demonstrate their ease of use and the clarity they can provide.

 

 

CTE Syntax

 

"Common table expression" is a bit of an intimidating mouthful. The V7R1 IBM i DB2 for i SQL Reference manual says this:

 

A common-table-expression permits defining a result table with a table-identifier that can be specified as a table name in any FROM clause of the fullselect that follows. Multiple common table expressions can be specified following the single WITH keyword. Each common table expression specified can also be referenced by name in the FROM clause of subsequent common table expressions.

 

This means:

  • A CTE must be part of a SELECT statement. (This is important to remember when you get around to trying to use a CTE in a CREATE statement or an INSERT statement. I'll provide an example that covers this.)
  • A CTE is defined using the WITH keyword.
  • The WITH keyword can define one or more CTEs.

Think of a CTE as a temporary named view as you follow along with the examples I provide.

 

Running the Examples

 

The examples in this article are based on file QIWS/QCUSTCDT, which I believe by default is available on almost everyone's machine, unless you have deleted it. (So far, no one has complained that QCUSTCDT is missing.) It contains just 12 records, and some of the data looks like this:

 

CUSNUM   LSTNAM   CITY   STATE ZIPCOD   CDTLMT     BALDUE

938,472   Henning   Dallas   TX   75,217   5,000     37.00

839,283   Jones     Clay     NY   13,041     400     100.00

392,859   Vine      Broton   VT     5,046     700     439.00

938,485   Johnson   Helen   GA   30,545   9,999   3,987.50

397,267   Tyron     Hector   NY   14,841   1,000       .00

389,572   Stevens   Denver   CO   80,226     400     58.75

846,283   Alison   Isle     MN   56,342   5,000     10.00

475,938   Doe       Sutter   CA   95,685     700     250.00

693,829   Thomas   Casper   WY   82,609   9,999       .00

593,029   Williams Dallas   TX   75,218     200     25.00

192,837   Lee       Hector   NY   14,841     700     489.50

583,990   Abraham   Isle     MN   56,342   9,999     500.00

 

The examples are contrived to fit this data, but they might bear some semblance to real business requirements. You should be able to cut and paste the example code into your favorite SQL client.

 

A Single CTE

 

Suppose we want to list those customers whose balance-to-credit ratio is greater than 50 percent and we want it by ratio descending. We need to take the balance due, divide by the credit limit, multiply by 100 to create a percent, and then ensure that the percent has two decimal places. We name the resulting field "Pct_Cred" for the report.

 

Our first attempt to code this query without a CTE might look like this:

 

select     decimal((BALDUE / CDTLMT) * 100,5,2) as Pct_Cred,

           CUSNUM, LSTNAM, CDTLMT, BALDUE

from       QIWS/QCUSTCDT

where     Pct_Cred > 50

order by   Pct_Cred desc

 

However, when you try to run this, SQL complains that "Column or global variable PCT_CRED not found." This is because the WHERE clause does not recognize the new Pct_Cred column (field) created in the SELECT clause.

 

A revised attempt might look like this, where we duplicate the Pct_Cred calculation in the WHERE clause:

 

select     decimal((BALDUE / CDTLMT) * 100,5,2) as Pct_Cred,

           CUSNUM, LSTNAM, CDTLMT, BALDUE

from       QIWS/QCUSTCDT

where     decimal((BALDUE / CDTLMT) * 100,5,2) > 50

order by   Pct_Cred desc

 

This does create the report we expect, which looks like this:

 

PCT_CRED   CUSNUM   LSTNAM   CDTLMT    BALDUE

   69.92   192,837   Lee         700     489.50

   62.71   392,859   Vine         700     439.00

 

I don't like coding the same calculation twice, even the relatively simple Pct_Credit calculation in this demonstration example. You all know the problems with duplicated code: It doesn't always all get changed, it doesn't always get changed the same way, and it takes more time to change. If I use a CTE, I can code the Pct_Credit calculation only once, like this:

 

with CreditRatio as (

select   decimal((BALDUE / CDTLMT) * 100,5,2) as Pct_Cred,

           a.*

from     QIWS/QCUSTCDT a

)

select     Pct_Cred, CUSNUM, LSTNAM, CDTLMT, BALDUE

from       CreditRatio

where     Pct_Cred > 50

order by   Pct_Cred desc

 

The CTE is the first five lines of the code, from the "with" on the first line to the ")" on the fifth line. The CTE name is CreditRatio. Think of CreditRatio as a temporary table that contains all columns of QCUSTCDT, plus a brand new column Pct_Cred.

 

Now that you have a table named CreditRatio, you can reference in a FROM clause, as done on the seventh line, and refer to all columns in CreditRatio, including the new column Pct_Cred.

 

The credit percent ratio logic is in a single place, it is easily changed, and I find it a lot easier to read the overall SQL.

 

Coding and Testing with CTE

 

You can develop and test incrementally. While it may be overkill for this example, I would first code and test this:

 

select   decimal((BALDUE / CDTLMT) * 100,5,2) as Pct_Cred,

           a.*

from   QIWS/QCUSTCDT a

 

Once I had this working, I would then wrap it in the WITH keyword and test again as below, to prove that I had the CTE working correctly:

 

with CreditRatio as (

select   decimal((BALDUE / CDTLMT) * 100,5,2) as Pct_Cred,

           a.*

from     QIWS/QCUSTCDT a

)

select     *

from       CreditRatio

 

Finally, I'd flesh out the final select.

 

Two CTEs

 

You can also have two, or more, CTEs.

 

Suppose the credit manager changes his mind (surprise!) and now wants to see the credit ratio of all customers, but wants them in three groups: up to 30 percent, 30–60 percent, and greater than 60 percent. We can now build a second CTE, CreditRank, based on the original CreditRatio CTE.

 

Note the following in the code below:

  • There's only one WITH keyword.
  • Each CTE is enclosed in parentheses.
  • CTEs are separated by commas.

I have changed the code formatting to highlight these points.

 

with

CreditRatio as

(

select   decimal((BALDUE / CDTLMT) * 100,5,2) as Pct_Cred,

           a.*

from     QIWS/QCUSTCDT a

)

,

CreditRank as

(

select   case

               when Pct_Cred < 30 then 1

               when Pct_Cred > 60 then 3

               else 2

           end as Cred_Rank,

           a.*

from     CreditRatio a

)

select     Cred_Rank, Pct_Cred, CUSNUM, LSTNAM, CDTLMT, BALDUE

from       CreditRank

order by   Cred_Rank, Pct_Cred, CUSNUM

 

The new CreditRank CTE selects from the CreditRatio CTE and uses a CASE statement to create another column, Cred_Rank. (If you need help with CASE syntax, check "The Case for SQL CASE.")

 

The FROM clause in the final select is then changed to use the CreditRank CTE.

 

This gives us results like this:

 

CRED_RANK   PCT_CRED   CUSNUM   LSTNAM   CDTLMT     BALDUE

       1       .00   397,267   Tyron     1,000       .00

       1       .00   693,829   Thomas     9,999       .00

       1       .20   846,283   Alison     5,000     10.00

       1       .74   938,472   Henning   5,000    37.00

       1     5.00   583,990   Abraham   9,999     500.00

       1     12.50   593,029   Williams     200     25.00

       1     14.68   389,572   Stevens     400     58.75

       1     25.00   839,283   Jones       400     100.00

       2     35.71   475,938   Doe         700     250.00

       2     39.87   938,485   Johnson   9,999   3,987.50

       3     62.71   392,859   Vine         700     439.00

       3     69.92   192,837   Lee         700     489.50

 

Note that a second or subsequent CTE does not have to select from a prior CTE as done here; it can just as easily select from another table or view.

 

CTEs with CREATE

 

Suppose we want to create a table that holds the credit ratio, customer number, and customer name of those customers who have a credit limit greater than 50 percent. It seems logical that the first thing you need to code is the WITH keyword, followed by CREATE, but this is incorrect.

 

Here is the correct syntax to use with a CREATE statement, where the WITH keyword is part of the SELECT statement:

 

create table QTEMP/Cust_Ratio as

(

with

CreditRatio as

(

   select   decimal((BALDUE / CDTLMT) * 100,5,2) as Pct_Cred,

             CUSNUM as Customer_Number,

             trim(LSTNAM) concat ', ' concat trim(INIT) as Customer_Name

   from     QIWS/QCUSTCDT

)

select     *

from       CreditRatio

where     Pct_Cred > 50

) with data

 

I created this table in QTEMP since this is a demonstration. You could create it in any library you desire. QTEMP/Cust_Ratio contains this data:

 

PCT_CRED CUSTOMER_NUMBER CUSTOMER_NAME

62.71       392,859     Vine, S S  

69.92       192,837     Lee, F L    

 

CTEs with INSERT

 

Using a CTE in an INSERT statement is very similar to CREATE. To demonstrate, we'll take those customers with a credit ratio less than 5 percent and insert then into QTEMP/Cust_Ratio.

 

insert into QTEMP/Cust_Ratio

with

CreditRatio as

(

   select   decimal((BALDUE / CDTLMT) * 100,5,2) as Pct_Cred,

             CUSNUM as Customer_Number,

             trim(LSTNAM) concat ', ' concat trim(INIT) as Customer_Name

   from     QIWS/QCUSTCDT

)

select     *

from       CreditRatio

where     Pct_Cred < 5

 

QTEMP/Cust_Ratio now contains this data:

 

PCT_CRED CUSTOMER_NUMBER CUSTOMER_NAME

62.71       392,859     Vine, S S    

69.92       192,837     Lee, F L    

   .74       938,472     Henning, G K

   .00       397,267     Tyron, W E  

   .20       846,283     Alison, J S  

   .00       693,829     Thomas, A N

  

Conclusion

Common table expressions (CTEs) are simply defined using the WITH keyword. They allow for logic to be coded in a single place and simplify coding and maintainability. SQL should be part of your developer toolbox, and using CTEs can make you more productive.

 

Notes

I ran these examples on the free V5R3 machine at http://www.rzkh.de, but CTEs have been available since V4R4.

 

I have formatted the example code because I find it much easier to read and debug. However, SQL does not require such formatting.

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: