Multidimensional Reporting With CROSS APPLY and PIVOT in MS SQL Server
Read this article in order to view a tutorial on how to use PIVOT relational operator to transform data from table-valued into another table.
Join the DZone community and get the full member experience.
Join For FreeIn this post, we’re going to demonstrate how to use PIVOT relational operator to transform data from table-valued into another table. As an example, we will use a simple Data Warehouse (DWH) that stores annual company reports for harvesting fruits. The goal is to display a report showing annual reports of sold fruits for each year.
DWH Schema
Our simple database stores information about annual reports of sold fruits grouped by companies:
Following query:
SELECT NAME, APPLE, GRAPE, YEAR
FROM dwh.dbo.HARVESTING_FRUITS
INNER JOIN dwh.dbo.COMPANY ON HARVESTING_FRUITS.COMPANY_ID = COMPANY.ID
Returns data:
Transform Reports to Separate Rows — (CROSS) APPLY
We are going to use CROSS APPLY operator to populate the same operation for each record from the left side — HARVESTING_FRUITS. In the below query, we want to return a pair of values for fruits reports based on year. Since we have a known amount of fruit types, we will return concatenated strings, like:
- APPLES + YEAR
- GRAPES + YEAR
as FRUIT_YEAR, and return value for given report as AMOUNT.
SELECT COMPANY.NAME, FRUITS_BY_YEAR.*
FROM dwh.dbo.HARVESTING_FRUITS FRUITS
INNER JOIN dwh.dbo.COMPANY ON FRUITS.COMPANY_ID = COMPANY.ID
CROSS APPLY (
VALUES
(CONCAT('APPLES - ', YEAR), APPLE),
(CONCAT('GRAPES - ', YEAR), GRAPE)
) FRUITS_BY_YEAR (FRUIT_YEAR, AMOUNT)
The output is as follows:
Transform Rows to Columns — PIVOT
Since we have reports separated by fruit name and year, we can turn values from FRUIT_YEAR column into multiple columns. Help comes with PIVOT operator. PIVOT syntax requires to use aggregate function so for AMOUNT we can use MAX function to just get value. Columns will be displayed based on given order:
- [APPLES - 2015]
- [APPLES - 2016]
- [APPLES - 2017]
- [GRAPES - 2015]
- [GRAPES - 2016]
- [GRAPES - 2017]
SELECT *
FROM (
SELECT COMPANY.NAME, FRUITS_BY_YEAR.*
FROM dwh.dbo.HARVESTING_FRUITS FRUITS
INNER JOIN dwh.dbo.COMPANY ON FRUITS.COMPANY_ID = COMPANY.ID
CROSS APPLY (
VALUES
(CONCAT('APPLES - ', YEAR), APPLE),
(CONCAT('GRAPES - ', YEAR), GRAPE)
) FRUITS_BY_YEAR (FRUIT_YEAR, AMOUNT)
) COLLECTED_FRUITS
PIVOT (
MAX(AMOUNT)
FOR FRUIT_YEAR IN (
[APPLES - 2015], [APPLES - 2016], [APPLES - 2017],
[GRAPES - 2015], [GRAPES - 2016], [GRAPES - 2017]
)
) COMBINED_FRUITS
The final report is:
Summary
MS SQL Server comes with very useful operators that simplifies working with DWHs. Although operators syntax is easy, CROSS APPLY and PIVOT could be used for complex transformations. The script for the example database creation can be found here.
Published at DZone with permission of Adam Zaręba, DZone MVB. See the original article here.
Opinions expressed by DZone contributors are their own.
Comments