Merged PR 2292: Propagate invoicing metrics for KPIs
This PR aims to propagate the invoicing metrics through the DWH. It does not expose them to users, yet. This PR effectively computes the following metrics, for both the "global" view (MTD) and the "by deal" view (by_deal): - Invoiced Operator Revenue - Host Resolution Count of Payments - Host Resolution Amount Paid With these 3 new metrics, we're able to combine them with the existing ones to compute: - Total Revenue - Total Revenue per Booking Created - Total Revenue per Guest Journey Created - Total Revenue per Deal Booked in Month - Total Revenue per Listings Booked in Month You'll also note that I've included standalone metrics for booking fees, listing fees, verification fees and waiver payments. This will not be exposed in this batch 2, but based on the conversation with Finance, will clearly make it for batch 3. I just find it easier to add it now, since it's straight forward. Main changes: - `int_mtd_vs_previous_year_metrics` now computes all the above mentioned metrics - `int_monthly_aggregated_metrics_history_by_deal` now computes all the above mentioned metrics, except Total Revenue per Deal Booked in Month since it does not make sense for the deal view. Additionally, I took the opportunity to include the missing metrics from listings (accommodations). The goal is not necessarily to display them, but at least compute it on our side. Additional changes: - In `int_xero__mtd_invoicing_metrics` and `int_xero__monthly_invoicing_history_by_deal`, there's a very silly name change to keep the same convention for fees: from `xero_operator_net_fees` to `xero_operator_net_fees_in_gbp` - I applied additional changes in `int_monthly_aggregated_metrics_history_by_deal` with the goal to keep the same format as we have in `int_mtd_vs_previous_year_metrics`, this meaning: 1 - explicit alias naming (from `gj` to `guest_journeys`) 2 - keep a similar arrangement of metrics, and clearly separate scopes depending on the metric type 3 - Re-apply autoformatting Related work items: #18108, #18109, #18110
This commit is contained in:
parent
698756e0f7
commit
bf473ab971
4 changed files with 198 additions and 66 deletions
|
|
@ -2,60 +2,132 @@
|
|||
This model aggregates the different metrics by deal for those hosts that have it assigned.
|
||||
|
||||
*/
|
||||
|
||||
with
|
||||
int_dates_by_deal as (select * from {{ ref("int_dates_by_deal") }}),
|
||||
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_monthly_guest_revenue_history_by_deal as (select * from {{ ref("int_monthly_guest_revenue_history_by_deal") }})
|
||||
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_xero__monthly_invoicing_history_by_deal as (
|
||||
select * from {{ ref("int_xero__monthly_invoicing_history_by_deal") }}
|
||||
),
|
||||
int_monthly_guest_revenue_history_by_deal as (
|
||||
select * from {{ ref("int_monthly_guest_revenue_history_by_deal") }}
|
||||
)
|
||||
|
||||
select
|
||||
d.year,
|
||||
d.month,
|
||||
d.day,
|
||||
d.date,
|
||||
d.id_deal,
|
||||
l.deal_lifecycle_state,
|
||||
b.created_bookings,
|
||||
b.check_out_bookings,
|
||||
b.cancelled_bookings,
|
||||
gj.created_guest_journeys,
|
||||
gj.started_guest_journeys,
|
||||
gj.completed_guest_journeys,
|
||||
gj.paid_guest_journeys,
|
||||
gj.start_rate_guest_journey,
|
||||
gj.completion_rate_guest_journey,
|
||||
gj.incompletion_rate_guest_journey,
|
||||
gj.payment_rate_guest_journey,
|
||||
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,
|
||||
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
|
||||
and d.id_deal = l.id_deal
|
||||
left join int_core__monthly_booking_history_by_deal b
|
||||
on d.date = b.date
|
||||
and d.id_deal = b.id_deal
|
||||
left join int_core__monthly_guest_journey_history_by_deal gj
|
||||
on d.date = gj.date
|
||||
and d.id_deal = gj.id_deal
|
||||
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
|
||||
select
|
||||
d.year,
|
||||
d.month,
|
||||
d.day,
|
||||
d.date,
|
||||
d.id_deal,
|
||||
-- DEAL LIFECYCLE --
|
||||
deal_lifecycle.deal_lifecycle_state,
|
||||
|
||||
-- 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,
|
||||
|
||||
-- LISTINGS --
|
||||
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,
|
||||
invoicing.xero_waiver_net_fees_in_gbp,
|
||||
|
||||
-- HOST RESOLUTIONS --
|
||||
invoicing.xero_host_resolution_amount_paid_in_gbp,
|
||||
invoicing.xero_host_resolution_payment_count,
|
||||
|
||||
-- TOTAL REVENUE --
|
||||
guest_revenue.total_guest_revenue_in_gbp
|
||||
+ invoicing.xero_operator_net_fees_in_gbp as total_revenue_in_gbp,
|
||||
|
||||
-- GUEST REVENUE AND PAYMENTS WEIGHTED METRICS --
|
||||
guest_revenue.total_guest_payments_in_gbp,
|
||||
guest_revenue.total_guest_revenue_in_gbp,
|
||||
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,
|
||||
|
||||
-- TOTAL REVENUE WEIGHTED METRICS --
|
||||
(guest_revenue.total_guest_revenue_in_gbp + invoicing.xero_operator_net_fees_in_gbp)
|
||||
/ nullif(bookings.created_bookings, 0) as total_revenue_per_created_booking,
|
||||
(
|
||||
guest_revenue.total_guest_revenue_in_gbp
|
||||
+ invoicing.xero_operator_net_fees_in_gbp
|
||||
) / nullif(
|
||||
guest_journeys.created_guest_journeys, 0
|
||||
) as total_revenue_per_created_guest_journey,
|
||||
(
|
||||
guest_revenue.total_guest_revenue_in_gbp
|
||||
+ invoicing.xero_operator_net_fees_in_gbp
|
||||
) / nullif(
|
||||
accommodations.listings_booked_in_month, 0
|
||||
) as total_revenue_per_listings_booked_in_month
|
||||
|
||||
from int_dates_by_deal d
|
||||
left join
|
||||
int_core__mtd_deal_lifecycle deal_lifecycle
|
||||
on d.date = deal_lifecycle.date
|
||||
and d.id_deal = deal_lifecycle.id_deal
|
||||
left join
|
||||
int_core__monthly_booking_history_by_deal bookings
|
||||
on d.date = bookings.date
|
||||
and d.id_deal = bookings.id_deal
|
||||
left join
|
||||
int_core__monthly_guest_journey_history_by_deal guest_journeys
|
||||
on d.date = guest_journeys.date
|
||||
and d.id_deal = guest_journeys.id_deal
|
||||
left join
|
||||
int_core__monthly_accommodation_history_by_deal accommodations
|
||||
on d.date = accommodations.date
|
||||
and d.id_deal = accommodations.id_deal
|
||||
left join
|
||||
int_monthly_guest_revenue_history_by_deal guest_revenue
|
||||
on d.date = guest_revenue.date
|
||||
and d.id_deal = guest_revenue.id_deal
|
||||
left join
|
||||
int_xero__monthly_invoicing_history_by_deal invoicing
|
||||
on d.date = invoicing.date
|
||||
and d.id_deal = invoicing.id_deal
|
||||
|
|
|
|||
|
|
@ -19,9 +19,13 @@ with
|
|||
int_mtd_guest_revenue_metrics as (
|
||||
select * from {{ ref("int_mtd_guest_revenue_metrics") }}
|
||||
),
|
||||
int_xero__mtd_invoicing_metrics as (
|
||||
select * from {{ ref("int_xero__mtd_invoicing_metrics") }}
|
||||
),
|
||||
int_dates_mtd as (select * from {{ ref("int_dates_mtd") }}),
|
||||
|
||||
plain_kpi_combination as (
|
||||
|
||||
select
|
||||
d.year,
|
||||
d.month,
|
||||
|
|
@ -69,11 +73,27 @@ with
|
|||
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,
|
||||
invoicing.xero_waiver_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_revenue.total_guest_payments_in_gbp,
|
||||
guest_revenue.total_guest_revenue_in_gbp,
|
||||
|
||||
-- WEIGHTED METRICS
|
||||
-- TOTAL REVENUE --
|
||||
guest_revenue.total_guest_revenue_in_gbp
|
||||
+ invoicing.xero_operator_net_fees_in_gbp
|
||||
as total_revenue_in_gbp,
|
||||
|
||||
-- GUEST REVENUE AND PAYMENTS WEIGHTED METRICS --
|
||||
guest_revenue.total_guest_payments_in_gbp / nullif(
|
||||
guest_journeys.completed_guest_journeys, 0
|
||||
) as guest_payments_per_completed_guest_journey,
|
||||
|
|
@ -85,19 +105,39 @@ with
|
|||
) 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
|
||||
) as guest_revenue_per_paid_guest_journey,
|
||||
|
||||
-- TOTAL REVENUE WEIGHTED METRICS --
|
||||
(guest_revenue.total_guest_revenue_in_gbp
|
||||
+ invoicing.xero_operator_net_fees_in_gbp) / nullif(
|
||||
bookings.created_bookings, 0
|
||||
) as total_revenue_per_created_booking,
|
||||
(guest_revenue.total_guest_revenue_in_gbp
|
||||
+ invoicing.xero_operator_net_fees_in_gbp) / nullif(
|
||||
guest_journeys.created_guest_journeys, 0
|
||||
) as total_revenue_per_created_guest_journey,
|
||||
(guest_revenue.total_guest_revenue_in_gbp
|
||||
+ invoicing.xero_operator_net_fees_in_gbp) / nullif(
|
||||
deals.deals_booked_in_month, 0
|
||||
) as total_revenue_per_deals_booked_in_month,
|
||||
(guest_revenue.total_guest_revenue_in_gbp
|
||||
+ invoicing.xero_operator_net_fees_in_gbp) / nullif(
|
||||
accommodations.listings_booked_in_month, 0
|
||||
) as total_revenue_per_listings_booked_in_month
|
||||
|
||||
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_mtd_guest_revenue_metrics guest_revenue on d.date = guest_revenue.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
|
||||
left join int_xero__mtd_invoicing_metrics invoicing
|
||||
on d.date = invoicing.date
|
||||
)
|
||||
select
|
||||
current.year,
|
||||
|
|
@ -147,15 +187,35 @@ select
|
|||
{{ 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") }},
|
||||
{{ calculate_safe_relative_increment("xero_waiver_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("total_guest_payments_in_gbp") }},
|
||||
{{ calculate_safe_relative_increment("total_guest_revenue_in_gbp") }},
|
||||
|
||||
-- WEIGHTED METRICS
|
||||
-- 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") }}
|
||||
{{ 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
|
||||
|
|
|
|||
|
|
@ -98,7 +98,7 @@ select
|
|||
hnf.xero_verification_net_fees_in_gbp,
|
||||
hnf.xero_booking_net_fees_in_gbp
|
||||
+ hnf.xero_listing_net_fees_in_gbp
|
||||
+ hnf.xero_verification_net_fees_in_gbp as xero_operator_net_fees,
|
||||
+ hnf.xero_verification_net_fees_in_gbp as xero_operator_net_fees_in_gbp,
|
||||
hnf.xero_waiver_net_fees_in_gbp,
|
||||
rhp.xero_host_resolution_amount_paid_in_gbp,
|
||||
rhp.xero_host_resolution_payment_count
|
||||
|
|
|
|||
|
|
@ -102,7 +102,7 @@ select
|
|||
hnf.xero_verification_net_fees_in_gbp,
|
||||
hnf.xero_booking_net_fees_in_gbp
|
||||
+ hnf.xero_listing_net_fees_in_gbp
|
||||
+ hnf.xero_verification_net_fees_in_gbp as xero_operator_net_fees,
|
||||
+ hnf.xero_verification_net_fees_in_gbp as xero_operator_net_fees_in_gbp,
|
||||
hnf.xero_waiver_net_fees_in_gbp,
|
||||
rhp.xero_host_resolution_amount_paid_in_gbp,
|
||||
rhp.xero_host_resolution_payment_count
|
||||
|
|
|
|||
Loading…
Add table
Add a link
Reference in a new issue