From 2e7c85d11bdb85d5551ff491e3617ce791d9231d Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Oriol=20Roqu=C3=A9=20Paniagua?= Date: Thu, 21 Nov 2024 11:30:36 +0000 Subject: [PATCH] Merged PR 3616: Compute weekly new dash created services # Description Changes: * Fixes weekly dates for KPIs. Before, joins were not working (but nothing was really used). * Computes weekly new dash created services and exposes it to reporting # 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. - [ ] 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: #20809 --- ...__agg_weekly_new_dash_created_services.sql | 25 +++ .../kpis/int_kpis__dimension_dates.sql | 6 +- ...etric_weekly_new_dash_created_services.sql | 34 ++++ ...int_kpis__product_new_dash_agg_metrics.sql | 12 ++ models/intermediate/kpis/schema.yml | 179 ++++++++++++++++++ models/reporting/kpis/schema.yml | 1 + 6 files changed, 254 insertions(+), 3 deletions(-) create mode 100644 models/intermediate/kpis/int_kpis__agg_weekly_new_dash_created_services.sql create mode 100644 models/intermediate/kpis/int_kpis__metric_weekly_new_dash_created_services.sql diff --git a/models/intermediate/kpis/int_kpis__agg_weekly_new_dash_created_services.sql b/models/intermediate/kpis/int_kpis__agg_weekly_new_dash_created_services.sql new file mode 100644 index 0000000..eeb5de1 --- /dev/null +++ b/models/intermediate/kpis/int_kpis__agg_weekly_new_dash_created_services.sql @@ -0,0 +1,25 @@ +{% set dimensions = get_kpi_dimensions_per_model("NEW_DASH_CREATED_SERVICES") %} + +{{ + config( + materialized="table", unique_key=["end_date", "dimension", "dimension_value"] + ) +}} + + +{% for dimension in dimensions %} + select + -- Unique Key -- + start_date, + end_date, + {{ dimension.dimension }} as dimension, + {{ dimension.dimension_value }} as dimension_value, + -- Metrics -- + sum(created_services) as created_services, + sum(booking_with_created_services_count) as booking_with_created_services_count + from {{ ref("int_kpis__metric_weekly_new_dash_created_services") }} + group by 1, 2, 3, 4 + {% if not loop.last %} + union all + {% endif %} +{% endfor %} diff --git a/models/intermediate/kpis/int_kpis__dimension_dates.sql b/models/intermediate/kpis/int_kpis__dimension_dates.sql index dc09b61..6b0cb61 100644 --- a/models/intermediate/kpis/int_kpis__dimension_dates.sql +++ b/models/intermediate/kpis/int_kpis__dimension_dates.sql @@ -8,13 +8,13 @@ with select id.year_number as year, id.month_of_year as month, - id.week_of_year as week, + id.iso_week_of_year as week, id.day_of_month as day, id.date_day as date, id.month_start_date as first_day_month, id.month_end_date as last_day_month, - id.week_start_date as first_day_week, - id.week_end_date as last_day_week, + id.iso_week_start_date as first_day_week, + id.iso_week_end_date as last_day_week, now()::date as today from int_dates id ) diff --git a/models/intermediate/kpis/int_kpis__metric_weekly_new_dash_created_services.sql b/models/intermediate/kpis/int_kpis__metric_weekly_new_dash_created_services.sql new file mode 100644 index 0000000..bb8bcaa --- /dev/null +++ b/models/intermediate/kpis/int_kpis__metric_weekly_new_dash_created_services.sql @@ -0,0 +1,34 @@ +{{ + config( + materialized="view", + unique_key=[ + "end_date", + "service_name", + "id_user_host", + "new_dash_version", + "active_accommodations_per_deal_segmentation", + ], + ) +}} + +select + -- Unique Key -- + d.first_day_week as start_date, + d.date as end_date, + cs.service_name, + cs.id_user_host, + cs.active_accommodations_per_deal_segmentation, + -- Dimensions -- + cs.new_dash_version, + cs.id_deal, + cs.is_upgraded_service, + cs.main_billing_country_iso_3_per_deal, + -- Metrics -- + sum(cs.created_services) as created_services, + count(distinct cs.id_booking) as booking_with_created_services_count +from {{ ref("int_kpis__dimension_dates") }} d +left join + {{ ref("int_kpis__metric_daily_new_dash_created_services") }} cs + on date_trunc('week', cs.date)::date = d.first_day_week +where d.is_end_of_week = true and cs.id_deal is not null +group by 1, 2, 3, 4, 5, 6, 7, 8, 9 diff --git a/models/intermediate/kpis/int_kpis__product_new_dash_agg_metrics.sql b/models/intermediate/kpis/int_kpis__product_new_dash_agg_metrics.sql index a2d87b8..f3b0519 100644 --- a/models/intermediate/kpis/int_kpis__product_new_dash_agg_metrics.sql +++ b/models/intermediate/kpis/int_kpis__product_new_dash_agg_metrics.sql @@ -2,6 +2,9 @@ with int_kpis__agg_daily_new_dash_created_services as ( select * from {{ ref("int_kpis__agg_daily_new_dash_created_services") }} ), + int_kpis__agg_weekly_new_dash_created_services as ( + select * from {{ ref("int_kpis__agg_weekly_new_dash_created_services") }} + ), int_kpis__agg_monthly_new_dash_created_services as ( select * from {{ ref("int_kpis__agg_monthly_new_dash_created_services") }} ) @@ -14,6 +17,15 @@ select booking_with_created_services_count from int_kpis__agg_daily_new_dash_created_services union all +select + end_date as date, + 'weekly' as time_granularity, + dimension, + dimension_value, + created_services, + booking_with_created_services_count +from int_kpis__agg_weekly_new_dash_created_services +union all select end_date as date, 'monthly' as time_granularity, diff --git a/models/intermediate/kpis/schema.yml b/models/intermediate/kpis/schema.yml index ca4fe59..57944d4 100644 --- a/models/intermediate/kpis/schema.yml +++ b/models/intermediate/kpis/schema.yml @@ -5497,6 +5497,184 @@ models: apply to the same booking and these do not need to be created in the same time period. Therefore, it's not an additive metric. + - name: int_kpis__metric_weekly_new_dash_created_services + description: | + This model computes the Weekly Created Services 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. + Be aware that any dimension that can change over the weekly period, + such as daily segmentations, are included in the primary key of the + model. + + The unique key corresponds to: + - end_date, + - service_name, + - id_user_host, + - active_accommodations_per_deal_segmentation. + + tests: + - dbt_utils.unique_combination_of_columns: + combination_of_columns: + - end_date + - service_name + - id_user_host + - active_accommodations_per_deal_segmentation + + columns: + - name: start_date + data_type: date + description: | + The start date of the time range considered for the metrics in this record. + tests: + - not_null + + - name: end_date + data_type: date + description: | + The end date of the time range considered for the metrics in this record. + tests: + - not_null + + - name: service_name + data_type: string + description: Name of the created service. + tests: + - not_null + + - name: id_user_host + data_type: string + description: Unique identifier of the user that acts as Host. + tests: + - not_null + + - name: id_deal + data_type: string + description: Unique identifier of an account. + 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. + tests: + - not_null + - accepted_values: + values: + - "YES" + - "NO" + + - 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. + 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. + 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. + tests: + - not_null + + - name: created_services + data_type: bigint + description: | + Count of services created in a given month and per specified dimension. + + - name: booking_with_created_services_count + data_type: bigint + description: | + Count of unique bookings in a given month and per specified dimension. + This is an approximation to booking count since different services can + apply to the same booking and these do not need to be created in the same + time period. Therefore, it's not an additive metric. + + - name: int_kpis__agg_weekly_new_dash_created_services + description: | + This model computes the dimension aggregation for Weekly Created Services. + 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 primary key of this model is end_date, dimension and dimension_value. + + tests: + - dbt_utils.unique_combination_of_columns: + combination_of_columns: + - end_date + - dimension + - dimension_value + + columns: + - name: start_date + data_type: date + description: | + The start date of the time range considered for the metrics in this record. + tests: + - not_null + + - name: end_date + data_type: date + description: | + The end date of the time range considered for the metrics in this record. + tests: + - not_null + + - name: dimension + data_type: string + description: The dimension or granularity of the metrics. + tests: + - assert_dimension_completeness: + metric_column_names: + - created_services + - accepted_values: + values: + - global + - by_number_of_listings + - by_billing_country + - by_deal + - by_new_dash_version + - by_has_upgraded_service + - by_service + - by_host + + - name: dimension_value + data_type: string + description: The value or segment available for the selected dimension. + tests: + - not_null + + - name: created_services + data_type: bigint + description: The weekly created services for a given date range, dimension and value. + + - name: booking_with_created_services_count + data_type: bigint + description: | + The weekly bookings with created services for a given date range, dimension and value. + This is an approximation to booking count since different services can + apply to the same booking and these do not need to be created in the same + time period. Therefore, it's not an additive metric. + - name: int_kpis__agg_monthly_new_dash_created_services description: | This model computes the dimension aggregation for Monthly Created Services. @@ -5650,6 +5828,7 @@ models: - accepted_values: values: - daily + - weekly - monthly - name: dimension diff --git a/models/reporting/kpis/schema.yml b/models/reporting/kpis/schema.yml index a2e1f87..d49f8dd 100644 --- a/models/reporting/kpis/schema.yml +++ b/models/reporting/kpis/schema.yml @@ -234,6 +234,7 @@ models: - accepted_values: values: - Daily + - Weekly - Monthly - name: dimension