data-dwh-dbt-project/models/intermediate/kpis/int_kpis__metric_daily_invoiced_revenue.sql

232 lines
8 KiB
MySQL
Raw Normal View History

-- 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
Merged PR 4727: Bookings fees are now Old Dashboard Booking Fees in Main KPIs # Description Booking fees is widely used with different meanings, for old dash, for new dash, for both, etc. This is painful. First step to align on a proper naming is ensure that what we report in Main KPIs is clearly stated, which in this case, Booking Fees are now called Old Dashboard Booking Fees. Changes: * Modify `stg_seed__accounting_aggregations` seed to rename Booking Fees to Old Dashboard Booking Fees. This is for us to clarify. This is only applied for KPIs compute. I also added an empty space that I mistakenly forgot in the past for `financial_l3_aggregation`. * Modify KPIs source, i.e., `int_kpis__metric_daily_invoiced_revenue`. Here I forcefully modify the name of the field to `xero_old_dashboard_booking_net_fees_in_gbp`. * Propagate changes of downstream usages of `xero_booking_net_fees_in_gbp` to `xero_old_dashboard_booking_net_fees_in_gbp`. This affects all models, including the reporting model. On this one we still have both names to avoid breaking it. I will need to modify the data glossary in PBI anyway so I'll do this change as well. * Modify displayed metric name from Booking Fees Revenue to Old Dashboard Booking Fees Revenue. * Modify schema so it reflects the proper names, descriptions, and tests. * Ensure outlier and completion tests still work after this change. I confirm the field `xero_booking_net_fees_in_gbp` does not exist anymore in the rest of DWH after these changes, except for the abovementioned comment on the reporting line. # 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
2025-03-18 14:55:32 +00:00
when ixsdm.accounting_root_aggregation = 'Old Dashboard Booking Fees'
then ixsdm.line_amount_wo_taxes_in_gbp
else 0
end
Merged PR 4727: Bookings fees are now Old Dashboard Booking Fees in Main KPIs # Description Booking fees is widely used with different meanings, for old dash, for new dash, for both, etc. This is painful. First step to align on a proper naming is ensure that what we report in Main KPIs is clearly stated, which in this case, Booking Fees are now called Old Dashboard Booking Fees. Changes: * Modify `stg_seed__accounting_aggregations` seed to rename Booking Fees to Old Dashboard Booking Fees. This is for us to clarify. This is only applied for KPIs compute. I also added an empty space that I mistakenly forgot in the past for `financial_l3_aggregation`. * Modify KPIs source, i.e., `int_kpis__metric_daily_invoiced_revenue`. Here I forcefully modify the name of the field to `xero_old_dashboard_booking_net_fees_in_gbp`. * Propagate changes of downstream usages of `xero_booking_net_fees_in_gbp` to `xero_old_dashboard_booking_net_fees_in_gbp`. This affects all models, including the reporting model. On this one we still have both names to avoid breaking it. I will need to modify the data glossary in PBI anyway so I'll do this change as well. * Modify displayed metric name from Booking Fees Revenue to Old Dashboard Booking Fees Revenue. * Modify schema so it reflects the proper names, descriptions, and tests. * Ensure outlier and completion tests still work after this change. I confirm the field `xero_booking_net_fees_in_gbp` does not exist anymore in the rest of DWH after these changes, except for the abovementioned comment on the reporting line. # 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
2025-03-18 14:55:32 +00:00
) 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,
2025-04-16 14:27:23 +02:00
sum(
case
when ixsdm.accounting_root_aggregation = 'Check in Hero API'
then ixsdm.line_amount_wo_taxes_in_gbp
else 0
end
) as xero_check_in_hero_api_net_fees_in_gbp,
sum(
case
when ixsdm.accounting_root_aggregation = 'Screen and Protect API'
then ixsdm.line_amount_wo_taxes_in_gbp
else 0
end
2025-04-16 16:18:14 +02:00
) as xero_screen_and_protect_net_fees_in_gbp,
2025-06-11 14:44:07 +02:00
sum(
case
when ixsdm.accounting_root_aggregation = 'Flex API'
then ixsdm.line_amount_wo_taxes_in_gbp
else 0
end
) as xero_flex_api_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