-
Notifications
You must be signed in to change notification settings - Fork 2
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
Merge pull request #45 from Gemma-Analytics/dim_dates
adding gemma dates model
- Loading branch information
Showing
8 changed files
with
273 additions
and
1 deletion.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
63 changes: 63 additions & 0 deletions
63
integration_tests/data/model_tests/gemma_dates/models_gemma_dates_sample_results.csv
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
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" |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
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 |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
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 %} |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters