Merged PR 2413: Adding submetrics of guest revenue by deal
Adding submetrics of guest revenue by deal: - deposit_fees_in_gbp - checkin_cover_fees_in_gbp - waiver_payments_in_gbp all of this adds up to - total_guest_income_in_gbp and the total_guest_revenue_in_gbp is now computed by subtracting waivers paid to hosts, coming from the invoiced model. This also affects the total revenue computation and the weighted metrics. This PR it's completely equivalent to the [Adding submetrics of guest revenue](https://guardhog.visualstudio.com/Data/_git/data-dwh-dbt-project/pullrequest/2381?path=/models/intermediate/cross/int_mtd_guest_revenue_metrics.sql&_a=files), that was already merged for the global view. The only difference is that this one is for the deal-based part. It does not expose the metrics to the report. A follow-up PR is expected to apply the correct naming conventions for guest revenue models. I recommend checking the first commit, the one that applies the changes, and should be easily understandable with the link to the previous PR. There's a couple of additional commits that only affect formatting. Related work items: #18787, #18914
This commit is contained in:
parent
da56aa3bb8
commit
04eb09c318
2 changed files with 95 additions and 67 deletions
|
|
@ -76,46 +76,68 @@ select
|
|||
invoicing.xero_host_resolution_amount_paid_in_gbp,
|
||||
invoicing.xero_host_resolution_payment_count,
|
||||
|
||||
-- GUEST REVENUE AND PAYMENTS --
|
||||
guest_revenue.deposit_fees_in_gbp,
|
||||
guest_revenue.waiver_payments_in_gbp,
|
||||
guest_revenue.checkin_cover_fees_in_gbp,
|
||||
guest_revenue.total_guest_payments_in_gbp,
|
||||
guest_revenue.total_guest_income_in_gbp,
|
||||
nullif(
|
||||
coalesce(guest_revenue.total_guest_income_in_gbp, 0)
|
||||
+ coalesce(invoicing.xero_waiver_net_fees_in_gbp, 0),
|
||||
0
|
||||
) as total_guest_revenue_in_gbp,
|
||||
|
||||
-- TOTAL REVENUE --
|
||||
nullif(
|
||||
coalesce(guest_revenue.total_guest_revenue_in_gbp, 0)
|
||||
coalesce(guest_revenue.total_guest_income_in_gbp, 0)
|
||||
+ coalesce(invoicing.xero_waiver_net_fees_in_gbp, 0)
|
||||
+ coalesce(invoicing.xero_operator_net_fees_in_gbp, 0)
|
||||
+ coalesce(invoicing.xero_apis_net_fees_in_gbp, 0),
|
||||
0
|
||||
) 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(
|
||||
nullif(
|
||||
coalesce(guest_revenue.total_guest_income_in_gbp, 0)
|
||||
+ coalesce(invoicing.xero_waiver_net_fees_in_gbp, 0),
|
||||
0
|
||||
) / nullif(
|
||||
guest_journeys.completed_guest_journeys, 0
|
||||
) as guest_revenue_per_completed_guest_journey,
|
||||
guest_revenue.total_guest_revenue_in_gbp / nullif(
|
||||
nullif(
|
||||
coalesce(guest_revenue.total_guest_income_in_gbp, 0)
|
||||
+ coalesce(invoicing.xero_waiver_net_fees_in_gbp, 0),
|
||||
0
|
||||
) / nullif(
|
||||
guest_journeys.paid_guest_journeys, 0
|
||||
) as guest_revenue_per_paid_guest_journey,
|
||||
|
||||
-- TOTAL REVENUE WEIGHTED METRICS --
|
||||
(
|
||||
coalesce(guest_revenue.total_guest_revenue_in_gbp, 0)
|
||||
coalesce(guest_revenue.total_guest_income_in_gbp, 0)
|
||||
+ coalesce(invoicing.xero_waiver_net_fees_in_gbp, 0)
|
||||
+ coalesce(invoicing.xero_operator_net_fees_in_gbp, 0)
|
||||
+ coalesce(invoicing.xero_apis_net_fees_in_gbp, 0)
|
||||
)
|
||||
/ nullif(bookings.created_bookings, 0) as total_revenue_per_created_booking,
|
||||
(
|
||||
coalesce(guest_revenue.total_guest_revenue_in_gbp, 0)
|
||||
coalesce(guest_revenue.total_guest_income_in_gbp, 0)
|
||||
+ coalesce(invoicing.xero_waiver_net_fees_in_gbp, 0)
|
||||
+ coalesce(invoicing.xero_operator_net_fees_in_gbp, 0)
|
||||
+ coalesce(invoicing.xero_apis_net_fees_in_gbp, 0)
|
||||
) / nullif(
|
||||
guest_journeys.created_guest_journeys, 0
|
||||
) as total_revenue_per_created_guest_journey,
|
||||
(
|
||||
coalesce(guest_revenue.total_guest_revenue_in_gbp, 0)
|
||||
coalesce(guest_revenue.total_guest_income_in_gbp, 0)
|
||||
+ coalesce(invoicing.xero_waiver_net_fees_in_gbp, 0)
|
||||
+ coalesce(invoicing.xero_operator_net_fees_in_gbp, 0)
|
||||
+ coalesce(invoicing.xero_apis_net_fees_in_gbp, 0)
|
||||
) / nullif(
|
||||
|
|
|
|||
|
|
@ -2,78 +2,84 @@
|
|||
This model provides monthly guest revenue metrics for those hosts that have a deal assigned.
|
||||
|
||||
*/
|
||||
{% set revenue_verification_payment_type_items = "('FEE','WAIVER','CHECKINCOVER')" %}
|
||||
{% set relevant_document_statuses = "('PAID', 'AUTHORISED')" %}
|
||||
{% set waiver_items = "('DAMAGE WAVER','DAMAGE WAIVER')" %}
|
||||
{% set deposit_fees_verification_payment_type_items = "('FEE')" %}
|
||||
{% set waiver_fees_verification_payment_type_items = "('WAIVER')" %}
|
||||
{% set checkin_cover_fees_verification_payment_type_items = "('CHECKINCOVER')" %}
|
||||
|
||||
{{ config(materialized="table", unique_key=["date","id_deal"]) }}
|
||||
{{ config(materialized="table", unique_key=["date", "id_deal"]) }}
|
||||
|
||||
with
|
||||
int_core__verification_requests as (select * from {{ ref("int_core__verification_requests") }}),
|
||||
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") }}
|
||||
int_core__verification_requests as (
|
||||
select * from {{ ref("int_core__verification_requests") }}
|
||||
),
|
||||
int_core__verification_payments as (
|
||||
select * from {{ ref("int_core__verification_payments") }}
|
||||
),
|
||||
int_xero__credit_notes as (select * from {{ ref("int_xero__credit_notes") }}),
|
||||
int_xero__contacts as (select * from {{ ref("int_xero__contacts") }}),
|
||||
int_dates_by_deal as (select * from {{ ref("int_dates_by_deal") }}),
|
||||
int_core__unified_user as (select * from {{ ref("int_core__unified_user") }}),
|
||||
|
||||
-- Paid Guest Revenue by id_deal --
|
||||
guest_payments_year_month as (
|
||||
select
|
||||
select
|
||||
date_trunc('month', vp.payment_paid_date_utc)::date as first_day_month,
|
||||
u.id_deal,
|
||||
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 {{ deposit_fees_verification_payment_type_items }}
|
||||
then vp.amount_in_gbp
|
||||
else null
|
||||
end
|
||||
) as total_guest_income_in_gbp
|
||||
) as deposit_fees_in_gbp,
|
||||
sum(
|
||||
case
|
||||
when
|
||||
upper(vp.verification_payment_type)
|
||||
in {{ waiver_fees_verification_payment_type_items }}
|
||||
then vp.amount_in_gbp
|
||||
else null
|
||||
end
|
||||
) as waiver_payments_in_gbp,
|
||||
sum(
|
||||
case
|
||||
when
|
||||
upper(vp.verification_payment_type)
|
||||
in {{ checkin_cover_fees_verification_payment_type_items }}
|
||||
then vp.amount_in_gbp
|
||||
else null
|
||||
end
|
||||
) as checkin_cover_fees_in_gbp
|
||||
from int_core__verification_payments vp
|
||||
inner join int_core__verification_requests vr
|
||||
on vp.id_verification_request = vr.id_verification_request
|
||||
inner join int_core__unified_user u
|
||||
on u.id_user = vr.id_user_host
|
||||
where upper(vp.payment_status) = {{ var("paid_payment_state")}}
|
||||
inner join
|
||||
int_core__verification_requests vr
|
||||
on vp.id_verification_request = vr.id_verification_request
|
||||
inner join int_core__unified_user u on u.id_user = vr.id_user_host
|
||||
where
|
||||
upper(vp.payment_status) = {{ var("paid_payment_state") }}
|
||||
and u.id_deal is not null
|
||||
group by 1,2
|
||||
),
|
||||
-- Waiver Credit Notes by id_deal --
|
||||
-- We need to get the credited waivers for those
|
||||
-- host-takes-waiver cases
|
||||
waiver_credit_notes as (
|
||||
select
|
||||
date_trunc('month', cn.credit_note_issued_date_utc)::date as first_day_month,
|
||||
c.id_deal,
|
||||
sum(cnli.line_amount_wo_taxes_in_gbp) as waiver_fees_credited
|
||||
from int_xero__credit_notes cn
|
||||
inner join int_xero__credit_note_line_items cnli
|
||||
on cn.id_credit_note = cnli.id_credit_note
|
||||
inner join int_xero__contacts c
|
||||
on cn.id_contact = c.id_contact
|
||||
where upper(cn.credit_note_status) in {{ relevant_document_statuses }}
|
||||
and upper(cnli.item_code) in {{ waiver_items }}
|
||||
and c.id_deal is not null
|
||||
group by 1,2
|
||||
group by 1, 2
|
||||
)
|
||||
-- Final aggregation of subqueries --
|
||||
select
|
||||
d.year,
|
||||
d.month,
|
||||
d.day,
|
||||
d.date,
|
||||
d.id_deal,
|
||||
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_by_deal d
|
||||
left join guest_payments_year_month gpym
|
||||
on d.first_day_month = gpym.first_day_month
|
||||
and d.id_deal = gpym.id_deal
|
||||
left join waiver_credit_notes wcn
|
||||
on d.first_day_month = wcn.first_day_month
|
||||
and d.id_deal = wcn.id_deal
|
||||
-- Final aggregation of subqueries --
|
||||
select
|
||||
d.year,
|
||||
d.month,
|
||||
d.day,
|
||||
d.date,
|
||||
d.id_deal,
|
||||
nullif(gpym.deposit_fees_in_gbp, 0) as deposit_fees_in_gbp,
|
||||
nullif(gpym.waiver_payments_in_gbp, 0) as waiver_payments_in_gbp,
|
||||
nullif(gpym.checkin_cover_fees_in_gbp, 0) as checkin_cover_fees_in_gbp,
|
||||
nullif(gpym.total_guest_payments_in_gbp, 0) as total_guest_payments_in_gbp,
|
||||
nullif(
|
||||
coalesce(gpym.deposit_fees_in_gbp, 0)
|
||||
+ coalesce(gpym.waiver_payments_in_gbp, 0)
|
||||
+ coalesce(gpym.checkin_cover_fees_in_gbp, 0),
|
||||
0
|
||||
) as total_guest_income_in_gbp
|
||||
from int_dates_by_deal d
|
||||
left join
|
||||
guest_payments_year_month gpym
|
||||
on d.first_day_month = gpym.first_day_month
|
||||
and d.id_deal = gpym.id_deal
|
||||
|
|
|
|||
Loading…
Add table
Add a link
Reference in a new issue