Merged PR 5441: New fields for Invoicing & Crediting
# Description New fields for Invoicing & Crediting that Finance needs for their usage. Specifically they need to be able to differentiate the amount due because of invoice and not credit notes to know who to pay resolutions claims or not. Will also add the amounts in local currency. # 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. New fields for Invoicing & Crediting Related work items: #30204
This commit is contained in:
commit
5abbff9560
4 changed files with 129 additions and 10 deletions
|
|
@ -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
|
||||
|
|
|
|||
|
|
@ -564,6 +564,16 @@ 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
|
||||
- dbt_utils.unique_combination_of_columns:
|
||||
combination_of_columns:
|
||||
- id_deal
|
||||
- currency
|
||||
|
||||
columns:
|
||||
|
||||
- name: id_contact
|
||||
|
|
@ -572,7 +582,6 @@ models:
|
|||
Unique identifier of a contact.
|
||||
data_tests:
|
||||
- not_null
|
||||
- unique
|
||||
|
||||
- name: id_deal
|
||||
data_type: character varying
|
||||
|
|
@ -580,17 +589,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
|
||||
|
|
|
|||
|
|
@ -1735,6 +1735,16 @@ 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
|
||||
- dbt_utils.unique_combination_of_columns:
|
||||
combination_of_columns:
|
||||
- id_deal
|
||||
- currency
|
||||
|
||||
columns:
|
||||
|
||||
- name: id_contact
|
||||
|
|
@ -1743,7 +1753,6 @@ models:
|
|||
Unique identifier of a contact.
|
||||
data_tests:
|
||||
- not_null
|
||||
- unique
|
||||
|
||||
- name: id_deal
|
||||
data_type: character varying
|
||||
|
|
@ -1751,17 +1760,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
|
||||
|
|
|
|||
|
|
@ -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
|
||||
|
|
|
|||
Loading…
Add table
Add a link
Reference in a new issue