How to convert columns to rows and rows to columns.

1 Pivoting

This first feature allows to transpose the structure of a resultset. So it will convert rows into columns.

Let's assume that we have the following table definition:

Copy
CREATE TABLE Sales (Year INT, Quarter INT, Results INT)

Which contains the following data:

Copy
YEAR        QUARTER     RESULTS
----------- ----------- -----------
       2004           1          20
       2004           2          30
       2004           3          15
       2004           4          10
       2005           1          18
       2005           2          40
       2005           3          12
       2005           4          27

What I want is a query that shows one row per year with each column being the results of the sales by quarter (i.e. one column per quarter). This is the result I want to see:

Copy
YEAR        Q1          Q2          Q3          Q4
----------- ----------- ----------- ----------- -----------
       2004          20          30          15          10
       2005          18          40          12          27

Here is the query that gives this to you:

Copy
SELECT Year,
       MAX(CASE WHEN Quarter = 1
           THEN Results END) AS Q1,
       MAX(CASE WHEN Quarter = 2
           THEN Results END) AS Q2,
       MAX(CASE WHEN Quarter = 3
           THEN Results END) AS Q3,
       MAX(CASE WHEN Quarter = 4
           THEN Results END) AS Q4
FROM Sales
GROUP BY Year

In this query we scan the SALES table and return the Year followed by 4 other columns. If we ignore the GROUP BY for one moment, the value of the 4 columns will be either the value in the RESULTS column if the Quarter is equal to the Quarter in the CASE expression or it will be NULL if it doesn't match. Here is what the results would look like if there was no GROUP BY clause (and no MAX function):

Copy
YEAR        Q1          Q2          Q3          Q4
----------- ----------- ----------- ----------- -----------
       2004          20           -           -           -
       2004           -          30           -           -
       2004           -           -          15           -
       2004           -           -           -          10
       2005          18           -           -           -
       2005           -          40           -           -
       2005           -           -          12           -
       2005           -           -           -          27

To avoid this scenario, we use the MAX function and group by YEAR. Now the resultset brings one row per year with the RESULTS in each of the 4 quarter columns. The MAX function is used here as it works with all compatible data types including strings.

The same result can be obtained by using the vtable.pivot function of xsql-script, as seen in the following example:

Copy
<xsql-script name='vtable_pivot'>
    <body>
        <println>
            <vtable.pivot pivotcolumns='quarter' datacolumns='results' prefix='Q'>
               <vtable>
                  <select>
                      <columns>
                          year, quarter, results
                      </columns>
                      <from table = 'sales'/>
                  </select>
               </vtable>
            </vtable.pivot>
        </println>
        
        <!--
           RESULT:
           +=======+=======+=======+=======+=======+
           |year   |Q1     |Q2     |Q3     |Q4     |
           |year   |1      |2      |3      |4      |
           |integer|results|results|results|results|
           |visible|integer|integer|integer|integer|
           |       |visible|visible|visible|visible|
           +=======+=======+=======+=======+=======+
           |   2004|     20|     30|     15|     10|
           |   2005|     18|     40|     12|     27|
           +=======+=======+=======+=======+=======+
        -->

    </body>
</xsql-script>

2 Unpivoting

This feature acts in the oposite way of 'pivoting', while transposing rows with multiple columns. Let's assume that we have the following table definition:

Copy
CREATE TABLE SalesAgg
(  year INTEGER,
   q1 INTEGER,
   q2 INTEGER,
   q3 INTEGER,
   q4 INTEGER );

With the following data in it:

Copy
YEAR        Q1          Q2          Q3          Q4
----------- ----------- ----------- ----------- -----------
       2004          20          30          15          10
       2005          18          40          12          27

But what I want is to produce one row for each Year/Quarter combination with the 3rd column being the results that appear in the year/quarter cell above. Here are the results I'm looking for:

Copy
YEAR        QUARTER     RESULTS
----------- ----------- -----------
       2004           1          20
       2004           2          30
       2004           3          15
       2004           4          10
       2005           1          18
       2005           2          40
       2005           3          12
       2005           4          27

Here is the query that will produce these results very efficiently:

Copy
SELECT year,1 quarter, q1 results FROM SalesAgg
 UNION ALL
SELECT year,2 quarter, q2 results FROM SalesAgg
 UNION ALL
SELECT year,3 quarter, q3 results FROM SalesAgg
 UNION ALL
SELECT year,4 quarter, q4 results FROM SalesAgg
ORDER BY 1,2