# Description Changes: * Propagates business scope, based on deal, for Deal and Listing metrics. This already handles the daily metric and the daily aggregation. * Modifies lifecycle_daily_deal to depend on dimension_deals and compute API segmentation. * Creates new metric: Live Deals, that includes New, Active and Reactivated. This will be needed for YTD/MTD overview. # 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: #27356
96 lines
3 KiB
SQL
96 lines
3 KiB
SQL
{{
|
|
config(
|
|
materialized="table",
|
|
unique_key=[
|
|
"date",
|
|
"main_billing_country_iso_3_per_deal",
|
|
"active_accommodations_per_deal_segmentation",
|
|
"business_scope",
|
|
],
|
|
)
|
|
}}
|
|
select
|
|
-- Unique Key --
|
|
ldl.date,
|
|
case
|
|
when ikdd.client_type = 'API'
|
|
then 'API'
|
|
when ikdd.client_type = 'PLATFORM'
|
|
then
|
|
case
|
|
when
|
|
icnddsd.id_deal is not null
|
|
and ldl.date >= icnddsd.min_user_in_new_dash_since_date_utc
|
|
then 'New Dash'
|
|
else 'Old Dash'
|
|
end
|
|
else 'UNSET'
|
|
end as business_scope,
|
|
coalesce(
|
|
ikdd.main_billing_country_iso_3_per_deal, 'UNSET'
|
|
) as main_billing_country_iso_3_per_deal,
|
|
case
|
|
when ldl.deal_lifecycle_state = '01-New'
|
|
then coalesce(ikdd.hubspot_listing_segmentation, 'UNSET')
|
|
else coalesce(icmas.active_accommodations_per_deal_segmentation, 'UNSET')
|
|
end as active_accommodations_per_deal_segmentation,
|
|
-- Metrics --
|
|
count(
|
|
distinct case
|
|
when ldl.deal_lifecycle_state = '01-New' then ldl.id_deal else null
|
|
end
|
|
) as new_deals,
|
|
count(
|
|
distinct case
|
|
when ldl.deal_lifecycle_state = '02-Never Booked' then ldl.id_deal else null
|
|
end
|
|
) as never_booked_deals,
|
|
count(
|
|
distinct case
|
|
when ldl.deal_lifecycle_state = '04-Active' then ldl.id_deal else null
|
|
end
|
|
) as active_deals,
|
|
count(
|
|
distinct case
|
|
when ldl.deal_lifecycle_state = '05-Churning' then ldl.id_deal else null
|
|
end
|
|
) as churning_deals,
|
|
count(
|
|
distinct case
|
|
when ldl.deal_lifecycle_state = '06-Inactive' then ldl.id_deal else null
|
|
end
|
|
) as inactive_deals,
|
|
count(
|
|
distinct case
|
|
when ldl.deal_lifecycle_state = '07-Reactivated' then ldl.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,
|
|
count(
|
|
distinct
|
|
case
|
|
when
|
|
ldl.deal_lifecycle_state
|
|
in ('01-New', '02-Never Booked', '04-Active', '07-Reactivated')
|
|
then ldl.id_deal
|
|
else null
|
|
end
|
|
) as live_deals
|
|
from {{ ref("int_kpis__lifecycle_daily_deal") }} as ldl
|
|
left join {{ ref("int_kpis__dimension_deals") }} as ikdd on ldl.id_deal = ikdd.id_deal
|
|
left join
|
|
{{ ref("int_kpis__dimension_daily_accommodation") }} as icmas
|
|
on ldl.id_deal = icmas.id_deal
|
|
and ldl.date = icmas.date
|
|
left join
|
|
{{ ref("int_core__new_dash_deal_since_date") }} as icnddsd
|
|
on ldl.id_deal = icnddsd.id_deal
|
|
group by 1, 2, 3, 4
|