data-dwh-dbt-project/models/intermediate/xero/int_xero__deals_due_amounts.sql
2025-06-11 16:57:10 +02:00

60 lines
2.3 KiB
SQL

{% set pending_transactions = "('AUTHORISED')" %}
with
int_xero__invoices as (select * from {{ ref("int_xero__invoices") }}),
int_xero__credit_notes as (select * from {{ ref("int_xero__credit_notes") }}),
int_xero__contacts as (select * from {{ ref("int_xero__contacts") }}),
amount_due_deals as (
select
c.id_contact as id_contact,
c.id_deal as id_deal,
c.contact_name as contact_name,
'invoice' as document_class,
i.invoice_currency_iso_4217 as currency,
i.total_due_local_curr,
i.total_due_in_gbp
from int_xero__invoices i
inner join int_xero__contacts c on c.id_contact = i.id_contact
where i.invoice_status = {{ pending_transactions }} and c.id_deal is not null
union all
select
c.id_contact,
c.id_deal,
c.contact_name,
'credit_note' as document_class,
cn.credit_note_currency_iso_4217 as currency,
cn.remaining_credit_local_curr,
cn.remaining_credit_in_gbp * -1
from int_xero__credit_notes cn
inner join int_xero__contacts c on c.id_contact = cn.id_contact
where
cn.credit_note_status = {{ pending_transactions }} and c.id_deal is not null
)
select
id_contact,
id_deal,
contact_name,
currency,
sum(
case when document_class = 'invoice' then total_due_local_curr else 0 end
) as total_due_invoice_amount_local_curr,
sum(
case when document_class = 'invoice' then total_due_in_gbp else 0 end
) as total_due_invoice_amount_in_gbp,
sum(
case when document_class = 'credit_note' then total_due_local_curr else 0 end
) as total_due_credit_note_amount_local_curr,
sum(
case when document_class = 'credit_note' then total_due_in_gbp else 0 end
) as total_due_credit_note_amount_in_gbp,
sum(coalesce(total_due_local_curr, 0)) as total_due_amount_local_curr,
sum(coalesce(total_due_in_gbp, 0)) as total_due_amount_in_gbp,
case
when sum(coalesce(total_due_in_gbp, 0)) < 0
then 'Outstanding Resolutions'
when sum(coalesce(total_due_in_gbp, 0)) > 0
then 'Outstanding Invoices'
else null
end as outstanding_type
from amount_due_deals
group by id_contact, id_deal, contact_name, currency