Merged PR 2087: Add Xero Bank Transactions to staging
- Main purpose is to bring the Bank Transactions table from sync to stg. - Along the way: - I created a couple of new generic tests. - I reviewed docs and tests for a couple of other Xero models that were not in the best shape. Related work items: #17551
This commit is contained in:
commit
80120e68a2
5 changed files with 499 additions and 12 deletions
16
macros/tests/length_between.sql
Normal file
16
macros/tests/length_between.sql
Normal file
|
|
@ -0,0 +1,16 @@
|
|||
-- Min and max length get included
|
||||
{% test length_between(model, column_name, min_length, max_length) %}
|
||||
|
||||
with
|
||||
invalid_length as (
|
||||
select {{ column_name }}
|
||||
from {{ model }}
|
||||
where
|
||||
length({{ column_name }}) not between {{ min_length }}
|
||||
and {{ max_length }}
|
||||
)
|
||||
|
||||
select *
|
||||
from invalid_length
|
||||
|
||||
{% endtest %}
|
||||
6
macros/tests/not_negative.sql
Normal file
6
macros/tests/not_negative.sql
Normal file
|
|
@ -0,0 +1,6 @@
|
|||
{% test not_negative(model, column_name) %}
|
||||
with validation as (select {{ column_name }} as value from {{ model }})
|
||||
select *
|
||||
from validation
|
||||
where value < 0
|
||||
{% endtest %}
|
||||
|
|
@ -19,3 +19,7 @@ sources:
|
|||
identifier: credit_notes
|
||||
description: |
|
||||
Credit notes that have been created within our accounting books.
|
||||
- name: bank_transactions
|
||||
identifier: bank_transactions
|
||||
description: |
|
||||
Bank transactions that have been created within our accounting books.
|
||||
|
|
|
|||
|
|
@ -10,6 +10,9 @@ models:
|
|||
- name: id_contact
|
||||
data_type: character varying
|
||||
description: Xero's unique identifier for the contact.
|
||||
tests:
|
||||
- not_null
|
||||
- unique
|
||||
|
||||
- name: account_number
|
||||
data_type: character varying
|
||||
|
|
@ -18,14 +21,29 @@ models:
|
|||
- name: contact_name
|
||||
data_type: character varying
|
||||
description: The name for the customer.
|
||||
tests:
|
||||
- not_null
|
||||
- unique
|
||||
|
||||
- name: is_customer
|
||||
data_type: boolean
|
||||
description: Flag that shows if the contact is a Superhog customer.
|
||||
tests:
|
||||
- not_null
|
||||
- accepted_values:
|
||||
values:
|
||||
- true
|
||||
- false
|
||||
|
||||
- name: is_supplier
|
||||
data_type: boolean
|
||||
description: Flag that shows if the contact is a Superhog supplier.
|
||||
tests:
|
||||
- not_null
|
||||
- accepted_values:
|
||||
values:
|
||||
- true
|
||||
- false
|
||||
|
||||
- name: tax_number
|
||||
data_type: character varying
|
||||
|
|
@ -119,7 +137,7 @@ models:
|
|||
data_type: character varying
|
||||
description: |
|
||||
The default currency used to interact with this contact.
|
||||
|
||||
|
||||
For customers, this is the currency we will usually use to invoice.
|
||||
|
||||
- name: validation_errors
|
||||
|
|
@ -171,15 +189,19 @@ models:
|
|||
description: ""
|
||||
- name: stg_xero__invoices
|
||||
description: |
|
||||
Invoices that we have raised within our accounting books.
|
||||
Invoices that we have raised within our accounting books.
|
||||
|
||||
This includes both our invoices towards customers and invoices provided by our suppliers.
|
||||
This includes both our invoices towards customers and invoices provided by our suppliers.
|
||||
|
||||
You can read more here: https://developer.xero.com/documentation/api/accounting/invoices
|
||||
|
||||
You can read more here: https://developer.xero.com/documentation/api/accounting/invoices
|
||||
columns:
|
||||
- name: id_invoice
|
||||
data_type: character varying
|
||||
description: Xero's unique identifier for the invoice.
|
||||
tests:
|
||||
- not_null
|
||||
- unique
|
||||
|
||||
- name: invoice_url
|
||||
data_type: character varying
|
||||
|
|
@ -194,42 +216,70 @@ models:
|
|||
description: |
|
||||
This field indicates whether the invoice is from Superhog towards a customer
|
||||
(value is "ACCREC") or from a supplier towards Superhog (value is "ACCPAY").
|
||||
tests:
|
||||
- not_null
|
||||
- accepted_values:
|
||||
values:
|
||||
- "ACCREC"
|
||||
- "ACCPAY"
|
||||
|
||||
- name: total_amount_local_curr
|
||||
data_type: numeric
|
||||
description: The total amount to be paid, in the currency the invoice is denominated in.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: total_amount_wo_tax_local_curr
|
||||
data_type: numeric
|
||||
description: The total amount to be paid minus taxes, in the currency the invoice is denominated in.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: total_tax_local_curr
|
||||
data_type: numeric
|
||||
description: The total tax, in the currency the invoice is denominated in.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: total_due_local_curr
|
||||
data_type: numeric
|
||||
description: The total amount outstanding right now, in the currency the invoice is denominated in.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: total_paid_local_curr
|
||||
data_type: numeric
|
||||
description: The total amount that has already been paid, in the currency the invoice is denominated in.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: invoice_status
|
||||
data_type: character varying
|
||||
description: |
|
||||
description: |
|
||||
The status of the invoice.
|
||||
|
||||
Can be one of: PAID, VOIDED, DRAFT, DELETED, AUTHORISED, SUBMITTED.
|
||||
|
||||
You can read more here: https://developer.xero.com/documentation/api/accounting/types#invoices
|
||||
tests:
|
||||
- not_null
|
||||
- accepted_values:
|
||||
values:
|
||||
- PAID
|
||||
- VOIDED
|
||||
- DRAFT
|
||||
- DELETED
|
||||
- AUTHORISED
|
||||
- SUBMITTED
|
||||
|
||||
- name: contact
|
||||
- name: full_contact_details
|
||||
data_type: jsonb
|
||||
description: |
|
||||
The contact related to this invoice.
|
||||
|
||||
The customer if it's an Accounts Receivables one, the supplier if it's an Accounts Payables one.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: invoice_due_date_utc
|
||||
data_type: timestamp with time zone
|
||||
|
|
@ -247,12 +297,14 @@ models:
|
|||
- name: line_items
|
||||
data_type: jsonb
|
||||
description: An array with all the line items and their details.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: reference
|
||||
data_type: character varying
|
||||
description: |
|
||||
The Superhog-set reference for the invoices. Only relevant for
|
||||
records of invoice type (ACCREC).
|
||||
records of invoice type (ACCREC).
|
||||
|
||||
- name: date_string
|
||||
data_type: timestamp with time zone
|
||||
|
|
@ -269,17 +321,25 @@ models:
|
|||
- name: invoice_currency_iso_4217
|
||||
data_type: character varying
|
||||
description: The ISO 4217 code for the currency which this invoice uses as unit of account.
|
||||
tests:
|
||||
- not_null
|
||||
- length_between:
|
||||
min_length: 3
|
||||
max_length: 3
|
||||
|
||||
- name: exchange_rate_to_gbp
|
||||
data_type: numeric
|
||||
description: |
|
||||
description: |
|
||||
The implied exchange rate between the invoice currency and GBP.
|
||||
|
||||
|
||||
This is the XXX to GBP rate. So the number represented in this field is the units of currency GBP
|
||||
that 1 unit of XXX buys you.
|
||||
|
||||
For example, if the invoice is 135 ZAR, and this rate is 0.0167, the invoice value in GBP is 2.25
|
||||
(135ZAR * 0.0167GBP/ZAR = 2.25GBP).
|
||||
tests:
|
||||
- not_null
|
||||
- not_negative
|
||||
|
||||
- name: is_discounted
|
||||
data_type: boolean
|
||||
|
|
@ -307,8 +367,8 @@ models:
|
|||
|
||||
- name: total_credited_local_curr
|
||||
data_type: numeric
|
||||
description:
|
||||
Total amount credited by related credit notes, over-payments and
|
||||
description:
|
||||
Total amount credited by related credit notes, over-payments and
|
||||
pre-payments.
|
||||
|
||||
- name: has_attachments
|
||||
|
|
@ -339,6 +399,12 @@ models:
|
|||
Indicates whether the amounts included in line items are tax
|
||||
inclusive (Inclusive), tax exclusive (Exclusive) or simply,
|
||||
there are no taxes on the invoice (NoTax).
|
||||
tests:
|
||||
- accepted_values:
|
||||
values:
|
||||
- Inclusive
|
||||
- Exclusive
|
||||
- NoTax
|
||||
|
||||
- name: payment_planned_date_utc
|
||||
data_type: timestamp with time zone
|
||||
|
|
@ -350,4 +416,361 @@ models:
|
|||
|
||||
- name: dwh_extracted_at_utc
|
||||
data_type: timestamp with time zone
|
||||
description: ""
|
||||
description: ""
|
||||
- name: stg_xero__credit_notes
|
||||
description: |
|
||||
Credit notes that we have issued within our accounting books.
|
||||
|
||||
This includes both our credit notes towards customers and credit notes provided by our suppliers.
|
||||
|
||||
You can read more here: https://developer.xero.com/documentation/api/accounting/creditnotes
|
||||
columns:
|
||||
- name: id_credit_note
|
||||
data_type: character varying
|
||||
description: Xero's unique identifier for the credit note.
|
||||
tests:
|
||||
- not_null
|
||||
- unique
|
||||
|
||||
- name: reference
|
||||
data_type: character varying
|
||||
description: The reference number for the credit note.
|
||||
|
||||
- name: credit_note_number
|
||||
data_type: character varying
|
||||
description: The number assigned to the credit note.
|
||||
|
||||
- name: credit_note_issued_at_utc
|
||||
data_type: timestamp with time zone
|
||||
description: The timestamp at which the credit note was issued.
|
||||
|
||||
- name: credit_note_issued_date_utc
|
||||
data_type: date
|
||||
description: The date on which the credit note was issued.
|
||||
|
||||
- name: credit_note_type
|
||||
data_type: character varying
|
||||
description: The type of the credit note (e.g., ACCRECCREDIT or ACCPAYCREDIT).
|
||||
tests:
|
||||
- not_null
|
||||
- accepted_values:
|
||||
values:
|
||||
- "ACCRECCREDIT"
|
||||
- "ACCPAYCREDIT"
|
||||
|
||||
- name: credit_note_currency_iso_4217
|
||||
data_type: character varying
|
||||
description: The ISO 4217 code for the currency in which the credit note is denominated.
|
||||
|
||||
- name: exchange_rate_to_gbp
|
||||
data_type: numeric
|
||||
description: |
|
||||
The implied exchange rate between the credit note currency and GBP.
|
||||
|
||||
This is the XXX to GBP rate, indicating how many GBP one unit of XXX is worth.
|
||||
tests:
|
||||
- not_null
|
||||
- not_negative
|
||||
|
||||
- name: total_amount_local_curr
|
||||
data_type: numeric
|
||||
description: The total amount of the credit note in the local currency.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: subtotal_local_curr
|
||||
data_type: numeric
|
||||
description: The subtotal of the credit note in the local currency, before tax.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: total_tax_local_curr
|
||||
data_type: numeric
|
||||
description: The total tax amount of the credit note in the local currency.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: remaining_credit_local_curr
|
||||
data_type: numeric
|
||||
description: The remaining credit amount in the local currency.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: applied_amount
|
||||
data_type: numeric
|
||||
description: The amount applied from the credit note.
|
||||
|
||||
- name: credit_note_status
|
||||
data_type: character varying
|
||||
description: |
|
||||
The status of the credit note.
|
||||
|
||||
Can be one of: PAID, VOIDED, DRAFT, DELETED, AUTHORISED, SUBMITTED.
|
||||
|
||||
You can read more here: https://developer.xero.com/documentation/api/accounting/types#invoices
|
||||
tests:
|
||||
- not_null
|
||||
- accepted_values:
|
||||
values:
|
||||
- PAID
|
||||
- VOIDED
|
||||
- DRAFT
|
||||
- DELETED
|
||||
- AUTHORISED
|
||||
- SUBMITTED
|
||||
|
||||
- name: full_contact_details
|
||||
data_type: jsonb
|
||||
description: The full contact details related to the credit note.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: credit_note_due_date
|
||||
data_type: timestamp with time zone
|
||||
description: The due date for the credit note.
|
||||
|
||||
- name: line_items
|
||||
data_type: jsonb
|
||||
description: An array of line items associated with the credit note.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: date_string
|
||||
data_type: character varying
|
||||
description: The date string representation of the credit note date.
|
||||
|
||||
- name: due_date_string
|
||||
data_type: character varying
|
||||
description: The date string representation of the credit note due date.
|
||||
|
||||
- name: allocations
|
||||
data_type: jsonb
|
||||
description: An array of allocations related to the credit note.
|
||||
|
||||
- name: has_been_sent_to_contact
|
||||
data_type: boolean
|
||||
description: Flag indicating if the credit note has been sent to the contact.
|
||||
|
||||
- name: has_attachments
|
||||
data_type: boolean
|
||||
description: Flag indicating if the credit note has attachments.
|
||||
|
||||
- name: updated_at_utc
|
||||
data_type: timestamp with time zone
|
||||
description: The timestamp at which the credit note was last updated.
|
||||
|
||||
- name: id_branding_theme
|
||||
data_type: character varying
|
||||
description: The identifier for the branding theme associated with the credit note.
|
||||
|
||||
- name: was_fully_paid_on_date_utc
|
||||
data_type: date
|
||||
description: The date on which the credit note was fully paid, if applicable.
|
||||
|
||||
- name: line_amount_tax_inclusiveness
|
||||
data_type: character varying
|
||||
description: |
|
||||
Indicates whether the amounts included in line items are tax
|
||||
inclusive (Inclusive), tax exclusive (Exclusive) or simply,
|
||||
there are no taxes on the credit note (NoTax).
|
||||
tests:
|
||||
- accepted_values:
|
||||
values:
|
||||
- Inclusive
|
||||
- Exclusive
|
||||
- NoTax
|
||||
|
||||
- name: updated_date_utc
|
||||
data_type: date
|
||||
description: The date on which the credit note was last updated.
|
||||
|
||||
- name: dwh_extracted_at_utc
|
||||
data_type: timestamp with time zone
|
||||
description: The timestamp at which the data warehouse last extracted the credit note data.
|
||||
- name: stg_xero__bank_transactions
|
||||
description: |
|
||||
Bank transactions that have happened in any of our bank accounts.
|
||||
|
||||
You can read more here: https://developer.xero.com/documentation/api/accounting/banktransactions
|
||||
|
||||
columns:
|
||||
- name: id_bank_transaction
|
||||
data_type: character varying
|
||||
description: Xero's unique identifier for the transaction.
|
||||
tests:
|
||||
- not_null
|
||||
- unique
|
||||
|
||||
- name: id_prepayment
|
||||
data_type: character varying
|
||||
description: |
|
||||
Xero generated identifier for a Prepayment (unique within
|
||||
organisations). This will be returned on BankTransactions with a Type
|
||||
of SPEND-PREPAYMENT or RECEIVE-PREPAYMENT.
|
||||
|
||||
- name: id_overpayment
|
||||
data_type: character varying
|
||||
description: Xero generated identifier for an Overpayment (unique within
|
||||
organisations). This will be returned on BankTransactions with a Type
|
||||
of SPEND-OVERPAYMENT or RECEIVE-OVERPAYMENT.
|
||||
|
||||
- name: reference
|
||||
data_type: character varying
|
||||
description: |
|
||||
Reference for the transaction. Only supported for SPEND and RECEIVE
|
||||
transactions.
|
||||
|
||||
- name: transaction_type
|
||||
data_type: character varying
|
||||
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
|
||||
|
||||
You can read more here: https://developer.xero.com/documentation/api/accounting/types#bank-transactions
|
||||
tests:
|
||||
- not_null
|
||||
- accepted_values:
|
||||
values:
|
||||
- RECEIVE
|
||||
- RECEIVE-OVERPAYMENT
|
||||
- RECEIVE-PREPAYMENT
|
||||
- SPEND
|
||||
- SPEND-OVERPAYMENT
|
||||
- SPEND-PREPAYMENT
|
||||
- RECEIVE-TRANSFER
|
||||
- SPEND-TRANSFER
|
||||
|
||||
- name: transaction_status
|
||||
data_type: character varying
|
||||
description: |
|
||||
The status of this transaction.
|
||||
|
||||
Can be one of: AUTHORISED, DELETED.
|
||||
|
||||
You can read more here: https://developer.xero.com/documentation/api/accounting/types#bank-transaction-status-codes
|
||||
tests:
|
||||
- not_null
|
||||
- accepted_values:
|
||||
values:
|
||||
- AUTHORISED
|
||||
- DELETED
|
||||
|
||||
- name: transaction_at_utc
|
||||
data_type: timestamp with time zone
|
||||
description: When did the transaction happen.
|
||||
|
||||
- name: date_string
|
||||
data_type: timestamp with time zone
|
||||
description: When did the transaction happen, as a string.
|
||||
|
||||
- name: total_amount_local_curr
|
||||
data_type: numeric
|
||||
description: |
|
||||
Total of bank transaction tax inclusive, in the currency the
|
||||
transaction is denominated in.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: subtotal_local_curr
|
||||
data_type: numeric
|
||||
description: |
|
||||
Total of bank transaction excluding taxes, in the currency the
|
||||
transaction is denominated in.
|
||||
|
||||
- name: total_tax_local_curr
|
||||
data_type: numeric
|
||||
description: |
|
||||
Total tax on bank transaction, in the currency the transaction is
|
||||
denominated in.
|
||||
|
||||
- name: transaction_currency_iso_4217
|
||||
data_type: character varying
|
||||
description: The ISO 4217 code for the currency of the transaction.
|
||||
tests:
|
||||
- not_null
|
||||
- length_between:
|
||||
min_length: 3
|
||||
max_length: 3
|
||||
|
||||
- name: exchange_rate_to_gbp
|
||||
data_type: numeric
|
||||
description: |
|
||||
|
||||
ATTENTION! unlike in many other Xero entities, here this field is not
|
||||
completed by Xero always. Some records will have a rate, some won't.
|
||||
You probably need to complement these rates with some other source if
|
||||
you want to
|
||||
|
||||
The implied exchange rate between the transaction currency and GBP.
|
||||
|
||||
This is the XXX to GBP rate. So the number represented in this field
|
||||
is the units of currency GBP that 1 unit of XXX buys you.
|
||||
|
||||
For example, if the transaction is 135 ZAR, and this rate is 0.0167,
|
||||
the transaction value in GBP is 2.25 (135ZAR * 0.0167GBP/ZAR =
|
||||
2.25GBP).
|
||||
tests:
|
||||
- not_negative
|
||||
|
||||
- name: line_amount_tax_inclusiveness
|
||||
data_type: character varying
|
||||
description: |
|
||||
Indicates whether the amounts included in line items are tax
|
||||
inclusive (Inclusive), tax exclusive (Exclusive) or simply,
|
||||
there are no taxes on the invoice (NoTax).
|
||||
tests:
|
||||
- accepted_values:
|
||||
values:
|
||||
- Inclusive
|
||||
- Exclusive
|
||||
- NoTax
|
||||
|
||||
- name: full_contact_details
|
||||
data_type: jsonb
|
||||
description: |
|
||||
The contact related to this transaction.
|
||||
|
||||
Might be null since not all transactions have a related contact.
|
||||
|
||||
- name: line_items
|
||||
data_type: jsonb
|
||||
description: An array with all the line items and their details.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: bank_account
|
||||
data_type: jsonb
|
||||
description: An array with the details of the related bank account.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: is_reconciled
|
||||
data_type: boolean
|
||||
description: A flag indicating if the transaction has been reconciled.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: has_attachments
|
||||
data_type: boolean
|
||||
description: ""
|
||||
|
||||
- name: url
|
||||
data_type: character varying
|
||||
description: ""
|
||||
|
||||
- name: external_link_provider_name
|
||||
data_type: character varying
|
||||
description: ""
|
||||
|
||||
- name: updated_at_utc
|
||||
data_type: timestamp with time zone
|
||||
description: ""
|
||||
|
||||
- name: updated_date_utc
|
||||
data_type: date
|
||||
description: ""
|
||||
|
||||
- name: dwh_extracted_at_utc
|
||||
data_type: timestamp with time zone
|
||||
description: ""
|
||||
|
|
|
|||
38
models/staging/xero/stg_xero__bank_transactions.sql
Normal file
38
models/staging/xero/stg_xero__bank_transactions.sql
Normal file
|
|
@ -0,0 +1,38 @@
|
|||
with
|
||||
raw_bank_transactions as (select * from {{ source("xero", "bank_transactions") }}),
|
||||
stg_xero__bank_transactions as (
|
||||
select
|
||||
{{ adapter.quote("BankTransactionID") }} as id_bank_transaction,
|
||||
{{ adapter.quote("PrepaymentID") }} as id_prepayment,
|
||||
{{ adapter.quote("OverpaymentID") }} as id_overpayment,
|
||||
{{ adapter.quote("Reference") }} as reference,
|
||||
|
||||
{{ adapter.quote("Type") }} as transaction_type,
|
||||
{{ adapter.quote("Status") }} as transaction_status,
|
||||
|
||||
{{ adapter.quote("Date") }} as transaction_at_utc,
|
||||
{{ adapter.quote("DateString") }} as date_string,
|
||||
|
||||
{{ adapter.quote("Total") }} as total_amount_local_curr,
|
||||
{{ adapter.quote("SubTotal") }} as subtotal_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,
|
||||
{{ adapter.quote("LineAmountTypes") }} as line_amount_tax_inclusiveness,
|
||||
|
||||
{{ adapter.quote("Contact") }} as full_contact_details,
|
||||
{{ adapter.quote("LineItems") }} as line_items,
|
||||
{{ adapter.quote("BankAccount") }} as bank_account,
|
||||
|
||||
{{ adapter.quote("IsReconciled") }} as is_reconciled,
|
||||
{{ adapter.quote("HasAttachments") }} as has_attachments,
|
||||
{{ adapter.quote("Url") }} as url,
|
||||
{{ adapter.quote("ExternalLinkProviderName") }}
|
||||
as external_link_provider_name,
|
||||
{{ 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
|
||||
)
|
||||
select *
|
||||
from stg_xero__bank_transactions
|
||||
Loading…
Add table
Add a link
Reference in a new issue