Merged PR 2607: Propagates and exposes multiple dimension handling for KPIs

# Description

This PR ensures the propagation of the dimensions for KPIs across the key aggregating and exposing models. Additionally, provides these 2 new fields in reporting while **not affecting the current data display**, thus it's safe to work in the PBI report without needing to work in 2 PRs in parallel.

**Changes:**

**1 - Intermediate, `int_mtd_vs_previous_year_metrics`:**

* Removes the temporary filter on `where dimension in ({{ production_dimensions }})`. This will be applied directly to reporting later. This ensures that the new dimension on customer segmentation is fully available only within intermediate.
* Adds `dimension` and `dimension_value` granularity. This includes: 1) adding these fields, 2) joining by these fields with all the source CTEs containing the source models with metrics - which in turn needs the change of the dates model - and 3) joining by these fields in the self-join to compute the incremental vs. previous year.
* Changes on the schema file

**2 - Intermediate, `int_mtd_aggregated_metrics`:**

* Adds `dimension` and `dimension_value` granularity. This includes only adding these fields.
* Changes on the schema file

**3 - Reporting, `mtd_aggregated_metrics`:**

* Adds the filter removed on `int_mtd_vs_previous_year_metrics`. This ensures that only the Global dimension is available for the reporting, thus **no changes from user POV**.
* Adds `dimension` and `dimension_value` granularity. This includes only adding these fields
* Changes on the schema file

# 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: #19325
This commit is contained in:
Oriol Roqué Paniagua 2024-08-20 15:42:27 +00:00
parent d65675fe03
commit 83d913f9fc
5 changed files with 103 additions and 18 deletions

View file

@ -3,35 +3,27 @@ This model pivots the data of the different mtd metrics models to get
previous year for each line & computing relative increment. --
*/
{% set production_dimensions = get_kpi_dimensions_for_production() %}
{{ config(materialized="table", unique_key="date") }}
{{ config(materialized="table", unique_key=["date", "dimension", "dimension_value"]) }}
with
int_core__mtd_booking_metrics as (
select * from {{ ref("int_core__mtd_booking_metrics") }}
where dimension in ({{ production_dimensions }})
),
int_core__mtd_guest_journey_metrics as (
select * from {{ ref("int_core__mtd_guest_journey_metrics") }}
where dimension in ({{ production_dimensions }})
),
int_core__mtd_accommodation_metrics as (
select * from {{ ref("int_core__mtd_accommodation_metrics") }}
where dimension in ({{ production_dimensions }})
),
int_core__mtd_deal_metrics as (
select * from {{ ref("int_core__mtd_deal_metrics") }}
where dimension in ({{ production_dimensions }})
),
int_core__mtd_guest_payments_metrics as (
select * from {{ ref("int_core__mtd_guest_payments_metrics") }}
where dimension in ({{ production_dimensions }})
),
int_xero__mtd_invoicing_metrics as (
select * from {{ ref("int_xero__mtd_invoicing_metrics") }}
where dimension in ({{ production_dimensions }})
),
int_dates_mtd as (select * from {{ ref("int_dates_mtd") }}),
int_dates_mtd_by_dimension as (select * from {{ ref("int_dates_mtd_by_dimension") }}),
plain_kpi_combination as (
@ -43,6 +35,8 @@ with
d.is_current_month,
d.first_day_month,
d.date,
d.dimension,
d.dimension_value,
-- BOOKINGS --
bookings.created_bookings,
@ -180,18 +174,37 @@ with
accommodations.listings_booked_in_month, 0
) as total_revenue_per_listings_booked_in_month
from int_dates_mtd d
left join int_core__mtd_booking_metrics bookings on d.date = bookings.date
from int_dates_mtd_by_dimension d
left join
int_core__mtd_booking_metrics bookings
on d.date = bookings.date
and d.dimension = bookings.dimension
and d.dimension_value = bookings.dimension_value
left join
int_core__mtd_guest_journey_metrics guest_journeys
on d.date = guest_journeys.date
and d.dimension = guest_journeys.dimension
and d.dimension_value = guest_journeys.dimension_value
left join
int_core__mtd_accommodation_metrics accommodations
on d.date = accommodations.date
left join int_core__mtd_deal_metrics deals on d.date = deals.date
and d.dimension = accommodations.dimension
and d.dimension_value = accommodations.dimension_value
left join
int_core__mtd_deal_metrics deals
on d.date = deals.date
and d.dimension = deals.dimension
and d.dimension_value = deals.dimension_value
left join
int_core__mtd_guest_payments_metrics guest_payments on d.date = guest_payments.date
left join int_xero__mtd_invoicing_metrics invoicing on d.date = invoicing.date
int_core__mtd_guest_payments_metrics guest_payments
on d.date = guest_payments.date
and d.dimension = guest_payments.dimension
and d.dimension_value = guest_payments.dimension_value
left join
int_xero__mtd_invoicing_metrics invoicing
on d.date = invoicing.date
and d.dimension = invoicing.dimension
and d.dimension_value = invoicing.dimension_value
)
select
current.year,
@ -201,6 +214,8 @@ select
current.is_current_month,
current.first_day_month,
current.date,
current.dimension,
current.dimension_value,
previous_year.date as previous_year_date,
-- BOOKINGS --
@ -293,7 +308,9 @@ select
from plain_kpi_combination current
left join
plain_kpi_combination previous_year
on current.month = previous_year.month
on current.dimension = previous_year.dimension
and current.dimension_value = previous_year.dimension_value
and current.month = previous_year.month
and current.year = previous_year.year + 1
where
(