data-dwh-dbt-project/models/intermediate/cross/int_monthly_churned_deals.sql
2025-03-06 15:02:44 +01:00

110 lines
3.8 KiB
SQL

-- HubSpot id_stage for live deals
{% set live_stage = "Live" %}
with
int_hubspot__deal as (select * from {{ ref("int_hubspot__deal") }}),
int_monthly_aggregated_metrics_history_by_deal_by_time_window as (
select *
from {{ ref("int_monthly_aggregated_metrics_history_by_deal_by_time_window") }}
),
int_core__user_host as (select * from {{ ref("int_core__user_host") }}),
int_core__accommodation as (select * from {{ ref("int_core__accommodation") }})
select
d.id_deal,
extract(year from d.cancellation_date_utc) as cancellation_year,
extract(month from d.cancellation_date_utc) as cancellation_month,
d.cancellation_date_utc,
d.live_date_utc,
case
when d.deal_hubspot_stage = '{{ live_stage }}' then true else false
end as is_currently_active,
mam.main_deal_name,
mam.client_type,
mam.has_active_pms,
mam.active_pms_list,
mam.main_billing_country_iso_3_per_deal,
sum(
case
when mam.time_window = 'Previous 12 months'
then mam.total_revenue_in_gbp
else 0
end
) as total_revenue_in_gbp_previous_12_months,
sum(
case
when mam.time_window = 'Previous 6 months'
then mam.total_revenue_in_gbp
else 0
end
) as total_revenue_in_gbp_previous_6_months,
sum(
case
when mam.time_window = 'Previous 3 months'
then mam.total_revenue_in_gbp
else 0
end
) as total_revenue_in_gbp_previous_3_months,
sum(
case
when mam.time_window = 'Previous month' then mam.total_revenue_in_gbp else 0
end
) as total_revenue_in_gbp_previous_month,
sum(
case
when mam.time_window = 'Previous 12 month'
then mam.revenue_retained_post_resolutions_in_gbp
else 0
end
) as revenue_retained_post_resolutions_in_gbp_previous_12_months,
sum(
case
when mam.time_window = 'Previous 6 month'
then mam.revenue_retained_post_resolutions_in_gbp
else 0
end
) as revenue_retained_post_resolutions_in_gbp_previous_6_months,
sum(
case
when mam.time_window = 'Previous 3 month'
then mam.revenue_retained_post_resolutions_in_gbp
else 0
end
) as revenue_retained_post_resolutions_in_gbp_previous_3_months,
sum(
case
when mam.time_window = 'Previous month'
then mam.revenue_retained_post_resolutions_in_gbp
else 0
end
) as revenue_retained_post_resolutions_in_gbp_previous_month,
sum(
case
when mam.time_window = 'Previous 12 month' then mam.created_bookings else 0
end
) as created_bookings_previous_12_months,
sum(
case
when mam.time_window = 'Previous 6 month' then mam.created_bookings else 0
end
) as created_bookings_previous_6_months,
sum(
case
when mam.time_window = 'Previous 3 month' then mam.created_bookings else 0
end
) as created_bookings_previous_3_months,
sum(
case
when mam.time_window = 'Previous month' then mam.created_bookings else 0
end
) as created_bookings_previous_month,
count(distinct a.id_accommodation) as number_of_accommodations
from int_hubspot__deal d
inner join
int_monthly_aggregated_metrics_history_by_deal_by_time_window mam
on d.id_deal = mam.id_deal
and date_trunc('month', d.cancellation_date_utc) = date_trunc('month', mam.date)
inner join
int_core__user_host uh on d.id_deal = uh.id_deal and uh.is_test_account = false
left join int_core__accommodation a on uh.id_user_host = a.id_user_host
where d.cancellation_date_utc is not null
group by 1, 2, 3, 4, 5, 6, 7, 8, 9, 10, 11