Skip to content

Commit 8e99b79

Browse files
authored
align synapse snapshot control with the other adapters
1 parent d76e137 commit 8e99b79

File tree

2 files changed

+68
-50
lines changed

2 files changed

+68
-50
lines changed

macros/tables/synapse/control_snap_v0.sql

Lines changed: 44 additions & 31 deletions
Original file line numberDiff line numberDiff line change
@@ -1,41 +1,54 @@
11
{%- macro synapse__control_snap_v0(start_date, end_date, daily_snapshot_time, sdts_alias) -%}
2-
{{ log('start_date: '~ start_date, false)}}
3-
WITH initial_timestamps AS (
4-
SELECT
5-
CAST(CAST('{{ start_date }}' AS VARCHAR) + ' ' + '{{ daily_snapshot_time }}' AS DATETIME) + CAST(rn - 1 AS INT) AS {{ sdts_alias }}
6-
FROM
7-
(
8-
SELECT
9-
TOP (DATEDIFF(DAY, '{{ start_date }}', '{{ end_date }}') + 1)
10-
ROW_NUMBER() OVER (ORDER BY (SELECT NULL)) AS rn
11-
FROM
12-
sys.all_objects s1
13-
CROSS JOIN
14-
sys.all_objects s2
15-
) AS system_row
2+
3+
{% if datavault4dbt.is_nothing(end_date) %}
4+
{% set end_date = datavault4dbt.current_timestamp() %}
5+
{% endif %}
6+
7+
WITH
8+
9+
{#- To generate a large amount of row for creation of the date-series #}
10+
initial_timestamps_prep AS (
11+
SELECT 1 AS num UNION ALL
12+
SELECT 2 UNION ALL
13+
SELECT 3 UNION ALL
14+
SELECT 4 UNION ALL
15+
SELECT 5 UNION ALL
16+
SELECT 6 UNION ALL
17+
SELECT 7 UNION ALL
18+
SELECT 8 UNION ALL
19+
SELECT 9 UNION ALL
20+
SELECT 10 UNION ALL
21+
SELECT 11 UNION ALL
22+
SELECT 12
23+
),
24+
25+
initial_timestamps AS (
26+
SELECT TOP (DATEDIFF(DAY, '{{ start_date }}', {{ end_date}}) + 1)
27+
DATEADD(DAY, ROW_NUMBER() OVER (ORDER BY (SELECT NULL)) - 1, '{{ start_date }}' ) AS {{ sdts_alias }}
28+
FROM initial_timestamps_prep s1
29+
CROSS JOIN initial_timestamps_prep s2
30+
CROSS JOIN initial_timestamps_prep s3
31+
CROSS JOIN initial_timestamps_prep s4
32+
CROSS JOIN initial_timestamps_prep s5
1633
),
1734

1835
enriched_timestamps AS (
1936

2037
SELECT
21-
CONVERT(datetime2, {{ sdts_alias }}) as {{ sdts_alias }},
22-
CONVERT(varchar, {{ sdts_alias }}, 23) as {{ sdts_alias }}_date,
38+
CONVERT(datetime2(6), {{ sdts_alias }}) as {{ sdts_alias }},
39+
CONVERT(varchar, {{ sdts_alias }}, 23) as {{ sdts_alias }}_date,
2340
1 as force_active,
24-
{{ sdts_alias }} AS replacement_{{ sdts_alias }},
25-
CONCAT('Snapshot ', CONVERT(date, {{ sdts_alias }}, 23)) AS caption,
26-
DATEPART(YEAR, {{ sdts_alias }}) as year,
27-
DATEPART(QUARTER, {{ sdts_alias }}) as quarter,
28-
DATEPART(MONTH, {{ sdts_alias }}) as month,
29-
DATEPART(DAY, {{ sdts_alias }}) as day_of_month,
30-
DATEPART(DAYOFYEAR, {{ sdts_alias }}) as day_of_year,
31-
DATEPART(WEEKDAY, {{ sdts_alias }}) as weekday,
32-
DATEPART(WEEK, {{ sdts_alias }}) as week,
33-
DATEPART(ISO_WEEK, {{ sdts_alias }}) as iso_week,
34-
CASE WHEN DATEPART(weekday, {{ sdts_alias }}) = 7 THEN 1 ELSE 0 END AS is_end_of_week,
35-
CASE WHEN LEAD(DATEPART(Day, {{ sdts_alias }}), 1) OVER (ORDER BY {{ sdts_alias }}) = 1 THEN 1 ELSE 0 END AS is_end_of_month,
36-
CASE WHEN LEAD(DATEPART(QUARTER, {{ sdts_alias }}), 1) OVER (ORDER BY {{ sdts_alias }}) != DATEPART(QUARTER, {{ sdts_alias }}) THEN 1 ELSE 0 END as is_end_of_quarter,
37-
CASE WHEN LEAD(DATEPART(Dayofyear, {{ sdts_alias }}), 1) OVER (ORDER BY {{ sdts_alias }}) = 1 THEN 1 ELSE 0 END AS is_end_of_year,
38-
NULL AS comment
41+
CONVERT(datetime2(6), {{ sdts_alias }}) AS replacement_{{ sdts_alias }},
42+
CONCAT('Snapshot ', CONVERT(date, {{ sdts_alias }}, 23)) AS caption,
43+
CASE WHEN DATEPART(HOUR, {{ sdts_alias }}) = 0 AND DATEPART(MINUTE, {{ sdts_alias }}) = 0 AND DATEPART(SECOND, {{ sdts_alias }}) = 0 THEN 1 ELSE 0 END AS is_hourly,
44+
CASE WHEN DATEPART(HOUR, {{ sdts_alias }}) = 0 AND DATEPART(MINUTE, {{ sdts_alias }}) = 0 AND DATEPART(SECOND, {{ sdts_alias }}) = 0 THEN 1 ELSE 0 END AS is_daily,
45+
CASE WHEN DATEPART(WEEKDAY, {{ sdts_alias }}) = 1 THEN 1 ELSE 0 END AS is_weekly, -- assuming 1 is Monday
46+
CASE WHEN DAY({{ sdts_alias }}) = 1 THEN 1 ELSE 0 END AS is_monthly,
47+
CASE WHEN LEAD(DATEPART(DAY, {{ sdts_alias }}), 1) OVER (ORDER BY {{ sdts_alias }}) = 1 THEN 1 ELSE 0 END AS is_end_of_month,
48+
CASE WHEN (MONTH({{ sdts_alias }}) IN (1, 4, 7, 10) AND DAY({{ sdts_alias }}) = 1) THEN 1 ELSE 0 END AS is_quarterly,
49+
CASE WHEN MONTH({{ sdts_alias }}) = 1 AND DAY({{ sdts_alias }}) = 1 THEN 1 ELSE 0 END AS is_yearly,
50+
CASE WHEN LEAD(DATEPART(DAYOFYEAR, {{ sdts_alias }}), 1) OVER (ORDER BY {{ sdts_alias }}) = 1 THEN 1 ELSE 0 END AS is_end_of_year,
51+
NULL AS comment
3952
FROM initial_timestamps )
4053

4154
SELECT * FROM enriched_timestamps

macros/tables/synapse/control_snap_v1.sql

Lines changed: 24 additions & 19 deletions
Original file line numberDiff line numberDiff line change
@@ -1,5 +1,4 @@
11
{%- macro synapse__control_snap_v1(control_snap_v0, log_logic, sdts_alias) -%}
2-
32
{%- set snapshot_trigger_column = var('datavault4dbt.snapshot_trigger_column', 'is_active') -%}
43

54
{%- set ns = namespace(forever_status_dict={}, log_logic_list=[], col_name='', log_logic={}) %}
@@ -69,23 +68,29 @@ dynamic as (SELECT
6968
src.{{ sdts_alias }},
7069
src.{{ sdts_alias }}_date,
7170
src.force_active,
72-
CASE WHEN itp.{{ sdts_alias }} is not null THEN 1 ELSE 0 END AS is_in_the_past,
73-
CASE WHEN itp.rn = 1 THEN 1 ELSE 0 END AS is_current,
74-
CASE WHEN src.year = DATEPART(YEAR, GETDATE()) THEN 1 ELSE 0 END as is_current_year,
75-
CASE WHEN src.year = DATEPART(YEAR, GETDATE())-1 THEN 1 ELSE 0 END as is_last_year,
76-
CASE WHEN DATEDIFF(day, src.{{ sdts_alias }}, GETDATE()) between 0 and 365 THEN 1 ELSE 0 END as is_current_rolling_year,
71+
{# CASE WHEN itp.{{ sdts_alias }} is not null THEN 1 ELSE 0 END AS is_in_the_past, #}
72+
CASE WHEN itp.rn = 1 THEN 1 ELSE 0 END AS is_latest,
73+
CASE WHEN DATEPART(YEAR, src.{{ sdts_alias }}) = DATEPART(YEAR, GETDATE()) THEN 1 ELSE 0 END as is_current_year,
74+
CASE WHEN DATEPART(YEAR, src.{{ sdts_alias }}) = DATEPART(YEAR, GETDATE())-1 THEN 1 ELSE 0 END as is_last_year,
75+
CASE WHEN DATEDIFF(day, src.{{ sdts_alias }}, GETDATE()) between 0 and 365 THEN 1 ELSE 0 END as is_rolling_year,
7776
CASE WHEN DATEDIFF(day, src.{{ sdts_alias }}, GETDATE()) between 366 and 730 THEN 1 ELSE 0 END as is_last_rolling_year,
78-
src.year,
79-
src.quarter,
80-
src.month,
81-
src.day_of_month,
82-
src.day_of_year,
83-
src.weekday,
84-
src.week,
85-
src.iso_week,
86-
src.is_end_of_week,
77+
{# src.year, #}
78+
{# src.quarter, #}
79+
{# src.month, #}
80+
{# src.day_of_month, #}
81+
{# src.day_of_year, #}
82+
{# src.weekday, #}
83+
{# src.week, #}
84+
{# src.iso_week, #}
85+
src.is_hourly,
86+
src.is_daily,
87+
src.is_weekly,
88+
src.is_monthly,
89+
{# src.is_end_of_week, #}
8790
src.is_end_of_month,
88-
src.is_end_of_quarter,
91+
src.is_quarterly,
92+
{# src.is_end_of_quarter, #}
93+
src.is_yearly,
8994
src.is_end_of_year
9095

9196

@@ -130,11 +135,11 @@ log_logic AS (
130135
{%- if 'weekly' in logic_definition.keys() %} OR
131136
{%- if logic_definition['weekly']['forever'] is true -%}
132137
{%- do ns.forever_status_dict.update({col_name: 'TRUE'}) -%}
133-
(c.is_end_of_week = 1)
138+
(DATEPART(weekday, c.{{ sdts_alias }}) = 7)
134139
{%- else %}
135140
{%- set weekly_duration = logic_definition['weekly']['duration'] -%}
136141
{%- set weekly_unit = logic_definition['weekly']['unit'] %}
137-
((c.{{ sdts_alias }} BETWEEN DATEADD({{ weekly_unit }}, -{{ weekly_duration }}, GETDATE()) AND GETDATE()) AND (c.is_end_of_week = 1))
142+
((c.{{ sdts_alias }} BETWEEN DATEADD({{ weekly_unit }}, -{{ weekly_duration }}, GETDATE()) AND GETDATE()) AND (DATEPART(weekday, c.{{ sdts_alias }}) = 7))
138143
{%- endif -%}
139144
{% endif -%}
140145

@@ -171,4 +176,4 @@ log_logic AS (
171176

172177
SELECT * FROM log_logic
173178

174-
{%- endmacro -%}
179+
{%- endmacro -%}

0 commit comments

Comments
 (0)