105 lines
2.9 KiB
MySQL
105 lines
2.9 KiB
MySQL
|
|
/*
|
||
|
|
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 Amount Paid by Guests',
|
||
|
|
'Checkout Bookings',
|
||
|
|
'Churning Deals',
|
||
|
|
'Churning Listings',
|
||
|
|
'Created Bookings',
|
||
|
|
'Deals Booked in 12 Months',
|
||
|
|
'Deals Booked in 6 Months',
|
||
|
|
'Deals Booked in Month',
|
||
|
|
'Deposit Fees',
|
||
|
|
'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 Payments',
|
||
|
|
'Guest Revenue',
|
||
|
|
'Host Resolutions Amount Paid',
|
||
|
|
'Host Resolutions Payment Count',
|
||
|
|
'Invoiced APIs Revenue',
|
||
|
|
'Invoiced Booking Fees',
|
||
|
|
'Invoiced E-Deposit Fees',
|
||
|
|
'Invoiced Guesty Fees',
|
||
|
|
'Invoiced Listing Fees',
|
||
|
|
'Invoiced Operator Revenue',
|
||
|
|
'Invoiced Verification Fees',
|
||
|
|
'Listings Booked in 12 Months',
|
||
|
|
'Listings Booked in 6 Months',
|
||
|
|
'Listings Booked in Month',
|
||
|
|
'New Deals',
|
||
|
|
'New Listings',
|
||
|
|
'Total Revenue',
|
||
|
|
'Waiver Amount Paid back to Hosts',
|
||
|
|
'Waiver Amount Paid by Guests',
|
||
|
|
'Waiver Net Fees')
|
||
|
|
%}
|
||
|
|
|
||
|
|
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
|