-
Notifications
You must be signed in to change notification settings - Fork 0
/
Copy pathDIM_DATE_DDL_DML.sql
407 lines (395 loc) · 21 KB
/
DIM_DATE_DDL_DML.sql
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
--===================================================
-------------DIM_DATE
--==================================================
-- Create table script for Dimension DIM_DATE
create or replace table DIM_DATE (
DATE_KEY number(9) PRIMARY KEY,
DATE date not null,
FULL_DATE_DESC varchar(64) not null,
DAY_NUM_IN_WEEK number(1) not null,
DAY_NUM_IN_MONTH number(2) not null,
DAY_NUM_IN_YEAR number(3) not null,
DAY_NAME varchar(10) not null,
DAY_ABBREV varchar(3) not null,
WEEKDAY_IND varchar(64) not null,
US_HOLIDAY_IND varchar(64) not null,
/*<COMPANYNAME>*/_HOLIDAY_IND varchar(64) not null,
MONTH_END_IND varchar(64) not null,
WEEK_BEGIN_DATE_NKEY number(9) not null,
WEEK_BEGIN_DATE date not null,
WEEK_END_DATE_NKEY number(9) not null,
WEEK_END_DATE date not null,
WEEK_NUM_IN_YEAR number(9) not null,
MONTH_NAME varchar(10) not null,
MONTH_ABBREV varchar(3) not null,
MONTH_NUM_IN_YEAR number(2) not null,
YEARMONTH varchar(10) not null,
QUARTER number(1) not null,
YEARQUARTER varchar(10) not null,
YEAR number(5) not null,
FISCAL_WEEK_NUM number(2) not null,
FISCAL_MONTH_NUM number(2) not null,
FISCAL_YEARMONTH varchar(10) not null,
FISCAL_QUARTER number(1) not null,
FISCAL_YEARQUARTER varchar(10) not null,
FISCAL_HALFYEAR number(1) not null,
FISCAL_YEAR number(5) not null,
SQL_TIMESTAMP timestamp_ntz,
CURRENT_ROW_IND char(1) default 'Y',
EFFECTIVE_DATE date default to_date(current_timestamp),
EXPIRATION_DATE date default To_date('9999-12-31')
)
comment = 'Type 0 Dimension Table Housing Calendar and Fiscal Year Date Attributes';
-- Populate data into DIM_DATE
insert into DIM_DATE
select DATE_PKEY,
DATE_COLUMN,
FULL_DATE_DESC,
DAY_NUM_IN_WEEK,
DAY_NUM_IN_MONTH,
DAY_NUM_IN_YEAR,
DAY_NAME,
DAY_ABBREV,
WEEKDAY_IND,
US_HOLIDAY_IND,
COMPANY_HOLIDAY_IND,
MONTH_END_IND,
WEEK_BEGIN_DATE_NKEY,
WEEK_BEGIN_DATE,
WEEK_END_DATE_NKEY,
WEEK_END_DATE,
WEEK_NUM_IN_YEAR,
MONTH_NAME,
MONTH_ABBREV,
MONTH_NUM_IN_YEAR,
YEARMONTH,
CURRENT_QUARTER,
YEARQUARTER,
CURRENT_YEAR,
FISCAL_WEEK_NUM,
FISCAL_MONTH_NUM,
FISCAL_YEARMONTH,
FISCAL_QUARTER,
FISCAL_YEARQUARTER,
FISCAL_HALFYEAR,
FISCAL_YEAR,
SQL_TIMESTAMP,
CURRENT_ROW_IND,
EFFECTIVE_DATE,
EXPIRA_DATE
from
( select to_date('2018-01-01 00:00:00','YYYY-MM-DD HH24:MI:SS') as DD, /*<<Modify date for preferred table start date*/
seq1() as Sl,row_number() over (order by Sl) as row_numbers,
dateadd(day,row_numbers,DD) as V_DATE,
case when date_part(dd, V_DATE) < 10 and date_part(mm, V_DATE) > 9 then
date_part(year, V_DATE)||date_part(mm, V_DATE)||'0'||date_part(dd, V_DATE)
when date_part(dd, V_DATE) < 10 and date_part(mm, V_DATE) < 10 then
date_part(year, V_DATE)||'0'||date_part(mm, V_DATE)||'0'||date_part(dd, V_DATE)
when date_part(dd, V_DATE) > 9 and date_part(mm, V_DATE) < 10 then
date_part(year, V_DATE)||'0'||date_part(mm, V_DATE)||date_part(dd, V_DATE)
when date_part(dd, V_DATE) > 9 and date_part(mm, V_DATE) > 9 then
date_part(year, V_DATE)||date_part(mm, V_DATE)||date_part(dd, V_DATE) end as DATE_PKEY,
V_DATE as DATE_COLUMN,
dayname(dateadd(day,row_numbers,DD)) as DAY_NAME_1,
case
when dayname(dateadd(day,row_numbers,DD)) = 'Mon' then 'Monday'
when dayname(dateadd(day,row_numbers,DD)) = 'Tue' then 'Tuesday'
when dayname(dateadd(day,row_numbers,DD)) = 'Wed' then 'Wednesday'
when dayname(dateadd(day,row_numbers,DD)) = 'Thu' then 'Thursday'
when dayname(dateadd(day,row_numbers,DD)) = 'Fri' then 'Friday'
when dayname(dateadd(day,row_numbers,DD)) = 'Sat' then 'Saturday'
when dayname(dateadd(day,row_numbers,DD)) = 'Sun' then 'Sunday' end ||', '||
case when monthname(dateadd(day,row_numbers,DD)) ='Jan' then 'January'
when monthname(dateadd(day,row_numbers,DD)) ='Feb' then 'February'
when monthname(dateadd(day,row_numbers,DD)) ='Mar' then 'March'
when monthname(dateadd(day,row_numbers,DD)) ='Apr' then 'April'
when monthname(dateadd(day,row_numbers,DD)) ='May' then 'May'
when monthname(dateadd(day,row_numbers,DD)) ='Jun' then 'June'
when monthname(dateadd(day,row_numbers,DD)) ='Jul' then 'July'
when monthname(dateadd(day,row_numbers,DD)) ='Aug' then 'August'
when monthname(dateadd(day,row_numbers,DD)) ='Sep' then 'September'
when monthname(dateadd(day,row_numbers,DD)) ='Oct' then 'October'
when monthname(dateadd(day,row_numbers,DD)) ='Nov' then 'November'
when monthname(dateadd(day,row_numbers,DD)) ='Dec' then 'December' end
||' '|| to_varchar(dateadd(day,row_numbers,DD), ' dd, yyyy') as FULL_DATE_DESC,
dateadd(day,row_numbers,DD) as V_DATE_1,
dayofweek(V_DATE_1)+1 as DAY_NUM_IN_WEEK,
Date_part(dd,V_DATE_1) as DAY_NUM_IN_MONTH,
dayofyear(V_DATE_1) as DAY_NUM_IN_YEAR,
case
when dayname(V_DATE_1) = 'Mon' then 'Monday'
when dayname(V_DATE_1) = 'Tue' then 'Tuesday'
when dayname(V_DATE_1) = 'Wed' then 'Wednesday'
when dayname(V_DATE_1) = 'Thu' then 'Thursday'
when dayname(V_DATE_1) = 'Fri' then 'Friday'
when dayname(V_DATE_1) = 'Sat' then 'Saturday'
when dayname(V_DATE_1) = 'Sun' then 'Sunday' end as DAY_NAME,
dayname(dateadd(day,row_numbers,DD)) as DAY_ABBREV,
case
when dayname(V_DATE_1) = 'Sun' and dayname(V_DATE_1) = 'Sat' then
'Not-Weekday'
else 'Weekday' end as WEEKDAY_IND,
case
when (DATE_PKEY = date_part(year, V_DATE)||'0101' or DATE_PKEY = date_part(year, V_DATE)||'0704' or
DATE_PKEY = date_part(year, V_DATE)||'1225' or DATE_PKEY = date_part(year, V_DATE)||'1226') then
'Holiday'
when monthname(V_DATE_1) ='May' and dayname(last_day(V_DATE_1)) = 'Wed'
and dateadd(day,-2,last_day(V_DATE_1)) = V_DATE_1 then
'Holiday'
when monthname(V_DATE_1) ='May' and dayname(last_day(V_DATE_1)) = 'Thu'
and dateadd(day,-3,last_day(V_DATE_1)) = V_DATE_1 then
'Holiday'
when monthname(V_DATE_1) ='May' and dayname(last_day(V_DATE_1)) = 'Fri'
and dateadd(day,-4,last_day(V_DATE_1)) = V_DATE_1 then
'Holiday'
when monthname(V_DATE_1) ='May' and dayname(last_day(V_DATE_1)) = 'Sat'
and dateadd(day,-5,last_day(V_DATE_1)) = V_DATE_1 then
'Holiday'
when monthname(V_DATE_1) ='May' and dayname(last_day(V_DATE_1)) = 'Sun'
and dateadd(day,-6,last_day(V_DATE_1)) = V_DATE_1 then
'Holiday'
when monthname(V_DATE_1) ='May' and dayname(last_day(V_DATE_1)) = 'Mon'
and last_day(V_DATE_1) = V_DATE_1 then
'Holiday'
when monthname(V_DATE_1) ='May' and dayname(last_day(V_DATE_1)) = 'Tue'
and dateadd(day,-1 ,last_day(V_DATE_1)) = V_DATE_1 then
'Holiday'
when monthname(V_DATE_1) ='Sep' and dayname(date_part(year, V_DATE_1)||'-09-01') = 'Wed'
and dateadd(day,5,(date_part(year, V_DATE_1)||'-09-01')) = V_DATE_1 then
'Holiday'
when monthname(V_DATE_1) ='Sep' and dayname(date_part(year, V_DATE_1)||'-09-01') = 'Thu'
and dateadd(day,4,(date_part(year, V_DATE_1)||'-09-01')) = V_DATE_1 then
'Holiday'
when monthname(V_DATE_1) ='Sep' and dayname(date_part(year, V_DATE_1)||'-09-01') = 'Fri'
and dateadd(day,3,(date_part(year, V_DATE_1)||'-09-01')) = V_DATE_1 then
'Holiday'
when monthname(V_DATE_1) ='Sep' and dayname(date_part(year, V_DATE_1)||'-09-01') = 'Sat'
and dateadd(day,2,(date_part(year, V_DATE_1)||'-09-01')) = V_DATE_1 then
'Holiday'
when monthname(V_DATE_1) ='Sep' and dayname(date_part(year, V_DATE_1)||'-09-01') = 'Sun'
and dateadd(day,1,(date_part(year, V_DATE_1)||'-09-01')) = V_DATE_1 then
'Holiday'
when monthname(V_DATE_1) ='Sep' and dayname(date_part(year, V_DATE_1)||'-09-01') = 'Mon'
and date_part(year, V_DATE_1)||'-09-01' = V_DATE_1 then
'Holiday'
when monthname(V_DATE_1) ='Sep' and dayname(date_part(year, V_DATE_1)||'-09-01') = 'Tue'
and dateadd(day,6 ,(date_part(year, V_DATE_1)||'-09-01')) = V_DATE_1 then
'Holiday'
when monthname(V_DATE_1) ='Nov' and dayname(date_part(year, V_DATE_1)||'-11-01') = 'Wed'
and (dateadd(day,23,(date_part(year, V_DATE_1)||'-11-01')) = V_DATE_1 or
dateadd(day,22,(date_part(year, V_DATE_1)||'-11-01')) = V_DATE_1 ) then
'Holiday'
when monthname(V_DATE_1) ='Nov' and dayname(date_part(year, V_DATE_1)||'-11-01') = 'Thu'
and ( dateadd(day,22,(date_part(year, V_DATE_1)||'-11-01')) = V_DATE_1 or
dateadd(day,21,(date_part(year, V_DATE_1)||'-11-01')) = V_DATE_1 ) then
'Holiday'
when monthname(V_DATE_1) ='Nov' and dayname(date_part(year, V_DATE_1)||'-11-01') = 'Fri'
and ( dateadd(day,21,(date_part(year, V_DATE_1)||'-11-01')) = V_DATE_1 or
dateadd(day,20,(date_part(year, V_DATE_1)||'-11-01')) = V_DATE_1 ) then
'Holiday'
when monthname(V_DATE_1) ='Nov' and dayname(date_part(year, V_DATE_1)||'-11-01') = 'Sat'
and ( dateadd(day,27,(date_part(year, V_DATE_1)||'-11-01')) = V_DATE_1 or
dateadd(day,26,(date_part(year, V_DATE_1)||'-11-01')) = V_DATE_1 ) then
'Holiday'
when monthname(V_DATE_1) ='Nov' and dayname(date_part(year, V_DATE_1)||'-11-01') = 'Sun'
and ( dateadd(day,26,(date_part(year, V_DATE_1)||'-11-01')) = V_DATE_1 or
dateadd(day,25,(date_part(year, V_DATE_1)||'-11-01')) = V_DATE_1 ) then
'Holiday'
when monthname(V_DATE_1) ='Nov' and dayname(date_part(year, V_DATE_1)||'-11-01') = 'Mon'
and (dateadd(day,25,(date_part(year, V_DATE_1)||'-11-01')) = V_DATE_1 or
dateadd(day,24,(date_part(year, V_DATE_1)||'-11-01')) = V_DATE_1 ) then
'Holiday'
when monthname(V_DATE_1) ='Nov' and dayname(date_part(year, V_DATE_1)||'-11-01') = 'Tue'
and (dateadd(day,24,(date_part(year, V_DATE_1)||'-11-01')) = V_DATE_1 or
dateadd(day,23,(date_part(year, V_DATE_1)||'-11-01')) = V_DATE_1 ) then
'Holiday'
else
'Not-Holiday' end as US_HOLIDAY_IND,
/*Modify the following for Company Specific Holidays*/
case
when (DATE_PKEY = date_part(year, V_DATE)||'0101' or DATE_PKEY = date_part(year, V_DATE)||'0219'
or DATE_PKEY = date_part(year, V_DATE)||'0528' or DATE_PKEY = date_part(year, V_DATE)||'0704'
or DATE_PKEY = date_part(year, V_DATE)||'1225' )then
'Holiday'
when monthname(V_DATE_1) ='Mar' and dayname(last_day(V_DATE_1)) = 'Fri'
and last_day(V_DATE_1) = V_DATE_1 then
'Holiday'
when monthname(V_DATE_1) ='Mar' and dayname(last_day(V_DATE_1)) = 'Sat'
and dateadd(day,-1,last_day(V_DATE_1)) = V_DATE_1 then
'Holiday'
when monthname(V_DATE_1) ='Mar' and dayname(last_day(V_DATE_1)) = 'Sun'
and dateadd(day,-2,last_day(V_DATE_1)) = V_DATE_1 then
'Holiday'
when monthname(V_DATE_1) ='Apr' and dayname(date_part(year, V_DATE_1)||'-04-01') = 'Tue'
and dateadd(day,3,(date_part(year, V_DATE_1)||'-04-01')) = V_DATE_1 then
'Holiday'
when monthname(V_DATE_1) ='Apr' and dayname(date_part(year, V_DATE_1)||'-04-01') = 'Wed'
and dateadd(day,2,(date_part(year, V_DATE_1)||'-04-01')) = V_DATE_1 then
'Holiday'
when monthname(V_DATE_1) ='Apr' and dayname(date_part(year, V_DATE_1)||'-04-01') = 'Thu'
and dateadd(day,1,(date_part(year, V_DATE_1)||'-04-01')) = V_DATE_1 then
'Holiday'
when monthname(V_DATE_1) ='Apr' and dayname(date_part(year, V_DATE_1)||'-04-01') = 'Fri'
and date_part(year, V_DATE_1)||'-04-01' = V_DATE_1 then
'Holiday'
when monthname(V_DATE_1) ='Apr' and dayname(date_part(year, V_DATE_1)||'-04-01') = 'Wed'
and dateadd(day,5,(date_part(year, V_DATE_1)||'-04-01')) = V_DATE_1 then
'Holiday'
when monthname(V_DATE_1) ='Apr' and dayname(date_part(year, V_DATE_1)||'-04-01') = 'Thu'
and dateadd(day,4,(date_part(year, V_DATE_1)||'-04-01')) = V_DATE_1 then
'Holiday'
when monthname(V_DATE_1) ='Apr' and dayname(date_part(year, V_DATE_1)||'-04-01') = 'Fri'
and dateadd(day,3,(date_part(year, V_DATE_1)||'-04-01')) = V_DATE_1 then
'Holiday'
when monthname(V_DATE_1) ='Apr' and dayname(date_part(year, V_DATE_1)||'-04-01') = 'Sat'
and dateadd(day,2,(date_part(year, V_DATE_1)||'-04-01')) = V_DATE_1 then
'Holiday'
when monthname(V_DATE_1) ='Apr' and dayname(date_part(year, V_DATE_1)||'-04-01') = 'Sun'
and dateadd(day,1,(date_part(year, V_DATE_1)||'-04-01')) = V_DATE_1 then
'Holiday'
when monthname(V_DATE_1) ='Apr' and dayname(date_part(year, V_DATE_1)||'-04-01') = 'Mon'
and date_part(year, V_DATE_1)||'-04-01'= V_DATE_1 then
'Holiday'
when monthname(V_DATE_1) ='Apr' and dayname(date_part(year, V_DATE_1)||'-04-01') = 'Tue'
and dateadd(day,6 ,(date_part(year, V_DATE_1)||'-04-01')) = V_DATE_1 then
'Holiday'
when monthname(V_DATE_1) ='Sep' and dayname(date_part(year, V_DATE_1)||'-09-01') = 'Wed'
and dateadd(day,5,(date_part(year, V_DATE_1)||'-09-01')) = V_DATE_1 then
'Holiday'
when monthname(V_DATE_1) ='Sep' and dayname(date_part(year, V_DATE_1)||'-09-01') = 'Thu'
and dateadd(day,4,(date_part(year, V_DATE_1)||'-09-01')) = V_DATE_1 then
'Holiday'
when monthname(V_DATE_1) ='Sep' and dayname(date_part(year, V_DATE_1)||'-09-01') = 'Fri'
and dateadd(day,3,(date_part(year, V_DATE_1)||'-09-01')) = V_DATE_1 then
'Holiday'
when monthname(V_DATE_1) ='Sep' and dayname(date_part(year, V_DATE_1)||'-09-01') = 'Sat'
and dateadd(day,2,(date_part(year, V_DATE_1)||'-09-01')) = V_DATE_1 then
'Holiday'
when monthname(V_DATE_1) ='Sep' and dayname(date_part(year, V_DATE_1)||'-09-01') = 'Sun'
and dateadd(day,1,(date_part(year, V_DATE_1)||'-09-01')) = V_DATE_1 then
'Holiday'
when monthname(V_DATE_1) ='Sep' and dayname(date_part(year, V_DATE_1)||'-09-01') = 'Mon'
and date_part(year, V_DATE_1)||'-09-01' = V_DATE_1 then
'Holiday'
when monthname(V_DATE_1) ='Sep' and dayname(date_part(year, V_DATE_1)||'-09-01') = 'Tue'
and dateadd(day,6 ,(date_part(year, V_DATE_1)||'-09-01')) = V_DATE_1 then
'Holiday'
when monthname(V_DATE_1) ='Nov' and dayname(date_part(year, V_DATE_1)||'-11-01') = 'Wed'
and dateadd(day,23,(date_part(year, V_DATE_1)||'-11-01')) = V_DATE_1 then
'Holiday'
when monthname(V_DATE_1) ='Nov' and dayname(date_part(year, V_DATE_1)||'-11-01') = 'Thu'
and dateadd(day,22,(date_part(year, V_DATE_1)||'-11-01')) = V_DATE_1 then
'Holiday'
when monthname(V_DATE_1) ='Nov' and dayname(date_part(year, V_DATE_1)||'-11-01') = 'Fri'
and dateadd(day,21,(date_part(year, V_DATE_1)||'-11-01')) = V_DATE_1 then
'Holiday'
when monthname(V_DATE_1) ='Nov' and dayname(date_part(year, V_DATE_1)||'-11-01') = 'Sat'
and dateadd(day,27,(date_part(year, V_DATE_1)||'-11-01')) = V_DATE_1 then
'Holiday'
when monthname(V_DATE_1) ='Nov' and dayname(date_part(year, V_DATE_1)||'-11-01') = 'Sun'
and dateadd(day,26,(date_part(year, V_DATE_1)||'-11-01')) = V_DATE_1 then
'Holiday'
when monthname(V_DATE_1) ='Nov' and dayname(date_part(year, V_DATE_1)||'-11-01') = 'Mon'
and dateadd(day,25,(date_part(year, V_DATE_1)||'-11-01')) = V_DATE_1 then
'Holiday'
when monthname(V_DATE_1) ='Nov' and dayname(date_part(year, V_DATE_1)||'-11-01') = 'Tue'
and dateadd(day,24,(date_part(year, V_DATE_1)||'-11-01')) = V_DATE_1 then
'Holiday'
else
'Not-Holiday' end as COMPANY_HOLIDAY_IND,
case
when last_day(V_DATE_1) = V_DATE_1 then
'Month-end'
else 'Not-Month-end' end as MONTH_END_IND,
case when date_part(mm,date_trunc('week',V_DATE_1)) < 10 and date_part(dd,date_trunc('week',V_DATE_1)) < 10 then
date_part(yyyy,date_trunc('week',V_DATE_1))||'0'||
date_part(mm,date_trunc('week',V_DATE_1))||'0'||
date_part(dd,date_trunc('week',V_DATE_1))
when date_part(mm,date_trunc('week',V_DATE_1)) < 10 and date_part(dd,date_trunc('week',V_DATE_1)) > 9 then
date_part(yyyy,date_trunc('week',V_DATE_1))||'0'||
date_part(mm,date_trunc('week',V_DATE_1))||date_part(dd,date_trunc('week',V_DATE_1))
when date_part(mm,date_trunc('week',V_DATE_1)) > 9 and date_part(dd,date_trunc('week',V_DATE_1)) < 10 then
date_part(yyyy,date_trunc('week',V_DATE_1))||date_part(mm,date_trunc('week',V_DATE_1))||
'0'||date_part(dd,date_trunc('week',V_DATE_1))
when date_part(mm,date_trunc('week',V_DATE_1)) > 9 and date_part(dd,date_trunc('week',V_DATE_1)) > 9 then
date_part(yyyy,date_trunc('week',V_DATE_1))||
date_part(mm,date_trunc('week',V_DATE_1))||
date_part(dd,date_trunc('week',V_DATE_1)) end as WEEK_BEGIN_DATE_NKEY,
date_trunc('week',V_DATE_1) as WEEK_BEGIN_DATE,
case when date_part(mm,last_day(V_DATE_1,'week')) < 10 and date_part(dd,last_day(V_DATE_1,'week')) < 10 then
date_part(yyyy,last_day(V_DATE_1,'week'))||'0'||
date_part(mm,last_day(V_DATE_1,'week'))||'0'||
date_part(dd,last_day(V_DATE_1,'week'))
when date_part(mm,last_day(V_DATE_1,'week')) < 10 and date_part(dd,last_day(V_DATE_1,'week')) > 9 then
date_part(yyyy,last_day(V_DATE_1,'week'))||'0'||
date_part(mm,last_day(V_DATE_1,'week'))||date_part(dd,last_day(V_DATE_1,'week'))
when date_part(mm,last_day(V_DATE_1,'week')) > 9 and date_part(dd,last_day(V_DATE_1,'week')) < 10 then
date_part(yyyy,last_day(V_DATE_1,'week'))||date_part(mm,last_day(V_DATE_1,'week'))||'0'||
date_part(dd,last_day(V_DATE_1,'week'))
when date_part(mm,last_day(V_DATE_1,'week')) > 9 and date_part(dd,last_day(V_DATE_1,'week')) > 9 then
date_part(yyyy,last_day(V_DATE_1,'week'))||
date_part(mm,last_day(V_DATE_1,'week'))||
date_part(dd,last_day(V_DATE_1,'week')) end as WEEK_END_DATE_NKEY,
last_day(V_DATE_1,'week') as WEEK_END_DATE,
week(V_DATE_1) as WEEK_NUM_IN_YEAR,
case when monthname(V_DATE_1) ='Jan' then 'January'
when monthname(V_DATE_1) ='Feb' then 'February'
when monthname(V_DATE_1) ='Mar' then 'March'
when monthname(V_DATE_1) ='Apr' then 'April'
when monthname(V_DATE_1) ='May' then 'May'
when monthname(V_DATE_1) ='Jun' then 'June'
when monthname(V_DATE_1) ='Jul' then 'July'
when monthname(V_DATE_1) ='Aug' then 'August'
when monthname(V_DATE_1) ='Sep' then 'September'
when monthname(V_DATE_1) ='Oct' then 'October'
when monthname(V_DATE_1) ='Nov' then 'November'
when monthname(V_DATE_1) ='Dec' then 'December' end as MONTH_NAME,
monthname(V_DATE_1) as MONTH_ABBREV,
month(V_DATE_1) as MONTH_NUM_IN_YEAR,
case when month(V_DATE_1) < 10 then
year(V_DATE_1)||'-0'||month(V_DATE_1)
else year(V_DATE_1)||'-'||month(V_DATE_1) end as YEARMONTH,
quarter(V_DATE_1) as CURRENT_QUARTER,
year(V_DATE_1)||'-0'||quarter(V_DATE_1) as YEARQUARTER,
year(V_DATE_1) as CURRENT_YEAR,
/*Modify the following based on company fiscal year - assumes Jan 01*/
to_date(year(V_DATE_1)||'-01-01','YYYY-MM-DD') as FISCAL_CUR_YEAR,
to_date(year(V_DATE_1) -1||'-01-01','YYYY-MM-DD') as FISCAL_PREV_YEAR,
case when V_DATE_1 < FISCAL_CUR_YEAR then
datediff('week', FISCAL_PREV_YEAR,V_DATE_1)
else
datediff('week', FISCAL_CUR_YEAR,V_DATE_1) end as FISCAL_WEEK_NUM ,
decode(datediff('MONTH',FISCAL_CUR_YEAR, V_DATE_1)+1 ,-2,10,-1,11,0,12,
datediff('MONTH',FISCAL_CUR_YEAR, V_DATE_1)+1 ) as FISCAL_MONTH_NUM,
concat( year(FISCAL_CUR_YEAR)
,case when to_number(FISCAL_MONTH_NUM) = 10 or
to_number(FISCAL_MONTH_NUM) = 11 or
to_number(FISCAL_MONTH_NUM) = 12 then
'-'||FISCAL_MONTH_NUM
else concat('-0',FISCAL_MONTH_NUM) end ) as FISCAL_YEARMONTH,
case when quarter(V_DATE_1) = 4 then 4
when quarter(V_DATE_1) = 3 then 3
when quarter(V_DATE_1) = 2 then 2
when quarter(V_DATE_1) = 1 then 1 end as FISCAL_QUARTER,
case when V_DATE_1 < FISCAL_CUR_YEAR then
year(FISCAL_CUR_YEAR)
else year(FISCAL_CUR_YEAR)+1 end
||'-0'||case when quarter(V_DATE_1) = 4 then 4
when quarter(V_DATE_1) = 3 then 3
when quarter(V_DATE_1) = 2 then 2
when quarter(V_DATE_1) = 1 then 1 end as FISCAL_YEARQUARTER,
case when quarter(V_DATE_1) = 4 then 2 when quarter(V_DATE_1) = 3 then 2
when quarter(V_DATE_1) = 1 then 1 when quarter(V_DATE_1) = 2 then 1
end as FISCAL_HALFYEAR,
year(FISCAL_CUR_YEAR) as FISCAL_YEAR,
to_timestamp_ntz(V_DATE) as SQL_TIMESTAMP,
'Y' as CURRENT_ROW_IND,
to_date(current_timestamp) as EFFECTIVE_DATE,
to_date('9999-12-31') as EXPIRA_DATE
from table(generator(rowcount => 8401)) /*<< Set to generate 20 years. Modify rowcount to increase or decrease size*/
)v;
--Miscellaneous queries
select * from DIM_DATE where date > '2021-01-01' order by date limit 300 ;
--delete from DIM_DATE;
--drop table DIM_DATE;
select to_date('2018-01-01 00:00:00','YYYY-MM-DD HH:MI:SS')