Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

How to get Distinct values across the table? Expand / Collapse
Author
Message
Posted Wednesday, September 19, 2012 5:45 AM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Friday, May 10, 2013 5:41 AM
Points: 12, 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.
Post #1361273
Posted Wednesday, September 19, 2012 6:20 AM
Ten Centuries

Ten CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen Centuries

Group: General Forum Members
Last Login: 2 days ago @ 11:21 AM
Points: 1,234, Visits: 1,271
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
Post #1361281
Posted Wednesday, September 19, 2012 6:30 AM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Friday, May 10, 2013 5:41 AM
Points: 12, Visits: 32
THANKS ROB. IT HELPS LOT :)
Post #1361291
Posted Wednesday, September 19, 2012 6:48 PM


Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: Today @ 3:01 AM
Points: 3,427, Visits: 5,380
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!
Post #1361702
Posted Thursday, September 20, 2012 6:05 AM
Ten Centuries

Ten CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen CenturiesTen Centuries

Group: General Forum Members
Last Login: 2 days ago @ 11:21 AM
Points: 1,234, Visits: 1,271
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
Post #1361897
Posted Thursday, September 20, 2012 6:08 AM


Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: Today @ 3:01 AM
Points: 3,427, Visits: 5,380
You're welcome.

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



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!
Post #1361900
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse