diff --git a/models/intermediate/xero/int_xero__deals_due_amounts.sql b/models/intermediate/xero/int_xero__deals_due_amounts.sql new file mode 100644 index 0000000..0fc0669 --- /dev/null +++ b/models/intermediate/xero/int_xero__deals_due_amounts.sql @@ -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 diff --git a/models/intermediate/xero/int_xero__sales_denom_mart.sql b/models/intermediate/xero/int_xero__sales_denom_mart.sql index e7521cd..e63b9b5 100644 --- a/models/intermediate/xero/int_xero__sales_denom_mart.sql +++ b/models/intermediate/xero/int_xero__sales_denom_mart.sql @@ -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 \ No newline at end of file diff --git a/models/intermediate/xero/schema.yml b/models/intermediate/xero/schema.yml index 00ec773..3278fa9 100644 --- a/models/intermediate/xero/schema.yml +++ b/models/intermediate/xero/schema.yml @@ -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" diff --git a/models/reporting/xero/schema.yml b/models/reporting/xero/schema.yml index 2109406..207cc0d 100644 --- a/models/reporting/xero/schema.yml +++ b/models/reporting/xero/schema.yml @@ -1722,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