diff --git a/dbt_project.yml b/dbt_project.yml index b4e291e..8ec1130 100644 --- a/dbt_project.yml +++ b/dbt_project.yml @@ -65,10 +65,13 @@ vars: # KPIs Start Date. This is the date from which we start calculating KPIs. "kpis_start_date": "'2022-04-01'" + # New Dash MVP Launch Date. This is the first date considered for New Dash in many areas. + "new_dash_mvp_launch_date": "'2024-07-30'" + # New Dash First Invoicing Date. This is the first date considered for New Dash invoicing. "new_dash_first_invoicing_date": "'2024-12-31'" - # The timestamp of when the Guest Squad activated the Feature Flag that + # The timestamp of when the Guest Squad activated the Feature Flag that # activated the big bang refactor of the Guest Products logic. "guest_products_feature_flag_activation_timestamp": "'2025-06-09T10:25:00+00:00'" diff --git a/models/intermediate/core/int_core__new_dash_user_overview.sql b/models/intermediate/core/int_core__new_dash_user_overview.sql index 0fcbfc7..40a4b61 100644 --- a/models/intermediate/core/int_core__new_dash_user_overview.sql +++ b/models/intermediate/core/int_core__new_dash_user_overview.sql @@ -1,3 +1,6 @@ +{% set deal_lifecycle_state_with_data_quality_issues = "99-Not in HubSpot" %} +{% set deal_lifecycle_states_churned = ("05-Churning", "06-Inactive") %} + with int_core__user_product_bundle as ( select * from {{ ref("int_core__user_product_bundle") }} @@ -44,27 +47,6 @@ with atpb_aggregation as ( select upb.id_user_host, - -- To be deleted from here - count( - distinct case - when - atpb.user_product_bundle_name - not in ({{ var("default_service") }}) - then atpb.id_accommodation - else null - end - ) as total_listings_with_product_bundle_with_paid_service, - count( - distinct case - when - atpb.user_product_bundle_name - not in ({{ var("default_service") }}) - and atpb.has_no_end_date = true - then atpb.id_accommodation - else null - end - ) as total_listings_with_active_product_bundle_with_paid_service, - -- To be deleted until here count( distinct case when @@ -90,12 +72,13 @@ with then atpb.id_accommodation else null end - ) as total_active_listings_with_active_product_bundle_with_paid_service + ) as total_active_listings_with_active_upgraded_product_bundle from int_core__user_product_bundle upb - left join + inner join int_core__accommodation_to_product_bundle atpb on upb.id_user_product_bundle = atpb.id_user_product_bundle - inner join int_core__accommodation a on upb.id_user_host = a.id_user_host + inner join + int_core__accommodation a on atpb.id_accommodation = a.id_accommodation where a.is_active = true group by 1 ), @@ -111,7 +94,7 @@ with then btpb.id_booking else null end - ) as total_bookings_with_product_bundle_with_paid_service + ) as total_bookings_with_upgraded_product_bundle from int_core__user_product_bundle upb left join int_core__booking_to_product_bundle btpb @@ -125,6 +108,7 @@ with uh.has_user_moved_from_old_dash, uh.new_dash_version as user_migration_phase, uh.user_in_new_dash_since_date_utc as user_estimated_migration_date_utc, + uh.has_new_dash_default_migration_date, kldd.deal_lifecycle_state, uh.has_active_pms, uh.active_pms_list, @@ -137,68 +121,147 @@ with upb.total_active_user_product_bundles, a.total_listings, a.total_active_listings, - atpb.total_active_listings_with_active_product_bundle, - atpb.total_active_listings_with_active_product_bundle_with_paid_service, - -- To be deleted from here - atpb.total_listings_with_product_bundle_with_paid_service, - atpb.total_listings_with_active_product_bundle_with_paid_service, - -- To be deleted until here + coalesce( + atpb.total_active_listings_with_active_product_bundle, 0 + ) as total_active_listings_with_active_product_bundle, + coalesce( + atpb.total_active_listings_with_active_upgraded_product_bundle, 0 + ) as total_active_listings_with_active_upgraded_product_bundle, btpb.total_bookings_with_product_bundle, - btpb.total_bookings_with_product_bundle_with_paid_service + btpb.total_bookings_with_upgraded_product_bundle from upb_aggregation upb left join accommodation_aggregation a on upb.id_user_host = a.id_user_host left join atpb_aggregation atpb on upb.id_user_host = atpb.id_user_host left join btpb_aggregation btpb on upb.id_user_host = btpb.id_user_host inner join int_core__user_host uh on upb.id_user_host = uh.id_user_host left join int_kpis__lifecycle_daily_deal kldd on uh.id_deal = kldd.id_deal + ), + user_with_boolean_features as ( + select + id_user_host, + id_deal, + has_user_moved_from_old_dash, + user_migration_phase, + user_estimated_migration_date_utc, + has_new_dash_default_migration_date, + deal_lifecycle_state, + has_active_pms, + active_pms_list, + company_name, + first_name, + last_name, + email, + account_currency, + total_user_product_bundles, + total_active_user_product_bundles, + total_listings, + total_active_listings, + total_active_listings_with_active_product_bundle, + total_active_listings_with_active_upgraded_product_bundle, + case + when total_active_listings > 0 then 1 else 0 + end as has_active_listings, + case + when total_active_listings_with_active_product_bundle > 0 then 1 else 0 + end as has_active_listings_with_active_product_bundle_applied, + case + when total_active_listings_with_active_upgraded_product_bundle > 0 + then 1 + else 0 + end as has_active_listings_with_active_upgraded_service_applied, + total_bookings_with_product_bundle, + total_bookings_with_upgraded_product_bundle, + case + when total_bookings_with_product_bundle > 0 then 1 else 0 + end as has_bookings_with_product_bundle, + case + when total_bookings_with_upgraded_product_bundle > 0 then 1 else 0 + end as has_bookings_with_upgraded_product_bundle + from user_aggregation ) select - id_user_host, - id_deal, - has_user_moved_from_old_dash, - user_migration_phase, - user_estimated_migration_date_utc, - deal_lifecycle_state, - has_active_pms, - active_pms_list, - company_name, - first_name, - last_name, - email, - account_currency, - total_user_product_bundles, - total_active_user_product_bundles, - total_listings, - total_active_listings, - total_active_listings_with_active_product_bundle, - total_active_listings_with_active_product_bundle_with_paid_service, - case when total_active_listings > 0 then 1 else 0 end as has_active_listings, + *, case - when total_active_listings_with_active_product_bundle > 0 then 1 else 0 - end as has_active_listings_with_active_product_bundle_applied, - case - when total_active_listings_with_active_product_bundle_with_paid_service > 0 - then 1 - else 0 - end as has_active_listings_with_active_paid_service_applied, - -- To be deleted from here - total_listings_with_product_bundle_with_paid_service, - total_listings_with_active_product_bundle_with_paid_service, - case - when total_listings_with_product_bundle_with_paid_service > 0 then 1 else 0 - end as has_listings_with_paid_service_applied, - case - when total_listings_with_active_product_bundle_with_paid_service > 0 - then 1 - else 0 - end as has_listings_with_active_paid_service_applied, - -- To be deleted until here - total_bookings_with_product_bundle, - total_bookings_with_product_bundle_with_paid_service, - case - when total_bookings_with_product_bundle > 0 then 1 else 0 - end as has_bookings_with_product_bundle, - case - when total_bookings_with_product_bundle_with_paid_service > 0 then 1 else 0 - end as has_bookings_with_product_bundle_with_paid_service -from user_aggregation + -- 99 - DATA QUALITY ISSUES -- + when has_new_dash_default_migration_date + then '99 - Has Data Quality Issues' + when + deal_lifecycle_state = '{{ deal_lifecycle_state_with_data_quality_issues }}' + then '99 - Has Data Quality Issues' + -- 98 - DEAL ALREADY CHURNED -- + when deal_lifecycle_state in {{ deal_lifecycle_states_churned }} + then '98 - Has Churned' + -- 00-08 - CATEGORISE THE USER BASED ON THE LISTING AND BOOKING BEHAVIOR -- + -- No Listings + when total_listings = 0 + then '01 - No Listings' + + -- No Active Listings + when has_active_listings = 0 + then '02 - No Active Listings' + + -- No Bookings - Can only generate Basic Screening Bookings + when + has_active_listings = 1 + and has_bookings_with_product_bundle = 0 + and has_active_listings_with_active_upgraded_service_applied = 0 + then '03 - No Bookings - No Upgraded Program in Listings' + + -- No Bookings - Can generate Upgraded Bookings + when + has_active_listings = 1 + and has_bookings_with_product_bundle = 0 + and has_active_listings_with_active_upgraded_service_applied = 1 + then '04 - No Bookings - Has Upgraded Program in Listings' + + -- Only Basic Screening Bookings - Can only generate Basic Screening + -- Bookings + when + has_active_listings = 1 + and has_bookings_with_product_bundle = 1 + and has_bookings_with_upgraded_product_bundle = 0 + and has_active_listings_with_active_upgraded_service_applied = 0 + then '05 - Only Basic Screening Bookings - No Upgraded Program in Listings' + + -- Only Basic Screening Bookings - Can generate Upgraded Bookings + when + has_active_listings = 1 + and has_bookings_with_product_bundle = 1 + and has_bookings_with_upgraded_product_bundle = 0 + and has_active_listings_with_active_upgraded_service_applied = 1 + then '06 - Only Basic Screening Bookings - Has Upgraded Program in Listings' + + -- Has Upgraded Bookings - No longer can generate Upgraded Bookings + when + has_active_listings = 1 + and has_bookings_with_product_bundle = 1 + and has_bookings_with_upgraded_product_bundle = 1 + and has_active_listings_with_active_upgraded_service_applied = 0 + then '07 - Has Upgraded Bookings - No Upgraded Program in Listings' + + -- Has Upgraded Bookings - Not all listings have Upgraded Program + when + has_active_listings = 1 + and has_bookings_with_product_bundle = 1 + and has_bookings_with_upgraded_product_bundle = 1 + and has_active_listings_with_active_upgraded_service_applied = 1 + and total_active_listings_with_active_upgraded_product_bundle + < total_active_listings + then + '08 - Has Upgraded Bookings - Not all Listings have Upgraded Program Applied' + + -- No Alert - Has Upgraded Bookings - Can generate Upgraded Bookings + -- in all listings + when + has_active_listings = 1 + and has_bookings_with_product_bundle = 1 + and has_bookings_with_upgraded_product_bundle = 1 + and has_active_listings_with_active_upgraded_service_applied = 1 + and total_active_listings_with_active_upgraded_product_bundle + = total_active_listings + then '00 - No Alert' + else 'UNKNOWN' + + end as user_categorisation + +from user_with_boolean_features diff --git a/models/intermediate/core/int_core__new_dash_users.sql b/models/intermediate/core/int_core__new_dash_users.sql index 9db175e..109cfac 100644 --- a/models/intermediate/core/int_core__new_dash_users.sql +++ b/models/intermediate/core/int_core__new_dash_users.sql @@ -1,5 +1,3 @@ -{% set new_dash_mvp_launch_date = "2024-07-30" %} - {{ config(materialized="table") }} with stg_core__claim as (select * from {{ ref("stg_core__claim") }}), @@ -53,12 +51,23 @@ select coalesce( nduwmd.new_dash_move_at_utc, greatest( - u.joined_at_utc, cast(date('{{new_dash_mvp_launch_date}}') as timestamp) + u.joined_at_utc, + cast(date({{ var("new_dash_mvp_launch_date") }}) as timestamp) ) ) as user_in_new_dash_since_timestamp_at_utc, coalesce( date(nduwmd.new_dash_move_at_utc), - greatest(u.joined_date_utc, date('{{new_dash_mvp_launch_date}}')) - ) as user_in_new_dash_since_date_utc + greatest(u.joined_date_utc, date({{ var("new_dash_mvp_launch_date") }})) + ) as user_in_new_dash_since_date_utc, + case + when + coalesce( + date(nduwmd.new_dash_move_at_utc), + greatest(u.joined_date_utc, date({{ var("new_dash_mvp_launch_date") }})) + ) + = date({{ var("new_dash_mvp_launch_date") }}) + then true + else false + end as is_default_migration_date from new_dash_users_with_move_date nduwmd inner join stg_core__user u on nduwmd.id_user_host = u.id_user diff --git a/models/intermediate/core/int_core__user_host.sql b/models/intermediate/core/int_core__user_host.sql index 894b4a9..e94c9bb 100644 --- a/models/intermediate/core/int_core__user_host.sql +++ b/models/intermediate/core/int_core__user_host.sql @@ -84,7 +84,10 @@ select ndu.new_dash_move_at_utc, ndu.new_dash_move_date_utc, ndu.user_in_new_dash_since_timestamp_at_utc, - ndu.user_in_new_dash_since_date_utc + ndu.user_in_new_dash_since_date_utc, + coalesce( + ndu.is_default_migration_date, false + ) as has_new_dash_default_migration_date from int_core__unified_user uu inner join unique_host_user uhu on uu.id_user = uhu.id_user left join int_core__new_dash_users ndu on uu.id_user = ndu.id_user_host diff --git a/models/intermediate/core/schema.yml b/models/intermediate/core/schema.yml index 2cba8c8..f23da30 100644 --- a/models/intermediate/core/schema.yml +++ b/models/intermediate/core/schema.yml @@ -1810,6 +1810,14 @@ models: these users can be considered in New Dash. If the user has moved from Old Dash, it will be the new_dash_move_at_utc. If not, it will correspond to the joined_at_utc. + - name: has_new_dash_default_migration_date + data_type: boolean + description: | + Flag to determine if the user migration date corresponds to + the default migration date. True if the user has the default + migration date, false if the user has a custom migration date + or is not in New Dash. + If true it might represent a data quality issue. - name: int_core__new_dash_users description: | @@ -1862,6 +1870,12 @@ models: these users can be considered in New Dash. If the user has moved from Old Dash, it will be the new_dash_move_at_utc. If not, it will correspond to the joined_at_utc. + - name: is_default_migration_date + data_type: boolean + description: | + Flag to determine if the user migration date corresponds to + the default migration date. It might represent a data quality + issue. - name: int_core__user_product_bundle description: | @@ -2316,6 +2330,13 @@ models: data_tests: - not_null + - name: has_new_dash_default_migration_date + data_type: boolean + description: | + Flag to determine if the user migration date corresponds to + the default migration date. It might represent a data quality + issue. + - name: deal_lifecycle_state data_type: character varying description: | @@ -2402,7 +2423,7 @@ models: description: | Count of active listings that currently have an active product bundle. - - name: total_active_listings_with_active_product_bundle_with_paid_service + - name: total_active_listings_with_active_upgraded_product_bundle data_type: integer description: | Count of active listings that currently have an active paid service @@ -2419,41 +2440,18 @@ models: Integer-based flag version of total_active_listings_with_active_product_bundle. - - name: has_active_listings_with_active_paid_service_applied + - name: has_active_listings_with_active_upgraded_service_applied data_type: integer description: | Integer-based flag version of - total_active_listings_with_active_product_bundle_with_paid_service. + total_active_listings_with_active_upgraded_product_bundle. - # To be deleted from here - - name: total_listings_with_product_bundle_with_paid_service - data_type: integer - description: | - Count of listings that have, or have had, a paid service - product bundle activated. - - - name: total_listings_with_active_product_bundle_with_paid_service - data_type: integer - description: | - Count of listings that currently have an active paid service - product bundle. - - - name: has_listings_with_paid_service_applied - data_type: integer - description: | - Integer-based flag version of total_listings_with_product_bundle_with_paid_service. - - - name: has_listings_with_active_paid_service_applied - data_type: integer - description: | - Integer-based flag version of total_listings_with_active_product_bundle_with_paid_service. - # To be deleted until here - name: total_bookings_with_product_bundle data_type: integer description: | Count of bookings that have a product bundle associated. - - name: total_bookings_with_product_bundle_with_paid_service + - name: total_bookings_with_upgraded_product_bundle data_type: integer description: | Count of bookings that have a product bundle associated that contain @@ -2464,10 +2462,44 @@ models: description: | Integer-based flag version of total_bookings_with_product_bundle. - - name: has_bookings_with_product_bundle_with_paid_service + - name: has_bookings_with_upgraded_product_bundle data_type: integer description: | - Integer-based flag version of total_bookings_with_product_bundle_with_paid_service. + Integer-based flag version of total_bookings_with_upgraded_product_bundle. + + - name: user_categorisation + data_type: string + description: | + Alert-based categorisation of the user based on the activity or lack of it. + The possible values are: + - "00 - No Alert" + - "01 - No Listings" + - "02 - No Active Listings" + - "03 - No Bookings - No Upgraded Program in Listings" + - "04 - No Bookings - Has Upgraded Program in Listings" + - "05 - Only Basic Screening Bookings - No Upgraded Program in Listings" + - "06 - Only Basic Screening Bookings - Has Upgraded Program in Listings" + - "07 - Has Upgraded Bookings - No Upgraded Program in Listings" + - "08 - Has Upgraded Bookings - Not all Listings have Upgraded Program Applied" + - "98 - Has Churned" + - "99 - Has Data Quality Issues" + It cannot be null. + + data_tests: + - not_null + - accepted_values: + values: + - "00 - No Alert" + - "01 - No Listings" + - "02 - No Active Listings" + - "03 - No Bookings - No Upgraded Program in Listings" + - "04 - No Bookings - Has Upgraded Program in Listings" + - "05 - Only Basic Screening Bookings - No Upgraded Program in Listings" + - "06 - Only Basic Screening Bookings - Has Upgraded Program in Listings" + - "07 - Has Upgraded Bookings - No Upgraded Program in Listings" + - "08 - Has Upgraded Bookings - Not all Listings have Upgraded Program Applied" + - "98 - Has Churned" + - "99 - Has Data Quality Issues" - name: int_core__invoicing_price_plans_per_month description: | diff --git a/models/reporting/core/core__new_dash_user_overview.sql b/models/reporting/core/core__new_dash_user_overview.sql index 242a782..2b8f9bf 100644 --- a/models/reporting/core/core__new_dash_user_overview.sql +++ b/models/reporting/core/core__new_dash_user_overview.sql @@ -22,26 +22,18 @@ select total_active_listings as total_active_listings, total_active_listings_with_active_product_bundle as total_active_listings_with_active_product_bundle, - total_active_listings_with_active_product_bundle_with_paid_service + total_active_listings_with_active_upgraded_product_bundle as total_active_listings_with_active_product_bundle_with_paid_service, has_active_listings as has_active_listings, has_active_listings_with_active_product_bundle_applied as has_active_listings_with_active_product_bundle_applied, - has_active_listings_with_active_paid_service_applied + has_active_listings_with_active_upgraded_service_applied as has_active_listings_with_active_paid_service_applied, - -- To be deleted from here - total_listings_with_product_bundle_with_paid_service - as total_listings_with_product_bundle_with_paid_service, - total_listings_with_active_product_bundle_with_paid_service - as total_listings_with_active_product_bundle_with_paid_service, - has_listings_with_paid_service_applied as has_listings_with_paid_service_applied, - has_listings_with_active_paid_service_applied - as has_listings_with_active_paid_service_applied, - -- To be deleted until here total_bookings_with_product_bundle as total_bookings_with_product_bundle, - total_bookings_with_product_bundle_with_paid_service + total_bookings_with_upgraded_product_bundle as total_bookings_with_product_bundle_with_paid_service, has_bookings_with_product_bundle as has_bookings_with_product_bundle, - has_bookings_with_product_bundle_with_paid_service - as has_bookings_with_product_bundle_with_paid_service + has_bookings_with_upgraded_product_bundle + as has_bookings_with_product_bundle_with_paid_service, + user_categorisation as user_categorisation from int_core__new_dash_user_overview diff --git a/models/reporting/core/schema.yml b/models/reporting/core/schema.yml index 40e4e37..b102b13 100644 --- a/models/reporting/core/schema.yml +++ b/models/reporting/core/schema.yml @@ -1044,17 +1044,31 @@ models: description: | Count of product bundles that this user has or has had. It contains both active and historic cases. + data_tests: + - not_null + - dbt_expectations.expect_column_values_to_be_between: + min_value: 0 - name: total_active_user_product_bundles data_type: integer description: | Count of product bundles that this user currently has. It contains only currently active cases. + data_tests: + - not_null + - dbt_expectations.expect_column_values_to_be_between: + min_value: 0 + max_value: total_user_product_bundles + strictly: false - name: total_listings data_type: integer description: | Count of listings that the user owns or has owned. + data_tests: + - not_null + - dbt_expectations.expect_column_values_to_be_between: + min_value: 0 - name: total_active_listings data_type: integer @@ -1063,78 +1077,129 @@ models: It contains only those that can accept bookings (hard activation - not to be confused with activity-based segmentation). + data_tests: + - not_null + - dbt_expectations.expect_column_values_to_be_between: + min_value: 0 + max_value: total_listings + strictly: false - name: total_active_listings_with_active_product_bundle data_type: integer description: | Count of active listings that currently have an active product bundle. + data_tests: + - not_null + - dbt_expectations.expect_column_values_to_be_between: + min_value: 0 + max_value: total_active_listings + strictly: false - - name: total_active_listings_with_active_product_bundle_with_paid_service + - name: total_active_listings_with_active_product_bundle_with_paid_serv data_type: integer description: | Count of active listings that currently have an active paid service product bundle. + Note the name of this column is truncated to fit the maximum length + of column characters in Postgres. + data_tests: + - not_null + - dbt_expectations.expect_column_values_to_be_between: + min_value: 0 + max_value: total_active_listings + strictly: false - name: has_active_listings data_type: integer description: | Integer-based flag version of total_active_listings. + data_tests: + - not_null - name: has_active_listings_with_active_product_bundle_applied data_type: integer description: | Integer-based flag version of total_active_listings_with_active_product_bundle. + data_tests: + - not_null - name: has_active_listings_with_active_paid_service_applied data_type: integer description: | Integer-based flag version of total_active_listings_with_active_product_bundle_with_paid_service. + data_tests: + - not_null - # To be deleted from here - - name: total_listings_with_product_bundle_with_paid_service - data_type: integer - description: | - Count of listings that have, or have had, a paid service - product bundle activated. - - - name: total_listings_with_active_product_bundle_with_paid_service - data_type: integer - description: | - Count of listings that currently have an active paid service - product bundle. - - - name: has_listings_with_paid_service_applied - data_type: integer - description: | - Integer-based flag version of total_listings_with_product_bundle_with_paid_service. - - - name: has_listings_with_active_paid_service_applied - data_type: integer - description: | - Integer-based flag version of total_listings_with_active_product_bundle_with_paid_service. - # To be deleted until here - name: total_bookings_with_product_bundle data_type: integer description: | Count of bookings that have a product bundle associated. + data_tests: + - not_null + - dbt_expectations.expect_column_values_to_be_between: + min_value: 0 - name: total_bookings_with_product_bundle_with_paid_service data_type: integer description: | Count of bookings that have a product bundle associated that contain a paid service. + data_tests: + - not_null + - dbt_expectations.expect_column_values_to_be_between: + min_value: 0 + max_value: total_bookings_with_product_bundle + strictly: false - name: has_bookings_with_product_bundle data_type: integer description: | Integer-based flag version of total_bookings_with_product_bundle. + data_tests: + - not_null - name: has_bookings_with_product_bundle_with_paid_service data_type: integer description: | Integer-based flag version of total_bookings_with_product_bundle_with_paid_service. + data_tests: + - not_null + + - name: user_categorisation + data_type: string + description: | + Alert-based categorisation of the user based on the activity or lack of it. + The possible values are: + - "00 - No Alert" + - "01 - No Listings" + - "02 - No Active Listings" + - "03 - No Bookings - No Upgraded Program in Listings" + - "04 - No Bookings - Has Upgraded Program in Listings" + - "05 - Only Basic Screening Bookings - No Upgraded Program in Listings" + - "06 - Only Basic Screening Bookings - Has Upgraded Program in Listings" + - "07 - Has Upgraded Bookings - No Upgraded Program in Listings" + - "08 - Has Upgraded Bookings - Not all Listings have Upgraded Program Applied" + - "98 - Has Churned" + - "99 - Has Data Quality Issues" + It cannot be null. + + data_tests: + - not_null + - accepted_values: + values: + - "00 - No Alert" + - "01 - No Listings" + - "02 - No Active Listings" + - "03 - No Bookings - No Upgraded Program in Listings" + - "04 - No Bookings - Has Upgraded Program in Listings" + - "05 - Only Basic Screening Bookings - No Upgraded Program in Listings" + - "06 - Only Basic Screening Bookings - Has Upgraded Program in Listings" + - "07 - Has Upgraded Bookings - No Upgraded Program in Listings" + - "08 - Has Upgraded Bookings - Not all Listings have Upgraded Program Applied" + - "98 - Has Churned" + - "99 - Has Data Quality Issues" - name: core__accommodations_activity description: |