Improved New Dash Services usage

This commit is contained in:
Joaquin 2025-03-21 17:07:56 +01:00
parent 12e0f55b08
commit c0a1e90fae
3 changed files with 173 additions and 0 deletions

View file

@ -0,0 +1,134 @@
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__user_product_bundle as (
select * from {{ ref("int_core__user_product_bundle") }}
),
int_core__user_product_bundle_contains_services as (
select * from {{ ref("int_core__user_product_bundle_contains_services") }}
),
int_core__accommodation_to_product_bundle as (
select * from {{ ref("int_core__accommodation_to_product_bundle") }}
),
int_core__booking_summary as (select * from {{ ref("int_core__booking_summary") }}),
user_services as (
select
bs.id_user_product_bundle,
bs.id_user_host,
uh.user_in_new_dash_since_date_utc,
bs.product_service_display_name as service_display_name,
uh.user_in_new_dash_since_date_utc as effective_start_date_utc,
coalesce(
hd.cancellation_date_utc, {{ var("end_of_time") }}
) as effective_end_date_utc
from int_core__user_product_bundle_contains_services bs
inner join
int_core__user_host uh
on bs.id_user_host = uh.id_user_host
and uh.is_user_in_new_dash = true
and uh.is_missing_id_deal = false
and uh.is_test_account = false
left join int_hubspot__deal hd on uh.id_deal = hd.id_deal
-- Union of all product services with all protection plan services.
-- This is because there are basically two types of services: product services
-- and protection plan services and they are stored in different tables.
union all
select
pb.id_user_product_bundle,
pb.id_user_host,
uh.user_in_new_dash_since_date_utc,
coalesce(
pb.protection_display_name, {{ var("default_service") }}
) as service_display_name,
pb.effective_start_date_utc,
coalesce(
hd.cancellation_date_utc,
pb.effective_end_date_utc,
{{ var("end_of_time") }}
) as effective_end_date_utc
from int_core__user_product_bundle pb
inner join
int_core__user_host uh
on pb.id_user_host = uh.id_user_host
and uh.is_user_in_new_dash = true
and uh.is_missing_id_deal = false
and uh.is_test_account = false
left join int_hubspot__deal hd on uh.id_deal = hd.id_deal
),
agg_user_services as (
select
d.date_day,
coalesce(us.service_display_name, 'GLOBAL') as service_display_name,
count(distinct us.id_user_host) as count_users
from int_dates d
left join
user_services us
on d.date_day >= us.user_in_new_dash_since_date_utc
and d.date_day
between us.effective_start_date_utc and us.effective_end_date_utc
where d.date_day between {{ var("new_dash_first_date") }} and current_date - 1
group by 1, rollup (us.service_display_name)
),
listing_services as (
select
us.service_display_name,
apb.id_accommodation,
apb.effective_start_date_utc,
coalesce(
apb.effective_end_date_utc, {{ var("end_of_time") }}
) as effective_end_date_utc
from user_services us
inner join
int_core__accommodation_to_product_bundle apb
on us.id_user_product_bundle = apb.id_user_product_bundle
),
agg_listing_services as (
select
d.date_day,
coalesce(ls.service_display_name, 'GLOBAL') as service_display_name,
count(distinct ls.id_accommodation) as count_accommodations
from int_dates d
inner join
listing_services ls
on d.date_day between {{ var("new_dash_first_date") }} and current_date - 1
and d.date_day
between ls.effective_start_date_utc and ls.effective_end_date_utc
group by 1, rollup (ls.service_display_name)
),
booking_services as (
select us.service_display_name, bs.id_booking, bs.booking_created_date_utc
from user_services us
inner join
int_core__booking_summary bs
on us.id_user_product_bundle = bs.id_user_product_bundle
and bs.booking_created_date_utc
between us.user_in_new_dash_since_date_utc and us.effective_end_date_utc
),
agg_booking_services as (
select
d.date_day,
coalesce(bs.service_display_name, 'GLOBAL') as service_display_name,
count(distinct bs.id_booking) as count_bookings
from int_dates d
inner join
booking_services bs
on d.date_day between {{ var("new_dash_first_date") }} and current_date - 1
and d.date_day = bs.booking_created_date_utc
group by 1, rollup (bs.service_display_name)
)
select
aus.date_day,
aus.service_display_name,
coalesce(aus.count_users, 0) as count_users,
coalesce(als.count_accommodations, 0) as count_accommodations,
coalesce(abs.count_bookings, 0) as count_bookings
from agg_user_services aus
left join
agg_listing_services als
on aus.date_day = als.date_day
and aus.service_display_name = als.service_display_name
left join
agg_booking_services abs
on aus.date_day = abs.date_day
and aus.service_display_name = abs.service_display_name

View file

@ -6084,3 +6084,39 @@ models:
Date of when this record was last updated.
data_tests:
- not_null
- name: int_core__daily_new_dash_services_applied
description: |
This model tracks the daily usage of different services of New Dash
applied across users, listings, and bookings.
data_tests:
- dbt_utils.unique_combination_of_columns:
combination_of_columns:
- date_day
- service_display_name
columns:
- name: date_day
data_type: date
description: "The date for which the service usage is recorded."
data_tests:
- not_null
- name: service_display_name
data_type: string
description: "The name of the service being tracked. 'Global' aggregates all services."
data_tests:
- not_null
- name: count_users
data_type: integer
description: "The number of distinct users (hosts) who have applied this service."
- name: count_accommodations
data_type: integer
description: "The number of distinct listings that have this service applied."
- name: count_bookings
data_type: integer
description: "The number of distinct bookings that have this service applied."