• Lynn Pettis (5/18/2012)


    MODEL 01:

    name email A B C D

    aa john@test.com 0 0 1 1

    bb rick@test.com 0 1 0 1

    cc sally@test.com 0 1 1 0

    dd aha@test.com 1 1 0 0

    What would make better sense is to take the four columns: A,B,C,D and move them into a separate table:

    MODEL 01A

    NameID Name EMail

    1 aa john@test.com

    2 bb rick@test.com

    3 cc sally@test.com

    4 dd aha@test.com

    NameID Mode

    1 C

    1 D

    2 B

    2 D

    3 B

    3 C

    4 A

    4 B

    This allows adding new modes by adding a row and deleting a mode by deleting a row.

    I want to help! If you've mistakenly used MODEL 01 and you want to convert to Lynn's MODEL 01A, you can do it this way:

    DECLARE @t TABLE

    (NameID INT IDENTITY, name VARCHAR(20), email VARCHAR(20), A INT, B INT, C INT, D INT)

    INSERT INTO @t

    SELECT 'aa','john@test.com',0, 0, 1, 1

    UNION ALL SELECT 'bb','rick@test.com',0, 1, 0, 1

    UNION ALL SELECT 'cc','sally@test.com',0, 1, 1, 0

    UNION ALL SELECT 'dd','aha@test.com',1, 1, 0, 0

    -- MODEL 01:

    SELECT * FROM @t

    -- MODEL 01A (table 2):

    SELECT NameID, Mode

    FROM @t

    CROSS APPLY (

    VALUES (CASE A WHEN 1 THEN 'A' ELSE NULL END)

    ,(CASE B WHEN 1 THEN 'B' ELSE NULL END)

    ,(CASE C WHEN 1 THEN 'C' ELSE NULL END)

    ,(CASE D WHEN 1 THEN 'D' ELSE NULL END)) x(Mode)

    WHERE Mode IS NOT NULL

    That my friends, is my stupid SQL trick for this Friday afternoon!


    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