Merge branch 'master' of ssh.dev.azure.com:v3/guardhog/Data/data-dwh-dbt-project
This commit is contained in:
commit
7ec5d91c6a
13 changed files with 436 additions and 174 deletions
|
|
@ -0,0 +1,83 @@
|
|||
/*
|
||||
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(
|
||||
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(
|
||||
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_payments_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,42 @@
|
|||
{{ config(materialized="table", unique_key=["date", "id_deal"]) }}
|
||||
with
|
||||
int_core__mtd_accommodation_lifecycle as (
|
||||
select * from {{ ref("int_core__mtd_accommodation_lifecycle") }}
|
||||
),
|
||||
int_core__unique_accommodation_to_user as (
|
||||
select * from {{ ref("int_core__unique_accommodation_to_user") }}
|
||||
),
|
||||
int_core__unified_user as (select * from {{ ref("int_core__unified_user") }}),
|
||||
|
||||
active_accommodations_per_deal as (
|
||||
select
|
||||
al.date,
|
||||
uu.id_deal,
|
||||
sum(
|
||||
case when al.has_been_booked_within_last_12_months then 1 else 0 end
|
||||
) as accommodations_booked_in_12_months
|
||||
from int_core__mtd_accommodation_lifecycle al
|
||||
inner join
|
||||
int_core__unique_accommodation_to_user atu
|
||||
on al.id_accommodation = atu.id_accommodation
|
||||
inner join int_core__unified_user uu on uu.id_user = atu.id_user_owner
|
||||
where uu.id_deal is not null
|
||||
group by 1, 2
|
||||
)
|
||||
select
|
||||
date,
|
||||
id_deal,
|
||||
case
|
||||
when accommodations_booked_in_12_months = 0
|
||||
then '0'
|
||||
when accommodations_booked_in_12_months between 1 and 5
|
||||
then '1-5'
|
||||
when accommodations_booked_in_12_months between 6 and 20
|
||||
then '6-20'
|
||||
when accommodations_booked_in_12_months between 21 and 60
|
||||
then '21-60'
|
||||
when accommodations_booked_in_12_months >= 61
|
||||
then '61+'
|
||||
end as active_accommodations_per_deal_segmentation,
|
||||
accommodations_booked_in_12_months
|
||||
from active_accommodations_per_deal
|
||||
|
|
@ -17,7 +17,6 @@ with
|
|||
guest_payments_year_month as (
|
||||
select
|
||||
d.date,
|
||||
sum(vp.amount_in_gbp) as total_guest_payments_in_gbp,
|
||||
sum(
|
||||
case
|
||||
when
|
||||
|
|
@ -64,12 +63,11 @@ select
|
|||
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
|
||||
) as total_guest_payments_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_core__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_core__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
|
||||
|
|
@ -715,6 +753,63 @@ models:
|
|||
data_type: boolean
|
||||
description: If the listing has had a booking created in the past 12 months.
|
||||
|
||||
- name: int_core__mtd_accommodation_segmentation
|
||||
description: |
|
||||
This model contains the historic information regarding the customer segmentation based on active accommodations,
|
||||
also known as listings. This model depends on the int_core__mtd_accommodation_lifecycle, thus the time granularity
|
||||
is the same as for any mtd model.
|
||||
|
||||
The segmentation is applied at deal level, not at user host level. This has the drawback that hosts without a
|
||||
deal assigned won't be considered in this segmentation. However, it correctly categorises customers based on the
|
||||
number of listings across the different user hosts each deal can have.
|
||||
|
||||
The segmentation is available in the field active_accommodations_per_deal_segmentation. It considers listings that
|
||||
have been booked within the last 12 months. Thus, it means it only considers the lifecycle states of
|
||||
03-First Time Booked, 04-Active and 07-Reactivated. The segments are the following:
|
||||
- '0'
|
||||
- '1-5'
|
||||
- '6-20'
|
||||
- '21-60'
|
||||
- '61+'
|
||||
These segments are inspired from the ones RevOps team uses, but the associated deals and listings volume will differ
|
||||
since the listing activity logic considered is different.
|
||||
|
||||
tests:
|
||||
- dbt_utils.unique_combination_of_columns:
|
||||
combination_of_columns:
|
||||
- date
|
||||
- id_deal
|
||||
|
||||
columns:
|
||||
- name: date
|
||||
data_type: date
|
||||
description: The date for the month-to-date. Information is inclusive to the date displayed.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: id_deal
|
||||
data_type: character varying
|
||||
description: Id of the deal associated to the host.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: active_accommodations_per_deal_segmentation
|
||||
data_type: character varying
|
||||
description: The segmentation based on the number of listings booked in the last 12 months.
|
||||
tests:
|
||||
- not_null
|
||||
- accepted_values:
|
||||
values:
|
||||
- '0'
|
||||
- '1-5'
|
||||
- '6-20'
|
||||
- '21-60'
|
||||
- '61+'
|
||||
|
||||
- name: accommodations_booked_in_12_months
|
||||
data_type: integer
|
||||
description: Informative field of the actual number of listings booked in the last 12 months
|
||||
|
||||
- name: int_core__mtd_deal_lifecycle
|
||||
description: |
|
||||
This model contains the historic information regarding the lifecycle of hosts, at deal level.
|
||||
|
|
|
|||
|
|
@ -19,8 +19,8 @@ with
|
|||
int_xero__monthly_invoicing_history_by_deal as (
|
||||
select * from {{ ref("int_xero__monthly_invoicing_history_by_deal") }}
|
||||
),
|
||||
int_monthly_guest_revenue_history_by_deal as (
|
||||
select * from {{ ref("int_monthly_guest_revenue_history_by_deal") }}
|
||||
int_core__monthly_guest_payments_history_by_deal as (
|
||||
select * from {{ ref("int_core__monthly_guest_payments_history_by_deal") }}
|
||||
)
|
||||
|
||||
select
|
||||
|
|
@ -65,7 +65,6 @@ select
|
|||
invoicing.xero_listing_net_fees_in_gbp,
|
||||
invoicing.xero_verification_net_fees_in_gbp,
|
||||
invoicing.xero_operator_net_fees_in_gbp,
|
||||
invoicing.xero_waiver_net_fees_in_gbp,
|
||||
|
||||
-- APIs REVENUE --
|
||||
invoicing.xero_apis_net_fees_in_gbp,
|
||||
|
|
@ -76,46 +75,73 @@ select
|
|||
invoicing.xero_host_resolution_amount_paid_in_gbp,
|
||||
invoicing.xero_host_resolution_payment_count,
|
||||
|
||||
-- GUEST REVENUE AND PAYMENTS --
|
||||
guest_payments.deposit_fees_in_gbp,
|
||||
guest_payments.waiver_payments_in_gbp,
|
||||
invoicing.xero_waiver_paid_back_to_host_in_gbp,
|
||||
nullif(
|
||||
coalesce(guest_payments.waiver_payments_in_gbp, 0)
|
||||
+ coalesce(invoicing.xero_waiver_paid_back_to_host_in_gbp, 0),
|
||||
0
|
||||
) as waiver_net_fees_in_gbp,
|
||||
guest_payments.checkin_cover_fees_in_gbp,
|
||||
guest_payments.total_guest_payments_in_gbp,
|
||||
nullif(
|
||||
coalesce(guest_payments.total_guest_payments_in_gbp, 0)
|
||||
+ coalesce(invoicing.xero_waiver_paid_back_to_host_in_gbp, 0),
|
||||
0
|
||||
) as total_guest_revenue_in_gbp,
|
||||
|
||||
-- TOTAL REVENUE --
|
||||
nullif(
|
||||
coalesce(guest_revenue.total_guest_revenue_in_gbp, 0)
|
||||
coalesce(guest_payments.total_guest_payments_in_gbp, 0)
|
||||
+ coalesce(invoicing.xero_waiver_paid_back_to_host_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_payments.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_payments.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_payments.total_guest_payments_in_gbp, 0)
|
||||
+ coalesce(invoicing.xero_waiver_paid_back_to_host_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_payments.total_guest_payments_in_gbp, 0)
|
||||
+ coalesce(invoicing.xero_waiver_paid_back_to_host_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_payments.total_guest_payments_in_gbp, 0)
|
||||
+ coalesce(invoicing.xero_waiver_paid_back_to_host_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_payments.total_guest_payments_in_gbp, 0)
|
||||
+ coalesce(invoicing.xero_waiver_paid_back_to_host_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_payments.total_guest_payments_in_gbp, 0)
|
||||
+ coalesce(invoicing.xero_waiver_paid_back_to_host_in_gbp, 0)
|
||||
+ coalesce(invoicing.xero_operator_net_fees_in_gbp, 0)
|
||||
+ coalesce(invoicing.xero_apis_net_fees_in_gbp, 0)
|
||||
) / nullif(
|
||||
|
|
@ -140,9 +166,9 @@ left join
|
|||
on d.date = accommodations.date
|
||||
and d.id_deal = accommodations.id_deal
|
||||
left join
|
||||
int_monthly_guest_revenue_history_by_deal guest_revenue
|
||||
on d.date = guest_revenue.date
|
||||
and d.id_deal = guest_revenue.id_deal
|
||||
int_core__monthly_guest_payments_history_by_deal guest_payments
|
||||
on d.date = guest_payments.date
|
||||
and d.id_deal = guest_payments.id_deal
|
||||
left join
|
||||
int_xero__monthly_invoicing_history_by_deal invoicing
|
||||
on d.date = invoicing.date
|
||||
|
|
|
|||
|
|
@ -1,79 +0,0 @@
|
|||
/*
|
||||
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
|
||||
|
|
@ -199,7 +199,7 @@
|
|||
"relative_increment": "relative_increment_total_revenue_in_gbp",
|
||||
"number_format": "currency_gbp",
|
||||
},
|
||||
{
|
||||
{
|
||||
"order_by": 201,
|
||||
"metric": "Total Revenue per Booking Created",
|
||||
"value": "total_revenue_per_created_booking",
|
||||
|
|
@ -239,6 +239,30 @@
|
|||
"relative_increment": "relative_increment_xero_operator_net_fees_in_gbp",
|
||||
"number_format": "currency_gbp",
|
||||
},
|
||||
{
|
||||
"order_by": 225,
|
||||
"metric": "Invoiced Booking Fees",
|
||||
"value": "xero_booking_net_fees_in_gbp",
|
||||
"previous_year_value": "previous_year_xero_booking_net_fees_in_gbp",
|
||||
"relative_increment": "relative_increment_xero_booking_net_fees_in_gbp",
|
||||
"number_format": "currency_gbp",
|
||||
},
|
||||
{
|
||||
"order_by": 226,
|
||||
"metric": "Invoiced Listing Fees",
|
||||
"value": "xero_listing_net_fees_in_gbp",
|
||||
"previous_year_value": "previous_year_xero_listing_net_fees_in_gbp",
|
||||
"relative_increment": "relative_increment_xero_listing_net_fees_in_gbp",
|
||||
"number_format": "currency_gbp",
|
||||
},
|
||||
{
|
||||
"order_by": 227,
|
||||
"metric": "Invoiced Verification Fees",
|
||||
"value": "xero_verification_net_fees_in_gbp",
|
||||
"previous_year_value": "previous_year_xero_verification_net_fees_in_gbp",
|
||||
"relative_increment": "relative_increment_xero_verification_net_fees_in_gbp",
|
||||
"number_format": "currency_gbp",
|
||||
},
|
||||
{
|
||||
"order_by": 230,
|
||||
"metric": "Invoiced APIs Revenue",
|
||||
|
|
@ -247,6 +271,22 @@
|
|||
"relative_increment": "relative_increment_xero_apis_net_fees_in_gbp",
|
||||
"number_format": "currency_gbp",
|
||||
},
|
||||
{
|
||||
"order_by": 235,
|
||||
"metric": "Invoiced Guesty Fees",
|
||||
"value": "xero_guesty_net_fees_in_gbp",
|
||||
"previous_year_value": "previous_year_xero_guesty_net_fees_in_gbp",
|
||||
"relative_increment": "relative_increment_xero_guesty_net_fees_in_gbp",
|
||||
"number_format": "currency_gbp",
|
||||
},
|
||||
{
|
||||
"order_by": 236,
|
||||
"metric": "Invoiced E-Deposit Fees",
|
||||
"value": "xero_e_deposit_net_fees_in_gbp",
|
||||
"previous_year_value": "previous_year_xero_e_deposit_net_fees_in_gbp",
|
||||
"relative_increment": "relative_increment_xero_e_deposit_net_fees_in_gbp",
|
||||
"number_format": "currency_gbp",
|
||||
},
|
||||
{
|
||||
"order_by": 250,
|
||||
"metric": "Guest Revenue",
|
||||
|
|
@ -271,6 +311,46 @@
|
|||
"relative_increment": "relative_increment_guest_revenue_per_paid_guest_journey",
|
||||
"number_format": "currency_gbp",
|
||||
},
|
||||
{
|
||||
"order_by": 260,
|
||||
"metric": "Deposit Fees",
|
||||
"value": "deposit_fees_in_gbp",
|
||||
"previous_year_value": "previous_year_deposit_fees_in_gbp",
|
||||
"relative_increment": "relative_increment_deposit_fees_in_gbp",
|
||||
"number_format": "currency_gbp",
|
||||
},
|
||||
{
|
||||
"order_by": 262,
|
||||
"metric": "Waiver Amount Paid by Guests",
|
||||
"value": "waiver_payments_in_gbp",
|
||||
"previous_year_value": "previous_year_waiver_payments_in_gbp",
|
||||
"relative_increment": "relative_increment_waiver_payments_in_gbp",
|
||||
"number_format": "currency_gbp",
|
||||
},
|
||||
{
|
||||
"order_by": 263,
|
||||
"metric": "Waiver Amount Paid back to Hosts",
|
||||
"value": "xero_waiver_paid_back_to_host_in_gbp",
|
||||
"previous_year_value": "previous_year_xero_waiver_paid_back_to_host_in_gbp",
|
||||
"relative_increment": "relative_increment_xero_waiver_paid_back_to_host_in_gbp",
|
||||
"number_format": "currency_gbp",
|
||||
},
|
||||
{
|
||||
"order_by": 264,
|
||||
"metric": "Waiver Net Fees",
|
||||
"value": "waiver_net_fees_in_gbp",
|
||||
"previous_year_value": "previous_year_waiver_net_fees_in_gbp",
|
||||
"relative_increment": "relative_increment_waiver_net_fees_in_gbp",
|
||||
"number_format": "currency_gbp",
|
||||
},
|
||||
{
|
||||
"order_by": 265,
|
||||
"metric": "Check-In Hero Amount Paid by Guests",
|
||||
"value": "checkin_cover_fees_in_gbp",
|
||||
"previous_year_value": "previous_year_checkin_cover_fees_in_gbp",
|
||||
"relative_increment": "relative_increment_checkin_cover_fees_in_gbp",
|
||||
"number_format": "currency_gbp",
|
||||
},
|
||||
{
|
||||
"order_by": 270,
|
||||
"metric": "Host Resolutions Amount Paid",
|
||||
|
|
|
|||
|
|
@ -16,8 +16,8 @@ with
|
|||
int_core__mtd_deal_metrics as (
|
||||
select * from {{ ref("int_core__mtd_deal_metrics") }}
|
||||
),
|
||||
int_mtd_guest_revenue_metrics as (
|
||||
select * from {{ ref("int_mtd_guest_revenue_metrics") }}
|
||||
int_core__mtd_guest_payments_metrics as (
|
||||
select * from {{ ref("int_core__mtd_guest_payments_metrics") }}
|
||||
),
|
||||
int_xero__mtd_invoicing_metrics as (
|
||||
select * from {{ ref("int_xero__mtd_invoicing_metrics") }}
|
||||
|
|
@ -80,7 +80,6 @@ with
|
|||
invoicing.xero_listing_net_fees_in_gbp,
|
||||
invoicing.xero_verification_net_fees_in_gbp,
|
||||
invoicing.xero_operator_net_fees_in_gbp,
|
||||
invoicing.xero_waiver_net_fees_in_gbp,
|
||||
|
||||
-- APIs REVENUE --
|
||||
invoicing.xero_apis_net_fees_in_gbp,
|
||||
|
|
@ -92,43 +91,48 @@ with
|
|||
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,
|
||||
guest_payments.deposit_fees_in_gbp,
|
||||
guest_payments.waiver_payments_in_gbp,
|
||||
invoicing.xero_waiver_paid_back_to_host_in_gbp,
|
||||
nullif(
|
||||
coalesce(guest_revenue.total_guest_income_in_gbp, 0)
|
||||
+ coalesce(invoicing.xero_waiver_net_fees_in_gbp, 0),
|
||||
coalesce(guest_payments.waiver_payments_in_gbp, 0)
|
||||
+ coalesce(invoicing.xero_waiver_paid_back_to_host_in_gbp, 0),
|
||||
0
|
||||
) as waiver_net_fees_in_gbp,
|
||||
guest_payments.checkin_cover_fees_in_gbp,
|
||||
guest_payments.total_guest_payments_in_gbp,
|
||||
nullif(
|
||||
coalesce(guest_payments.total_guest_payments_in_gbp, 0)
|
||||
+ coalesce(invoicing.xero_waiver_paid_back_to_host_in_gbp, 0),
|
||||
0
|
||||
) as total_guest_revenue_in_gbp,
|
||||
|
||||
-- TOTAL REVENUE --
|
||||
nullif(
|
||||
coalesce(guest_revenue.total_guest_income_in_gbp, 0)
|
||||
+ coalesce(invoicing.xero_waiver_net_fees_in_gbp, 0)
|
||||
coalesce(guest_payments.total_guest_payments_in_gbp, 0)
|
||||
+ coalesce(invoicing.xero_waiver_paid_back_to_host_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 / nullif(
|
||||
guest_payments.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_payments.total_guest_payments_in_gbp / nullif(
|
||||
guest_journeys.paid_guest_journeys, 0
|
||||
) as guest_payments_per_paid_guest_journey,
|
||||
nullif(
|
||||
coalesce(guest_revenue.total_guest_income_in_gbp, 0)
|
||||
+ coalesce(invoicing.xero_waiver_net_fees_in_gbp, 0),
|
||||
coalesce(guest_payments.total_guest_payments_in_gbp, 0)
|
||||
+ coalesce(invoicing.xero_waiver_paid_back_to_host_in_gbp, 0),
|
||||
0
|
||||
) / nullif(
|
||||
guest_journeys.completed_guest_journeys, 0
|
||||
) as guest_revenue_per_completed_guest_journey,
|
||||
nullif(
|
||||
coalesce(guest_revenue.total_guest_income_in_gbp, 0)
|
||||
+ coalesce(invoicing.xero_waiver_net_fees_in_gbp, 0),
|
||||
coalesce(guest_payments.total_guest_payments_in_gbp, 0)
|
||||
+ coalesce(invoicing.xero_waiver_paid_back_to_host_in_gbp, 0),
|
||||
0
|
||||
) / nullif(
|
||||
guest_journeys.paid_guest_journeys, 0
|
||||
|
|
@ -136,31 +140,31 @@ with
|
|||
|
||||
-- TOTAL REVENUE WEIGHTED METRICS --
|
||||
(
|
||||
coalesce(guest_revenue.total_guest_income_in_gbp, 0)
|
||||
+ coalesce(invoicing.xero_waiver_net_fees_in_gbp, 0)
|
||||
coalesce(guest_payments.total_guest_payments_in_gbp, 0)
|
||||
+ coalesce(invoicing.xero_waiver_paid_back_to_host_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_income_in_gbp, 0)
|
||||
+ coalesce(invoicing.xero_waiver_net_fees_in_gbp, 0)
|
||||
coalesce(guest_payments.total_guest_payments_in_gbp, 0)
|
||||
+ coalesce(invoicing.xero_waiver_paid_back_to_host_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_income_in_gbp, 0)
|
||||
+ coalesce(invoicing.xero_waiver_net_fees_in_gbp, 0)
|
||||
coalesce(guest_payments.total_guest_payments_in_gbp, 0)
|
||||
+ coalesce(invoicing.xero_waiver_paid_back_to_host_in_gbp, 0)
|
||||
+ coalesce(invoicing.xero_operator_net_fees_in_gbp, 0)
|
||||
+ coalesce(invoicing.xero_apis_net_fees_in_gbp, 0)
|
||||
) / nullif(
|
||||
deals.deals_booked_in_month, 0
|
||||
) as total_revenue_per_deals_booked_in_month,
|
||||
(
|
||||
coalesce(guest_revenue.total_guest_income_in_gbp, 0)
|
||||
+ coalesce(invoicing.xero_waiver_net_fees_in_gbp, 0)
|
||||
coalesce(guest_payments.total_guest_payments_in_gbp, 0)
|
||||
+ coalesce(invoicing.xero_waiver_paid_back_to_host_in_gbp, 0)
|
||||
+ coalesce(invoicing.xero_operator_net_fees_in_gbp, 0)
|
||||
+ coalesce(invoicing.xero_apis_net_fees_in_gbp, 0)
|
||||
) / nullif(
|
||||
|
|
@ -177,7 +181,7 @@ with
|
|||
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
|
||||
int_core__mtd_guest_payments_metrics guest_payments on d.date = guest_payments.date
|
||||
left join int_xero__mtd_invoicing_metrics invoicing on d.date = invoicing.date
|
||||
)
|
||||
select
|
||||
|
|
@ -235,7 +239,6 @@ select
|
|||
{{ calculate_safe_relative_increment("xero_listing_net_fees_in_gbp") }},
|
||||
{{ calculate_safe_relative_increment("xero_verification_net_fees_in_gbp") }},
|
||||
{{ 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") }},
|
||||
|
|
@ -249,9 +252,10 @@ select
|
|||
-- GUEST REVENUE AND PAYMENTS --
|
||||
{{ calculate_safe_relative_increment("deposit_fees_in_gbp") }},
|
||||
{{ calculate_safe_relative_increment("waiver_payments_in_gbp") }},
|
||||
{{ calculate_safe_relative_increment("xero_waiver_paid_back_to_host_in_gbp") }},
|
||||
{{ calculate_safe_relative_increment("waiver_net_fees_in_gbp") }},
|
||||
{{ calculate_safe_relative_increment("checkin_cover_fees_in_gbp") }},
|
||||
{{ calculate_safe_relative_increment("total_guest_payments_in_gbp") }},
|
||||
{{ calculate_safe_relative_increment("total_guest_income_in_gbp") }},
|
||||
{{ calculate_safe_relative_increment("total_guest_revenue_in_gbp") }},
|
||||
|
||||
-- TOTAL REVENUE --
|
||||
|
|
|
|||
|
|
@ -132,20 +132,6 @@ models:
|
|||
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_mtd_vs_previous_year_metrics
|
||||
description: |
|
||||
This model is used for global KPIs.
|
||||
|
|
@ -164,30 +150,6 @@ models:
|
|||
- 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
|
||||
|
||||
- name: int_mtd_aggregated_metrics
|
||||
description: |
|
||||
The `int_mtd_aggregated_metrics` model aggregates multiple metrics on a year, month, and day basis.
|
||||
|
|
|
|||
|
|
@ -101,7 +101,7 @@ with
|
|||
then sdm.line_amount_wo_taxes_in_gbp
|
||||
else 0
|
||||
end
|
||||
) as xero_waiver_net_fees_in_gbp
|
||||
) as xero_waiver_paid_back_to_host_in_gbp
|
||||
from int_xero__sales_denom_mart sdm
|
||||
where
|
||||
upper(sdm.document_status) in {{ relevant_document_statuses }}
|
||||
|
|
@ -140,7 +140,7 @@ select
|
|||
0
|
||||
) as xero_apis_net_fees_in_gbp,
|
||||
-- WAIVERS PAID BACK TO HOST --
|
||||
hnf.xero_waiver_net_fees_in_gbp,
|
||||
hnf.xero_waiver_paid_back_to_host_in_gbp,
|
||||
-- HOST RESOLUTIONS --
|
||||
rhp.xero_host_resolution_amount_paid_in_gbp,
|
||||
rhp.xero_host_resolution_payment_count
|
||||
|
|
|
|||
|
|
@ -104,7 +104,7 @@ with
|
|||
then sdm.line_amount_wo_taxes_in_gbp
|
||||
else 0
|
||||
end
|
||||
) as xero_waiver_net_fees_in_gbp
|
||||
) as xero_waiver_paid_back_to_host_in_gbp
|
||||
from int_dates_mtd d
|
||||
inner join
|
||||
int_xero__sales_denom_mart sdm
|
||||
|
|
@ -148,7 +148,7 @@ select
|
|||
0
|
||||
) as xero_apis_net_fees_in_gbp,
|
||||
-- WAIVERS PAID BACK TO HOST --
|
||||
hnf.xero_waiver_net_fees_in_gbp,
|
||||
hnf.xero_waiver_paid_back_to_host_in_gbp,
|
||||
-- HOST RESOLUTIONS --
|
||||
rhp.xero_host_resolution_amount_paid_in_gbp,
|
||||
rhp.xero_host_resolution_payment_count
|
||||
|
|
|
|||
|
|
@ -83,8 +83,46 @@ select
|
|||
then xero_host_resolution_payment_count
|
||||
else null
|
||||
end as xero_host_resolution_payment_count,
|
||||
case
|
||||
when {{ is_date_before_previous_month("date") }}
|
||||
then xero_booking_net_fees_in_gbp
|
||||
else null
|
||||
end as xero_booking_net_fees_in_gbp,
|
||||
case
|
||||
when {{ is_date_before_previous_month("date") }}
|
||||
then xero_listing_net_fees_in_gbp
|
||||
else null
|
||||
end as xero_listing_net_fees_in_gbp,
|
||||
case
|
||||
when {{ is_date_before_previous_month("date") }}
|
||||
then xero_verification_net_fees_in_gbp
|
||||
else null
|
||||
end as xero_verification_net_fees_in_gbp,
|
||||
case
|
||||
when {{ is_date_before_previous_month("date") }}
|
||||
then xero_guesty_net_fees_in_gbp
|
||||
else null
|
||||
end as xero_guesty_net_fees_in_gbp,
|
||||
case
|
||||
when {{ is_date_before_previous_month("date") }}
|
||||
then xero_e_deposit_net_fees_in_gbp
|
||||
else null
|
||||
end as xero_e_deposit_net_fees_in_gbp,
|
||||
case
|
||||
when {{ is_date_before_previous_month("date") }}
|
||||
then xero_waiver_paid_back_to_host_in_gbp
|
||||
else null
|
||||
end as xero_waiver_paid_back_to_host_in_gbp,
|
||||
case
|
||||
when {{ is_date_before_previous_month("date") }}
|
||||
then waiver_net_fees_in_gbp
|
||||
else null
|
||||
end as waiver_net_fees_in_gbp,
|
||||
total_guest_payments_in_gbp as total_guest_payments_in_gbp,
|
||||
guest_payments_per_completed_guest_journey
|
||||
as guest_payments_per_completed_guest_journey,
|
||||
guest_payments_per_paid_guest_journey as guest_payments_per_paid_guest_journey
|
||||
guest_payments_per_paid_guest_journey as guest_payments_per_paid_guest_journey,
|
||||
deposit_fees_in_gbp as deposit_fees_in_gbp,
|
||||
waiver_payments_in_gbp as waiver_payments_in_gbp,
|
||||
checkin_cover_fees_in_gbp as checkin_cover_fees_in_gbp
|
||||
from int_monthly_aggregated_metrics_history_by_deal
|
||||
|
|
|
|||
|
|
@ -37,9 +37,22 @@ from int_mtd_aggregated_metrics
|
|||
*/
|
||||
where
|
||||
(
|
||||
-- Not show current + previous month if revenue metric or resolution
|
||||
(lower(metric) like '%revenue%' or lower(metric) like '%resolutions%')
|
||||
-- Not show current + previous month if the metric depends on invoicing cycle
|
||||
(
|
||||
lower(metric) like '%revenue%'
|
||||
or lower(metric) like '%resolutions%'
|
||||
or lower(metric) like '%invoiced%'
|
||||
or lower(metric) like '%back to host%'
|
||||
or lower(metric) like '%waiver net fees%'
|
||||
)
|
||||
and {{ is_date_before_previous_month("date") }}
|
||||
)
|
||||
-- Keep all history for the rest of metrics
|
||||
or not (lower(metric) like '%revenue%' or lower(metric) like '%resolutions%')
|
||||
or not
|
||||
(
|
||||
lower(metric) like '%revenue%'
|
||||
or lower(metric) like '%resolutions%'
|
||||
or lower(metric) like '%invoiced%'
|
||||
or lower(metric) like '%back to host%'
|
||||
or lower(metric) like '%waiver net fees%'
|
||||
)
|
||||
|
|
|
|||
Loading…
Add table
Add a link
Reference in a new issue