From 3d9c7cf5714ebeaf73f382fe22c5790a96cd5d5b Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Oriol=20Roqu=C3=A9=20Paniagua?= Date: Mon, 26 Aug 2024 09:18:56 +0000 Subject: [PATCH] Merged PR 2636: First version of User Product Bundle # Description Working version of User Product Bundle in intermediate. I tried to be quite explicit in the documentation of the model and the choices made (both in the code itself and in the schema). There's some opinionated choices so feel free to challenge them. There's a small change on the user_migration model, in which I didn't properly set a field into a date. Note that there's some schema comments pending from Lou's validation. Up to you if we prefer to wait until resolved or we move forward - to me, it's not blocking. # 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: #19570 --- .../core/int_core__user_migration.sql | 2 +- .../core/int_core__user_product_bundle.sql | 46 ++++++ models/intermediate/core/schema.yaml | 155 +++++++++++++++++- 3 files changed, 201 insertions(+), 2 deletions(-) create mode 100644 models/intermediate/core/int_core__user_product_bundle.sql diff --git a/models/intermediate/core/int_core__user_migration.sql b/models/intermediate/core/int_core__user_migration.sql index 204962e..ee14014 100644 --- a/models/intermediate/core/int_core__user_migration.sql +++ b/models/intermediate/core/int_core__user_migration.sql @@ -16,7 +16,7 @@ with case {% for phase in migration_phases %} when upper(claim_type) = '{{ phase.claim_type }}' - then '{{ phase.deployment_date }}' + then date('{{ phase.deployment_date }}') {% endfor %} else null end as lower_limit_migration_date_utc diff --git a/models/intermediate/core/int_core__user_product_bundle.sql b/models/intermediate/core/int_core__user_product_bundle.sql new file mode 100644 index 0000000..2f92056 --- /dev/null +++ b/models/intermediate/core/int_core__user_product_bundle.sql @@ -0,0 +1,46 @@ +{{ config(materialized="table", unique_key="id_user_product_bundle") }} +with + stg_core__user_product_bundle as (select * from {{ ref("stg_core__user_product_bundle") }}), + int_core__user_host as (select * from {{ ref("int_core__user_host") }} + ) + +select + upb.id_user_product_bundle, + upb.id_user as id_user_host, + upb.id_product_bundle, + upb.id_protection_plan, + upb.product_bundle_name, + upb.product_bundle_display_name, + upb.display_on_front_end, + upb.chosen_product_services, + upb.starts_at_utc as original_starts_at_utc, + upb.ends_at_utc as original_ends_at_utc, + /* + The following is to ensure that we cap the reporting to the + dates in which these product bundles could have been active. + For analysis and reporting purposes, it is encouraged to use + the effective fields (start_date and end_date) rather than the + backend ones (named as original_starts_at and original_ends_at). + */ + greatest(date(upb.starts_at_utc), uh.lower_limit_migration_date_utc) as effective_start_date_utc, + case + when upb.has_no_end_date then null + else greatest(date(upb.ends_at_utc), uh.lower_limit_migration_date_utc) + end as effective_end_date_utc, + upb.has_no_end_date, + upb.created_at_utc, + upb.created_date_utc, + upb.updated_at_utc, + upb.updated_date_utc, + upb.dwh_extracted_at +from stg_core__user_product_bundle upb +/* +There are many not migrated users that have product bundles. +Since users are not migrated, these bundles cannot be active. +In order to avoid potential upstream problems, it is enforced + that product bundles need to be from users that have been + already migrated. +*/ +inner join int_core__user_host uh +on upb.id_user = uh.id_user_host +and uh.is_user_migrated = True diff --git a/models/intermediate/core/schema.yaml b/models/intermediate/core/schema.yaml index 972f8d4..c77c05a 100644 --- a/models/intermediate/core/schema.yaml +++ b/models/intermediate/core/schema.yaml @@ -2267,4 +2267,157 @@ models: - name: dwh_extracted_at_utc data_type: timestamp with time zone - description: "Date and time at which the record was extracted from the backend into the DWH." \ No newline at end of file + description: "Date and time at which the record was extracted from the backend into the DWH." + + - name: int_core__user_product_bundle + description: | + This model contains the relationship of a User has a Product Bundle. It contains + both the active Product Bundles as well as inactive, past ones, for each user, + with the dates in which it was active. If a Product Bundle is active, then the + end date is null. + + In the initiatives of "new pricing" and "new dashboard" (2024), a User that + has been migrated into this setup can have one or many Product Bundles active. + This table won't display Product Bundles from users that have not been migrated. + + A Product Bundle is a bundle of one or many Product Services. In other words, + different combinations of Product Services (Basic Screening, Id Verification, + Screening Plus, Basic Damage Deposit, Damage Deposit Plus, Waiver Pro, etc) + ) would result into different Product Bundles. + + For instance, for the New Dashboard MVP, we only have 2 Product Bundles: + - Basic Screening: only contains one service, which is Basic Screening + - Basic Program: contains 2 services, which are Basic Screening and + Waiver Pro. + + Important: + A User having an active Product Bundle does NOT mean that the bundle is in use. + In order to be in use, the Product Bundle needs to be applied to a Listing. + Thus, the relationship in this table only shows, from user point of view, what + Product Bundles she/he can apply into a Listing. + + tests: + - dbt_utils.unique_combination_of_columns: + combination_of_columns: + - id_user_host + - id_product_bundle + - original_starts_at_utc + + columns: + - name: id_user_product_bundle + data_type: bigint + description: | + The identifier unique identifier of this table. + tests: + - not_null + - unique + + - name: id_user_host + data_type: string + description: | + The identifier of the User. Can be duplicated if it has many Product Bundles. + tests: + - not_null + + - name: id_product_bundle + data_type: int + description: | + The identifier of the Product Bundle associated to the user. The same Product + Bundle can be applied into many users. + tests: + - not_null + + - name: id_protection_plan + data_type: int + description: | + The identifier of the Protection Plan. There's a 1 to 1 relationship between + a Product Bundle and a Protection Plan. Pending confirmation of Lou D. + + - name: product_bundle_name + data_type: string + description: | + The CamelCase name of the Product Bundle. + + - name: product_bundle_display_name + data_type: string + description: | + The name of the Product Bundle, better fit for visualisations. + + - name: display_on_front_end + data_type: boolean + description: | + Flag that accounts for the capacity of a Host being able to modify the Product Bundle. + Pending confirmation of Lou D. + + - name: chosen_product_services + data_type: int + description: | + Identifier of the combination of Services that apply to a Product Bundle. In essence, + the sum of Service Ids applied return the number displayed in this column. For example, + a chosen_product_services = 257 means it has the services 1 + 256, which are the + Basic Screening and the Waiver Pro. + + - name: original_starts_at_utc + data_type: timestamp + description: | + Timestamp of when this User has Product Bundle was active for the first time, according to + the Backend. + Keep in mind that this timestamp can be before the migration of the user, thus + effective_start_date_utc might be better for reporting and analysis purposes. + tests: + - not_null + + - name: original_ends_at_utc + data_type: timestamp + description: | + Timestamp of when this User has Product Bundle was active for the last time, according to + the Backend. If null it means that it's currently active. + Keep in mind that this timestamp can be before the migration of the user, thus + effective_end_date_utc might be better for reporting and analysis purposes. + + - name: effective_start_date_utc + data_type: date + description: | + Effective date of when this User has Product Bundle was active for the first time. + It takes into account the fact that a User needs to be migrated in order for + the Product Bundle to be active. In case of doubt, use this date. + tests: + - not_null + + - name: effective_end_date_utc + data_type: date + description: | + Effective date of when this User has Product Bundle was active for the last time. + If null it means that it's currently active. + It takes into account the fact that a User needs to be migrated in order for + the Product Bundle to be active. In case of doubt, use this date. + + - name: has_no_end_date + data_type: boolean + description: | + Flag to determine if the end date is filled or not. + + - name: created_at_utc + data_type: timestamp + description: | + Timestamp of when this User has Product Bundle was created in the Backend. + + - name: created_date_utc + data_type: date + description: | + Date of when this User has Product Bundle was created in the Backend. + + - name: updated_at_utc + data_type: timestamp + description: | + Timestamp of when this User has Product Bundle was last updated in the Backend. + + - name: updated_date_utc + data_type: date + description: | + Date of when this User has Product Bundle was last updated in the Backend. + + - name: dwh_extracted_at + data_type: timestamp + description: | + Timestamp of when this row was ingested from the Backend to the DWH.