From 1ebd1c5ccbcd77a7fa314d52cec0fcb71aeaf7e3 Mon Sep 17 00:00:00 2001 From: Joaquin Date: Mon, 24 Mar 2025 13:00:24 +0100 Subject: [PATCH] Created new kpi daily model for new dash users --- dbt_project.yml | 3 - ..._core__daily_new_dash_services_applied.sql | 134 ------------------ models/intermediate/core/schema.yml | 39 +---- ..._daily_new_dash_users_offered_services.sql | 92 ++++++++++++ models/intermediate/kpis/schema.yml | 118 +++++++++++++++ 5 files changed, 213 insertions(+), 173 deletions(-) delete mode 100644 models/intermediate/core/int_core__daily_new_dash_services_applied.sql create mode 100644 models/intermediate/kpis/int_kpis__metric_daily_new_dash_users_offered_services.sql diff --git a/dbt_project.yml b/dbt_project.yml index 39de2fa..e61362d 100644 --- a/dbt_project.yml +++ b/dbt_project.yml @@ -68,9 +68,6 @@ vars: # New Dash First Invoicing Date. This is the first date considered for New Dash invoicing. "new_dash_first_invoicing_date": "'2024-12-31'" - # New Dash First Date. This is the first date considered for New Dash. - "new_dash_first_date": "'2024-07-30'" - # A distant future date to use as a default when cutoff values are missing. "end_of_time": "'2050-12-31'" diff --git a/models/intermediate/core/int_core__daily_new_dash_services_applied.sql b/models/intermediate/core/int_core__daily_new_dash_services_applied.sql deleted file mode 100644 index 48734e4..0000000 --- a/models/intermediate/core/int_core__daily_new_dash_services_applied.sql +++ /dev/null @@ -1,134 +0,0 @@ -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 diff --git a/models/intermediate/core/schema.yml b/models/intermediate/core/schema.yml index 9c52cbb..ee29edd 100644 --- a/models/intermediate/core/schema.yml +++ b/models/intermediate/core/schema.yml @@ -5319,6 +5319,9 @@ models: 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." + meta: + deprecated: true + deprecation_date: "2025-06-30" columns: - name: service_display_name @@ -6084,39 +6087,3 @@ 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." diff --git a/models/intermediate/kpis/int_kpis__metric_daily_new_dash_users_offered_services.sql b/models/intermediate/kpis/int_kpis__metric_daily_new_dash_users_offered_services.sql new file mode 100644 index 0000000..9cea854 --- /dev/null +++ b/models/intermediate/kpis/int_kpis__metric_daily_new_dash_users_offered_services.sql @@ -0,0 +1,92 @@ +{{ + config( + materialized="table", + unique_key=[ + "id_user_host", + "id_user_product_bundle", + "service_name", + "date", + "service_business_type", + ], + ) +}} +select + -- Unique Key -- + d.date_day as date, + bs.id_user_host, + bs.id_user_product_bundle, + bs.product_service_display_name as service_name, + coalesce(ps.service_business_type, 'UNSET') as service_business_type, + -- Dimensions -- + coalesce(uh.id_deal, 'UNSET') as id_deal, + case when ps.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_dates") }} as d +inner join + {{ ref("int_core__user_host") }} as uh + on uh.is_user_in_new_dash = true + and uh.is_missing_id_deal = false + and uh.is_test_account = false + and d.date_day between uh.user_in_new_dash_since_date_utc and current_date - 1 +inner join + {{ ref("int_core__user_product_bundle_contains_services") }} as bs + on uh.id_user_host = bs.id_user_host +left join + {{ ref("stg_core__product_service") }} as ps + on ps.product_service_display_name = bs.product_service_display_name +left join + {{ ref("int_hubspot__deal") }} as hd + on uh.id_deal = hd.id_deal + and coalesce(hd.cancellation_date_utc, {{ var("end_of_time") }}) >= d.date_day +left join + {{ ref("int_kpis__dimension_daily_accommodation") }} as icmas + on uh.id_deal = icmas.id_deal + and d.date_day = icmas.date +-- 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 + -- Unique Key -- + d.date_day as date, + pb.id_user_host, + pb.id_user_product_bundle, + coalesce(pb.protection_display_name, {{ var("default_service") }}) as service_name, + 'PROTECTION' as service_business_type, + -- Dimensions -- + coalesce(uh.id_deal, 'UNSET') as id_deal, + case when pp.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_dates") }} as d +inner join + {{ ref("int_core__user_host") }} as uh + on uh.is_user_in_new_dash = true + and uh.is_missing_id_deal = false + and uh.is_test_account = false + and d.date_day between uh.user_in_new_dash_since_date_utc and current_date - 1 +inner join + {{ ref("int_core__user_product_bundle") }} as pb + on uh.id_user_host = pb.id_user_host +left join + {{ ref("stg_core__protection_plan") }} as pp + on pp.protection_display_name = pb.protection_display_name +left join + {{ ref("int_hubspot__deal") }} as hd + on uh.id_deal = hd.id_deal + and coalesce(hd.cancellation_date_utc, {{ var("end_of_time") }}) >= d.date_day +left join + {{ ref("int_kpis__dimension_daily_accommodation") }} as icmas + on uh.id_deal = icmas.id_deal + and d.date_day = icmas.date diff --git a/models/intermediate/kpis/schema.yml b/models/intermediate/kpis/schema.yml index 6c57e52..0600575 100644 --- a/models/intermediate/kpis/schema.yml +++ b/models/intermediate/kpis/schema.yml @@ -7383,3 +7383,121 @@ 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_users_offered_services + description: | + This model computes the Daily Offered Services by Users 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_user_host, + - id_user_product_bundle, + - service_name, + - service_business_type + + data_tests: + - dbt_utils.unique_combination_of_columns: + combination_of_columns: + - date + - id_user_host + - 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_user_host + data_type: bigint + description: Unique identifier of the User Host. + 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: id_deal + data_type: string + description: Unique identifier of an account. + data_tests: + - not_null + + - 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: 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" + - "UNKNOWN" + - "UNSET" + + - 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 + + - name: created_services + data_type: bigint + description: | + Count of daily services created in a given date and per specified dimension.