data-dwh-dbt-project/models/intermediate/cross/int_mtd_vs_previous_year_metrics.sql
Oriol Roqué Paniagua 83d913f9fc 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
2024-08-20 15:42:27 +00:00

319 lines
14 KiB
SQL

/*
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", "dimension", "dimension_value"]) }}
with
int_core__mtd_booking_metrics as (
select * from {{ ref("int_core__mtd_booking_metrics") }}
),
int_core__mtd_guest_journey_metrics as (
select * from {{ ref("int_core__mtd_guest_journey_metrics") }}
),
int_core__mtd_accommodation_metrics as (
select * from {{ ref("int_core__mtd_accommodation_metrics") }}
),
int_core__mtd_deal_metrics as (
select * from {{ ref("int_core__mtd_deal_metrics") }}
),
int_core__mtd_guest_payments_metrics as (
select * from {{ ref("int_core__mtd_guest_payments_metrics") }}
),
int_xero__mtd_invoicing_metrics as (
select * from {{ ref("int_xero__mtd_invoicing_metrics") }}
),
int_dates_mtd_by_dimension as (select * from {{ ref("int_dates_mtd_by_dimension") }}),
plain_kpi_combination as (
select
d.year,
d.month,
d.day,
d.is_end_of_month,
d.is_current_month,
d.first_day_month,
d.date,
d.dimension,
d.dimension_value,
-- BOOKINGS --
bookings.created_bookings,
bookings.check_out_bookings,
bookings.cancelled_bookings,
bookings.billable_bookings,
-- GUEST JOURNEYS --
guest_journeys.created_guest_journeys,
guest_journeys.started_guest_journeys,
guest_journeys.completed_guest_journeys,
guest_journeys.paid_guest_journeys,
guest_journeys.start_rate_guest_journey,
guest_journeys.completion_rate_guest_journey,
guest_journeys.incompletion_rate_guest_journey,
guest_journeys.payment_rate_guest_journey,
-- DEALS --
deals.new_deals,
deals.never_booked_deals,
deals.first_time_booked_deals,
deals.active_deals,
deals.churning_deals,
deals.inactive_deals,
deals.reactivated_deals,
deals.deals_booked_in_month,
deals.deals_booked_in_6_months,
deals.deals_booked_in_12_months,
-- LISTINGS (ACCOMMODATIONS) --
accommodations.new_listings,
accommodations.never_booked_listings,
accommodations.first_time_booked_listings,
accommodations.active_listings,
accommodations.churning_listings,
accommodations.inactive_listings,
accommodations.reactivated_listings,
accommodations.listings_booked_in_month,
accommodations.listings_booked_in_6_months,
accommodations.listings_booked_in_12_months,
-- HOST (OPERATOR) REVENUE --
invoicing.xero_booking_net_fees_in_gbp,
invoicing.xero_listing_net_fees_in_gbp,
invoicing.xero_verification_net_fees_in_gbp,
invoicing.xero_operator_net_fees_in_gbp,
-- APIs REVENUE --
invoicing.xero_apis_net_fees_in_gbp,
invoicing.xero_e_deposit_net_fees_in_gbp,
invoicing.xero_guesty_net_fees_in_gbp,
-- HOST RESOLUTIONS --
invoicing.xero_host_resolution_amount_paid_in_gbp,
invoicing.xero_host_resolution_payment_count,
-- GUEST REVENUE AND PAYMENTS --
guest_payments.deposit_fees_in_gbp,
guest_payments.waiver_payments_in_gbp,
invoicing.xero_waiver_paid_back_to_host_in_gbp,
nullif(
coalesce(guest_payments.waiver_payments_in_gbp, 0)
+ coalesce(invoicing.xero_waiver_paid_back_to_host_in_gbp, 0),
0
) as waiver_net_fees_in_gbp,
guest_payments.checkin_cover_fees_in_gbp,
guest_payments.total_guest_payments_in_gbp,
nullif(
coalesce(guest_payments.total_guest_payments_in_gbp, 0)
+ coalesce(invoicing.xero_waiver_paid_back_to_host_in_gbp, 0),
0
) as total_guest_revenue_in_gbp,
-- TOTAL REVENUE --
nullif(
coalesce(guest_payments.total_guest_payments_in_gbp, 0)
+ coalesce(invoicing.xero_waiver_paid_back_to_host_in_gbp, 0)
+ coalesce(invoicing.xero_operator_net_fees_in_gbp, 0)
+ coalesce(invoicing.xero_apis_net_fees_in_gbp, 0),
0
) as total_revenue_in_gbp,
-- GUEST REVENUE AND PAYMENTS WEIGHTED METRICS --
guest_payments.total_guest_payments_in_gbp / nullif(
guest_journeys.completed_guest_journeys, 0
) as guest_payments_per_completed_guest_journey,
guest_payments.total_guest_payments_in_gbp / nullif(
guest_journeys.paid_guest_journeys, 0
) as guest_payments_per_paid_guest_journey,
nullif(
coalesce(guest_payments.total_guest_payments_in_gbp, 0)
+ coalesce(invoicing.xero_waiver_paid_back_to_host_in_gbp, 0),
0
) / nullif(
guest_journeys.completed_guest_journeys, 0
) as guest_revenue_per_completed_guest_journey,
nullif(
coalesce(guest_payments.total_guest_payments_in_gbp, 0)
+ coalesce(invoicing.xero_waiver_paid_back_to_host_in_gbp, 0),
0
) / nullif(
guest_journeys.paid_guest_journeys, 0
) as guest_revenue_per_paid_guest_journey,
-- TOTAL REVENUE WEIGHTED METRICS --
(
coalesce(guest_payments.total_guest_payments_in_gbp, 0)
+ coalesce(invoicing.xero_waiver_paid_back_to_host_in_gbp, 0)
+ coalesce(invoicing.xero_operator_net_fees_in_gbp, 0)
+ coalesce(invoicing.xero_apis_net_fees_in_gbp, 0)
)
/ nullif(bookings.created_bookings, 0) as total_revenue_per_created_booking,
(
coalesce(guest_payments.total_guest_payments_in_gbp, 0)
+ coalesce(invoicing.xero_waiver_paid_back_to_host_in_gbp, 0)
+ coalesce(invoicing.xero_operator_net_fees_in_gbp, 0)
+ coalesce(invoicing.xero_apis_net_fees_in_gbp, 0)
) / nullif(
guest_journeys.created_guest_journeys, 0
) as total_revenue_per_created_guest_journey,
(
coalesce(guest_payments.total_guest_payments_in_gbp, 0)
+ coalesce(invoicing.xero_waiver_paid_back_to_host_in_gbp, 0)
+ coalesce(invoicing.xero_operator_net_fees_in_gbp, 0)
+ coalesce(invoicing.xero_apis_net_fees_in_gbp, 0)
) / nullif(
deals.deals_booked_in_month, 0
) as total_revenue_per_deals_booked_in_month,
(
coalesce(guest_payments.total_guest_payments_in_gbp, 0)
+ coalesce(invoicing.xero_waiver_paid_back_to_host_in_gbp, 0)
+ coalesce(invoicing.xero_operator_net_fees_in_gbp, 0)
+ coalesce(invoicing.xero_apis_net_fees_in_gbp, 0)
) / nullif(
accommodations.listings_booked_in_month, 0
) as total_revenue_per_listings_booked_in_month
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
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
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,
current.month,
current.day,
current.is_end_of_month,
current.is_current_month,
current.first_day_month,
current.date,
current.dimension,
current.dimension_value,
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") }},
{{ calculate_safe_relative_increment("billable_bookings") }},
-- GUEST JOURNEYS --
{{ calculate_safe_relative_increment("created_guest_journeys") }},
{{ calculate_safe_relative_increment("started_guest_journeys") }},
{{ calculate_safe_relative_increment("completed_guest_journeys") }},
{{ calculate_safe_relative_increment("paid_guest_journeys") }},
{{ calculate_safe_relative_increment("start_rate_guest_journey") }},
{{ calculate_safe_relative_increment("completion_rate_guest_journey") }},
{{ calculate_safe_relative_increment("incompletion_rate_guest_journey") }},
{{ calculate_safe_relative_increment("payment_rate_guest_journey") }},
-- DEALS --
{{ calculate_safe_relative_increment("new_deals") }},
{{ calculate_safe_relative_increment("never_booked_deals") }},
{{ calculate_safe_relative_increment("first_time_booked_deals") }},
{{ calculate_safe_relative_increment("active_deals") }},
{{ calculate_safe_relative_increment("churning_deals") }},
{{ calculate_safe_relative_increment("inactive_deals") }},
{{ calculate_safe_relative_increment("reactivated_deals") }},
{{ calculate_safe_relative_increment("deals_booked_in_month") }},
{{ calculate_safe_relative_increment("deals_booked_in_6_months") }},
{{ calculate_safe_relative_increment("deals_booked_in_12_months") }},
-- LISTINGS --
{{ calculate_safe_relative_increment("new_listings") }},
{{ calculate_safe_relative_increment("never_booked_listings") }},
{{ calculate_safe_relative_increment("first_time_booked_listings") }},
{{ calculate_safe_relative_increment("active_listings") }},
{{ calculate_safe_relative_increment("churning_listings") }},
{{ calculate_safe_relative_increment("inactive_listings") }},
{{ calculate_safe_relative_increment("reactivated_listings") }},
{{ calculate_safe_relative_increment("listings_booked_in_month") }},
{{ calculate_safe_relative_increment("listings_booked_in_6_months") }},
{{ calculate_safe_relative_increment("listings_booked_in_12_months") }},
-- HOST (OPERATOR) REVENUE --
{{ calculate_safe_relative_increment("xero_booking_net_fees_in_gbp") }},
{{ calculate_safe_relative_increment("xero_listing_net_fees_in_gbp") }},
{{ calculate_safe_relative_increment("xero_verification_net_fees_in_gbp") }},
{{ calculate_safe_relative_increment("xero_operator_net_fees_in_gbp") }},
-- APIs REVENUE --
{{ calculate_safe_relative_increment("xero_apis_net_fees_in_gbp") }},
{{ calculate_safe_relative_increment("xero_e_deposit_net_fees_in_gbp") }},
{{ calculate_safe_relative_increment("xero_guesty_net_fees_in_gbp") }},
-- HOST RESOLUTIONS --
{{ calculate_safe_relative_increment("xero_host_resolution_amount_paid_in_gbp") }},
{{ calculate_safe_relative_increment("xero_host_resolution_payment_count") }},
-- GUEST REVENUE AND PAYMENTS --
{{ calculate_safe_relative_increment("deposit_fees_in_gbp") }},
{{ calculate_safe_relative_increment("waiver_payments_in_gbp") }},
{{ calculate_safe_relative_increment("xero_waiver_paid_back_to_host_in_gbp") }},
{{ calculate_safe_relative_increment("waiver_net_fees_in_gbp") }},
{{ calculate_safe_relative_increment("checkin_cover_fees_in_gbp") }},
{{ calculate_safe_relative_increment("total_guest_payments_in_gbp") }},
{{ calculate_safe_relative_increment("total_guest_revenue_in_gbp") }},
-- TOTAL REVENUE --
{{ calculate_safe_relative_increment("total_revenue_in_gbp") }},
-- GUEST REVENUE AND PAYMENTS WEIGHTED METRICS --
{{
calculate_safe_relative_increment(
"guest_payments_per_completed_guest_journey"
)
}},
{{ calculate_safe_relative_increment("guest_payments_per_paid_guest_journey") }},
{{ calculate_safe_relative_increment("guest_revenue_per_completed_guest_journey") }},
{{ calculate_safe_relative_increment("guest_revenue_per_paid_guest_journey") }},
-- TOTAL REVENUE WEIGHTED METRICS --
{{ calculate_safe_relative_increment("total_revenue_per_created_booking") }},
{{ calculate_safe_relative_increment("total_revenue_per_created_guest_journey") }},
{{ calculate_safe_relative_increment("total_revenue_per_deals_booked_in_month") }},
{{
calculate_safe_relative_increment(
"total_revenue_per_listings_booked_in_month"
)
}}
from plain_kpi_combination current
left join
plain_kpi_combination previous_year
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
(
current.is_end_of_month = 1
or (current.is_current_month = 1 and current.day = previous_year.day)
)