From 42d70f72d5cfd2e0d693bb047c8b24dfc0810fb9 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Oriol=20Roqu=C3=A9=20Paniagua?= Date: Tue, 26 Nov 2024 14:19:41 +0000 Subject: [PATCH] Merged PR 3667: Creates Chargeable metrics for New Dash KPIs # Description Creates the models for KPIs for New Dash - Chargeable metrics. In essence, computes 4 metrics: - Chargeable Services - Chargeable Amount (in GBP) - Chargeable Bookings (unique over a time period and dimension, not additive) - Chargeable Listings (unique over a time period and dimension, not additive) This is done by creating: - A Weekly Metric and Monthly Metric model. Here we keep the granularity of id_booking / id_accommodation to be able to compute the uniqueness. - A Daily, Weekly and Monthly Aggregated models. Same as usual. - Integrates everything to the existing model for Product New Dash Agg Metrics - Exposes everything into reporting NB: I removed on "by_host" in Created Services - I forgot to clear it out. # 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: #20809 --- macros/business_kpis_configuration.sql | 19 + ...agg_daily_new_dash_chargeable_services.sql | 26 + ...g_monthly_new_dash_chargeable_services.sql | 27 + ...gg_weekly_new_dash_chargeable_services.sql | 27 + ...c_monthly_new_dash_chargeable_services.sql | 35 ++ ...ic_weekly_new_dash_chargeable_services.sql | 36 ++ ...int_kpis__product_new_dash_agg_metrics.sql | 84 ++- models/intermediate/kpis/schema.yml | 536 +++++++++++++++++- .../kpis__product_new_dash_agg_metrics.sql | 6 +- models/reporting/kpis/schema.yml | 36 +- 10 files changed, 808 insertions(+), 24 deletions(-) create mode 100644 models/intermediate/kpis/int_kpis__agg_daily_new_dash_chargeable_services.sql create mode 100644 models/intermediate/kpis/int_kpis__agg_monthly_new_dash_chargeable_services.sql create mode 100644 models/intermediate/kpis/int_kpis__agg_weekly_new_dash_chargeable_services.sql create mode 100644 models/intermediate/kpis/int_kpis__metric_monthly_new_dash_chargeable_services.sql create mode 100644 models/intermediate/kpis/int_kpis__metric_weekly_new_dash_chargeable_services.sql diff --git a/macros/business_kpis_configuration.sql b/macros/business_kpis_configuration.sql index e05a6ed..a881580 100644 --- a/macros/business_kpis_configuration.sql +++ b/macros/business_kpis_configuration.sql @@ -85,6 +85,16 @@ Please note that strings should be encoded with " ' your_value_here ' ", ) }} {% endmacro %} +{% macro dim_pricing_business_type() %} + {{ + return( + { + "dimension": "'by_service_business_type'", + "dimension_value": "service_business_type", + } + ) + }} +{% endmacro %} {% macro dim_new_dash_version() %} {{ return( @@ -146,6 +156,15 @@ Provides a general assignement for the Dimensions available for each KPI ] %} {% endif %} + {% if entity_name == "NEW_DASH_CHARGEABLE_SERVICES" %} + {% set additional_dimensions = additional_dimensions + [ + dim_has_upgraded_service(), + dim_new_dash_version(), + dim_pricing_service(), + dim_pricing_business_type(), + ] %} + {% endif %} + {# Combine base dimensions with additional dimensions for the specific model #} {% set dimensions = base_dimensions + additional_dimensions %} {{ return(dimensions) }} diff --git a/models/intermediate/kpis/int_kpis__agg_daily_new_dash_chargeable_services.sql b/models/intermediate/kpis/int_kpis__agg_daily_new_dash_chargeable_services.sql new file mode 100644 index 0000000..95b47e4 --- /dev/null +++ b/models/intermediate/kpis/int_kpis__agg_daily_new_dash_chargeable_services.sql @@ -0,0 +1,26 @@ +{% set dimensions = get_kpi_dimensions_per_model("NEW_DASH_CREATED_SERVICES") %} + +{{ config(materialized="table", unique_key=["date", "dimension", "dimension_value"]) }} + + +{% for dimension in dimensions %} + select + -- Unique Key -- + d.date, + {{ dimension.dimension }} as dimension, + {{ dimension.dimension_value }} as dimension_value, + -- Metrics -- + sum(chargeable_services) as total_chargeable_services, + sum(service_total_price_in_gbp) as total_chargeable_amount_in_gbp, + count(distinct id_booking) as unique_chargeable_bookings, + count(distinct id_accommodation) as unique_chargeable_listings + from {{ ref("int_kpis__dimension_dates") }} d + left join + {{ ref("int_kpis__metric_daily_new_dash_chargeable_services") }} as cs + on d.date = cs.date + where cs.id_deal is not null + group by 1, 2, 3 + {% if not loop.last %} + union all + {% endif %} +{% endfor %} diff --git a/models/intermediate/kpis/int_kpis__agg_monthly_new_dash_chargeable_services.sql b/models/intermediate/kpis/int_kpis__agg_monthly_new_dash_chargeable_services.sql new file mode 100644 index 0000000..f28c863 --- /dev/null +++ b/models/intermediate/kpis/int_kpis__agg_monthly_new_dash_chargeable_services.sql @@ -0,0 +1,27 @@ +{% set dimensions = get_kpi_dimensions_per_model("NEW_DASH_CHARGEABLE_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(chargeable_services) as total_chargeable_services, + sum(service_total_price_in_gbp) as total_chargeable_amount_in_gbp, + count(distinct id_booking) as unique_chargeable_bookings, + count(distinct id_accommodation) as unique_chargeable_listings + from {{ ref("int_kpis__metric_monthly_new_dash_chargeable_services") }} + group by 1, 2, 3, 4 + {% if not loop.last %} + union all + {% endif %} +{% endfor %} diff --git a/models/intermediate/kpis/int_kpis__agg_weekly_new_dash_chargeable_services.sql b/models/intermediate/kpis/int_kpis__agg_weekly_new_dash_chargeable_services.sql new file mode 100644 index 0000000..243a6be --- /dev/null +++ b/models/intermediate/kpis/int_kpis__agg_weekly_new_dash_chargeable_services.sql @@ -0,0 +1,27 @@ +{% set dimensions = get_kpi_dimensions_per_model("NEW_DASH_CHARGEABLE_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(chargeable_services) as total_chargeable_services, + sum(service_total_price_in_gbp) as total_chargeable_amount_in_gbp, + count(distinct id_booking) as unique_chargeable_bookings, + count(distinct id_accommodation) as unique_chargeable_listings + from {{ ref("int_kpis__metric_weekly_new_dash_chargeable_services") }} + group by 1, 2, 3, 4 + {% if not loop.last %} + union all + {% endif %} +{% endfor %} diff --git a/models/intermediate/kpis/int_kpis__metric_monthly_new_dash_chargeable_services.sql b/models/intermediate/kpis/int_kpis__metric_monthly_new_dash_chargeable_services.sql new file mode 100644 index 0000000..60caf3b --- /dev/null +++ b/models/intermediate/kpis/int_kpis__metric_monthly_new_dash_chargeable_services.sql @@ -0,0 +1,35 @@ +{{ + config( + materialized="view", + unique_key=[ + "end_date", + "service_name", + "id_booking", + "active_accommodations_per_deal_segmentation", + ], + ) +}} + +select + -- Unique Key -- + d.first_day_week as start_date, + d.date as end_date, + cs.id_booking, + cs.service_name, + cs.active_accommodations_per_deal_segmentation, + -- Dimensions -- + cs.id_deal, + cs.id_accommodation, + cs.service_business_type, + cs.new_dash_version, + cs.is_upgraded_service, + cs.main_billing_country_iso_3_per_deal, + -- Metrics -- + sum(cs.chargeable_services) as chargeable_services, + sum(cs.service_total_price_in_gbp) as service_total_price_in_gbp +from {{ ref("int_kpis__dimension_dates") }} d +left join + {{ ref("int_kpis__metric_daily_new_dash_chargeable_services") }} cs + on date_trunc('month', cs.date)::date = d.first_day_month +where d.is_end_of_month = true and cs.id_deal is not null +group by 1, 2, 3, 4, 5, 6, 7, 8, 9, 10, 11 diff --git a/models/intermediate/kpis/int_kpis__metric_weekly_new_dash_chargeable_services.sql b/models/intermediate/kpis/int_kpis__metric_weekly_new_dash_chargeable_services.sql new file mode 100644 index 0000000..dc34dea --- /dev/null +++ b/models/intermediate/kpis/int_kpis__metric_weekly_new_dash_chargeable_services.sql @@ -0,0 +1,36 @@ +{{ + config( + materialized="view", + unique_key=[ + "end_date", + "id_booking", + "service_name", + "active_accommodations_per_deal_segmentation", + ], + ) +}} + + +select + -- Unique Key -- + d.first_day_week as start_date, + d.date as end_date, + cs.id_booking, + cs.service_name, + cs.active_accommodations_per_deal_segmentation, + -- Dimensions -- + cs.id_deal, + cs.id_accommodation, + cs.service_business_type, + cs.new_dash_version, + cs.is_upgraded_service, + cs.main_billing_country_iso_3_per_deal, + -- Metrics -- + sum(cs.chargeable_services) as chargeable_services, + sum(cs.service_total_price_in_gbp) as service_total_price_in_gbp +from {{ ref("int_kpis__dimension_dates") }} d +left join + {{ ref("int_kpis__metric_daily_new_dash_chargeable_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, 10, 11 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 f3b0519..dc87da1 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 @@ -7,30 +7,78 @@ with ), int_kpis__agg_monthly_new_dash_created_services as ( select * from {{ ref("int_kpis__agg_monthly_new_dash_created_services") }} + ), + int_kpis__agg_daily_new_dash_chargeable_services as ( + select * from {{ ref("int_kpis__agg_daily_new_dash_chargeable_services") }} + ), + int_kpis__agg_weekly_new_dash_chargeable_services as ( + select * from {{ ref("int_kpis__agg_weekly_new_dash_chargeable_services") }} + ), + int_kpis__agg_monthly_new_dash_chargeable_services as ( + select * from {{ ref("int_kpis__agg_monthly_new_dash_chargeable_services") }} ) select - date, + coalesce(created.date, chargeable.date) as date, 'daily' as time_granularity, - dimension, - dimension_value, - created_services, - booking_with_created_services_count -from int_kpis__agg_daily_new_dash_created_services + coalesce(created.dimension, chargeable.dimension) as dimension, + coalesce(created.dimension_value, chargeable.dimension_value) as dimension_value, + coalesce(created.created_services, 0) as created_services, + coalesce( + created.booking_with_created_services_count, 0 + ) as booking_with_created_services_count, + coalesce(chargeable.total_chargeable_services, 0) as total_chargeable_services, + coalesce( + chargeable.total_chargeable_amount_in_gbp, 0 + ) as total_chargeable_amount_in_gbp, + coalesce(chargeable.unique_chargeable_bookings, 0) as unique_chargeable_bookings, + coalesce(chargeable.unique_chargeable_listings, 0) as unique_chargeable_listings +from int_kpis__agg_daily_new_dash_created_services created +full outer join + int_kpis__agg_daily_new_dash_chargeable_services chargeable + on created.date = chargeable.date + and created.dimension = chargeable.dimension + and created.dimension_value = chargeable.dimension_value union all select - end_date as date, + coalesce(created.end_date, chargeable.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 + coalesce(created.dimension, chargeable.dimension) as dimension, + coalesce(created.dimension_value, chargeable.dimension_value) as dimension_value, + coalesce(created.created_services, 0) as created_services, + coalesce( + created.booking_with_created_services_count, 0 + ) as booking_with_created_services_count, + coalesce(chargeable.total_chargeable_services, 0) as total_chargeable_services, + coalesce( + chargeable.total_chargeable_amount_in_gbp, 0 + ) as total_chargeable_amount_in_gbp, + coalesce(chargeable.unique_chargeable_bookings, 0) as unique_chargeable_bookings, + coalesce(chargeable.unique_chargeable_listings, 0) as unique_chargeable_listings +from int_kpis__agg_weekly_new_dash_created_services created +full outer join + int_kpis__agg_weekly_new_dash_chargeable_services chargeable + on created.end_date = chargeable.end_date + and created.dimension = chargeable.dimension + and created.dimension_value = chargeable.dimension_value union all select - end_date as date, + coalesce(created.end_date, chargeable.end_date) as date, 'monthly' as time_granularity, - dimension, - dimension_value, - created_services, - booking_with_created_services_count -from int_kpis__agg_monthly_new_dash_created_services + coalesce(created.dimension, chargeable.dimension) as dimension, + coalesce(created.dimension_value, chargeable.dimension_value) as dimension_value, + coalesce(created.created_services, 0) as created_services, + coalesce( + created.booking_with_created_services_count, 0 + ) as booking_with_created_services_count, + coalesce(chargeable.total_chargeable_services, 0) as total_chargeable_services, + coalesce( + chargeable.total_chargeable_amount_in_gbp, 0 + ) as total_chargeable_amount_in_gbp, + coalesce(chargeable.unique_chargeable_bookings, 0) as unique_chargeable_bookings, + coalesce(chargeable.unique_chargeable_listings, 0) as unique_chargeable_listings +from int_kpis__agg_monthly_new_dash_created_services created +full outer join + int_kpis__agg_monthly_new_dash_chargeable_services chargeable + on created.end_date = chargeable.end_date + and created.dimension = chargeable.dimension + and created.dimension_value = chargeable.dimension_value diff --git a/models/intermediate/kpis/schema.yml b/models/intermediate/kpis/schema.yml index 3017f6d..680031a 100644 --- a/models/intermediate/kpis/schema.yml +++ b/models/intermediate/kpis/schema.yml @@ -5718,7 +5718,6 @@ models: - by_new_dash_version - by_has_upgraded_service - by_service - - by_host - name: dimension_value data_type: string @@ -5841,6 +5840,7 @@ models: - by_new_dash_version - by_has_upgraded_service - by_service + - by_service_business_type - name: dimension_value data_type: string @@ -5850,16 +5850,47 @@ models: - name: created_services data_type: bigint - description: The daily created services for a given date, dimension and value. + description: | + The created services for a given time granularity, date or dates range, + dimension and value. - name: booking_with_created_services_count data_type: bigint description: | - The daily bookings with created services for a given date, dimension and value. + The bookings with created services for a given time granularity, date or + dates 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: total_chargeable_services + data_type: integer + description: | + The total chargeable services for a given time granularity, date or + dates range, dimension and value. + + - name: total_chargeable_amount_in_gbp + data_type: decimal + description: | + The total daily chargeable amount for a given time granularity, date or + dates range, dimension and value, in GBP. + + - name: unique_chargeable_bookings + data_type: integer + description: | + The unique daily chargeable bookings for a given time granularity, date or + dates range, dimension and value. + This metric is not additive, and its value can vary depending on the time + period considered. + + - name: unique_chargeable_listings + data_type: integer + description: | + The unique daily chargeable accommodations, or listings, for a given time + granularity, date or dates range, dimension and value. + This metric is not additive, and its value can vary depending on the time + period considered. + - name: int_kpis__metric_daily_new_dash_chargeable_services description: | This model computes the Daily Chargeable Services at the deepest granularity. @@ -5978,3 +6009,502 @@ models: description: | Sum of the total prices of the chargeable services in a given date and per specified dimension, in GBP. + + - name: int_kpis__metric_monthly_new_dash_chargeable_services + description: | + This model computes the Monthly Chargeable 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 chargeable after the user has moved to New Dash. + Be aware that any dimension that can change over the monthly period, + such as daily segmentations, are included in the primary key of the + model. + + The unique key corresponds to: + - end_date, + - service_name, + - id_booking, + - active_accommodations_per_deal_segmentation. + + tests: + - dbt_utils.unique_combination_of_columns: + combination_of_columns: + - end_date + - id_booking + - service_name + - 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: id_booking + data_type: bigint + description: Unique identifier of the Booking. + tests: + - not_null + + - name: service_name + data_type: string + description: Name of the chargeable service. + tests: + - not_null + + - name: id_deal + data_type: string + description: Unique identifier of an account. + tests: + - not_null + + - name: id_accommodation + data_type: bigint + description: Unique identifier of an accommodation, or listing. + 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: service_business_type + data_type: string + description: | + Identifies the service type (Screening, Deposit Management, Protection) + according to New Pricing documentation. + Cannot be null. + tests: + - not_null + - accepted_values: + values: + - "SCREENING" + - "PROTECTION" + - "DEPOSIT_MANAGEMENT" + - "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. + 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: chargeable_services + data_type: integer + description: | + Count of monthly chargeable services in a given date and per specified + dimension. + + - name: service_total_price_in_gbp + data_type: decimal + description: | + Sum of the total prices of the chargeable services in a given time range + and per specified dimension, in GBP. + + - name: int_kpis__metric_weekly_new_dash_chargeable_services + description: | + This model computes the Weekly Chargeable 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 chargeable after the user has moved to New Dash. + Be aware that any dimension that can change over the monthly period, + such as daily segmentations, are included in the primary key of the + model. + + The unique key corresponds to: + - end_date, + - service_name, + - id_booking, + - active_accommodations_per_deal_segmentation. + + tests: + - dbt_utils.unique_combination_of_columns: + combination_of_columns: + - end_date + - id_booking + - service_name + - 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: id_booking + data_type: bigint + description: Unique identifier of the Booking. + tests: + - not_null + + - name: service_name + data_type: string + description: Name of the chargeable service. + tests: + - not_null + + - name: id_deal + data_type: string + description: Unique identifier of an account. + tests: + - not_null + + - name: id_accommodation + data_type: bigint + description: Unique identifier of an accommodation, or listing. + 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: service_business_type + data_type: string + description: | + Identifies the service type (Screening, Deposit Management, Protection) + according to New Pricing documentation. + Cannot be null. + tests: + - not_null + - accepted_values: + values: + - "SCREENING" + - "PROTECTION" + - "DEPOSIT_MANAGEMENT" + - "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. + 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: chargeable_services + data_type: integer + description: | + Count of weekly chargeable services in a given date and per specified + dimension. + + - name: service_total_price_in_gbp + data_type: decimal + description: | + Sum of the total prices of the chargeable services in a given time range + and per specified dimension, in GBP. + + - name: int_kpis__agg_weekly_new_dash_chargeable_services + description: | + This model computes the dimension aggregation for Weekly Chargeable Services. + It only retrieves services that come from users that are in New Dash, as well + as it only considers services chargeable 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: + - total_chargeable_services + - total_chargeable_amount_in_gbp + - accepted_values: + values: + - global + - by_number_of_listings + - by_billing_country + - by_deal + - by_new_dash_version + - by_has_upgraded_service + - by_service + - by_service_business_type + + - name: dimension_value + data_type: string + description: The value or segment available for the selected dimension. + tests: + - not_null + + - name: total_chargeable_services + data_type: integer + description: | + The total weekly chargeable services in a given time range and per specified + dimension. + + - name: total_chargeable_amount_in_gbp + data_type: decimal + description: | + The total weekly chargeable amount in a given time range and per specified + dimension, in GBP. + + - name: unique_chargeable_bookings + data_type: integer + description: | + The unique weekly chargeable bookings 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: unique_chargeable_listings + data_type: integer + description: | + The unique weekly 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__agg_monthly_new_dash_chargeable_services + description: | + This model computes the dimension aggregation for Monthly Chargeable Services. + It only retrieves services that come from users that are in New Dash, as well + as it only considers services chargeable 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: + - total_chargeable_services + - total_chargeable_amount_in_gbp + - accepted_values: + values: + - global + - by_number_of_listings + - by_billing_country + - by_deal + - by_new_dash_version + - by_has_upgraded_service + - by_service + - by_service_business_type + + - name: dimension_value + data_type: string + description: The value or segment available for the selected dimension. + tests: + - not_null + + - name: total_chargeable_services + data_type: integer + description: | + The total monthly chargeable services in a given time range and per specified + dimension. + + - name: total_chargeable_amount_in_gbp + data_type: decimal + description: | + The total monthly chargeable amount in a given time range and per specified + dimension, in GBP. + + - name: unique_chargeable_bookings + data_type: integer + description: | + The unique monthly chargeable bookings 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: unique_chargeable_listings + data_type: integer + description: | + The unique monthly 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__agg_daily_new_dash_chargeable_services + description: | + This model computes the dimension aggregation for Daily Chargeable Services. + It only retrieves services that come from users that are in New Dash, as well + as it only considers services chargeable after the user has moved to New Dash. + The primary key of this model is date, dimension and dimension_value. + + tests: + - dbt_utils.unique_combination_of_columns: + combination_of_columns: + - date + - dimension + - dimension_value + + columns: + - name: date + data_type: date + description: | + The daily date acting as time range 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: + - total_chargeable_services + - total_chargeable_amount_in_gbp + - accepted_values: + values: + - global + - by_number_of_listings + - by_billing_country + - by_deal + - by_new_dash_version + - by_has_upgraded_service + - by_service + - by_service_business_type + + - name: dimension_value + data_type: string + description: The value or segment available for the selected dimension. + tests: + - not_null + + - name: total_chargeable_services + data_type: integer + description: | + The total daily chargeable services in a given time range and per specified + dimension. + + - name: total_chargeable_amount_in_gbp + data_type: decimal + description: | + The total daily chargeable amount in a given time range and per specified + dimension, in GBP. + + - name: unique_chargeable_bookings + data_type: integer + description: | + The unique daily chargeable bookings 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: unique_chargeable_listings + data_type: integer + description: | + 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. diff --git a/models/reporting/kpis/kpis__product_new_dash_agg_metrics.sql b/models/reporting/kpis/kpis__product_new_dash_agg_metrics.sql index b59abc2..22d67e2 100644 --- a/models/reporting/kpis/kpis__product_new_dash_agg_metrics.sql +++ b/models/reporting/kpis/kpis__product_new_dash_agg_metrics.sql @@ -8,5 +8,9 @@ select {{ capitalise_and_remove_underscores("dimension") }} as dimension, dimension_value as dimension_value, created_services as created_services, - booking_with_created_services_count as booking_with_created_services_count + booking_with_created_services_count as booking_with_created_services_count, + total_chargeable_services as total_chargeable_services, + total_chargeable_amount_in_gbp as total_chargeable_amount_in_gbp, + unique_chargeable_bookings as unique_chargeable_bookings, + unique_chargeable_listings as unique_chargeable_listings from int_kpis__product_new_dash_agg_metrics diff --git a/models/reporting/kpis/schema.yml b/models/reporting/kpis/schema.yml index 15efcd8..3d36e6e 100644 --- a/models/reporting/kpis/schema.yml +++ b/models/reporting/kpis/schema.yml @@ -303,6 +303,7 @@ models: - "By New Dash Version" - "By Has Upgraded Service" - "By Service" + - "By Service Business Type" - name: dimension_value data_type: string @@ -312,12 +313,43 @@ models: - name: created_services data_type: bigint - description: The daily created services for a given date, dimension and value. + description: | + The created services for a given time granularity, date or dates range, + dimension and value. - name: booking_with_created_services_count data_type: bigint description: | - The daily bookings with created services for a given date, dimension and value. + The bookings with created services for a given time granularity, date or + dates 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: total_chargeable_services + data_type: integer + description: | + The total chargeable services for a given time granularity, date or + dates range, dimension and value. + + - name: total_chargeable_amount_in_gbp + data_type: decimal + description: | + The total daily chargeable amount for a given time granularity, date or + dates range, dimension and value, in GBP. + + - name: unique_chargeable_bookings + data_type: integer + description: | + The unique daily chargeable bookings for a given time granularity, date or + dates range, dimension and value. + This metric is not additive, and its value can vary depending on the time + period considered. + + - name: unique_chargeable_listings + data_type: integer + description: | + The unique daily chargeable accommodations, or listings, for a given time + granularity, date or dates range, dimension and value. + This metric is not additive, and its value can vary depending on the time + period considered.