Merged PR 2161: Sign for bank transactions

The bank transactions table coming from Xero has positive amounts for all transactions by default.

Nevertheless, some transactions are receiving and some are sending.

This PR implements sign for transactions amounts throughout the DWH so that aggregations work properly.

I've also left the transaction sign column in some spots since it might be useful for some aggregation wizardry (ie cancel out receiving transactions in resolutions so that counts are more accurate).

Related work items: #17551
This commit is contained in:
Pablo Martín 2024-07-01 12:02:25 +00:00
commit 915b9d5165
7 changed files with 115 additions and 42 deletions

View file

@ -14,42 +14,53 @@ select
j.item_code,
j.quantity::numeric,
j.unit_amount::numeric,
j.line_amount_local_curr::numeric,
(j.line_amount_local_curr::numeric * bt.exchange_rate_to_gbp)::numeric(
18, 4
) as line_amount_in_gbp,
case
when bt.line_amount_tax_inclusiveness = 'Inclusive'
then j.line_amount_local_curr::numeric - j.tax_amount_local_curr::numeric
when bt.line_amount_tax_inclusiveness = 'Exclusive'
then j.line_amount_local_curr::numeric
when bt.line_amount_tax_inclusiveness = 'NoTax'
then j.line_amount_local_curr::numeric
else null
end as line_amount_wo_taxes_local_curr,
case
when bt.line_amount_tax_inclusiveness = 'Inclusive'
then
(
(j.line_amount_local_curr::numeric - j.tax_amount_local_curr::numeric)
* bt.exchange_rate_to_gbp
)::numeric(18, 4)
when bt.line_amount_tax_inclusiveness = 'Exclusive'
then
(j.line_amount_local_curr::numeric * bt.exchange_rate_to_gbp)::numeric(
18, 4
)
when bt.line_amount_tax_inclusiveness = 'NoTax'
then
(j.line_amount_local_curr::numeric * bt.exchange_rate_to_gbp)::numeric(
18, 4
)
else null
end as line_amount_wo_taxes_in_gbp,
j.tax_amount_local_curr::numeric,
(j.tax_amount_local_curr::numeric * bt.exchange_rate_to_gbp)::numeric(
18, 4
) as tax_amount_in_gbp,
bt.transaction_sign * j.line_amount_local_curr::numeric as line_amount_local_curr,
(
bt.transaction_sign
* j.line_amount_local_curr::numeric
* bt.exchange_rate_to_gbp
)::numeric(18, 4) as line_amount_in_gbp,
(
case
when bt.line_amount_tax_inclusiveness = 'Inclusive'
then j.line_amount_local_curr::numeric - j.tax_amount_local_curr::numeric
when bt.line_amount_tax_inclusiveness = 'Exclusive'
then j.line_amount_local_curr::numeric
when bt.line_amount_tax_inclusiveness = 'NoTax'
then j.line_amount_local_curr::numeric
else null
end
)
* bt.transaction_sign as line_amount_wo_taxes_local_curr,
(
case
when bt.line_amount_tax_inclusiveness = 'Inclusive'
then
(
(
j.line_amount_local_curr::numeric
- j.tax_amount_local_curr::numeric
)
* bt.exchange_rate_to_gbp
)::numeric(18, 4)
when bt.line_amount_tax_inclusiveness = 'Exclusive'
then
(j.line_amount_local_curr::numeric * bt.exchange_rate_to_gbp)::numeric(
18, 4
)
when bt.line_amount_tax_inclusiveness = 'NoTax'
then
(j.line_amount_local_curr::numeric * bt.exchange_rate_to_gbp)::numeric(
18, 4
)
else null
end
)
* bt.transaction_sign as line_amount_wo_taxes_in_gbp,
bt.transaction_sign * j.tax_amount_local_curr::numeric as tax_amount_local_curr,
(
bt.transaction_sign * j.tax_amount_local_curr::numeric * bt.exchange_rate_to_gbp
)::numeric(18, 4) as tax_amount_in_gbp,
j.tax_type,
bt.transaction_currency_iso_4217
from int_xero__bank_transactions bt

View file

@ -11,6 +11,7 @@ select
bt.bank_account ->> 'BankAccountID' as id_bank_account,
bt.reference,
bt.transaction_type,
bt.transaction_sign,
bt.transaction_status,
bt.transaction_at_utc,
bt.transaction_date_utc,

View file

@ -833,7 +833,12 @@ models:
description: |
What kind of transaction is this record.
Can be one of: RECEIVE, RECEIVE-OVERPAYMENT, RECEIVE-PREPAYMENT, SPEND, SPEND-OVERPAYMENT, SPEND-PREPAYMENT, RECEIVE-TRANSFER, SPEND-TRANSFER
Can be one of: RECEIVE, RECEIVE-OVERPAYMENT, RECEIVE-PREPAYMENT,
SPEND, SPEND-OVERPAYMENT, SPEND-PREPAYMENT, RECEIVE-TRANSFER,
SPEND-TRANSFER
The type will affect the sign of all amounts. Amounts we send are
negative, amounts we receive are positive.
You can read more here: https://developer.xero.com/documentation/api/accounting/types#bank-transactions
tests:
@ -849,6 +854,19 @@ models:
- RECEIVE-TRANSFER
- SPEND-TRANSFER
- name: transaction_sign
data_type: numeric
description: |
The sign for the transactions. Spending transactions show as -1,
receiving transactions show as 1. This helps in converting the
transaction amounts in the right sign, since Xero brings all amounts
as positive by default.
tests:
- not_null
- accepted_values:
values:
- 1
- -1
- name: transaction_status
data_type: character varying

