Merged PR 4874: Daily model for Total and Retained Revenue
# Description Daily model for Total and Retained Revenue metrics. I opted for keeping both Total Revenue alongside of Revenue Retained and Revenue Retained Post-Resolutions within the same model. Please, verify that you're happy with the naming of `total_and_retained_revenue`, before continuing with the usual monthly/mtd metric/aggregated models. # 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:
parent
57626f266a
commit
adcb8d2231
2 changed files with 212 additions and 2 deletions
|
|
@ -0,0 +1,118 @@
|
||||||
|
{{ config(materialized="table", unique_key=["date", "id_deal", "business_scope"]) }}
|
||||||
|
with
|
||||||
|
int_kpis__metric_daily_guest_payments as (
|
||||||
|
select * from {{ ref("int_kpis__metric_daily_guest_payments") }}
|
||||||
|
),
|
||||||
|
int_kpis__metric_daily_host_resolutions as (
|
||||||
|
select * from {{ ref("int_kpis__metric_daily_host_resolutions") }}
|
||||||
|
),
|
||||||
|
int_kpis__metric_daily_invoiced_revenue as (
|
||||||
|
select * from {{ ref("int_kpis__metric_daily_invoiced_revenue") }}
|
||||||
|
),
|
||||||
|
unique_keys as (
|
||||||
|
select distinct
|
||||||
|
date,
|
||||||
|
id_deal,
|
||||||
|
business_scope,
|
||||||
|
main_billing_country_iso_3_per_deal,
|
||||||
|
active_accommodations_per_deal_segmentation
|
||||||
|
from int_kpis__metric_daily_guest_payments
|
||||||
|
union
|
||||||
|
select distinct
|
||||||
|
date,
|
||||||
|
id_deal,
|
||||||
|
business_scope,
|
||||||
|
main_billing_country_iso_3_per_deal,
|
||||||
|
active_accommodations_per_deal_segmentation
|
||||||
|
from int_kpis__metric_daily_invoiced_revenue
|
||||||
|
union
|
||||||
|
select distinct
|
||||||
|
date,
|
||||||
|
id_deal,
|
||||||
|
business_scope,
|
||||||
|
main_billing_country_iso_3_per_deal,
|
||||||
|
active_accommodations_per_deal_segmentation
|
||||||
|
from int_kpis__metric_daily_host_resolutions
|
||||||
|
),
|
||||||
|
combination_of_sources as (
|
||||||
|
|
||||||
|
select
|
||||||
|
k.date,
|
||||||
|
k.id_deal,
|
||||||
|
k.business_scope,
|
||||||
|
k.main_billing_country_iso_3_per_deal,
|
||||||
|
k.active_accommodations_per_deal_segmentation,
|
||||||
|
sum(
|
||||||
|
coalesce(gr.total_guest_payments_in_gbp, 0)
|
||||||
|
) as total_guest_payments_in_gbp,
|
||||||
|
sum(
|
||||||
|
coalesce(ir.xero_operator_net_fees_in_gbp, 0)
|
||||||
|
) as xero_operator_net_fees_in_gbp,
|
||||||
|
sum(coalesce(ir.xero_apis_net_fees_in_gbp, 0)) as xero_apis_net_fees_in_gbp,
|
||||||
|
sum(
|
||||||
|
coalesce(ir.xero_waiver_paid_back_to_host_in_gbp, 0)
|
||||||
|
) as xero_waiver_paid_back_to_host_in_gbp,
|
||||||
|
sum(
|
||||||
|
coalesce(hr.xero_host_resolution_amount_paid_in_gbp, 0)
|
||||||
|
) as xero_host_resolution_amount_paid_in_gbp
|
||||||
|
from unique_keys k
|
||||||
|
left join
|
||||||
|
int_kpis__metric_daily_guest_payments gr
|
||||||
|
on k.date = gr.date
|
||||||
|
and k.id_deal = gr.id_deal
|
||||||
|
and k.business_scope = gr.business_scope
|
||||||
|
and k.main_billing_country_iso_3_per_deal
|
||||||
|
= gr.main_billing_country_iso_3_per_deal
|
||||||
|
and k.active_accommodations_per_deal_segmentation
|
||||||
|
= gr.active_accommodations_per_deal_segmentation
|
||||||
|
left join
|
||||||
|
int_kpis__metric_daily_invoiced_revenue ir
|
||||||
|
on k.date = ir.date
|
||||||
|
and k.id_deal = ir.id_deal
|
||||||
|
and k.business_scope = ir.business_scope
|
||||||
|
and k.main_billing_country_iso_3_per_deal
|
||||||
|
= ir.main_billing_country_iso_3_per_deal
|
||||||
|
and k.active_accommodations_per_deal_segmentation
|
||||||
|
= ir.active_accommodations_per_deal_segmentation
|
||||||
|
left join
|
||||||
|
int_kpis__metric_daily_host_resolutions hr
|
||||||
|
on k.date = hr.date
|
||||||
|
and k.id_deal = hr.id_deal
|
||||||
|
and k.business_scope = hr.business_scope
|
||||||
|
and k.main_billing_country_iso_3_per_deal
|
||||||
|
= hr.main_billing_country_iso_3_per_deal
|
||||||
|
and k.active_accommodations_per_deal_segmentation
|
||||||
|
= hr.active_accommodations_per_deal_segmentation
|
||||||
|
group by 1, 2, 3, 4, 5
|
||||||
|
)
|
||||||
|
select
|
||||||
|
-- Unique Key --
|
||||||
|
date,
|
||||||
|
id_deal,
|
||||||
|
business_scope,
|
||||||
|
-- Attributes --
|
||||||
|
main_billing_country_iso_3_per_deal,
|
||||||
|
active_accommodations_per_deal_segmentation,
|
||||||
|
-- Metrics --
|
||||||
|
nullif(
|
||||||
|
total_guest_payments_in_gbp
|
||||||
|
+ xero_operator_net_fees_in_gbp
|
||||||
|
+ xero_apis_net_fees_in_gbp,
|
||||||
|
0
|
||||||
|
) as total_revenue_in_gbp,
|
||||||
|
nullif(
|
||||||
|
total_guest_payments_in_gbp
|
||||||
|
+ xero_operator_net_fees_in_gbp
|
||||||
|
+ xero_apis_net_fees_in_gbp
|
||||||
|
+ xero_waiver_paid_back_to_host_in_gbp,
|
||||||
|
0
|
||||||
|
) as revenue_retained_in_gbp,
|
||||||
|
nullif(
|
||||||
|
total_guest_payments_in_gbp
|
||||||
|
+ xero_operator_net_fees_in_gbp
|
||||||
|
+ xero_apis_net_fees_in_gbp
|
||||||
|
+ xero_waiver_paid_back_to_host_in_gbp
|
||||||
|
+ xero_host_resolution_amount_paid_in_gbp,
|
||||||
|
0
|
||||||
|
) as revenue_retained_post_resolutions_in_gbp
|
||||||
|
from combination_of_sources
|
||||||
|
|
@ -7753,7 +7753,7 @@ models:
|
||||||
data_type: bigint
|
data_type: bigint
|
||||||
description: |
|
description: |
|
||||||
The count of deals with services offered by the end of a given month, dimension and value.
|
The count of deals with services offered by the end of a given month, dimension and value.
|
||||||
|
|
||||||
- name: int_kpis__agg_daily_new_dash_accommodation_offered_services
|
- name: int_kpis__agg_daily_new_dash_accommodation_offered_services
|
||||||
description: |
|
description: |
|
||||||
This model computes the dimension aggregation for Daily Accommodation Offered Services.
|
This model computes the dimension aggregation for Daily Accommodation Offered Services.
|
||||||
|
|
@ -7910,4 +7910,96 @@ models:
|
||||||
- name: accommodation_with_offered_service_count
|
- name: accommodation_with_offered_service_count
|
||||||
data_type: bigint
|
data_type: bigint
|
||||||
description: |
|
description: |
|
||||||
The count of accommodations with services offered by the end of a given month, dimension and value.
|
The count of accommodations with services offered by the end of a given month, dimension and value.
|
||||||
|
|
||||||
|
- name: int_kpis__metric_daily_total_and_retained_revenue
|
||||||
|
description: |
|
||||||
|
This model computes the Daily Total Revenue and Revenue Retained metrics
|
||||||
|
at the deepest granularity.
|
||||||
|
|
||||||
|
The logic behind this model is to combine the daily revenue and payouts
|
||||||
|
from different sources:
|
||||||
|
- Guest Revenue (from int_kpis__metric_daily_guest_payments)
|
||||||
|
- Invoiced Revenue and Payouts (from int_kpis__metric_daily_invoiced_revenue)
|
||||||
|
- Host Resolutions Payouts (from int_kpis__metric_daily_host_resolutions)
|
||||||
|
in order to compute Total Revenue, Retained Revenue and Retained Revenue Post-Resolutions.
|
||||||
|
|
||||||
|
The unique key corresponds to the deepest granularity of the model,
|
||||||
|
in this case:
|
||||||
|
- date,
|
||||||
|
- id_deal,
|
||||||
|
- business_scope.
|
||||||
|
|
||||||
|
data_tests:
|
||||||
|
- dbt_utils.unique_combination_of_columns:
|
||||||
|
combination_of_columns:
|
||||||
|
- date
|
||||||
|
- id_deal
|
||||||
|
- business_scope
|
||||||
|
|
||||||
|
columns:
|
||||||
|
- name: date
|
||||||
|
data_type: date
|
||||||
|
description: Date of when the document was issued.
|
||||||
|
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 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 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 date and per specified dimension.
|
||||||
|
|
|
||||||
Loading…
Add table
Add a link
Reference in a new issue