DZone
Thanks for visiting DZone today,
Edit Profile
  • Manage Email Subscriptions
  • How to Post to DZone
  • Article Submission Guidelines
Sign Out View Profile
  • Post an Article
  • Manage My Drafts
Over 2 million developers have joined DZone.
Log In / Join
Refcards Trend Reports
Events Video Library
Refcards
Trend Reports

Events

View Events Video Library

Zones

Culture and Methodologies Agile Career Development Methodologies Team Management
Data Engineering AI/ML Big Data Data Databases IoT
Software Design and Architecture Cloud Architecture Containers Integration Microservices Performance Security
Coding Frameworks Java JavaScript Languages Tools
Testing, Deployment, and Maintenance Deployment DevOps and CI/CD Maintenance Monitoring and Observability Testing, Tools, and Frameworks
Culture and Methodologies
Agile Career Development Methodologies Team Management
Data Engineering
AI/ML Big Data Data Databases IoT
Software Design and Architecture
Cloud Architecture Containers Integration Microservices Performance Security
Coding
Frameworks Java JavaScript Languages Tools
Testing, Deployment, and Maintenance
Deployment DevOps and CI/CD Maintenance Monitoring and Observability Testing, Tools, and Frameworks

How are you handling the data revolution? We want your take on what's real, what's hype, and what's next in the world of data engineering.

Generative AI has transformed nearly every industry. How can you leverage GenAI to improve your productivity and efficiency?

SBOMs are essential to circumventing software supply chain attacks, and they provide visibility into various software components.

Related

  • The Materialized Path Technique: Tree Structures for Relational Database Systems
  • Useful System Table Queries in Relational Databases
  • How to Recover a Deleted Table in a SQL Server Database
  • Why Should Databases Go Natural?

Trending

  • Top NoSQL Databases and Use Cases
  • Designing Microservices Architecture With a Custom Spring Boot Starter and Auto-Configuration Framework
  • Advanced gRPC in Microservices: Hard-Won Insights and Best Practices
  • How We Broke the Monolith (and Kept Our Sanity): Lessons From Moving to Microservices
  1. DZone
  2. Data Engineering
  3. Databases
  4. Multidimensional Reporting With CROSS APPLY and PIVOT in MS SQL Server

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.

By 
Adam Zaręba user avatar
Adam Zaręba
·
May. 30, 18 · Tutorial
Likes (1)
Comment
Save
Tweet
Share
17.3K Views

Join the DZone community and get the full member experience.

Join For Free

In 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:

database-schema

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:

select_all

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:

select_cross_apply

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:

select_pivot

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.

Microsoft SQL Server sql Database Relational database

Published at DZone with permission of Adam Zaręba, DZone MVB. See the original article here.

Opinions expressed by DZone contributors are their own.

Related

  • The Materialized Path Technique: Tree Structures for Relational Database Systems
  • Useful System Table Queries in Relational Databases
  • How to Recover a Deleted Table in a SQL Server Database
  • Why Should Databases Go Natural?

Partner Resources

×

Comments

The likes didn't load as expected. Please refresh the page and try again.

ABOUT US

  • About DZone
  • Support and feedback
  • Community research
  • Sitemap

ADVERTISE

  • Advertise with DZone

CONTRIBUTE ON DZONE

  • Article Submission Guidelines
  • Become a Contributor
  • Core Program
  • Visit the Writers' Zone

LEGAL

  • Terms of Service
  • Privacy Policy

CONTACT US

  • 3343 Perimeter Hill Drive
  • Suite 100
  • Nashville, TN 37211
  • [email protected]

Let's be friends: