Merged PR 2422: Ensure that guest payments models follow nomenclature
Small refactor to follow up on last week's PR. We removed from the Guest Revenue models the host-takes-waiver aspect, thus these models are now only depending from Core. We just need to migrate it from cross to core. One small detail as well, since we do not take into account at these models level the host-takes-waiver, technically, I would not call these models revenue but rather Guest Payments. This is why I also took the opportunity to apply this name. Changes: - `int_monthly_guest_revenue_by_deal` is now `int_core__monthly_guest_payments_history_by_deal`, and the location has changed from `intermediate.cross` to `intermediate.core` - `int_mtd_guest_revenue_metrics` is now `int_core__mtd_guest_payments_metrics`, and the location has changed from `intermediate.cross` to `intermediate.core` - Schema changes, moving these 2 models' documentation with the new naming from Cross to Core - Provide continuity in following dependants: `int_mtd_vs_previous_year_metrics` and `int_monthly_aggregated_metrics_history_by_deal` now read from the 2 new models respectively. Additionally, the model alias has changed from `guest_revenue` to `guest_payments` to keep consistency. This PR does not expose new metrics, but should keep the existing ones unaffected. Related work items: #18914
This commit is contained in:
parent
04eb09c318
commit
1b1b97380a
6 changed files with 75 additions and 75 deletions
|
|
@ -0,0 +1,85 @@
|
|||
/*
|
||||
This model provides monthly guest revenue metrics for those hosts that have a deal assigned.
|
||||
|
||||
*/
|
||||
{% 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"]) }}
|
||||
|
||||
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_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 {{ deposit_fees_verification_payment_type_items }}
|
||||
then vp.amount_in_gbp
|
||||
else null
|
||||
end
|
||||
) 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") }}
|
||||
and u.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.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
|
||||
|
|
@ -0,0 +1,75 @@
|
|||
/*
|
||||
This model provides Month-To-Date (MTD) based on Guest Revenue metrics.
|
||||
|
||||
*/
|
||||
{% 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") }}
|
||||
with
|
||||
int_core__verification_payments as (
|
||||
select * from {{ ref("int_core__verification_payments") }}
|
||||
),
|
||||
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 {{ deposit_fees_verification_payment_type_items }}
|
||||
then vp.amount_in_gbp
|
||||
else null
|
||||
end
|
||||
) 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_dates_mtd d
|
||||
inner join
|
||||
int_core__verification_payments vp
|
||||
on date_trunc('month', vp.payment_paid_date_utc)::date = d.first_day_month
|
||||
and extract(day from vp.payment_paid_date_utc) <= d.day
|
||||
where upper(vp.payment_status) = {{ var("paid_payment_state") }}
|
||||
group by 1
|
||||
)
|
||||
-- Final aggregation of subqueries --
|
||||
select
|
||||
d.year,
|
||||
d.month,
|
||||
d.day,
|
||||
d.date,
|
||||
d.is_end_of_month,
|
||||
d.is_current_month,
|
||||
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_mtd d
|
||||
left join guest_payments_year_month gpym on gpym.date = d.date
|
||||
|
|
@ -272,6 +272,44 @@ models:
|
|||
- not_null
|
||||
- unique
|
||||
|
||||
- name: int_mtd_guest_payments_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_payments_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
|
||||
|
||||
- name: int_core__verification_request_completeness
|
||||
description: |
|
||||
The `int_core__verification_request_completeness` model allows to determine if a verification request is
|
||||
|
|
|
|||
Loading…
Add table
Add a link
Reference in a new issue