data-dwh-dbt-project/models/intermediate/kpis/int_kpis__dimension_dates.sql
2024-11-06 11:47:47 +01:00

56 lines
1.7 KiB
SQL

{{ 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.week_of_year as week,
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,
id.week_start_date as first_day_week,
id.week_end_date as last_day_week,
now()::date as today
from int_dates id
)
select distinct
rd.year,
rd.month,
rd.week,
rd.day,
rd.date,
rd.first_day_month,
rd.last_day_month,
case when rd.date = rd.last_day_month then true else false end as is_end_of_month,
case
when date_trunc('month', rd.date) = date_trunc('month', rd.today)
then true
else false
end as is_current_month,
case
when date_trunc('month', rd.date) = date_trunc('month', rd.today)
then true
when
rd.year = extract(year from rd.today) - 1
and rd.month = extract(month from rd.today)
and rd.day < extract(day from rd.today)
then true
else false
end as is_month_to_date,
rd.first_day_week,
rd.last_day_week,
case when rd.date = rd.last_day_week then true else false end as is_end_of_week,
case
when date_trunc('week', rd.date) = date_trunc('week', rd.today)
then true
else false
end as is_current_week
from raw_dates rd
where
-- include only up-to yesterday
rd.today > rd.date