Merged PR 2232: KPI refactor - 1st step, bookings
First step on refactor of kpis: - Remove relative incremental vs. previous year computation from the source model (`mtd_booking_metrics`, in this case) - Aggregate the source mtd global metrics models into a single model: `int_mtd_vs_previous_year_metrics` (to enable multi-source weighted metric computation) and compute previous year value and relative increment. Now this logic is encapsulated into a macro `calculate_safe_relative_increment`, easing readability and providing a bit more robustness. - End-to-end continuity to not break the existing dashboard display in `int_core__mtd_aggregated_metrics` This is a substep of the global change. All info can be found in the documentation [here](https://www.notion.so/knowyourguest-superhog/Refactoring-Business-KPIs-5deb6aadddb34884ae90339402ac16e3) Related work items: #18202
This commit is contained in:
parent
62ad19ea9e
commit
409ac47591
5 changed files with 101 additions and 46 deletions
14
macros/calculate_safe_relative_increment.sql
Normal file
14
macros/calculate_safe_relative_increment.sql
Normal file
|
|
@ -0,0 +1,14 @@
|
|||
/*
|
||||
This macro displays a metric value common in two sources, current and previous,
|
||||
and computes the relative increment of current vs. previous.
|
||||
|
||||
It's designed to be placed within a SELECT statement.
|
||||
|
||||
It ensure safe divide by zero division by applying a nullif function.
|
||||
|
||||
*/
|
||||
{% macro calculate_safe_relative_increment(metric, current='current', previous='previous_year') %}
|
||||
{{ current }}.{{ metric }},
|
||||
{{ previous }}.{{ metric }} as {{ previous }}_{{ metric }},
|
||||
cast({{ current }}.{{ metric }} as decimal) / nullif({{ previous }}.{{ metric }},0) - 1 as relative_increment_{{ metric }}
|
||||
{% endmacro %}
|
||||
|
|
@ -1,6 +1,6 @@
|
|||
{% set metrics = [
|
||||
{
|
||||
"source": "int_core__mtd_booking_metrics",
|
||||
"source": "int_mtd_vs_previous_year_metrics",
|
||||
"order_by": 1,
|
||||
"metric": "Created Bookings",
|
||||
"value": "created_bookings",
|
||||
|
|
@ -9,7 +9,7 @@
|
|||
"number_format": "integer",
|
||||
},
|
||||
{
|
||||
"source": "int_core__mtd_booking_metrics",
|
||||
"source": "int_mtd_vs_previous_year_metrics",
|
||||
"order_by": 2,
|
||||
"metric": "Cancelled Bookings",
|
||||
"value": "cancelled_bookings",
|
||||
|
|
@ -18,7 +18,7 @@
|
|||
"number_format": "integer",
|
||||
},
|
||||
{
|
||||
"source": "int_core__mtd_booking_metrics",
|
||||
"source": "int_mtd_vs_previous_year_metrics",
|
||||
"order_by": 3,
|
||||
"metric": "Checkout Bookings",
|
||||
"value": "check_out_bookings",
|
||||
|
|
@ -190,8 +190,8 @@
|
|||
},
|
||||
] %}
|
||||
with
|
||||
int_core__mtd_booking_metrics as (
|
||||
select * from {{ ref("int_core__mtd_booking_metrics") }}
|
||||
int_mtd_vs_previous_year_metrics as (
|
||||
select * from {{ ref("int_mtd_vs_previous_year_metrics") }}
|
||||
),
|
||||
int_core__mtd_guest_journey_metrics as (
|
||||
select * from {{ ref("int_core__mtd_guest_journey_metrics") }}
|
||||
|
|
|
|||
|
|
@ -41,10 +41,9 @@ with
|
|||
and extract(day from b.updated_date_utc) <= d.day
|
||||
and upper(b.booking_state) = {{ var("cancelled_booking_state") }}
|
||||
group by 1
|
||||
),
|
||||
main_kpi as (
|
||||
-- Final aggregation of subqueries --
|
||||
select
|
||||
)
|
||||
-- Final aggregation of subqueries --
|
||||
select
|
||||
d.year,
|
||||
d.month,
|
||||
d.day,
|
||||
|
|
@ -54,33 +53,7 @@ with
|
|||
crym.created_bookings,
|
||||
coym.check_out_bookings,
|
||||
caym.cancelled_bookings
|
||||
from int_dates_mtd d
|
||||
left join created_year_month crym on crym.date = d.date
|
||||
left join check_out_year_month coym on coym.date = d.date
|
||||
left join cancelled_year_month caym on caym.date = d.date
|
||||
)
|
||||
-- Pivoting to get previous year for each line & computing relative increment
|
||||
-- (rel_incr) --
|
||||
select
|
||||
a.year,
|
||||
a.month,
|
||||
a.day,
|
||||
a.is_end_of_month,
|
||||
a.is_current_month,
|
||||
a.date,
|
||||
b.date as previous_year_date,
|
||||
a.created_bookings,
|
||||
b.created_bookings as previous_year_created_bookings,
|
||||
cast(a.created_bookings as decimal) / b.created_bookings
|
||||
- 1 as relative_increment_created_bookings,
|
||||
a.check_out_bookings,
|
||||
b.check_out_bookings as previous_year_check_out_bookings,
|
||||
cast(a.check_out_bookings as decimal) / b.check_out_bookings
|
||||
- 1 as relative_increment_check_out_bookings,
|
||||
a.cancelled_bookings,
|
||||
b.cancelled_bookings as previous_year_cancelled_bookings,
|
||||
cast(a.cancelled_bookings as decimal) / b.cancelled_bookings
|
||||
- 1 as relative_increment_cancelled_bookings
|
||||
from main_kpi a
|
||||
left join main_kpi b on a.month = b.month and a.year = b.year + 1
|
||||
where (a.is_end_of_month = 1 or (a.is_current_month = 1 and a.day = b.day))
|
||||
from int_dates_mtd d
|
||||
left join created_year_month crym on crym.date = d.date
|
||||
left join check_out_year_month coym on coym.date = d.date
|
||||
left join cancelled_year_month caym on caym.date = d.date
|
||||
|
|
|
|||
|
|
@ -0,0 +1,50 @@
|
|||
/*
|
||||
This model pivots the data of the different mtd metrics models to get
|
||||
previous year for each line & computing relative increment. --
|
||||
*/
|
||||
|
||||
{{ config(materialized="table", unique_key="date") }}
|
||||
with
|
||||
int_core__mtd_booking_metrics as (
|
||||
select * from {{ ref("int_core__mtd_booking_metrics") }}
|
||||
),
|
||||
int_dates_mtd as (select * from {{ ref("int_dates_mtd") }}),
|
||||
|
||||
plain_kpi_combination as (
|
||||
select
|
||||
d.year,
|
||||
d.month,
|
||||
d.day,
|
||||
d.is_end_of_month,
|
||||
d.is_current_month,
|
||||
d.date,
|
||||
bookings.created_bookings,
|
||||
bookings.check_out_bookings,
|
||||
bookings.cancelled_bookings
|
||||
from int_dates_mtd d
|
||||
left join int_core__mtd_booking_metrics bookings
|
||||
on d.date = bookings.date
|
||||
)
|
||||
select
|
||||
current.year,
|
||||
current.month,
|
||||
current.day,
|
||||
current.is_end_of_month,
|
||||
current.is_current_month,
|
||||
current.date,
|
||||
previous_year.date as previous_year_date,
|
||||
|
||||
-- BOOKINGS --
|
||||
{{ calculate_safe_relative_increment('created_bookings') }},
|
||||
{{ calculate_safe_relative_increment('check_out_bookings') }},
|
||||
{{ calculate_safe_relative_increment('cancelled_bookings') }}
|
||||
|
||||
from plain_kpi_combination current
|
||||
left join plain_kpi_combination previous_year
|
||||
on current.month = previous_year.month
|
||||
and current.year = previous_year.year + 1
|
||||
where
|
||||
(
|
||||
current.is_end_of_month = 1
|
||||
or (current.is_current_month = 1 and current.day = previous_year.day)
|
||||
)
|
||||
|
|
@ -146,6 +146,24 @@ models:
|
|||
- not_null
|
||||
- unique
|
||||
|
||||
- name: int_mtd_vs_previous_year_metrics
|
||||
description: |
|
||||
This model is used for global KPIs.
|
||||
|
||||
It aggregates all the mtd models with the different metrics per source
|
||||
and computes any necessary weighted metric across different sources.
|
||||
Finally, it displays any metric on the current date, the previous year
|
||||
date and it computes the relative increment by using the macro:
|
||||
- calculate_safe_relative_increment
|
||||
|
||||
columns:
|
||||
- name: date
|
||||
data_type: date
|
||||
description: The date for the month-to-date metrics.
|
||||
tests:
|
||||
- not_null
|
||||
- unique
|
||||
|
||||
- name: int_monthly_guest_revenue_history_by_deal
|
||||
description: |
|
||||
This model contains the historic information regarding the guest revenue for each deal id.
|
||||
|
|
|
|||
Loading…
Add table
Add a link
Reference in a new issue