diff --git a/models/intermediate/xero/int_xero__deals_due_amounts.sql b/models/intermediate/xero/int_xero__deals_due_amounts.sql new file mode 100644 index 0000000..142e1c5 --- /dev/null +++ b/models/intermediate/xero/int_xero__deals_due_amounts.sql @@ -0,0 +1,40 @@ +with + int_xero__invoice_line_items as ( + select * from {{ ref("int_xero__invoice_line_items") }} + ), + int_xero__invoices as (select * from {{ ref("int_xero__invoices") }}), + int_xero__credit_note_line_items as ( + select * from {{ ref("int_xero__credit_note_line_items") }} + ), + int_xero__credit_notes as (select * from {{ ref("int_xero__credit_notes") }}), + int_xero__contacts as (select * from {{ ref("int_xero__contacts") }}), + stg_seed__accounting_aggregations as ( + select * from {{ ref("stg_seed__accounting_aggregations") }} + ), + amount_due_deals as ( + select c.id_contact as id_contact, + c.id_deal as id_deal, + c.contact_name as contact_name, + i.total_due_in_gbp + from int_xero__invoices i + left join int_xero__contacts c on c.id_contact = i.id_contact + where i.invoice_status = 'AUTHORISED' and c.id_deal is not null + union all + select c.id_contact, + c.id_deal, + c.contact_name, cn.remaining_credit_in_gbp * -1 + from int_xero__credit_notes cn + left join int_xero__contacts c on c.id_contact = cn.id_contact + where cn.credit_note_status = 'AUTHORISED' and c.id_deal is not null + ) + select + id_deal, + sum(total_due_in_gbp) as total_outstanding_in_gbp, + case + when sum(total_due_in_gbp) < 0 + then 'Outstanding Resolutions' + when sum(total_due_in_gbp) >= 0 + then 'Outstanding Invoices' + end as outstanding_type + from amount_due_deals + group by id_deal \ No newline at end of file