Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

feat: implement datediff for for week days (DNA-24249: DNA-24526 + DNA-24512) #87

Merged
merged 4 commits into from
Mar 28, 2024
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
2 changes: 2 additions & 0 deletions .pipelines/profiles.yml
Original file line number Diff line number Diff line change
Expand Up @@ -32,5 +32,7 @@ default:
http_path: "{{ var('DBT_DATABRICKS_HTTP_PATH') }}"
token: "{{ var('DBT_DATABRICKS_TOKEN') }}"
threads: 10
session_properties:
legacy_time_parser_policy: LEGACY

target: databricks-ci
8 changes: 7 additions & 1 deletion README.md
Original file line number Diff line number Diff line change
Expand Up @@ -101,11 +101,17 @@ Usage:
`{{ pm_utils.date_from_timestamp('[expression]') }}`

#### datediff ([source](macros/multiple_databases/datediff.sql))
This macro computes the difference between two date or datetime expressions based on the specified `datepart` and returns an integer value. The datepart can be any of the following values for SQL Server and Snowflake: year, quarter, month, week, day, hour, minute, second, millisecond. For Databricks, the datepart can be any of the following values: year, day, hour, minute, second, millisecond. The difference in weeks is calculated for weeks starting on Monday.
This macro computes the difference between two date or datetime expressions based on the specified `datepart` and returns an integer value. The datepart can be any of the following values: year, quarter, month, week, day, hour, minute, second, millisecond. Weeks are defined from Sunday to Saturday.

Usage:
`{{ pm_utils.datediff('[datepart]', '[start_date_expression]', '[end_date_expression]') }}`

#### diff_weekdays ([source](macros/multiple_databases/diff_weekdays.sql))
This macro computes the number of days between a start and end date. It returns one day when the start and end date are on the same date. The Saturdays and Sundays are excluded from the number of days.

Usage:
`{{ pm_utils.diff_weekdays('[start_date_expression]', '[end_date_expression]') }}`

#### id ([source](macros/multiple_databases/id.sql))
This macro generates an id field that can be used as a column for the current model.

Expand Down
2 changes: 1 addition & 1 deletion dbt_project.yml
Original file line number Diff line number Diff line change
@@ -1,5 +1,5 @@
name: 'pm_utils'
version: '1.2.1'
version: '1.3.0'
config-version: 2

require-dbt-version: [">=1.0.0", "<2.0.0"]
60 changes: 60 additions & 0 deletions integration_tests/models/schema.yml
Original file line number Diff line number Diff line change
Expand Up @@ -111,3 +111,63 @@ models:
- equal_value:
actual: '`stddev_with_null_values_actual`'
expected: '`stddev_with_null_values_expected`'

- name: test_datediff
tests:
- equal_value:
actual: '`Year`'
expected: '`Year_expected`'
- equal_value:
actual: '`Quarter`'
expected: '`Quarter_expected`'
- equal_value:
actual: '`Month`'
expected: '`Month_expected`'
- equal_value:
actual: '`Week_saturday_to_sunday`'
expected: '`Week_saturday_to_sunday_expected`'
- equal_value:
actual: '`Week_sunday_to_saturday`'
expected: '`Week_sunday_to_saturday_expected`'
- equal_value:
actual: '`Day`'
expected: '`Day_expected`'
- equal_value:
actual: '`Hour`'
expected: '`Hour_expected`'
- equal_value:
actual: '`Minute`'
expected: '`Minute_expected`'
- equal_value:
actual: '`Second`'
expected: '`Second_expected`'
- equal_value:
actual: '`Millisecond`'
expected: '`Millisecond_expected`'

