data-dwh-dbt-project/models/intermediate/kpis/projected/int_kpis_projected__dimension_dates.sql

67 lines
2.2 KiB
MySQL
Raw Normal View History

Merged PR 4665: Projected Bookings to the end of the current month # Description Computes projected Bookings to the end of the current month per dimension and dimension value KPIs changes: * Adds a int_kpis__agg_daily_created_bookings model. This is a standard KPIs model that computes created bookings at a daily level per dimension and dimension value. Projected KPIs (NEW): * Adds a new folder named projected within KPIs. This includes a simple Readme. * Adds a default dimension dates model that ranges from the past 3 complete months to the end of the current month, that is in the future. * Adds 2 projected models for created bookings: The daily one, that handles the logic of the projection (same month + last 7 days) and the monthly one, that retrieves the end of month projected value as well as some indicators of how good or bad this was for previous months. How good is the projection at 11th of March (so 10 days in the month)? `select * from intermediate.int_kpis_projected__agg_monthly_created_bookings order by actual_created_bookings desc` ![image.png](https://guardhog.visualstudio.com/4148d95f-4b6d-4205-bcff-e9c8e0d2ca65/_apis/git/repositories/54ac356f-aad7-46d2-b62c-e8c5b3bb8ebf/pullRequests/4665/attachments/image.png) # Checklist - [X] The edited models and dependants run properly with production data. - [X] The edited models are sufficiently documented. - [X] The edited models contain PK tests, and I've ran and passed them. - [X] I have checked for DRY opportunities with other models and docs. - [X] I've picked the right materialization for the affected models. # Other - [ ] Check if a full-refresh is required after this PR is merged. Related work items: #28251
2025-03-11 14:34:30 +00:00
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