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,