From d50442e88779e0bf716d2e65838c2fd9097efcea Mon Sep 17 00:00:00 2001 From: Joaquin Date: Tue, 3 Jun 2025 11:53:40 +0200 Subject: [PATCH] New model for deals total due amount --- .../xero/int_xero__deals_due_amounts.sql | 51 ++++++++-------- .../xero/int_xero__sales_denom_mart.sql | 34 +---------- models/intermediate/xero/schema.yml | 55 +++++++++++++---- models/reporting/xero/schema.yml | 59 +++++++++++++++---- .../xero/xero__deals_due_amounts.sql | 11 ++++ .../reporting/xero/xero__sales_denom_mart.sql | 1 - 6 files changed, 129 insertions(+), 82 deletions(-) create mode 100644 models/reporting/xero/xero__deals_due_amounts.sql diff --git a/models/intermediate/xero/int_xero__deals_due_amounts.sql b/models/intermediate/xero/int_xero__deals_due_amounts.sql index 828c4b6..c328a15 100644 --- a/models/intermediate/xero/int_xero__deals_due_amounts.sql +++ b/models/intermediate/xero/int_xero__deals_due_amounts.sql @@ -1,38 +1,39 @@ +{% set pending_transactions = "('AUTHORISED')" %} + with - int_xero__invoices as (select * from {{ ref("int_xero__invoices") }}), + 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") }}), 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 + 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 + 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, 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 + where + cn.credit_note_status = {{ pending_transactions }} and c.id_deal is not null ) - select - id_contact, - id_deal, - contact_name, - 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_contact, - id_deal, - contact_name \ No newline at end of file +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 diff --git a/models/intermediate/xero/int_xero__sales_denom_mart.sql b/models/intermediate/xero/int_xero__sales_denom_mart.sql index d3ba738..e63b9b5 100644 --- a/models/intermediate/xero/int_xero__sales_denom_mart.sql +++ b/models/intermediate/xero/int_xero__sales_denom_mart.sql @@ -10,30 +10,6 @@ with 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_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 ili.id_line_item as id_line_item, @@ -87,7 +63,6 @@ select 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_in_gbp as header_total_due_in_gbp, - od.outstanding_type as outstanding_type, c.id_contact as id_contact, c.id_deal as id_deal, @@ -103,8 +78,6 @@ from int_xero__invoice_line_items ili 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 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 @@ -163,7 +136,6 @@ select cn.total_tax_in_gbp * -1, cn.remaining_credit_local_curr * -1, cn.remaining_credit_in_gbp * -1, - od.outstanding_type as outstanding_type, c.id_contact, c.id_deal, @@ -178,8 +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 - outstanding_deals od - on od.id_deal = c.id_deal - and cn.credit_note_status = 'AUTHORISED' +left join stg_seed__accounting_aggregations aa on aa.account_code = cnli.account_code \ No newline at end of file diff --git a/models/intermediate/xero/schema.yml b/models/intermediate/xero/schema.yml index 306c65a..3278fa9 100644 --- a/models/intermediate/xero/schema.yml +++ b/models/intermediate/xero/schema.yml @@ -322,17 +322,6 @@ models: data_type: numeric description: "" - - 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 data_type: character varying description: "" @@ -567,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" diff --git a/models/reporting/xero/schema.yml b/models/reporting/xero/schema.yml index 02e8d23..207cc0d 100644 --- a/models/reporting/xero/schema.yml +++ b/models/reporting/xero/schema.yml @@ -1426,17 +1426,6 @@ models: data_type: numeric description: "" - - 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 data_type: character varying description: "" @@ -1733,4 +1722,50 @@ models: - name: contact_status data_type: character varying - description: "" \ No newline at end of file + description: "" + + - name: 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" + \ No newline at end of file diff --git a/models/reporting/xero/xero__deals_due_amounts.sql b/models/reporting/xero/xero__deals_due_amounts.sql new file mode 100644 index 0000000..e2e90df --- /dev/null +++ b/models/reporting/xero/xero__deals_due_amounts.sql @@ -0,0 +1,11 @@ +with + int_xero__deals_due_amounts as ( + select * from {{ ref("int_xero__deals_due_amounts") }} + ) +select + dda.id_contact as id_contact, + dda.id_deal as id_deal, + dda.contact_name as contact_name, + 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 diff --git a/models/reporting/xero/xero__sales_denom_mart.sql b/models/reporting/xero/xero__sales_denom_mart.sql index 72273de..db18fa9 100644 --- a/models/reporting/xero/xero__sales_denom_mart.sql +++ b/models/reporting/xero/xero__sales_denom_mart.sql @@ -40,7 +40,6 @@ select 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_in_gbp as header_total_due_in_gbp, - sdm.outstanding_type as outstanding_type, sdm.id_contact as id_contact, sdm.id_deal as id_deal, sdm.contact_name as contact_name,