21
Sat, Dec
3 New Articles

TechTip: More on Combining Multiple Row Values into a Single Row with SQL in DB2 for i

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

Leverage recursive table expressions to pivot row values into a single column.

 

After my last article, I had a number of readers express interest in a solution that would work on servers running pre-IBM i 7.1 operating system release levels. Luckily, recursive SQL capabilities were first made available with the DB2 for i V5R4 release, so this article will provide a solution that can run on release levels of V5R4 and newer.

As a brief refresher, the requirement was to produce a report similar to the one displayed in the table below. This type of report is challenging because the auto make values are going to be scattered across different rows of the table, which stores the automobile inventory data as shown. Essentially, the report writer is being asked to pivot the row values up into a single column value for the report output.

Make

Model

Chevy

Malibu, Tahoe

Ford

Focus, Taurus, Fusion

Honda

Odyssey

In this article, the recursive common table expression (CTE) support will be used to solve this challenging requirement with a single SQL statement as opposed to the CONNECT BY recursion support used in the prior article.

The following SQL SELECT statement produces the desired report format automobile table by recursively processing the data with a CTE. Let's walk through the key components of the SELECT statement that enables values from multiple rows to be delivered as a single-column value.

WITH numbered_sets (make, model, rownum) AS                          

   (SELECT make, model,                                      

     ROW_NUMBER() OVER(PARTITION BY make ORDER BY model)

   FROM inventory),                                                  

navigate_sets(make, model_list, rownum) AS                              

   (SELECT t.make , CAST(t.model AS VARCHAR(200)), t.rownum                              

    FROM numbered_sets t WHERE t.rownum = 1                                              

         UNION ALL                                              

   SELECT s.make, n.model_list || ', ' || s.model, s.rownum        

    FROM numbered_sets s INNER JOIN navigate_sets n

     ON s.make = n.make AND s.rownum = n.rownum+1 )                          

SELECT make, MAX(model_list) FROM navigate_sets GROUP BY make

The SELECT statement uses two CTEsone recursive and one non-recursive. The first CTE, numbered_sets, is a non-recursive expression that logically numbers each row that contains a model (e.g., Focus) belonging to the same make (e.g., Ford). That logical numbering is accomplished with the ROW_NUMBER specification, which can be used to number each row in a set. The PARTITION BY clauses cause the numbering to start over at 1 once all of the rows associated with a single make have been numbered. Figure 1 gives you an idea of the row values produced by this CTE for rows in the inventory table that stored data for the Ford make.

Make

Model

Rownum

. . .

. . .

. . .

Ford

Focus

1

Ford

Fusion

2

Ford

Taurus

3         

. . .

. . .

. . .

Figure 1: This representation shows the numbered_sets table expression.

Now that the rows belonging to each make of automobile have been logically divided into numbered sets by the non-recursive CTE, let's examine the usage of a recursive CTE to combine these rows into a single value.

A recursive CTE is always composed of two SELECT clauses unioned together. This composition is found in the navigate_sets recursive expression defined in this example. The first SELECT clause is used to seed (start) the recursive processing. In this example, the selection criteria of t.rownum=1 directs the recursive processing to start with the first numbered model for each make. Using Figure 1 as a reference, the recursive process will start with Focus model in the set of Ford automobiles.

The second SELECT clause defines the recursive processing. Notice how the second SELECT clause references the navigate_sets CTE on the INNER JOIN clause. The definition of the navigate_sets CTE includes this reference to itself, which is the indicator to DB2 to perform recursive processing.

The recursive leg of the navigate_sets CTE joins itself to the data returned by the numbered_sets table expression so that each model for a particular make can be recursively detected by DB2. The ON clause defines how to find the next model for a make. The comparison of s.make=n.make tells DB2 to only find automobiles that match the make value currently being processed. This comparison of make values is logically ANDed with the comparison of s.rownum=n.rownum+1 to direct DB2 to recursively find the next model within the set of automobiles' makes numbered by the numbered_sets CTE.

Again using Figure 1 as a reference, the first SELECT clause would start with the Focus model (t.rownum=1) within the set of Ford automobiles. The second, recursive SELECT clause would find the Fusion as the next model in the Ford set because the rownum values meet the specified criteria of n.rownum+1=s.rownum. The Taurus model would be found in the next round of recursive processing due to also satisfying the same criteria of n.rownum+1=s.rownum. At this point, the recursive processing would end for the set of Ford automobiles because there would be no other rows in the numbered_sets CTE meeting the make and rownum comparison criteria. Once the processing ends for the Ford make value, DB2 would perform the same recursive processing for the other make values (Honda and Chevy) in the numbered_sets CTE.

The concatenation operation on the second SELECT clause of n.model_list with s.model (n.model_list || ', ' || s.model)is how all of the model values from each row get combined into a single value. The literal value of a comma with a blank provides a nice separation between each model value in the concatenated list.

The MAX function and GROUP BY clause are needed on the main SELECT statement that executes the navigate_sets recursive CTE. The concatenated set of model values is output for each recursive iteration through the data, so without grouping the Ford set, output would look like the following:

Ford     Focus

Ford     Focus, Fusion

Ford     Focus, Fusion, Taurus

Grouping all of the Ford rows together results in the last value above being chosen as the MAX value since blank characters have a lesser value than non-blank characters.

I am guessing that by now you have noticed that this recursive CTE solution is more verbose than the CONNECT BY recursion discussed in the first article. The amount of coding doesn't necessarily make one solution better than other. When choosing between these two recursive techniques, you need to focus on your requirements (e.g., operating system release level) and the syntax that's easiest for you to implement and maintain. If you think you need more help getting proficient with the SQL recursion and table expression technologies discussed in this article series, then you should consider the DB2 for i Advanced SQL offering.

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: