data-dwh-dbt-project/models/intermediate/cross/int_mtd_deal_metrics.sql
Oriol Roqué Paniagua 004616bb79 Merged PR 3187: Move deal lifecycle related models to cross
# Description

Moves from intermediate/core to intermediate/cross the following models:
- `int_core__mtd_deal_lifecycle`
- `int_core__mtd_deal_metrics`

to their equivalents:
- `int_mtd_deal_lifecycle`
- `int_mtd_deal_metrics`

This also changes the schema entries, from core to cross, including changing the name of the model in the entry.
This also changes the dependencies, namely in `int_mtd_deal_metrics`, `int_mtd_vs_previous_year_metrics` and `int_monthly_aggregated_metrics_history_by_deal`.
This does NOT aim to alter the logic of the lifecycle in any case; it will be done in a separated PR.

Runs correctly end-to-end. We might need to drop the old models from production manually.

# 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: #22689
2024-10-16 11:56:49 +00:00

125 lines
4.7 KiB
SQL

/*
This model provides Month-To-Date (MTD) based on Deal metrics.
*/
{% set dimensions = get_kpi_dimensions() %}
{{ config(materialized="table", unique_key=["date", "dimension", "dimension_value"]) }}
with
int_mtd_deal_lifecycle as (select * from {{ ref("int_mtd_deal_lifecycle") }}),
int_dates_mtd_by_dimension as (
select * from {{ ref("int_dates_mtd_by_dimension") }}
),
int_core__mtd_accommodation_segmentation as (
select * from {{ ref("int_core__mtd_accommodation_segmentation") }}
),
int_core__deal as (select * from {{ ref("int_core__deal") }}),
deals_metric_aggregation_per_date as (
{% for dimension in dimensions %}
select
al.date,
{{ dimension.dimension }} as dimension,
{{ dimension.dimension_value }} as dimension_value,
count(
distinct case
when al.deal_lifecycle_state = '01-New'
then al.id_deal
else null
end
) as new_deals,
count(
distinct case
when al.deal_lifecycle_state = '02-Never Booked'
then al.id_deal
else null
end
) as never_booked_deals,
count(
distinct case
when al.deal_lifecycle_state = '03-First Time Booked'
then al.id_deal
else null
end
) as first_time_booked_deals,
count(
distinct case
when al.deal_lifecycle_state = '04-Active'
then al.id_deal
else null
end
) as active_deals,
count(
distinct case
when al.deal_lifecycle_state = '05-Churning'
then al.id_deal
else null
end
) as churning_deals,
count(
distinct case
when al.deal_lifecycle_state = '06-Inactive'
then al.id_deal
else null
end
) as inactive_deals,
count(
distinct case
when al.deal_lifecycle_state = '07-Reactivated'
then al.id_deal
else null
end
) as reactivated_deals,
sum(
case when has_been_booked_within_current_month then 1 else 0 end
) as deals_booked_in_month,
sum(
case when has_been_booked_within_last_6_months then 1 else 0 end
) as deals_booked_in_6_months,
sum(
case when has_been_booked_within_last_12_months then 1 else 0 end
) as deals_booked_in_12_months
from int_mtd_deal_lifecycle al
{% if dimension.dimension == "'by_number_of_listings'" %}
inner join
int_core__mtd_accommodation_segmentation mas
on al.id_deal = mas.id_deal
and al.date = mas.date
{% elif dimension.dimension == "'by_billing_country'" %}
inner join
int_core__deal ud
on al.id_deal = ud.id_deal
and ud.main_billing_country_iso_3_per_deal is not null
{% endif %}
group by 1, 2, 3
{% if not loop.last %}
union all
{% endif %}
{% endfor %}
)
-- Final aggregation of subqueries --
select
d.year,
d.month,
d.day,
d.date,
d.dimension,
d.dimension_value,
d.is_end_of_month,
d.is_current_month,
nullif(l.new_deals, 0) as new_deals,
nullif(l.never_booked_deals, 0) as never_booked_deals,
nullif(l.first_time_booked_deals, 0) as first_time_booked_deals,
nullif(l.active_deals, 0) as active_deals,
nullif(l.churning_deals, 0) as churning_deals,
nullif(l.inactive_deals, 0) as inactive_deals,
nullif(l.reactivated_deals, 0) as reactivated_deals,
nullif(l.deals_booked_in_month, 0) as deals_booked_in_month,
nullif(l.deals_booked_in_6_months, 0) as deals_booked_in_6_months,
nullif(l.deals_booked_in_12_months, 0) as deals_booked_in_12_months
from int_dates_mtd_by_dimension d
left join
deals_metric_aggregation_per_date l
on l.date = d.date
and l.dimension = d.dimension
and l.dimension_value = d.dimension_value