T-SQL return record for every day of year

  • I'm having a hard time explaining my intentions here. I will do my best. Hopefully someone can read my mind. LOL

    I have a table with one record per month. For example:

    Month Price

    1/1/09 50

    2/1/09 58

    3/1/09 65

    I want to write a query that will duplicate each month's record and return a record for every day of the year. So, using above example, bring back this:

    1/1/09 50

    1/2/09 50

    1/3/09 50

    duplicated all the way thru 1/31/09

    2/1/09 58

    2/2/09 58

    2/3/09 58

    duplicated all the way thru 2/28/09

    I could join my table by month/year to another static table that just had all the days of the year in it. But I was hoping to avoid creating and remembering to maintain such a table every year.

    Thanks.

    Joel

  • Joel you are on the right track; you'll need to join against another table, but it doesn't necessarily need to be a real calendar table. you can use a Tally or Numbers table;

    here is an example of an inline Tally table tat is being used to generate days with some data function.

    then the code is generating balances for all the days that were not featured in the data...similar to what you are planning;

    example results:

    TranDateTransactionAmountBalance

    2008-12-01 00:00:00.000100.00100.00

    2008-12-02 00:00:00.0000.00100.00

    2008-12-03 00:00:00.000-60.0040.00

    2008-12-04 00:00:00.00010.0050.00

    2008-12-05 00:00:00.0000.0050.00

    2008-12-06 00:00:00.0000.0050.00

    the code example:

    SET DATEFORMAT MDY

    DROP TABLE #myBalances

    CREATE TABLE #myBalances (

    [TranDate] DATETIME,

    [TransactionAmount] money,

    [Balance] money)

    INSERT INTO #myBalances VALUES ('12/1/2008',100,100)

    INSERT INTO #myBalances VALUES ('12/3/2008',-60,40)

    INSERT INTO #myBalances VALUES ('12/4/2008',10,50)

    DECLARE @StartDate DATETIME, @EndDate DATETIME

    SET @StartDate = '12/1/2008'

    SET @EndDate = '12/6/2008'

    ;with TallyCalendar as (

    --5 years prior to today plus 5 years after

    SELECT dateadd( dd, -3650 + RW ,DATEADD(dd, DATEDIFF(dd,0,getdate()), 0)) As N

    FROM (

    SELECT TOP 7300 -- ~10 years of days

    row_number() OVER (ORDER BY sc1.id) AS RW

    FROM Master.dbo.SysColumns sc1

    CROSS JOIN Master.dbo.SysColumns sc2

    ) X

    )

    SELECT DATEADD(DD, 0, Tally.n) AS TranDate, ISNULL(b.TransactionAmount, 0) AS TransactionAmount, x.Balance

    FROM TallyCalendar Tally

    LEFT JOIN #myBalances b ON b.TranDate = DATEADD(DD, 0, Tally.n)

    LEFT JOIN #myBalances x ON x.TranDate = (SELECT MAX(TranDate) AS TranDate FROM #myBalances WHERE TranDate <= DATEADD(DD, 0, Tally.n))

    WHERE n BETWEEN DATEDIFF(DD, 0, @StartDate) AND DATEDIFF(DD, 0, @EndDate)

    Lowell


    --help us help you! If you post a question, make sure you include a CREATE TABLE... statement and INSERT INTO... statement into that table to give the volunteers here representative data. with your description of the problem, we can provide a tested, verifiable solution to your question! asking the question the right way gets you a tested answer the fastest way possible!

  • hughesj23 (2/1/2010)


    I could join my table by month/year to another static table that just had all the days of the year in it. But I was hoping to avoid creating and remembering to maintain such a table every year.

    Thanks.

    Joel

    Create a scheduled job to run at the end of each month or year to add the values for the upcoming month or year.



    Alvin Ramard
    Memphis PASS Chapter[/url]

    All my SSC forum answers come with a money back guarantee. If you didn't like the answer then I'll gladly refund what you paid for it.

    For best practices on asking questions, please read the following article: Forum Etiquette: How to post data/code on a forum to get the best help[/url]

  • USE tempdb;

    DECLARE @data

    TABLE (

    input_month DATETIME NOT NULL,

    price MONEY

    );

    INSERT @data

    VALUES ('20090101', $50.00),

    ('20090201', $58.00),

    ('20090301', $65.00);

    SELECT Days.output_date,

    D.price

    FROM @data D

    CROSS

    JOIN (

    VALUES (00), (01), (02), (03), (04), (05), (06), (07), (08), (09),

    (10), (11), (12), (13), (14), (15), (16), (17), (18), (19),

    (20), (21), (22), (23), (24), (25), (26), (27), (28), (29), (30)

    ) DayOffset (n)

    CROSS

    APPLY (SELECT DATEADD(DAY, DayOffset.n, D.input_month)) Days (output_date)

    WHERE MONTH(Days.output_date) = MONTH(D.input_month);

    edit: Fixed!

  • Paul, nice solution! However, the first day of the month is missing. Either subtract 1 from DayOffset.n as the parameter for the dateadd function or use a zero-based DayOffset (0-30) will fix it.

    Peter

  • Peter Brinkhaus (2/2/2010)


    Paul, nice solution! However, the first day of the month is missing. Either subtract 1 from DayOffset.n as the parameter for the dateadd function or use a zero-based DayOffset (0-30) will fix it.

    Darn it!!! :w00t:

    Fixed - thanks for the great catch!

  • Good stuff. This has gotten the wheels turning. Thank you all.

  • With the introduction of CTEs is SQL 2005 it made it a lot easier to create a record for every date in a range.

    WITH Dates AS (

    SELECT

    [Date] = CONVERT(DATETIME,'01/01/2010')

    UNION ALL SELECT

    [Date] = DATEADD(DAY, 1, [Date])

    FROM

    Dates

    WHERE

    Date < '12/31/2010'

    ) SELECT

    [Date]

    FROM

    Dates

    OPTION (MAXRECURSION 400)

    ]

  • Beware, recursive CTEs can perform poorly. See here[/url]

  • Hi,

    IMHO it is worthwhile having a calendar table (often called a time dimension in data warehousing lingo), particularly to support reporting with external tools. (Tools beyond T-SQL, I mean.)

    This http://www.sqlservercentral.com/scripts/Date/68389/ is a good recent article which would get you up and running. We have a large shared calendar table which is always being extended with new clients' week, month and year periods, etc. (Good practice for date arithmetic.;-)) HTH

Viewing 10 posts - 1 through 9 (of 9 total)

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