Skip to content

Commit

Permalink
align synapse snapshot control with the other adapters
Browse files Browse the repository at this point in the history
  • Loading branch information
tkiehn authored Aug 26, 2024
1 parent d76e137 commit 8e99b79
Show file tree
Hide file tree
Showing 2 changed files with 68 additions and 50 deletions.
75 changes: 44 additions & 31 deletions macros/tables/synapse/control_snap_v0.sql
Original file line number Diff line number Diff line change
@@ -1,41 +1,54 @@
{%- macro synapse__control_snap_v0(start_date, end_date, daily_snapshot_time, sdts_alias) -%}
{{ log('start_date: '~ start_date, false)}}
WITH initial_timestamps AS (
SELECT
CAST(CAST('{{ start_date }}' AS VARCHAR) + ' ' + '{{ daily_snapshot_time }}' AS DATETIME) + CAST(rn - 1 AS INT) AS {{ sdts_alias }}
FROM
(
SELECT
TOP (DATEDIFF(DAY, '{{ start_date }}', '{{ end_date }}') + 1)
ROW_NUMBER() OVER (ORDER BY (SELECT NULL)) AS rn
FROM
sys.all_objects s1
CROSS JOIN
sys.all_objects s2
) AS system_row

{% if datavault4dbt.is_nothing(end_date) %}
{% set end_date = datavault4dbt.current_timestamp() %}
{% endif %}

WITH

{#- To generate a large amount of row for creation of the date-series #}
initial_timestamps_prep AS (
SELECT 1 AS num UNION ALL
SELECT 2 UNION ALL
SELECT 3 UNION ALL
SELECT 4 UNION ALL
SELECT 5 UNION ALL
SELECT 6 UNION ALL
SELECT 7 UNION ALL
SELECT 8 UNION ALL
SELECT 9 UNION ALL
SELECT 10 UNION ALL
SELECT 11 UNION ALL
SELECT 12
),

initial_timestamps AS (
SELECT TOP (DATEDIFF(DAY, '{{ start_date }}', {{ end_date}}) + 1)
DATEADD(DAY, ROW_NUMBER() OVER (ORDER BY (SELECT NULL)) - 1, '{{ start_date }}' ) AS {{ sdts_alias }}
FROM initial_timestamps_prep s1
CROSS JOIN initial_timestamps_prep s2
CROSS JOIN initial_timestamps_prep s3
CROSS JOIN initial_timestamps_prep s4
CROSS JOIN initial_timestamps_prep s5
),

enriched_timestamps AS (

SELECT
CONVERT(datetime2, {{ sdts_alias }}) as {{ sdts_alias }},
CONVERT(varchar, {{ sdts_alias }}, 23) as {{ sdts_alias }}_date,
CONVERT(datetime2(6), {{ sdts_alias }}) as {{ sdts_alias }},
CONVERT(varchar, {{ sdts_alias }}, 23) as {{ sdts_alias }}_date,
1 as force_active,
{{ sdts_alias }} AS replacement_{{ sdts_alias }},
CONCAT('Snapshot ', CONVERT(date, {{ sdts_alias }}, 23)) AS caption,
DATEPART(YEAR, {{ sdts_alias }}) as year,
DATEPART(QUARTER, {{ sdts_alias }}) as quarter,
DATEPART(MONTH, {{ sdts_alias }}) as month,
DATEPART(DAY, {{ sdts_alias }}) as day_of_month,
DATEPART(DAYOFYEAR, {{ sdts_alias }}) as day_of_year,
DATEPART(WEEKDAY, {{ sdts_alias }}) as weekday,
DATEPART(WEEK, {{ sdts_alias }}) as week,
DATEPART(ISO_WEEK, {{ sdts_alias }}) as iso_week,
CASE WHEN DATEPART(weekday, {{ sdts_alias }}) = 7 THEN 1 ELSE 0 END AS is_end_of_week,
CASE WHEN LEAD(DATEPART(Day, {{ sdts_alias }}), 1) OVER (ORDER BY {{ sdts_alias }}) = 1 THEN 1 ELSE 0 END AS is_end_of_month,
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,
CASE WHEN LEAD(DATEPART(Dayofyear, {{ sdts_alias }}), 1) OVER (ORDER BY {{ sdts_alias }}) = 1 THEN 1 ELSE 0 END AS is_end_of_year,
NULL AS comment
CONVERT(datetime2(6), {{ sdts_alias }}) AS replacement_{{ sdts_alias }},
CONCAT('Snapshot ', CONVERT(date, {{ sdts_alias }}, 23)) AS caption,
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,
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,
CASE WHEN DATEPART(WEEKDAY, {{ sdts_alias }}) = 1 THEN 1 ELSE 0 END AS is_weekly, -- assuming 1 is Monday
CASE WHEN DAY({{ sdts_alias }}) = 1 THEN 1 ELSE 0 END AS is_monthly,
CASE WHEN LEAD(DATEPART(DAY, {{ sdts_alias }}), 1) OVER (ORDER BY {{ sdts_alias }}) = 1 THEN 1 ELSE 0 END AS is_end_of_month,
CASE WHEN (MONTH({{ sdts_alias }}) IN (1, 4, 7, 10) AND DAY({{ sdts_alias }}) = 1) THEN 1 ELSE 0 END AS is_quarterly,
CASE WHEN MONTH({{ sdts_alias }}) = 1 AND DAY({{ sdts_alias }}) = 1 THEN 1 ELSE 0 END AS is_yearly,
CASE WHEN LEAD(DATEPART(DAYOFYEAR, {{ sdts_alias }}), 1) OVER (ORDER BY {{ sdts_alias }}) = 1 THEN 1 ELSE 0 END AS is_end_of_year,
NULL AS comment
FROM initial_timestamps )

SELECT * FROM enriched_timestamps
Expand Down
43 changes: 24 additions & 19 deletions macros/tables/synapse/control_snap_v1.sql
Original file line number Diff line number Diff line change
@@ -1,5 +1,4 @@
{%- macro synapse__control_snap_v1(control_snap_v0, log_logic, sdts_alias) -%}

{%- set snapshot_trigger_column = var('datavault4dbt.snapshot_trigger_column', 'is_active') -%}

{%- set ns = namespace(forever_status_dict={}, log_logic_list=[], col_name='', log_logic={}) %}
Expand Down Expand Up @@ -69,23 +68,29 @@ dynamic as (SELECT
src.{{ sdts_alias }},
src.{{ sdts_alias }}_date,
src.force_active,
CASE WHEN itp.{{ sdts_alias }} is not null THEN 1 ELSE 0 END AS is_in_the_past,
CASE WHEN itp.rn = 1 THEN 1 ELSE 0 END AS is_current,
CASE WHEN src.year = DATEPART(YEAR, GETDATE()) THEN 1 ELSE 0 END as is_current_year,
CASE WHEN src.year = DATEPART(YEAR, GETDATE())-1 THEN 1 ELSE 0 END as is_last_year,
CASE WHEN DATEDIFF(day, src.{{ sdts_alias }}, GETDATE()) between 0 and 365 THEN 1 ELSE 0 END as is_current_rolling_year,
{# CASE WHEN itp.{{ sdts_alias }} is not null THEN 1 ELSE 0 END AS is_in_the_past, #}
CASE WHEN itp.rn = 1 THEN 1 ELSE 0 END AS is_latest,
CASE WHEN DATEPART(YEAR, src.{{ sdts_alias }}) = DATEPART(YEAR, GETDATE()) THEN 1 ELSE 0 END as is_current_year,
CASE WHEN DATEPART(YEAR, src.{{ sdts_alias }}) = DATEPART(YEAR, GETDATE())-1 THEN 1 ELSE 0 END as is_last_year,
CASE WHEN DATEDIFF(day, src.{{ sdts_alias }}, GETDATE()) between 0 and 365 THEN 1 ELSE 0 END as is_rolling_year,
CASE WHEN DATEDIFF(day, src.{{ sdts_alias }}, GETDATE()) between 366 and 730 THEN 1 ELSE 0 END as is_last_rolling_year,
src.year,
src.quarter,
src.month,
src.day_of_month,
src.day_of_year,
src.weekday,
src.week,
src.iso_week,
src.is_end_of_week,
{# src.year, #}
{# src.quarter, #}
{# src.month, #}
{# src.day_of_month, #}
{# src.day_of_year, #}
{# src.weekday, #}
{# src.week, #}
{# src.iso_week, #}
src.is_hourly,
src.is_daily,
src.is_weekly,
src.is_monthly,
{# src.is_end_of_week, #}
src.is_end_of_month,
src.is_end_of_quarter,
src.is_quarterly,
{# src.is_end_of_quarter, #}
src.is_yearly,
src.is_end_of_year


Expand Down Expand Up @@ -130,11 +135,11 @@ log_logic AS (
{%- if 'weekly' in logic_definition.keys() %} OR
{%- if logic_definition['weekly']['forever'] is true -%}
{%- do ns.forever_status_dict.update({col_name: 'TRUE'}) -%}
(c.is_end_of_week = 1)
(DATEPART(weekday, c.{{ sdts_alias }}) = 7)
{%- else %}
{%- set weekly_duration = logic_definition['weekly']['duration'] -%}
{%- set weekly_unit = logic_definition['weekly']['unit'] %}
((c.{{ sdts_alias }} BETWEEN DATEADD({{ weekly_unit }}, -{{ weekly_duration }}, GETDATE()) AND GETDATE()) AND (c.is_end_of_week = 1))
((c.{{ sdts_alias }} BETWEEN DATEADD({{ weekly_unit }}, -{{ weekly_duration }}, GETDATE()) AND GETDATE()) AND (DATEPART(weekday, c.{{ sdts_alias }}) = 7))
{%- endif -%}
{% endif -%}

Expand Down Expand Up @@ -171,4 +176,4 @@ log_logic AS (

SELECT * FROM log_logic

{%- endmacro -%}
{%- endmacro -%}

0 comments on commit 8e99b79

Please sign in to comment.