New fields for Invoicing & Crediting

This commit is contained in:
Joaquin 2025-06-11 16:57:10 +02:00
parent 84e8100706
commit 80651ce60e
4 changed files with 121 additions and 10 deletions

View file

@ -9,12 +9,22 @@ with
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, cn.remaining_credit_in_gbp * -1
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
@ -24,6 +34,20 @@ 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
@ -33,4 +57,4 @@ select
else null
end as outstanding_type
from amount_due_deals
group by id_contact, id_deal, contact_name
group by id_contact, id_deal, contact_name, currency

View file

@ -564,6 +564,12 @@ models:
specifically focusing on the amounts owed by Truvi or to Truvi.
This includes all AUTHORISED invoices and credit notes.
data_tests:
- dbt_utils.unique_combination_of_columns:
combination_of_columns:
- id_contact
- currency
columns:
- name: id_contact
@ -572,7 +578,6 @@ models:
Unique identifier of a contact.
data_tests:
- not_null
- unique
- name: id_deal
data_type: character varying
@ -580,17 +585,52 @@ models:
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: currency
data_type: character varying
description: "The currency of the transaction, represented in ISO 4217 format."
data_tests:
- not_null
- name: total_due_invoice_amount_local_curr
data_type: numeric
description: |
Total outstanding amount in the local currency, which is the sum of all AUTHORISED
invoices for the deal.
- name: total_due_invoice_amount_in_gbp
data_type: numeric
description: |
Total outstanding amount in GBP, which is the sum of all AUTHORISED invoices
for the deal, converted to GBP.
- name: total_due_credit_note_amount_local_curr
data_type: numeric
description: |
Total outstanding amount in the local currency, which is the sum of all AUTHORISED
credit notes for the deal.
- name: total_due_credit_note_amount_in_gbp
data_type: numeric
description: |
Total outstanding amount in GBP, which is the sum of all AUTHORISED credit notes
for the deal, converted to GBP.
- name: total_due_amount_local_curr
data_type: numeric
description: |
Total outstanding amount in the local currency, which is the sum of all AUTHORISED
invoices and credit notes for 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.
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

View file

@ -1735,6 +1735,12 @@ models:
specifically focusing on the amounts owed by Truvi or to Truvi.
This includes all AUTHORISED invoices and credit notes.
data_tests:
- dbt_utils.unique_combination_of_columns:
combination_of_columns:
- id_contact
- currency
columns:
- name: id_contact
@ -1743,7 +1749,6 @@ models:
Unique identifier of a contact.
data_tests:
- not_null
- unique
- name: id_deal
data_type: character varying
@ -1751,17 +1756,52 @@ models:
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: currency
data_type: character varying
description: "The currency of the transaction, represented in ISO 4217 format."
data_tests:
- not_null
- name: total_due_invoice_amount_local_curr
data_type: numeric
description: |
Total outstanding amount in the local currency, which is the sum of all AUTHORISED
invoices for the deal.
- name: total_due_invoice_amount_in_gbp
data_type: numeric
description: |
Total outstanding amount in GBP, which is the sum of all AUTHORISED invoices
for the deal, converted to GBP.
- name: total_due_credit_note_amount_local_curr
data_type: numeric
description: |
Total outstanding amount in the local currency, which is the sum of all AUTHORISED
credit notes for the deal.
- name: total_due_credit_note_amount_in_gbp
data_type: numeric
description: |
Total outstanding amount in GBP, which is the sum of all AUTHORISED credit notes
for the deal, converted to GBP.
- name: total_due_amount_local_curr
data_type: numeric
description: |
Total outstanding amount in the local currency, which is the sum of all AUTHORISED
invoices and credit notes for 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.
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

View file

@ -6,6 +6,13 @@ select
dda.id_contact as id_contact,
dda.id_deal as id_deal,
dda.contact_name as contact_name,
dda.currency as currency,
dda.total_due_invoice_amount_local_curr as total_due_invoice_amount_local_curr,
dda.total_due_invoice_amount_in_gbp as total_due_invoice_amount_in_gbp,
dda.total_due_credit_note_amount_local_curr
as total_due_credit_note_amount_local_curr,
dda.total_due_credit_note_amount_in_gbp as total_due_credit_note_amount_in_gbp,
dda.total_due_amount_local_curr as total_due_amount_local_curr,
dda.total_due_amount_in_gbp as total_due_amount_in_gbp,
dda.outstanding_type as outstanding_type
from int_xero__deals_due_amounts dda