SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


How do I convert column data into row data?


How do I convert column data into row data?

Author
Message
Luis Cazares
Luis Cazares
SSCoach
SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)

Group: General Forum Members
Points: 16697 Visits: 19108
Erland Sommarskog (9/11/2013)
ChrisM@Work (9/4/2013)
Or CROSS APPLY VALUES


Somewhat odd to use CROSS APPLY here. The normal is CROSS JOIN. Of course since there is no correlation on the right side, the CROSS APPLU is effectively a CROSS JOIN, but nevertheless.

Are you sure? CROSS JOIN shows an error because it can't referenciate n1, n2 and n3.


Luis C.
General Disclaimer:
Are you seriously taking the advice and code from someone from the internet without testing it? Do you at least understand it? Or can it easily kill your server?


How to post data/code on a forum to get the best help: Option 1 / Option 2
ChrisM@Work
ChrisM@Work
SSCoach
SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)

Group: General Forum Members
Points: 16436 Visits: 19554
Erland Sommarskog (9/11/2013)
ChrisM@Work (9/4/2013)
Or CROSS APPLY VALUES


Somewhat odd to use CROSS APPLY here. The normal is CROSS JOIN. Of course since there is no correlation on the right side, the CROSS APPLU is effectively a CROSS JOIN, but nevertheless.


There are similarities and differences to CROSS JOIN. All rows from the RHS are matched to all rows on the LHS, for instance. However, whilst the VALUES clause of a CAV block introduces a table source such as CROSS JOIN requires, the values are taken from the "current row" on the LHS, from any table source in scope.
(CROSS) APPLY without introducing a table source effectively translates to "calculate new columns" using the current row(s). VALUES expands on this functionality allowing you to create new rows as well. Correlation is moot - you play with the data already in scope.

“Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
Exploring Recursive CTEs by Example Dwain Camps
Erland Sommarskog
Erland Sommarskog
SSCrazy
SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)

Group: General Forum Members
Points: 2129 Visits: 872
Ah, I see. I had just completed an unpivot solution (using CROSS JOIN) in another thread prior to reading this thread. I need to look into this idea more.

Erland Sommarskog, SQL Server MVP, www.sommarskog.se
ChrisM@Work
ChrisM@Work
SSCoach
SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)

Group: General Forum Members
Points: 16436 Visits: 19554
Dwain C has a nice article covering usage, I've put a link in an earlier post in this thread.
Blimey. I've learned so much from your website over the years. Nice - and a privilege - to see the tables turned.

“Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
Exploring Recursive CTEs by Example Dwain Camps
dwain.c
dwain.c
SSCertifiable
SSCertifiable (7.4K reputation)SSCertifiable (7.4K reputation)SSCertifiable (7.4K reputation)SSCertifiable (7.4K reputation)SSCertifiable (7.4K reputation)SSCertifiable (7.4K reputation)SSCertifiable (7.4K reputation)SSCertifiable (7.4K reputation)

Group: General Forum Members
Points: 7383 Visits: 6431
ChrisM@Work (9/12/2013)
Blimey. I've learned so much from your website over the years. Nice - and a privilege - to see the tables turned.


I would have to second that.


My mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

My thought question: Have you ever been told that your query runs too fast?

My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.


Need to UNPIVOT? Why not CROSS APPLY VALUES instead?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
My temporal SQL musings: Calendar Tables, an Easter SQL, Time Slots and Self-maintaining, Contiguous Effective Dates in Temporal Tables
Erland Sommarskog
Erland Sommarskog
SSCrazy
SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)SSCrazy (2.1K reputation)

Group: General Forum Members
Points: 2129 Visits: 872
Blimey? Must be some lingo local to Port Moresby.

Any way, since I don't think that there was a post with CROSS JOIN for unpivotting, here is an example, taken from another thread. When looking at the query plans, the CROSS APPLY solution looks better, but I would need more data to test. I would like to point out, though, that the solution with CROSS JOIN has the distinct advantage of being fully portable across platforms. (Hm, not all engines may support the VALUES clause, but it's easliy replaced with SELECT UNION ALL.)

Create Table #sample 
( Name Varchar(100) PRIMARY KEY,
Mark1 int,
Mark2 int,
Mark3 int)

insert into #sample values ('Vignesh',100,59,95)
insert into #sample values ('ram',23,45,33)
insert into #sample values ('kumar',58,12,15)
insert into #sample values ('umar',15,25,98)
go
SELECT s.Name, CASE n.n WHEN 1 THEN s.Mark1
WHEN 2 THEN s.Mark2
WHEN 3 THEN s.Mark3
END AS Mark,
CASE n.n WHEN 1 THEN 'Mark1'
WHEN 2 THEN 'Mark2'
WHEN 3 THEN 'Mark3'
END AS MarkName
FROM #sample s
CROSS JOIN (VALUES (1), (2), (3)) AS n(n)
ORDER BY s.Name, n.n
go
SELECT s.Name, M.Mark, M.name
FROM #sample s
CROSS APPLY (VALUES (1, s.Mark1, 'Mark1'), (2, s.Mark2, 'Mark2'), (3, s.Mark1, 'Mark3')) AS M(n, Mark, name)
ORDER BY s.Name, M.n
go
DROP TABLE #sample



