A Cross Tab query, sort of....

  • Hi Experts,

    It's Friday afternoon here in NZ and I'm looking at some code, that works fine, thinking "there's got to be a more elegant solution",

    but after pulling out what little hair I have left I thought I would use my "ask a friend" option, so....

    We have a set of data, where a Customer always has at least one Tariff attached and potentially four. Each Record / Tariff combination is a sperate row in a table. So the data appears like this [we have a little shy of 100,000 records in this table] -

    CustomerTariffTariffOrder

    Record1 1211

    Record1 1712

    Record1 1713

    Record2 1211

    Record2 1712

    Record3 1211

    Record4 1011

    Record5 1011

    Record5 1512

    Record5 1713

    Record5 1714

    Record6 1211

    Record6 1712

    Record7 1011

    Record8 1011

    Record8 1712

    Record8 1713

    Record9 1011

    Record10 1711

    But we have a requirement to report on the distinct combinations, so the report looks like this -

    Counttariff1tariff2tariff3tariff4

    3101NULLNULLNULL

    1101151171171

    1101171171NULL

    1121NULLNULLNULL

    2121171NULLNULL

    1121171171NULL

    1171NULLNULLNULL

    I've achieved this using a Temp table and a couple of update statements that performs adequately, but is there another solution? Perhaps one that could be flexible with the number of combinations?

    We are using SQL 2008 r2.

    Thank you for your time!

    And some code to create a limited set of sample data -

    create table #Cust

    (

    Customer char(10) not null,

    Tariff char(3) not null,

    TariffOrder tinyint not null

    )

    insert into #Cust (Customer, Tariff, TariffOrder) values

    ('Record1', '121', 1),

    ('Record1', '171', 2),

    ('Record1', '171', 3),

    ('Record2', '121', 1),

    ('Record2', '171', 2),

    ('Record3', '121', 1),

    ('Record4', '101', 1),

    ('Record5', '101', 1),

    ('Record5', '151', 2),

    ('Record5', '171', 3),

    ('Record5', '171', 4),

    ('Record6', '121', 1),

    ('Record6', '171', 2),

    ('Record7', '101', 1),

    ('Record8', '101', 1),

    ('Record8', '171', 2),

    ('Record8', '171', 3),

    ('Record9', '101', 1),

    ('Record10', '171', 1)

  • I'm no expert, but can I still reply?

    What you need is a crosstab query, which is pretty straightforward given a known number of tariffs and the fact that you even supplied a tariff order column.

    SELECT Customer, Count=COUNT(*)

    ,tariff1=MAX(CASE TariffOrder WHEN 1 THEN Tariff END)

    ,tariff2=MAX(CASE TariffOrder WHEN 2 THEN Tariff END)

    ,tariff3=MAX(CASE TariffOrder WHEN 3 THEN Tariff END)

    ,tariff4=MAX(CASE TariffOrder WHEN 4 THEN Tariff END)

    FROM #Cust

    GROUP BY Customer

    Very nice job of posting DDL, sample data and expected results by the way.


    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

  • Duplicate post deleted.


    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

  • Duplicate post deleted.


    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

  • Hi Dwain,

    Thanks for your reply, it's not quite what I'm after though.... Your solution appears to provide a count of the Tariffs for each Customer, I need to get a count of the Customers with a particular combination of Tariff. So from the sample data I would expect 7 rows with a count of the various Tariff combinations not 10, being the count of distinct Customers.

    Thanks for the post

  • This will do it. If you want the NULLs to show up instead of the blanks, just remove the ELSE '' from each line where it appears.

    WITH

    cteCrossTab AS

    (

    SELECT Customer,

    Tariff1 = MAX(CASE WHEN TariffOrder = 1 THEN Tariff ELSE '' END),

    Tariff2 = MAX(CASE WHEN TariffOrder = 2 THEN Tariff ELSE '' END),

    Tariff3 = MAX(CASE WHEN TariffOrder = 3 THEN Tariff ELSE '' END),

    Tariff4 = MAX(CASE WHEN TariffOrder = 4 THEN Tariff ELSE '' END)

    FROM #Cust

    GROUP BY Customer

    )

    SELECT [Count] = COUNT(*),

    Tariff1, Tariff2, Tariff3, Tariff4

    FROM cteCrossTab

    GROUP BY Tariff1, Tariff2, Tariff3, Tariff4

    ORDER BY Tariff1, Tariff2, Tariff3, Tariff4

    ;

    Results from the given data in the original post:

    Count Tariff1 Tariff2 Tariff3 Tariff4

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

    3 101

    1 101 151 171 171

    1 101 171 171

    1 121

    2 121 171

    1 121 171 171

    1 171

    (7 row(s) affected)

    --Jeff Moden


    RBAR is pronounced "ree-bar" and is a "Modenism" for Row-By-Agonizing-Row.
    First step towards the paradigm shift of writing Set Based code:
    ________Stop thinking about what you want to do to a ROW... think, instead, of what you want to do to a COLUMN.

    Change is inevitable... Change for the better is not.


    Helpful Links:
    How to post code problems
    How to Post Performance Problems
    Create a Tally Function (fnTally)

  • Jeff,

    Thank you for the elegant solution I was after.

    Intrigued, I added this code into a stored procedure and compared the performance against the existing, the average over 10 runs indicates that Jeff's solution is approximately twice as fast. Nice one!

    Thank you

  • SeanF-708538 (9/23/2012)


    Jeff,

    Thank you for the elegant solution I was after.

    Intrigued, I added this code into a stored procedure and compared the performance against the existing, the average over 10 runs indicates that Jeff's solution is approximately twice as fast. Nice one!

    Thank you

    Heh... twice as fast? I'm slipping up in my old age. 😛

    Thanks for the feedback, Sean.

    --Jeff Moden


    RBAR is pronounced "ree-bar" and is a "Modenism" for Row-By-Agonizing-Row.
    First step towards the paradigm shift of writing Set Based code:
    ________Stop thinking about what you want to do to a ROW... think, instead, of what you want to do to a COLUMN.

    Change is inevitable... Change for the better is not.


    Helpful Links:
    How to post code problems
    How to Post Performance Problems
    Create a Tally Function (fnTally)

Viewing 8 posts - 1 through 7 (of 7 total)

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