Skip to content

Commit

Permalink
Merge pull request #45 from Gemma-Analytics/dim_dates
Browse files Browse the repository at this point in the history
adding gemma dates model
  • Loading branch information
soltanianalytics authored Jul 7, 2021
2 parents 6a17a7a + 081e7ef commit 1a9a4b5
Show file tree
Hide file tree
Showing 8 changed files with 273 additions and 1 deletion.
24 changes: 24 additions & 0 deletions README.md
Original file line number Diff line number Diff line change
Expand Up @@ -32,6 +32,30 @@ vars:
'gemma:fx:base_currency': EUR
'gemma:fx:enabled': true
```
### (Dim) Dates
This model will create the table `gemma_dates` in the schema `YOUR_SCHEMA_gemma_dbt_utils`. Starting from a defined date it will create a date series with different date columns until a specified number of days, e.g. 30 days after the current date. It works for postgres and bigquery - specified through the target type in the `profiles.yml`
The configurations are:

| Variables | Default | Purpose |
| --- | --- | --- |
| gemma:dates:timezone | 'Europe/Berlin' | Optional String. Sets the timezone for this model. By defaul, it's set to 'Europe/Berlin' |
| gemma:dates:enabled | false | Required Boolean. Set to true to activate the model|
| gemma:dates:start_date | '2020-01-01' | Optional String. Sets the `start_date` for the date series. By defaul, it's set to '2020-01-01' |
| gemma:dates:end_date | '30 day' | Optional String. It is an interval relative to current_date, which sets the `end_date` for the date series. By defaul, it's set to '30 day' |
| gemma:dates:table | 'gemma_dates' | Optional String. Sets an alias for the model. By default, it's set to 'gemma_dates' |
| gemma:dates:schema | 'gemma_dbt_utils' | Optional String. Sets the a custom schema for the model. By default, it's set to 'gemma_dbt_utils' |

Example `dbt_project.yml`:
```yaml
vars:
'gemma:dates:timezone': 'Europe/Berlin' # overwrite to get a different default value
'gemma:dates:enabled': false # overwrite this variable to enable the date model
'gemma:dates:start_date': '2020-01-01' # overwrite to get a different default value
'gemma:dates:end_date': '30 day' # 30 days after the current date
'gemma:dates:table': 'gemma_dates' # overwrite to get a different default value
'gemma:dates:schema': 'gemma_dbt_utils' # overwrite to get a different default value
```

## Schema Tests

Expand Down
10 changes: 9 additions & 1 deletion dbt_project.yml
Original file line number Diff line number Diff line change
@@ -1,7 +1,7 @@
config-version: 2

name: 'gemma_dbt_utils'
version: '0.2.9'
version: '0.2.10'

require-dbt-version: '>=0.17.0'

Expand All @@ -17,6 +17,14 @@ macro-paths: ["macros"]
source-paths: ["models"]

vars:
# Variables related to the dim_dates model
'gemma:dates:timezone': 'Europe/Berlin' # overwrite to get a different default value
'gemma:dates:enabled': false # overwrite this variable to enable the date model
'gemma:dates:start_date': '2020-01-01' # overwrite to get a different default value
'gemma:dates:end_date': '30 day' # 30 days after the current date
'gemma:dates:table': 'gemma_dates' # overwrite to get a different default value
'gemma:dates:schema': 'gemma_dbt_utils' # overwrite to get a different default value

# Variables related to the fx model
'gemma:fx:currencies':
EUR: 'gemma:fx:eur' # define currency as other variables, or ...
Expand Down
Original file line number Diff line number Diff line change
@@ -0,0 +1,63 @@
"date","month_last_day","previous_month_first_day"
"2021-04-02","2021-04-30","2021-03-01"
"2021-04-01","2021-04-30","2021-03-01"
"2021-04-03","2021-04-30","2021-03-01"
"2021-04-04","2021-04-30","2021-03-01"
"2021-04-05","2021-04-30","2021-03-01"
"2021-04-06","2021-04-30","2021-03-01"
"2021-04-07","2021-04-30","2021-03-01"
"2021-04-08","2021-04-30","2021-03-01"
"2021-04-09","2021-04-30","2021-03-01"
"2021-04-10","2021-04-30","2021-03-01"
"2021-04-11","2021-04-30","2021-03-01"
"2021-04-12","2021-04-30","2021-03-01"
"2021-04-13","2021-04-30","2021-03-01"
"2021-04-14","2021-04-30","2021-03-01"
"2021-04-15","2021-04-30","2021-03-01"
"2021-04-16","2021-04-30","2021-03-01"
"2021-04-17","2021-04-30","2021-03-01"
"2021-04-18","2021-04-30","2021-03-01"
"2021-04-19","2021-04-30","2021-03-01"
"2021-04-20","2021-04-30","2021-03-01"
"2021-04-21","2021-04-30","2021-03-01"
"2021-04-22","2021-04-30","2021-03-01"
"2021-04-23","2021-04-30","2021-03-01"
"2021-04-24","2021-04-30","2021-03-01"
"2021-04-25","2021-04-30","2021-03-01"
"2021-04-26","2021-04-30","2021-03-01"
"2021-04-27","2021-04-30","2021-03-01"
"2021-04-28","2021-04-30","2021-03-01"
"2021-04-29","2021-04-30","2021-03-01"
"2021-04-30","2021-04-30","2021-03-01"
"2021-05-01","2021-05-31","2021-04-01"
"2021-05-02","2021-05-31","2021-04-01"
"2021-05-03","2021-05-31","2021-04-01"
"2021-05-04","2021-05-31","2021-04-01"
"2021-05-05","2021-05-31","2021-04-01"
"2021-05-06","2021-05-31","2021-04-01"
"2021-05-07","2021-05-31","2021-04-01"
"2021-05-08","2021-05-31","2021-04-01"
"2021-05-09","2021-05-31","2021-04-01"
"2021-05-10","2021-05-31","2021-04-01"
"2021-05-11","2021-05-31","2021-04-01"
"2021-05-12","2021-05-31","2021-04-01"
"2021-05-13","2021-05-31","2021-04-01"
"2021-05-14","2021-05-31","2021-04-01"
"2021-05-15","2021-05-31","2021-04-01"
"2021-05-16","2021-05-31","2021-04-01"
"2021-05-17","2021-05-31","2021-04-01"
"2021-05-18","2021-05-31","2021-04-01"
"2021-05-19","2021-05-31","2021-04-01"
"2021-05-20","2021-05-31","2021-04-01"
"2021-05-21","2021-05-31","2021-04-01"
"2021-05-22","2021-05-31","2021-04-01"
"2021-05-23","2021-05-31","2021-04-01"
"2021-05-24","2021-05-31","2021-04-01"
"2021-05-25","2021-05-31","2021-04-01"
"2021-05-26","2021-05-31","2021-04-01"
"2021-05-27","2021-05-31","2021-04-01"
"2021-05-28","2021-05-31","2021-04-01"
"2021-05-29","2021-05-31","2021-04-01"
"2021-05-30","2021-05-31","2021-04-01"
"2021-05-31","2021-05-31","2021-04-01"
"2021-06-01","2021-06-30","2021-05-01"
7 changes: 7 additions & 0 deletions integration_tests/dbt_project.yml
Original file line number Diff line number Diff line change
Expand Up @@ -20,6 +20,13 @@ clean-targets: # directories to be removed by `dbt clean`

vars:
# Set variables to configure the Gemma dbt utils package
'gemma:dates:timezone': 'Europe/Berlin'
'gemma:dates:enabled': true
'gemma:dates:start_date': '2020-01-01'
'gemma:dates:end_date': '30 day'
'gemma:dates:table': 'gemma_dates'
'gemma:dates:schema': 'gemma_dbt_utils'

'gemma:fx:currencies':
EUR: 'gemma:fx:eur'
CHF: 'gemma:fx:chf'
Expand Down
2 changes: 2 additions & 0 deletions integration_tests/models/model_tests/schema.yml
Original file line number Diff line number Diff line change
Expand Up @@ -7,6 +7,8 @@ seeds:
description: Sample raw FX rates from Yahoo Finance (USDEUR)
- name: models_gemma_fx_result_eur_chf
description: Correct EURCHF fx rates based on USDCHF and USDEUR. Test gemma_fx with this data.
- name: models_gemma_dates_sample_results
description: Correct sample year_day_num and quarter_day_num. Test gemma_date with this data.

sources:
- name: fx
Expand Down
22 changes: 22 additions & 0 deletions integration_tests/tests/test_gemma_dates.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,22 @@
WITH correct_results AS (

SELECT
date AS date
, month_last_day AS month_last_day
, previous_month_first_day AS previous_month_first_day

FROM {{ ref('models_gemma_dates_sample_results') }}

), test AS (

SELECT *
FROM correct_results AS cr
LEFT JOIN {{ ref('gemma_dates') }} AS gd
ON gd.date = cr.date
WHERE NOT COALESCE(gd.month_last_day = cr.month_last_day, FALSE)
OR NOT COALESCE(
gd.previous_month_first_day = cr.previous_month_first_day, FALSE)

)

SELECT * FROM test
134 changes: 134 additions & 0 deletions models/gemma_dates.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,134 @@
{{ config(alias=var("gemma:dates:table"),
schema=var("gemma:dates:schema"), enabled=var("gemma:dates:enabled")) }}

{% if target.type == 'postgres' | as_bool() %}

WITH dates AS (

SELECT
GENERATE_SERIES(
'{{ var('gemma:dates:start_date') }}',
DATE(TIMEZONE('{{ var('gemma:dates:timezone') }}', CURRENT_TIMESTAMP))
+ INTERVAL '{{ var('gemma:dates:end_date') }}', '1 day'
) AS date

), final AS (

SELECT
TO_CHAR(date, 'YYYYMMDD') AS date_id
, DATE(date) AS date
, EXTRACT(DOY FROM date) AS year_day_num
, DATE_PART('day', date - DATE_TRUNC('quarter', date)) + 1
AS quarter_day_num
, EXTRACT(DAY FROM date) AS month_day_num
, EXTRACT(MONTH FROM date) AS month_num
, TO_CHAR(date, 'Month') AS month_name
, TO_CHAR(date, 'Mon') AS month_abbreviated
, EXTRACT(DAY FROM DATE_TRUNC('month', date) + INTERVAL '1 month - 1 day')
AS month_days
, TO_CHAR(date, 'YYYY-MM') AS year_month
, EXTRACT(QUARTER FROM date) AS quarter_num
, DATE_PART('day',
(DATE_TRUNC('quarter', date) + INTERVAL '3 month')
- DATE_TRUNC('quarter', date)
) AS quarter_days
, EXTRACT(YEAR FROM date) AS year
, EXTRACT(ISOYEAR FROM date) AS iso_year
, EXTRACT(YEAR FROM date - INTERVAL '1 year') AS previous_year
, EXTRACT(QUARTER FROM date - INTERVAL '3 month') AS previous_quarter_num
, EXTRACT(MONTH FROM date - INTERVAL '1 month') AS previous_month_num
, EXTRACT(WEEK FROM date) AS year_week_num
, EXTRACT(ISOYEAR FROM date) || TO_CHAR(date, '"-CW"IW') AS year_week_name
, EXTRACT(ISODOW FROM date) AS weekday_num
, TO_CHAR(date, 'Day') AS weekday_name
, TO_CHAR(date, 'Dy') AS weekday_abbreviated
, EXTRACT(ISODOW FROM date) NOT IN (6,7) AS is_weekday
, DATE(DATE_TRUNC('year', date)) AS year_first_day
, DATE(DATE_TRUNC('year', date) + INTERVAL '1 year - 1 day')
AS year_last_day
, DATE(DATE_TRUNC('quarter', date)) AS quarter_first_day
, DATE(DATE_TRUNC('quarter', date) + INTERVAL '3 month - 1 day')
AS quarter_last_day
, DATE(DATE_TRUNC('month', date)) AS month_first_day
, DATE(DATE_TRUNC('month', date) + INTERVAL '1 month - 1 day')
AS month_last_day
, DATE(DATE_TRUNC('week', date)) AS week_first_day
, DATE(DATE_TRUNC('week', date) + INTERVAL '1 week - 1 day')
AS week_last_day
, DATE(DATE_TRUNC('month', date - INTERVAL '1 month'))
AS previous_month_first_day
, DATE(DATE_TRUNC('month', date) - INTERVAL '1 day')
AS previous_month_last_day
, DATE(DATE_TRUNC('month', date + INTERVAL '1 month'))
AS next_month_first_day
, DATE(DATE_TRUNC('month', date) + INTERVAL '2 month - 1 day')
AS next_month_last_day

FROM dates

)

SELECT * FROM final

{% elif target.type == 'bigquery' | as_bool() %}

WITH dates AS (

SELECT * FROM UNNEST(
GENERATE_DATE_ARRAY('{{ var('gemma:dates:start_date') }}'
, DATE_ADD(current_date(), INTERVAL {{ var('gemma:dates:end_date') }})
, INTERVAL 1 DAY)) AS date

), final AS (

SELECT
FORMAT_DATE('%Y%m%d', date) AS date_id
, DATE(date) AS date
, EXTRACT(DAYOFYEAR FROM date) AS year_day_num
, DATE_DIFF(date, DATE_TRUNC(date, QUARTER), DAY) + 1 AS quarter_day_num
, EXTRACT(YEAR FROM date) AS year
, EXTRACT(ISOYEAR FROM date) AS iso_year
, EXTRACT(WEEK FROM date) AS year_week_num
, EXTRACT(ISOWEEK FROM date) AS year_isoweek_num
, EXTRACT(DAY FROM date) month_day_num
, FORMAT_DATE('%Q', date) AS quarter_num
, EXTRACT(MONTH FROM date) AS month_num
, FORMAT_DATE('%B', date) AS month_name
, FORMAT_DATE('%b', date) AS month_abbreviated
, EXTRACT(DAY FROM LAST_DAY(date, MONTH)) AS month_days
, FORMAT_DATE('%A', date) AS weekday_name
, FORMAT_DATE('%a', date) AS weekday_abbreviated
, EXTRACT(DAYOFWEEK FROM date) NOT IN (1,7) AS is_weekday
, EXTRACT(YEAR FROM DATE_SUB(date, INTERVAL 1 YEAR)) AS previous_year
, FORMAT_DATE('%Q', DATE_SUB(date, INTERVAL 1 QUARTER))
AS previous_quarter_num
, EXTRACT(MONTH FROM DATE_SUB(date, INTERVAL 1 MONTH)) AS previous_month_num
, DATE_TRUNC(date, YEAR) AS year_first_day
, LAST_DAY(date, YEAR) AS year_last_day
, DATE_TRUNC(date, QUARTER) AS quarter_first_day
, LAST_DAY(date, QUARTER) AS quarter_last_day
, DATE_TRUNC(date, MONTH) AS month_first_day
, LAST_DAY(date, MONTH) AS month_last_day
, DATE_TRUNC(date, WEEK(MONDAY)) AS week_first_day
, LAST_DAY(date, WEEK(MONDAY)) AS week_last_day
, DATE_TRUNC(date, ISOWEEK) AS isoweek_first_day
, LAST_DAY(date, ISOWEEK) AS isoweek_last_day
, DATE_TRUNC(DATE_SUB(date, INTERVAL 1 MONTH), MONTH)
AS previous_month_first_day
, LAST_DAY(DATE_SUB(date, INTERVAL 1 MONTH), MONTH)
AS previous_month_last_day
, DATE_TRUNC(DATE_ADD(date, INTERVAL 1 MONTH), MONTH)
AS next_month_first_day
, LAST_DAY(DATE_ADD(date, INTERVAL 1 MONTH), MONTH) AS next_month_last_day

FROM dates

)

SELECT * FROM final

{% elif target.type not in ('bigquery','postgres') | as_bool() %}

{% do exceptions.raise_compiler_error("This DB is not supported in dim_dates model") %}

{% endif %}
12 changes: 12 additions & 0 deletions models/schema.yml
Original file line number Diff line number Diff line change
Expand Up @@ -23,3 +23,15 @@ models:
description: Multiply an amount in the source currency aka fx_currency with the fx_rate to get an equivalent amount in the base currency.
tests:
- not_null

- name: gemma_dates
description: "A calendar table: date series with one row per day."
columns:
- name: date_id
tests:
- unique
- not_null
- name: date
tests:
- unique
- not_null

0 comments on commit 1a9a4b5

Please sign in to comment.