Skip to content

Commit

Permalink
Merge pull request #2 from calogica/add/fiscal-calendar
Browse files Browse the repository at this point in the history
Adds Fiscal Calendar
  • Loading branch information
clausherther authored Oct 15, 2019
2 parents 2e9436c + 0a03b90 commit d2a718f
Show file tree
Hide file tree
Showing 25 changed files with 279 additions and 21 deletions.
60 changes: 43 additions & 17 deletions README.md
Original file line number Diff line number Diff line change
Expand Up @@ -33,9 +33,22 @@ Usage:
{{ dbt_date.get_date_dimension('2015-01-01', '2022-12-31') }}
```

### Fiscal Periods

#### get_fiscal_periods ([source](macros/fiscal_date/get_fiscal_periods.sql))
Returns query to build a fiscal period calendar based on the 4-5-4 week retail period concept.
See the [example model](models/examples/dim_date_fiscal.sql) for details and this [blog post](https://calogica.com/sql/dbt/2018/11/15/retail-calendar-in-sql.html) for more context on custom business calendars.

Usage:

```python
{{ dbt_date.get_fiscal_periods(ref('dates'), year_end_month, week_start_day) }}
```
Note: the first parameter expects a dbt `ref` variable, i.e. a reference to a model containing the necessary date dimension attributes, which can be generated via the `get_date_dimension` macro (see above).

### Date

#### convert_timezone ([source](macros/date/convert_timezone.sql))
#### convert_timezone ([source](macros/calendar_date/convert_timezone.sql))
Cross-database implemention of convert_timezone function.

Usage:
Expand All @@ -62,7 +75,7 @@ Using named parameters, we can also specify the source only and rely on the conf
{{ dbt_date.convert_timezone('my_column', source_tz='UTC') }}
```

#### date_part ([source](macros/date/date_part.sql))
#### date_part ([source](macros/calendar_date/date_part.sql))
Extracts date parts from date.

Usage:
Expand All @@ -71,7 +84,7 @@ Usage:
{{ dbt_date.date_part('dayofweek', 'date_day') }} as day_of_week
```

#### day_name ([source](macros/date/day_name.sql))
#### day_name ([source](macros/calendar_date/day_name.sql))
Extracts name of weekday from date.

Usage:
Expand All @@ -81,7 +94,7 @@ Usage:
{{ dbt_date.day_name('date_day', short=false) }} as day_of_week_long_name
```

#### last_week ([source](macros/date/last_week.sql))
#### last_week ([source](macros/calendar_date/last_week.sql))
Convenience function to get the start date of last week

