Merged PR 4780: Improved New Dash Services usage

# Description

New KPIs model for Daily New Dash Users Services Offered
It shows which users have which services active daily per there product bundles.
There might be some services that are active in more than 1 bundle so I added the Bundle Id to the unique keys set

# 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.

# Other

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

Improved New Dash Services usage

Related work items: #28640
This commit is contained in:
Joaquin Ossa 2025-03-26 09:24:39 +00:00
commit 3d84678380
7 changed files with 218 additions and 513 deletions

View file

@ -1,235 +0,0 @@
{% set protected_service_status = "'PROTECTED'" %}
{% set rejected_service_status = "'REJECTED'" %}
{% set no_checks_service_status = "'NOCHECKS'" %}
{% set no_flags_service_status = "'NOFLAGS'" %}
{% set paid_service_status = "'PAID'" %}
{% set pending_service_status = "'PENDING'" %}
{% set unknown_service_status = "'-'" %}
{% set partially_protected_service_status = "'PARTIALLY PROTECTED'" %}
{% set not_protected_service_status = "'NOT PROTECTED'" %}
{% set not_paid_service_status = "'NOT PAID'" %}
{% set confirmed_service_status = "'CONFIRMED'" %}
{% set for_review_service_status = "'FORREVIEW'" %}
{% set flagged_service_status = "'FLAGGED'" %}
with
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__user_host as (select * from {{ ref("int_core__user_host") }}),
int_core__accommodation_to_product_bundle as (
select * from {{ ref("int_core__accommodation_to_product_bundle") }}
),
int_core__accommodation as (select * from {{ ref("int_core__accommodation") }}),
int_core__booking_to_product_bundle as (
select * from {{ ref("int_core__booking_to_product_bundle") }}
),
int_core__booking_service_detail as (
select * from {{ ref("int_core__booking_service_detail") }}
),
int_core__booking_summary as (select * from {{ ref("int_core__booking_summary") }}),
bundle_services as (
select
bs.id_user_product_bundle,
bs.id_user_host,
bs.product_service_display_name as service_display_name
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
-- 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,
coalesce(
pb.protection_display_name, {{ var("default_service") }}
) as service_display_name
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
),
users as (
select
bs.service_display_name,
count(distinct bs.id_user_host) as number_users,
-- Count only users that have at least one active accommodation.
-- with this service.
count(
distinct case
when apb.id_accommodation is not null and a.is_active
then bs.id_user_host
else null
end
) as number_users_with_service_applied_in_accommodation
from bundle_services bs
left join
int_core__accommodation_to_product_bundle apb
on bs.id_user_product_bundle = apb.id_user_product_bundle
and bs.id_user_host = apb.id_user_host
left join int_core__accommodation a on apb.id_accommodation = a.id_accommodation
group by 1
),
accommodations as (
select
bs.service_display_name,
count(distinct apb.id_accommodation) as number_accommodations,
count(
distinct case when a.is_active then apb.id_accommodation else null end
) as number_active_accommodations,
count(
distinct case
when a.is_active is false then apb.id_accommodation else null
end
) as number_inactive_accommodations
from bundle_services bs
left join
int_core__accommodation_to_product_bundle apb
on apb.id_user_product_bundle = bs.id_user_product_bundle
and now() between apb.original_starts_at_utc and coalesce(
apb.original_ends_at_utc, {{ var("end_of_time") }}
)
left join int_core__accommodation a on apb.id_accommodation = a.id_accommodation
group by 1
),
bookings as (
select
sd.service_name as service_display_name,
count(distinct sd.id_booking) as number_bookings,
count(
distinct case
when upper(sd.service_status) = {{ protected_service_status }}
then sd.id_booking
else null
end
) as number_bookings_with_service_status_protected,
count(
distinct case
when upper(sd.service_status) = {{ rejected_service_status }}
then sd.id_booking
else null
end
) as number_bookings_with_service_status_rejected,
count(
distinct case
when upper(sd.service_status) = {{ no_checks_service_status }}
then sd.id_booking
else null
end
) as number_bookings_with_service_status_no_checks,
count(
distinct case
when upper(sd.service_status) = {{ no_flags_service_status }}
then sd.id_booking
else null
end
) as number_bookings_with_service_status_no_flags,
count(
distinct case
when upper(sd.service_status) = {{ paid_service_status }}
then sd.id_booking
else null
end
) as number_bookings_with_service_status_paid,
count(
distinct case
when upper(sd.service_status) = {{ pending_service_status }}
then sd.id_booking
else null
end
) as number_bookings_with_service_status_pending,
count(
distinct case
when upper(sd.service_status) = {{ unknown_service_status }}
then sd.id_booking
else null
end
) as number_bookings_with_service_status_unknown,
count(
distinct case
when
upper(sd.service_status)
= {{ partially_protected_service_status }}
then sd.id_booking
else null
end
) as number_bookings_with_service_status_partially_protected,
count(
distinct case
when upper(sd.service_status) = {{ not_protected_service_status }}
then sd.id_booking
else null
end
) as number_bookings_with_service_status_not_protected,
count(
distinct case
when upper(sd.service_status) = {{ not_paid_service_status }}
then sd.id_booking
else null
end
) as number_bookings_with_service_status_not_paid,
count(
distinct case
when upper(sd.service_status) = {{ confirmed_service_status }}
then sd.id_booking
else null
end
) as number_bookings_with_service_status_confirmed,
count(
distinct case
when upper(sd.service_status) = {{ for_review_service_status }}
then sd.id_booking
else null
end
) as number_bookings_with_service_status_for_review,
count(
distinct case
when upper(sd.service_status) = {{ flagged_service_status }}
then sd.id_booking
else null
end
) as number_bookings_with_service_status_flagged
from int_core__booking_service_detail sd
left join int_core__booking_summary bs on sd.id_booking = bs.id_booking
where bs.is_user_in_new_dash = true and bs.is_missing_id_deal = false
group by 1
)
select
coalesce(u.service_display_name, b.service_display_name) as service_display_name,
u.number_users,
u.number_users_with_service_applied_in_accommodation,
u.number_users
- u.number_users_with_service_applied_in_accommodation
as number_users_without_service_applied_in_accommodation,
a.number_accommodations,
a.number_active_accommodations,
a.number_inactive_accommodations,
b.number_bookings,
b.number_bookings_with_service_status_protected,
b.number_bookings_with_service_status_rejected,
b.number_bookings_with_service_status_no_checks,
b.number_bookings_with_service_status_no_flags,
b.number_bookings_with_service_status_paid,
b.number_bookings_with_service_status_pending,
b.number_bookings_with_service_status_unknown,
b.number_bookings_with_service_status_partially_protected,
b.number_bookings_with_service_status_not_protected,
b.number_bookings_with_service_status_not_paid,
b.number_bookings_with_service_status_confirmed,
b.number_bookings_with_service_status_for_review,
b.number_bookings_with_service_status_flagged
from users u
left join accommodations a on u.service_display_name = a.service_display_name
full outer join bookings b on u.service_display_name = b.service_display_name

