diff --git a/models/intermediate/cross/int_monthly_aggregated_metrics_history_by_deal.sql b/models/intermediate/cross/int_monthly_aggregated_metrics_history_by_deal.sql index ed65b86..9d58ab5 100644 --- a/models/intermediate/cross/int_monthly_aggregated_metrics_history_by_deal.sql +++ b/models/intermediate/cross/int_monthly_aggregated_metrics_history_by_deal.sql @@ -8,7 +8,8 @@ with int_core__mtd_deal_lifecycle as (select * from {{ ref("int_core__mtd_deal_lifecycle") }}), int_core__monthly_guest_journey_history_by_deal as (select * from {{ ref("int_core__monthly_guest_journey_history_by_deal") }}), int_core__monthly_accommodation_history_by_deal as (select * from {{ ref("int_core__monthly_accommodation_history_by_deal") }}), - int_core__monthly_booking_history_by_deal as (select * from {{ ref("int_core__monthly_booking_history_by_deal") }}) + int_core__monthly_booking_history_by_deal as (select * from {{ ref("int_core__monthly_booking_history_by_deal") }}), + int_monthly_guest_revenue_history_by_deal as (select * from {{ ref("int_monthly_guest_revenue_history_by_deal") }}) select d.year, @@ -26,12 +27,19 @@ select gj.start_rate_guest_journey, gj.completion_rate_guest_journey, gj.incompletion_rate_guest_journey, + gj.paid_guest_journeys, a.new_listings, a.first_time_booked_listings, a.churning_listings, a.listings_booked_in_month, a.listings_booked_in_6_months, - a.listings_booked_in_12_months + a.listings_booked_in_12_months, + gr.total_guest_payments_in_gbp, + gr.total_guest_revenue_in_gbp, + gr.total_guest_payments_in_gbp/nullif(gj.completed_guest_journeys,0) as guest_payments_per_completed_guest_journey, + gr.total_guest_payments_in_gbp/nullif(gj.paid_guest_journeys,0) as guest_payments_per_paid_guest_journey, + gr.total_guest_revenue_in_gbp/nullif(gj.completed_guest_journeys,0) as guest_revenue_per_completed_guest_journey, + gr.total_guest_revenue_in_gbp/nullif(gj.paid_guest_journeys,0) as guest_revenue_per_paid_guest_journey from int_dates_by_deal d left join int_core__mtd_deal_lifecycle l on d.date = l.date @@ -45,5 +53,8 @@ left join int_core__monthly_guest_journey_history_by_deal gj left join int_core__monthly_accommodation_history_by_deal a on d.date = a.date and d.id_deal = a.id_deal +left join int_monthly_guest_revenue_history_by_deal gr + on d.date = gr.date + and d.id_deal = gr.id_deal diff --git a/models/intermediate/cross/int_mtd_guest_revenue_metrics.sql b/models/intermediate/cross/int_mtd_guest_revenue_metrics.sql index 1e4b1b8..cb4090b 100644 --- a/models/intermediate/cross/int_mtd_guest_revenue_metrics.sql +++ b/models/intermediate/cross/int_mtd_guest_revenue_metrics.sql @@ -8,7 +8,9 @@ This model provides Month-To-Date (MTD) based on Guest Revenue metrics. {{ config(materialized="table", unique_key="date") }} with - int_core__verification_payments as (select * from {{ ref("int_core__verification_payments") }}), + int_core__verification_payments as ( + select * from {{ ref("int_core__verification_payments") }} + ), int_xero__credit_note_line_items as ( select * from {{ ref("int_xero__credit_note_line_items") }} ), @@ -17,77 +19,61 @@ with -- Paid Guest Revenue MTD -- guest_payments_year_month as ( - select - d.date, + select + d.date, sum(vp.amount_in_gbp) as total_guest_payments_in_gbp, - sum(case - when upper(vp.verification_payment_type) in {{ revenue_verification_payment_type_items }} - then vp.amount_in_gbp - else null + sum( + case + when + upper(vp.verification_payment_type) + in {{ revenue_verification_payment_type_items }} + then vp.amount_in_gbp + else null end - ) as total_guest_income_in_gbp + ) as total_guest_income_in_gbp from int_dates_mtd d - inner join int_core__verification_payments vp + inner join + int_core__verification_payments vp on extract(year from vp.payment_paid_date_utc) = d.year and extract(month from vp.payment_paid_date_utc) = d.month and extract(day from vp.payment_paid_date_utc) <= d.day - where upper(vp.payment_status) = {{ var("paid_payment_state")}} + where upper(vp.payment_status) = {{ var("paid_payment_state") }} group by 1 ), -- Waiver Credit Notes MTD -- -- We need to get the credited waivers for those -- host-takes-waiver cases waiver_credit_notes as ( - select - d.date, - sum(cnli.line_amount_wo_taxes_in_gbp) as waiver_fees_credited + select d.date, sum(cnli.line_amount_wo_taxes_in_gbp) as waiver_fees_credited from int_dates_mtd d - inner join int_xero__credit_notes cn + inner join + int_xero__credit_notes cn on extract(year from cn.credit_note_issued_date_utc) = d.year and extract(month from cn.credit_note_issued_date_utc) = d.month - and extract(day from cn.credit_note_issued_date_utc) <= d.day - inner join int_xero__credit_note_line_items cnli - on cn.id_credit_note = cnli.id_credit_note - where upper(cn.credit_note_status) in {{ relevant_document_statuses }} + and extract(day from cn.credit_note_issued_date_utc) <= d.day + inner join + int_xero__credit_note_line_items cnli + on cn.id_credit_note = cnli.id_credit_note + where + upper(cn.credit_note_status) in {{ relevant_document_statuses }} and upper(cnli.item_code) in {{ waiver_items }} group by 1 - ), - main_kpi as ( - -- Final aggregation of subqueries -- - select - d.year, - d.month, - d.day, - d.date, - d.is_end_of_month, - d.is_current_month, - nullif(gpym.total_guest_payments_in_gbp,0) as total_guest_payments_in_gbp, - -- Deduct from total guest income the host-takes-waiver income - nullif( - coalesce(gpym.total_guest_income_in_gbp,0) - coalesce(wcn.waiver_fees_credited,0) - ,0) as total_guest_revenue_in_gbp - from int_dates_mtd d - left join guest_payments_year_month gpym on gpym.date = d.date - left join waiver_credit_notes wcn on wcn.date = d.date ) --- Pivoting to get previous year for each line & computing relative increment --- (rel_incr) -- +-- Final aggregation of subqueries -- 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.total_guest_payments_in_gbp, - b.total_guest_payments_in_gbp as previous_year_total_guest_payments_in_gbp, - cast(a.total_guest_payments_in_gbp as decimal) / b.total_guest_payments_in_gbp - - 1 as relative_increment_total_guest_payments_in_gbp, - a.total_guest_revenue_in_gbp, - b.total_guest_revenue_in_gbp as previous_year_total_guest_revenue_in_gbp, - cast(a.total_guest_revenue_in_gbp as decimal) / b.total_guest_revenue_in_gbp - - 1 as relative_increment_total_guest_revenue_in_gbp -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)) + d.year, + d.month, + d.day, + d.date, + d.is_end_of_month, + d.is_current_month, + nullif(gpym.total_guest_payments_in_gbp, 0) as total_guest_payments_in_gbp, + -- Deduct from total guest income the host-takes-waiver income + nullif( + coalesce(gpym.total_guest_income_in_gbp, 0) + - coalesce(wcn.waiver_fees_credited, 0), + 0 + ) as total_guest_revenue_in_gbp +from int_dates_mtd d +left join guest_payments_year_month gpym on gpym.date = d.date +left join waiver_credit_notes wcn on wcn.date = d.date diff --git a/models/intermediate/cross/int_mtd_vs_previous_year_metrics.sql b/models/intermediate/cross/int_mtd_vs_previous_year_metrics.sql index 854b0d2..aa0a24d 100644 --- a/models/intermediate/cross/int_mtd_vs_previous_year_metrics.sql +++ b/models/intermediate/cross/int_mtd_vs_previous_year_metrics.sql @@ -2,7 +2,6 @@ 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 ( @@ -17,6 +16,9 @@ with 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 ( @@ -65,17 +67,37 @@ with accommodations.reactivated_listings, accommodations.listings_booked_in_month, accommodations.listings_booked_in_6_months, - accommodations.listings_booked_in_12_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 + 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 + 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_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, @@ -87,46 +109,57 @@ select 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("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') }}, + {{ 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') }}, + {{ 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') }} + {{ 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 +left join + plain_kpi_combination previous_year on current.month = previous_year.month and current.year = previous_year.year + 1 where