2024-11-07 10:49:06 +00:00
|
|
|
/*
|
|
|
|
|
This model provides Month-To-Date (MTD) deal lifecycle based on booking metrics.
|
|
|
|
|
Assumes a host will have a deal being filled.
|
|
|
|
|
|
|
|
|
|
*/
|
|
|
|
|
{{ config(materialized="table", unique_key=["date", "id_deal"]) }}
|
|
|
|
|
with
|
|
|
|
|
int_core__bookings as (select * from {{ ref("int_core__bookings") }}),
|
|
|
|
|
int_core__user_host as (select * from {{ ref("int_core__user_host") }}),
|
|
|
|
|
int_kpis__dimension_dates as (select * from {{ ref("int_kpis__dimension_dates") }}),
|
|
|
|
|
int_hubspot__deal as (select * from {{ ref("int_hubspot__deal") }}),
|
|
|
|
|
|
|
|
|
|
hubspot_deal_offboardings as (
|
|
|
|
|
-- At the moment it's not possible to account for deal reactivation within
|
|
|
|
|
-- hubspot, meaning, once a deal has a cancellation date we'll be considering
|
|
|
|
|
-- it as churned. However, a deal can be reactivated and if so, the
|
|
|
|
|
-- cancellation date might be set up to null, thus loosing the previous
|
|
|
|
|
-- history of offboarding and affecting backwards history. Lastly,
|
|
|
|
|
-- cancellation date not being null is preferred vs. the hubspot deal stage
|
|
|
|
|
-- since an actual churned deal might be in a process of reactivation,
|
|
|
|
|
-- discussing with our colleagues from sales / am teams. In this discussion
|
|
|
|
|
-- period, the stage could be different than cancelled, but still not
|
|
|
|
|
-- reactivated.
|
|
|
|
|
select id_deal, cancellation_date_utc
|
|
|
|
|
from int_hubspot__deal
|
|
|
|
|
where cancellation_date_utc is not null
|
|
|
|
|
),
|
|
|
|
|
booked_days_per_deal as (
|
|
|
|
|
select
|
|
|
|
|
icuh.id_deal,
|
2025-01-29 11:20:12 +01:00
|
|
|
icb.created_date_utc as created_date_utc,
|
|
|
|
|
lag(icb.created_date_utc, 1) over (
|
|
|
|
|
partition by icuh.id_deal order by icb.created_date_utc asc
|
2024-11-07 10:49:06 +00:00
|
|
|
) as previous_booked_date
|
|
|
|
|
from int_core__bookings icb
|
|
|
|
|
inner join int_core__user_host icuh on icb.id_user_host = icuh.id_user_host
|
2025-01-28 16:47:44 +01:00
|
|
|
inner join int_hubspot__deal hd on icuh.id_deal = hd.id_deal
|
2024-11-07 10:49:06 +00:00
|
|
|
where icuh.id_deal is not null
|
2025-01-29 11:20:12 +01:00
|
|
|
group by icuh.id_deal, icb.created_date_utc
|
|
|
|
|
),
|
|
|
|
|
deals as (
|
|
|
|
|
select
|
|
|
|
|
coalesce(hd.id_deal, h.id_deal) as id_deal,
|
|
|
|
|
min(coalesce(hd.live_date_utc, h.created_date_utc)) as created_date_utc
|
|
|
|
|
from intermediate.int_hubspot__deal hd
|
|
|
|
|
full outer join
|
|
|
|
|
intermediate.int_core__user_host h
|
|
|
|
|
on hd.id_deal = h.id_deal
|
|
|
|
|
and h.id_deal is not null
|
|
|
|
|
where hd.id_deal is not null
|
|
|
|
|
group by 1
|
2024-11-07 10:49:06 +00:00
|
|
|
),
|
|
|
|
|
deal_historic_booking_dates as (
|
|
|
|
|
select
|
|
|
|
|
d.date,
|
|
|
|
|
h.id_deal,
|
2024-12-31 08:04:03 +00:00
|
|
|
min(h.created_date_utc) as creation_date_utc,
|
2024-11-07 10:49:06 +00:00
|
|
|
min(b.created_date_utc) as first_time_booked_date_utc,
|
|
|
|
|
max(b.created_date_utc) as last_time_booked_date_utc,
|
|
|
|
|
max(b.previous_booked_date) as second_to_last_time_booked_date_utc
|
|
|
|
|
from int_kpis__dimension_dates d
|
2025-01-29 11:20:12 +01:00
|
|
|
inner join deals h on d.date >= h.created_date_utc
|
2024-11-07 10:49:06 +00:00
|
|
|
left join
|
|
|
|
|
booked_days_per_deal b
|
|
|
|
|
on h.id_deal = b.id_deal
|
|
|
|
|
and d.date >= b.created_date_utc
|
|
|
|
|
where h.id_deal is not null
|
|
|
|
|
group by d.date, h.id_deal
|
|
|
|
|
),
|
|
|
|
|
deal_historic_features as (
|
|
|
|
|
select
|
|
|
|
|
hhbf.date,
|
|
|
|
|
hhbf.id_deal,
|
|
|
|
|
hhbf.creation_date_utc,
|
|
|
|
|
hhbf.first_time_booked_date_utc,
|
|
|
|
|
hhbf.last_time_booked_date_utc,
|
|
|
|
|
hhbf.second_to_last_time_booked_date_utc,
|
|
|
|
|
hdo.cancellation_date_utc,
|
|
|
|
|
case
|
|
|
|
|
when hhbf.date >= hdo.cancellation_date_utc then true else false
|
|
|
|
|
end as deal_has_been_offboarded,
|
|
|
|
|
case
|
|
|
|
|
when
|
|
|
|
|
date_trunc('month', hdo.cancellation_date_utc)
|
|
|
|
|
= date_trunc('month', hhbf.date)
|
|
|
|
|
then true
|
|
|
|
|
else false
|
|
|
|
|
end as deal_was_offboarded_this_month,
|
|
|
|
|
case
|
|
|
|
|
when hhbf.first_time_booked_date_utc is not null then true else false
|
|
|
|
|
end as deal_has_at_least_one_booking,
|
|
|
|
|
case
|
|
|
|
|
when
|
|
|
|
|
date_trunc('month', hhbf.creation_date_utc)
|
|
|
|
|
= date_trunc('month', hhbf.date)
|
|
|
|
|
then true
|
|
|
|
|
else false
|
|
|
|
|
end as deal_was_created_this_month,
|
|
|
|
|
case
|
|
|
|
|
when
|
|
|
|
|
date_trunc('month', hhbf.first_time_booked_date_utc)
|
|
|
|
|
= date_trunc('month', hhbf.last_time_booked_date_utc)
|
|
|
|
|
then true
|
|
|
|
|
else false
|
|
|
|
|
end as deal_has_first_booking,
|
|
|
|
|
case
|
|
|
|
|
when
|
|
|
|
|
date_trunc('month', hhbf.last_time_booked_date_utc)
|
|
|
|
|
= date_trunc('month', hhbf.date)
|
|
|
|
|
then true
|
|
|
|
|
else false
|
|
|
|
|
end as has_been_booked_within_current_month,
|
|
|
|
|
case
|
|
|
|
|
when
|
|
|
|
|
date_trunc('month', hhbf.last_time_booked_date_utc)
|
|
|
|
|
+ interval '6 months'
|
|
|
|
|
> date_trunc('month', hhbf.date)
|
|
|
|
|
then true
|
|
|
|
|
else false
|
|
|
|
|
end as has_been_booked_within_last_6_months,
|
|
|
|
|
case
|
|
|
|
|
when
|
|
|
|
|
date_trunc('month', hhbf.last_time_booked_date_utc)
|
|
|
|
|
+ interval '12 months'
|
|
|
|
|
> date_trunc('month', hhbf.date)
|
|
|
|
|
then true
|
|
|
|
|
else false
|
|
|
|
|
end as has_been_booked_within_last_12_months,
|
|
|
|
|
case
|
|
|
|
|
when
|
|
|
|
|
date_trunc('month', hhbf.last_time_booked_date_utc)
|
|
|
|
|
+ interval '12 months'
|
|
|
|
|
= date_trunc('month', hhbf.date)
|
|
|
|
|
then true
|
|
|
|
|
else false
|
|
|
|
|
end as last_booking_was_12_months_ago,
|
|
|
|
|
case
|
|
|
|
|
when
|
|
|
|
|
date_trunc('month', hhbf.second_to_last_time_booked_date_utc)
|
|
|
|
|
+ interval '12 months'
|
|
|
|
|
< date_trunc('month', hhbf.last_time_booked_date_utc)
|
|
|
|
|
then true
|
|
|
|
|
else false
|
|
|
|
|
end as had_previous_booking_more_than_12_months_before_the_last
|
|
|
|
|
from deal_historic_booking_dates hhbf
|
|
|
|
|
left join hubspot_deal_offboardings hdo on hhbf.id_deal = hdo.id_deal
|
|
|
|
|
|
|
|
|
|
)
|
|
|
|
|
select
|
|
|
|
|
date,
|
|
|
|
|
id_deal,
|
|
|
|
|
creation_date_utc,
|
|
|
|
|
first_time_booked_date_utc,
|
|
|
|
|
last_time_booked_date_utc,
|
|
|
|
|
second_to_last_time_booked_date_utc,
|
|
|
|
|
cancellation_date_utc,
|
|
|
|
|
case
|
2025-01-27 14:55:53 +01:00
|
|
|
-- 01-New: The deal has been created this month.
|
2024-11-07 10:49:06 +00:00
|
|
|
-- Additionally, the deal has not been offboarded in hubspot.
|
2025-01-29 11:20:12 +01:00
|
|
|
when deal_was_created_this_month and not deal_has_been_offboarded
|
2024-11-07 10:49:06 +00:00
|
|
|
then '01-New'
|
|
|
|
|
-- 02-Never Booked: The deal has been created before this month and has not
|
|
|
|
|
-- had any booking. Additionally, the deal has not been offboarded in hubspot.
|
|
|
|
|
when
|
|
|
|
|
not deal_has_at_least_one_booking
|
|
|
|
|
and not deal_was_created_this_month
|
|
|
|
|
and not deal_has_been_offboarded
|
|
|
|
|
then '02-Never Booked'
|
|
|
|
|
-- 04-Active: The deal has had at least 1 booking in its history and it's
|
|
|
|
|
-- been less than 12 months since the last booking and has not been offboarded
|
|
|
|
|
-- in hubspot and is not reactivated and is not FTB
|
|
|
|
|
when
|
|
|
|
|
deal_has_at_least_one_booking
|
2025-01-27 14:55:53 +01:00
|
|
|
and not deal_was_created_this_month
|
2024-11-07 10:49:06 +00:00
|
|
|
and has_been_booked_within_last_12_months
|
|
|
|
|
and not deal_has_been_offboarded
|
|
|
|
|
-- not reactivated
|
|
|
|
|
and not (
|
|
|
|
|
had_previous_booking_more_than_12_months_before_the_last
|
|
|
|
|
and has_been_booked_within_current_month
|
|
|
|
|
)
|
|
|
|
|
then '04-Active'
|
|
|
|
|
-- 05-Churning: The deal has been offboarded this month. Alternatively, The
|
|
|
|
|
-- deal has been booked at least once and it's been 12 months since the last
|
|
|
|
|
-- booking
|
|
|
|
|
when
|
|
|
|
|
(
|
|
|
|
|
deal_has_at_least_one_booking
|
|
|
|
|
and last_booking_was_12_months_ago
|
|
|
|
|
and not deal_has_been_offboarded
|
|
|
|
|
)
|
|
|
|
|
or deal_was_offboarded_this_month
|
|
|
|
|
then '05-Churning'
|
|
|
|
|
-- 06-Inactive: The deal has been offboarded in the past but not this month.
|
|
|
|
|
-- Alternatively, the deal is not offboarded and the deal has been booked at
|
|
|
|
|
-- least once and it's been more than 12 months since the last booking.
|
|
|
|
|
when
|
|
|
|
|
(
|
|
|
|
|
deal_has_at_least_one_booking
|
|
|
|
|
and not has_been_booked_within_last_12_months
|
|
|
|
|
and not last_booking_was_12_months_ago
|
|
|
|
|
and not deal_has_been_offboarded
|
|
|
|
|
)
|
|
|
|
|
or (deal_has_been_offboarded and not deal_was_offboarded_this_month)
|
|
|
|
|
then '06-Inactive'
|
|
|
|
|
-- 07-Reactivated: The deal is not offboarded but was churned/inactive, and
|
|
|
|
|
-- now has had a new booking this month
|
|
|
|
|
when
|
|
|
|
|
had_previous_booking_more_than_12_months_before_the_last
|
|
|
|
|
and has_been_booked_within_current_month
|
|
|
|
|
and not deal_has_been_offboarded
|
|
|
|
|
then '07-Reactivated'
|
|
|
|
|
else null
|
|
|
|
|
end as deal_lifecycle_state,
|
|
|
|
|
has_been_booked_within_current_month,
|
|
|
|
|
has_been_booked_within_last_6_months,
|
|
|
|
|
has_been_booked_within_last_12_months,
|
|
|
|
|
deal_has_been_offboarded as has_been_offboarded
|
|
|
|
|
|
|
|
|
|
from deal_historic_features
|