Skip to content

Commit edf4bd1

Browse files
committed
More cross-db macros
- datediff - replace - added documentation
1 parent ddd4b0e commit edf4bd1

File tree

6 files changed

+143
-8
lines changed

6 files changed

+143
-8
lines changed

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

Lines changed: 4 additions & 4 deletions
Original file line numberDiff line numberDiff line change
@@ -17,11 +17,11 @@
1717

1818
{% macro oracle__dateadd(datepart, interval, from_date_or_timestamp) %}
1919
{%- set single_quote = "\'" -%}
20-
{%- set DS_INTERVAL_UNITS = ['DAY', 'HOUR', 'MINUTE', 'SECOND'] -%}
21-
{%- set MY_INTERVAL_UNITS = ['YEAR','MONTH'] -%}
22-
{%- if datepart.upper() in DS_INTERVAL_UNITS -%}
20+
{%- set D2S_INTERVAL_UNITS = ['DAY', 'HOUR', 'MINUTE', 'SECOND'] -%}
21+
{%- set M2Y_INTERVAL_UNITS = ['YEAR','MONTH'] -%}
22+
{%- if datepart.upper() in D2S_INTERVAL_UNITS -%}
2323
{{ from_date_or_timestamp }} + NUMTODSINTERVAL({{ interval }}, {{single_quote ~ datepart ~ single_quote}})
24-
{%- elif datepart.upper() in MY_INTERVAL_UNITS -%}
24+
{%- elif datepart.upper() in M2Y_INTERVAL_UNITS -%}
2525
{{ from_date_or_timestamp }} + NUMTOYMINTERVAL({{ interval }}, {{single_quote ~ datepart ~ single_quote}})
2626
{%- elif datepart.upper() == 'QUARTER' -%}
2727
ADD_MONTHS({{ from_date_or_timestamp }}, 3*{{ interval }})
Lines changed: 37 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,37 @@
1+
{#
2+
Copyright (c) 2022, Oracle and/or its affiliates.
3+
Copyright (c) 2020, Vitor Avancini
4+
5+
Licensed under the Apache License, Version 2.0 (the "License");
6+
you may not use this file except in compliance with the License.
7+
You may obtain a copy of the License at
8+
9+
https://www.apache.org/licenses/LICENSE-2.0
10+
11+
Unless required by applicable law or agreed to in writing, software
12+
distributed under the License is distributed on an "AS IS" BASIS,
13+
WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
14+
See the License for the specific language governing permissions and
15+
limitations under the License.
16+
#}
17+
{# Returns difference (in integer) between 2 dates #}
18+
{% 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))))
32+
{% 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))
36+
{% endif %}
37+
{% endmacro %}

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

Lines changed: 1 addition & 1 deletion
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 date with the 'datepart' portion truncated #}
1818
{% macro oracle__date_trunc(datepart, date) %}
1919
{% if datepart.upper() == 'QUARTER' %}
2020
{% set datepart = 'Q' %}

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

Lines changed: 1 addition & 1 deletion
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 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)))}}
2020
{% endmacro %}

tests/functional/adapter/utils/test_common_utils.py

Lines changed: 40 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -27,10 +27,12 @@
2727
from dbt.tests.adapter.utils.test_right import BaseRight
2828
from dbt.tests.adapter.utils.test_cast_bool_to_text import BaseCastBoolToText
2929
from dbt.tests.adapter.utils.test_replace import BaseReplace
30+
from dbt.tests.adapter.utils.test_length import BaseLength
3031

3132
from dbt.tests.adapter.utils.fixture_cast_bool_to_text import models__test_cast_bool_to_text_yml
3233
from dbt.tests.adapter.utils.fixture_escape_single_quotes import models__test_escape_single_quotes_yml
3334
from dbt.tests.adapter.utils.fixture_string_literal import models__test_string_literal_yml
35+
from dbt.tests.adapter.utils.fixture_replace import models__test_replace_yml
3436

3537