View file

@ -1,20 +1,54 @@
-- Default Protection Plan Id to use when the Id is missing in the source data.
-- This value represents "Basic Screening" protection.
{% set default_id_protection = 1 %}
{{ config(materialized="table") }}
with
stg_core__user_product_bundle as (
select * from {{ ref("stg_core__user_product_bundle") }}
),
stg_core__product_service as (select * from {{ ref("stg_core__product_service") }})
stg_core__product_service as (select * from {{ ref("stg_core__product_service") }}),
stg_core__protection_plan as (select * from {{ ref("stg_core__protection_plan") }}),
int_core__user_host as (
select *
from {{ ref("int_core__user_host") }}
where
is_user_in_new_dash = true
and is_missing_id_deal = false
and is_test_account = false
)
select
pb.id_user_product_bundle,
pb.id_user as id_user_host,
pb.id_product_bundle,
ps.id_product_service,
ps.id_product_service as id_service,
'PRODUCT' as service_source,
pb.product_bundle_name,
ps.product_service_name,
ps.product_service_display_name
ps.service_business_type,
ps.is_default_service,
ps.product_service_display_name as service_name
from stg_core__user_product_bundle pb
inner join int_core__user_host uh on pb.id_user = uh.id_user_host
cross join stg_core__product_service ps
where
-- bitwise AND (&) operator to determine if a specific service is part of the bundle
pb.chosen_product_services & ps.product_service_binary_tier > 0
union all
select
pb.id_user_product_bundle,
pb.id_user as id_user_host,
pb.id_product_bundle,
pb.id_protection_plan as id_service,
'PROTECTION' as service_source,
pb.product_bundle_name,
'PROTECTION' as service_business_type,
pp.is_default_service,
pp.protection_display_name as service_name
from stg_core__user_product_bundle pb
inner join int_core__user_host uh on pb.id_user = uh.id_user_host
inner join
stg_core__protection_plan pp
on pb.id_protection_plan = pp.id_protection_plan
and pb.id_protection_plan is not null
where pp.id_protection_plan <> {{ default_id_protection }}

