/* This model provides Month-To-Date (MTD) based on anything related to 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')" %} {% set waiver_items = "('DAMAGE WAVER', 'DAMAGE WAIVER')" %} {% set verification_fee_items = "('VERIFICATION FEE')" %} {% set resolutions_host_payment_account_name = "('RESOLUTIONS - HOST PAYMENT')" %} {% set e_deposit_account_name = "('E-DEPOSIT FEES')" %} {% set guesty_account_name = "('GUESTY FEES', 'GUESTY ADMINISTRATION FEE')" %} {{ config(materialized="table", unique_key=["date", "dimension", "dimension_value"]) }} with int_xero__sales_denom_mart as ( select * from {{ ref("int_xero__sales_denom_mart") }} ), int_dates_mtd as (select * from {{ ref("int_dates_mtd") }}), int_xero__bank_transaction_line_items as ( select * from {{ ref("int_xero__bank_transaction_line_items") }} ), 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") }}), int_core__deal as (select * from {{ ref("int_core__deal") }}), resolution_host_payment as ( {% 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 {% elif dimension.dimension == "'by_billing_country'" %} inner join int_xero__contacts c on c.id_contact = bt.id_contact inner join int_core__deal ud on c.id_deal = ud.id_deal and ud.main_billing_country_iso_3_per_deal is not null {% endif %} group by 1, 2, 3 {% if not loop.last %} union all {% endif %} {% endfor %} ), apis_net_fees as ( {% 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 {% elif dimension.dimension == "'by_billing_country'" %} inner join int_core__deal ud on sdm.id_deal = ud.id_deal and ud.main_billing_country_iso_3_per_deal is not null {% 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 ( {% 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 {% elif dimension.dimension == "'by_billing_country'" %} inner join int_core__deal ud on sdm.id_deal = ud.id_deal and ud.main_billing_country_iso_3_per_deal is not null {% 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 d.year, d.month, d.day, d.date, d.dimension, d.dimension_value, d.is_end_of_month, d.is_current_month, -- HOST/OPERATOR -- hnf.xero_booking_net_fees_in_gbp, hnf.xero_listing_net_fees_in_gbp, hnf.xero_verification_net_fees_in_gbp, nullif( coalesce(hnf.xero_booking_net_fees_in_gbp, 0) + coalesce(hnf.xero_listing_net_fees_in_gbp, 0) + coalesce(hnf.xero_verification_net_fees_in_gbp, 0), 0 ) as xero_operator_net_fees_in_gbp, -- APIs -- anf.xero_e_deposit_net_fees_in_gbp, anf.xero_guesty_net_fees_in_gbp, nullif( coalesce(anf.xero_e_deposit_net_fees_in_gbp, 0) + coalesce(anf.xero_guesty_net_fees_in_gbp, 0), 0 ) as xero_apis_net_fees_in_gbp, -- WAIVERS PAID BACK TO HOST -- hnf.xero_waiver_paid_back_to_host_in_gbp, -- HOST RESOLUTIONS -- rhp.xero_host_resolution_amount_paid_in_gbp, rhp.xero_host_resolution_payment_count 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