Merged PR 2110: Bank Transactions and Line Items

This PR brings Bank transactions to `int` and also creates an `int` model with their line items by unfolding a JSON nested field in `stg_xero__bank_transactions`.

I also had to bring in the `accounts` entity to make sense of the line items.

Related work items: #17551
This commit is contained in:
Pablo Martín 2024-06-25 14:24:50 +00:00
commit ffc8985362
7 changed files with 209 additions and 1 deletions

View file

@ -0,0 +1,76 @@
with
int_xero__bank_transactions as (
select * from {{ ref("int_xero__bank_transactions") }}
),
stg_xero__accounts as (select * from {{ ref("stg_xero__accounts") }})
select
bt.id_bank_transaction,
j.id_line_item,
j.line_description,
j.id_account,
j.account_code,
a.account_name,
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,
j.tax_type,
bt.transaction_currency_iso_4217
from int_xero__bank_transactions bt
cross join
lateral(
select
(jsonb_array_elements(bt.line_items) ->> 'LineItemID') as id_line_item,
(jsonb_array_elements(bt.line_items) ->> 'AccountID') as id_account,
(jsonb_array_elements(bt.line_items) ->> 'Quantity') as quantity,
(jsonb_array_elements(bt.line_items) ->> 'UnitAmount') as unit_amount,
(
jsonb_array_elements(bt.line_items) ->> 'LineAmount'
) as line_amount_local_curr,
(
jsonb_array_elements(bt.line_items) ->> 'TaxAmount'
) as tax_amount_local_curr,
(jsonb_array_elements(bt.line_items) ->> 'TaxType') as tax_type,
(jsonb_array_elements(bt.line_items) ->> 'Description') as line_description,
(jsonb_array_elements(bt.line_items) ->> 'AccountCode') as account_code,
(jsonb_array_elements(bt.line_items) ->> 'ItemCode') as item_code
) j
left join stg_xero__accounts a on j.account_code = a.account_code

View file

@ -0,0 +1,48 @@
with
stg_xero__bank_transactions as (
select * from {{ ref("stg_xero__bank_transactions") }}
),
int_simple_exchange_rates as (select * from {{ ref("int_simple_exchange_rates") }})
select
bt.id_bank_transaction,
bt.id_prepayment,
bt.id_overpayment,
bt.full_contact_details ->> 'ContactID' as id_contact,
bt.bank_account ->> 'BankAccountID' as id_bank_account,
bt.reference,
bt.transaction_type,
bt.transaction_status,
bt.transaction_at_utc,
bt.transaction_date_utc,
bt.date_string,
bt.total_amount_local_curr,
(bt.total_amount_local_curr * coalesce(bt.exchange_rate_to_gbp, ser.rate))::numeric(
18, 4
) as total_amount_in_gbp,
bt.total_amount_wo_tax_local_curr,
(
bt.total_amount_wo_tax_local_curr * coalesce(bt.exchange_rate_to_gbp, ser.rate)
)::numeric(18, 4) as total_amount_wo_tax_in_gbp,
bt.total_tax_local_curr,
(bt.total_tax_local_curr * coalesce(bt.exchange_rate_to_gbp, ser.rate))::numeric(
18, 4
) as total_tax_in_gbp,
bt.transaction_currency_iso_4217,
-- We try to use Xero's rate. If no rate is available, we fall back to the
-- oficial dwh rate.
coalesce(bt.exchange_rate_to_gbp, ser.rate) as exchange_rate_to_gbp,
bt.line_amount_tax_inclusiveness,
bt.line_items,
bt.is_reconciled,
bt.has_attachments,
bt.url,
bt.external_link_provider_name,
bt.updated_at_utc,
bt.updated_date_utc,
bt.dwh_extracted_at_utc
from stg_xero__bank_transactions bt
left join
int_simple_exchange_rates ser
on bt.transaction_currency_iso_4217 = ser.from_currency
and ser.to_currency = 'GBP'
and bt.transaction_date_utc = ser.rate_date_utc