3638
# Oracle requires FROM DUAL
@@ -68,6 +70,29 @@
6870
from data
6971
"""
7072

73+
models__test_replace_sql = """
74+
with data as (
75+
76+
select
77+
78+
string_text,
79+
coalesce(search_chars, '') as old_chars,
80+
coalesce(replace_chars, '') as new_chars,
81+
result
82+
83+
from {{ ref('data_replace') }}
84+
85+
)
86+
87+
select
88+
89+
{{ replace('string_text', 'old_chars', 'new_chars') }} as actual,
90+
result as expected
91+
92+
from data
93+
"""
94+
95+
7196
class TestCastBoolToText(BaseCastBoolToText):
7297

7398
@pytest.fixture(scope="class")
@@ -131,5 +156,18 @@ class TestStringRight(BaseRight):
131156
pass
132157

133158

134-
# class TestStringReplace(BaseReplace):
135-
# pass
159+
class TestStringReplace(BaseReplace):
160+
161+
@pytest.fixture(scope="class")
162+
def models(self):
163+
return {
164+
"test_replace.yml": models__test_replace_yml,
165+
"test_replace.sql": self.interpolate_macro_namespace(
166+
models__test_replace_sql, "replace"
167+
),
168+
}
169+
170+
171+
class TestStringLength(BaseLength):
172+
pass
173+

tests/functional/adapter/utils/test_dateutils.py

Lines changed: 60 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -19,8 +19,10 @@
1919
from dbt.tests.adapter.utils.test_dateadd import BaseDateAdd
2020
from dbt.tests.adapter.utils.test_last_day import BaseLastDay
2121
from dbt.tests.adapter.utils.test_date_trunc import BaseDateTrunc
22+
from dbt.tests.adapter.utils.test_datediff import BaseDateDiff
2223

2324
from dbt.tests.adapter.utils.fixture_dateadd import models__test_dateadd_yml
25+
from dbt.tests.adapter.utils.fixture_datediff import models__test_datediff_yml
2426

2527
seeds__data_date_trunc_csv = """updated_at,day,month
2628
2018-01-05 12:00:00,2017-12-31 00:00:00,2018-01-01 00:00:00
@@ -56,6 +58,48 @@
5658
"""
5759

5860

61+
seeds__data_datediff_csv = """first_date,second_date,datepart,result
62+
2018-01-01 01:00:00,2018-01-02 01:00:00,day,1
63+
2018-01-01 01:00:00,2018-02-01 01:00:00,month,1
64+
2018-01-01 01:00:00,2019-01-01 01:00:00,year,1
65+
2018-01-01 01:00:00,2018-01-01 02:00:00,hour,1
66+
2018-01-01 01:00:00,2018-01-01 02:01:00,minute,61
67+
2018-01-01 01:00:00,2018-01-01 02:00:01,second,3601
68+
2019-12-31 00:00:00,2019-12-27 00:00:00,week,-1
69+
2019-12-31 00:00:00,2019-12-30 00:00:00,week,0
70+
2019-12-31 00:00:00,2020-01-02 00:00:00,week,0
71+
2019-12-31 00:00:00,2020-01-06 02:00:00,week,1
72+
,2018-01-01 02:00:00,hour,
73+
2018-01-01 02:00:00,,hour,
74+
"""
75+
76+
77+
models__test_datediff_sql = """
78+
with data as (
79+
80+
select * from {{ ref('data_datediff') }}
81+
82+
)
83+
84+
select
85+
86+
case
87+
when datepart = 'second' then {{ datediff('first_date', 'second_date', 'second') }}
88+
when datepart = 'minute' then {{ datediff('first_date', 'second_date', 'minute') }}
89+
when datepart = 'hour' then {{ datediff('first_date', 'second_date', 'hour') }}
90+
when datepart = 'day' then {{ datediff('first_date', 'second_date', 'day') }}
91+
when datepart = 'week' then {{ datediff('first_date', 'second_date', 'week') }}
92+
when datepart = 'month' then {{ datediff('first_date', 'second_date', 'month') }}
93+
when datepart = 'year' then {{ datediff('first_date', 'second_date', 'year') }}
94+
else null
95+
end as actual,
96+
result as expected
97+
98+
from data
99+
100+
"""
101+
102+
59103
class TestDateAdd(BaseDateAdd):
60104

61105
@pytest.fixture(scope="class")
@@ -81,3 +125,19 @@ def seeds(self):
81125

82126
class TestLastDay(BaseLastDay):
83127
pass
128+
129+
130+
class TestDateDiff(BaseDateDiff):
131+
132+
@pytest.fixture(scope="class")
133+
def seeds(self):
134+
return {"data_datediff.csv": seeds__data_datediff_csv}
135+
136+
@pytest.fixture(scope="class")
137+
def models(self):
138+
return {
139+
"test_datediff.yml": models__test_datediff_yml,
140+
"test_datediff.sql": self.interpolate_macro_namespace(
141+
models__test_datediff_sql, "datediff"
142+
),
143+
}

0 commit comments

Comments
 (0)