Merged PR 5364: Outstanding Payments

# Description

Adds a field that helps categorize whether we owe money to an account or they owe money to Truvi.
Outstanding Resolutions or Outstanding Invoices

The idea is to include this field as a filter in the Invoicing & Crediting report to help Finance and Resolutions in the payment and approval process.

# Checklist

- [x] The edited models and dependants run properly with production data.
- [x] The edited models are sufficiently documented.
- [x] The edited models contain PK tests, and I've ran and passed them.
- [ ] I have checked for DRY opportunities with other models and docs.
- [ ] I've picked the right materialization for the affected models.

# Other

- [ ] Check if a full-refresh is required after this PR is merged.

Outstanding Payments

Related work items: #30204
This commit is contained in:
Joaquin Ossa 2025-06-03 12:53:59 +00:00
commit 536ab9b2a1
5 changed files with 139 additions and 2 deletions

View file

@ -0,0 +1,36 @@
{% 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,
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, 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,
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

View file

@ -150,4 +150,4 @@ select
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__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

View file

@ -556,4 +556,48 @@ models:
data_type: character varying
description: "The currency of the transaction, represented in ISO 4217 format."
- name: int_xero__deals_due_amounts
description: |
This model provides a view on outstanding amounts related to deals,
specifically focusing on the amounts owed by Truvi or to Truvi.
This includes all AUTHORISED invoices and credit notes.
columns:
- name: id_contact
data_type: character varying
description: |
Unique identifier of a contact.
data_tests:
- not_null
- unique
- name: id_deal
data_type: character varying
description: |
Identifier of the account.
data_tests:
- not_null
- unique
- name: contact_name
data_type: character varying
description: "Name of the contact associated with the deal."
- name: total_due_amount_in_gbp
data_type: numeric
description: |
Total outstanding amount in GBP, which is the sum of all AUTHORISED invoices and credit notes
for the deal, converted to GBP.
- 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"