# Description Adds listing metrics model. It's a bit similar as the Deal metrics, but here we can aggregate by deal :) I'm aware that int_kpis__metric_daily_listings takes quite a bit (3 min). To be optimised later on. # 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. - [ ] I have checked for DRY opportunities with other models and docs. - [ ] 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: #23567
73 lines
2.2 KiB
SQL
73 lines
2.2 KiB
SQL
{{
|
|
config(
|
|
materialized="table",
|
|
unique_key=[
|
|
"date",
|
|
"main_billing_country_iso_3_per_deal",
|
|
"active_accommodations_per_deal_segmentation",
|
|
],
|
|
)
|
|
}}
|
|
select
|
|
-- Unique Key --
|
|
ldl.date,
|
|
coalesce(
|
|
icd.main_billing_country_iso_3_per_deal, 'UNSET'
|
|
) as main_billing_country_iso_3_per_deal,
|
|
coalesce(
|
|
icmas.active_accommodations_per_deal_segmentation, 'UNSET'
|
|
) 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 = '03-First Time Booked'
|
|
then ldl.id_deal
|
|
else null
|
|
end
|
|
) as first_time_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
|
|
from {{ ref("int_kpis__lifecycle_daily_deal") }} as ldl
|
|
left join {{ ref("int_core__deal") }} as icd on ldl.id_deal = icd.id_deal
|
|
left join
|
|
{{ ref("int_kpis__dimension_daily_accommodation") }} as icmas
|
|
on ldl.id_deal = icmas.id_deal
|
|
and ldl.date = icmas.date
|
|
group by 1, 2, 3
|