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


How to get Distinct values across the table?


How to get Distinct values across the table?

Author
Message
lokesha.b
lokesha.b
Grasshopper
Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)

Group: General Forum Members
Points: 14 Visits: 32
DECLARE @t TABLE( col1 VARCHAR(1), col2 VARCHAR(1), col3 VARCHAR(1), col4 VARCHAR(1) )

INSERT INTO @t VALUES( 'A', 'B', 'C','D' );
INSERT INTO @t VALUES( 'D', 'E', 'F','E' );
INSERT INTO @t VALUES( 'A', 'J', 'K','D' );
INSERT INTO @t VALUES( 'G', 'H', 'H','E' );

SELECT * FROM @t

Col1 Col2 Col3 Col4
---- ---- ---- ----
A B I D
D E F E
A J K D
G H H C

I want the unique values as below,

RESULT
-------
A
B
C
D
E
F
G
H
I
J
K

Please give me the query which provides good performance.
Rob Taylor
Rob Taylor
Hall of Fame
Hall of Fame (3.8K reputation)Hall of Fame (3.8K reputation)Hall of Fame (3.8K reputation)Hall of Fame (3.8K reputation)Hall of Fame (3.8K reputation)Hall of Fame (3.8K reputation)Hall of Fame (3.8K reputation)Hall of Fame (3.8K reputation)

Group: General Forum Members
Points: 3760 Visits: 1616
Couldn't you just unpivot your data? Something like:


SELECT DISTINCT SpecificCols
FROM
(SELECT col1, col2, col3, col4
FROM @t) t
UNPIVOT
(SpecificCols FOR AllCols IN (col1, col2, col3, col4)) AS unpvt;



HTH,
Rob
lokesha.b
lokesha.b
Grasshopper
Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)Grasshopper (14 reputation)

Group: General Forum Members
Points: 14 Visits: 32
THANKS ROB. IT HELPS LOT Smile
dwain.c
dwain.c
SSCoach
SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)

Group: General Forum Members
Points: 17371 Visits: 6431
robert.gerald.taylor (9/19/2012)
Couldn't you just unpivot your data? Something like:


SELECT DISTINCT SpecificCols
FROM
(SELECT col1, col2, col3, col4
FROM @t) t
UNPIVOT
(SpecificCols FOR AllCols IN (col1, col2, col3, col4)) AS unpvt;



HTH,
Rob


There's a (usually) faster way:


SELECT col
FROM @t
CROSS APPLY (
VALUES (col1), (col2), (col3), (col4)) a(col)




This article describes the CROSS APPLY VALUES approach to UNPIVOT: http://www.sqlservercentral.com/Authors/Articles/Dwain_Camps/1444841/ including some information on the performance characteristics. More detailed performance results can be found in the associated discussion thread.


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
Rob Taylor
Rob Taylor
Hall of Fame
Hall of Fame (3.8K reputation)Hall of Fame (3.8K reputation)Hall of Fame (3.8K reputation)Hall of Fame (3.8K reputation)Hall of Fame (3.8K reputation)Hall of Fame (3.8K reputation)Hall of Fame (3.8K reputation)Hall of Fame (3.8K reputation)

Group: General Forum Members
Points: 3760 Visits: 1616
dwain.c (9/19/2012)

There's a (usually) faster way:


SELECT col
FROM @t
CROSS APPLY (
VALUES (col1), (col2), (col3), (col4)) a(col)




This article describes the CROSS APPLY VALUES approach to UNPIVOT: http://www.sqlservercentral.com/Authors/Articles/Dwain_Camps/1444841/ including some information on the performance characteristics. More detailed performance results can be found in the associated discussion thread.


Good article; thanks for pointing that out. I wasn't aware of that.

Rob
dwain.c
dwain.c
SSCoach
SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)SSCoach (17K reputation)

Group: General Forum Members
Points: 17371 Visits: 6431
You're welcome.

I know the author well. He's not that skilled but once in awhile gets inspired.:-D


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