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

163 lines
5.4 KiB
MySQL
Raw Normal View History

-- Document Status --
{% set relevant_document_statuses = "('PAID', 'AUTHORISED')" %}
{{ config(materialized="table", unique_key=["date", "id_deal"]) }}
select
-- Unique Key --
ixsdm.document_issued_date_utc as date,
coalesce(ixsdm.id_deal, 'UNSET') as id_deal,
-- Dimensions --
coalesce(
icd.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 = 'Booking Fees'
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
-- New Dash
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_issued_date_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_core__deal") }} as icd on ixsdm.id_deal = icd.id_deal
left join
{{ ref("int_kpis__dimension_daily_accommodation") }} as icmas
on ixsdm.id_deal = icmas.id_deal
and ixsdm.document_issued_date_utc = icmas.date
where upper(ixsdm.document_status) in {{ relevant_document_statuses }}
group by 1, 2, 3, 4