data-dwh-dbt-project/tests/kpis_additive_metrics_per_dimension_are_consistent.sql
Oriol Roqué Paniagua 6a90eb30f9 Merged PR 3272: Expose Churn Rates into Main KPIs
# Description

Exposes Churn Rates into Main KPIs, specifically Revenue Churn Rate, Bookings Churn Rate and Listings Churn Rate. This is based on the average approach.

Additionally, it adds these 3 metrics in the kpis_additive_metrics_per_dimension_are_consistent test.
Additionally, it removes from int_mtd_vs_previous_year_metrics the computation of the additive Churn Rates. The removal of further unused code will be handled in a separated PR.

# 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.
- [NA] I have checked for DRY opportunities with other models and docs.
- [NA] 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: #22691
2024-10-22 08:08:03 +00:00

94 lines
3.2 KiB
SQL

/*
This test is applied in the reporting layer for Main KPIs,
specifically on reporting.mtd_aggregated_metrics.
It just ensures that for the last available date, the sum of metrics
for any dimension provides an equal or lower aggregated value compared
to what is expected at Global level. This is because some dimensions
depend on Deal, and not all users have a Deal, thus it's normal that
the aggregation might not match the Global value on a given metric.
However, the aggregation cannot be higher than the value reported in
the Global dimension.
*/
{% set additive_metric_names = (
"Cancelled Bookings",
"Check-In Hero Revenue",
"Checkout Bookings",
"Churning Deals",
"Churning Listings",
"Created Bookings",
"Deals Booked in 12 Months",
"Deals Booked in 6 Months",
"Deals Booked in Month",
"Deposit Fees Revenue",
"Est. Billable Bookings",
"First Time Booked Deals",
"First Time Booked Listings",
"Guest Journey Completed",
"Guest Journey Created",
"Guest Journey Started",
"Guest Journey with Payment",
"Guest Revenue",
"Host Resolutions Amount Paid",
"Host Resolutions Payment Count",
"Invoiced APIs Revenue",
"Invoiced Booking Fees Revenue",
"Invoiced E-Deposit Revenue",
"Invoiced Athena Revenue",
"Invoiced Listing Fees Revenue",
"Invoiced Operator Revenue",
"Invoiced Verification Fees Revenue",
"Listings Booked in 12 Months",
"Listings Booked in 6 Months",
"Listings Booked in Month",
"New Deals",
"New Listings",
"Total Revenue",
"Damage Host-Waiver Payments",
"Waiver Revenue",
"Waiver Retained",
"Revenue Churn Rate",
"Bookings Churn Rate",
"Listings Churn Rate",
) %}
with
dimensions_total_metric_values as (
select date, dimension, metric, number_format, sum(value) as total_metric_value
from {{ ref("mtd_aggregated_metrics") }}
where
date in (select max(date) from {{ ref("mtd_aggregated_metrics") }})
and metric in {{ additive_metric_names }}
group by date, dimension, metric, number_format
),
global_dimension_metric_values as (
select date, dimension, metric, number_format, total_metric_value
from dimensions_total_metric_values
where dimension = 'Global'
),
other_dimension_metric_values as (
select date, dimension, metric, number_format, total_metric_value
from dimensions_total_metric_values
where dimension != 'Global'
),
difference_computation as (
select
g.date,
g.metric,
o.dimension,
g.number_format,
abs(g.total_metric_value) as global_metric_value,
abs(o.total_metric_value) as dimension_metric_value,
abs(o.total_metric_value) - abs(g.total_metric_value) as abs_diff,
abs(o.total_metric_value) / nullif(abs(g.total_metric_value), 0)
- 1 as rel_diff
from global_dimension_metric_values as g
left join
other_dimension_metric_values as o
on g.date = o.date
and g.metric = o.metric
)
select *
from difference_computation
where abs_diff > 0