diff --git a/models/intermediate/cross/int_mtd_deal_lifecycle.sql b/models/intermediate/cross/int_mtd_deal_lifecycle.sql index 38a65eb..ba7106f 100644 --- a/models/intermediate/cross/int_mtd_deal_lifecycle.sql +++ b/models/intermediate/cross/int_mtd_deal_lifecycle.sql @@ -8,7 +8,23 @@ with int_core__bookings as (select * from {{ ref("int_core__bookings") }}), int_core__unified_user as (select * from {{ ref("int_core__unified_user") }}), int_dates_mtd as (select * from {{ ref("int_dates_mtd") }}), + 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_host as ( select id_user_host, @@ -36,7 +52,7 @@ with where h.id_deal is not null group by d.date, h.id_deal ), - deal_historic_booking_features as ( + deal_historic_features as ( select hhbf.date, hhbf.id_deal, @@ -44,6 +60,17 @@ with 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, @@ -101,6 +128,8 @@ with 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, @@ -109,24 +138,37 @@ select 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 and has not had any booking - when not deal_has_at_least_one_booking and deal_was_created_this_month + -- 01-New: The deal has been created 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 deal_was_created_this_month + and not deal_has_been_offboarded then '01-New' -- 02-Never Booked: The deal has been created before this month and has not - -- had any booking - when not deal_has_at_least_one_booking and not deal_was_created_this_month + -- 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' -- 03-First Time Booked: The deal has been booked for the first time and it - -- has been created this month - when deal_has_first_booking and has_been_booked_within_current_month + -- has been created this month. Additionally, the deal has not been offboarded + -- in hubspot. + when + deal_has_first_booking + and has_been_booked_within_current_month + and not deal_has_been_offboarded then '03-First Time 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 is not reactivated and is not FTB + -- 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 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 @@ -135,26 +177,41 @@ select -- not FTB and not (deal_has_first_booking and has_been_booked_within_current_month) then '04-Active' - -- 05-Churning: 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 - then '05-Churning' - -- 06-Inactive: The deal has been booked at least once and it's been more - -- than 12 months since the last booking + -- 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 not has_been_booked_within_last_12_months - and not last_booking_was_12_months_ago + ( + 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 was churned/inactive but has had a new booking - -- this month + -- 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 -from deal_historic_booking_features + has_been_booked_within_last_12_months, + deal_has_been_offboarded as has_been_offboarded + +from deal_historic_features diff --git a/models/intermediate/cross/schema.yml b/models/intermediate/cross/schema.yml index 45164ab..989f382 100644 --- a/models/intermediate/cross/schema.yml +++ b/models/intermediate/cross/schema.yml @@ -1404,13 +1404,13 @@ models: deal regarding its activity. This information is encapsulated in the following columns: deal_lifecycle_state: contains one of the following states - - 01-New: Deals that have been created in the current month, without bookings - - 02-Never Booked: Deals that have been created before the current month, without bookings. - - 03-First Time Booked: Deals that have been booked for the first time in the current month. - - 04-Active: Deals that have booking activity in the past 12 months (that are not FTB nor reactivated) - - 05-Churning: Deals that are becoming inactive because of lack of bookings in the past 12 months - - 06-Inactive: Deals that have not had a booking for more than 12 months. - - 07-Reactivated: Deals that have had a booking in the current month that were inactive or churning before. + - 01-New: Deals that have been created in the current month, without bookings, that are not offboarded. + - 02-Never Booked: Deals that have been created before the current month, without bookings, that are not offboarded. + - 03-First Time Booked: Deals that have been booked for the first time in the current month, that are not offboarded. + - 04-Active: Deals that have booking activity in the past 12 months (that are not FTB nor reactivated), that are not offboarded. + - 05-Churning: Either Deals that are offboarded in that month or Deals that are becoming inactive because of lack of bookings in the past 12 months + - 06-Inactive: Either Deals that have been previously offboarded or Deals that have not had a booking for more than 12 months. + - 07-Reactivated: Deals that have had a booking in the current month that were inactive or churning before, that are not offboarded. - Finally, if none of the logic applies, which should not happen, null will be set and a dbt alert will raise. Since the states of Active, First Time Booked and Reactivated indicate certain booking activity and are @@ -1422,6 +1422,12 @@ models: Note that if a deal has had a booking created in a given month, all 3 columns will be true. Similarly, if the last booking created to a deal was 5 months ago, only the column has_been_booked_in_1_month will be false; while the other 2 will be true. + Some final considerations: + - It's possible but not common that a Deal gets offboarded on the same month that has had some bookings created. + - It shouldn't happen that a Deal that is Inactive has some bookings created. However, there's few cases in which + this happens likely because of misconfiguration between Hubspot and Core. This should be reported to increase + data quality. + tests: - dbt_utils.unique_combination_of_columns: combination_of_columns: @@ -1466,6 +1472,12 @@ models: on the lifecycle. Can be null if the deal has never had a booking associated with it or if the deal only had 1 booking in its history. + - name: cancellation_date_utc + data_type: date + description: | + Date of when the deal was cancelled, according to Hubspot. This is the date we're considering + for hard offboarding. It can be null, meaning the account has not been offboarded. + - name: deal_lifecycle_state data_type: character varying description: | @@ -1474,6 +1486,15 @@ models: 07-Reactivated. Failing to implement the logic will result in alert. tests: - not_null + - accepted_values: + values: + - 01-New + - 02-Never Booked + - 03-First Time Booked + - 04-Active + - 05-Churning + - 06-Inactive + - 07-Reactivated - name: has_been_booked_within_current_month data_type: boolean @@ -1487,6 +1508,10 @@ models: data_type: boolean description: If the deal has had a booking created in the past 12 months. + - name: has_been_offboarded + data_type: boolean + description: If the deal has been cancelled or not. + - name: int_mtd_deal_metrics description: | This model contains the historic information regarding the deals in an aggregated manner.