Merged PR 5322: First version of Stay Disrupt conversion funnel

# Description

First version of Stay Disrupt conversion funnel. It's a simple monthly compute of:
Active accounts -> Accounts that offered SD in GJ started in month -> Accounts that have had payments paid of SD in month
Total Guest Journeys Started -> GJ that offered SD in month-> Payments paid of SD in month

Some details:
* It also includes CIH, and data starts on 1st Jan 2025. This is to create report. This needs to be changed once the report is created.
* Note that Accounts that offered SD in GJ started in month and GJ that offered SD in month is equal to 0 as no data flows through the new flow. The rest has data.
* I consider all users, not only New Dash, knowing that I don't know if someone knows which users will have a certain Guest Product enabled.

Model is "agnostic" to the GP if we want, though the name still aims to be only for SD.

# Checklist

- [X] The edited models and dependants run properly with production data.
- [X] The edited models are sufficiently documented.
- [X] The edited models contain PK tests, and I've ran and passed them.
- [X] I have checked for DRY opportunities with other models and docs.
- [X] I've picked the right materialization for the affected models. **View to start with**

# Other

- [ ] Check if a full-refresh is required after this PR is merged.

Related work items: #30277
This commit is contained in:
Oriol Roqué Paniagua 2025-05-27 09:41:49 +00:00
parent 42af06c4dd
commit 06a4f679ea
2 changed files with 290 additions and 0 deletions

View file

@ -0,0 +1,164 @@
{% set stay_disrupt_launch_date = "'2025-01-07'" %} -- Switch to '2025-06-07'
{% set stay_disrupt_guest_product_names = "('CHECKINCOVER','STAYDISRUPT')" %} -- Switch to Stay Disrupt only
with
int_dates as (select * from {{ ref("int_dates") }}),
int_core__user_host as (select * from {{ ref("int_core__user_host") }}),
int_hubspot__deal as (select * from {{ ref("int_hubspot__deal") }}),
int_core__verification_requests as (
select * from {{ ref("int_core__verification_requests") }}
),
stg_core__verification_request_to_guest_product as (
select * from {{ ref("stg_core__verification_request_to_guest_product") }}
),
int_core__guest_journey_payments as (
select * from {{ ref("int_core__guest_journey_payments") }}
),
int_core__guest_products as (select * from {{ ref("int_core__guest_products") }}),
relevant_months as (
select distinct month_start_date
from int_dates
where date_day between {{ stay_disrupt_launch_date }} and current_date - 1
),
relevant_guest_products as (
select id_guest_product, guest_product_name, guest_product_latest_display_name
from int_core__guest_products
where guest_product_name in {{ stay_disrupt_guest_product_names }}
),
users as (
select
uh.id_user_host,
uh.id_deal,
date_trunc('month', uh.created_date_utc)::date
as active_from_month_start_date,
date_trunc(
'month', coalesce(d.cancellation_date_utc, {{ var("end_of_time") }})
)::date as active_to_month_start_date
from int_core__user_host uh
-- Includes HubSpot cancellation date to determine active users in range
inner join int_hubspot__deal d on uh.id_deal = d.id_deal
where
-- Ensure deal has gone live
d.live_date_utc is not null
),
-- Below serves as a skeleton for following measurements
active_users_per_guest_product_per_month as (
select
m.month_start_date,
u.id_user_host,
u.id_deal,
gp.id_guest_product,
gp.guest_product_name,
gp.guest_product_latest_display_name
from relevant_months m
inner join
users u
on m.month_start_date
between u.active_from_month_start_date and u.active_to_month_start_date
cross join relevant_guest_products gp
),
-- How many active accounts do we have per month?
active_accounts_per_month as (
select
ske.month_start_date,
ske.guest_product_name,
ske.guest_product_latest_display_name,
count(distinct ske.id_deal) as count_active_accounts
from active_users_per_guest_product_per_month ske
group by 1, 2, 3
),
-- How many Guest Journeys started per month? How many of them offered the Guest
-- Product? How many active accounts had the Guest Product offered?
guest_product_offered_at_guest_journey_level_per_month as (
select
ske.month_start_date,
ske.guest_product_name,
count(
distinct icvr.id_verification_request
) as count_guest_journeys_started,
count(
distinct vrtgp.id_verification_request
) as count_guest_journeys_started_with_guest_product_offered,
count(
distinct case
when vrtgp.id_verification_request is not null
then ske.id_deal
else null
end
) as count_active_accounts_with_guest_product_offered
from active_users_per_guest_product_per_month ske
-- Retrieve all Guest Journeys from users
inner join
int_core__verification_requests icvr
on ske.id_user_host = icvr.id_user_host
and ske.month_start_date
= date_trunc('month', icvr.verification_estimated_started_date_utc)::date
-- Check which ones offered Stay Disrupt
left join
stg_core__verification_request_to_guest_product vrtgp
on icvr.id_verification_request = vrtgp.id_verification_request
and ske.id_guest_product = vrtgp.id_guest_product
group by 1, 2
),
-- How many Guest Journeys had payments for these Guest Products? How many active
-- accounts had payments for these Guest Products? How much was paid?
guest_product_at_payment_level_per_month as (
select
ske.month_start_date,
ske.guest_product_name,
count(
distinct ske.id_deal
) as count_active_accounts_with_guest_product_payments,
count(id_guest_journey_payment) as count_guest_product_payments,
sum(amount_without_taxes_in_gbp) as sum_amount_paid_without_taxes_in_gbp
from active_users_per_guest_product_per_month ske
-- Retrieve all Guest Journeys from users
inner join
int_core__guest_journey_payments icgjp
on ske.id_user_host = icgjp.id_user_host
and ske.month_start_date
= date_trunc('month', icgjp.payment_paid_date_utc)::date
and ske.guest_product_name = icgjp.product_name
and icgjp.is_paid_status = true
group by 1, 2
)
select
active_accounts.month_start_date,
active_accounts.guest_product_name,
active_accounts.guest_product_latest_display_name,
-- Host Funnel --
coalesce(active_accounts.count_active_accounts, 0) as count_active_accounts,
coalesce(
guest_journey_level.count_active_accounts_with_guest_product_offered, 0
) as count_active_accounts_with_guest_product_offered,
coalesce(
payment_level.count_active_accounts_with_guest_product_payments, 0
) as count_active_accounts_with_guest_product_payments,
-- Guest Journey Funnel --
coalesce(
guest_journey_level.count_guest_journeys_started, 0
) as count_guest_journeys_started,
coalesce(
guest_journey_level.count_guest_journeys_started_with_guest_product_offered, 0
) as count_guest_journeys_started_with_guest_product_offered,
coalesce(
payment_level.count_guest_product_payments, 0
) as count_guest_product_payments,
-- Amount Paid --
coalesce(
payment_level.sum_amount_paid_without_taxes_in_gbp, 0
) as sum_amount_paid_without_taxes_in_gbp
from active_accounts_per_month active_accounts
left join
guest_product_offered_at_guest_journey_level_per_month guest_journey_level
on active_accounts.month_start_date = guest_journey_level.month_start_date
and active_accounts.guest_product_name = guest_journey_level.guest_product_name
left join
guest_product_at_payment_level_per_month payment_level
on active_accounts.month_start_date = payment_level.month_start_date
and active_accounts.guest_product_name = payment_level.guest_product_name