# Description Exposes new metrics: * Created Bookings (Excl. Cancelled) * Cancelled Created Bookings * Check Out Bookings (Excl. Cancelled) * Cancelled Check Out Bookings Re-naming of existing metrics: * Created Bookings -> Total Created Bookings * Checkout Bookings -> Total Check Out Bookings Removes exposure of previous Cancelled Bookings. In the monthly by deal model, it's hardcoded still - need to change PBI to remove safely. This will be done later on once we remove the Cancelled Bookings models. Adapts the existing tests on KPIs to accommodate for the changes by including new metrics. Also, I've set the detector to 5 (from 8) since it's been a while this has not triggered thus might be worth the effort to have more detection capabilities. # 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: #24637
101 lines
3.5 KiB
SQL
101 lines
3.5 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, up to a certain threshold.
|
|
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, with a certain tolerance,
|
|
than the value reported in the Global dimension.
|
|
*/
|
|
{% set tolerance_threshold = 0.000001 %}
|
|
|
|
{% set additive_metric_names = (
|
|
"Bookings Churn Rate",
|
|
"Cancelled Check Out Bookings",
|
|
"Cancelled Created Bookings",
|
|
"Check-In Hero Revenue",
|
|
"Check Out Bookings (Excl. Cancelled)",
|
|
"Churning Deals",
|
|
"Churning Listings",
|
|
"Created Bookings (Excl. Cancelled)",
|
|
"Damage Host-Waiver Payments",
|
|
"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 Athena Revenue",
|
|
"Invoiced Booking Fees Revenue",
|
|
"Invoiced E-Deposit 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",
|
|
"Revenue Churn Rate",
|
|
"Revenue Retained",
|
|
"Revenue Retained Post-Resolutions",
|
|
"Total Check Out Bookings",
|
|
"Total Created Bookings",
|
|
"Total Revenue",
|
|
"Waiver Revenue",
|
|
"Waiver Retained",
|
|
) %}
|
|
|
|
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 > {{ tolerance_threshold }}
|