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 CTEs—one 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.
LATEST COMMENTS
MC Press Online