View file

@ -0,0 +1,35 @@
version: 2
models:
- name: int_xero__invoices
columns:
- name: id_invoice
tests:
- not_null
- unique
- name: int_xero__credit_notes
columns:
- name: id_credit_note
tests:
- not_null
- unique
- name: int_xero__invoice_line_items
columns:
- name: id_line_item
tests:
- not_null
- unique
- name: int_xero__credit_note_line_items
columns:
- name: id_line_item
tests:
- not_null
- unique
- name: int_xero__bank_transactions
columns:
- name: id_bank_transaction
tests:
- not_null
- unique

View file

@ -23,3 +23,7 @@ sources:
identifier: bank_transactions identifier: bank_transactions
description: | description: |
Bank transactions that have been created within our accounting books. Bank transactions that have been created within our accounting books.
- name: accounts
identifier: accounts
description: |
Accounts from our accounting trees.

View file

@ -774,3 +774,18 @@ models:
- name: dwh_extracted_at_utc - name: dwh_extracted_at_utc
data_type: timestamp with time zone data_type: timestamp with time zone
description: "" description: ""
- name: stg_xero__accounts
description: |
Accounts in our accounting tree.
columns:
- name: id_account
data_type: character varying
description: Xero's unique identifier for the account.
tests:
- not_null
- unique
- name: account_code
data_type: character varying
description: Human readable account code.
tests:
- unique

View file

@ -0,0 +1,29 @@
with
raw_accounts as (select * from {{ source("xero", "accounts") }}),
stg_xero__accounts as (
select
{{ adapter.quote("AccountID") }} as id_account,
{{ adapter.quote("Code") }} as account_code,
{{ adapter.quote("Name") }} as account_name,
{{ adapter.quote("Type") }} as account_type,
{{ adapter.quote("Class") }} as account_class,
{{ adapter.quote("Status") }} as is_active,
{{ adapter.quote("TaxType") }} as account_tax_type,
{{ adapter.quote("Description") }} as account_description,
{{ adapter.quote("CurrencyCode") }} as account_currency_iso_4217,
{{ adapter.quote("ReportingCode") }} as reporting_code,
{{ adapter.quote("ReportingCodeName") }} as reporting_name,
{{ adapter.quote("SystemAccount") }} as system_account,
{{ adapter.quote("HasAttachments") }} as has_attachments,
{{ adapter.quote("BankAccountType") }} as bank_account_type,
{{ adapter.quote("BankAccountNumber") }} as bank_account_number,
{{ adapter.quote("ShowInExpenseClaims") }} as show_in_expense_claims,
{{ adapter.quote("EnablePaymentsToAccount") }}
as enable_payments_to_account,
{{ adapter.quote("UpdatedDateUTC") }} as updated_at_utc,
{{ adapter.quote("_airbyte_extracted_at") }} as dwh_extracted_at_utc
from raw_accounts
)
select *
from stg_xero__accounts

View file

@ -11,10 +11,11 @@ with
{{ adapter.quote("Status") }} as transaction_status, {{ adapter.quote("Status") }} as transaction_status,
{{ adapter.quote("Date") }} as transaction_at_utc, {{ 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("DateString") }} as date_string,
{{ adapter.quote("Total") }} as total_amount_local_curr, {{ adapter.quote("Total") }} as total_amount_local_curr,
{{ adapter.quote("SubTotal") }} as subtotal_local_curr, {{ adapter.quote("SubTotal") }} as total_amount_wo_tax_local_curr,
{{ adapter.quote("TotalTax") }} as total_tax_local_curr, {{ adapter.quote("TotalTax") }} as total_tax_local_curr,
{{ adapter.quote("CurrencyCode") }} as transaction_currency_iso_4217, {{ adapter.quote("CurrencyCode") }} as transaction_currency_iso_4217,
1 / {{ adapter.quote("CurrencyRate") }} as exchange_rate_to_gbp, 1 / {{ adapter.quote("CurrencyRate") }} as exchange_rate_to_gbp,