Click here to Skip to main content
15,889,315 members
Articles / Programming Languages / SQL
Article

Generate Date Table in SQL Server

Rate me:
Please Sign up or sign in to vote.
2.44/5 (6 votes)
1 Jun 2008CPOL 50.6K   13   7
Generate Date Table in SQL Server

Background

In many reports, one of the axis will be the a date range, either monthly or daily. However, there may be no data in a specific month or on a specific day. There will be no record when joining different tables. For example, if no user on 2008-05-03, the row of 2008-05-03 will not appear


DateNumber of User
2008-05-013
2008-05-025
2008-05-046

This SQL script generates a date range for left/right joining other tables so the result will include date with no data.

DateNumber of User
2008-05-013
2008-05-02
5
2008-05-030
2008-05-04
6
Create Function dbo.fnDateTable
(
  @StartDate datetime,
  @EndDate datetime,
  @DayPart char(5) -- support 'day','month','year','hour', default 'day'
)
Returns @Result Table
(
  [Date] datetime
)
As
Begin
  Declare @CurrentDate datetime
  Set @CurrentDate=@StartDate
  While @CurrentDate<=@EndDate
  Begin
    Insert Into @Result Values (@CurrentDate)
    Select @CurrentDate=
    Case
    When @DayPart='year' Then DateAdd(yy,1,@CurrentDate)
    When @DayPart='month' Then DateAdd(mm,1,@CurrentDate)
    When @DayPart='hour' Then DateAdd(hh,1,@CurrentDate)
    Else
      DateAdd(dd,1,@CurrentDate)
    End
  End
  Return
End

Points of Interest

Parameterized User-defined function is very useful. And caller to the function can use the result directly just like a table.

License

This article, along with any associated source code and files, is licensed under The Code Project Open License (CPOL)


Written By
Web Developer
Hong Kong Hong Kong
A .NET Programmer for 8 years, who wants to share the experience.

Comments and Discussions

 
GeneralA more robust approach based on SQL Guru Jeff Moden's numbers table Pin
astanton19783-Jun-08 2:43
astanton19783-Jun-08 2:43 
GeneralRe: A more robust approach based on SQL Guru Jeff Moden's numbers table Pin
WPKF3-Jun-08 16:30
WPKF3-Jun-08 16:30 
GeneralRe: A more robust approach based on SQL Guru Jeff Moden's numbers table Pin
astanton19784-Jun-08 5:32
astanton19784-Jun-08 5:32 
GeneralRe: A more robust approach based on SQL Guru Jeff Moden's numbers table Pin
Jeff Moden13-Sep-09 15:50
Jeff Moden13-Sep-09 15:50 
WPKF wrote:
I tried my while loop and it can generate the 30 year of day in 2 seconds too.


Agreed... but the estimate on how long the Tally table version would take was way too high (proof lies below). Further, a While loop doesn't allow for the very high speed TVF form of a user defined function. Take a look at the following equivalent code...

 CREATE FUNCTION dbo.jbmDateTable
     -- Created by Jeff Moden
        (
        @StartDate DATETIME,
        @EndDate   DATETIME,
        @DayPart   VARCHAR(5) -- support 'day','month','year','hour', default 'day'
        )
RETURNS TABLE
     AS
 RETURN
(
         WITH cteTally AS
        (
         SELECT TOP (
                     CASE @DayPart 
                     WHEN 'day'   THEN DATEDIFF(dd,@StartDate,@EndDate)
                     WHEN 'month' THEN DATEDIFF(mm,@StartDate,@EndDate)
                     WHEN 'year'  THEN DATEDIFF(yy,@StartDate,@EndDate)
                     WHEN 'hour'  THEN DATEDIFF(hh,@StartDate,@EndDate)
                     END  + 1
                     )
                ROW_NUMBER() OVER (ORDER BY GETDATE())-1 AS N
           FROM Master.sys.All_Columns sc1
          CROSS JOIN Master.sys.All_Columns sc2
        )
         SELECT CASE @DayPart 
                WHEN 'day'   THEN DATEADD(dd,t.N,@StartDate)
                WHEN 'month' THEN DATEADD(mm,t.N,@StartDate)
                WHEN 'year'  THEN DATEADD(yy,t.N,@StartDate)
                WHEN 'hour'  THEN DATEADD(hh,t.N,@StartDate)
                 END AS Date
           FROM cteTally t
)
;


Like your code, the code above provides the correct date info and doesn't use a permanent Tally table, but that's where the similarity ends. When I run the code below on my 7 year old 1.8GHz single CPU box...
 PRINT '========== Original Function =========='
   SET STATISTICS TIME ON
SELECT * FROM dbo.fnDateTable('20000101','20300101','day')
   SET STATISTICS TIME OFF

 PRINT '========== cteTally Function =========='
   SET STATISTICS TIME ON
SELECT * FROM dbo.jbmDateTable('20000101','20300101','day')
   SET STATISTICS TIME OFF


... here's what I get for stats...
========== Original Function ==========

(10959 row(s) affected)

SQL Server Execution Times:
   CPU time = 2140 ms,  elapsed time = 3575 ms.
========== cteTally Function ==========

(10959 row(s) affected)

SQL Server Execution Times:
   CPU time = 16 ms,  elapsed time = 323 ms.


Please, folks... treat 99.99% of all While Loops like drugs... Just say "NO!" Wink | ;) If you can't think of a way to do something without a While Loop, get on a good SQL Server forum and ask an expert how to do it with a Tally or Numbers table. Except for certain control loops (not RBAR), there's no reason to use While Loops.

p.s. Truth be told, except for demonstration purposes, I'd never write a function for this... direct code will be even faster because there will be no CASE statements.
GeneralVery large hammer Pin
Chris Maunder2-Jun-08 2:12
cofounderChris Maunder2-Jun-08 2:12 
GeneralRe: Very large hammer Pin
Member 14586602-Jun-08 3:13
Member 14586602-Jun-08 3:13 
GeneralRe: Very large hammer Pin
WPKF2-Jun-08 15:45
WPKF2-Jun-08 15:45 

General General    News News    Suggestion Suggestion    Question Question    Bug Bug    Answer Answer    Joke Joke    Praise Praise    Rant Rant    Admin Admin   

Use Ctrl+Left/Right to switch messages, Ctrl+Up/Down to switch threads, Ctrl+Shift+Left/Right to switch pages.