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

100 lines
3.8 KiB
MySQL
Raw Normal View History

{% 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')" %}
{% set waiver_items = "('DAMAGE WAVER', 'DAMAGE WAIVER')" %}
{% set verification_fee_items = "('VERIFICATION FEE')" %}
{% set e_deposit_account_name = "('E-DEPOSIT FEES')" %}
{% set guesty_account_name = "('GUESTY FEES', 'GUESTY ADMINISTRATION FEE')" %}
{{ 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 upper(ixsdm.item_code) in {{ booking_fee_items }}
then ixsdm.line_amount_wo_taxes_in_gbp
else null
end
) as xero_booking_net_fees_in_gbp,
sum(
case
when upper(ixsdm.item_code) in {{ listing_fee_items }}
then ixsdm.line_amount_wo_taxes_in_gbp
else null
end
) as xero_listing_net_fees_in_gbp,
sum(
case
when upper(ixsdm.item_code) in {{ verification_fee_items }}
then ixsdm.line_amount_wo_taxes_in_gbp
else null
end
) as xero_verification_net_fees_in_gbp,
sum(
case
when
upper(ixsdm.item_code) in {{ booking_fee_items }}
or upper(ixsdm.item_code) in {{ listing_fee_items }}
or upper(ixsdm.item_code) in {{ verification_fee_items }}
then ixsdm.line_amount_wo_taxes_in_gbp
else null
end
) as xero_operator_net_fees_in_gbp,
sum(
case
when upper(ixsdm.item_code) in {{ waiver_items }}
then ixsdm.line_amount_wo_taxes_in_gbp
else null
end
) as xero_waiver_paid_back_to_host_in_gbp,
sum(
case
when upper(ixsdm.account_name) in {{ e_deposit_account_name }}
then ixsdm.line_amount_wo_taxes_in_gbp
else null
end
) as xero_e_deposit_net_fees_in_gbp,
sum(
case
when upper(ixsdm.account_name) in {{ guesty_account_name }}
then ixsdm.line_amount_wo_taxes_in_gbp
else null
end
) as xero_guesty_net_fees_in_gbp,
sum(
case
when
upper(ixsdm.account_name) in {{ e_deposit_account_name }}
or upper(ixsdm.account_name) in {{ guesty_account_name }}
then ixsdm.line_amount_wo_taxes_in_gbp
else null
end
) as xero_apis_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 }}
and (
upper(ixsdm.item_code) in {{ booking_fee_items }}
or upper(ixsdm.item_code) in {{ listing_fee_items }}
or upper(ixsdm.item_code) in {{ verification_fee_items }}
or upper(ixsdm.item_code) in {{ waiver_items }}
or upper(ixsdm.account_name) in {{ e_deposit_account_name }}
or upper(ixsdm.account_name) in {{ guesty_account_name }}
)
group by 1, 2, 3, 4