Skip to content

Commit 96d672a

Browse files
committed
Testing cross-db macros
- Changed the implementation of datediff macro - Added newline at the end of file
1 parent edf4bd1 commit 96d672a

File tree

10 files changed

+67
-27
lines changed

10 files changed

+67
-27
lines changed

dbt/include/oracle/macros/utils/cast_bool_to_text.sql

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -20,4 +20,4 @@
2020
WHEN {{ bool_expression }} THEN 'true'
2121
ELSE 'false'
2222
END
23-
{% endmacro %}
23+
{% endmacro %}

dbt/include/oracle/macros/utils/dateadd.sql

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -28,4 +28,4 @@
2828
{% elif datepart.upper() == 'WEEK' %}
2929
{{ from_date_or_timestamp }} + 7*{{ interval }}
3030
{%- endif -%}
31-
{% endmacro %}
31+
{% endmacro %}

dbt/include/oracle/macros/utils/datediff.sql

Lines changed: 19 additions & 17 deletions
Original file line numberDiff line numberDiff line change
@@ -14,24 +14,26 @@
1414
See the License for the specific language governing permissions and
1515
limitations under the License.
1616
#}
17-
{# Returns difference (in integer) between 2 dates #}
17+
{# Returns difference (as an integer) in between 2 dates #}
1818
{% macro oracle__datediff(first_date, second_date, datepart) %}
19-
{%- set single_quote = "\'" -%}
20-
{%- set D2S_INTERVAL_UNITS = ['DAY', 'HOUR', 'MINUTE', 'SECOND'] -%}
21-
{% if datepart.upper() in D2S_INTERVAL_UNITS %}
22-
ROUND((CAST({{ second_date }} AS DATE) - CAST({{ first_date }} AS DATE)) *
23-
decode(upper({{single_quote ~ datepart ~ single_quote}}),
24-
'HOUR', 24,
25-
'MINUTE', 24*60,
26-
'SECOND', 24*60*60,
27-
1))
28-
{% elif datepart.upper() == 'WEEK' %}
29-
ROUND((CAST({{ second_date }} AS DATE) - CAST({{ first_date }} AS DATE))/7)
30-
{% elif datepart.upper() == 'MONTH' %}
31-
ROUND((MONTHS_BETWEEN(CAST({{second_date}} AS DATE), CAST({{first_date}} AS DATE))))
19+
{% if datepart.upper() == 'YEAR' %}
20+
ROUND(MONTHS_BETWEEN(TRUNC(CAST({{second_date}} AS DATE), 'YEAR'), TRUNC(CAST({{first_date}} AS DATE), 'YEAR'))/12)
3221
{% elif datepart.upper() == 'QUARTER' %}
33-
ROUND((MONTHS_BETWEEN(CAST({{second_date}} AS DATE), CAST({{first_date}} AS DATE))/3))
34-
{% elif datepart.upper() == 'YEAR' %}
35-
ROUND((MONTHS_BETWEEN(CAST({{second_date}} AS DATE), CAST({{first_date}} AS DATE))/12))
22+
ROUND(MONTHS_BETWEEN(TRUNC(CAST({{second_date}} AS DATE), 'Q'), TRUNC(CAST({{first_date}} AS DATE), 'Q'))/3)
23+
{% elif datepart.upper() == 'MONTH'%}
24+
ROUND(MONTHS_BETWEEN(TRUNC(CAST({{second_date}} AS DATE), 'MONTH'), TRUNC(CAST({{first_date}} AS DATE), 'MONTH')))
25+
{% elif datepart.upper() == 'WEEK' %}
26+
ROUND((TRUNC(CAST({{ second_date }} AS DATE), 'DAY') - TRUNC(CAST({{ first_date }} AS DATE), 'DAY'))/7)
27+
{% elif datepart.upper() == 'DAY' %}
28+
ROUND(TRUNC(CAST({{ second_date }} AS DATE), 'DD') - TRUNC(CAST({{ first_date }} AS DATE), 'DD'))
29+
{% elif datepart.upper() == 'HOUR' %}
30+
ROUND((TRUNC(CAST({{ second_date }} AS DATE), 'HH') - TRUNC(CAST({{ first_date }} AS DATE), 'HH'))*24)
31+
{% elif datepart.upper() == 'MINUTE' %}
32+
ROUND((TRUNC(CAST({{ second_date }} AS DATE), 'MI') - TRUNC(CAST({{ first_date }} AS DATE), 'MI'))*24*60)
33+
{% elif datepart.upper() == 'SECOND' %}
34+
EXTRACT(DAY FROM (CAST({{ second_date }} AS TIMESTAMP) - CAST({{ first_date }} AS TIMESTAMP)))*24*60*60
35+
+EXTRACT(HOUR FROM (CAST({{ second_date }} AS TIMESTAMP) - CAST({{ first_date }} AS TIMESTAMP)))*60*60
36+
+EXTRACT(MINUTE FROM (CAST({{ second_date }} AS TIMESTAMP) - CAST({{ first_date }} AS TIMESTAMP)))*60
37+
+EXTRACT(SECOND FROM (CAST({{ second_date }} AS TIMESTAMP) - CAST({{ first_date }} AS TIMESTAMP)))
3638
{% endif %}
3739
{% endmacro %}

dbt/include/oracle/macros/utils/datetrunc.sql

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -24,4 +24,4 @@
2424
{% endif %}
2525
{%- set single_quote = "\'" -%}
2626
TRUNC({{date}}, {{single_quote ~ datepart ~ single_quote}})
27-
{% endmacro %}
27+
{% endmacro %}

dbt/include/oracle/macros/utils/except.sql

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -17,4 +17,4 @@
1717

1818
{% macro oracle__except() %}
1919
MINUS
20-
{% endmacro %}
20+
{% endmacro %}

dbt/include/oracle/macros/utils/hash.sql

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -18,4 +18,4 @@
1818
{% macro oracle__hash(field, method='MD5') %}
1919
{%- set single_quote = "\'" -%}
2020
STANDARD_HASH({{field}}, {{single_quote ~ method ~ single_quote }})
21-
{% endmacro %}
21+
{% endmacro %}

dbt/include/oracle/macros/utils/last_day.sql

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -17,4 +17,4 @@
1717
{# Returns last day of the quarter, year or month #}
1818
{% macro oracle__last_day(date, datepart) %}
1919
{{dbt.dateadd('day', '-1', dbt.dateadd(datepart, '1', dbt.date_trunc(datepart, date)))}}
20-
{% endmacro %}
20+
{% endmacro %}

dbt/include/oracle/macros/utils/position.sql

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -17,4 +17,4 @@
1717

1818
{% macro oracle__position(substring_text, string_text) %}
1919
INSTR({{ string_text }}, {{ substring_text }})
20-
{% endmacro %}
20+
{% endmacro %}

dbt/include/oracle/macros/utils/right.sql

Lines changed: 2 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -14,7 +14,7 @@
1414
See the License for the specific language governing permissions and
1515
limitations under the License.
1616
#}
17-
17+
{# Returns N rightmost characters from a string #}
1818
{% macro oracle__right(string_text, length_expression) %}
1919

2020
case when {{ length_expression }} = 0
@@ -26,4 +26,4 @@
2626
)
2727
end
2828

29-
{%- endmacro -%}
29+
{%- endmacro -%}

tests/functional/adapter/utils/test_dateutils.py

Lines changed: 39 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -96,7 +96,45 @@
9696
result as expected
9797
9898
from data
99-
99+
-- Also test correct casting of literal values.
100+
union all
101+
select {{ datediff("TO_TIMESTAMP('1999-12-31 23:59:59.999999', 'YYYY-MM-DD HH24:MI:SS.FF')",
102+
"TO_TIMESTAMP('2000-01-01 00:00:00.000000', 'YYYY-MM-DD HH24:MI:SS.FF')",
103+
"minute") }} as actual,
104+
1 as expected FROM DUAL
105+
106+
union all
107+
select {{ datediff("TO_TIMESTAMP('1999-12-31 23:59:59.999999', 'YYYY-MM-DD HH24:MI:SS.FF')",
108+
"TO_TIMESTAMP('2000-01-01 00:00:00.000000', 'YYYY-MM-DD HH24:MI:SS.FF')",
109+
"hour") }} as actual,
110+
1 as expected FROM DUAL
111+
112+
union all
113+
select {{ datediff("TO_TIMESTAMP('1999-12-31 23:59:59.999999', 'YYYY-MM-DD HH24:MI:SS.FF')",
114+
"TO_TIMESTAMP('2000-01-01 00:00:00.000000', 'YYYY-MM-DD HH24:MI:SS.FF')",
115+
"day") }} as actual,
116+
1 as expected FROM DUAL
117+
118+
union all
119+
select {{ datediff("TO_TIMESTAMP('1999-12-31 23:59:59.999999', 'YYYY-MM-DD HH24:MI:SS.FF')",
120+
"TO_TIMESTAMP('2000-01-03 00:00:00.000000', 'YYYY-MM-DD HH24:MI:SS.FF')",
121+
"week") }} as actual,
122+
1 as expected FROM DUAL
123+
union all
124+
select {{ datediff("TO_TIMESTAMP('1999-12-31 23:59:59.999999', 'YYYY-MM-DD HH24:MI:SS.FF')",
125+
"TO_TIMESTAMP('2000-01-01 00:00:00.000000', 'YYYY-MM-DD HH24:MI:SS.FF')",
126+
"month") }} as actual,
127+
1 as expected FROM DUAL
128+
union all
129+
select {{ datediff("TO_TIMESTAMP('1999-12-31 23:59:59.999999', 'YYYY-MM-DD HH24:MI:SS.FF')",
130+
"TO_TIMESTAMP('2000-01-01 00:00:00.000000', 'YYYY-MM-DD HH24:MI:SS.FF')",
131+
"quarter") }} as actual,
132+
1 as expected FROM DUAL
133+
union all
134+
select {{ datediff("TO_TIMESTAMP('1999-12-31 23:59:59.999999', 'YYYY-MM-DD HH24:MI:SS.FF')",
135+
"TO_TIMESTAMP('2000-01-01 00:00:00.000000', 'YYYY-MM-DD HH24:MI:SS.FF')",
136+
"year") }} as actual,
137+
1 as expected FROM DUAL
100138
"""
101139

102140

0 commit comments

Comments
 (0)