2024-09-05 14:01:58 +00:00
|
|
|
/*
|
|
|
|
|
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
|
2024-12-02 17:00:52 +00:00
|
|
|
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.
|
2024-09-05 14:01:58 +00:00
|
|
|
|
2024-12-02 17:00:52 +00:00
|
|
|
However, the aggregation cannot be higher, with a certain tolerance,
|
|
|
|
|
than the value reported in the Global dimension.
|
2024-09-05 14:01:58 +00:00
|
|
|
*/
|
2024-12-02 17:00:52 +00:00
|
|
|
{% set tolerance_threshold = 0.000001 %}
|
|
|
|
|
|
Merged PR 3124: 1/3 - Revenue renaming Main KPIs - MTD scope
# Description
Adapts revenue figures in Main KPIs - MTD scope or global view. This includes MTD, Monthly Overview, Global Evolution over Time, Detail by Category. In essence, everything that is not by deal.
The changes are mainly 2:
* Remove the line that deducts the `Waiver Amount Paid Back to Hosts` in all metrics except the `Waiver Net Fees`. This effectively means that the previous `Guest Revenue` = `Guest Payments`, thus I dropped all 3 `Guest Payments` metrics.
* Do a renaming at metric display level, but not in the code. This means that I remove the computation of `guest_revenue_in_gbp` for instance and keep `guest_payments_in_gbp`, and apply the renaming later on, since the modelisation already accounts for defining metric names differently from those of the fields. For the rest of metrics, I revised all metrics name and did changes based on the [whiteboard](https://whiteboard.office.com/me/whiteboards/p/c3BvOmh0dHBzOi8vZ3VhcmRob2ctbXkuc2hhcmVwb2ludC5jb20vcGVyc29uYWwvcGFibG9fbWFydGluX3N1cGVyaG9nX2NvbQ%3d%3d/b!T2D3opQuBECSDnhuFZrUacFu3TxvSvdIsnI4Dxsh2IuaB1AigbciRqkqte61I4wz/01H5SI4J4L7HTPJGUT7JGYKTOSQYYWACXU). I also changed the dedicated data tests in Main KPIs to ensure it's working. I also changed the exclusion logic in reporting based on the name of the metric to not display metrics that depend on the invoicing cycle unless it's 2 months ago or before.
To keep in mind:
* Merging this will automatically display the new figures/naming in production. Might be wise to communicate to stakeholders since some key metrics (namely, Guest Revenue / Total Revenue) will change the meaning.
* We also need to do these changes in the metrics by deal part of the computation. I'd do first the removal of these fields in the PBI report (and take the opportunity to change the Data Catalogue) and then do the PR in DWH to change the logic. Before that though let's check that the names included in this PR are the correct ones :)
# Checklist
- [X] The edited models and dependants run properly with production data.
- [NA] 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: #22688
2024-10-10 13:46:59 +00:00
|
|
|
{% 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",
|
2024-10-22 08:08:03 +00:00
|
|
|
"Revenue Churn Rate",
|
|
|
|
|
"Bookings Churn Rate",
|
|
|
|
|
"Listings Churn Rate",
|
Merged PR 3124: 1/3 - Revenue renaming Main KPIs - MTD scope
# Description
Adapts revenue figures in Main KPIs - MTD scope or global view. This includes MTD, Monthly Overview, Global Evolution over Time, Detail by Category. In essence, everything that is not by deal.
The changes are mainly 2:
* Remove the line that deducts the `Waiver Amount Paid Back to Hosts` in all metrics except the `Waiver Net Fees`. This effectively means that the previous `Guest Revenue` = `Guest Payments`, thus I dropped all 3 `Guest Payments` metrics.
* Do a renaming at metric display level, but not in the code. This means that I remove the computation of `guest_revenue_in_gbp` for instance and keep `guest_payments_in_gbp`, and apply the renaming later on, since the modelisation already accounts for defining metric names differently from those of the fields. For the rest of metrics, I revised all metrics name and did changes based on the [whiteboard](https://whiteboard.office.com/me/whiteboards/p/c3BvOmh0dHBzOi8vZ3VhcmRob2ctbXkuc2hhcmVwb2ludC5jb20vcGVyc29uYWwvcGFibG9fbWFydGluX3N1cGVyaG9nX2NvbQ%3d%3d/b!T2D3opQuBECSDnhuFZrUacFu3TxvSvdIsnI4Dxsh2IuaB1AigbciRqkqte61I4wz/01H5SI4J4L7HTPJGUT7JGYKTOSQYYWACXU). I also changed the dedicated data tests in Main KPIs to ensure it's working. I also changed the exclusion logic in reporting based on the name of the metric to not display metrics that depend on the invoicing cycle unless it's 2 months ago or before.
To keep in mind:
* Merging this will automatically display the new figures/naming in production. Might be wise to communicate to stakeholders since some key metrics (namely, Guest Revenue / Total Revenue) will change the meaning.
* We also need to do these changes in the metrics by deal part of the computation. I'd do first the removal of these fields in the PBI report (and take the opportunity to change the Data Catalogue) and then do the PR in DWH to change the logic. Before that though let's check that the names included in this PR are the correct ones :)
# Checklist
- [X] The edited models and dependants run properly with production data.
- [NA] 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: #22688
2024-10-10 13:46:59 +00:00
|
|
|
) %}
|
2024-09-05 14:01:58 +00:00
|
|
|
|
|
|
|
|
with
|
Merged PR 3124: 1/3 - Revenue renaming Main KPIs - MTD scope
# Description
Adapts revenue figures in Main KPIs - MTD scope or global view. This includes MTD, Monthly Overview, Global Evolution over Time, Detail by Category. In essence, everything that is not by deal.
The changes are mainly 2:
* Remove the line that deducts the `Waiver Amount Paid Back to Hosts` in all metrics except the `Waiver Net Fees`. This effectively means that the previous `Guest Revenue` = `Guest Payments`, thus I dropped all 3 `Guest Payments` metrics.
* Do a renaming at metric display level, but not in the code. This means that I remove the computation of `guest_revenue_in_gbp` for instance and keep `guest_payments_in_gbp`, and apply the renaming later on, since the modelisation already accounts for defining metric names differently from those of the fields. For the rest of metrics, I revised all metrics name and did changes based on the [whiteboard](https://whiteboard.office.com/me/whiteboards/p/c3BvOmh0dHBzOi8vZ3VhcmRob2ctbXkuc2hhcmVwb2ludC5jb20vcGVyc29uYWwvcGFibG9fbWFydGluX3N1cGVyaG9nX2NvbQ%3d%3d/b!T2D3opQuBECSDnhuFZrUacFu3TxvSvdIsnI4Dxsh2IuaB1AigbciRqkqte61I4wz/01H5SI4J4L7HTPJGUT7JGYKTOSQYYWACXU). I also changed the dedicated data tests in Main KPIs to ensure it's working. I also changed the exclusion logic in reporting based on the name of the metric to not display metrics that depend on the invoicing cycle unless it's 2 months ago or before.
To keep in mind:
* Merging this will automatically display the new figures/naming in production. Might be wise to communicate to stakeholders since some key metrics (namely, Guest Revenue / Total Revenue) will change the meaning.
* We also need to do these changes in the metrics by deal part of the computation. I'd do first the removal of these fields in the PBI report (and take the opportunity to change the Data Catalogue) and then do the PR in DWH to change the logic. Before that though let's check that the names included in this PR are the correct ones :)
# Checklist
- [X] The edited models and dependants run properly with production data.
- [NA] 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: #22688
2024-10-10 13:46:59 +00:00
|
|
|
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 *
|
2024-09-05 14:01:58 +00:00
|
|
|
from difference_computation
|
2024-12-02 17:00:52 +00:00
|
|
|
where abs_diff > {{ tolerance_threshold }}
|