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

Remove dependency on dbt-utils #91

Merged
merged 2 commits into from
Nov 18, 2022
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
106 changes: 54 additions & 52 deletions README.md
Original file line number Diff line number Diff line change
Expand Up @@ -4,8 +4,6 @@

Extension package for [**dbt**](https://github.com/dbt-labs/dbt) to handle date logic and calendar functionality.

FYI: this package includes [**dbt-utils**](https://github.com/dbt-labs/dbt-utils) so there"s no need to also import dbt-utils in your local project. (In fact, you may get an error if you do.)

Include in `packages.yml`

```yaml
Expand All @@ -15,7 +13,13 @@ packages:
# <see https://github.com/calogica/dbt-date/releases/latest> for the latest version tag
```

Note: we no longer include `spark_utils` in this package to avoid versioning conflicts. If you are running this package on non-core (Snowflake, BigQuery, Redshift, Postgres) platforms, you will need to use a package like `spark_utils` to shim macros.
This package supports:

* Postgres
* Snowflake
* BigQuery

For other platforms, you will have to include a shim package for the platform, such as `spark-utils`, or `tsql-utils`.

For example, in `packages.yml`, you will need to include the relevant package:

Expand Down Expand Up @@ -43,65 +47,54 @@ vars:
You may specify [any valid timezone string](https://en.wikipedia.org/wiki/List_of_tz_database_time_zones) in place of `America/Los_Angeles`.
For example, use `America/New_York` for East Coast Time.

## Integration Tests (Developers Only)

This project contains integration tests for all test macros in a separate `integration_tests` dbt project contained in this repo.

To run the tests:

1. You will need a profile called `integration_tests` in `~/.dbt/profiles.yml` pointing to a writable database. We only support postgres, BigQuery and Snowflake.
2. Then, from within the `integration_tests` folder, run `dbt build` to run the test models in `integration_tests/models/schema_tests/` and run the tests specified in `integration_tests/models/schema_tests/schema.yml`

## Available Tests

## Available Macros

### Date Dimension

- [get_base_dates](#get_base_datesstart_datenone-end_datenone-n_datepartsnone-datepartday)
- [get_date_dimension](#get_date_dimensionstart_date-end_date)
* [get_base_dates](#get_base_datesstart_datenone-end_datenone-n_datepartsnone-datepartday)
* [get_date_dimension](#get_date_dimensionstart_date-end_date)

### Calendar Date

- [convert_timezone](#convert_timezone-column-target_tznone-source_tznone)
- [date_part](#date_partdatepart-date)
- [day_name](#day_namedate-shorttrue)
- [day_of_month](#day_of_monthdate)
- [day_of_week](#day_of_weekdate-isoweektrue)
- [day_of_year](#day_of_yeardate)
- [from_unixtimestamp](#from_unixtimestampepochs-formatseconds)
- [iso_week_end](#iso_week_enddatenone-tznone)
- [iso_week_of_year](#iso_week_of_yeardatenone-tznone)
- [iso_week_start](#iso_week_startdatenone-tznone)
- [last_month_name](#last_month_nameshorttrue-tznone)
- [last_month_number](#last_month_numbertznone)
- [last_month](#last_monthtznone)
- [last_week](#last_weektznone)
- [month_name](#month_namedate-shorttrue-tznone)
- [n_days_ago](#n_days_agon-datenone-tznone)
- [n_days_away](#n_days_awayn-datenone-tznone)
- [n_months_ago](#n_months_agon-tznone)
- [n_months_away](#n_months_awayn-tznone)
- [n_weeks_ago](#n_weeks_agon-tznone)
- [n_weeks_away](#n_weeks_awayn-tznone)
- [next_month_name](#next_month_nameshorttrue-tznone)
- [next_month_number](#next_month_numbertznone)
- [next_month](#next_monthtznone)
- [next_week](#next_weektznone)
- [now](#nowtznone)
- [periods_since](#periods_sincedate_col-period_nameday-tznone)
- [round_timestamp](#round_timestamptimestamp)
- [to_unixtimestamp](#to_unixtimestamptimestamp)
- [today](#todaytznone)
- [tomorrow](#tomorrowdatenone-tznone)
- [week_end](#week_enddatenone-tznone)
- [week_of_year](#week_of_yeardatenone-tznone)
- [week_start](#week_startdatenone-tznone)
- [yesterday](#yesterdaydatenone-tznone)
* [convert_timezone](#convert_timezone-column-target_tznone-source_tznone)
* [date_part](#date_partdatepart-date)
* [day_name](#day_namedate-shorttrue)
* [day_of_month](#day_of_monthdate)
* [day_of_week](#day_of_weekdate-isoweektrue)
* [day_of_year](#day_of_yeardate)
* [from_unixtimestamp](#from_unixtimestampepochs-formatseconds)
* [iso_week_end](#iso_week_enddatenone-tznone)
* [iso_week_of_year](#iso_week_of_yeardatenone-tznone)
* [iso_week_start](#iso_week_startdatenone-tznone)
* [last_month_name](#last_month_nameshorttrue-tznone)
* [last_month_number](#last_month_numbertznone)
* [last_month](#last_monthtznone)
* [last_week](#last_weektznone)
* [month_name](#month_namedate-shorttrue-tznone)
* [n_days_ago](#n_days_agon-datenone-tznone)
* [n_days_away](#n_days_awayn-datenone-tznone)
* [n_months_ago](#n_months_agon-tznone)
* [n_months_away](#n_months_awayn-tznone)
* [n_weeks_ago](#n_weeks_agon-tznone)
* [n_weeks_away](#n_weeks_awayn-tznone)
* [next_month_name](#next_month_nameshorttrue-tznone)
* [next_month_number](#next_month_numbertznone)
* [next_month](#next_monthtznone)
* [next_week](#next_weektznone)
* [now](#nowtznone)
* [periods_since](#periods_sincedate_col-period_nameday-tznone)
* [round_timestamp](#round_timestamptimestamp)
* [to_unixtimestamp](#to_unixtimestamptimestamp)
* [today](#todaytznone)
* [tomorrow](#tomorrowdatenone-tznone)
* [week_end](#week_enddatenone-tznone)
* [week_of_year](#week_of_yeardatenone-tznone)
* [week_start](#week_startdatenone-tznone)
* [yesterday](#yesterdaydatenone-tznone)

## Fiscal Date

- [get_fiscal_periods](#get_fiscal_periodsdates-year_end_month-week_start_day-shift_year1)
* [get_fiscal_periods](#get_fiscal_periodsdates-year_end_month-week_start_day-shift_year1)

## Documentation

Expand Down Expand Up @@ -801,3 +794,12 @@ or, optionally, you can override the default timezone:
```sql
{{ dbt_date.yesterday(tz="America/New_York") }} as date_yesterday
```

## Integration Tests (Developers Only)

This project contains integration tests for all test macros in a separate `integration_tests` dbt project contained in this repo.

To run the tests:

1. You will need a profile called `integration_tests` in `~/.dbt/profiles.yml` pointing to a writable database. We only support postgres, BigQuery and Snowflake.
2. Then, from within the `integration_tests` folder, run `dbt build` to run the test models in `integration_tests/models/schema_tests/` and run the tests specified in `integration_tests/models/schema_tests/schema.yml`
22 changes: 22 additions & 0 deletions integration_tests/macros/expression_is_true.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,22 @@
{% test expression_is_true(model, expression, column_name=None, condition='1=1') %}
{# T-SQL has no boolean data type so we use 1=1 which returns TRUE #}
{# ref https://stackoverflow.com/a/7170753/3842610 #}
{{ return(adapter.dispatch('test_expression_is_true', 'dbt_date_integration_tests')(model, expression, column_name, condition)) }}
{% endtest %}

{% macro default__test_expression_is_true(model, expression, column_name, condition) %}

with meet_condition as (
select * from {{ model }} where {{ condition }}
)

select
*
from meet_condition
{% if column_name is none %}
where not({{ expression }})
{%- else %}
where not({{ column_name }} {{ expression }})
{%- endif %}

{% endmacro %}
44 changes: 22 additions & 22 deletions integration_tests/models/test_dates.yml
Original file line number Diff line number Diff line change
Expand Up @@ -2,50 +2,50 @@ version: 2
models:
- name: test_dates
tests:
- dbt_utils.expression_is_true:
- expression_is_true:
expression: "prior_date_day = {{ dbt_date.yesterday('date_day') }}"
- dbt_utils.expression_is_true:
- expression_is_true:
expression: "next_date_day = {{ dbt_date.tomorrow('date_day') }}"
- dbt_utils.expression_is_true:
- expression_is_true:
expression: "day_name = {{ dbt_date.day_name('date_day', short=False) }}"
- dbt_utils.expression_is_true:
- expression_is_true:
expression: "day_name_short = {{ dbt_date.day_name('date_day', short=True) }}"
- dbt_utils.expression_is_true:
- expression_is_true:
expression: "day_of_month = {{ dbt_date.day_of_month('date_day') }}"
- dbt_utils.expression_is_true:
- expression_is_true:
expression: "day_of_week = {{ dbt_date.day_of_week('date_day', isoweek=False) }}"
- dbt_utils.expression_is_true:
- expression_is_true:
expression: "iso_day_of_week = {{ dbt_date.day_of_week('date_day', isoweek=True) }}"
- dbt_utils.expression_is_true:
- expression_is_true:
expression: "day_of_year = {{ dbt_date.day_of_year('date_day') }}"

- dbt_utils.expression_is_true:
- expression_is_true:
expression: "week_start_date = {{ dbt_date.week_start('date_day') }}"
- dbt_utils.expression_is_true:
- expression_is_true:
expression: "week_end_date = {{ dbt_date.week_end('date_day') }}"
- dbt_utils.expression_is_true:
- expression_is_true:
expression: "week_of_year = {{ dbt_date.week_of_year('date_day') }}"
- dbt_utils.expression_is_true:
- expression_is_true:
expression: "iso_week_start_date = {{ dbt_date.iso_week_start('date_day') }}"
- dbt_utils.expression_is_true:
- expression_is_true:
expression: "iso_week_end_date = {{ dbt_date.iso_week_end('date_day') }}"
- dbt_utils.expression_is_true:
- expression_is_true:
expression: "iso_week_of_year = {{ dbt_date.iso_week_of_year('date_day') }}"
- dbt_utils.expression_is_true:
- expression_is_true:
expression: "time_stamp_utc = {{ dbt_date.from_unixtimestamp('unix_epoch') }}"
- dbt_utils.expression_is_true:
- expression_is_true:
expression: "unix_epoch = {{ dbt_date.to_unixtimestamp('time_stamp_utc') }}"
- dbt_utils.expression_is_true:
- expression_is_true:
expression: "time_stamp = {{ dbt_date.convert_timezone('time_stamp_utc') }}"
- dbt_utils.expression_is_true:
- expression_is_true:
expression: "time_stamp = {{ dbt_date.convert_timezone('time_stamp_utc', source_tz='UTC') }}"
# - dbt_utils.expression_is_true:
# - expression_is_true:
# expression: "time_stamp_utc = {{ dbt_date.convert_timezone('time_stamp', source_tz='America/Los_Angeles', target_tz='UTC') }}"
# - dbt_utils.expression_is_true:
# - expression_is_true:
# expression: "time_stamp = {{ dbt_date.convert_timezone('time_stamp', source_tz='America/Los_Angeles', target_tz='America/Los_Angeles') }}"
- dbt_utils.expression_is_true:
- expression_is_true:
expression: "rounded_timestamp = {{ dbt_date.round_timestamp('time_stamp') }}"
- dbt_utils.expression_is_true:
- expression_is_true:
expression: "rounded_timestamp_utc = {{ dbt_date.round_timestamp('time_stamp_utc') }}"

columns:
Expand Down
2 changes: 1 addition & 1 deletion integration_tests/packages.yml
Original file line number Diff line number Diff line change
@@ -1,2 +1,2 @@
packages:
- local: ../
- local: ../
77 changes: 77 additions & 0 deletions macros/_utils/date_spine.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,77 @@
{% macro get_intervals_between(start_date, end_date, datepart) -%}
{{ return(adapter.dispatch('get_intervals_between', 'dbt_date')(start_date, end_date, datepart)) }}
{%- endmacro %}

{% macro default__get_intervals_between(start_date, end_date, datepart) -%}
{%- call statement('get_intervals_between', fetch_result=True) %}

select {{ datediff(start_date, end_date, datepart) }}

{%- endcall -%}

{%- set value_list = load_result('get_intervals_between') -%}

{%- if value_list and value_list['data'] -%}
{%- set values = value_list['data'] | map(attribute=0) | list %}
{{ return(values[0]) }}
{%- else -%}
{{ return(1) }}
{%- endif -%}

{%- endmacro %}




{% macro date_spine(datepart, start_date, end_date) %}
{{ return(adapter.dispatch('date_spine', 'dbt_date')(datepart, start_date, end_date)) }}
{%- endmacro %}

{% macro default__date_spine(datepart, start_date, end_date) %}


{# call as follows:

date_spine(
"day",
"to_date('01/01/2016', 'mm/dd/yyyy')",
"dateadd(week, 1, current_date)"
) #}


with rawdata as (

{{
dbt_date.generate_series(
dbt_date.get_intervals_between(start_date, end_date, datepart)
)
}}

),

all_periods as (

select (
{{
dateadd(
datepart,
"row_number() over (order by 1) - 1",
start_date
)
}}
) as date_{{datepart}}
from rawdata

),

filtered as (

select *
from all_periods
where date_{{datepart}} <= {{ end_date }}

)

select * from filtered

{% endmacro %}
53 changes: 53 additions & 0 deletions macros/_utils/generate_series.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,53 @@
{% macro get_powers_of_two(upper_bound) %}
{{ return(adapter.dispatch('get_powers_of_two', 'dbt_date')(upper_bound)) }}
{% endmacro %}

{% macro default__get_powers_of_two(upper_bound) %}

{% if upper_bound <= 0 %}
{{ exceptions.raise_compiler_error("upper bound must be positive") }}
{% endif %}

{% for _ in range(1, 100) %}
{% if upper_bound <= 2 ** loop.index %}{{ return(loop.index) }}{% endif %}
{% endfor %}

{% endmacro %}


{% macro generate_series(upper_bound) %}
{{ return(adapter.dispatch('generate_series', 'dbt_date')(upper_bound)) }}
{% endmacro %}

{% macro default__generate_series(upper_bound) %}

{% set n = dbt_date.get_powers_of_two(upper_bound) %}

with p as (
select 0 as generated_number union all select 1
), unioned as (

select

{% for i in range(n) %}
p{{i}}.generated_number * power(2, {{i}})
{% if not loop.last %} + {% endif %}
{% endfor %}
+ 1
as generated_number

from

{% for i in range(n) %}
p as p{{i}}
{% if not loop.last %} cross join {% endif %}
{% endfor %}

)

select *
from unioned
where generated_number <= {{upper_bound}}
order by generated_number

{% endmacro %}
4 changes: 2 additions & 2 deletions macros/get_base_dates.sql
Original file line number Diff line number Diff line change
Expand Up @@ -17,7 +17,7 @@
with date_spine as
(

{{ dbt_utils.date_spine(
{{ dbt_date.date_spine(
datepart=datepart,
start_date=start_date,
end_date=end_date,
Expand Down Expand Up @@ -46,7 +46,7 @@ from
with date_spine as
(

{{ dbt_utils.date_spine(
{{ dbt_date.date_spine(
datepart=datepart,
start_date=start_date,
end_date=end_date,
Expand Down
3 changes: 0 additions & 3 deletions packages.yml
Original file line number Diff line number Diff line change
@@ -1,3 +0,0 @@
packages:
- package: dbt-labs/dbt_utils
version: [">=0.9.0", "<1.0.0"]