/* We have different tables computing fees for different line items coming. The only difference between these tables is what Xero Line Items are we looking into. To avoid copying the same logic multiple times, we created this macro. */ {% macro generate_xero_net_fees_model(item_codes_to_include) %} {% set relevant_document_statuses = "('PAID', 'AUTHORISED')" %} 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") }}), booking_fees_invoiced as ( select extract(year from i.invoice_issued_date_utc) as invoice_issued_year, extract(month from i.invoice_issued_date_utc) as invoice_issued_month, 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 {{ item_codes_to_include }} group by extract(year from i.invoice_issued_date_utc), extract(month from i.invoice_issued_date_utc) ), booking_fees_credited as ( select extract( year from cn.credit_note_issued_date_utc ) as credit_note_issued_year, extract( month from cn.credit_note_issued_date_utc ) as credit_note_issued_month, 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 {{ item_codes_to_include }} group by extract(year from cn.credit_note_issued_date_utc), extract(month from cn.credit_note_issued_date_utc) ) select i.invoice_issued_year as issued_year, i.invoice_issued_month as issued_month, coalesce(i.fees_invoiced, 0) as fees_invoiced, coalesce(c.fees_credited, 0) as fees_credited, (coalesce(i.fees_invoiced, 0) - coalesce(c.fees_credited, 0)) as net_fees from booking_fees_invoiced i left join booking_fees_credited c on i.invoice_issued_year = c.credit_note_issued_year and i.invoice_issued_month = c.credit_note_issued_month {% endmacro %}