diff --git a/models/intermediate/core/int_core__user_product_bundle_contains_services.sql b/models/intermediate/core/int_core__user_product_bundle_contains_services.sql index 5dd9363..8cf933e 100644 --- a/models/intermediate/core/int_core__user_product_bundle_contains_services.sql +++ b/models/intermediate/core/int_core__user_product_bundle_contains_services.sql @@ -3,18 +3,50 @@ 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_product, + 'SERVICE' as product_type, pb.product_bundle_name, - ps.product_service_name, - ps.product_service_display_name + ps.service_business_type, + ps.is_default_service, + ps.product_service_name as product_name, + ps.product_service_display_name as product_display_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, + coalesce(pb.id_protection_plan, 1) as id_product, + 'PROTECTION' as product_type, + pb.product_bundle_name, + 'PROTECTION' as service_business_type, + pp.is_default_service, + coalesce(pp.protection_name, {{ var("default_service") }}) as product_name, + coalesce( + pp.protection_display_name, {{ var("default_service") }} + ) as product_display_name +from stg_core__user_product_bundle pb +inner join int_core__user_host uh on pb.id_user = uh.id_user_host +left join + stg_core__protection_plan pp + on coalesce(pb.id_protection_plan, 1) = pp.id_protection_plan diff --git a/models/intermediate/core/schema.yml b/models/intermediate/core/schema.yml index ee29edd..332fc08 100644 --- a/models/intermediate/core/schema.yml +++ b/models/intermediate/core/schema.yml @@ -3018,15 +3018,17 @@ 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 + - id_product + - product_type columns: - name: id_user_product_bundle @@ -3049,13 +3051,24 @@ models: description: | The identifier of the product bundle. Can be null if it's a custom bundle. - - name: id_product_service + - name: id_product data_type: bigint description: | - The identifier of the product service. + The identifier of the product. data_tests: - not_null + - name: product_type + data_type: string + description: | + The type of the product, which can be either "service" or "protection". + data_tests: + - not_null + - accepted_values: + values: + - "SERVICE" + - "PROTECTION" + - name: product_bundle_name data_type: string description: | @@ -3063,17 +3076,38 @@ 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_name + data_type: string + description: | + The name of the product service or protection. data_tests: - not_null - - name: product_service_display_name + - name: product_display_name data_type: string description: | - The display name of the product service. + The display name of the product service or protection. data_tests: - not_null 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 index 9cea854..aa0be74 100644 --- 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 @@ -2,24 +2,24 @@ config( materialized="table", unique_key=[ - "id_user_host", - "id_user_product_bundle", - "service_name", "date", + "id_user_host", + "product_bundle_name", + "service_name", "service_business_type", ], ) }} select -- Unique Key -- - d.date_day as date, + dd.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, + bs.product_bundle_name, + bs.product_display_name as service_name, + bs.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, + 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' @@ -27,66 +27,14 @@ select coalesce( icmas.active_accommodations_per_deal_segmentation, 'UNSET' ) as active_accommodations_per_deal_segmentation -from {{ ref("int_dates") }} as d +from {{ ref("int_kpis__dimension_dates") }} as dd 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 + 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("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 + and dd.date = icmas.date diff --git a/models/intermediate/kpis/schema.yml b/models/intermediate/kpis/schema.yml index 0600575..e85af90 100644 --- a/models/intermediate/kpis/schema.yml +++ b/models/intermediate/kpis/schema.yml @@ -7393,7 +7393,7 @@ models: in this case: - date, - id_user_host, - - id_user_product_bundle, + - product_bundle_name, - service_name, - service_business_type @@ -7419,9 +7419,9 @@ models: data_tests: - not_null - - name: id_user_product_bundle - data_type: bigint - description: Unique identifier of the User Product Bundle. + - name: product_bundle_name + data_type: string + description: Name of the product bundle. data_tests: - not_null @@ -7496,8 +7496,3 @@ models: 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.