Outstanding Payments
This commit is contained in:
parent
d33e5ff2b2
commit
0fdfe651a2
4 changed files with 70 additions and 0 deletions
|
|
@ -10,6 +10,30 @@ with
|
||||||
int_xero__contacts as (select * from {{ ref("int_xero__contacts") }}),
|
int_xero__contacts as (select * from {{ ref("int_xero__contacts") }}),
|
||||||
stg_seed__accounting_aggregations as (
|
stg_seed__accounting_aggregations as (
|
||||||
select * from {{ ref("stg_seed__accounting_aggregations") }}
|
select * from {{ ref("stg_seed__accounting_aggregations") }}
|
||||||
|
),
|
||||||
|
amount_due_deals as (
|
||||||
|
select c.id_deal, 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_deal, 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
|
||||||
|
),
|
||||||
|
outstanding_deals as (
|
||||||
|
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
|
||||||
)
|
)
|
||||||
select
|
select
|
||||||
ili.id_line_item as id_line_item,
|
ili.id_line_item as id_line_item,
|
||||||
|
|
@ -63,6 +87,8 @@ select
|
||||||
i.total_tax_in_gbp as header_total_tax_in_gbp,
|
i.total_tax_in_gbp as header_total_tax_in_gbp,
|
||||||
i.total_due_local_curr as header_total_due_local_curr,
|
i.total_due_local_curr as header_total_due_local_curr,
|
||||||
i.total_due_in_gbp as header_total_due_in_gbp,
|
i.total_due_in_gbp as header_total_due_in_gbp,
|
||||||
|
od.total_outstanding_in_gbp,
|
||||||
|
od.outstanding_type as outstanding_type,
|
||||||
|
|
||||||
c.id_contact as id_contact,
|
c.id_contact as id_contact,
|
||||||
c.id_deal as id_deal,
|
c.id_deal as id_deal,
|
||||||
|
|
@ -78,6 +104,8 @@ from int_xero__invoice_line_items ili
|
||||||
left join int_xero__invoices i on i.id_invoice = ili.id_invoice
|
left join int_xero__invoices i on i.id_invoice = ili.id_invoice
|
||||||
left join int_xero__contacts c on c.id_contact = i.id_contact
|
left join int_xero__contacts c on c.id_contact = i.id_contact
|
||||||
left join stg_seed__accounting_aggregations aa on aa.account_code = ili.account_code
|
left join stg_seed__accounting_aggregations aa on aa.account_code = ili.account_code
|
||||||
|
left join
|
||||||
|
outstanding_deals od on od.id_deal = c.id_deal and i.invoice_status = 'AUTHORISED'
|
||||||
|
|
||||||
union all
|
union all
|
||||||
|
|
||||||
|
|
@ -136,6 +164,8 @@ select
|
||||||
cn.total_tax_in_gbp * -1,
|
cn.total_tax_in_gbp * -1,
|
||||||
cn.remaining_credit_local_curr * -1,
|
cn.remaining_credit_local_curr * -1,
|
||||||
cn.remaining_credit_in_gbp * -1,
|
cn.remaining_credit_in_gbp * -1,
|
||||||
|
od.total_outstanding_in_gbp,
|
||||||
|
od.outstanding_type as outstanding_type,
|
||||||
|
|
||||||
c.id_contact,
|
c.id_contact,
|
||||||
c.id_deal,
|
c.id_deal,
|
||||||
|
|
@ -151,3 +181,7 @@ from int_xero__credit_note_line_items cnli
|
||||||
left join int_xero__credit_notes cn on cn.id_credit_note = cnli.id_credit_note
|
left join int_xero__credit_notes cn on cn.id_credit_note = cnli.id_credit_note
|
||||||
left join int_xero__contacts c on c.id_contact = cn.id_contact
|
left join int_xero__contacts c on c.id_contact = cn.id_contact
|
||||||
left join stg_seed__accounting_aggregations aa on aa.account_code = cnli.account_code
|
left join stg_seed__accounting_aggregations aa on aa.account_code = cnli.account_code
|
||||||
|
left join
|
||||||
|
outstanding_deals od
|
||||||
|
on od.id_deal = c.id_deal
|
||||||
|
and cn.credit_note_status = 'AUTHORISED'
|
||||||
|
|
|
||||||
|
|
@ -322,6 +322,23 @@ models:
|
||||||
data_type: numeric
|
data_type: numeric
|
||||||
description: ""
|
description: ""
|
||||||
|
|
||||||
|
- name: total_outstanding_in_gbp
|
||||||
|
data_type: numeric
|
||||||
|
description: |
|
||||||
|
The total amount outstanding in GBP, which is the sum of all authorized documents
|
||||||
|
or due amounts for the deal account. This includes both invoices and credit notes.
|
||||||
|
|
||||||
|
- name: outstanding_type
|
||||||
|
data_type: character varying
|
||||||
|
description: |
|
||||||
|
Field indicating whether Truvi ows more money to the deal account ('Outstanding Resolutions')
|
||||||
|
or the deal account owes more money to Truvi ('Outstanding Invoices').
|
||||||
|
data_tests:
|
||||||
|
- accepted_values:
|
||||||
|
values:
|
||||||
|
- "Outstanding Resolutions"
|
||||||
|
- "Outstanding Invoices"
|
||||||
|
|
||||||
- name: id_contact
|
- name: id_contact
|
||||||
data_type: character varying
|
data_type: character varying
|
||||||
description: ""
|
description: ""
|
||||||
|
|
|
||||||
|
|
@ -1426,6 +1426,23 @@ models:
|
||||||
data_type: numeric
|
data_type: numeric
|
||||||
description: ""
|
description: ""
|
||||||
|
|
||||||
|
- name: total_outstanding_in_gbp
|
||||||
|
data_type: numeric
|
||||||
|
description: |
|
||||||
|
The total amount outstanding in GBP, which is the sum of all authorized documents
|
||||||
|
or due amounts for the deal account. This includes both invoices and credit notes.
|
||||||
|
|
||||||
|
- name: outstanding_type
|
||||||
|
data_type: character varying
|
||||||
|
description: |
|
||||||
|
Field indicating whether Truvi ows more money to the deal account ('Outstanding Resolutions')
|
||||||
|
or the deal account owes more money to Truvi ('Outstanding Invoices').
|
||||||
|
data_tests:
|
||||||
|
- accepted_values:
|
||||||
|
values:
|
||||||
|
- "Outstanding Resolutions"
|
||||||
|
- "Outstanding Invoices"
|
||||||
|
|
||||||
- name: id_contact
|
- name: id_contact
|
||||||
data_type: character varying
|
data_type: character varying
|
||||||
description: ""
|
description: ""
|
||||||
|
|
|
||||||
|
|
@ -40,6 +40,8 @@ select
|
||||||
sdm.header_total_tax_in_gbp as header_total_tax_in_gbp,
|
sdm.header_total_tax_in_gbp as header_total_tax_in_gbp,
|
||||||
sdm.header_total_due_local_curr as header_total_due_local_curr,
|
sdm.header_total_due_local_curr as header_total_due_local_curr,
|
||||||
sdm.header_total_due_in_gbp as header_total_due_in_gbp,
|
sdm.header_total_due_in_gbp as header_total_due_in_gbp,
|
||||||
|
sdm.total_outstanding_in_gbp as total_outstanding_in_gbp,
|
||||||
|
sdm.outstanding_type as outstanding_type,
|
||||||
sdm.id_contact as id_contact,
|
sdm.id_contact as id_contact,
|
||||||
sdm.id_deal as id_deal,
|
sdm.id_deal as id_deal,
|
||||||
sdm.contact_name as contact_name,
|
sdm.contact_name as contact_name,
|
||||||
|
|
|
||||||
Loading…
Add table
Add a link
Reference in a new issue