View file

@ -30,6 +30,7 @@ select
bt.id_bank_account,
bt.reference,
bt.transaction_type,
bt.transaction_sign,
bt.transaction_status,
bt.transaction_at_utc,
bt.transaction_date_utc,

View file

@ -10,6 +10,7 @@ select
bt.id_bank_account as id_bank_account,
bt.reference as reference,
bt.transaction_type as transaction_type,
bt.transaction_sign as transaction_sign,
bt.transaction_status as transaction_status,
bt.transaction_at_utc as transaction_at_utc,
bt.transaction_date_utc as transaction_date_utc,

View file

@ -625,7 +625,12 @@ models:
description: |
What kind of transaction is this record.
Can be one of: RECEIVE, RECEIVE-OVERPAYMENT, RECEIVE-PREPAYMENT, SPEND, SPEND-OVERPAYMENT, SPEND-PREPAYMENT, RECEIVE-TRANSFER, SPEND-TRANSFER
Can be one of: RECEIVE, RECEIVE-OVERPAYMENT, RECEIVE-PREPAYMENT,
SPEND, SPEND-OVERPAYMENT, SPEND-PREPAYMENT, RECEIVE-TRANSFER,
SPEND-TRANSFER
The type will affect the sign of all amounts. Amounts we send are
negative, amounts we receive are positive.
You can read more here: https://developer.xero.com/documentation/api/accounting/types#bank-transactions
tests:
@ -640,6 +645,20 @@ models:
- SPEND-PREPAYMENT
- RECEIVE-TRANSFER
- SPEND-TRANSFER
- name: transaction_sign
data_type: numeric
description: |
The sign for the transactions. Spending transactions show as -1,
receiving transactions show as 1. This helps in converting the
transaction amounts in the right sign, since Xero brings all amounts
as positive by default.
tests:
- not_null
- accepted_values:
values:
- 1
- -1
- name: transaction_status
data_type: character varying

View file

@ -1,5 +1,20 @@
with
raw_bank_transactions as (select * from {{ source("xero", "bank_transactions") }}),
transaction_signs as (
-- making this tiny CTE to be able to reference the transaction_sign col
-- in the main body easily and avoid plastering the case-when a
-- gazillion times.
select
{{ adapter.quote("BankTransactionID") }} as id_bank_transaction,
case
when {{ adapter.quote("Type") }} like '%SPEND%'
then -1
when {{ adapter.quote("Type") }} like '%RECEIVE%'
then 1
else null
end as transaction_sign
from raw_bank_transactions
),
stg_xero__bank_transactions as (
select
{{ adapter.quote("BankTransactionID") }} as id_bank_transaction,
@ -8,15 +23,19 @@ with
{{ adapter.quote("Reference") }} as reference,
{{ adapter.quote("Type") }} as transaction_type,
ts.transaction_sign as transaction_sign,
{{ adapter.quote("Status") }} as transaction_status,
{{ adapter.quote("Date") }} as transaction_at_utc,
cast({{ adapter.quote("Date") }} as date) as transaction_date_utc,
{{ adapter.quote("DateString") }} as date_string,
{{ adapter.quote("Total") }} as total_amount_local_curr,
{{ adapter.quote("SubTotal") }} as total_amount_wo_tax_local_curr,
{{ adapter.quote("TotalTax") }} as total_tax_local_curr,
{{ adapter.quote("Total") }}
* ts.transaction_sign as total_amount_local_curr,
{{ adapter.quote("SubTotal") }}
* ts.transaction_sign as total_amount_wo_tax_local_curr,
{{ adapter.quote("TotalTax") }}
* ts.transaction_sign as total_tax_local_curr,
{{ adapter.quote("CurrencyCode") }} as transaction_currency_iso_4217,
1 / {{ adapter.quote("CurrencyRate") }} as exchange_rate_to_gbp,
{{ adapter.quote("LineAmountTypes") }} as line_amount_tax_inclusiveness,
@ -33,7 +52,10 @@ with
{{ adapter.quote("UpdatedDateUTC") }} as updated_at_utc,
cast({{ adapter.quote("UpdatedDateUTC") }} as date) as updated_date_utc,
{{ adapter.quote("_airbyte_extracted_at") }} as dwh_extracted_at_utc
from raw_bank_transactions
from raw_bank_transactions bt
left join
transaction_signs ts
on bt.{{ adapter.quote("BankTransactionID") }} = ts.id_bank_transaction
)
select *
from stg_xero__bank_transactions