|
| 1 | +use w |
| 2 | +go |
| 3 | +DROP TABLE IF EXISTS dbo.DimDate |
| 4 | +GO |
| 5 | + |
| 6 | +CREATE TABLE dbo.DimDate ( |
| 7 | + [dimDateID] INT NOT NULL, |
| 8 | + [CalendarDate] DATE NOT NULL, |
| 9 | + [Day_of_Month] TINYINT NOT NULL, |
| 10 | + [Day_of_Year] SMALLINT NOT NULL, |
| 11 | + [Day_of_Week] TINYINT NOT NULL, |
| 12 | + [Year] SMALLINT NOT NULL, |
| 13 | + [Quarter] CHAR (2) NOT NULL, |
| 14 | + [Month] TINYINT NOT NULL, |
| 15 | + [Month_Name] VARCHAR (30) NOT NULL, |
| 16 | + [Week_of_Year] TINYINT NOT NULL, |
| 17 | + [DayOfWeek_Month] TINYINT NOT NULL, |
| 18 | + [DayofWeek_Name] VARCHAR (30) NOT NULL, |
| 19 | + [ISOWeek_of_Year] TINYINT NOT NULL, |
| 20 | + [FirstDay_Month] DATE NOT NULL, |
| 21 | + [LastDay_Month] DATE NOT NULL, |
| 22 | + [FirstDay_Year] DATE NOT NULL, |
| 23 | + [IsWeekend] CHAR (3) NOT NULL, |
| 24 | + [IsHoliday] BIT NULL, |
| 25 | + [HolidayText] VARCHAR(64) NULL, |
| 26 | + CONSTRAINT [PK_WH_DimDate] PRIMARY KEY NONCLUSTERED ([CalendarDate] ASC) WITH (DATA_COMPRESSION = PAGE), |
| 27 | + CONSTRAINT [IDX_NC_DimDate_DimDateID] UNIQUE CLUSTERED ([dimDateID] ASC) WITH (DATA_COMPRESSION = PAGE) |
| 28 | +); |
| 29 | +go |
| 30 | + |
| 31 | +--Bad |
| 32 | +--Antipattern. Takes forever. |
| 33 | +DROP TABLE IF EXISTS #DimDate |
| 34 | +CREATE TABLE #DimDate (Seeddate date); |
| 35 | + |
| 36 | +INSERT INTO #DimDate (seeddate) |
| 37 | +select seeddate = convert(date, '1/1/2000'); |
| 38 | + |
| 39 | +While (Select TOP 1 dateadd(day, 1, seeddate) from #DimDate) < '1/1/2050' |
| 40 | +INSERT INTO #DimDate |
| 41 | + select TOP 1 dateadd(day, 1, seeddate) |
| 42 | + from #DimDate |
| 43 | + ORDER BY seeddate desc; |
| 44 | + |
| 45 | + |
| 46 | + |
| 47 | +--Better |
| 48 | + |
| 49 | +TRUNCATE TABLE dbo.DimDate; |
| 50 | + |
| 51 | + |
| 52 | +SET STATISTICS IO ON |
| 53 | +DROP TABLE IF EXISTS #DimDate |
| 54 | +CREATE TABLE #DimDate (Seeddate date) |
| 55 | + |
| 56 | +;with cteDate (seeddate) as |
| 57 | + ( |
| 58 | + select seeddate = convert(date, '1/1/2000') |
| 59 | + UNION ALL |
| 60 | + select dateadd(day, 1, seeddate) |
| 61 | + from cteDate |
| 62 | + where seeddate < '1/1/2050' |
| 63 | + ) |
| 64 | +INSERT INTO #DimDate |
| 65 | +SELECT seeddate from cteDate |
| 66 | +OPTION (MAXRECURSION 0); |
| 67 | + |
| 68 | +insert into dbo.DimDate (dimDateID, CalendarDate, Day_of_Month, Day_of_Year, Day_of_Week, Year, Quarter, Month, Month_Name, DayOfWeek_Month, Week_of_Year, DayofWeek_Name, ISOWeek_of_Year, FirstDay_Month, LastDay_Month, FirstDay_Year, IsWeekend) |
| 69 | + select |
| 70 | + dimDateID = convert(int,convert(varchar(8),seeddate, 112)) |
| 71 | + , CalendarDate = seeddate |
| 72 | + , Day_of_Month = DatePart(d, seeddate) |
| 73 | + , Day_of_Year = DatePart(dy, seeddate) |
| 74 | + , Day_of_Week = DatePart(dw, seeddate) |
| 75 | + , [Year] = DatePart(yyyy, seeddate) |
| 76 | + , [Quarter] = 'Q' + Convert(char(1), datepart(quarter , seeddate)) |
| 77 | + , [Month] = DatePart(M, seeddate) |
| 78 | + , [Month_Name] = DateName(m, seeddate) |
| 79 | + , [DayOfWeek_Month] = CONVERT(TINYINT, ROW_NUMBER() OVER |
| 80 | + (PARTITION BY (CONVERT(DATE, DATEADD(MONTH, DATEDIFF(MONTH, 0, seeddate), 0))), DatePart(dw, seeddate) ORDER BY seeddate)) |
| 81 | + , Week_of_Year = DatePart(week, seeddate) |
| 82 | + , DayofWeek_Name = DateName(dw, seeddate) |
| 83 | + , ISOWeek_of_Year = DatePart(ISO_WEEK, seeddate) |
| 84 | + , [FirstDay_Month] = CONVERT(DATE, DATEADD(MONTH, DATEDIFF(MONTH, 0, seeddate), 0)) |
| 85 | + , [LastDay_Month] = MAX(seeddate) OVER (PARTITION BY DatePart(yyyy, seeddate), DatePart(M, seeddate)) |
| 86 | + , [FirstDay_Year] = CONVERT(DATE, DATEADD(YEAR, DATEDIFF(YEAR, 0, seeddate), 0)) |
| 87 | + , IsWeekend = CASE WHEN DatePart(dw, seeddate) in (1,7) THEN 'Yes' ELSE 'No' END |
| 88 | +from #DimDate |
| 89 | +where seeddate < '1/1/2050' |
| 90 | +SET STATISTICS IO OFF |
| 91 | +GO |
| 92 | + |
| 93 | + |
| 94 | + |
| 95 | + |
| 96 | + |
| 97 | + |
| 98 | + |
| 99 | + |
| 100 | +--Best |
| 101 | +-- |
| 102 | +--Takes 2-3s to create 18263 records |
| 103 | + |
| 104 | +TRUNCATE TABLE dbo.DimDate; |
| 105 | +SET STATISTICS IO ON |
| 106 | +;with cteDate (seeddate) as |
| 107 | + ( |
| 108 | + select seeddate = convert(date, '1/1/2000') |
| 109 | + UNION ALL |
| 110 | + select dateadd(day, 1, seeddate) |
| 111 | + from cteDate |
| 112 | + where seeddate < '1/1/2050' |
| 113 | +) |
| 114 | + |
| 115 | +insert into dbo.DimDate (dimDateID, CalendarDate, Day_of_Month, Day_of_Year, Day_of_Week, Year, Quarter, Month, Month_Name, DayOfWeek_Month, Week_of_Year, DayofWeek_Name, ISOWeek_of_Year, FirstDay_Month, LastDay_Month, FirstDay_Year, IsWeekend) |
| 116 | + select |
| 117 | + dimDateID = convert(int,convert(varchar(8),seeddate, 112)) |
| 118 | + , CalendarDate = seeddate |
| 119 | + , Day_of_Month = DatePart(d, seeddate) |
| 120 | + , Day_of_Year = DatePart(dy, seeddate) |
| 121 | + , Day_of_Week = DatePart(dw, seeddate) |
| 122 | + , [Year] = DatePart(yyyy, seeddate) |
| 123 | + , [Quarter] = 'Q' + Convert(char(1), datepart(quarter , seeddate)) |
| 124 | + , [Month] = DatePart(M, seeddate) |
| 125 | + , [Month_Name] = DateName(m, seeddate) |
| 126 | + , [DayOfWeek_Month] = CONVERT(TINYINT, ROW_NUMBER() OVER |
| 127 | + (PARTITION BY (CONVERT(DATE, DATEADD(MONTH, DATEDIFF(MONTH, 0, seeddate), 0))), DatePart(dw, seeddate) ORDER BY seeddate)) |
| 128 | + , Week_of_Year = DatePart(week, seeddate) |
| 129 | + , DayofWeek_Name = DateName(dw, seeddate) |
| 130 | + , ISOWeek_of_Year = DatePart(ISO_WEEK, seeddate) |
| 131 | + , [FirstDay_Month] = CONVERT(DATE, DATEADD(MONTH, DATEDIFF(MONTH, 0, seeddate), 0)) |
| 132 | + , [LastDay_Month] = MAX(seeddate) OVER (PARTITION BY DatePart(yyyy, seeddate), DatePart(M, seeddate)) |
| 133 | + , [FirstDay_Year] = CONVERT(DATE, DATEADD(YEAR, DATEDIFF(YEAR, 0, seeddate), 0)) |
| 134 | + , IsWeekend = CASE WHEN DatePart(dw, seeddate) in (1,7) THEN 'Yes' ELSE 'No' END |
| 135 | +from cteDate |
| 136 | +where seeddate < '1/1/2050' |
| 137 | +OPTION (MAXRECURSION 0); |
| 138 | +SET STATISTICS IO OFF |
| 139 | +GO |
| 140 | + |
| 141 | + |
| 142 | + |
0 commit comments