Merged PR 3599: New Dash KPIs skeleton with Created Services
# Description This PR handles the computation of KPIs for New Dash, focusing on Created Services. New dimensions configured in `business_kpis_configuration` and applied in this new models for `NEW_DASH_CREATED_SERVICES`: * `dim_host`, * `dim_has_upgraded_service`, * `dim_new_dash_version`, * `dim_pricing_service` New daily metric model `int_kpis__metric_daily_new_dash_created_services` * Follows a similar pattern as for the rest of daily metric models. The only difference is that is aggregated to `id_booking` to ensure we can handle count distinct of bookings per different time granularities. * Reads from the new pricing tables `int_core__booking_summary` and `int_core__booking_service_detail`. The main filters applied are selecting only new dash users and only services created after the user move timestamp to new dash. An additional metric model at monthly level is created `int_kpis__metric_monthly_new_dash_created_services` These finally go to a dimension aggregated model (`dimension`, `dimension_value`), respectively: * Daily: `int_kpis__agg_daily_new_dash_created_services` * Monthly: `int_kpis__agg_monthly_new_dash_created_services` A final model aims to aggregate the different dimension aggregated metrics for New Dash: `int_kpis__product_new_dash_agg_metrics` * It computes a `time_granularity` aggregation * Here I will add additional metrics (such as revenue) once we have them. A final model reading from the previous is exposed to reporting: `kpis__product_new_dash_agg_metrics` # 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
This commit is contained in:
parent
d73ca6555c
commit
86c81c1f21
9 changed files with 662 additions and 2 deletions
|
|
@ -61,7 +61,39 @@ Please note that strings should be encoded with " ' your_value_here ' ",
|
|||
{% macro dim_has_id_check() %}
|
||||
{{ return({"dimension": "'by_has_id_check'", "dimension_value": "has_id_check"}) }}
|
||||
{% endmacro %}
|
||||
|
||||
{% macro dim_host() %}
|
||||
{{ return({"dimension": "'by_host'", "dimension_value": "id_user_host"}) }}
|
||||
{% endmacro %}
|
||||
{% macro dim_has_upgraded_service() %}
|
||||
{{
|
||||
return(
|
||||
{
|
||||
"dimension": "'by_has_upgraded_service'",
|
||||
"dimension_value": "is_upgraded_service",
|
||||
}
|
||||
)
|
||||
}}
|
||||
{% endmacro %}
|
||||
{% macro dim_pricing_service() %}
|
||||
{{
|
||||
return(
|
||||
{
|
||||
"dimension": "'by_service'",
|
||||
"dimension_value": "service_name",
|
||||
}
|
||||
)
|
||||
}}
|
||||
{% endmacro %}
|
||||
{% macro dim_new_dash_version() %}
|
||||
{{
|
||||
return(
|
||||
{
|
||||
"dimension": "'by_new_dash_version'",
|
||||
"dimension_value": "new_dash_version",
|
||||
}
|
||||
)
|
||||
}}
|
||||
{% endmacro %}
|
||||
/*
|
||||
Macro: get_kpi_dimensions_per_model
|
||||
|
||||
|
|
@ -105,6 +137,15 @@ Provides a general assignement for the Dimensions available for each KPI
|
|||
] %}
|
||||
{% endif %}
|
||||
|
||||
{% if entity_name == "NEW_DASH_CREATED_SERVICES" %}
|
||||
{% set additional_dimensions = additional_dimensions + [
|
||||
dim_host(),
|
||||
dim_has_upgraded_service(),
|
||||
dim_new_dash_version(),
|
||||
dim_pricing_service(),
|
||||
] %}
|
||||
{% endif %}
|
||||
|
||||
{# Combine base dimensions with additional dimensions for the specific model #}
|
||||
{% set dimensions = base_dimensions + additional_dimensions %}
|
||||
{{ return(dimensions) }}
|
||||
|
|
|
|||
|
|
@ -0,0 +1,28 @@
|
|||
{% 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 --
|
||||
d.date,
|
||||
{{ dimension.dimension }} as dimension,
|
||||
{{ dimension.dimension_value }} as dimension_value,
|
||||
-- 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") }} 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 %}
|
||||
|
|
@ -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_monthly_new_dash_created_services") }}
|
||||
group by 1, 2, 3, 4
|
||||
{% if not loop.last %}
|
||||
union all
|
||||
{% endif %}
|
||||
{% endfor %}
|
||||
|
|
@ -0,0 +1,33 @@
|
|||
{{ config(materialized="table", unique_key=["id_booking", "service_name", "date"]) }}
|
||||
select
|
||||
-- Unique Key --
|
||||
icbs.id_booking,
|
||||
date(icbsd.service_detail_created_at_utc) as date,
|
||||
coalesce(icbsd.service_name) as service_name,
|
||||
-- Dimensions --
|
||||
coalesce(icbs.id_user_host, 'UNSET') as id_user_host,
|
||||
coalesce(icbs.id_deal, 'UNSET') as id_deal,
|
||||
case when icbsd.is_upgraded_service then 'YES' else 'NO' end as is_upgraded_service,
|
||||
coalesce(icbs.new_dash_version, 'UNSET') as new_dash_version,
|
||||
coalesce(
|
||||
icd.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,
|
||||
-- Metrics --
|
||||
count(distinct icbsd.id_booking_service_detail) as created_services
|
||||
from {{ ref("int_core__booking_summary") }} as icbs
|
||||
inner join
|
||||
{{ ref("int_core__booking_service_detail") }} as icbsd
|
||||
on icbs.id_booking = icbsd.id_booking
|
||||
left join {{ ref("int_core__deal") }} as icd on icbs.id_deal = icd.id_deal
|
||||
left join
|
||||
{{ ref("int_kpis__dimension_daily_accommodation") }} as icmas
|
||||
on icbs.id_deal = icmas.id_deal
|
||||
and date(icbsd.service_detail_created_at_utc) = icmas.date
|
||||
where
|
||||
icbs.is_user_in_new_dash = true
|
||||
and icbsd.service_detail_created_at_utc
|
||||
>= icbs.user_in_new_dash_since_timestamp_at_utc
|
||||
group by 1, 2, 3, 4, 5, 6, 7, 8, 9
|
||||
|
|
@ -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_month 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('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
|
||||
|
|
@ -0,0 +1,24 @@
|
|||
with
|
||||
int_kpis__agg_daily_new_dash_created_services as (
|
||||
select * from {{ ref("int_kpis__agg_daily_new_dash_created_services") }}
|
||||
),
|
||||
int_kpis__agg_monthly_new_dash_created_services as (
|
||||
select * from {{ ref("int_kpis__agg_monthly_new_dash_created_services") }}
|
||||
)
|
||||
select
|
||||
date,
|
||||
'daily' as time_granularity,
|
||||
dimension,
|
||||
dimension_value,
|
||||
created_services,
|
||||
booking_with_created_services_count
|
||||
from int_kpis__agg_daily_new_dash_created_services
|
||||
union all
|
||||
select
|
||||
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
|
||||
|
|
@ -1044,7 +1044,7 @@ models:
|
|||
|
||||
- name: created_guest_journeys
|
||||
data_type: bigint
|
||||
description: The monthtly created guest journeys for a given date, dimension and value.
|
||||
description: The monthly created guest journeys for a given date, dimension and value.
|
||||
|
||||
- name: int_kpis__agg_mtd_created_guest_journeys
|
||||
description: |
|
||||
|
|
@ -6114,3 +6114,401 @@ models:
|
|||
description: |
|
||||
Sum of total payments paid by guests, excluding taxes, in GBP
|
||||
on the same date in the previous year, segmented by the specified dimension.
|
||||
|
||||
- name: int_kpis__metric_daily_new_dash_created_services
|
||||
description: |
|
||||
This model computes the Daily 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.
|
||||
The unique key corresponds to the deepest granularity of the model,
|
||||
in this case:
|
||||
- date,
|
||||
- id_booking,
|
||||
- service_name
|
||||
|
||||
tests:
|
||||
- dbt_utils.unique_combination_of_columns:
|
||||
combination_of_columns:
|
||||
- date
|
||||
- id_booking
|
||||
- service_name
|
||||
|
||||
columns:
|
||||
- name: date
|
||||
data_type: date
|
||||
description: Date of when Services have been created.
|
||||
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 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 daily services created in a given date and per specified dimension.
|
||||
|
||||
- name: int_kpis__metric_monthly_new_dash_created_services
|
||||
description: |
|
||||
This model computes the Monthly 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 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_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_monthly_new_dash_created_services
|
||||
description: |
|
||||
This model computes the dimension aggregation for Monthly 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 monthly created services for a given date range, dimension and value.
|
||||
|
||||
- name: booking_with_created_services_count
|
||||
data_type: bigint
|
||||
description: |
|
||||
The monthly 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_daily_new_dash_created_services
|
||||
description: |
|
||||
This model computes the dimension aggregation for Daily 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 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:
|
||||
- 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 daily created services for a given date, 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.
|
||||
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__product_new_dash_agg_metrics
|
||||
description: |
|
||||
This model serves as the skeleton for New Dash metrics and dimensions.
|
||||
This model computes the time granularity aggregation per previously computed
|
||||
dimension aggregation.
|
||||
|
||||
tests:
|
||||
- dbt_utils.unique_combination_of_columns:
|
||||
combination_of_columns:
|
||||
- date
|
||||
- time_granularity
|
||||
- dimension
|
||||
- dimension_value
|
||||
|
||||
columns:
|
||||
- name: date
|
||||
data_type: date
|
||||
description: |
|
||||
The end date of the time range specified in the time_granularity
|
||||
for the dimension, dimension_value and metrics in this record.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: time_granularity
|
||||
data_type: string
|
||||
description: The time dimension.
|
||||
tests:
|
||||
- accepted_values:
|
||||
values:
|
||||
- daily
|
||||
- monthly
|
||||
|
||||
- name: dimension
|
||||
data_type: string
|
||||
description: The dimension or granularity of the metrics.
|
||||
tests:
|
||||
- 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 daily created services for a given date, 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.
|
||||
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.
|
||||
|
|
|
|||
12
models/reporting/kpis/kpis__product_new_dash_agg_metrics.sql
Normal file
12
models/reporting/kpis/kpis__product_new_dash_agg_metrics.sql
Normal file
|
|
@ -0,0 +1,12 @@
|
|||
with
|
||||
int_kpis__product_new_dash_agg_metrics as (
|
||||
select * from {{ ref("int_kpis__product_new_dash_agg_metrics") }}
|
||||
)
|
||||
select
|
||||
date as date,
|
||||
time_granularity as time_granularity,
|
||||
dimension as dimension,
|
||||
dimension_value as dimension_value,
|
||||
created_services as created_services,
|
||||
booking_with_created_services_count as booking_with_created_services_count
|
||||
from int_kpis__product_new_dash_agg_metrics
|
||||
|
|
@ -203,3 +203,68 @@ models:
|
|||
description: |
|
||||
Sum of total payments paid by guests, excluding taxes, in GBP
|
||||
on the same date in the previous year, segmented by the specified dimension.
|
||||
|
||||
- name: kpis__product_new_dash_agg_metrics
|
||||
description: |
|
||||
Reporting model for New Dash specific KPIs. It's an aggregated version
|
||||
of time granularity, dimension, dimension value and list of metrics
|
||||
with their value.
|
||||
|
||||
tests:
|
||||
- dbt_utils.unique_combination_of_columns:
|
||||
combination_of_columns:
|
||||
- date
|
||||
- time_granularity
|
||||
- dimension
|
||||
- dimension_value
|
||||
|
||||
columns:
|
||||
- name: date
|
||||
data_type: date
|
||||
description: |
|
||||
The end date of the time range specified in the time_granularity
|
||||
for the dimension, dimension_value and metrics in this record.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: time_granularity
|
||||
data_type: string
|
||||
description: The time dimension.
|
||||
tests:
|
||||
- accepted_values:
|
||||
values:
|
||||
- daily
|
||||
- monthly
|
||||
|
||||
- name: dimension
|
||||
data_type: string
|
||||
description: The dimension or granularity of the metrics.
|
||||
tests:
|
||||
- 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 daily created services for a given date, 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.
|
||||
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.
|
||||
|
|
|
|||
Loading…
Add table
Add a link
Reference in a new issue