/* 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__unified_user as (select * from {{ ref("int_core__unified_user") }}), int_dates_mtd as (select * from {{ ref("int_dates_mtd") }}), booked_days_per_host as ( select id_user_host, created_date_utc, lag(created_date_utc, 1) over ( partition by id_user_host order by created_date_utc asc ) as previous_booked_date from int_core__bookings group by id_user_host, created_date_utc ), deal_historic_booking_dates as ( select d.date, h.id_deal, min(h.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_dates_mtd d inner join int_core__unified_user h on d.date >= h.created_date_utc left join booked_days_per_host b on h.id_user = b.id_user_host and d.date >= b.created_date_utc where h.id_deal is not null group by d.date, h.id_deal ), deal_historic_booking_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, 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 ) select date, id_deal, creation_date_utc, first_time_booked_date_utc, last_time_booked_date_utc, second_to_last_time_booked_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 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 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 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 when deal_has_at_least_one_booking and has_been_booked_within_last_12_months -- not reactivated and not ( had_previous_booking_more_than_12_months_before_the_last and has_been_booked_within_current_month ) -- 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 when deal_has_at_least_one_booking and not has_been_booked_within_last_12_months and not last_booking_was_12_months_ago then '06-Inactive' -- 07-Reactivated: The deal was churned/inactive but 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 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