|
1 | 1 | {%- 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 |
16 | 33 | ),
|
17 | 34 |
|
18 | 35 | enriched_timestamps AS (
|
19 | 36 |
|
20 | 37 | 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, |
23 | 40 | 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 |
39 | 52 | FROM initial_timestamps )
|
40 | 53 |
|
41 | 54 | SELECT * FROM enriched_timestamps
|
|
0 commit comments