diff --git a/models/intermediate/xero/int_xero__bank_transaction_line_items.sql b/models/intermediate/xero/int_xero__bank_transaction_line_items.sql new file mode 100644 index 0000000..10da0fe --- /dev/null +++ b/models/intermediate/xero/int_xero__bank_transaction_line_items.sql @@ -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 diff --git a/models/intermediate/xero/int_xero__bank_transactions.sql b/models/intermediate/xero/int_xero__bank_transactions.sql new file mode 100644 index 0000000..fefdf22 --- /dev/null +++ b/models/intermediate/xero/int_xero__bank_transactions.sql @@ -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 diff --git a/models/intermediate/xero/schema.yaml b/models/intermediate/xero/schema.yaml new file mode 100644 index 0000000..aa1b3e3 --- /dev/null +++ b/models/intermediate/xero/schema.yaml @@ -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 + + \ No newline at end of file diff --git a/models/staging/xero/_xero_sources.yml b/models/staging/xero/_xero_sources.yml index 88cbb79..2833340 100644 --- a/models/staging/xero/_xero_sources.yml +++ b/models/staging/xero/_xero_sources.yml @@ -23,3 +23,7 @@ sources: identifier: bank_transactions description: | Bank transactions that have been created within our accounting books. + - name: accounts + identifier: accounts + description: | + Accounts from our accounting trees. diff --git a/models/staging/xero/schema.yml b/models/staging/xero/schema.yml index b2490f8..09704d1 100644 --- a/models/staging/xero/schema.yml +++ b/models/staging/xero/schema.yml @@ -774,3 +774,18 @@ models: - name: dwh_extracted_at_utc data_type: timestamp with time zone 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 diff --git a/models/staging/xero/stg_xero__accounts.sql b/models/staging/xero/stg_xero__accounts.sql new file mode 100644 index 0000000..8aa0f53 --- /dev/null +++ b/models/staging/xero/stg_xero__accounts.sql @@ -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 diff --git a/models/staging/xero/stg_xero__bank_transactions.sql b/models/staging/xero/stg_xero__bank_transactions.sql index 75d9f42..dec8c6f 100644 --- a/models/staging/xero/stg_xero__bank_transactions.sql +++ b/models/staging/xero/stg_xero__bank_transactions.sql @@ -11,10 +11,11 @@ with {{ 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 subtotal_local_curr, + {{ adapter.quote("SubTotal") }} as total_amount_wo_tax_local_curr, {{ adapter.quote("TotalTax") }} as total_tax_local_curr, {{ adapter.quote("CurrencyCode") }} as transaction_currency_iso_4217, 1 / {{ adapter.quote("CurrencyRate") }} as exchange_rate_to_gbp,