# Description Main Changes: * Computes the total booking fees in `int_kpis__metric_daily_invoiced_revenue` * Propagates within KPIs, including schema and tests * Propagates within cross in both "by deal" and "by dimension/global" * Propagates to main kpis tests Small fix: * In `int_mtd_vs_previous_year_metrics`, manual formatting because sqlfmt is broken on this model... # Checklist - [X] The edited models and dependants run properly with production data. - [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: #28560
210 lines
7.3 KiB
SQL
210 lines
7.3 KiB
SQL
-- Document Status --
|
|
{% set relevant_document_statuses = "('PAID', 'AUTHORISED')" %}
|
|
|
|
{{ config(materialized="table", unique_key=["date", "id_deal", "business_scope"]) }}
|
|
select
|
|
-- Unique Key --
|
|
ixsdm.document_is_effective_at_end_of_month_utc as date,
|
|
coalesce(ixsdm.id_deal, 'UNSET') as id_deal,
|
|
case
|
|
when ikdd.client_type = 'API'
|
|
then 'API'
|
|
-- We will assume that any invoice happening in the same month or after the
|
|
-- user has been created in the New Dash is considered as New Dash. This might
|
|
-- not be 100% accurate, but it's a reasonable assumption.
|
|
when ikdd.client_type = 'PLATFORM'
|
|
then
|
|
case
|
|
when
|
|
icnddsd.id_deal is not null
|
|
and date_trunc(
|
|
'month',
|
|
ixsdm.document_is_effective_at_end_of_month_utc
|
|
)::date >= date_trunc(
|
|
'month', icnddsd.min_user_in_new_dash_since_date_utc
|
|
)::date
|
|
and ixsdm.document_is_effective_at_end_of_month_utc
|
|
>= date({{ var("new_dash_first_invoicing_date") }})
|
|
then 'New Dash'
|
|
else 'Old Dash'
|
|
end
|
|
else 'UNSET'
|
|
end as business_scope,
|
|
-- Dimensions --
|
|
coalesce(
|
|
ikdd.main_billing_country_iso_3_per_deal, 'UNSET'
|
|
) as main_billing_country_iso_3_per_deal,
|
|
coalesce(
|
|
icmas.active_accommodations_per_deal_segmentation, 'UNSET'
|
|
) as active_accommodations_per_deal_segmentation,
|
|
-- Metrics --
|
|
sum(
|
|
case
|
|
when ixsdm.accounting_root_aggregation = 'Basic Protection'
|
|
then ixsdm.line_amount_wo_taxes_in_gbp
|
|
else 0
|
|
end
|
|
) as xero_basic_protection_net_fees_in_gbp,
|
|
sum(
|
|
case
|
|
when ixsdm.accounting_root_aggregation = 'Waiver Pro'
|
|
then ixsdm.line_amount_wo_taxes_in_gbp
|
|
else 0
|
|
end
|
|
) as xero_waiver_pro_net_fees_in_gbp,
|
|
sum(
|
|
case
|
|
when ixsdm.accounting_root_aggregation = 'Id Verification'
|
|
then ixsdm.line_amount_wo_taxes_in_gbp
|
|
else 0
|
|
end
|
|
) as xero_id_verification_net_fees_in_gbp,
|
|
sum(
|
|
case
|
|
when ixsdm.accounting_root_aggregation = 'Protection Plus'
|
|
then ixsdm.line_amount_wo_taxes_in_gbp
|
|
else 0
|
|
end
|
|
) as xero_protection_plus_net_fees_in_gbp,
|
|
sum(
|
|
case
|
|
when ixsdm.accounting_root_aggregation = 'Screening Plus'
|
|
then ixsdm.line_amount_wo_taxes_in_gbp
|
|
else 0
|
|
end
|
|
) as xero_screening_plus_net_fees_in_gbp,
|
|
sum(
|
|
case
|
|
when ixsdm.accounting_root_aggregation = 'Sex Offenders Check'
|
|
then ixsdm.line_amount_wo_taxes_in_gbp
|
|
else 0
|
|
end
|
|
) as xero_sex_offenders_check_net_fees_in_gbp,
|
|
sum(
|
|
case
|
|
when ixsdm.accounting_root_aggregation = 'Protection Pro'
|
|
then ixsdm.line_amount_wo_taxes_in_gbp
|
|
else 0
|
|
end
|
|
) as xero_protection_pro_net_fees_in_gbp,
|
|
sum(
|
|
case
|
|
when ixsdm.accounting_root_aggregation = 'Basic Screening'
|
|
then ixsdm.line_amount_wo_taxes_in_gbp
|
|
else 0
|
|
end
|
|
) as xero_basic_screening_net_fees_in_gbp,
|
|
sum(
|
|
case
|
|
when ixsdm.accounting_root_aggregation = 'Old Dashboard Booking Fees'
|
|
then ixsdm.line_amount_wo_taxes_in_gbp
|
|
else 0
|
|
end
|
|
) as xero_old_dashboard_booking_net_fees_in_gbp,
|
|
sum(
|
|
case
|
|
when
|
|
-- Computes total bookings fees from both Old Dash and New Dash
|
|
-- This needs to be properly handled in the aggregation logic once
|
|
-- the alignment with Finance is done.
|
|
ixsdm.accounting_root_aggregation in (
|
|
'Old Dashboard Booking Fees',
|
|
'Basic Protection',
|
|
'Protection Plus',
|
|
'Protection Pro',
|
|
'Basic Screening',
|
|
'Screening Plus',
|
|
'Id Verification',
|
|
'Sex Offenders Check'
|
|
)
|
|
then ixsdm.line_amount_wo_taxes_in_gbp
|
|
else 0
|
|
end
|
|
) as xero_booking_net_fees_in_gbp,
|
|
sum(
|
|
case
|
|
when ixsdm.accounting_root_aggregation = 'Listing Fees'
|
|
then ixsdm.line_amount_wo_taxes_in_gbp
|
|
else 0
|
|
end
|
|
) as xero_listing_net_fees_in_gbp,
|
|
sum(
|
|
case
|
|
when ixsdm.accounting_root_aggregation = 'Verification Fees'
|
|
then ixsdm.line_amount_wo_taxes_in_gbp
|
|
else 0
|
|
end
|
|
) as xero_verification_net_fees_in_gbp,
|
|
sum(
|
|
case
|
|
when
|
|
ixsdm.accounting_kpis_aggregation = 'Invoiced Operator Revenue'
|
|
-- Prior to 1st January 2023 we didn't have the split of Booking
|
|
-- Fees, Listing Fees and Verification Fees. Everything is
|
|
-- considered as Other Invoiced Revenue.
|
|
or (
|
|
ixsdm.accounting_root_aggregation = 'Other Invoiced Revenue'
|
|
and date_trunc(
|
|
'year', ixsdm.document_is_effective_at_end_of_month_utc
|
|
)::date
|
|
= '2022-01-01'::date
|
|
)
|
|
then ixsdm.line_amount_wo_taxes_in_gbp
|
|
else 0
|
|
end
|
|
) as xero_operator_net_fees_in_gbp,
|
|
sum(
|
|
case
|
|
when ixsdm.accounting_root_aggregation = 'Damage Host-Waiver Payments'
|
|
then ixsdm.line_amount_wo_taxes_in_gbp
|
|
else 0
|
|
end
|
|
) as xero_waiver_paid_back_to_host_in_gbp,
|
|
sum(
|
|
case
|
|
when ixsdm.accounting_root_aggregation = 'E-Deposit API'
|
|
then ixsdm.line_amount_wo_taxes_in_gbp
|
|
else 0
|
|
end
|
|
) as xero_e_deposit_net_fees_in_gbp,
|
|
sum(
|
|
case
|
|
when ixsdm.accounting_root_aggregation = 'Athena API'
|
|
then ixsdm.line_amount_wo_taxes_in_gbp
|
|
else 0
|
|
end
|
|
) as xero_athena_net_fees_in_gbp,
|
|
sum(
|
|
case
|
|
when ixsdm.accounting_root_aggregation = 'Guesty Resolutions'
|
|
then ixsdm.line_amount_wo_taxes_in_gbp
|
|
else 0
|
|
end
|
|
) as xero_guesty_resolutions_net_fees_in_gbp,
|
|
sum(
|
|
case
|
|
when ixsdm.accounting_kpis_aggregation = 'Invoiced API Revenue'
|
|
then ixsdm.line_amount_wo_taxes_in_gbp
|
|
else 0
|
|
end
|
|
) as xero_apis_net_fees_in_gbp,
|
|
sum(
|
|
case
|
|
when
|
|
ixsdm.accounting_root_aggregation = 'Guesty Resolutions'
|
|
or ixsdm.accounting_root_aggregation = 'Athena API'
|
|
then ixsdm.line_amount_wo_taxes_in_gbp
|
|
else 0
|
|
end
|
|
) as xero_guesty_net_fees_in_gbp
|
|
from {{ ref("int_xero__sales_denom_mart") }} as ixsdm
|
|
left join {{ ref("int_kpis__dimension_deals") }} as ikdd on ixsdm.id_deal = ikdd.id_deal
|
|
left join
|
|
{{ ref("int_kpis__dimension_daily_accommodation") }} as icmas
|
|
on ixsdm.id_deal = icmas.id_deal
|
|
and ixsdm.document_is_effective_at_end_of_month_utc = icmas.date
|
|
left join
|
|
{{ ref("int_core__new_dash_deal_since_date") }} as icnddsd
|
|
on ixsdm.id_deal = icnddsd.id_deal
|
|
where upper(ixsdm.document_status) in {{ relevant_document_statuses }}
|
|
group by 1, 2, 3, 4, 5
|