View file

@ -3018,15 +3018,16 @@ models:
- name: int_core__user_product_bundle_contains_services
description: |
This table contains the information of "this user has a certain product bundle which
contains these services."
It's a denormalised relationship to break the power of 2 link between chosen_product_services
and product_service_binary_tier, which allows standard joins using the ids.
contains these services and protections."
It's a denormalised relationship to break the power of 2 link between
chosen_product_services/protection and product_binary_tier,
which allows standard joins using the ids.
data_tests:
- dbt_utils.unique_combination_of_columns:
combination_of_columns:
- id_user_product_bundle
- id_product_service
- service_name
columns:
- name: id_user_product_bundle
@ -3049,13 +3050,24 @@ models:
description: |
The identifier of the product bundle. Can be null if it's a custom bundle.
- name: id_product_service
- name: id_service
data_type: bigint
description: |
The identifier of the product service.
The identifier of the service.
data_tests:
- not_null
- name: service_source
data_type: string
description: |
The type of the service, which can be either "product" or "protection".
data_tests:
- not_null
- accepted_values:
values:
- "PRODUCT"
- "PROTECTION"
- name: product_bundle_name
data_type: string
description: |
@ -3063,17 +3075,31 @@ models:
data_tests:
- not_null
- name: product_service_name
- name: service_business_type
data_type: string
description: |
The name of the product service.
Identifies the service type (Screening, Deposit Management, Protection
or Guest Agreement) according to New Pricing documentation.
Cannot be null.
data_tests:
- not_null
- accepted_values:
values:
- SCREENING
- DEPOSIT_MANAGEMENT
- GUEST_AGREEMENT
- PROTECTION
- name: is_default_service
data_type: boolean
description: |
Flag that determines if the service is a default one (True)
or an upgraded service (False).
- name: product_service_display_name
- name: service_name
data_type: string
description: |
The display name of the product service.
The display name of the service.
data_tests:
- not_null
@ -5315,117 +5341,6 @@ models:
data_type: boolean
description: "Boolean value indicating if the guest chose CheckIn Cover."
- name: int_core__new_dash_services_offered
description: "This model contains the the services offered in New Dash.
These offers are displayed by different measures, such as the number of users,
accommodations and bookings."
columns:
- name: service_display_name
data_type: text
description: "The name of the New Dash service."
data_tests:
- not_null
- name: number_users
data_type: bigint
description:
"Number of user accounts that have a bundle that considers this service.
The fact that a user has a bundle with the service included does not mean
that the service is active or used. Each user can associate any of their
bundles with any of their accommodations."
- name: number_users_with_service_applied_in_accommodation
data_type: bigint
description:
"Number of user accounts that have a bundle that considers this service
and that bundle is active in at least one active accommodation.
In other words there is at least one active accommodation that offers
this service for this number of users."
- name: number_users_without_service_applied_in_accommodation
data_type: bigint
description:
"Number of user accounts that have a bundle that considers this service
but none of those bundle with the service is active in any active
accommodation.
It is basically the difference between number_users and
number_users_with_service_applied_in_accommodation."
- name: number_accommodations
data_type: bigint
description:
"Number of accommodations or listings that have a bundle that considers
this service."
- name: number_active_accommodations
data_type: bigint
description:
"Number of accommodations or listings that have a bundle that considers
this service and are active."
- name: number_inactive_accommodations
data_type: bigint
description:
"Number of accommodations or listings that have a bundle that considers
this service and are inactive."
- name: number_bookings
data_type: bigint
description: "Number of bookings that have a bundle that considers this service."
- name: number_bookings_with_service_status_protected
data_type: bigint
description: "Number of bookings with status PROTECTED for this service."
- name: number_bookings_with_service_status_rejected
data_type: bigint
description: "Number of bookings with status REJECTED for this service."
- name: number_bookings_with_service_status_no_checks
data_type: bigint
description: "Number of bookings with status NO CHECKS for this service."
- name: number_bookings_with_service_status_no_flags
data_type: bigint
description: "Number of bookings with status NO FLAGS for this service."
- name: number_bookings_with_service_status_paid
data_type: bigint
description: "Number of bookings with status PAID for this service."
- name: number_bookings_with_service_status_pending
data_type: bigint
description: "Number of bookings with status PENDING for this service."
- name: number_bookings_with_service_status_unknown
data_type: bigint
description: "Number of bookings with unknown status for this service."
- name: number_bookings_with_service_status_partially_protected
data_type: bigint
description: "Number of bookings with status PARTIALLY PROTECTED for this service."
- name: number_bookings_with_service_status_not_protected
data_type: bigint
description: "Number of bookings with status NOT PROTECTED for this service."
- name: number_bookings_with_service_status_not_paid
data_type: bigint
description: "Number of bookings with status NOT PAID for this service."
- name: number_bookings_with_service_status_confirmed
data_type: bigint
description: "Number of bookings with status CONFIRMED for this service."
- name: number_bookings_with_service_status_for_review
data_type: bigint
description: "Number of bookings with status FOR REVIEW for this service."
- name: number_bookings_with_service_status_flagged
data_type: bigint
description: "Number of bookings with status FLAGGED for this service."
- name: int_core__payments
description: |
A table holding payment details for guest journeys, including amounts in both

