TSQL Subtotalling

  • Please forgive my ignorance if this is a simple fix but I am having a brain cramp. The goal: derive new records with subtotals of a recordset.

    Source recordset:

    index, workcode, value

    1, CL, 5

    2, CL, 10

    3, CL, 10

    4, LI, 10

    5, LI, 10

    6, ME, 5

    7, ME, 5

    8, CL, 10

    9, CL, 10

    10, CL, 5

    11, ME, 10

    12, ME, 10

    Output:

    1, CL, 25

    4, LI, 20

    6, ME, 10

    8, CL, 25

    11, ME, 20

    Notice that each break of the code is what triggers a new output record. Any assistance on TSQL code for accomplishing this would be greatly appreciated.

    Thanks in advance!

  • Oops, bad code deleted!

    If you haven't even tried to resolve your issue, please don't expect the hard-working volunteers here to waste their time providing links to answers which you could easily have found yourself.

  • Using the technique here http://www.sqlservercentral.com/articles/T-SQL/71550/

    WITH SourceRecordset AS (

    SELECT [index], workcode, value

    FROM (

    VALUES(1, 'CL', 5),

    (2, 'CL', 10),

    (3, 'CL', 10),

    (4, 'LI', 10),

    (5, 'LI', 10),

    (6, 'ME', 5),

    (7, 'ME', 5),

    (8, 'CL', 10),

    (9, 'CL', 10),

    (10, 'CL', 5),

    (11, 'ME', 10),

    (12, 'ME', 10)

    ) d([index], workcode, value)

    ),

    Grouped AS (

    SELECT [index], workcode, value,

    ROW_NUMBER() OVER(ORDER BY [index])-

    ROW_NUMBER() OVER(PARTITION BY workcode ORDER BY [index]) AS rnDiff

    FROM SourceRecordset)

    SELECT MIN([index]) AS [index],

    workcode,

    SUM(value) AS value

    FROM Grouped

    GROUP BY workcode,rnDiff

    ORDER BY MIN([index]);

    ____________________________________________________

    Deja View - The strange feeling that somewhere, sometime you've optimised this query before

    How to get the best help on a forum

    http://www.sqlservercentral.com/articles/Best+Practices/61537
  • Thank you for this. I will test it on my system to verify that I am getting the desired results.

  • Your solution worked perfectly! Thank you!

  • Mark - I'm not sure why you used two window functions:

    WITH SourceRecordset AS (

    SELECT [index], workcode, value

    FROM (

    VALUES(1, 'CL', 5),

    (2, 'CL', 10),

    (3, 'CL', 10),

    (4, 'LI', 10),

    (5, 'LI', 10),

    (6, 'ME', 5),

    (7, 'ME', 5),

    (8, 'CL', 10),

    (9, 'CL', 10),

    (10, 'CL', 5),

    (11, 'ME', 10),

    (12, 'ME', 10)

    ) d([index], workcode, value)

    )

    SELECT [index]=MIN([index]), workcode=MAX(workcode), value=SUM(value)

    FROM (

    SELECT [index], workcode, value

    ,rn=[index]-ROW_NUMBER() OVER (PARTITION BY workcode ORDER BY [index])

    FROM SourceRecordset) a

    GROUP BY rn

    ORDER BY [index]


    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 (1/20/2013)


    Mark - I'm not sure why you used two window functions:

    WITH SourceRecordset AS (

    SELECT [index], workcode, value

    FROM (

    VALUES(1, 'CL', 5),

    (2, 'CL', 10),

    (3, 'CL', 10),

    (4, 'LI', 10),

    (5, 'LI', 10),

    (6, 'ME', 5),

    (7, 'ME', 5),

    (8, 'CL', 10),

    (9, 'CL', 10),

    (10, 'CL', 5),

    (11, 'ME', 10),

    (12, 'ME', 10)

    ) d([index], workcode, value)

    )

    SELECT [index]=MIN([index]), workcode=MAX(workcode), value=SUM(value)

    FROM (

    SELECT [index], workcode, value

    ,rn=[index]-ROW_NUMBER() OVER (PARTITION BY workcode ORDER BY [index])

    FROM SourceRecordset) a

    GROUP BY rn

    ORDER BY [index]

    Sure, but that requires [index] to be contiguous- it wasn't clear from OP whether than was the case.

    ____________________________________________________

    Deja View - The strange feeling that somewhere, sometime you've optimised this query before

    How to get the best help on a forum

    http://www.sqlservercentral.com/articles/Best+Practices/61537

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

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