sql query to find the difference in values from previous month

  • I have my sql tables and query as shown below :

    CREATE TABLE #ABC([Year] INT, [Month] INT, Stores INT);

    CREATE TABLE #DEF([Year] INT, [Month] INT, SalesStores INT);

    CREATE TABLE #GHI([Year] INT, [Month] INT, Products INT);

    INSERT #ABC VALUES (2013,1,1);

    INSERT #ABC VALUES (2013,1,2);

    INSERT #ABC VALUES (2013,2,3);

    INSERT #DEF VALUES (2013,1,4);

    INSERT #DEF VALUES (2013,1,5);

    INSERT #DEF VALUES (2013,2,6);

    INSERT #GHI VALUES (2013,1,7);

    INSERT #GHI VALUES (2013,1,8);

    INSERT #GHI VALUES (2013,2,9);

    INSERT #GHI VALUES (2013,3,10);

    My current query is

    I have @Year and @Month as parameters , both integers , example @Year = '2013' , @Month = '11'

    SELECT T.[Year],

    T.[Month]

    -- select the sum for each year/month combination using a correlated subquery (each result from the main query causes another data retrieval operation to be run)

    ,

    (SELECT SUM(Stores)

    FROM #ABC

    WHERE [Year] = T.[Year]

    AND [Month] = T.[Month]) AS [Sum_Stores],

    (SELECT SUM(SalesStores)

    FROM #DEF

    WHERE [Year] = T.[Year]

    AND [Month] = T.[Month]) AS [Sum_SalesStores],

    (SELECT SUM(Products)

    FROM #GHI

    WHERE [Year] = T.[Year]

    AND [Month] = T.[Month]) AS [Sum_Products]

    FROM (

    -- this selects a list of all possible dates.

    SELECT [Year],

    [Month]

    FROM #ABC where [Year] = @Year and [Month] = @Month

    UNION

    SELECT [Year],

    [Month]

    FROM #DEF where [Year] = @Year and [Month] = @Month

    UNION

    SELECT [Year],

    [Month]

    FROM #GHI where [Year] = @Year and [Month] = @Month) AS T;

    Which returns

    +------+-------+------------+-----------------+--------------+

    | Year | Month | Sum_Stores | Sum_SalesStores | Sum_Products |

    +------+-------+------------+-----------------+--------------+

    | 2013 | | | | |

    | 2013 | | | | |

    | 2013 | | | | |

    +------+-------+------------+-----------------+--------------+

    What I want to do is to add more columns to the query which show the difference from the last month. as shown below. Example : The Diff beside the Sum_Stores shows the difference in the Sum_Stores from last month to this month.

    Something like this :

    +------+-------+------------+-----------------+-----|-----|---+-----------------

    | Year | Month | Sum_Stores |Diff | Sum_SalesStores |Diff | Sum_Products |Diff|

    +------+-------+------------+-----|------------+----|---- |----+--------------|

    | 2013 | | | | | | | |

    | 2013 | | | | | | | |

    | 2013 | | | | | | | |

    +------+-------+------------+-----|------------+--- |-----|----+---------| ----

    Can anyone tell me how I can modify this to achive my goal.

  • Have you looked at the new LAG and LEAD windowing functions?

    John

  • First of all, you should avoid using integers to store dates, even if they are just partial as month and year. You get in lots of trouble when calculating change of years (in this case).

    Here's a possible solution but something else might be better.

    --Parameters

    DECLARE @Year int = 2013,

    @Month int = 2;

    --Variables for previous dates

    DECLARE@PrevYear int,

    @PrevMonth int;

    SELECT @PrevYear = YEAR( DATEADD( MONTH, @Month - 2, CAST( CAST( @Year AS CHAR(4)) AS datetime))),

    @PrevMonth = MONTH( DATEADD( MONTH, @Month - 2, CAST( CAST( @Year AS CHAR(4)) AS datetime)))

    SELECT @Year AS [Year],

    @Month AS [Month],

    MAX( CASE WHEN [Month] = @Month AND [Description] = 'Stores' THEN Value END) AS [SumStores],

    MAX( CASE WHEN [Month] = @Month AND [Description] = 'Stores' THEN Value END) -

    MAX( CASE WHEN [Month] = @PrevMonth AND [Description] = 'Stores' THEN Value END) AS [Diff],

    MAX( CASE WHEN [Month] = @Month AND [Description] = 'SalesStores' THEN Value END) AS [SumStores],

    MAX( CASE WHEN [Month] = @Month AND [Description] = 'SalesStores' THEN Value END) -

    MAX( CASE WHEN [Month] = @PrevMonth AND [Description] = 'SalesStores' THEN Value END) AS [Diff],

    MAX( CASE WHEN [Month] = @Month AND [Description] = 'Products' THEN Value END) AS [SumStores],

    MAX( CASE WHEN [Month] = @Month AND [Description] = 'Products' THEN Value END) -

    MAX( CASE WHEN [Month] = @PrevMonth AND [Description] = 'Products' THEN Value END) AS [Diff]

    FROM (

    -- this selects a list of all possible dates.

    SELECT [Year],

    [Month],

    SUM(Stores) Value,

    'Stores' Description

    FROM #ABC

    where ([Year] = @Year and [Month] = @Month)

    OR ([Year] = @PrevYear and [Month] = @PrevMonth)

    GROUP BY [Year], [Month]

    UNION

    SELECT [Year],

    [Month],

    SUM(SalesStores),

    'SalesStores' Description

    FROM #DEF

    where ([Year] = @Year and [Month] = @Month)

    OR ([Year] = @PrevYear and [Month] = @PrevMonth)

    GROUP BY [Year], [Month]

    UNION

    SELECT [Year],

    [Month],

    SUM(Products),

    'Products' Description

    FROM #GHI

    where ([Year] = @Year and [Month] = @Month)

    OR ([Year] = @PrevYear and [Month] = @PrevMonth)

    GROUP BY [Year], [Month]) AS T

    ;

    Luis C.
    General Disclaimer:
    Are you seriously taking the advice and code from someone from the internet without testing it? Do you at least understand it? Or can it easily kill your server?

    How to post data/code on a forum to get the best help: Option 1 / Option 2
  • John Mitchell-245523 (12/12/2013)


    Have you looked at the new LAG and LEAD windowing functions?

    John

    I agree with John that LAG would be pretty good for this:

    WITH Aggregates AS

    (

    SELECT [Year], [Month]

    ,SumStores=ISNULL(SUM(Stores), 0)

    ,SumSalesStores=ISNULL(SUM(SalesStores), 0)

    ,SumProducts=ISNULL(SUM(Products), 0)

    ,[Date]=DATEADD(month, [Month]-1, CAST([Year] AS CHAR(4)))

    FROM

    (

    SELECT [Year], [Month], Stores, SalesStores=NULL, Products=NULL

    FROM #ABC

    UNION ALL

    SELECT [Year], [Month], NULL, SalesStores, NULL

    FROM #DEF

    UNION ALL

    SELECT [Year], [Month], NULL, NULL, Products

    FROM #GHI

    ) a

    GROUP BY [Year], [Month]

    )

    SELECT [Year], [Month]

    ,SumStores

    ,DiffStores=CASE

    WHEN DATEDIFF(month, [Date], LastMonth) = -1

    THEN SumStores-LastStores

    WHEN LastMonth IS NULL THEN NULL

    ELSE SumStores END

    ,SumSalesStores

    ,DiffSalesStores=CASE

    WHEN DATEDIFF(month, [Date], LastMonth) = -1

    THEN SumStores-LastSalesStores

    WHEN LastMonth IS NULL THEN NULL

    ELSE SumStores END

    ,SumProducts

    ,DiffProducts=CASE

    WHEN DATEDIFF(month, [Date], LastMonth) = -1

    THEN SumStores-LastProducts

    WHEN LastMonth IS NULL THEN NULL

    ELSE SumStores END

    FROM

    (

    SELECT [Year], [Month], [Date], SumStores, SumSalesStores, SumProducts

    ,LastMonth=LAG([Date], 1) OVER (ORDER BY [Date])

    ,LastStores=LAG(SumStores, 1) OVER (ORDER BY [Date])

    ,LastSalesStores=LAG(SumStores, 1) OVER (ORDER BY [Date])

    ,LastProducts=LAG(SumStores, 1) OVER (ORDER BY [Date])

    FROM Aggregates

    ) a;

    That should be close to what you need.


    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 4 posts - 1 through 3 (of 3 total)

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