data-dwh-dbt-project/models/intermediate/cross/int_dates_mtd.sql

57 lines
2.1 KiB
SQL

/*
This model provides Month-To-Date (MTD) necessary dates for MTD-based models to work.
- For month-to-month complete information, it retrieves all end month dates that have elapsed since 2020.
- For month-to-date information, it retrieves the days of the current month of this year up to yesterday.
Additionally, it also gets the days of its equivalent month from last year previous the current day of month of today.
Example:
Imagine we have are at 4th June 2024.
- We will get the dates for 1st, 2nd, 3rd of June 2024.
- We will also get the dates for 1st, 2nd, 3rd of June 2023.
- We will get all end of months from 2020 to yesterday,
i.e., 31st January 2020, 29th February 2020, ..., 30th April 2024, 31st May 2024.
*/
with
int_dates as (select * from {{ ref("int_dates") }} where date_day >= {{ var("start_date") }}),
raw_dates as (
select
id.year_number as year,
id.month_of_year as month,
id.day_of_month as day,
id.date_day as date,
id.month_start_date as first_day_month,
id.month_end_date as last_day_month,
now()::date as today
from int_dates id
)
-- Dates keeps only end of month (EOM) dates, as well as
-- dates corresponding to the current month and the same month last year
select distinct
rd.year,
rd.month,
rd.day,
rd.date,
rd.first_day_month,
rd.last_day_month,
case when rd.date = rd.last_day_month then 1 else 0 end as is_end_of_month,
case
when date_trunc('month', rd.date) = date_trunc('month', rd.today) then 1 else 0
end as is_current_month
from raw_dates rd
where
rd.today > rd.date
-- include only up-to yesterday
and (
rd.date = rd.last_day_month
-- keep all last day of the month
or rd.date >= date_trunc('month', rd.today)
-- keep all individual days of the current month
or (
rd.year = extract(year from rd.today) - 1
and rd.month = extract(month from rd.today)
and rd.day < extract(day from rd.today)
)
-- keep all days of same month last day up to yesterday's day
)