Leverage recursive SQL to pivot row values into a single column.
Often, when looking at a report, a user prefers to see similar values grouped together on a single line of output instead of having those values spread across multiple lines of report. An example of that type of report is displayed in the table below. For each automobile make, the report lists all of the models that are currently in inventory in a single row of the report.
Make |
Model |
Chevy |
Malibu, Tahoe |
Ford |
Focus, Taurus, Fusion |
Honda |
Odyssey |
This can be a challenging report to write because the auto make values are going to be scattered across different rows of the table, which stores the automobile inventory data as shown in the following table. Essentially, the report writer is being asked to pivot the row values up into a single column value for the report output.
Make |
Model |
Ford |
Fusion |
Chevy |
Tahoe |
Honda |
Odyssey |
Ford |
Taurus |
Ford |
Focus |
Chevy |
Malibu |
The recursive support provided by DB2 for i allows this challenging requirement to be solved with a single SQL statement. Obviously, a solution could be delivered by utilizing your favorite IBM i programming language. However, a recursive SQL solution requires fewer lines of code.
The following SQL SELECT statement transforms the raw table data in the second table into the desired report format in the first table. 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, curr, prev) AS (
SELECT make, model,
ROW_NUMBER() OVER (PARTITION BY make ORDER BY model) AS curr,
ROW_NUMBER() OVER (PARTITION BY make ORDER BY model) -1 AS prev
FROM inventory)
SELECT make,
MAX (TRIM(L ',' FROM
CAST(SYS_CONNECT_BY_PATH(model, ',') AS VARCHAR(256)) ))
FROM numbered_sets
START WITH curr = 1
CONNECT BY make = PRIOR make AND prev = PRIOR curr
GROUP BY make
The statement uses a common table expression named numbered_sets to logically number and link each row that contains a model (e.g., Taurus) 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. The rationale behind two row-number values being assigned to each row will become clear when the recursive processing is discussed. Figure 1 gives you an idea of the row values produced by the table expression for rows in the inventory table that stored data for the Ford make.
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 common table expression, let's examine the usage of recursion to combine these rows into a single value.
The CONNECT BY clause was made available in the IBM i 7.1 release to enable SQL to recursively navigate data relationships in your tables. The purpose of generating two sets of row numbers was to provide a way to link together the rows that share the same make value. The START WITH clause is even enough to understand it's stating that the recursive process should start with the first row in each set of automobile makes. For the set of Ford rows, that would be the row containing the Fusion model inventory data. The CONNECT BY clause contains two column comparisons that direct the recursive searches. The first comparison is easier to understand because it's stating that recursive processing should continue as long as it can find a row that contains the same make value.
The second comparison (prev = PRIOR curr) is more difficult to understand. That comparison is telling DB2 to find a row that contains a prev value that matches the curr value in the prior row of the data hierarchy. This comparison is represented with the arrows embedded in Figure 1. DB2 starts with the Focus row (curr=1) and then finds a match with the Fusion row because its prev value of 1 matches the curr value in the Focus row. The Taurus row will get matched on the next level of recursion because its prev value of 2 matches the curr value of the Fusion row. The recursive processing of the Ford numbered set will stop with the Fusion row because it won't find any more rows with a matching make value.
The CONNECT BY clause allows DB2 to logically link all of the rows sharing the same make value, but it's the SYS_CONNECT_BY_PATH function that combines all of the model values from each row into a single value. This function essentially concatenates each value in the specified column (model in this example) with the column values processed during prior recursive iterations to represent the path taken through your data. The second argument is a separator value (comma in this example), which is concatenated to the specified column value. This delimiter is concatenated to the beginning of the column value. This is the reason that the TRIM function is nested around the SYS_CONNECT_BY_PATH function to remove the comma separator value from the beginning of the generated path value.
The MAX function and GROUP BY clause are needed to compress the path value generated during the recursive processing. The path value is output for each recursive iteration, 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 think this SELECT statement is a great example of how easy it is to leverage multiple SQL features on a single request to perform powerful data transformations.
Hopefully, this article starts you thinking about how to apply technologies such as recursion and table expressions to meet other business requirements. If you think you need more help getting proficient with the advanced SQL technologies discussed in this article, then you should consider the DB2 for i Advanced SQL offering.
LATEST COMMENTS
MC Press Online