How to get Distinct values across the table?

  • 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

    Col1Col2Col3Col4

    ----------------

    ABID

    DEFE

    AJKD

    GHHC

    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.

  • 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

  • THANKS ROB. IT HELPS LOT 🙂

  • 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![/I]

    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?[/url]
    Since random numbers are too important to be left to chance, let's generate some![/url]
    Learn to understand recursive CTEs by example.[/url]
    [url url=http://www.sqlservercentral.com/articles/St

  • 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

  • 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![/I]

    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?[/url]
    Since random numbers are too important to be left to chance, let's generate some![/url]
    Learn to understand recursive CTEs by example.[/url]
    [url url=http://www.sqlservercentral.com/articles/St

Viewing 6 posts - 1 through 5 (of 5 total)

You must be logged in to reply to this topic. Login to reply