-
Notifications
You must be signed in to change notification settings - Fork 0
/
Copy pathget_date_dimension.sql
180 lines (157 loc) · 7.77 KB
/
get_date_dimension.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
{% macro get_date_dimension(start_date, end_date) %}
{{ adapter.dispatch("get_date_dimension", "dbt_date")(start_date, end_date) }}
{% endmacro %}
{% macro default__get_date_dimension(start_date, end_date) %}
with
base_dates as ({{ dbt_date.get_base_dates(start_date, end_date) }}),
dates_with_prior_year_dates as (
select
cast(d.date_day as date) as date_day,
cast(
{{ dbt.dateadd("year", -1, "d.date_day") }} as date
) as prior_year_date_day,
cast(
{{ dbt.dateadd("day", -364, "d.date_day") }} as date
) as prior_year_over_year_date_day
from base_dates d
)
select
d.date_day,
{{ dbt_date.yesterday("d.date_day") }} as prior_date_day,
{{ dbt_date.tomorrow("d.date_day") }} as next_date_day,
d.prior_year_date_day as prior_year_date_day,
d.prior_year_over_year_date_day,
{{ dbt_date.day_of_week("d.date_day", isoweek=false) }} as day_of_week,
{{ dbt_date.day_of_week("d.date_day", isoweek=true) }} as day_of_week_iso,
{{ dbt_date.day_name("d.date_day", short=false) }} as day_of_week_name,
{{ dbt_date.day_name("d.date_day", short=true) }} as day_of_week_name_short,
{{ dbt_date.day_of_month("d.date_day") }} as day_of_month,
{{ dbt_date.day_of_year("d.date_day") }} as day_of_year,
{{ dbt_date.week_start("d.date_day") }} as week_start_date,
{{ dbt_date.week_end("d.date_day") }} as week_end_date,
{{ dbt_date.week_start("d.prior_year_over_year_date_day") }}
as prior_year_week_start_date,
{{ dbt_date.week_end("d.prior_year_over_year_date_day") }}
as prior_year_week_end_date,
{{ dbt_date.week_of_year("d.date_day") }} as week_of_year,
{{ dbt_date.iso_week_start("d.date_day") }} as iso_week_start_date,
{{ dbt_date.iso_week_end("d.date_day") }} as iso_week_end_date,
{{ dbt_date.iso_week_start("d.prior_year_over_year_date_day") }}
as prior_year_iso_week_start_date,
{{ dbt_date.iso_week_end("d.prior_year_over_year_date_day") }}
as prior_year_iso_week_end_date,
{{ dbt_date.iso_week_of_year("d.date_day") }} as iso_week_of_year,
{{ dbt_date.week_of_year("d.prior_year_over_year_date_day") }}
as prior_year_week_of_year,
{{ dbt_date.iso_week_of_year("d.prior_year_over_year_date_day") }}
as prior_year_iso_week_of_year,
cast(
{{ dbt_date.date_part("month", "d.date_day") }} as {{ dbt.type_int() }}
) as month_of_year,
{{ dbt_date.month_name("d.date_day", short=false) }} as month_name,
{{ dbt_date.month_name("d.date_day", short=true) }} as month_name_short,
cast({{ dbt.date_trunc("month", "d.date_day") }} as date) as month_start_date,
cast({{ last_day("d.date_day", "month") }} as date) as month_end_date,
cast(
{{ dbt.date_trunc("month", "d.prior_year_date_day") }} as date
) as prior_year_month_start_date,
cast(
{{ last_day("d.prior_year_date_day", "month") }} as date
) as prior_year_month_end_date,
cast(
{{ dbt_date.date_part("quarter", "d.date_day") }} as {{ dbt.type_int() }}
) as quarter_of_year,
cast(
{{ dbt.date_trunc("quarter", "d.date_day") }} as date
) as quarter_start_date,
cast({{ last_day("d.date_day", "quarter") }} as date) as quarter_end_date,
cast(
{{ dbt_date.date_part("year", "d.date_day") }} as {{ dbt.type_int() }}
) as year_number,
cast({{ dbt.date_trunc("year", "d.date_day") }} as date) as year_start_date,
cast({{ last_day("d.date_day", "year") }} as date) as year_end_date
from dates_with_prior_year_dates d
order by 1
{% endmacro %}
{% macro postgres__get_date_dimension(start_date, end_date) %}
with
base_dates as ({{ dbt_date.get_base_dates(start_date, end_date) }}),
dates_with_prior_year_dates as (
select
cast(d.date_day as date) as date_day,
cast(
{{ dbt.dateadd("year", -1, "d.date_day") }} as date
) as prior_year_date_day,
cast(
{{ dbt.dateadd("day", -364, "d.date_day") }} as date
) as prior_year_over_year_date_day
from base_dates d
)
select
d.date_day,
{{ dbt_date.yesterday("d.date_day") }} as prior_date_day,
{{ dbt_date.tomorrow("d.date_day") }} as next_date_day,
d.prior_year_date_day as prior_year_date_day,
d.prior_year_over_year_date_day,
{{ dbt_date.day_of_week("d.date_day", isoweek=true) }} as day_of_week,
{{ dbt_date.day_name("d.date_day", short=false) }} as day_of_week_name,
{{ dbt_date.day_name("d.date_day", short=true) }} as day_of_week_name_short,
{{ dbt_date.day_of_month("d.date_day") }} as day_of_month,
{{ dbt_date.day_of_year("d.date_day") }} as day_of_year,
{{ dbt_date.week_start("d.date_day") }} as week_start_date,
{{ dbt_date.week_end("d.date_day") }} as week_end_date,
{{ dbt_date.week_start("d.prior_year_over_year_date_day") }}
as prior_year_week_start_date,
{{ dbt_date.week_end("d.prior_year_over_year_date_day") }}
as prior_year_week_end_date,
{{ dbt_date.week_of_year("d.date_day") }} as week_of_year,
{{ dbt_date.iso_week_start("d.date_day") }} as iso_week_start_date,
{{ dbt_date.iso_week_end("d.date_day") }} as iso_week_end_date,
{{ dbt_date.iso_week_start("d.prior_year_over_year_date_day") }}
as prior_year_iso_week_start_date,
{{ dbt_date.iso_week_end("d.prior_year_over_year_date_day") }}
as prior_year_iso_week_end_date,
{{ dbt_date.iso_week_of_year("d.date_day") }} as iso_week_of_year,
{{ dbt_date.week_of_year("d.prior_year_over_year_date_day") }}
as prior_year_week_of_year,
{{ dbt_date.iso_week_of_year("d.prior_year_over_year_date_day") }}
as prior_year_iso_week_of_year,
cast(
{{ dbt_date.date_part("month", "d.date_day") }} as {{ dbt.type_int() }}
) as month_of_year,
{{ dbt_date.month_name("d.date_day", short=false) }} as month_name,
{{ dbt_date.month_name("d.date_day", short=true) }} as month_name_short,
cast({{ dbt.date_trunc("month", "d.date_day") }} as date) as month_start_date,
cast({{ last_day("d.date_day", "month") }} as date) as month_end_date,
cast(
{{ dbt.date_trunc("month", "d.prior_year_date_day") }} as date
) as prior_year_month_start_date,
cast(
{{ last_day("d.prior_year_date_day", "month") }} as date
) as prior_year_month_end_date,
cast(
{{ dbt_date.date_part("quarter", "d.date_day") }} as {{ dbt.type_int() }}
) as quarter_of_year,
cast(
{{ dbt.date_trunc("quarter", "d.date_day") }} as date
) as quarter_start_date,
{# last_day does not support quarter because postgresql does not support quarter interval. #}
cast(
{{
dbt.dateadd(
"day",
"-1",
dbt.dateadd(
"month", "3", dbt.date_trunc("quarter", "d.date_day")
),
)
}} as date
) as quarter_end_date,
cast(
{{ dbt_date.date_part("year", "d.date_day") }} as {{ dbt.type_int() }}
) as year_number,
cast({{ dbt.date_trunc("year", "d.date_day") }} as date) as year_start_date,
cast({{ last_day("d.date_day", "year") }} as date) as year_end_date
from dates_with_prior_year_dates d
order by 1
{% endmacro %}