diff --git a/models/reporting/xero/schema.yaml b/models/reporting/xero/schema.yaml index a0d92c0..0067437 100644 --- a/models/reporting/xero/schema.yaml +++ b/models/reporting/xero/schema.yaml @@ -1139,7 +1139,49 @@ models: data_type: text description: | A fee category, one of out of booking_fees, listing_fees, - verification_fees. + verification_fees, waiver fees. + + - name: fees_invoiced_in_gbp + data_type: numeric + description: The total sum of invoiced fees. + + - name: fees_credited_in_gbp + data_type: numeric + description: The total sum of credited fees. + + - name: net_fees_in_gbp + data_type: numeric + description: | + Net fees are calculated by subtracting credited fees from invoiced + fees. It might be the case that net fees are negative in some month, + if it happens to be that we have given back to customers more than we + have invoiced them. + + - name: xero__net_fees_by_deal + description: | + A summary aggregation table showing the total raw and net fees by month + and year, dedicated for deal attribution. + + Information comes from both Invoices and Credit notes. + + Only documents in statuses ('PAID', 'AUTHORISED') are kept. + + Net fees get computed by subtracting credited amounts from invoiced + amounts. + + columns: + - name: issued_year + data_type: numeric + description: The issuing year of the aggregated documents. + + - name: issued_month + data_type: numeric + description: The issuing month of the aggregated documents. + + - name: id_deal + data_type: text + description: | + A fee category per deal. - name: fees_invoiced_in_gbp data_type: numeric diff --git a/models/reporting/xero/xero__net_fees_by_deal.sql b/models/reporting/xero/xero__net_fees_by_deal.sql new file mode 100644 index 0000000..19e5698 --- /dev/null +++ b/models/reporting/xero/xero__net_fees_by_deal.sql @@ -0,0 +1,43 @@ +{% set relevant_document_statuses = "('PAID', 'AUTHORISED')" %} + +with + xero__invoices as (select * from {{ ref("xero__invoices") }}), + xero__credit_notes as (select * from {{ ref("xero__credit_notes") }}), + xero__contacts as (select * from {{ ref("xero__contacts") }}), + fees_invoiced as ( + select + cast( + date_trunc('month', i.invoice_issued_date_utc) as date + ) as invoice_issued_year_month, + c.id_deal, + sum(i.total_amount_wo_tax_in_gbp) as fees_invoiced + from xero__invoices i + left join xero__contacts c on i.id_contact = c.id_contact + where i.invoice_status in {{ relevant_document_statuses }} + group by date_trunc('month', i.invoice_issued_date_utc), c.id_deal + ), + fees_credited as ( + select + cast( + date_trunc('month', cn.credit_note_issued_at_utc) as date + ) as credit_note_issued_year_month, + c.id_deal, + sum(cn.subtotal_in_gbp) as fees_credited + from xero__credit_notes cn + left join xero__contacts c on cn.id_contact = c.id_contact + where cn.credit_note_status in {{ relevant_document_statuses }} + group by date_trunc('month', cn.credit_note_issued_at_utc), c.id_deal + ) +select + coalesce( + i.invoice_issued_year_month, c.credit_note_issued_year_month + ) as issued_year_month, + coalesce(i.id_deal, c.id_deal) as id_deal, + 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.id_deal = c.id_deal