Note that here I have added a column n to the CROSS APPLY table to make that query fully equivalent to the CROSS JOIN solution, but in the APPLY solution you don't need n if you don't care about order, whereas it's a driving column in the CROSS JOIN solution.

As for UNPIVOT - I have never been able to learn it, the same with PIVOT.

Erland Sommarskog, SQL Server MVP, www.sommarskog.se
dwain.c
dwain.c
SSCertifiable
SSCertifiable (7.4K reputation)SSCertifiable (7.4K reputation)SSCertifiable (7.4K reputation)SSCertifiable (7.4K reputation)SSCertifiable (7.4K reputation)SSCertifiable (7.4K reputation)SSCertifiable (7.4K reputation)SSCertifiable (7.4K reputation)

Group: General Forum Members
Points: 7383 Visits: 6431
Erland Sommarskog (9/12/2013)
Blimey? Must be some lingo local to Port Moresby.


I didn't hear that much when I was out and about with my signboard.

I have it on good authority that Blimey is an exclusively British slang and that the Australian equivalent is Crikey, although the Tasmanian I heard that from is known for pulling my leg. There's a lot of Aussies in Port Moresby.

Now Pohmmie can refer to either Aussies (Prisoners Of Her Majesty) or Brits (turnabout is fair play) depending on who you talk to.


My mantra: No loops! No CURSORs! No RBAR! Hoo-uh!

My thought question: Have you ever been told that your query runs too fast?

My advice:
INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.


Need to UNPIVOT? Why not CROSS APPLY VALUES instead?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
My temporal SQL musings: Calendar Tables, an Easter SQL, Time Slots and Self-maintaining, Contiguous Effective Dates in Temporal Tables
ChrisM@Work
ChrisM@Work
SSCoach
SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)SSCoach (16K reputation)

Group: General Forum Members
Points: 16436 Visits: 19554
Erland Sommarskog (9/12/2013)
Blimey? Must be some lingo local to Port Moresby.

Any way, since I don't think that there was a post with CROSS JOIN for unpivotting, here is an example, taken from another thread. When looking at the query plans, the CROSS APPLY solution looks better, but I would need more data to test. I would like to point out, though, that the solution with CROSS JOIN has the distinct advantage of being fully portable across platforms. (Hm, not all engines may support the VALUES clause, but it's easliy replaced with SELECT UNION ALL.)

Create Table #sample 
( Name Varchar(100) PRIMARY KEY,
Mark1 int,
Mark2 int,
Mark3 int)

insert into #sample values ('Vignesh',100,59,95)
insert into #sample values ('ram',23,45,33)
insert into #sample values ('kumar',58,12,15)
insert into #sample values ('umar',15,25,98)
go
SELECT s.Name, CASE n.n WHEN 1 THEN s.Mark1
WHEN 2 THEN s.Mark2
WHEN 3 THEN s.Mark3
END AS Mark,
CASE n.n WHEN 1 THEN 'Mark1'
WHEN 2 THEN 'Mark2'
WHEN 3 THEN 'Mark3'
END AS MarkName
FROM #sample s
CROSS JOIN (VALUES (1), (2), (3)) AS n(n)
ORDER BY s.Name, n.n
go
SELECT s.Name, M.Mark, M.name
FROM #sample s
CROSS APPLY (VALUES (1, s.Mark1, 'Mark1'), (2, s.Mark2, 'Mark2'), (3, s.Mark1, 'Mark3')) AS M(n, Mark, name)
ORDER BY s.Name, M.n
go
DROP TABLE #sample



Note that here I have added a column n to the CROSS APPLY table to make that query fully equivalent to the CROSS JOIN solution, but in the APPLY solution you don't need n if you don't care about order, whereas it's a driving column in the CROSS JOIN solution.

As for UNPIVOT - I have never been able to learn it, the same with PIVOT.


Thanks for posting this - it's interesting to see both together. I'll have a closer look (in a couple of weeks, after vacation).
I've not been able to learn PIVOT and UNPIVOT either - a swift look at BOL is always necessary. Since they both look like quick-and-dirty implementations, I'll wait until MS rewrites them properly.

“Write the query the simplest way. If through testing it becomes clear that the performance is inadequate, consider alternative query forms.” - Gail Shaw

For fast, accurate and documented assistance in answering your questions, please read this article.
Understanding and using APPLY, (I) and (II) Paul White
Hidden RBAR: Triangular Joins / The "Numbers" or "Tally" Table: What it is and how it replaces a loop Jeff Moden
Exploring Recursive CTEs by Example Dwain Camps
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search