From 25761d11edd6412a1cf0ac79c7dc4fd4ec134e37 Mon Sep 17 00:00:00 2001 From: Mjumbe Poe Date: Tue, 28 Jan 2020 18:51:18 -0500 Subject: [PATCH 1/8] Add datediff implementation for postgres --- .../data/cross_db/data_datediff.csv | 6 +++ .../models/cross_db_utils/test_datediff.sql | 46 +++++++++++++------ macros/cross_db_utils/datediff.sql | 26 ++++++++++- 3 files changed, 62 insertions(+), 16 deletions(-) diff --git a/integration_tests/data/cross_db/data_datediff.csv b/integration_tests/data/cross_db/data_datediff.csv index 5d266969..852573de 100644 --- a/integration_tests/data/cross_db/data_datediff.csv +++ b/integration_tests/data/cross_db/data_datediff.csv @@ -2,6 +2,12 @@ first_date,second_date,datepart,result 2018-01-01 01:00:00,2018-01-02 01:00:00,day,1 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 +1985-01-01 01:00:00,2019-01-01 01:00:00,decade,3 +1985-01-01 01:00:00,2019-01-01 01:00:00,century,1 +1985-01-01 01:00:00,2019-01-01 01:00:00,millennium,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-30 01:00:00,2020-01-06 02:00:00,week,1 ,2018-01-01 02:00:00,hour, 2018-01-01 02:00:00,,hour, diff --git a/integration_tests/models/cross_db_utils/test_datediff.sql b/integration_tests/models/cross_db_utils/test_datediff.sql index acb7c217..d3aefd7b 100644 --- a/integration_tests/models/cross_db_utils/test_datediff.sql +++ b/integration_tests/models/cross_db_utils/test_datediff.sql @@ -6,19 +6,37 @@ 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') }} + when datepart = 'decade' then {{ dbt_utils.datediff('first_date', 'second_date', 'decade') }} + when datepart = 'century' then {{ dbt_utils.datediff('first_date', 'second_date', 'century') }} + when datepart = 'millennium' then {{ dbt_utils.datediff('first_date', 'second_date', 'millennium') }} + 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-01 00:00:00.000000'", "week") }} as actual, 0 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 +union all select {{ dbt_utils.datediff("'1999-12-31 23:59:59.999999'", "'2000-01-01 00:00:00.000000'", "decade") }} as actual, 1 as expected +union all select {{ dbt_utils.datediff("'1999-12-31 23:59:59.999999'", "'2001-01-01 00:00:00.000000'", "century") }} as actual, 1 as expected +union all select {{ dbt_utils.datediff("'1999-12-31 23:59:59.999999'", "'2001-01-01 00:00:00.000000'", "millennium") }} as actual, 1 as expected diff --git a/macros/cross_db_utils/datediff.sql b/macros/cross_db_utils/datediff.sql index 546a7a62..e498f7be 100644 --- a/macros/cross_db_utils/datediff.sql +++ b/macros/cross_db_utils/datediff.sql @@ -20,13 +20,35 @@ 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 in ('year', 'decade', 'century', 'millennium') %} + (date_part('{{datepart}}', {{second_date}}::date) - date_part('{{datepart}}', {{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' %} + (floor({{ dbt_utils.datediff(first_date, second_date, 'day') }} / 7) + case when date_part('dow', {{second_date}}::timestamp) < date_part('dow', {{first_date}}::timestamp) then 1 else 0 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 %} From 5ae9c4f2addd14a90907c66bc9bdbada32984213 Mon Sep 17 00:00:00 2001 From: Mjumbe Poe Date: Tue, 28 Jan 2020 18:53:07 -0500 Subject: [PATCH 2/8] Remove unnecessary floor --- macros/cross_db_utils/datediff.sql | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/macros/cross_db_utils/datediff.sql b/macros/cross_db_utils/datediff.sql index e498f7be..a5fd3636 100644 --- a/macros/cross_db_utils/datediff.sql +++ b/macros/cross_db_utils/datediff.sql @@ -36,7 +36,7 @@ {% elif datepart == 'day' %} ({{second_date}}::date - {{first_date}}::date) {% elif datepart == 'week' %} - (floor({{ dbt_utils.datediff(first_date, second_date, 'day') }} / 7) + case when date_part('dow', {{second_date}}::timestamp) < date_part('dow', {{first_date}}::timestamp) then 1 else 0 end) + ({{ dbt_utils.datediff(first_date, second_date, 'day') }} / 7 + case when date_part('dow', {{second_date}}::timestamp) < date_part('dow', {{first_date}}::timestamp) then 1 else 0 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' %} From 5d0d8df6c3558d6ccb33f99488405a6522feaefc Mon Sep 17 00:00:00 2001 From: Mjumbe Poe Date: Tue, 28 Jan 2020 19:07:45 -0500 Subject: [PATCH 3/8] Wrap inputs in parentheses before casting in datediff --- macros/cross_db_utils/datediff.sql | 20 ++++++++++---------- 1 file changed, 10 insertions(+), 10 deletions(-) diff --git a/macros/cross_db_utils/datediff.sql b/macros/cross_db_utils/datediff.sql index a5fd3636..a7e9425d 100644 --- a/macros/cross_db_utils/datediff.sql +++ b/macros/cross_db_utils/datediff.sql @@ -28,25 +28,25 @@ {% macro postgres__datediff(first_date, second_date, datepart) %} {% if datepart in ('year', 'decade', 'century', 'millennium') %} - (date_part('{{datepart}}', {{second_date}}::date) - date_part('{{datepart}}', {{first_date}}::date)) + (date_part('{{datepart}}', ({{second_date}})::date) - date_part('{{datepart}}', ({{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)) + ({{ 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)) + ({{ 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) + (({{second_date}})::date - ({{first_date}})::date) {% elif datepart == 'week' %} - ({{ dbt_utils.datediff(first_date, second_date, 'day') }} / 7 + case when date_part('dow', {{second_date}}::timestamp) < date_part('dow', {{first_date}}::timestamp) then 1 else 0 end) + ({{ dbt_utils.datediff(first_date, second_date, 'day') }} / 7 + case when date_part('dow', ({{second_date}})::timestamp) < date_part('dow', ({{first_date}})::timestamp) then 1 else 0 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)) + ({{ 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)) + ({{ 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))) + ({{ 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))) + ({{ 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))) + ({{ 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 %} From 8a314616081e4ab00240f5c482a130c69bc3b2d6 Mon Sep 17 00:00:00 2001 From: Mjumbe Poe Date: Mon, 24 Feb 2020 13:49:27 -0500 Subject: [PATCH 4/8] Fix week diffing Since postgres rounds integer division toward 0, we should treat positive and negative date differences distinctly --- integration_tests/models/cross_db_utils/test_datediff.sql | 1 + macros/cross_db_utils/datediff.sql | 4 +++- 2 files changed, 4 insertions(+), 1 deletion(-) diff --git a/integration_tests/models/cross_db_utils/test_datediff.sql b/integration_tests/models/cross_db_utils/test_datediff.sql index d3aefd7b..66294749 100644 --- a/integration_tests/models/cross_db_utils/test_datediff.sql +++ b/integration_tests/models/cross_db_utils/test_datediff.sql @@ -32,6 +32,7 @@ union all select {{ dbt_utils.datediff("'1999-12-31 23:59:59.999999'", "'2000-01 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'", "'1999-12-30 00:00:00.000000'", "week") }} as actual, 0 as expected union all select {{ dbt_utils.datediff("'1999-12-31 23:59:59.999999'", "'2000-01-01 00:00:00.000000'", "week") }} as actual, 0 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 diff --git a/macros/cross_db_utils/datediff.sql b/macros/cross_db_utils/datediff.sql index a7e9425d..67a38282 100644 --- a/macros/cross_db_utils/datediff.sql +++ b/macros/cross_db_utils/datediff.sql @@ -35,8 +35,10 @@ ({{ 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' %} + {% elif datepart == 'week' and first_date <= second_date %} ({{ dbt_utils.datediff(first_date, second_date, 'day') }} / 7 + case when date_part('dow', ({{second_date}})::timestamp) < date_part('dow', ({{first_date}})::timestamp) then 1 else 0 end) + {% elif datepart == 'week' %} + ({{ dbt_utils.datediff(first_date, second_date, 'day') }} / 7 + case when date_part('dow', ({{second_date}})::timestamp) > date_part('dow', ({{first_date}})::timestamp) then 1 else 0 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' %} From 1a72530f05803b0d9aeb9c563671c31a43c36ba8 Mon Sep 17 00:00:00 2001 From: Mjumbe Poe Date: Mon, 24 Feb 2020 13:50:00 -0500 Subject: [PATCH 5/8] Get rid of uncommon diff units (decade, century, millenium) --- integration_tests/models/cross_db_utils/test_datediff.sql | 6 ------ macros/cross_db_utils/datediff.sql | 4 ++-- 2 files changed, 2 insertions(+), 8 deletions(-) diff --git a/integration_tests/models/cross_db_utils/test_datediff.sql b/integration_tests/models/cross_db_utils/test_datediff.sql index 66294749..503b3f17 100644 --- a/integration_tests/models/cross_db_utils/test_datediff.sql +++ b/integration_tests/models/cross_db_utils/test_datediff.sql @@ -15,9 +15,6 @@ select 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') }} - when datepart = 'decade' then {{ dbt_utils.datediff('first_date', 'second_date', 'decade') }} - when datepart = 'century' then {{ dbt_utils.datediff('first_date', 'second_date', 'century') }} - when datepart = 'millennium' then {{ dbt_utils.datediff('first_date', 'second_date', 'millennium') }} else null end as actual, result as expected @@ -38,6 +35,3 @@ union all select {{ dbt_utils.datediff("'1999-12-31 23:59:59.999999'", "'2000-01 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 -union all select {{ dbt_utils.datediff("'1999-12-31 23:59:59.999999'", "'2000-01-01 00:00:00.000000'", "decade") }} as actual, 1 as expected -union all select {{ dbt_utils.datediff("'1999-12-31 23:59:59.999999'", "'2001-01-01 00:00:00.000000'", "century") }} as actual, 1 as expected -union all select {{ dbt_utils.datediff("'1999-12-31 23:59:59.999999'", "'2001-01-01 00:00:00.000000'", "millennium") }} as actual, 1 as expected diff --git a/macros/cross_db_utils/datediff.sql b/macros/cross_db_utils/datediff.sql index 67a38282..00822687 100644 --- a/macros/cross_db_utils/datediff.sql +++ b/macros/cross_db_utils/datediff.sql @@ -27,8 +27,8 @@ {% macro postgres__datediff(first_date, second_date, datepart) %} - {% if datepart in ('year', 'decade', 'century', 'millennium') %} - (date_part('{{datepart}}', ({{second_date}})::date) - date_part('{{datepart}}', ({{first_date}})::date)) + {% 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' %} From bfae48e9709cbf28f15c9c46064de92d079e9675 Mon Sep 17 00:00:00 2001 From: Mjumbe Poe Date: Mon, 24 Feb 2020 13:57:43 -0500 Subject: [PATCH 6/8] Remove unnecessary seed data --- integration_tests/data/cross_db/data_datediff.csv | 3 --- 1 file changed, 3 deletions(-) diff --git a/integration_tests/data/cross_db/data_datediff.csv b/integration_tests/data/cross_db/data_datediff.csv index 852573de..7363244f 100644 --- a/integration_tests/data/cross_db/data_datediff.csv +++ b/integration_tests/data/cross_db/data_datediff.csv @@ -2,9 +2,6 @@ first_date,second_date,datepart,result 2018-01-01 01:00:00,2018-01-02 01:00:00,day,1 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 -1985-01-01 01:00:00,2019-01-01 01:00:00,decade,3 -1985-01-01 01:00:00,2019-01-01 01:00:00,century,1 -1985-01-01 01:00:00,2019-01-01 01:00:00,millennium,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 From 2b1f3bcff655cdf4801d2d69e71342374dfb9f73 Mon Sep 17 00:00:00 2001 From: Mjumbe Poe Date: Mon, 24 Feb 2020 14:12:31 -0500 Subject: [PATCH 7/8] Rearrange datediff tests Week calculation tests are more about correctness than parsing, so belong in the seed data. --- integration_tests/data/cross_db/data_datediff.csv | 5 ++++- integration_tests/models/cross_db_utils/test_datediff.sql | 2 -- 2 files changed, 4 insertions(+), 3 deletions(-) diff --git a/integration_tests/data/cross_db/data_datediff.csv b/integration_tests/data/cross_db/data_datediff.csv index 7363244f..57b0da4e 100644 --- a/integration_tests/data/cross_db/data_datediff.csv +++ b/integration_tests/data/cross_db/data_datediff.csv @@ -5,6 +5,9 @@ first_date,second_date,datepart,result 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-30 01:00:00,2020-01-06 02:00:00,week,1 +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, diff --git a/integration_tests/models/cross_db_utils/test_datediff.sql b/integration_tests/models/cross_db_utils/test_datediff.sql index 503b3f17..a2340456 100644 --- a/integration_tests/models/cross_db_utils/test_datediff.sql +++ b/integration_tests/models/cross_db_utils/test_datediff.sql @@ -29,8 +29,6 @@ union all select {{ dbt_utils.datediff("'1999-12-31 23:59:59.999999'", "'2000-01 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'", "'1999-12-30 00:00:00.000000'", "week") }} as actual, 0 as expected -union all select {{ dbt_utils.datediff("'1999-12-31 23:59:59.999999'", "'2000-01-01 00:00:00.000000'", "week") }} as actual, 0 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 From 7871a2108c63a99bce3c95a84ddf7add3ff8aba4 Mon Sep 17 00:00:00 2001 From: Mjumbe Poe Date: Mon, 24 Feb 2020 15:58:32 -0500 Subject: [PATCH 8/8] Fix week comparison first_date and second_date need to be compared in sql instead of jinja, as their values are going to come from the sql data. --- macros/cross_db_utils/datediff.sql | 9 ++++++--- 1 file changed, 6 insertions(+), 3 deletions(-) diff --git a/macros/cross_db_utils/datediff.sql b/macros/cross_db_utils/datediff.sql index 00822687..c0c1e7d4 100644 --- a/macros/cross_db_utils/datediff.sql +++ b/macros/cross_db_utils/datediff.sql @@ -35,10 +35,13 @@ ({{ 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' and first_date <= second_date %} - ({{ dbt_utils.datediff(first_date, second_date, 'day') }} / 7 + case when date_part('dow', ({{second_date}})::timestamp) < date_part('dow', ({{first_date}})::timestamp) then 1 else 0 end) {% elif datepart == 'week' %} - ({{ dbt_utils.datediff(first_date, second_date, 'day') }} / 7 + case when date_part('dow', ({{second_date}})::timestamp) > date_part('dow', ({{first_date}})::timestamp) then 1 else 0 end) + ({{ 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' %}