# Description It adds 2 new metrics in Main KPIs, both for Global/per Dimension and By Deal. If merged, metrics will NOT appear automatically in the Global/per Dimension nor in the By Deal. These two new metrics are: * Income Retained: Total Revenue - Waiver Paid Back to Host * Income Retained Post Resolutions: Total Revenue - Waiver Paid Back to Host - Host Resolutions Amount Paid Why these are important:  Even though we grow considerably in terms of Revenue, the gap of Waivers that we pay back to host is also increasing. Thus the "real" increment is actually lower. However, what I find more interesting is the heavy decrease in Income Retained Post Resolutions. Here's the Year-by-Year comparison:  In November 2024, we're back to the figures of 2023 (-0.4%) and this should be alarming considering we're growing in Total Revenue by 27% and in Retained Income by 41% vs. Nov 23. In terms of business impact, I'd opt for having these 2 metrics computed as these capture a reality that otherwise we keep hidden. Happy to discuss renames and how/if we move forward with this. # 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. Attached working excel with the extraction [20241227_retained_revenue_global.xlsx](https://guardhog.visualstudio.com/4148d95f-4b6d-4205-bcff-e9c8e0d2ca65/_apis/git/repositories/54ac356f-aad7-46d2-b62c-e8c5b3bb8ebf/pullRequests/3906/attachments/20241227_retained_revenue_global.xlsx) Related work items: #25804
534 lines
22 KiB
SQL
534 lines
22 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
|
|
created_bookings as (
|
|
select *
|
|
from {{ ref("int_kpis__agg_mtd_created_bookings") }}
|
|
where
|
|
dimension in ('global', 'by_number_of_listings', 'by_billing_country')
|
|
and dimension_value <> 'UNSET'
|
|
union all
|
|
select *
|
|
from {{ ref("int_kpis__agg_monthly_created_bookings") }}
|
|
where
|
|
dimension in ('global', 'by_number_of_listings', 'by_billing_country')
|
|
and dimension_value <> 'UNSET'
|
|
),
|
|
check_out_bookings as (
|
|
select *
|
|
from {{ ref("int_kpis__agg_mtd_check_out_bookings") }}
|
|
where
|
|
dimension in ('global', 'by_number_of_listings', 'by_billing_country')
|
|
and dimension_value <> 'UNSET'
|
|
union all
|
|
select *
|
|
from {{ ref("int_kpis__agg_monthly_check_out_bookings") }}
|
|
where
|
|
dimension in ('global', 'by_number_of_listings', 'by_billing_country')
|
|
and dimension_value <> 'UNSET'
|
|
),
|
|
cancelled_bookings as (
|
|
select *
|
|
from {{ ref("int_kpis__agg_mtd_cancelled_bookings") }}
|
|
where
|
|
dimension in ('global', 'by_number_of_listings', 'by_billing_country')
|
|
and dimension_value <> 'UNSET'
|
|
union all
|
|
select *
|
|
from {{ ref("int_kpis__agg_monthly_cancelled_bookings") }}
|
|
where
|
|
dimension in ('global', 'by_number_of_listings', 'by_billing_country')
|
|
and dimension_value <> 'UNSET'
|
|
),
|
|
billable_bookings as (
|
|
select *
|
|
from {{ ref("int_kpis__agg_mtd_billable_bookings") }}
|
|
where
|
|
dimension in ('global', 'by_number_of_listings', 'by_billing_country')
|
|
and dimension_value <> 'UNSET'
|
|
union all
|
|
select *
|
|
from {{ ref("int_kpis__agg_monthly_billable_bookings") }}
|
|
where
|
|
dimension in ('global', 'by_number_of_listings', 'by_billing_country')
|
|
and dimension_value <> 'UNSET'
|
|
),
|
|
created_guest_journeys as (
|
|
select *
|
|
from {{ ref("int_kpis__agg_mtd_created_guest_journeys") }}
|
|
where
|
|
dimension in ('global', 'by_number_of_listings', 'by_billing_country')
|
|
and dimension_value <> 'UNSET'
|
|
union all
|
|
select *
|
|
from {{ ref("int_kpis__agg_monthly_created_guest_journeys") }}
|
|
where
|
|
dimension in ('global', 'by_number_of_listings', 'by_billing_country')
|
|
and dimension_value <> 'UNSET'
|
|
),
|
|
started_guest_journeys as (
|
|
select *
|
|
from {{ ref("int_kpis__agg_mtd_started_guest_journeys") }}
|
|
where
|
|
dimension in ('global', 'by_number_of_listings', 'by_billing_country')
|
|
and dimension_value <> 'UNSET'
|
|
union all
|
|
select *
|
|
from {{ ref("int_kpis__agg_monthly_started_guest_journeys") }}
|
|
where
|
|
dimension in ('global', 'by_number_of_listings', 'by_billing_country')
|
|
and dimension_value <> 'UNSET'
|
|
),
|
|
completed_guest_journeys as (
|
|
select *
|
|
from {{ ref("int_kpis__agg_mtd_completed_guest_journeys") }}
|
|
where
|
|
dimension in ('global', 'by_number_of_listings', 'by_billing_country')
|
|
and dimension_value <> 'UNSET'
|
|
union all
|
|
select *
|
|
from {{ ref("int_kpis__agg_monthly_completed_guest_journeys") }}
|
|
where
|
|
dimension in ('global', 'by_number_of_listings', 'by_billing_country')
|
|
and dimension_value <> 'UNSET'
|
|
),
|
|
guest_journeys_with_payment as (
|
|
select *
|
|
from {{ ref("int_kpis__agg_mtd_guest_journeys_with_payment") }}
|
|
where
|
|
dimension in ('global', 'by_number_of_listings', 'by_billing_country')
|
|
and dimension_value <> 'UNSET'
|
|
union all
|
|
select *
|
|
from {{ ref("int_kpis__agg_monthly_guest_journeys_with_payment") }}
|
|
where
|
|
dimension in ('global', 'by_number_of_listings', 'by_billing_country')
|
|
and dimension_value <> 'UNSET'
|
|
),
|
|
listings as (
|
|
select *
|
|
from {{ ref("int_kpis__agg_daily_listings") }}
|
|
where
|
|
dimension in ('global', 'by_number_of_listings', 'by_billing_country')
|
|
and dimension_value <> 'UNSET'
|
|
and (is_month_to_date = true or is_end_of_month = true)
|
|
),
|
|
deals as (
|
|
select *
|
|
from {{ ref("int_kpis__agg_daily_deals") }}
|
|
where
|
|
dimension in ('global', 'by_number_of_listings', 'by_billing_country')
|
|
and dimension_value <> 'UNSET'
|
|
and (is_month_to_date = true or is_end_of_month = true)
|
|
),
|
|
guest_payments as (
|
|
select *
|
|
from {{ ref("int_kpis__agg_mtd_guest_payments") }}
|
|
where
|
|
dimension in ('global', 'by_number_of_listings', 'by_billing_country')
|
|
and dimension_value <> 'UNSET'
|
|
union all
|
|
select *
|
|
from {{ ref("int_kpis__agg_monthly_guest_payments") }}
|
|
where
|
|
dimension in ('global', 'by_number_of_listings', 'by_billing_country')
|
|
and dimension_value <> 'UNSET'
|
|
),
|
|
invoiced_revenue as (
|
|
select *
|
|
from {{ ref("int_kpis__agg_mtd_invoiced_revenue") }}
|
|
where
|
|
dimension in ('global', 'by_number_of_listings', 'by_billing_country')
|
|
and dimension_value <> 'UNSET'
|
|
union all
|
|
select *
|
|
from {{ ref("int_kpis__agg_monthly_invoiced_revenue") }}
|
|
where
|
|
dimension in ('global', 'by_number_of_listings', 'by_billing_country')
|
|
and dimension_value <> 'UNSET'
|
|
),
|
|
host_resolutions as (
|
|
select *
|
|
from {{ ref("int_kpis__agg_mtd_host_resolutions") }}
|
|
where
|
|
dimension in ('global', 'by_number_of_listings', 'by_billing_country')
|
|
and dimension_value <> 'UNSET'
|
|
union all
|
|
select *
|
|
from {{ ref("int_kpis__agg_monthly_host_resolutions") }}
|
|
where
|
|
dimension in ('global', 'by_number_of_listings', 'by_billing_country')
|
|
and dimension_value <> 'UNSET'
|
|
),
|
|
int_monthly_churn_metrics as (select * from {{ ref("int_monthly_churn_metrics") }}),
|
|
int_kpis__agg_dates_main_kpis as (
|
|
select *
|
|
from {{ ref("int_kpis__agg_dates_main_kpis") }}
|
|
where
|
|
dimension in ('global', 'by_number_of_listings', 'by_billing_country')
|
|
and dimension_value <> 'UNSET'
|
|
),
|
|
|
|
plain_kpi_combination as (
|
|
|
|
select
|
|
d.year,
|
|
d.month,
|
|
d.day,
|
|
d.is_end_of_month,
|
|
d.is_current_month,
|
|
d.is_end_of_month_or_yesterday,
|
|
d.first_day_month,
|
|
d.date,
|
|
d.dimension,
|
|
d.dimension_value,
|
|
|
|
-- BOOKINGS --
|
|
created_bookings.created_bookings,
|
|
check_out_bookings.check_out_bookings,
|
|
cancelled_bookings.cancelled_bookings,
|
|
billable_bookings.billable_bookings,
|
|
|
|
-- GUEST JOURNEYS --
|
|
created_guest_journeys.created_guest_journeys,
|
|
started_guest_journeys.started_guest_journeys,
|
|
completed_guest_journeys.completed_guest_journeys,
|
|
guest_journeys_with_payment.guest_journeys_with_payment
|
|
as paid_guest_journeys,
|
|
cast(started_guest_journeys.started_guest_journeys as decimal)
|
|
/ created_guest_journeys.created_guest_journeys as start_rate_guest_journey,
|
|
cast(completed_guest_journeys.completed_guest_journeys as decimal)
|
|
/ started_guest_journeys.started_guest_journeys
|
|
as completion_rate_guest_journey,
|
|
1
|
|
- cast(completed_guest_journeys.completed_guest_journeys as decimal)
|
|
/ started_guest_journeys.started_guest_journeys
|
|
as incompletion_rate_guest_journey,
|
|
cast(guest_journeys_with_payment.guest_journeys_with_payment as decimal)
|
|
/ completed_guest_journeys.completed_guest_journeys
|
|
as 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) --
|
|
listings.new_listings,
|
|
listings.never_booked_listings,
|
|
listings.first_time_booked_listings,
|
|
listings.active_listings,
|
|
listings.churning_listings,
|
|
listings.inactive_listings,
|
|
listings.reactivated_listings,
|
|
listings.listings_booked_in_month,
|
|
listings.listings_booked_in_6_months,
|
|
listings.listings_booked_in_12_months,
|
|
|
|
-- HOST (OPERATOR) REVENUE --
|
|
invoiced_revenue.xero_booking_net_fees_in_gbp,
|
|
invoiced_revenue.xero_listing_net_fees_in_gbp,
|
|
invoiced_revenue.xero_verification_net_fees_in_gbp,
|
|
invoiced_revenue.xero_operator_net_fees_in_gbp,
|
|
|
|
-- APIs REVENUE --
|
|
invoiced_revenue.xero_apis_net_fees_in_gbp,
|
|
invoiced_revenue.xero_e_deposit_net_fees_in_gbp,
|
|
invoiced_revenue.xero_guesty_net_fees_in_gbp,
|
|
|
|
-- HOST RESOLUTIONS --
|
|
host_resolutions.xero_host_resolution_amount_paid_in_gbp,
|
|
host_resolutions.xero_host_resolution_payment_count,
|
|
|
|
-- GUEST REVENUE AND PAYMENTS --
|
|
guest_payments.deposit_fees_in_gbp,
|
|
guest_payments.waiver_payments_in_gbp,
|
|
invoiced_revenue.xero_waiver_paid_back_to_host_in_gbp,
|
|
nullif(
|
|
coalesce(guest_payments.waiver_payments_in_gbp, 0)
|
|
+ coalesce(invoiced_revenue.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,
|
|
|
|
-- TOTAL REVENUE --
|
|
nullif(
|
|
coalesce(guest_payments.total_guest_payments_in_gbp, 0)
|
|
+ coalesce(invoiced_revenue.xero_operator_net_fees_in_gbp, 0)
|
|
+ coalesce(invoiced_revenue.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(
|
|
completed_guest_journeys.completed_guest_journeys, 0
|
|
) as guest_payments_per_completed_guest_journey,
|
|
guest_payments.total_guest_payments_in_gbp / nullif(
|
|
guest_journeys_with_payment.guest_journeys_with_payment, 0
|
|
) as guest_payments_per_paid_guest_journey,
|
|
|
|
-- TOTAL REVENUE WEIGHTED METRICS --
|
|
(
|
|
coalesce(guest_payments.total_guest_payments_in_gbp, 0)
|
|
+ coalesce(invoiced_revenue.xero_operator_net_fees_in_gbp, 0)
|
|
+ coalesce(invoiced_revenue.xero_apis_net_fees_in_gbp, 0)
|
|
) / nullif(
|
|
created_bookings.created_bookings, 0
|
|
) as total_revenue_per_created_booking,
|
|
(
|
|
coalesce(guest_payments.total_guest_payments_in_gbp, 0)
|
|
+ coalesce(invoiced_revenue.xero_operator_net_fees_in_gbp, 0)
|
|
+ coalesce(invoiced_revenue.xero_apis_net_fees_in_gbp, 0)
|
|
) / nullif(
|
|
created_guest_journeys.created_guest_journeys, 0
|
|
) as total_revenue_per_created_guest_journey,
|
|
(
|
|
coalesce(guest_payments.total_guest_payments_in_gbp, 0)
|
|
+ coalesce(invoiced_revenue.xero_operator_net_fees_in_gbp, 0)
|
|
+ coalesce(invoiced_revenue.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(invoiced_revenue.xero_operator_net_fees_in_gbp, 0)
|
|
+ coalesce(invoiced_revenue.xero_apis_net_fees_in_gbp, 0)
|
|
) / nullif(
|
|
listings.listings_booked_in_month, 0
|
|
) as total_revenue_per_listings_booked_in_month,
|
|
|
|
-- CHURN --
|
|
churn.total_revenue_churn_average_contribution,
|
|
churn.created_bookings_churn_average_contribution,
|
|
churn.listings_booked_in_month_churn_average_contribution,
|
|
|
|
-- INCOME RETAINED --
|
|
nullif(
|
|
coalesce(guest_payments.total_guest_payments_in_gbp, 0)
|
|
+ coalesce(invoiced_revenue.xero_operator_net_fees_in_gbp, 0)
|
|
+ coalesce(invoiced_revenue.xero_apis_net_fees_in_gbp, 0)
|
|
+ coalesce(invoiced_revenue.xero_waiver_paid_back_to_host_in_gbp, 0),
|
|
0
|
|
) as revenue_retained_in_gbp,
|
|
|
|
-- INCOME RETAINED POST RESOLUTIONS--
|
|
nullif(
|
|
coalesce(guest_payments.total_guest_payments_in_gbp, 0)
|
|
+ coalesce(invoiced_revenue.xero_operator_net_fees_in_gbp, 0)
|
|
+ coalesce(invoiced_revenue.xero_apis_net_fees_in_gbp, 0)
|
|
+ coalesce(invoiced_revenue.xero_waiver_paid_back_to_host_in_gbp, 0)
|
|
+ coalesce(host_resolutions.xero_host_resolution_amount_paid_in_gbp, 0),
|
|
0
|
|
) as revenue_retained_post_resolutions_in_gbp
|
|
|
|
from int_kpis__agg_dates_main_kpis d
|
|
left join
|
|
created_bookings
|
|
on d.date = created_bookings.end_date
|
|
and d.dimension = created_bookings.dimension
|
|
and d.dimension_value = created_bookings.dimension_value
|
|
left join
|
|
check_out_bookings
|
|
on d.date = check_out_bookings.end_date
|
|
and d.dimension = check_out_bookings.dimension
|
|
and d.dimension_value = check_out_bookings.dimension_value
|
|
left join
|
|
cancelled_bookings
|
|
on d.date = cancelled_bookings.end_date
|
|
and d.dimension = cancelled_bookings.dimension
|
|
and d.dimension_value = cancelled_bookings.dimension_value
|
|
left join
|
|
billable_bookings
|
|
on d.date = billable_bookings.end_date
|
|
and d.dimension = billable_bookings.dimension
|
|
and d.dimension_value = billable_bookings.dimension_value
|
|
left join
|
|
created_guest_journeys
|
|
on d.date = created_guest_journeys.end_date
|
|
and d.dimension = created_guest_journeys.dimension
|
|
and d.dimension_value = created_guest_journeys.dimension_value
|
|
left join
|
|
started_guest_journeys
|
|
on d.date = started_guest_journeys.end_date
|
|
and d.dimension = started_guest_journeys.dimension
|
|
and d.dimension_value = started_guest_journeys.dimension_value
|
|
left join
|
|
completed_guest_journeys
|
|
on d.date = completed_guest_journeys.end_date
|
|
and d.dimension = completed_guest_journeys.dimension
|
|
and d.dimension_value = completed_guest_journeys.dimension_value
|
|
left join
|
|
guest_journeys_with_payment
|
|
on d.date = guest_journeys_with_payment.end_date
|
|
and d.dimension = guest_journeys_with_payment.dimension
|
|
and d.dimension_value = guest_journeys_with_payment.dimension_value
|
|
left join
|
|
listings
|
|
on d.date = listings.date
|
|
and d.dimension = listings.dimension
|
|
and d.dimension_value = listings.dimension_value
|
|
left join
|
|
deals
|
|
on d.date = deals.date
|
|
and d.dimension = deals.dimension
|
|
and d.dimension_value = deals.dimension_value
|
|
left join
|
|
guest_payments
|
|
on d.date = guest_payments.end_date
|
|
and d.dimension = guest_payments.dimension
|
|
and d.dimension_value = guest_payments.dimension_value
|
|
left join
|
|
invoiced_revenue
|
|
on d.date = invoiced_revenue.end_date
|
|
and d.dimension = invoiced_revenue.dimension
|
|
and d.dimension_value = invoiced_revenue.dimension_value
|
|
left join
|
|
host_resolutions
|
|
on d.date = host_resolutions.end_date
|
|
and d.dimension = host_resolutions.dimension
|
|
and d.dimension_value = host_resolutions.dimension_value
|
|
left join
|
|
int_monthly_churn_metrics churn
|
|
on d.date = churn.date
|
|
and d.dimension = churn.dimension
|
|
and d.dimension_value = churn.dimension_value
|
|
)
|
|
select
|
|
current.year,
|
|
current.month,
|
|
current.day,
|
|
current.is_end_of_month,
|
|
current.is_current_month,
|
|
current.is_end_of_month_or_yesterday,
|
|
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 --
|
|
{{ 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") }},
|
|
|
|
-- TOTAL REVENUE --
|
|
{{ calculate_safe_relative_increment("total_revenue_in_gbp") }},
|
|
|
|
-- GUEST REVENUE WEIGHTED METRICS --
|
|
{{
|
|
calculate_safe_relative_increment(
|
|
"guest_payments_per_completed_guest_journey"
|
|
)
|
|
}},
|
|
{{ calculate_safe_relative_increment("guest_payments_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"
|
|
)
|
|
}},
|
|
|
|
-- CHURN --
|
|
{{ calculate_safe_relative_increment("total_revenue_churn_average_contribution") }},
|
|
{{
|
|
calculate_safe_relative_increment(
|
|
"created_bookings_churn_average_contribution"
|
|
)
|
|
}},
|
|
{{
|
|
calculate_safe_relative_increment(
|
|
"listings_booked_in_month_churn_average_contribution"
|
|
)
|
|
}},
|
|
|
|
-- INCOME RETAINED --
|
|
{{ calculate_safe_relative_increment("revenue_retained_in_gbp") }},
|
|
|
|
-- INCOME RETAINED POST RESOLUTIONS--
|
|
{{ calculate_safe_relative_increment("revenue_retained_post_resolutions_in_gbp") }}
|
|
|
|
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 = true
|
|
or (current.is_current_month = true and current.day = previous_year.day)
|
|
)
|