View file

@ -0,0 +1,39 @@
{{
config(
materialized="table",
unique_key=[
"date",
"id_deal",
"id_user_product_bundle",
"service_name",
"service_business_type",
],
)
}}
select
-- Unique Key --
dd.date,
uh.id_deal,
bs.id_user_product_bundle,
bs.service_name,
bs.service_business_type,
-- Dimensions --
case when bs.is_default_service then 'NO' else 'YES' end as is_upgraded_service,
coalesce(uh.new_dash_version, 'UNSET') as new_dash_version,
coalesce(
uh.main_billing_country_iso_3_per_deal, 'UNSET'
) as main_billing_country_iso_3_per_deal,
coalesce(
icmas.active_accommodations_per_deal_segmentation, 'UNSET'
) as active_accommodations_per_deal_segmentation
from {{ ref("int_kpis__dimension_dates") }} as dd
inner join
{{ ref("int_core__user_host") }} as uh
on dd.date >= uh.user_in_new_dash_since_date_utc
inner join
{{ ref("int_core__user_product_bundle_contains_services") }} as bs
on uh.id_user_host = bs.id_user_host
left join
{{ ref("int_kpis__dimension_daily_accommodation") }} as icmas
on uh.id_deal = icmas.id_deal
and dd.date = icmas.date

