data-dwh-dbt-project/models/intermediate/kpis/int_kpis__lifecycle_daily_deal.sql
2025-03-14 10:39:01 +01:00

251 lines
10 KiB
SQL

/*
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_kpis__dimension_deals as (select * from {{ ref("int_kpis__dimension_deals") }}),
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, hubspot_deal_cancellation_date_utc as cancellation_date_utc
from int_kpis__dimension_deals
where hubspot_deal_cancellation_date_utc is not null
),
booked_days_per_deal as (
select
icuh.id_deal,
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
) 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
-- Ensure only Platform deals are considered (exclude API deals)
inner join
int_kpis__dimension_deals ikdd
on icuh.id_deal = ikdd.id_deal
and ikdd.client_type = 'PLATFORM'
where icuh.id_deal is not null
group by icuh.id_deal, icb.created_date_utc
),
deals as (
select
ikdd.id_deal,
ikdd.client_type,
ikdd.is_deal_in_hubspot,
ikdd.effective_deal_start_date_utc as created_date_utc
from int_kpis__dimension_deals ikdd
),
deal_historic_booking_dates as (
select
d.date,
ikdd.id_deal,
ikdd.is_deal_in_hubspot,
min(ikdd.client_type) as client_type,
min(ikdd.created_date_utc) as creation_date_utc,
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
inner join deals ikdd on d.date >= ikdd.created_date_utc
left join
booked_days_per_deal b
on ikdd.id_deal = b.id_deal
and d.date >= b.created_date_utc
group by d.date, ikdd.id_deal, ikdd.is_deal_in_hubspot
),
deal_historic_features as (
select
hhbf.date,
hhbf.id_deal,
hhbf.is_deal_in_hubspot,
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.client_type = 'API' then true else false end as is_api_deal,
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
-- 01-New: The deal has been created this month.
-- Additionally, the deal has not been offboarded in hubspot.
when
deal_was_created_this_month
and not deal_has_been_offboarded
and is_deal_in_hubspot
then '01-New'
-- 02-Never Booked: The deal is not API, 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
and not is_api_deal
and is_deal_in_hubspot
then '02-Never Booked'
-- 04-Active:
-- The deal is API, is not New and has not been offboarded
-- The deal is not API and 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
when
-- API deals --
is_api_deal
and not deal_was_created_this_month
and not deal_has_been_offboarded
and is_deal_in_hubspot
-- Platform deals --
or (
not is_api_deal
and deal_has_at_least_one_booking
and not deal_was_created_this_month
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
)
and is_deal_in_hubspot
)
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
and not is_api_deal
)
or deal_was_offboarded_this_month
and is_deal_in_hubspot
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
and not is_api_deal
)
or (deal_has_been_offboarded and not deal_was_offboarded_this_month)
and is_deal_in_hubspot
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
and not is_api_deal
and is_deal_in_hubspot
then '07-Reactivated'
else '99-Not in HubSpot'
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