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

50 lines
1.6 KiB
MySQL
Raw Normal View History

{{ config(materialized="table", unique_key="date") }}
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
-- If today is 1st of Month, include last day of month for MTD display
when rd.today = rd.last_day_month + 1 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
)