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:
Oriol Roqué Paniagua 2024-07-19 07:30:42 +00:00
parent b16cb172b6
commit 361ad31299
4 changed files with 156 additions and 35 deletions

View file

@ -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