67 lines
2.2 KiB
MySQL
67 lines
2.2 KiB
MySQL
|
|
with
|
||
|
|
int_kpis__dimension_dates as (select * from {{ ref("int_kpis__dimension_dates") }}),
|
||
|
|
last_available_date as (
|
||
|
|
select max(date) as last_date from int_kpis__dimension_dates
|
||
|
|
),
|
||
|
|
dates_to_project as (
|
||
|
|
select
|
||
|
|
generate_series(
|
||
|
|
-- Start from 3 months before the last available date
|
||
|
|
(
|
||
|
|
select date_trunc('month', last_date)::date - interval '3 months'
|
||
|
|
from last_available_date
|
||
|
|
),
|
||
|
|
-- End at the last date of the current month
|
||
|
|
(
|
||
|
|
select
|
||
|
|
date_trunc('month', last_date)::date
|
||
|
|
+ interval '1 month'
|
||
|
|
- interval '1 day'
|
||
|
|
from last_available_date
|
||
|
|
),
|
||
|
|
'1 day'::interval
|
||
|
|
)::date as date
|
||
|
|
)
|
||
|
|
select
|
||
|
|
dtp.date,
|
||
|
|
date_trunc('month', dtp.date)::date as first_day_month,
|
||
|
|
(date_trunc('month', dtp.date)::date + interval '1 month' - interval '1 day')::date
|
||
|
|
as last_day_month,
|
||
|
|
(dtp.date - interval '6 days')::date as previous_6_days,
|
||
|
|
case
|
||
|
|
when
|
||
|
|
dtp.date
|
||
|
|
= date_trunc('month', dtp.date)::date
|
||
|
|
+ interval '1 month'
|
||
|
|
- interval '1 day'
|
||
|
|
then true
|
||
|
|
else false
|
||
|
|
end as is_end_of_month,
|
||
|
|
case
|
||
|
|
when
|
||
|
|
date_trunc('month', dtp.date)::date
|
||
|
|
= date_trunc('month', lad.last_date)::date
|
||
|
|
then true
|
||
|
|
else false
|
||
|
|
end as is_current_month,
|
||
|
|
case when dtp.date > lad.last_date then true else false end as is_in_the_future,
|
||
|
|
case
|
||
|
|
when dtp.date = lad.last_date then true else false
|
||
|
|
end as is_latest_historical_date,
|
||
|
|
case
|
||
|
|
when
|
||
|
|
extract('day' from dtp.date) <= extract('day' from lad.last_date)
|
||
|
|
and dtp.date <= lad.last_date
|
||
|
|
then true
|
||
|
|
else false
|
||
|
|
end as is_available_for_same_month_projection,
|
||
|
|
case
|
||
|
|
when
|
||
|
|
extract('day' from dtp.date) = extract('day' from lad.last_date)
|
||
|
|
and dtp.date <= lad.last_date
|
||
|
|
then true
|
||
|
|
else false
|
||
|
|
end as is_available_for_last_7_days_projection
|
||
|
|
from dates_to_project dtp
|
||
|
|
cross join last_available_date lad
|