Merged PR 2221: Computes (paid) guest revenue metric - fixed

IMPORTANT: this PR was merged and reverted. The division by 0 error has been fixed in the last commit

Adds the following metrics:
- Guest Revenue

by both visions (global and by deal id)
It creates 2 new models:
- int_mtd_guest_revenue_metrics
- int_monthly_guest_revenue_history_by_deal

the approaches are similar in the sense that we retrieve the information from the int_core__verification_payments and a filter by a PAID status. I checked and the aggregated volumes of the figures correspond to the decimal as what is reported to the guest_payments dashboard (aggregating the information from the currency tab)

Same as last PR, this one does not exposes the data since a refactor of how the code is structured will follow shortly.

Related work items: #18107
This commit is contained in:
Oriol Roqué Paniagua 2024-07-08 11:02:02 +00:00
parent e214641b9f
commit d2b0afdca6
3 changed files with 210 additions and 0 deletions

View file

@ -0,0 +1,79 @@
/*
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')" %}
{{ 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_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
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
end
) as total_guest_income_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")}}
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
)
-- 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

View file

@ -0,0 +1,93 @@
/*
This model provides Month-To-Date (MTD) based on Guest Revenue metrics.
*/
{% set revenue_verification_payment_type_items = "('FEE','WAIVER','CHECKINCOVER')" %}
{% set relevant_document_statuses = "('PAID', 'AUTHORISED')" %}
{% set waiver_items = "('DAMAGE WAVER','DAMAGE WAIVER')" %}
{{ config(materialized="table", unique_key="date") }}
with
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_xero__credit_notes as (select * from {{ ref("int_xero__credit_notes") }}),
int_dates_mtd as (select * from {{ ref("int_dates_mtd") }}),
-- Paid Guest Revenue MTD --
guest_payments_year_month as (
select
d.date,
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
end
) as total_guest_income_in_gbp
from int_dates_mtd d
inner join int_core__verification_payments vp
on extract(year from vp.payment_paid_date_utc) = d.year
and extract(month from vp.payment_paid_date_utc) = d.month
and extract(day from vp.payment_paid_date_utc) <= d.day
where upper(vp.payment_status) = {{ var("paid_payment_state")}}
group by 1
),
-- Waiver Credit Notes MTD --
-- We need to get the credited waivers for those
-- host-takes-waiver cases
waiver_credit_notes as (
select
d.date,
sum(cnli.line_amount_wo_taxes_in_gbp) as waiver_fees_credited
from int_dates_mtd d
inner join int_xero__credit_notes cn
on extract(year from cn.credit_note_issued_date_utc) = d.year
and extract(month from cn.credit_note_issued_date_utc) = d.month
and extract(day from cn.credit_note_issued_date_utc) <= d.day
inner join int_xero__credit_note_line_items cnli
on cn.id_credit_note = cnli.id_credit_note
where upper(cn.credit_note_status) in {{ relevant_document_statuses }}
and upper(cnli.item_code) in {{ waiver_items }}
group by 1
),
main_kpi as (
-- Final aggregation of subqueries --
select
d.year,
d.month,
d.day,
d.date,
d.is_end_of_month,
d.is_current_month,
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_mtd d
left join guest_payments_year_month gpym on gpym.date = d.date
left join waiver_credit_notes wcn on wcn.date = d.date
)
-- Pivoting to get previous year for each line & computing relative increment
-- (rel_incr) --
select
a.year,
a.month,
a.day,
a.is_end_of_month,
a.is_current_month,
a.date,
b.date as previous_year_date,
a.total_guest_payments_in_gbp,
b.total_guest_payments_in_gbp as previous_year_total_guest_payments_in_gbp,
cast(a.total_guest_payments_in_gbp as decimal) / b.total_guest_payments_in_gbp
- 1 as relative_increment_total_guest_payments_in_gbp,
a.total_guest_revenue_in_gbp,
b.total_guest_revenue_in_gbp as previous_year_total_guest_revenue_in_gbp,
cast(a.total_guest_revenue_in_gbp as decimal) / b.total_guest_revenue_in_gbp
- 1 as relative_increment_total_guest_revenue_in_gbp
from main_kpi a
left join main_kpi b on a.month = b.month and a.year = b.year + 1
where (a.is_end_of_month = 1 or (a.is_current_month = 1 and a.day = b.day))

View file

@ -131,3 +131,41 @@ models:
DWH, this will be the point in time when we made the assumption.
tests:
- not_null
- name: int_mtd_guest_revenue_metrics
description: |
This model contains the historic information regarding the guest revenue in an aggregated manner.
It's used for the business KPIs. Data is aggregated at the last day of the month and in the
days necessary for the Month-to-Date computation of the current month.
columns:
- name: date
data_type: date
description: The date for the month-to-date guest revenue-related metrics.
tests:
- not_null
- unique
- name: int_monthly_guest_revenue_history_by_deal
description: |
This model contains the historic information regarding the guest revenue for each deal id.
It's used for the business KPIs in the view by deal id. Data is aggregated at the last
day of the month, or up to yesterday if it's the current month.
tests:
- dbt_utils.unique_combination_of_columns:
combination_of_columns:
- date
- id_deal
columns:
- name: date
data_type: date
description: The last day of the month or yesterday for historic guest revenue metrics.
tests:
- not_null
- name: id_deal
data_type: character varying
description: Id of the deal associated to the host.
tests:
- not_null