{% set resolutions_host_payment_account_name = "('RESOLUTIONS - HOST PAYMENT')" %} {% set relevant_transaction_status = "('AUTHORISED')" %} {{ config(materialized="table", unique_key=["date", "id_deal", "business_scope"]) }} select -- Unique Key -- hrp.transaction_date_utc as date, coalesce(hrp.id_deal, 'UNSET') as id_deal, case when ikdd.client_type = 'API' then 'API' -- We will assume that any host resolution payment 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', hrp.transaction_date_utc)::date >= date_trunc( 'month', icnddsd.min_user_in_new_dash_since_date_utc )::date and hrp.transaction_date_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(hrp.line_amount_wo_taxes_in_gbp) as xero_host_resolution_amount_paid_in_gbp, count(distinct hrp.id_line_item) as xero_host_resolution_payment_count from {{ ref("int_xero__host_resolutions_payments") }} as hrp left join {{ ref("int_kpis__dimension_deals") }} as ikdd on hrp.id_deal = ikdd.id_deal left join {{ ref("int_kpis__dimension_daily_accommodation") }} as icmas on hrp.id_deal = icmas.id_deal and hrp.transaction_date_utc = icmas.date left join {{ ref("int_core__new_dash_deal_since_date") }} as icnddsd on hrp.id_deal = icnddsd.id_deal group by 1, 2, 3, 4, 5