Wraps:
Expand All @@ -97,15 +110,15 @@ Usage:
{{ dbt_date.last_week(tz='America/New_York)) }}
```

#### month_name ([source](macros/date/month_name.sql))
#### month_name ([source](macros/calendar_date/month_name.sql))
Extracts name of month from date.

```python
{{ dbt_date.month_name('date_day', short=true) }} as month_short_name,
{{ dbt_date.month_name('date_day', short=false) }} as month_long_name
```

#### n_days_ago ([source](macros/date/n_days_ago.sql))
#### n_days_ago ([source](macros/calendar_date/n_days_ago.sql))
Gets date _n_ days ago, based on local date.

Usage:
Expand All @@ -114,7 +127,7 @@ Usage:
{{ dbt_date.n_days_ago(7) }}
```

#### n_days_away ([source](macros/date/n_days_away.sql))
#### n_days_away ([source](macros/calendar_date/n_days_away.sql))
Gets date _n_ days away, based on local date.

Usage:
Expand All @@ -123,7 +136,7 @@ Usage:
{{ dbt_date.n_days_away(7) }}
```

#### n_months_ago ([source](macros/date/n_months_ago.sql))
#### n_months_ago ([source](macros/calendar_date/n_months_ago.sql))
Gets date _n_ months ago, based on local date.

Usage:
Expand All @@ -132,7 +145,7 @@ Usage:
{{ dbt_date.n_months_ago(12) }}
```

#### n_months_away ([source](macros/date/n_months_away.sql))
#### n_months_away ([source](macros/calendar_date/n_months_away.sql))
Gets date _n_ months ago, based on local date.

Usage:
Expand All @@ -141,7 +154,7 @@ Usage:
{{ dbt_date.n_months_away(12) }}
```

#### n_weeks_ago ([source](macros/date/n_weeks_ago.sql))
#### n_weeks_ago ([source](macros/calendar_date/n_weeks_ago.sql))
Gets date _n_ weeks ago, based on local date.

Usage:
Expand All @@ -150,7 +163,7 @@ Usage:
{{ dbt_date.n_weeks_ago(4) }}
```

#### n_weeks_away ([source](macros/date/n_weeks_away.sql))
#### n_weeks_away ([source](macros/calendar_date/n_weeks_away.sql))
Gets date _n_ weeks from now, based on local date.

Usage:
Expand All @@ -159,7 +172,7 @@ Usage:
{{ dbt_date.n_weeks_away(4) }}
```

#### now ([source](macros/date/now.sql))
#### now ([source](macros/calendar_date/now.sql))
Gets time based on local timezone (specified). Default is "America/Los_Angeles".

Usage:
Expand All @@ -174,7 +187,7 @@ or, specify a timezone:
{{ dbt_date.now('America/New_York') }}
```

#### periods_since ([source](macros/date/periods_since.sql))
#### periods_since ([source](macros/calendar_date/periods_since.sql))
Returns the number of periods since a specified date.

Usage:
Expand All @@ -190,7 +203,7 @@ Alternatively, a timezone can be specified via the `tz` parameter:
{{ dbt_date.periods_since('my_timestamp_column', period_name='minute', tz='UTC' }}
```

#### this_week ([source](macros/date/this_week.sql))
#### this_week ([source](macros/calendar_date/this_week.sql))
Gets current week start date, based on local date.

Usage:
Expand All @@ -199,7 +212,20 @@ Usage:
{{ dbt_date.this_week() }}
```

#### today ([source](macros/date/today.sql))
#### to_unixtimestamp ([source](macros/calendar_date/to_unixtimestamp.sql))
Gets Unix timestamp (epochs) based on provided timestamp.

Usage:

```python
{{ dbt_date.to_unixtimestamp('my_timestamp_column') }}
```

```python
{{ dbt_date.to_unixtimestamp(dbt_date.now()) }}
```

#### today ([source](macros/calendar_date/today.sql))
Gets date based on local timezone (specified). Package default is "America/Los_Angeles". The default must be specified in `dbt_project.yml`, in the `'dbt_date:time_zone'` variable. e.g `'dbt_date:time_zone': 'America/New_York'`.

Usage:
Expand All @@ -213,7 +239,7 @@ or, specify a timezone:
{{ dbt_date.today('America/New_York') }}
```

#### tomorrow ([source](macros/date/tomorrow.sql))
#### tomorrow ([source](macros/calendar_date/tomorrow.sql))
Gets tomorrow's date, based on local date.

Usage:
Expand All @@ -227,7 +253,7 @@ or, specify a timezone:
{{ dbt_date.tomorrow('America/New_York') }}
```

#### yesterday ([source](macros/date/yesterday.sql))
#### yesterday ([source](macros/calendar_date/yesterday.sql))
Gets yesterday's date, based on local date.

Usage:
Expand Down
File renamed without changes.
File renamed without changes.
File renamed without changes.
File renamed without changes.
File renamed without changes.
File renamed without changes.
File renamed without changes.
File renamed without changes.
File renamed without changes.
File renamed without changes.
File renamed without changes.
File renamed without changes.
File renamed without changes.
File renamed without changes.
11 changes: 11 additions & 0 deletions macros/calendar_date/to_unixtimestamp.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,11 @@
{% macro to_unixtimestamp(timestamp) -%}
{{ adapter_macro('dbt_date.to_unixtimestamp', timestamp) }}
{%- endmacro %}

{% macro default__to_unixtimestamp(timestamp) -%}
{{ dbt_date.date_part('epoch_seconds', timestamp) }}
{%- endmacro %}

{% macro bigquery__to_unixtimestamp(timestamp) -%}
unix_seconds({{ timestamp }})
{%- endmacro %}
File renamed without changes.
File renamed without changes.
File renamed without changes.
72 changes: 72 additions & 0 deletions macros/fiscal_date/get_fiscal_periods.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,72 @@
{% macro get_fiscal_periods(dates, year_end_month, week_start_day, shift_year=1) %}
{#
This macro requires you to pass in a ref to a date dimension, created via
dbt_date.get_date_dimension()s
#}
with fscl_year_dates_for_periods as (
{{ dbt_date.get_fiscal_year_dates(dates, year_end_month, week_start_day, shift_year) }}
),
fscl_year_w13 as (

select
f.*,
-- We count the weeks in a 13 week period
-- and separate the 4-5-4 week sequences
mod(cast(
(f.fiscal_week_of_year-1) as {{ dbt_utils.type_int() }}
), 13) as w13_number,
-- Chop weeks into 13 week merch quarters
cast(
least(
floor((f.fiscal_week_of_year-1)/13.0)
, 3)
as {{ dbt_utils.type_int() }}) as quarter_number
from
fscl_year_dates_for_periods f

),
fscl_periods as (

select
f.date_day,
f.fiscal_year_number,
f.week_start_date,
f.week_end_date,
f.fiscal_week_of_year,
case
-- we move week 53 into the 3rd period of the quarter
when f.fiscal_week_of_year = 53 then 3
when f.w13_number between 0 and 3 then 1
when f.w13_number between 4 and 8 then 2
when f.w13_number between 9 and 12 then 3
end as period_of_quarter,
f.quarter_number
from
fscl_year_w13 f

),
fscl_periods_quarters as (

select
f.*,
cast((
(f.quarter_number * 3) + f.period_of_quarter
) as {{ dbt_utils.type_int() }}) as fiscal_period_number
from
fscl_periods f

)
select
date_day,
fiscal_year_number,
week_start_date,
week_end_date,
fiscal_week_of_year,
dense_rank() over(partition by fiscal_period_number order by fiscal_week_of_year) as fiscal_week_of_period,
fiscal_period_number,
quarter_number+1 as fiscal_quarter_number,
period_of_quarter as fiscal_period_of_quarter
from
fscl_periods_quarters
order by 1,2
{% endmacro %}
108 changes: 108 additions & 0 deletions macros/fiscal_date/get_fiscal_year_dates.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,108 @@
{% macro get_fiscal_year_dates(dates, year_end_month=12, week_start_day=1, shift_year=1) %}
{{ adapter_macro('dbt_date.get_fiscal_year_dates', dates, year_end_month, week_start_day, shift_year) }}
{% endmacro %}

{% macro default__get_fiscal_year_dates(dates, year_end_month, week_start_day, shift_year) %}
-- this gets all the dates within a fiscal year
-- determined by the given year-end-month
-- ending on the saturday closest to that month's end date
with date_dimension as (
select * from {{ dates }}
),
year_month_end as (

select
d.year_number-{{ shift_year }} as fiscal_year_number,
d.month_end_date
from
date_dimension d
where
d.month_of_year = {{ year_end_month }}
group by 1,2

),
weeks as (

select
d.year_number,
d.month_of_year,
d.date_day as week_start_date,
cast({{ dbt_utils.dateadd('day', 6, 'd.date_day') }} as date) as week_end_date
from
date_dimension d
where
d.day_of_week = {{ week_start_day }}

),
-- get all the weeks that start in the month the year ends
year_week_ends as (

select
d.year_number-{{ shift_year }} as fiscal_year_number,
d.week_end_date
from
weeks d
where
d.month_of_year = {{ year_end_month }}
group by
1,2

),
-- then calculate which Saturday is closest to month end
weeks_at_month_end as (

select
d.fiscal_year_number,
d.week_end_date,
m.month_end_date,
rank() over
(partition by d.fiscal_year_number
order by
abs({{ dbt_utils.datediff('d.week_end_date', 'm.month_end_date', 'day') }})

) as closest_to_month_end
from
year_week_ends d
join
year_month_end m on d.fiscal_year_number = m.fiscal_year_number
),
fiscal_year_range as (

select
w.fiscal_year_number,
cast(
{{ dbt_utils.dateadd('day', 1,
'lag(w.week_end_date) over(order by w.week_end_date)') }}
as date) as fiscal_year_start_date,
w.week_end_date as fiscal_year_end_date
from
weeks_at_month_end w
where
w.closest_to_month_end = 1

),
fiscal_year_dates as (

select
d.date_day,
m.fiscal_year_number,
m.fiscal_year_start_date,
m.fiscal_year_end_date,
w.week_start_date,
w.week_end_date,
-- we reset the weeks of the year starting with the merch year start date
dense_rank()
over(
partition by m.fiscal_year_number
order by w.week_start_date
) as fiscal_week_of_year
from
date_dimension d
join
fiscal_year_range m on d.date_day between m.fiscal_year_start_date and m.fiscal_year_end_date
join
weeks w on d.date_day between w.week_start_date and w.week_end_date

)
select * from fiscal_year_dates order by 1
{% endmacro %}
4 changes: 2 additions & 2 deletions macros/get_base_dates.sql
Original file line number Diff line number Diff line change
@@ -1,5 +1,5 @@
{% macro get_base_dates(start_date, end_date) %}
with dates as
with date_spine as
(
{{ dbt_utils.date_spine(
datepart="day",
Expand All @@ -11,5 +11,5 @@ with dates as
select
d.date_day
from
dates d
date_spine d
{% endmacro %}
Loading

0 comments on commit d2a718f

Please sign in to comment.