{% 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')" %} with xero__invoice_line_items as (select * from {{ ref("xero__invoice_line_items") }}), xero__invoices as (select * from {{ ref("xero__invoices") }}), xero__credit_note_line_items as ( select * from {{ ref("xero__credit_note_line_items") }} ), xero__credit_notes as (select * from {{ ref("xero__credit_notes") }}), fees_invoiced as ( select cast( date_trunc('month', i.invoice_issued_date_utc) as date ) as invoice_issued_year_month, case when ili.item_code in {{ booking_fee_items }} then 'booking_fees' when ili.item_code in {{ listing_fee_items }} then 'listing_fees' when ili.item_code in {{ verification_fee_items }} then 'verification_fees' when ili.item_code in {{ waiver_items }} then 'damager_waiver' else null end as fee_category, sum(ili.line_amount_wo_taxes_in_gbp) as fees_invoiced from xero__invoice_line_items ili left join xero__invoices i on i.id_invoice = ili.id_invoice where i.invoice_status in {{ relevant_document_statuses }} and ( ili.item_code in {{ booking_fee_items }} or ili.item_code in {{ listing_fee_items }} or ili.item_code in {{ verification_fee_items }} or ili.item_code in {{ waiver_items }} ) group by date_trunc('month', i.invoice_issued_date_utc), case when ili.item_code in {{ booking_fee_items }} then 'booking_fees' when ili.item_code in {{ listing_fee_items }} then 'listing_fees' when ili.item_code in {{ verification_fee_items }} then 'verification_fees' when ili.item_code in {{ waiver_items }} then 'damager_waiver' else null end ), fees_credited as ( select cast( date_trunc('month', cn.credit_note_issued_date_utc) as date ) as credit_note_issued_year_month, case when cnli.item_code in {{ booking_fee_items }} then 'booking_fees' when cnli.item_code in {{ listing_fee_items }} then 'listing_fees' when cnli.item_code in {{ verification_fee_items }} then 'verification_fees' when cnli.item_code in {{ waiver_items }} then 'damager_waiver' else null end as fee_category, sum(cnli.line_amount_wo_taxes_in_gbp) as fees_credited from reporting.xero__credit_note_line_items cnli left join reporting.xero__credit_notes cn on cn.id_credit_note = cnli.id_credit_note where cn.credit_note_status in {{ relevant_document_statuses }} and ( cnli.item_code in {{ booking_fee_items }} or cnli.item_code in {{ listing_fee_items }} or cnli.item_code in {{ verification_fee_items }} or cnli.item_code in {{ waiver_items }} ) group by date_trunc('month', cn.credit_note_issued_date_utc), case when cnli.item_code in {{ booking_fee_items }} then 'booking_fees' when cnli.item_code in {{ listing_fee_items }} then 'listing_fees' when cnli.item_code in {{ verification_fee_items }} then 'verification_fees' when cnli.item_code in {{ waiver_items }} then 'damager_waiver' else null end ) select coalesce( i.invoice_issued_year_month, c.credit_note_issued_year_month ) as issued_year_month, coalesce(i.fee_category, c.fee_category) as fee_category, coalesce(i.fees_invoiced, 0) as fees_invoiced_in_gbp, coalesce(c.fees_credited, 0) as fees_credited_in_gbp, (coalesce(i.fees_invoiced, 0) - coalesce(c.fees_credited, 0)) as net_fees_in_gbp from fees_invoiced i full outer join fees_credited c on i.invoice_issued_year_month = c.credit_note_issued_year_month and i.fee_category = c.fee_category