Merged PR 4878: Adds Monthly/MTD and Aggregated/Metric models for Total and Retained Revenue

# Description

Adds 4 models for Total and Retained Revenue:
* 2 Metric models on Monthly and MTD
* 2 Aggregated models on Monthly and MTD

This follows the standard for KPIs. First manual checks vs data look ok, although I'll run the proper test analysis with the dbt audit tool in the next PR when merging into the current production tables.

# 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: #28946
This commit is contained in:
Oriol Roqué Paniagua 2025-04-02 08:53:49 +00:00
commit ce723b335e
6 changed files with 467 additions and 0 deletions

View file

@ -0,0 +1,28 @@
{% set dimensions = get_kpi_dimensions_per_model("TOTAL_AND_RETAINED_REVENUE") %}
{{
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(total_revenue_in_gbp) as total_revenue_in_gbp,
sum(revenue_retained_in_gbp) as revenue_retained_in_gbp,
sum(
revenue_retained_post_resolutions_in_gbp
) as revenue_retained_post_resolutions_in_gbp
from {{ ref("int_kpis__metric_monthly_total_and_retained_revenue") }}
group by 1, 2, 3, 4
{% if not loop.last %}
union all
{% endif %}
{% endfor %}

View file

@ -0,0 +1,28 @@
{% set dimensions = get_kpi_dimensions_per_model("TOTAL_AND_RETAINED_REVENUE") %}
{{
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(total_revenue_in_gbp) as total_revenue_in_gbp,
sum(revenue_retained_in_gbp) as revenue_retained_in_gbp,
sum(
revenue_retained_post_resolutions_in_gbp
) as revenue_retained_post_resolutions_in_gbp
from {{ ref("int_kpis__metric_mtd_total_and_retained_revenue") }}
group by 1, 2, 3, 4
{% if not loop.last %}
union all
{% endif %}
{% endfor %}

View file

@ -0,0 +1,33 @@
{{
config(
materialized="view",
unique_key=[
"end_date",
"id_deal",
"active_accommodations_per_deal_segmentation",
"business_scope",
],
)
}}
select
-- Unique Key --
d.first_day_month as start_date,
d.date as end_date,
r.id_deal,
r.business_scope,
r.active_accommodations_per_deal_segmentation,
-- Dimensions --
r.main_billing_country_iso_3_per_deal,
-- Metrics --
sum(r.total_revenue_in_gbp) as total_revenue_in_gbp,
sum(r.revenue_retained_in_gbp) as revenue_retained_in_gbp,
sum(
r.revenue_retained_post_resolutions_in_gbp
) as revenue_retained_post_resolutions_in_gbp
from {{ ref("int_kpis__dimension_dates") }} d
left join
{{ ref("int_kpis__metric_daily_total_and_retained_revenue") }} r
on date_trunc('month', r.date)::date = d.first_day_month
where d.is_end_of_month = true and r.id_deal is not null
group by 1, 2, 3, 4, 5, 6

View file

@ -0,0 +1,34 @@
{{
config(
materialized="view",
unique_key=[
"end_date",
"id_deal",
"active_accommodations_per_deal_segmentation",
"business_scope",
],
)
}}
select
-- Unique Key --
d.first_day_month as start_date,
d.date as end_date,
r.id_deal,
r.business_scope,
r.active_accommodations_per_deal_segmentation,
-- Dimensions --
r.main_billing_country_iso_3_per_deal,
-- Metrics --
sum(r.total_revenue_in_gbp) as total_revenue_in_gbp,
sum(r.revenue_retained_in_gbp) as revenue_retained_in_gbp,
sum(
r.revenue_retained_post_resolutions_in_gbp
) as revenue_retained_post_resolutions_in_gbp
from {{ ref("int_kpis__dimension_dates") }} d
left join
{{ ref("int_kpis__metric_daily_total_and_retained_revenue") }} r
on date_trunc('month', r.date)::date = d.first_day_month
and extract(day from r.date) <= d.day
where d.is_month_to_date = true and r.id_deal is not null
group by 1, 2, 3, 4, 5, 6

View file

@ -8003,3 +8003,346 @@ models:
description: |
Revenue Retained minus Host Resolutions Payouts due to resolutions,
in GBP, without taxes, in a given date and per specified dimension.
- name: int_kpis__metric_monthly_total_and_retained_revenue
description: |
This model computes the Monthly Total Revenue, Retained
Revenue and Revenue Retained Post-Resolutions at the deepest
granularity.
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,
- id_deal,
- business_scope,
- active_accommodations_per_deal_segmentation.
data_tests:
- dbt_utils.unique_combination_of_columns:
combination_of_columns:
- end_date
- id_deal
- business_scope
- 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.
data_tests:
- not_null
- name: end_date
data_type: date
description: |
The end date of the time range considered for the metrics in this record.
data_tests:
- not_null
- name: id_deal
data_type: string
description: Unique identifier of an account.
data_tests:
- not_null
- name: business_scope
data_type: string
description: |
Business scope identifying the metric source.
data_tests:
- not_null
- accepted_values:
values:
- "Old Dash"
- "New Dash"
- "API"
- "UNSET"
- 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.
data_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.
data_tests:
- not_null
- name: total_revenue_in_gbp
data_type: decimal
description: |
Sum of Guest Revenue, Invoiced Operator Revenue and APIs Revenue,
in GBP, without taxes, in a given month and per specified dimension.
- name: revenue_retained_in_gbp
data_type: decimal
description: |
Total Revenue minus Waiver Payouts due to Host Takes Risk,
in GBP, without taxes, in a given month and per specified dimension.
- name: revenue_retained_post_resolutions_in_gbp
data_type: decimal
description: |
Revenue Retained minus Host Resolutions Payouts due to resolutions,
in GBP, without taxes, in a given month and per specified dimension.
- name: int_kpis__metric_mtd_total_and_retained_revenue
description: |
This model computes the Month-To-Date Total Revenue, Retained
Revenue and Revenue Retained Post-Resolutions at the deepest
granularity.
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,
- id_deal,
- business_scope,
- active_accommodations_per_deal_segmentation.
data_tests:
- dbt_utils.unique_combination_of_columns:
combination_of_columns:
- end_date
- id_deal
- business_scope
- 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.
data_tests:
- not_null
- name: end_date
data_type: date
description: |
The end date of the time range considered for the metrics in this record.
data_tests:
- not_null
- name: id_deal
data_type: string
description: Unique identifier of an account.
data_tests:
- not_null
- name: business_scope
data_type: string
description: |
Business scope identifying the metric source.
data_tests:
- not_null
- accepted_values:
values:
- "Old Dash"
- "New Dash"
- "API"
- "UNSET"
- 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.
data_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.
data_tests:
- not_null
- name: total_revenue_in_gbp
data_type: decimal
description: |
Sum of Guest Revenue, Invoiced Operator Revenue and APIs Revenue,
in GBP, without taxes, in a given month to the current date
and per specified dimension.
- name: revenue_retained_in_gbp
data_type: decimal
description: |
Total Revenue minus Waiver Payouts due to Host Takes Risk,
in GBP, without taxes, in a given month to the current date
and per specified dimension.
- name: revenue_retained_post_resolutions_in_gbp
data_type: decimal
description: |
Revenue Retained minus Host Resolutions Payouts due to resolutions,
in GBP, without taxes, in a given month to the current date
and per specified dimension.
- name: int_kpis__agg_monthly_total_and_retained_revenue
description: |
This model computes the dimension aggregation for
Monthly Total Revenue, Retained Revenue and
Revenue Retained Post-Resolutions.
The primary key of this model is end_date, dimension
and dimension_value.
data_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.
data_tests:
- not_null
- name: end_date
data_type: date
description: |
The end date of the time range considered for the metrics in this record.
data_tests:
- not_null
- name: dimension
data_type: string
description: The dimension or granularity of the metrics.
data_tests:
- assert_dimension_completeness:
metric_column_names:
- total_revenue_in_gbp
- revenue_retained_in_gbp
- revenue_retained_post_resolutions_in_gbp
- accepted_values:
values:
- global
- by_number_of_listings
- by_billing_country
- by_business_scope
- by_deal
- name: dimension_value
data_type: string
description: The value or segment available for the selected dimension.
data_tests:
- not_null
- name: total_revenue_in_gbp
data_type: decimal
description: |
The monthly Total Revenue in GBP
for a given date, dimension and value.
- name: revenue_retained_in_gbp
data_type: decimal
description: |
The monthly Revenue Retained in GBP
for a given date, dimension and value.
- name: revenue_retained_post_resolutions_in_gbp
data_type: decimal
description: |
The monthly Revenue Retained Post-Resolutions in GBP
for a given date, dimension and value.
- name: int_kpis__agg_mtd_total_and_retained_revenue
description: |
This model computes the dimension aggregation for
Month-To-Date Total Revenue, Retained Revenue and
Revenue Retained Post-Resolutions.
The primary key of this model is end_date, dimension
and dimension_value.
data_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.
data_tests:
- not_null
- name: end_date
data_type: date
description: |
The end date of the time range considered for the metrics in this record.
data_tests:
- not_null
- name: dimension
data_type: string
description: The dimension or granularity of the metrics.
data_tests:
- assert_dimension_completeness:
metric_column_names:
- total_revenue_in_gbp
- revenue_retained_in_gbp
- revenue_retained_post_resolutions_in_gbp
- accepted_values:
values:
- global
- by_number_of_listings
- by_billing_country
- by_business_scope
- by_deal
- name: dimension_value
data_type: string
description: The value or segment available for the selected dimension.
data_tests:
- not_null
- name: total_revenue_in_gbp
data_type: decimal
description: |
The month-to-date Total Revenue in GBP
for a given date, dimension and value.
- name: revenue_retained_in_gbp
data_type: decimal
description: |
The month-to-date Revenue Retained in GBP
for a given date, dimension and value.
- name: revenue_retained_post_resolutions_in_gbp
data_type: decimal
description: |
The month-to-date Revenue Retained Post-Resolutions in GBP
for a given date, dimension and value.