data-dwh-dbt-project/models/intermediate/cross/int_mtd_vs_previous_year_metrics.sql

170 lines
7.1 KiB
MySQL
Raw Normal View History

/*
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)
)