Skip to content

Add a datediff implementation for postgres #187

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

Merged
merged 8 commits into from
Feb 25, 2020
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
6 changes: 6 additions & 0 deletions integration_tests/data/cross_db/data_datediff.csv
Original file line number Diff line number Diff line change
Expand Up @@ -3,5 +3,11 @@ first_date,second_date,datepart,result
2018-01-01 01:00:00,2018-02-01 01:00:00,month,1
2018-01-01 01:00:00,2019-01-01 01:00:00,year,1
2018-01-01 01:00:00,2018-01-01 02:00:00,hour,1
2018-01-01 01:00:00,2018-01-01 02:01:00,minute,61
2018-01-01 01:00:00,2018-01-01 02:00:01,second,3601
2019-12-31 00:00:00,2019-12-27 00:00:00,week,-1
2019-12-31 00:00:00,2019-12-30 00:00:00,week,0
2019-12-31 00:00:00,2020-01-02 00:00:00,week,0
2019-12-31 00:00:00,2020-01-06 02:00:00,week,1
,2018-01-01 02:00:00,hour,
2018-01-01 02:00:00,,hour,
39 changes: 25 additions & 14 deletions integration_tests/models/cross_db_utils/test_datediff.sql
Original file line number Diff line number Diff line change
Expand Up @@ -6,19 +6,30 @@ with data as (
)

select
-- not implemented for postgres
{% if target.type == 'postgres' %}
null::text as actual,
null::text as expected
{% else %}
case
when datepart = 'hour' then {{ dbt_utils.datediff('first_date', 'second_date', 'hour') }}
when datepart = 'day' then {{ dbt_utils.datediff('first_date', 'second_date', 'day') }}
when datepart = 'month' then {{ dbt_utils.datediff('first_date', 'second_date', 'month') }}
when datepart = 'year' then {{ dbt_utils.datediff('first_date', 'second_date', 'year') }}
else null
end as actual,
result as expected
{% endif %}

case
when datepart = 'second' then {{ dbt_utils.datediff('first_date', 'second_date', 'second') }}
when datepart = 'minute' then {{ dbt_utils.datediff('first_date', 'second_date', 'minute') }}
when datepart = 'hour' then {{ dbt_utils.datediff('first_date', 'second_date', 'hour') }}
when datepart = 'day' then {{ dbt_utils.datediff('first_date', 'second_date', 'day') }}
when datepart = 'week' then {{ dbt_utils.datediff('first_date', 'second_date', 'week') }}
when datepart = 'month' then {{ dbt_utils.datediff('first_date', 'second_date', 'month') }}
when datepart = 'year' then {{ dbt_utils.datediff('first_date', 'second_date', 'year') }}
else null
end as actual,
result as expected

from data

-- Also test correct casting of literal values.

union all select {{ dbt_utils.datediff("'1999-12-31 23:59:59.999999'", "'2000-01-01 00:00:00.000000'", "microsecond") }} as actual, 1 as expected
union all select {{ dbt_utils.datediff("'1999-12-31 23:59:59.999999'", "'2000-01-01 00:00:00.000000'", "millisecond") }} as actual, 1 as expected
union all select {{ dbt_utils.datediff("'1999-12-31 23:59:59.999999'", "'2000-01-01 00:00:00.000000'", "second") }} as actual, 1 as expected
union all select {{ dbt_utils.datediff("'1999-12-31 23:59:59.999999'", "'2000-01-01 00:00:00.000000'", "minute") }} as actual, 1 as expected
union all select {{ dbt_utils.datediff("'1999-12-31 23:59:59.999999'", "'2000-01-01 00:00:00.000000'", "hour") }} as actual, 1 as expected
union all select {{ dbt_utils.datediff("'1999-12-31 23:59:59.999999'", "'2000-01-01 00:00:00.000000'", "day") }} as actual, 1 as expected
union all select {{ dbt_utils.datediff("'1999-12-31 23:59:59.999999'", "'2000-01-03 00:00:00.000000'", "week") }} as actual, 1 as expected
union all select {{ dbt_utils.datediff("'1999-12-31 23:59:59.999999'", "'2000-01-01 00:00:00.000000'", "month") }} as actual, 1 as expected
union all select {{ dbt_utils.datediff("'1999-12-31 23:59:59.999999'", "'2000-01-01 00:00:00.000000'", "quarter") }} as actual, 1 as expected
union all select {{ dbt_utils.datediff("'1999-12-31 23:59:59.999999'", "'2000-01-01 00:00:00.000000'", "year") }} as actual, 1 as expected
31 changes: 29 additions & 2 deletions macros/cross_db_utils/datediff.sql
Original file line number Diff line number Diff line change
Expand Up @@ -20,13 +20,40 @@
cast({{second_date}} as datetime),
cast({{first_date}} as datetime),
{{datepart}}
)
)

{% endmacro %}


{% macro postgres__datediff(first_date, second_date, datepart) %}

{{ exceptions.raise_compiler_error("macro datediff not implemented for this adapter") }}
{% if datepart == 'year' %}
(date_part('year', ({{second_date}})::date) - date_part('year', ({{first_date}})::date))
{% elif datepart == 'quarter' %}
({{ dbt_utils.datediff(first_date, second_date, 'year') }} * 4 + date_part('quarter', ({{second_date}})::date) - date_part('quarter', ({{first_date}})::date))
{% elif datepart == 'month' %}
({{ dbt_utils.datediff(first_date, second_date, 'year') }} * 12 + date_part('month', ({{second_date}})::date) - date_part('month', ({{first_date}})::date))
{% elif datepart == 'day' %}
(({{second_date}})::date - ({{first_date}})::date)
{% elif datepart == 'week' %}
({{ dbt_utils.datediff(first_date, second_date, 'day') }} / 7 + case
when date_part('dow', ({{first_date}})::timestamp) <= date_part('dow', ({{second_date}})::timestamp) then
case when {{first_date}} <= {{second_date}} then 0 else -1 end
else
case when {{first_date}} <= {{second_date}} then 1 else 0 end
end)
{% elif datepart == 'hour' %}
({{ dbt_utils.datediff(first_date, second_date, 'day') }} * 24 + date_part('hour', ({{second_date}})::timestamp) - date_part('hour', ({{first_date}})::timestamp))
{% elif datepart == 'minute' %}
({{ dbt_utils.datediff(first_date, second_date, 'hour') }} * 60 + date_part('minute', ({{second_date}})::timestamp) - date_part('minute', ({{first_date}})::timestamp))
{% elif datepart == 'second' %}
({{ dbt_utils.datediff(first_date, second_date, 'minute') }} * 60 + floor(date_part('second', ({{second_date}})::timestamp)) - floor(date_part('second', ({{first_date}})::timestamp)))
{% elif datepart == 'millisecond' %}
({{ dbt_utils.datediff(first_date, second_date, 'minute') }} * 60000 + floor(date_part('millisecond', ({{second_date}})::timestamp)) - floor(date_part('millisecond', ({{first_date}})::timestamp)))
{% elif datepart == 'microsecond' %}
({{ dbt_utils.datediff(first_date, second_date, 'minute') }} * 60000000 + floor(date_part('microsecond', ({{second_date}})::timestamp)) - floor(date_part('microsecond', ({{first_date}})::timestamp)))
{% else %}
{{ exceptions.raise_compiler_error("Unsupported datepart for macro datediff in postgres: {!r}".format(datepart)) }}
{% endif %}

{% endmacro %}