View file

@ -7383,3 +7383,108 @@ models:
The unique daily chargeable accommodations, or listings, in a given time range
and per specified dimension. This metric is not additive, and its value
can vary depending on the time period considered.
- name: int_kpis__metric_daily_new_dash_deals_offered_services
description: |
This model computes the Daily Offered Services by Deals at the deepest granularity.
It only retrieves services that come from users that are in New Dash, as well
as it only considers services created after the user has moved to New Dash.
The unique key corresponds to the deepest granularity of the model,
in this case:
- date,
- id_deal,
- id_user_product_bundle,
- service_name,
- service_business_type
data_tests:
- dbt_utils.unique_combination_of_columns:
combination_of_columns:
- date
- id_deal
- id_user_product_bundle
- service_name
- service_business_type
columns:
- name: date
data_type: date
description: Date of when user has a bundle with service active.
data_tests:
- not_null
- name: id_deal
data_type: string
description: Unique identifier of an account.
data_tests:
- not_null
- name: id_user_product_bundle
data_type: bigint
description: Unique identifier of the User Product Bundle.
data_tests:
- not_null
- name: service_name
data_type: string
description: Name of the created service.
data_tests:
- not_null
- name: service_business_type
data_type: string
description: |
Identifies the service type (Screening, Deposit Management, Protection
or Guest Agreement) according to New Pricing documentation.
Cannot be null.
data_tests:
- not_null
- accepted_values:
values:
- "SCREENING"
- "PROTECTION"
- "DEPOSIT_MANAGEMENT"
- "GUEST_AGREEMENT"
- name: is_upgraded_service
data_type: string
description: |
Whether the service is an upgraded version of the
default. In other words, if it's not Basic Screening.
data_tests:
- not_null
- accepted_values:
values:
- "YES"
- "NO"
- name: new_dash_version
data_type: string
description: |
The version of the New Dash. It corresponds to the
release or migration phase from user point of view.
data_tests:
- not_null
- name: active_accommodations_per_deal_segmentation
data_type: string
description: |
Segment value based on the number of listings booked in 12 months
for a given deal and date.
data_tests:
- not_null
- accepted_values:
values:
- "0"
- "01-05"
- "06-20"
- "21-60"
- "61+"
- "UNSET"
- name: main_billing_country_iso_3_per_deal
data_type: string
description: |
Main billing country of the host aggregated at Deal level.
data_tests:
- not_null

View file

@ -1,42 +0,0 @@
with
int_core__new_dash_services_offered as (
select * from {{ ref("int_core__new_dash_services_offered") }}
)
select
service_display_name as service_display_name,
number_users as number_users,
number_users_with_service_applied_in_accommodation
as number_users_with_service_applied_in_accommodation,
number_users_without_service_applied_in_accommodation
as number_users_without_service_applied_in_accommodation,
number_accommodations as number_accommodations,
number_active_accommodations as number_active_accommodations,
number_inactive_accommodations as number_inactive_accommodations,
number_bookings as number_bookings,
number_bookings_with_service_status_protected
as number_bookings_with_service_status_protected,
number_bookings_with_service_status_rejected
as number_bookings_with_service_status_rejected,
number_bookings_with_service_status_no_checks
as number_bookings_with_service_status_no_checks,
number_bookings_with_service_status_no_flags
as number_bookings_with_service_status_no_flags,
number_bookings_with_service_status_paid
as number_bookings_with_service_status_paid,
number_bookings_with_service_status_pending
as number_bookings_with_service_status_pending,
number_bookings_with_service_status_unknown
as number_bookings_with_service_status_unknown,
number_bookings_with_service_status_partially_protected
as number_bookings_with_service_status_partially_protected,
number_bookings_with_service_status_not_protected
as number_bookings_with_service_status_not_protected,
number_bookings_with_service_status_not_paid
as number_bookings_with_service_status_not_paid,
number_bookings_with_service_status_confirmed
as number_bookings_with_service_status_confirmed,
number_bookings_with_service_status_for_review
as number_bookings_with_service_status_for_review,
number_bookings_with_service_status_flagged
as number_bookings_with_service_status_flagged
from int_core__new_dash_services_offered

