# Description Improvements on onboarding data: * Hubspot services that clients expressed their interest in are now sorted alphabetically. This is needed for: * A new boolean to compare current active services applied in listings vs. services that captured the interest of the client on onboarding. This can help identify clients that we might need to follow up to ensure all programs are created and applied. # 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. - [ ] I have checked for DRY opportunities with other models and docs. - [ ] I've picked the right materialization for the affected models. # Other - [ ] Check if a full-refresh is required after this PR is merged. Related work items: #30249
289 lines
12 KiB
SQL
289 lines
12 KiB
SQL
{{ config(materialized="table") }}
|
|
with
|
|
int_core__user_host as (select * from {{ ref("int_core__user_host") }}),
|
|
int_hubspot__deal as (select * from {{ ref("int_hubspot__deal") }}),
|
|
int_core__accommodation as (select * from {{ ref("int_core__accommodation") }}),
|
|
int_core__booking_summary as (select * from {{ ref("int_core__booking_summary") }}),
|
|
int_core__user_product_bundle_contains_services as (
|
|
select * from {{ ref("int_core__user_product_bundle_contains_services") }}
|
|
),
|
|
int_core__user_product_bundle as (
|
|
select * from {{ ref("int_core__user_product_bundle") }}
|
|
),
|
|
int_core__accommodation_to_product_bundle as (
|
|
select * from {{ ref("int_core__accommodation_to_product_bundle") }}
|
|
),
|
|
int_xero__sales_denom_mart as (
|
|
select * from {{ ref("int_xero__sales_denom_mart") }}
|
|
),
|
|
new_dash_new_business_accounts as (
|
|
select
|
|
ihd.id_deal,
|
|
ihd.deal_name,
|
|
ihd.onboarding_owner,
|
|
ihd.account_manager,
|
|
ihd.live_date_utc,
|
|
ihd.contract_signed_date_utc,
|
|
ihd.cancellation_date_utc,
|
|
ihd.expressed_service_interest,
|
|
string_agg(icuh.company_name, ', ') as platform_company_name,
|
|
min(
|
|
icuh.user_in_new_dash_since_timestamp_at_utc
|
|
) as backend_account_creation_utc,
|
|
count(distinct icuh.id_user_host) as count_platform_accounts
|
|
from int_core__user_host icuh
|
|
-- Deal needs to exist in HS
|
|
inner join int_hubspot__deal ihd on icuh.id_deal = ihd.id_deal
|
|
where
|
|
-- Filters to replicate New Dash Overview
|
|
icuh.is_user_in_new_dash = true
|
|
and icuh.is_missing_id_deal = false
|
|
and icuh.is_test_account = false
|
|
-- Filter to only select new business (i.e., not migrated from Old Dash)
|
|
and icuh.has_user_moved_from_old_dash = false
|
|
group by 1, 2, 3, 4, 5, 6, 7, 8
|
|
),
|
|
program_creation_per_deal as (
|
|
select
|
|
id_deal,
|
|
min(icupb.created_at_utc) as first_program_created_at_utc,
|
|
min(
|
|
case
|
|
when icupb.has_upgraded_services then icupb.created_at_utc else null
|
|
end
|
|
) as first_upgraded_program_created_at_utc,
|
|
count(
|
|
distinct icupb.id_user_product_bundle
|
|
) as count_programs_at_deal_level,
|
|
count(
|
|
distinct case
|
|
when icupb.has_upgraded_services
|
|
then icupb.id_user_product_bundle
|
|
else null
|
|
end
|
|
) as count_upgraded_programs_at_deal_level,
|
|
string_agg(
|
|
distinct service_name, '|' order by service_name asc
|
|
) as services_in_programs_at_deal_level
|
|
from int_core__user_product_bundle icupb
|
|
inner join int_core__user_host icuh on icupb.id_user_host = icuh.id_user_host
|
|
left join
|
|
int_core__user_product_bundle_contains_services cs
|
|
on icupb.id_user_product_bundle = cs.id_user_product_bundle
|
|
where icuh.id_deal is not null
|
|
group by 1
|
|
),
|
|
listing_creation_per_deal as (
|
|
select
|
|
id_deal,
|
|
min(ica.created_at_utc) as first_listing_created_at_utc,
|
|
count(distinct ica.id_accommodation) as count_listings,
|
|
count(
|
|
distinct
|
|
case when ica.is_active = true then ica.id_accommodation else null end
|
|
) as count_active_listings
|
|
from int_core__accommodation ica
|
|
inner join int_core__user_host icuh on ica.id_user_host = icuh.id_user_host
|
|
where
|
|
-- Filters to replicate New Dash Overview
|
|
icuh.is_user_in_new_dash = true
|
|
and icuh.is_missing_id_deal = false
|
|
and icuh.is_test_account = false
|
|
-- Filter to only select new business (i.e., not migrated from Old Dash)
|
|
and icuh.has_user_moved_from_old_dash = false
|
|
group by 1
|
|
),
|
|
upgraded_program_applied_to_listing_per_deal as (
|
|
select
|
|
id_deal,
|
|
min(
|
|
atpb.created_at_utc
|
|
) as first_upgraded_program_applied_to_listing_at_utc,
|
|
count(
|
|
distinct atpb.id_user_product_bundle
|
|
) as count_upgraded_programs_at_listing_level,
|
|
count(
|
|
distinct case
|
|
when atpb.has_no_end_date and ica.is_active
|
|
then atpb.id_user_product_bundle
|
|
else null
|
|
end
|
|
) as count_active_upgraded_programs_at_active_listing_level,
|
|
count(
|
|
distinct atpb.id_accommodation
|
|
) as count_listings_with_upgraded_programs,
|
|
count(
|
|
distinct case
|
|
when atpb.has_no_end_date and ica.is_active
|
|
then atpb.id_accommodation
|
|
else null
|
|
end
|
|
) as count_active_listings_with_active_upgraded_programs,
|
|
string_agg(
|
|
distinct service_name, '|' order by service_name asc
|
|
) as services_in_programs_applied_to_listings,
|
|
string_agg(
|
|
distinct case
|
|
when atpb.has_no_end_date and ica.is_active
|
|
then service_name
|
|
else null
|
|
end,
|
|
'|'
|
|
order by
|
|
case
|
|
when atpb.has_no_end_date and ica.is_active
|
|
then service_name
|
|
else null
|
|
end asc
|
|
) as active_services_in_programs_applied_to_listings
|
|
from int_core__accommodation_to_product_bundle atpb
|
|
inner join int_core__user_host icuh on atpb.id_user_host = icuh.id_user_host
|
|
left join
|
|
int_core__user_product_bundle_contains_services cs
|
|
on atpb.id_user_product_bundle = cs.id_user_product_bundle
|
|
left join
|
|
int_core__accommodation ica on atpb.id_accommodation = ica.id_accommodation
|
|
where
|
|
icuh.id_deal is not null
|
|
-- Force that programs in listings have upgraded services
|
|
and atpb.has_upgraded_services = true
|
|
group by 1
|
|
),
|
|
booking_creation_per_deal as (
|
|
select
|
|
id_deal,
|
|
min(bs.booking_created_at_utc) as first_booking_created_at_utc,
|
|
min(
|
|
case
|
|
when bs.has_paid_services then bs.booking_created_at_utc else null
|
|
end
|
|
) as first_booking_with_paid_services_created_at_utc,
|
|
count(distinct bs.id_booking) as count_bookings,
|
|
count(
|
|
distinct case when bs.has_paid_services then bs.id_booking else null end
|
|
) as count_bookings_with_paid_service
|
|
from int_core__booking_summary bs
|
|
where id_deal is not null
|
|
group by 1
|
|
),
|
|
invoice_per_deal as (
|
|
select
|
|
id_deal,
|
|
min(document_issued_at_utc) at time zone 'utc' as first_invoice_at_utc
|
|
from int_xero__sales_denom_mart
|
|
where
|
|
-- Select only invoices
|
|
upper(document_class) = 'INVOICE'
|
|
and upper(document_status) in ('PAID', 'AUTHORISED')
|
|
and id_deal is not null
|
|
group by 1
|
|
),
|
|
combination_of_sources as (
|
|
select
|
|
ndnba.id_deal,
|
|
ndnba.deal_name,
|
|
ndnba.onboarding_owner,
|
|
ndnba.account_manager,
|
|
ndnba.platform_company_name,
|
|
ndnba.count_platform_accounts,
|
|
-- Activity --
|
|
coalesce(l.count_listings, 0) as count_listings,
|
|
coalesce(l.count_active_listings, 0) as count_active_listings,
|
|
coalesce(
|
|
upl.count_listings_with_upgraded_programs, 0
|
|
) as count_listings_with_upgraded_programs,
|
|
coalesce(
|
|
upl.count_active_listings_with_active_upgraded_programs, 0
|
|
) as count_active_listings_with_active_upgraded_programs,
|
|
coalesce(b.count_bookings, 0) as count_bookings,
|
|
coalesce(
|
|
b.count_bookings_with_paid_service, 0
|
|
) as count_bookings_with_paid_service,
|
|
-- Program funnel --
|
|
coalesce(p.count_programs_at_deal_level, 0) as count_programs_at_deal_level,
|
|
coalesce(
|
|
p.count_upgraded_programs_at_deal_level, 0
|
|
) as count_upgraded_programs_at_deal_level,
|
|
coalesce(
|
|
upl.count_upgraded_programs_at_listing_level, 0
|
|
) as count_upgraded_programs_at_listing_level,
|
|
coalesce(
|
|
upl.count_active_upgraded_programs_at_active_listing_level, 0
|
|
) as count_active_upgraded_programs_at_active_listing_level,
|
|
-- HubSpot main dates --
|
|
ndnba.contract_signed_date_utc,
|
|
ndnba.live_date_utc,
|
|
ndnba.cancellation_date_utc,
|
|
-- First time timestamps --
|
|
ndnba.backend_account_creation_utc,
|
|
l.first_listing_created_at_utc,
|
|
b.first_booking_created_at_utc,
|
|
p.first_program_created_at_utc,
|
|
p.first_upgraded_program_created_at_utc,
|
|
upl.first_upgraded_program_applied_to_listing_at_utc,
|
|
b.first_booking_with_paid_services_created_at_utc,
|
|
inv.first_invoice_at_utc,
|
|
-- Services --
|
|
ndnba.expressed_service_interest,
|
|
p.services_in_programs_at_deal_level,
|
|
upl.services_in_programs_applied_to_listings,
|
|
upl.active_services_in_programs_applied_to_listings,
|
|
-- Additional for filtering --
|
|
case
|
|
when ndnba.cancellation_date_utc is not null then true else false
|
|
end as has_churned
|
|
from new_dash_new_business_accounts ndnba
|
|
left join listing_creation_per_deal l on ndnba.id_deal = l.id_deal
|
|
left join program_creation_per_deal p on ndnba.id_deal = p.id_deal
|
|
left join
|
|
upgraded_program_applied_to_listing_per_deal upl
|
|
on ndnba.id_deal = upl.id_deal
|
|
left join booking_creation_per_deal b on ndnba.id_deal = b.id_deal
|
|
left join invoice_per_deal inv on ndnba.id_deal = inv.id_deal
|
|
)
|
|
select
|
|
*,
|
|
-- Basic Alerts --
|
|
case
|
|
when first_listing_created_at_utc is null and count_listings = 0
|
|
then false
|
|
else true
|
|
end as has_listings,
|
|
case when count_active_listings = 0 then false else true end as has_active_listings,
|
|
case
|
|
when first_booking_created_at_utc is null and count_bookings = 0
|
|
then false
|
|
else true
|
|
end as has_bookings,
|
|
case
|
|
when first_invoice_at_utc is null then false else true
|
|
end as has_been_invoiced,
|
|
|
|
-- Advanced Alerts --
|
|
case
|
|
when count_bookings > 0 and count_bookings_with_paid_service = 0
|
|
then true
|
|
else false
|
|
end as are_all_bookings_free,
|
|
case
|
|
when
|
|
count_bookings_with_paid_service > 0
|
|
and count_active_upgraded_programs_at_active_listing_level = 0
|
|
then true
|
|
else false
|
|
end as is_account_no_longer_generating_paid_bookings,
|
|
case
|
|
when
|
|
active_services_in_programs_applied_to_listings
|
|
<> services_in_programs_applied_to_listings
|
|
then true
|
|
else false
|
|
end as has_account_changed_services_applied_in_listings,
|
|
case
|
|
when
|
|
active_services_in_programs_applied_to_listings
|
|
<> expressed_service_interest
|
|
then true
|
|
else false
|
|
end as are_active_services_different_from_expressed_interest
|
|
from combination_of_sources
|