This PR aims to propagate the computation of guest revenue model into the aggregated models. Changes: - I changed the logic on `int_mtd_guest_revenue_metrics` since it was still using the old computation of the relative increment within the same model. Basically, I removed it (last part of the query). The rest of changes in this model are just formatting. - I also applied the formatting in the int_mtd_vs_previous_year_metrics, mainly changing the macro calls from **'**xyz**'** to **"**xyz**"**. What's new: - `int_mtd_guest_revenue_metrics` into `int_mtd_vs_previous_year_metrics`, by adding `total_guest_revenue_in_gbp` and `total_guest_payments_in_gbp`. Additionally, with the new logic, for the first time we're able to compute **weighted metrics** coming from different sources. Specifically, it computes the weighted measures per guest journey completed and guest journey with payment. - Similar behavior on the 'by deal', adding `int_monthly_guest_revenue_history_by_deal` into `int_monthly_aggregated_metrics` and similar computation This model does not affect the exposing logic still, meaning these metrics won't be exposed in the report. This will come in a separated PR. Related work items: #18107
169 lines
7.1 KiB
SQL
169 lines
7.1 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") }}
|
|
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_mtd_guest_revenue_metrics as (
|
|
select * from {{ ref("int_mtd_guest_revenue_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 --
|
|
bookings.created_bookings,
|
|
bookings.check_out_bookings,
|
|
bookings.cancelled_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,
|
|
|
|
-- GUEST REVENUE AND PAYMENTS --
|
|
guest_revenue.total_guest_payments_in_gbp,
|
|
guest_revenue.total_guest_revenue_in_gbp,
|
|
|
|
-- WEIGHTED METRICS
|
|
guest_revenue.total_guest_payments_in_gbp / nullif(
|
|
guest_journeys.completed_guest_journeys, 0
|
|
) as guest_payments_per_completed_guest_journey,
|
|
guest_revenue.total_guest_payments_in_gbp / nullif(
|
|
guest_journeys.paid_guest_journeys, 0
|
|
) as guest_payments_per_paid_guest_journey,
|
|
guest_revenue.total_guest_revenue_in_gbp / nullif(
|
|
guest_journeys.completed_guest_journeys, 0
|
|
) as guest_revenue_per_completed_guest_journey,
|
|
guest_revenue.total_guest_revenue_in_gbp / nullif(
|
|
guest_journeys.paid_guest_journeys, 0
|
|
) as guest_revenue_per_paid_guest_journey
|
|
|
|
from int_dates_mtd d
|
|
left join int_core__mtd_booking_metrics bookings on d.date = bookings.date
|
|
left join
|
|
int_core__mtd_guest_journey_metrics guest_journeys
|
|
on d.date = guest_journeys.date
|
|
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
|
|
left join
|
|
int_mtd_guest_revenue_metrics guest_revenue on d.date = guest_revenue.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") }},
|
|
|
|
-- 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") }},
|
|
|
|
-- GUEST REVENUE AND PAYMENTS --
|
|
{{ calculate_safe_relative_increment("total_guest_payments_in_gbp") }},
|
|
{{ calculate_safe_relative_increment("total_guest_revenue_in_gbp") }},
|
|
|
|
-- 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") }}
|
|
|
|
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)
|
|
)
|