View file

@ -1568,117 +1568,6 @@ models:
data_type: boolean
description: "Boolean value indicating if the guest chose CheckIn Cover."
- name: core__new_dash_services_offered
description: "This model contains the the services offered in New Dash.
These offers are displayed by different measures, such as the number of users,
accommodations and bookings."
columns:
- name: service_display_name
data_type: text
description: "The name of the New Dash service."
data_tests:
- not_null
- name: number_users
data_type: bigint
description:
"Number of user accounts that have a bundle that considers this service.
The fact that a user has a bundle with the service included does not mean
that the service is active or used. Each user can associate any of their
bundles with any of their accommodations."
- name: number_users_with_service_applied_in_accommodation
data_type: bigint
description:
"Number of user accounts that have a bundle that considers this service
and that bundle is active in at least one active accommodation.
In other words there is at least one active accommodation that offers
this service for this number of users."
- name: number_users_without_service_applied_in_accommodation
data_type: bigint
description:
"Number of user accounts that have a bundle that considers this service
but none of those bundle with the service is active in any active
accommodation.
It is basically the difference between number_users and
number_users_with_service_applied_in_accommodation."
- name: number_accommodations
data_type: bigint
description:
"Number of accommodations or listings that have a bundle that considers
this service."
- name: number_active_accommodations
data_type: bigint
description:
"Number of accommodations or listings that have a bundle that considers
this service and are active."
- name: number_inactive_accommodations
data_type: bigint
description:
"Number of accommodations or listings that have a bundle that considers
this service and are inactive."
- name: number_bookings
data_type: bigint
description: "Number of bookings that have a bundle that considers this service."
- name: number_bookings_with_service_status_protected
data_type: bigint
description: "Number of bookings with status PROTECTED for this service."
- name: number_bookings_with_service_status_rejected
data_type: bigint
description: "Number of bookings with status REJECTED for this service."
- name: number_bookings_with_service_status_no_checks
data_type: bigint
description: "Number of bookings with status NO CHECKS for this service."
- name: number_bookings_with_service_status_no_flags
data_type: bigint
description: "Number of bookings with status NO FLAGS for this service."
- name: number_bookings_with_service_status_paid
data_type: bigint
description: "Number of bookings with status PAID for this service."
- name: number_bookings_with_service_status_pending
data_type: bigint
description: "Number of bookings with status PENDING for this service."
- name: number_bookings_with_service_status_unknown
data_type: bigint
description: "Number of bookings with unknown status for this service."
- name: number_bookings_with_service_status_partially_protected
data_type: bigint
description: "Number of bookings with status PARTIALLY PROTECTED for this service."
- name: number_bookings_with_service_status_not_protected
data_type: bigint
description: "Number of bookings with status NOT PROTECTED for this service."
- name: number_bookings_with_service_status_not_paid
data_type: bigint
description: "Number of bookings with status NOT PAID for this service."
- name: number_bookings_with_service_status_confirmed
data_type: bigint
description: "Number of bookings with status CONFIRMED for this service."
- name: number_bookings_with_service_status_for_review
data_type: bigint
description: "Number of bookings with status FOR REVIEW for this service."
- name: number_bookings_with_service_status_flagged
data_type: bigint
description: "Number of bookings with status FLAGGED for this service."
- name: core__payments
description: |
A table holding payment details for guest journeys, including amounts in both