data-dwh-dbt-project/models/reporting/xero/xero__net_fees_by_deal.sql

44 lines
1.8 KiB
MySQL
Raw Normal View History

{% 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