Merged PR 2583: Invoicing metrics per customer segmentation
# Description Silly change: * Modifies `int_core__mtd_guest_payments_metrics` to apply the proper key on date, dimension and dimension_value. * -> *The weird thing is that the previous dbt test I run worked well. Is it possible that the configuration in the schema file prevails on top of the model configuration? I thought it was the other way around...* Main changes: * Modifies `int_xero__mtd_invoicing_metrics` to include the customer segmentation based on listings. * `schema.yaml` is also affected including new fields and tests * Added the macro to retrieve the production dimension in `int_core__mtd_vs_previous_year_metrics` to avoid propagating this upwards and messing up with the data display. Overall, follows a similar strategy as we did for Booking, Guest Journey, Deal, Accommodation and Guest Payments metrics. For reference, [here's the previous PR on Guest Payments](https://guardhog.visualstudio.com/Data/_git/data-dwh-dbt-project/pullrequest/2580). This is the last PR on the source models for KPIs. Will follow: propagation + exposure # Checklist - [X] The edited models and dependants run properly with production data. * **Important note**: this segmentation provides null values for all API-related KPIs. Makes sense, since the 4 deal id we have for APIs do NOT have, or have had, a listing linked to them. I'd say it's not a blocker. - [X] The edited models are sufficiently documented. - [X] The edited models contain PK tests, and I've ran and passed them. - [X] I have checked for DRY opportunities with other models and docs. - [X] I've picked the right materialization for the affected models. # Other - [ ] Check if a full-refresh is required after this PR is merged. Related work items: #19325
This commit is contained in:
parent
68f490f9fa
commit
80abac494a
4 changed files with 183 additions and 97 deletions
|
|
@ -4,6 +4,8 @@ invoicing metrics. This includes Operator (Host) fees, waiver payments,
|
|||
APIs and Host Resolutions.
|
||||
|
||||
*/
|
||||
{% set dimensions = get_kpi_dimensions() %}
|
||||
|
||||
{% set relevant_document_statuses = "('PAID', 'AUTHORISED')" %}
|
||||
{% set booking_fee_items = "('EU BOOKING FEE','ZAR BOOKINGS','BOOKING FEE - NON-UK','USD BOOKINGS','CAD BOOKINGS','BOOKING FEE - UK','AUD BOOKINGS')" %}
|
||||
{% set listing_fee_items = "('USD LISTINGS','LISTING FEE - NON UK','ZAR LISTINGS','CAD LISTINGS','LISTING FEE - UK','AUD LISTINGS','EU LISTINGS')" %}
|
||||
|
|
@ -13,7 +15,7 @@ APIs and Host Resolutions.
|
|||
{% set e_deposit_account_name = "('E-DEPOSIT FEES')" %}
|
||||
{% set guesty_account_name = "('GUESTY FEES', 'GUESTY ADMINISTRATION FEE')" %}
|
||||
|
||||
{{ config(materialized="table", unique_key="date") }}
|
||||
{{ config(materialized="table", unique_key=["date", "dimension", "dimension_value"]) }}
|
||||
with
|
||||
int_xero__sales_denom_mart as (
|
||||
select * from {{ ref("int_xero__sales_denom_mart") }}
|
||||
|
|
@ -25,101 +27,149 @@ with
|
|||
int_xero__bank_transactions as (
|
||||
select * from {{ ref("int_xero__bank_transactions") }}
|
||||
),
|
||||
|
||||
int_core__mtd_accommodation_segmentation as (
|
||||
select * from {{ ref("int_core__mtd_accommodation_segmentation") }}
|
||||
),
|
||||
int_dates_mtd_by_dimension as (
|
||||
select * from {{ ref("int_dates_mtd_by_dimension") }}
|
||||
),
|
||||
int_xero__contacts as (select * from {{ ref("int_xero__contacts") }}),
|
||||
resolution_host_payment as (
|
||||
select
|
||||
d.date,
|
||||
sum(
|
||||
btli.line_amount_wo_taxes_in_gbp
|
||||
) as xero_host_resolution_amount_paid_in_gbp,
|
||||
count(distinct bt.id_bank_transaction) as xero_host_resolution_payment_count
|
||||
from int_dates_mtd d
|
||||
inner join
|
||||
int_xero__bank_transactions bt
|
||||
on date_trunc('month', bt.transaction_date_utc)::date = d.first_day_month
|
||||
and extract(day from bt.transaction_date_utc) <= d.day
|
||||
inner join
|
||||
int_xero__bank_transaction_line_items btli
|
||||
on bt.id_bank_transaction = btli.id_bank_transaction
|
||||
and upper(btli.account_name) in {{ resolutions_host_payment_account_name }}
|
||||
group by 1
|
||||
{% for dimension in dimensions %}
|
||||
select
|
||||
d.date,
|
||||
{{ dimension.dimension }} as dimension,
|
||||
{{ dimension.dimension_value }} as dimension_value,
|
||||
sum(
|
||||
btli.line_amount_wo_taxes_in_gbp
|
||||
) as xero_host_resolution_amount_paid_in_gbp,
|
||||
count(
|
||||
distinct bt.id_bank_transaction
|
||||
) as xero_host_resolution_payment_count
|
||||
from int_dates_mtd d
|
||||
inner join
|
||||
int_xero__bank_transactions bt
|
||||
on date_trunc('month', bt.transaction_date_utc)::date = d.first_day_month
|
||||
and extract(day from bt.transaction_date_utc) <= d.day
|
||||
inner join
|
||||
int_xero__bank_transaction_line_items btli
|
||||
on bt.id_bank_transaction = btli.id_bank_transaction
|
||||
and upper(btli.account_name)
|
||||
in {{ resolutions_host_payment_account_name }}
|
||||
{% if dimension.dimension == "'by_number_of_listings'" %}
|
||||
inner join int_xero__contacts c on c.id_contact = bt.id_contact
|
||||
inner join
|
||||
int_core__mtd_accommodation_segmentation mas
|
||||
on c.id_deal = mas.id_deal
|
||||
and d.date = mas.date
|
||||
{% endif %}
|
||||
group by 1, 2, 3
|
||||
{% if not loop.last %}
|
||||
union all
|
||||
{% endif %}
|
||||
{% endfor %}
|
||||
),
|
||||
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
|
||||
{% for dimension in dimensions %}
|
||||
select
|
||||
d.date,
|
||||
{{ dimension.dimension }} as dimension,
|
||||
{{ dimension.dimension_value }} as dimension_value,
|
||||
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
|
||||
{% if dimension.dimension == "'by_number_of_listings'" %}
|
||||
inner join
|
||||
int_core__mtd_accommodation_segmentation mas
|
||||
on sdm.id_deal = mas.id_deal
|
||||
and d.date = mas.date
|
||||
{% endif %}
|
||||
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, 2, 3
|
||||
{% if not loop.last %}
|
||||
union all
|
||||
{% endif %}
|
||||
{% endfor %}
|
||||
),
|
||||
host_net_fees as (
|
||||
select
|
||||
d.date,
|
||||
sum(
|
||||
case
|
||||
when upper(sdm.item_code) in {{ booking_fee_items }}
|
||||
then sdm.line_amount_wo_taxes_in_gbp
|
||||
else 0
|
||||
end
|
||||
) as xero_booking_net_fees_in_gbp,
|
||||
sum(
|
||||
case
|
||||
when upper(sdm.item_code) in {{ listing_fee_items }}
|
||||
then sdm.line_amount_wo_taxes_in_gbp
|
||||
else 0
|
||||
end
|
||||
) as xero_listing_net_fees_in_gbp,
|
||||
sum(
|
||||
case
|
||||
when upper(sdm.item_code) in {{ verification_fee_items }}
|
||||
then sdm.line_amount_wo_taxes_in_gbp
|
||||
else 0
|
||||
end
|
||||
) as xero_verification_net_fees_in_gbp,
|
||||
sum(
|
||||
case
|
||||
when upper(sdm.item_code) in {{ waiver_items }}
|
||||
then sdm.line_amount_wo_taxes_in_gbp
|
||||
else 0
|
||||
end
|
||||
) as xero_waiver_paid_back_to_host_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.item_code) in {{ booking_fee_items }}
|
||||
or upper(sdm.item_code) in {{ listing_fee_items }}
|
||||
or upper(sdm.item_code) in {{ verification_fee_items }}
|
||||
or upper(sdm.item_code) in {{ waiver_items }}
|
||||
)
|
||||
group by 1
|
||||
|
||||
{% for dimension in dimensions %}
|
||||
select
|
||||
d.date,
|
||||
{{ dimension.dimension }} as dimension,
|
||||
{{ dimension.dimension_value }} as dimension_value,
|
||||
sum(
|
||||
case
|
||||
when upper(sdm.item_code) in {{ booking_fee_items }}
|
||||
then sdm.line_amount_wo_taxes_in_gbp
|
||||
else 0
|
||||
end
|
||||
) as xero_booking_net_fees_in_gbp,
|
||||
sum(
|
||||
case
|
||||
when upper(sdm.item_code) in {{ listing_fee_items }}
|
||||
then sdm.line_amount_wo_taxes_in_gbp
|
||||
else 0
|
||||
end
|
||||
) as xero_listing_net_fees_in_gbp,
|
||||
sum(
|
||||
case
|
||||
when upper(sdm.item_code) in {{ verification_fee_items }}
|
||||
then sdm.line_amount_wo_taxes_in_gbp
|
||||
else 0
|
||||
end
|
||||
) as xero_verification_net_fees_in_gbp,
|
||||
sum(
|
||||
case
|
||||
when upper(sdm.item_code) in {{ waiver_items }}
|
||||
then sdm.line_amount_wo_taxes_in_gbp
|
||||
else 0
|
||||
end
|
||||
) as xero_waiver_paid_back_to_host_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
|
||||
{% if dimension.dimension == "'by_number_of_listings'" %}
|
||||
inner join
|
||||
int_core__mtd_accommodation_segmentation mas
|
||||
on sdm.id_deal = mas.id_deal
|
||||
and d.date = mas.date
|
||||
{% endif %}
|
||||
where
|
||||
upper(sdm.document_status) in {{ relevant_document_statuses }}
|
||||
and (
|
||||
upper(sdm.item_code) in {{ booking_fee_items }}
|
||||
or upper(sdm.item_code) in {{ listing_fee_items }}
|
||||
or upper(sdm.item_code) in {{ verification_fee_items }}
|
||||
or upper(sdm.item_code) in {{ waiver_items }}
|
||||
)
|
||||
group by 1, 2, 3
|
||||
{% if not loop.last %}
|
||||
union all
|
||||
{% endif %}
|
||||
{% endfor %}
|
||||
)
|
||||
-- Final aggregation of subqueries --
|
||||
select
|
||||
|
|
@ -127,6 +177,8 @@ select
|
|||
d.month,
|
||||
d.day,
|
||||
d.date,
|
||||
d.dimension,
|
||||
d.dimension_value,
|
||||
d.is_end_of_month,
|
||||
d.is_current_month,
|
||||
-- HOST/OPERATOR --
|
||||
|
|
@ -152,7 +204,19 @@ select
|
|||
-- 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
|
||||
from int_dates_mtd_by_dimension d
|
||||
left join
|
||||
resolution_host_payment rhp
|
||||
on rhp.date = d.date
|
||||
and rhp.dimension = d.dimension
|
||||
and rhp.dimension_value = d.dimension_value
|
||||
left join
|
||||
apis_net_fees anf
|
||||
on anf.date = d.date
|
||||
and anf.dimension = d.dimension
|
||||
and anf.dimension_value = d.dimension_value
|
||||
left join
|
||||
host_net_fees hnf
|
||||
on hnf.date = d.date
|
||||
and hnf.dimension = d.dimension
|
||||
and hnf.dimension_value = d.dimension_value
|
||||
|
|
|
|||
|
|
@ -291,10 +291,31 @@ models:
|
|||
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.
|
||||
|
||||
tests:
|
||||
- dbt_utils.unique_combination_of_columns:
|
||||
combination_of_columns:
|
||||
- date
|
||||
- dimension
|
||||
- dimension_value
|
||||
|
||||
columns:
|
||||
- name: date
|
||||
data_type: date
|
||||
description: The date for the month-to-date invoicing-related metrics.
|
||||
tests:
|
||||
- not_null
|
||||
- unique
|
||||
|
||||
- name: dimension
|
||||
data_type: string
|
||||
description: The dimension or granularity of the metrics.
|
||||
tests:
|
||||
- accepted_values:
|
||||
values:
|
||||
- global
|
||||
- by_number_of_listings
|
||||
|
||||
- name: dimension_value
|
||||
data_type: string
|
||||
description: The value or segment available for the selected dimension.
|
||||
tests:
|
||||
- not_null
|
||||
|
|
|
|||
Loading…
Add table
Add a link
Reference in a new issue