Merged PR 2353: Computing and propagating APIs revenue metrics
Computing and propagating APIs revenue metrics. I retrieved the revenues linked to Guesty and e-deposits. The sum of those are considered the total API revenue at this stage. These 3 metrics are available in upper layers (not exposed yet to the report), just to fix the total revenue computation, which now includes APIs revenue Related work items: #18719
This commit is contained in:
parent
b16cb172b6
commit
361ad31299
4 changed files with 156 additions and 35 deletions
|
|
@ -37,7 +37,7 @@ select
|
|||
bookings.check_out_bookings,
|
||||
bookings.cancelled_bookings,
|
||||
bookings.billable_bookings,
|
||||
|
||||
|
||||
-- GUEST JOURNEYS --
|
||||
guest_journeys.created_guest_journeys,
|
||||
guest_journeys.started_guest_journeys,
|
||||
|
|
@ -67,13 +67,19 @@ select
|
|||
invoicing.xero_operator_net_fees_in_gbp,
|
||||
invoicing.xero_waiver_net_fees_in_gbp,
|
||||
|
||||
-- APIs REVENUE --
|
||||
invoicing.xero_apis_net_fees_in_gbp,
|
||||
invoicing.xero_e_deposit_net_fees_in_gbp,
|
||||
invoicing.xero_guesty_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,
|
||||
+ invoicing.xero_operator_net_fees_in_gbp
|
||||
+ invoicing.xero_apis_net_fees_in_gbp as total_revenue_in_gbp,
|
||||
|
||||
-- GUEST REVENUE AND PAYMENTS WEIGHTED METRICS --
|
||||
guest_revenue.total_guest_payments_in_gbp,
|
||||
|
|
@ -92,17 +98,23 @@ select
|
|||
) 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)
|
||||
(
|
||||
guest_revenue.total_guest_revenue_in_gbp
|
||||
+ invoicing.xero_operator_net_fees_in_gbp
|
||||
+ invoicing.xero_apis_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
|
||||
+ invoicing.xero_apis_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
|
||||
+ invoicing.xero_apis_net_fees_in_gbp
|
||||
) / nullif(
|
||||
accommodations.listings_booked_in_month, 0
|
||||
) as total_revenue_per_listings_booked_in_month
|
||||
|
|
|
|||
|
|
@ -20,7 +20,7 @@ with
|
|||
select * from {{ ref("int_mtd_guest_revenue_metrics") }}
|
||||
),
|
||||
int_xero__mtd_invoicing_metrics as (
|
||||
select * from {{ ref("int_xero__mtd_invoicing_metrics") }}
|
||||
select * from {{ ref("int_xero__mtd_invoicing_metrics") }}
|
||||
),
|
||||
int_dates_mtd as (select * from {{ ref("int_dates_mtd") }}),
|
||||
|
||||
|
|
@ -82,6 +82,11 @@ with
|
|||
invoicing.xero_operator_net_fees_in_gbp,
|
||||
invoicing.xero_waiver_net_fees_in_gbp,
|
||||
|
||||
-- APIs REVENUE --
|
||||
invoicing.xero_apis_net_fees_in_gbp,
|
||||
invoicing.xero_e_deposit_net_fees_in_gbp,
|
||||
invoicing.xero_guesty_net_fees_in_gbp,
|
||||
|
||||
-- HOST RESOLUTIONS --
|
||||
invoicing.xero_host_resolution_amount_paid_in_gbp,
|
||||
invoicing.xero_host_resolution_payment_count,
|
||||
|
|
@ -92,8 +97,8 @@ with
|
|||
|
||||
-- TOTAL REVENUE --
|
||||
guest_revenue.total_guest_revenue_in_gbp
|
||||
+ invoicing.xero_operator_net_fees_in_gbp
|
||||
as total_revenue_in_gbp,
|
||||
+ invoicing.xero_operator_net_fees_in_gbp
|
||||
+ invoicing.xero_apis_net_fees_in_gbp as total_revenue_in_gbp,
|
||||
|
||||
-- GUEST REVENUE AND PAYMENTS WEIGHTED METRICS --
|
||||
guest_revenue.total_guest_payments_in_gbp / nullif(
|
||||
|
|
@ -110,36 +115,46 @@ with
|
|||
) 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_revenue.total_guest_revenue_in_gbp
|
||||
+ invoicing.xero_operator_net_fees_in_gbp
|
||||
+ invoicing.xero_apis_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
|
||||
+ invoicing.xero_apis_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(
|
||||
(
|
||||
guest_revenue.total_guest_revenue_in_gbp
|
||||
+ invoicing.xero_operator_net_fees_in_gbp
|
||||
+ invoicing.xero_apis_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(
|
||||
(
|
||||
guest_revenue.total_guest_revenue_in_gbp
|
||||
+ invoicing.xero_operator_net_fees_in_gbp
|
||||
+ invoicing.xero_apis_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_xero__mtd_invoicing_metrics invoicing
|
||||
on d.date = invoicing.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,
|
||||
|
|
@ -198,6 +213,11 @@ select
|
|||
{{ calculate_safe_relative_increment("xero_operator_net_fees_in_gbp") }},
|
||||
{{ calculate_safe_relative_increment("xero_waiver_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") }},
|
||||
|
|
@ -210,16 +230,24 @@ select
|
|||
{{ 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_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") }},
|
||||
|
||||
-- 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")}}
|
||||
{{ 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
|
||||
|
|
|
|||
|
|
@ -1,7 +1,7 @@
|
|||
/*
|
||||
This model provides monthly metrics for those hosts that have a deal assigned,
|
||||
on anything related to invoicing metrics. This includes Operator (Host) fees,
|
||||
waiver payments and Host Resolutions.
|
||||
waiver payments, APIs and Host Resolutions.
|
||||
|
||||
*/
|
||||
{% set relevant_document_statuses = "('PAID', 'AUTHORISED')" %}
|
||||
|
|
@ -10,6 +10,8 @@ waiver payments and Host Resolutions.
|
|||
{% set waiver_items = "('DAMAGE WAVER', 'DAMAGE WAIVER')" %}
|
||||
{% set verification_fee_items = "('VERIFICATION FEE')" %}
|
||||
{% set resolutions_host_payment_account_name = "('RESOLUTIONS - HOST PAYMENT')" %}
|
||||
{% set e_deposit_account_name = "('E-DEPOSIT FEES')" %}
|
||||
{% set guesty_account_name = "('GUESTY FEES', 'GUESTY ADMINISTRATION FEE')" %}
|
||||
|
||||
{{ config(materialized="table", unique_key="date") }}
|
||||
with
|
||||
|
|
@ -41,10 +43,37 @@ with
|
|||
where upper(btli.account_name) in {{ resolutions_host_payment_account_name }}
|
||||
group by 1, 2
|
||||
),
|
||||
apis_net_fees as (
|
||||
select
|
||||
date_trunc('month', sdm.document_issued_date_utc)::date as first_day_month,
|
||||
id_deal,
|
||||
sum(
|
||||
case
|
||||
when upper(sdm.account_name) in {{ e_deposit_account_name }}
|
||||
then sdm.line_amount_wo_taxes_in_gbp
|
||||
else 0
|
||||
end
|
||||
) as xero_e_deposit_net_fees_in_gbp,
|
||||
sum(
|
||||
case
|
||||
when upper(sdm.account_name) in {{ guesty_account_name }}
|
||||
then sdm.line_amount_wo_taxes_in_gbp
|
||||
else 0
|
||||
end
|
||||
) as xero_guesty_net_fees_in_gbp
|
||||
from int_xero__sales_denom_mart sdm
|
||||
where
|
||||
upper(sdm.document_status) in {{ relevant_document_statuses }}
|
||||
and (
|
||||
upper(sdm.account_name) in {{ e_deposit_account_name }}
|
||||
or upper(sdm.account_name) in {{ guesty_account_name }}
|
||||
)
|
||||
group by 1, 2
|
||||
),
|
||||
host_net_fees as (
|
||||
select
|
||||
date_trunc('month', sdm.document_issued_date_utc)::date as first_day_month,
|
||||
c.id_deal,
|
||||
id_deal,
|
||||
sum(
|
||||
case
|
||||
when upper(sdm.item_code) in {{ booking_fee_items }}
|
||||
|
|
@ -74,7 +103,6 @@ with
|
|||
end
|
||||
) as xero_waiver_net_fees_in_gbp
|
||||
from int_xero__sales_denom_mart sdm
|
||||
inner join int_xero__contacts c on c.id_contact = sdm.id_contact
|
||||
where
|
||||
upper(sdm.document_status) in {{ relevant_document_statuses }}
|
||||
and (
|
||||
|
|
@ -93,13 +121,21 @@ select
|
|||
d.day,
|
||||
d.date,
|
||||
d.id_deal,
|
||||
-- HOST/OPERATOR --
|
||||
hnf.xero_booking_net_fees_in_gbp,
|
||||
hnf.xero_listing_net_fees_in_gbp,
|
||||
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_in_gbp,
|
||||
-- APIs --
|
||||
anf.xero_e_deposit_net_fees_in_gbp,
|
||||
anf.xero_guesty_net_fees_in_gbp,
|
||||
anf.xero_e_deposit_net_fees_in_gbp
|
||||
+ anf.xero_guesty_net_fees_in_gbp as xero_apis_net_fees_in_gbp,
|
||||
-- WAIVERS PAID BACK TO HOST --
|
||||
hnf.xero_waiver_net_fees_in_gbp,
|
||||
-- HOST RESOLUTIONS --
|
||||
rhp.xero_host_resolution_amount_paid_in_gbp,
|
||||
rhp.xero_host_resolution_payment_count
|
||||
from int_dates_by_deal d
|
||||
|
|
@ -107,6 +143,10 @@ left join
|
|||
resolution_host_payment rhp
|
||||
on d.first_day_month = rhp.first_day_month
|
||||
and d.id_deal = rhp.id_deal
|
||||
left join
|
||||
apis_net_fees anf
|
||||
on d.first_day_month = anf.first_day_month
|
||||
and d.id_deal = anf.id_deal
|
||||
left join
|
||||
host_net_fees hnf
|
||||
on d.first_day_month = hnf.first_day_month
|
||||
|
|
|
|||
|
|
@ -1,7 +1,7 @@
|
|||
/*
|
||||
This model provides Month-To-Date (MTD) based on anything related to
|
||||
invoicing metrics. This includes Operator (Host) fees, waiver payments,
|
||||
and Host Resolutions.
|
||||
APIs and Host Resolutions.
|
||||
|
||||
*/
|
||||
{% set relevant_document_statuses = "('PAID', 'AUTHORISED')" %}
|
||||
|
|
@ -10,6 +10,8 @@ and Host Resolutions.
|
|||
{% set waiver_items = "('DAMAGE WAVER', 'DAMAGE WAIVER')" %}
|
||||
{% set verification_fee_items = "('VERIFICATION FEE')" %}
|
||||
{% set resolutions_host_payment_account_name = "('RESOLUTIONS - HOST PAYMENT')" %}
|
||||
{% set e_deposit_account_name = "('E-DEPOSIT FEES')" %}
|
||||
{% set guesty_account_name = "('GUESTY FEES', 'GUESTY ADMINISTRATION FEE')" %}
|
||||
|
||||
{{ config(materialized="table", unique_key="date") }}
|
||||
with
|
||||
|
|
@ -42,6 +44,36 @@ with
|
|||
and upper(btli.account_name) in {{ resolutions_host_payment_account_name }}
|
||||
group by 1
|
||||
),
|
||||
apis_net_fees as (
|
||||
select
|
||||
d.date,
|
||||
sum(
|
||||
case
|
||||
when upper(sdm.account_name) in {{ e_deposit_account_name }}
|
||||
then sdm.line_amount_wo_taxes_in_gbp
|
||||
else 0
|
||||
end
|
||||
) as xero_e_deposit_net_fees_in_gbp,
|
||||
sum(
|
||||
case
|
||||
when upper(sdm.account_name) in {{ guesty_account_name }}
|
||||
then sdm.line_amount_wo_taxes_in_gbp
|
||||
else 0
|
||||
end
|
||||
) as xero_guesty_net_fees_in_gbp
|
||||
from int_dates_mtd d
|
||||
inner join
|
||||
int_xero__sales_denom_mart sdm
|
||||
on date_trunc('month', sdm.document_issued_date_utc) = d.first_day_month
|
||||
and extract(day from sdm.document_issued_date_utc) <= d.day
|
||||
where
|
||||
upper(sdm.document_status) in {{ relevant_document_statuses }}
|
||||
and (
|
||||
upper(sdm.account_name) in {{ e_deposit_account_name }}
|
||||
or upper(sdm.account_name) in {{ guesty_account_name }}
|
||||
)
|
||||
group by 1
|
||||
),
|
||||
host_net_fees as (
|
||||
select
|
||||
d.date,
|
||||
|
|
@ -97,15 +129,24 @@ select
|
|||
d.date,
|
||||
d.is_end_of_month,
|
||||
d.is_current_month,
|
||||
-- HOST/OPERATOR --
|
||||
hnf.xero_booking_net_fees_in_gbp,
|
||||
hnf.xero_listing_net_fees_in_gbp,
|
||||
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_in_gbp,
|
||||
-- APIs --
|
||||
anf.xero_e_deposit_net_fees_in_gbp,
|
||||
anf.xero_guesty_net_fees_in_gbp,
|
||||
anf.xero_e_deposit_net_fees_in_gbp
|
||||
+ anf.xero_guesty_net_fees_in_gbp as xero_apis_net_fees_in_gbp,
|
||||
-- WAIVERS PAID BACK TO HOST --
|
||||
hnf.xero_waiver_net_fees_in_gbp,
|
||||
-- HOST RESOLUTIONS --
|
||||
rhp.xero_host_resolution_amount_paid_in_gbp,
|
||||
rhp.xero_host_resolution_payment_count
|
||||
from int_dates_mtd d
|
||||
left join resolution_host_payment rhp on rhp.date = d.date
|
||||
left join apis_net_fees anf on anf.date = d.date
|
||||
left join host_net_fees hnf on hnf.date = d.date
|
||||
|
|
|
|||
Loading…
Add table
Add a link
Reference in a new issue