Merged PR 4970: Fix data quality issue on Revenue Retained metrics

# Description

As raised by Kayla, Retained metrics are not computed correctly in AM Account Margin report, see screenshot:

![image.png](https://guardhog.visualstudio.com/4148d95f-4b6d-4205-bcff-e9c8e0d2ca65/_apis/git/repositories/54ac356f-aad7-46d2-b62c-e8c5b3bb8ebf/pullRequests/4970/attachments/image.png)

Issue lies in the fact that Guest Payments contains more dimensions than the rest of the models. This is generating duplicates in the combination_of_sources CTE, but these are effectively hidden because of the sum() applied of the metrics.

In the case of a Deal having in the same day Guest Payments with different dimensions from those selected, AND on the same day having a value on Invoiced Revenue or Host Resolutions, then the Invoiced Revenue or Host Resolutions would be duplicated.

This PR aims to fix this issue, and also adds a few tests on the base model for AM Account Margin to ensure this is kind of error raises an alert.

I'll be debugging other affected models and increase the robustness test-wise; as well as gathering the full impact.

# 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.
- [ ] 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: #29227
This commit is contained in:
Oriol Roqué Paniagua 2025-04-10 07:23:31 +00:00
parent e5a4187e57
commit fa6114b2af
2 changed files with 73 additions and 18 deletions

View file

@ -9,6 +9,49 @@ with
int_kpis__metric_daily_invoiced_revenue as (
select * from {{ ref("int_kpis__metric_daily_invoiced_revenue") }}
),
-- Aggregated models to ensure all revenue sources are included at the desired
-- granularity and to avoid duplicates in the final result
aggregated_guest_payments as (
select
date,
id_deal,
business_scope,
main_billing_country_iso_3_per_deal,
active_accommodations_per_deal_segmentation,
sum(coalesce(total_guest_payments_in_gbp, 0)) as total_guest_payments_in_gbp
from int_kpis__metric_daily_guest_payments
group by 1, 2, 3, 4, 5
),
aggregated_invoiced_revenue as (
select
date,
id_deal,
business_scope,
main_billing_country_iso_3_per_deal,
active_accommodations_per_deal_segmentation,
sum(
coalesce(xero_operator_net_fees_in_gbp, 0)
) as xero_operator_net_fees_in_gbp,
sum(coalesce(xero_apis_net_fees_in_gbp, 0)) as xero_apis_net_fees_in_gbp,
sum(
coalesce(xero_waiver_paid_back_to_host_in_gbp, 0)
) as xero_waiver_paid_back_to_host_in_gbp
from int_kpis__metric_daily_invoiced_revenue
group by 1, 2, 3, 4, 5
),
aggregated_host_resolutions as (
select
date,
id_deal,
business_scope,
main_billing_country_iso_3_per_deal,
active_accommodations_per_deal_segmentation,
sum(
coalesce(xero_host_resolution_amount_paid_in_gbp, 0)
) as xero_host_resolution_amount_paid_in_gbp
from int_kpis__metric_daily_host_resolutions
group by 1, 2, 3, 4, 5
),
unique_keys as (
select distinct
date,
@ -16,7 +59,7 @@ with
business_scope,
main_billing_country_iso_3_per_deal,
active_accommodations_per_deal_segmentation
from int_kpis__metric_daily_guest_payments
from aggregated_guest_payments
union
select distinct
date,
@ -24,7 +67,7 @@ with
business_scope,
main_billing_country_iso_3_per_deal,
active_accommodations_per_deal_segmentation
from int_kpis__metric_daily_invoiced_revenue
from aggregated_invoiced_revenue
union
select distinct
date,
@ -32,32 +75,29 @@ with
business_scope,
main_billing_country_iso_3_per_deal,
active_accommodations_per_deal_segmentation
from int_kpis__metric_daily_host_resolutions
from aggregated_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)
coalesce(gr.total_guest_payments_in_gbp, 0) as total_guest_payments_in_gbp,
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)
coalesce(ir.xero_apis_net_fees_in_gbp, 0) as xero_apis_net_fees_in_gbp,
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)
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
aggregated_guest_payments gr
on k.date = gr.date
and k.id_deal = gr.id_deal
and k.business_scope = gr.business_scope
@ -66,7 +106,7 @@ with
and k.active_accommodations_per_deal_segmentation
= gr.active_accommodations_per_deal_segmentation
left join
int_kpis__metric_daily_invoiced_revenue ir
aggregated_invoiced_revenue ir
on k.date = ir.date
and k.id_deal = ir.id_deal
and k.business_scope = ir.business_scope
@ -75,7 +115,7 @@ with
and k.active_accommodations_per_deal_segmentation
= ir.active_accommodations_per_deal_segmentation
left join
int_kpis__metric_daily_host_resolutions hr
aggregated_host_resolutions hr
on k.date = hr.date
and k.id_deal = hr.id_deal
and k.business_scope = hr.business_scope
@ -83,7 +123,6 @@ with
= 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 --