Merged PR 4317: Services Usage in New Dash

# Description

Model that shows the usage of each New Dash service by users, listings and booking (and segmented by state)

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

Related work items: #25934
This commit is contained in:
Joaquin Ossa 2025-02-10 14:01:35 +00:00
commit aa04b1a84f
7 changed files with 304 additions and 5 deletions

View file

@ -65,10 +65,19 @@ vars:
# KPIs Start Date. This is the date from which we start calculating KPIs. # KPIs Start Date. This is the date from which we start calculating KPIs.
"kpis_start_date": "'2022-04-01'" "kpis_start_date": "'2022-04-01'"
# A distant future date to use as a default when cutoff values are missing.
"end_of_time": "'2050-12-31'"
# Booking state variables # Booking state variables
# States should be strings in capital letters. Models need to force an upper() # States should be strings in capital letters. Models need to force an upper()
"cancelled_booking_state": "'CANCELLED'" "cancelled_booking_state": "'CANCELLED'"
"approved_booking_state": "'APPROVED'"
"flagged_booking_state": "'FLAGGED'"
# Payment state variables # Payment state variables
# States should be strings in capital letters. Models need to force an upper() # States should be strings in capital letters. Models need to force an upper()
"paid_payment_state": "'PAID'" "paid_payment_state": "'PAID'"
# Protection service state variables
# States should be strings in capital letters. Models need to force an upper()
"default_service": "'BASIC SCREENING'"

View file

@ -0,0 +1,122 @@
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__bookings as (select * from {{ ref("int_core__bookings") }}),
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 distinct
bs.service_display_name, count(distinct bs.id_user_host) as number_users
from bundle_services bs
group by 1
),
accommodations as (
select distinct
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 distinct
bs.service_display_name,
count(distinct bpb.id_booking) as number_bookings,
count(
distinct case
when upper(b.booking_state) = {{ var("approved_booking_state") }}
then bpb.id_booking
else null
end
) as number_approved_bookings,
count(
distinct case
when upper(b.booking_state) = {{ var("cancelled_booking_state") }}
then bpb.id_booking
else null
end
) as number_cancelled_bookings,
count(
distinct case
when upper(b.booking_state) = {{ var("flagged_booking_state") }}
then bpb.id_booking
else null
end
) as number_flagged_bookings
from bundle_services bs
left join
int_core__booking_to_product_bundle bpb
on bpb.id_user_product_bundle = bs.id_user_product_bundle
inner join
int_core__bookings b
on b.id_booking = bpb.id_booking
and b.is_duplicate_booking is false
group by 1
)
select
u.service_display_name,
u.number_users,
a.number_accommodations,
a.number_active_accommodations,
a.number_inactive_accommodations,
b.number_bookings,
b.number_approved_bookings,
b.number_cancelled_bookings,
b.number_flagged_bookings
from users u
left join accommodations a on u.service_display_name = a.service_display_name
left join bookings b on u.service_display_name = b.service_display_name

View file

@ -1,4 +1,3 @@
{% set product_bundles_without_paid_service = "('BASIC SCREENING')" %}
with with
int_core__user_product_bundle as ( int_core__user_product_bundle as (
select * from {{ ref("int_core__user_product_bundle") }} select * from {{ ref("int_core__user_product_bundle") }}
@ -43,7 +42,7 @@ with
distinct case distinct case
when when
atpb.user_product_bundle_name atpb.user_product_bundle_name
not in {{ product_bundles_without_paid_service }} not in ({{ var("default_service") }})
then atpb.id_accommodation then atpb.id_accommodation
else null else null
end end
@ -52,7 +51,7 @@ with
distinct case distinct case
when when
atpb.user_product_bundle_name atpb.user_product_bundle_name
not in {{ product_bundles_without_paid_service }} not in ({{ var("default_service") }})
and atpb.has_no_end_date = true and atpb.has_no_end_date = true
then atpb.id_accommodation then atpb.id_accommodation
else null else null
@ -72,7 +71,7 @@ with
distinct case distinct case
when when
btpb.user_product_bundle_name btpb.user_product_bundle_name
not in {{ product_bundles_without_paid_service }} not in ({{ var("default_service") }})
then btpb.id_booking then btpb.id_booking
else null else null
end end

View file

@ -11,7 +11,8 @@ select
pb.id_product_bundle, pb.id_product_bundle,
ps.id_product_service, ps.id_product_service,
pb.product_bundle_name, pb.product_bundle_name,
ps.product_service_name ps.product_service_name,
ps.product_service_display_name
from stg_core__user_product_bundle pb from stg_core__user_product_bundle pb
cross join stg_core__product_service ps cross join stg_core__product_service ps
where where

View file

@ -3023,6 +3023,13 @@ models:
data_tests: data_tests:
- not_null - not_null
- name: product_service_display_name
data_type: string
description: |
The display name of the product service.
data_tests:
- not_null
- name: int_core__product_service_to_price - name: int_core__product_service_to_price
description: | description: |
This model provides the information related to the prices of the different This model provides the information related to the prices of the different
@ -5165,3 +5172,76 @@ models:
- name: chose_checkin_cover - name: chose_checkin_cover
data_type: boolean data_type: boolean
description: "Boolean value indicating if the guest chose CheckIn Cover." 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
- accepted_values:
values:
- "BASIC SCREENING"
- "SCREENING PLUS"
- "ID VERIFICATION"
- "SEX OFFENDERS CHECK"
- "BASIC DAMAGE DEPOSIT"
- "BASIC WAIVER"
- "WAIVER PLUS"
- "WAIVER PRO"
- "BASIC PROTECTION"
- "PROTECTION PLUS"
- "PROTECTION PRO"
- 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_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_approved_bookings
data_type: bigint
description:
"Number of bookings that have a bundle that considers this service and
are approved."
- name: number_cancelled_bookings
data_type: bigint
description:
"Number of bookings that have a bundle that considers this service and
are cancelled."
- name: number_flagged_bookings
data_type: bigint
description:
"Number of bookings that have a bundle that considers this service and
are flagged."

View file

@ -0,0 +1,15 @@
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_accommodations as number_accommodations,
number_active_accommodations as number_active_accommodations,
number_inactive_accommodations as number_inactive_accommodations,
number_bookings as number_bookings,
number_approved_bookings as number_approved_bookings,
number_cancelled_bookings as number_cancelled_bookings,
number_flagged_bookings as number_flagged_bookings
from int_core__new_dash_services_offered

View file

@ -1567,3 +1567,76 @@ models:
- name: chose_checkin_cover - name: chose_checkin_cover
data_type: boolean data_type: boolean
description: "Boolean value indicating if the guest chose CheckIn Cover." 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
- accepted_values:
values:
- "BASIC SCREENING"
- "SCREENING PLUS"
- "ID VERIFICATION"
- "SEX OFFENDERS CHECK"
- "BASIC DAMAGE DEPOSIT"
- "BASIC WAIVER"
- "WAIVER PLUS"
- "WAIVER PRO"
- "BASIC PROTECTION"
- "PROTECTION PLUS"
- "PROTECTION PRO"
- 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_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_approved_bookings
data_type: bigint
description:
"Number of bookings that have a bundle that considers this service and
are approved."
- name: number_cancelled_bookings
data_type: bigint
description:
"Number of bookings that have a bundle that considers this service and
are cancelled."
- name: number_flagged_bookings
data_type: bigint
description:
"Number of bookings that have a bundle that considers this service and
are flagged."