Compare this years data with last years data - day adjusted

  • Hi all

    our business get orders through the week with the weekends (Fri & Sat) orders being higher than weekdays. Im wanting to graph this years data with last years and possible the years before but to compare days in such a way that the all the weekdays line up. so comparing 2015 week 1 with 2014 week 1 but with 03/01/2015 (Sat) lining up with 04/01/2014 (Sat) etc.

    I'm looking for alternatives to adding or removing days from the dates to solve this issue, i have a date dimension table for the past 5 years that i can use to compare calendar week 201401 with calendar week 201501 but im finding it a bit inflexable. Has anyone else ever had this problem.

    Many thanks.

  • Shouldn't you be able to join on WeekOfYear and DayOfWeek? Then you should be golden, right?

    Sounds like you might be missing some columns in your Calendar table. Can you post the create table script of the Calendar table?

  • Use ISOWEEK for this.

    --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)

  • It's much easier to visualize with data.

    Try this for example:

    DECLARE @test-2 TABLE(myDate DATE, Sales MONEY)

    INSERT INTO @test-2(myDate, Sales)

    VALUES

    ('12/30/2013',100),

    ('12/31/2013',100),

    ('01/01/2014',100),

    ('01/02/2014',100),

    ('01/03/2014',200),

    ('01/04/2014',200),

    ('01/05/2014',100),

    ('01/06/2014',100),

    ('01/07/2014',100),

    ('01/08/2014',100),

    ('01/09/2014',100),

    ('01/10/2014',250),

    ('01/11/2014',250),

    ('01/01/2015',100),

    ('01/02/2015',150),

    ('01/03/2015',150),

    ('01/04/2015',100),

    ('01/05/2015',100),

    ('01/06/2015',100),

    ('01/07/2015',100),

    ('01/08/2015',100),

    ('01/09/2015',300),

    ('01/10/2015',300)

    SELECT *, DATEPART(dw, myDate) AS Day_Week, DATEPART(isowk, myDate) AS Week_Num FROM @test-2

    SELECT DATEPART(isowk, myDate) AS Week_Num, DATEPART(yyyy, myDate) AS [Year], SUM(Sales) AS TotalSales

    FROM @test-2

    WHERE DATEPART(dw, myDate) IN (6,7) --Friday and Saturday Only

    GROUP BY DATEPART(isowk, myDate), DATEPART(yyyy, myDate)

    You can use whatever predicate you want based on your needs. I just used this example to demonstrate grouping up Fridays and Saturdays over multiple years.


    SELECT quote FROM brain WHERE original = 1
    0 rows returned

  • many thanks guys ISOWEEK was spot on, never knew about that.

  • ps_vbdev (5/26/2015)


    many thanks guys ISOWEEK was spot on, never knew about that.

    Thanks for the feedback. Just remember that some years have 52 weeks and some have 53. It's the nature of the year being 52.17 weeks long on average. For comparing the last week of each year, you might want to consider using the maximum week of the year.

    --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 6 posts - 1 through 5 (of 5 total)

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