- name: test_diff_weekdays
tests:
- equal_value:
actual: '`Two_weekends`'
expected: '`Two_weekends_expected`'
- equal_value:
actual: '`One_half_weekends`'
expected: '`One_half_weekends_expected`'
- equal_value:
actual: '`One_weekend`'
expected: '`One_weekend_expected`'
- equal_value:
actual: '`One_weekend_end`'
expected: '`One_weekend_end_expected`'
- equal_value:
actual: '`Half_weekend`'
expected: '`Half_weekend_expected`'
- equal_value:
actual: '`Start_weekend`'
expected: '`Start_weekend_expected`'
- equal_value:
actual: '`Start_half_weekend`'
expected: '`Start_half_weekend_expected`'
- equal_value:
actual: '`Only_weekend`'
expected: '`Only_weekend_expected`'
30 changes: 30 additions & 0 deletions integration_tests/models/test_datediff.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,30 @@
select
{# Compute difference for every unit. Input parameters are date or datetime data types. #}
{{ pm_utils.datediff('year', "'2023-01-01'", "'2024-03-05'") }} as `Year`,
1 as `Year_expected`,

{{ pm_utils.datediff('quarter', "'2023-01-01'", "'2024-03-05'") }} as `Quarter`,
4 as `Quarter_expected`,

{{ pm_utils.datediff('month', "'2023-01-01'", "'2024-03-05'")}} as `Month`,
14 as `Month_expected`,

{{ pm_utils.datediff('week', "'2024-03-23'", "'2024-03-24'") }} as `Week_saturday_to_sunday`,
{{ pm_utils.datediff('week', "'2024-03-24'", "'2024-03-30'") }} as `Week_sunday_to_saturday`,
1 as `Week_saturday_to_sunday_expected`,
0 as `Week_sunday_to_saturday_expected`,

{{ pm_utils.datediff('day', "'2024-03-01'", "'2024-03-30'") }} as `Day`,
29 as `Day_expected`,

{{ pm_utils.datediff('hour', "'2024-03-01 00:00:00'", "'2024-03-01 23:59:59'") }} as `Hour`,
23 as `Hour_expected`,

{{ pm_utils.datediff('minute', "'2024-03-01 00:00:00'", "'2024-03-01 00:59:59'") }} as `Minute`,
59 as `Minute_expected`,

{{ pm_utils.datediff('second', "'2024-03-01 00:00:00'", "'2024-03-01 00:00:59'") }} as `Second`,
59 as `Second_expected`,

{{ pm_utils.datediff('millisecond', "'2024-03-01 00:00:00'", "'2024-03-01 00:00:00.999'") }} as `Millisecond`,
999 as `Millisecond_expected`
25 changes: 25 additions & 0 deletions integration_tests/models/test_diff_weekdays.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,25 @@
select
{# Compute difference for different use cases where the complete and half of the weekend falls in the date range. #}
{{ pm_utils.diff_weekdays("'2024-03-14'", "'2024-03-25'") }} as `Two_weekends`,
8 as `Two_weekends_expected`,

{{ pm_utils.diff_weekdays("'2024-03-14'", "'2024-03-23'") }} as `One_half_weekends`,
7 as `One_half_weekends_expected`,

{{ pm_utils.diff_weekdays("'2024-03-21'", "'2024-03-25'") }} as `One_weekend`,
3 as `One_weekend_expected`,

{{ pm_utils.diff_weekdays("'2024-03-21'", "'2024-03-24'") }} as `One_weekend_end`,
2 as `One_weekend_end_expected`,

{{ pm_utils.diff_weekdays("'2024-03-21'", "'2024-03-23'") }} as `Half_weekend`,
2 as `Half_weekend_expected`,

{{ pm_utils.diff_weekdays("'2024-03-16'", "'2024-03-19'") }} as `Start_weekend`,
2 as `Start_weekend_expected`,

{{ pm_utils.diff_weekdays("'2024-03-17'", "'2024-03-19'") }} as `Start_half_weekend`,
2 as `Start_half_weekend_expected`,

{{ pm_utils.diff_weekdays("'2024-03-16'", "'2024-03-17'") }} as `Only_weekend`,
0 as `Only_weekend_expected`
24 changes: 17 additions & 7 deletions macros/multiple_databases/datediff.sql
Original file line number Diff line number Diff line change
@@ -1,25 +1,35 @@
{%- macro datediff(datepart, start_date_field, end_date_field) -%}

{%- if target.type == 'snowflake' -%}
datediff({{ datepart }}, {{ start_date_field }}, {{ end_date_field }})
{%- elif target.type == 'sqlserver' -%}
{# Snowflake week is defined from Monday to Sunday. Add one day to align computation for week differences. #}
{%- if datepart == 'week' -%}
{# To calculate week differences, weeks start by default on Sunday. Change to align with Snowflake (week starts on Monday) #}
datediff_big({{ datepart }}, dateadd(day, -1, {{ start_date_field }}), dateadd(day, -1, {{ end_date_field }}))
datediff({{ datepart }}, dateadd(day, 1, {{ start_date_field }}), dateadd(day, 1, {{ end_date_field }}))
{%- else -%}
datediff_big({{ datepart }}, {{ start_date_field }}, {{ end_date_field }})
datediff({{ datepart }}, {{ start_date_field }}, {{ end_date_field }})
{%- endif -%}
{%- elif target.type == 'sqlserver' -%}
datediff_big({{ datepart }}, {{ start_date_field }}, {{ end_date_field }})
{%- elif target.type == 'databricks' -%}
{%- if datepart == 'millisecond' -%}
unix_millis(to_timestamp({{ end_date_field }})) - unix_millis(to_timestamp({{ start_date_field }}))
{%- elif datepart == 'second' -%}
unix_seconds(to_timestamp({{ end_date_field }})) - unix_seconds(to_timestamp({{ start_date_field }}))
{%- elif datepart == 'minute' -%}
bigint((unix_seconds(to_timestamp({{ end_date_field }})) - unix_seconds(to_timestamp({{ start_date_field }})))/60)
bigint((unix_seconds(to_timestamp({{ end_date_field }})) - unix_seconds(to_timestamp({{ start_date_field }}))) / 60)
{%- elif datepart == 'hour' -%}
bigint((unix_seconds(to_timestamp({{ end_date_field }})) - unix_seconds(to_timestamp({{ start_date_field }})))/3600)
bigint((unix_seconds(to_timestamp({{ end_date_field }})) - unix_seconds(to_timestamp({{ start_date_field }}))) / 3600)
{%- elif datepart == 'day' -%}
bigint(datediff({{ end_date_field }}, {{ start_date_field }}))
{%- elif datepart == 'week' -%}
case
when dayofweek({{ end_date_field }}) < dayofweek({{ start_date_field }})
then bigint(datediff({{ end_date_field }}, {{ start_date_field }}) / 7) + 1
else bigint(datediff({{ end_date_field }}, {{ start_date_field }}) / 7)
end
{%- elif datepart == 'month' -%}
bigint(months_between(to_timestamp({{ end_date_field }}), to_timestamp({{ start_date_field }})))
{%- elif datepart == 'quarter' -%}
bigint(quarter({{ end_date_field }}) - quarter({{ start_date_field }}) + 4 * (year({{ end_date_field }}) - year({{ start_date_field }})))
{%- elif datepart == 'year' -%}
bigint(year({{ end_date_field }}) - year({{ start_date_field }}))
{%- endif -%}
Expand Down
11 changes: 11 additions & 0 deletions macros/multiple_databases/diff_weekdays.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,11 @@
{%- macro diff_weekdays(start_date_field, end_date_field) -%}

{# Take two dates as input and compute the total number of days between the two dates. Also count it as one day in case the "from date" and the "to date" are on the same day.
From this total number of days, we subtract the weekend days (Saturday and Sunday). We use the function datediff with parameter week.
This function returns 1 for every complete week, where a week is defined from Sunday to Saturday.
Since the function only returns full weeks, we need to adjust the parameters to account for date ranges that start on Sunday or end at Saturday. #}
{{ pm_utils.datediff('day', start_date_field, end_date_field) }} + 1
- {{ pm_utils.datediff('week', start_date_field, pm_utils.dateadd('day', 1, end_date_field)) }}
- {{ pm_utils.datediff('week', pm_utils.dateadd('day', -1, start_date_field), end_date_field) }}

{%- endmacro -%}
Loading