Merged PR 2231: Xero Sales Mart
This PR implements a denormalized view of Xero invoice and credit notes data. This is done because this shaped of data will both enable very simple reporting on some accounting reports, as well as easier modeling in some of the KPIs effort. I also included a tiny change on dates and times in the invoice models. Related work items: #17550
This commit is contained in:
commit
62ad19ea9e
5 changed files with 321 additions and 1 deletions
|
|
@ -5,6 +5,7 @@ select
|
|||
full_contact_details ->> 'ContactID' as id_contact,
|
||||
reference,
|
||||
invoice_number,
|
||||
invoice_issued_at_utc,
|
||||
invoice_issued_date_utc,
|
||||
invoice_due_date_utc,
|
||||
was_fully_paid_on_date_utc,
|
||||
|
|
|
|||
100
models/intermediate/xero/int_xero__sales_denom_mart.sql
Normal file
100
models/intermediate/xero/int_xero__sales_denom_mart.sql
Normal file
|
|
@ -0,0 +1,100 @@
|
|||
with
|
||||
int_xero__invoice_line_items as (
|
||||
select * from {{ ref("int_xero__invoice_line_items") }}
|
||||
),
|
||||
int_xero__invoices as (select * from {{ ref("int_xero__invoices") }}),
|
||||
int_xero__credit_note_line_items as (
|
||||
select * from {{ ref("int_xero__credit_note_line_items") }}
|
||||
),
|
||||
int_xero__credit_notes as (select * from {{ ref("int_xero__credit_notes") }}),
|
||||
int_xero__contacts as (select * from {{ ref("int_xero__contacts") }})
|
||||
select
|
||||
ili.id_line_item as id_line_item,
|
||||
ili.id_item as id_item,
|
||||
'invoice' as document_class,
|
||||
ili.item_code as item_code,
|
||||
ili.quantity as quantity,
|
||||
ili.unit_amount as unit_amount,
|
||||
ili.line_amount_local_curr as line_amount_local_curr,
|
||||
ili.line_amount_in_gbp as line_amount_in_gbp,
|
||||
ili.line_amount_wo_taxes_local_curr,
|
||||
ili.line_amount_wo_taxes_in_gbp,
|
||||
ili.tax_amount_local_curr as tax_amount_local_curr,
|
||||
ili.tax_amount_in_gbp as tax_amount_in_gbp,
|
||||
ili.tax_type as tax_type,
|
||||
ili.line_description as line_description,
|
||||
|
||||
i.id_invoice as id_document,
|
||||
i.reference as reference,
|
||||
i.invoice_number as document_number,
|
||||
i.invoice_issued_at_utc as document_issued_at_utc,
|
||||
i.invoice_issued_date_utc as document_issued_date_utc,
|
||||
i.invoice_type as document_type,
|
||||
i.invoice_currency_iso_4217 as document_currency_iso_4217,
|
||||
i.exchange_rate_to_gbp as exchange_rate_to_gbp,
|
||||
i.invoice_status as document_status,
|
||||
i.line_amount_tax_inclusiveness as line_amount_tax_inclusiveness,
|
||||
i.total_amount_local_curr as header_total_amount_local_curr,
|
||||
i.total_amount_in_gbp as header_total_amount_in_gbp,
|
||||
i.total_amount_wo_tax_local_curr as header_total_amount_wo_tax_local_curr,
|
||||
i.total_amount_wo_tax_in_gbp as header_total_amount_wo_tax_in_gbp,
|
||||
i.total_tax_local_curr as header_total_tax_local_curr,
|
||||
i.total_tax_in_gbp as header_total_tax_in_gbp,
|
||||
i.total_due_local_curr as header_total_due_local_curr,
|
||||
i.total_due_in_gbp as header_total_due_in_gbp,
|
||||
|
||||
c.id_contact as id_contact,
|
||||
c.id_deal as id_deal,
|
||||
c.contact_name as contact_name
|
||||
|
||||
from int_xero__invoice_line_items ili
|
||||
left join int_xero__invoices i on i.id_invoice = ili.id_invoice
|
||||
left join int_xero__contacts c on c.id_contact = i.id_contact
|
||||
|
||||
union all
|
||||
|
||||
select
|
||||
|
||||
cnli.id_line_item,
|
||||
cnli.id_item,
|
||||
'credit note' as document_class,
|
||||
cnli.item_code,
|
||||
cnli.quantity,
|
||||
cnli.unit_amount,
|
||||
-- We multiply all credit amounts by -1 so aggregations with
|
||||
-- invoicing side work the way you would expect them to
|
||||
cnli.line_amount_local_curr * -1,
|
||||
cnli.line_amount_in_gbp * -1,
|
||||
cnli.line_amount_wo_taxes_local_curr * -1,
|
||||
cnli.line_amount_wo_taxes_in_gbp * -1,
|
||||
cnli.tax_amount_local_curr * -1,
|
||||
cnli.tax_amount_in_gbp * -1,
|
||||
cnli.tax_type,
|
||||
cnli.line_description,
|
||||
|
||||
cn.id_credit_note,
|
||||
cn.reference,
|
||||
cn.credit_note_number,
|
||||
cn.credit_note_issued_at_utc,
|
||||
cn.credit_note_issued_date_utc,
|
||||
cn.credit_note_type,
|
||||
cn.credit_note_currency_iso_4217,
|
||||
cn.exchange_rate_to_gbp,
|
||||
cn.credit_note_status,
|
||||
cn.line_amount_tax_inclusiveness,
|
||||
cn.total_amount_local_curr * -1,
|
||||
cn.total_amount_in_gbp * -1,
|
||||
cn.subtotal_local_curr * -1,
|
||||
cn.subtotal_in_gbp * -1,
|
||||
cn.total_tax_local_curr * -1,
|
||||
cn.total_tax_in_gbp * -1,
|
||||
cn.remaining_credit_local_curr * -1,
|
||||
cn.remaining_credit_in_gbp * -1,
|
||||
|
||||
c.id_contact,
|
||||
c.id_deal,
|
||||
c.contact_name
|
||||
|
||||
from int_xero__credit_note_line_items cnli
|
||||
left join int_xero__credit_notes cn on cn.id_credit_note = cnli.id_credit_note
|
||||
left join int_xero__contacts c on c.id_contact = cn.id_contact
|
||||
|
|
@ -31,5 +31,222 @@ models:
|
|||
tests:
|
||||
- not_null
|
||||
- unique
|
||||
|
||||
- name: int_xero__sales_denom_mart
|
||||
description: |
|
||||
This table is a denormalized mix of all invoices and credit notes data.
|
||||
|
||||
It is built by creating a snowflake schema for the invoicing area and
|
||||
another one for the crediting area. In both cases, the cardinality is
|
||||
*:1 between line items and documents, and *:1 between documents and
|
||||
contacts. Then, the invoice and credit note side get unioned to be stored
|
||||
in a single structure. The only transformation that happens differently
|
||||
across both is that credit note amounts get their sign reversed (* -1) so
|
||||
that aggregations happen naturally (credit amounts subtract from invoice
|
||||
amounts). The final granularity of the table is on the line item level.
|
||||
Invoice and credit note records can be told apart through the
|
||||
document_class field.
|
||||
|
||||
The word _document_ in the context of this table encompasses both invoices
|
||||
and credit notes.
|
||||
|
||||
The source of amounts is identifiable by their prefix. `line_` amount
|
||||
fields come from the line items data, while `header_` fields come from the
|
||||
document level data. Aggregating line fields can be done without worries.
|
||||
Document level data can't be summed or averaged since it's duplicated per
|
||||
line item, so be careful with it.
|
||||
|
||||
Fields are not documented here: you can find more details in upstream
|
||||
models.
|
||||
|
||||
columns:
|
||||
- name: id_line_item
|
||||
data_type: text
|
||||
description: ""
|
||||
tests:
|
||||
- not_null
|
||||
- unique
|
||||
|
||||
- name: id_item
|
||||
data_type: text
|
||||
description: ""
|
||||
|
||||
- name: document_class
|
||||
data_type: text
|
||||
description: |
|
||||
Indicates whether the record belongs in an invoice or a credit note.
|
||||
tests:
|
||||
- not_null
|
||||
- accepted_values:
|
||||
values:
|
||||
- 'invoice'
|
||||
- 'credit note'
|
||||
|
||||
- name: item_code
|
||||
data_type: text
|
||||
description: ""
|
||||
|
||||
- name: quantity
|
||||
data_type: numeric
|
||||
description: ""
|
||||
|
||||
- name: unit_amount
|
||||
data_type: numeric
|
||||
description: ""
|
||||
|
||||
- name: line_amount_local_curr
|
||||
data_type: numeric
|
||||
description: ""
|
||||
|
||||
- name: line_amount_in_gbp
|
||||
data_type: numeric
|
||||
description: ""
|
||||
|
||||
- name: line_amount_wo_taxes_local_curr
|
||||
data_type: numeric
|
||||
description: ""
|
||||
|
||||
- name: line_amount_wo_taxes_in_gbp
|
||||
data_type: numeric
|
||||
description: ""
|
||||
|
||||
- name: tax_amount_local_curr
|
||||
data_type: numeric
|
||||
description: ""
|
||||
|
||||
- name: tax_amount_in_gbp
|
||||
data_type: numeric
|
||||
description: ""
|
||||
|
||||
- name: tax_type
|
||||
data_type: text
|
||||
description: ""
|
||||
|
||||
- name: document_currency_iso_4217
|
||||
data_type: character varying
|
||||
description: ""
|
||||
tests:
|
||||
- not_null
|
||||
- length_between:
|
||||
min_length: 3
|
||||
max_length: 3
|
||||
|
||||
- name: line_description
|
||||
data_type: text
|
||||
description: ""
|
||||
|
||||
- name: id_document
|
||||
data_type: character varying
|
||||
description: ""
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: reference
|
||||
data_type: character varying
|
||||
description: ""
|
||||
|
||||
- name: document_number
|
||||
data_type: character varying
|
||||
description: ""
|
||||
|
||||
- name: document_issued_at_utc
|
||||
data_type: timestamp with time zone
|
||||
description: ""
|
||||
|
||||
- name: document_issued_date_utc
|
||||
data_type: date
|
||||
description: ""
|
||||
|
||||
- name: document_type
|
||||
data_type: character varying
|
||||
description: ""
|
||||
tests:
|
||||
- not_null
|
||||
- accepted_values:
|
||||
values:
|
||||
- "ACCREC"
|
||||
- "ACCPAY"
|
||||
- "ACCRECCREDIT"
|
||||
- "ACCPAYCREDIT"
|
||||
|
||||
- name: document_currency_iso_4217
|
||||
data_type: character varying
|
||||
description: ""
|
||||
|
||||
- name: exchange_rate_to_gbp
|
||||
data_type: numeric
|
||||
description: ""
|
||||
tests:
|
||||
- not_null
|
||||
- not_negative
|
||||
|
||||
- name: document_status
|
||||
data_type: character varying
|
||||
description: ""
|
||||
tests:
|
||||
- not_null
|
||||
- accepted_values:
|
||||
values:
|
||||
- PAID
|
||||
- VOIDED
|
||||
- DRAFT
|
||||
- DELETED
|
||||
- AUTHORISED
|
||||
- SUBMITTED
|
||||
|
||||
- name: line_amount_tax_inclusiveness
|
||||
data_type: character varying
|
||||
description: ""
|
||||
tests:
|
||||
- accepted_values:
|
||||
values:
|
||||
- Inclusive
|
||||
- Exclusive
|
||||
- NoTax
|
||||
|
||||
- name: header_total_amount_local_curr
|
||||
data_type: numeric
|
||||
description: ""
|
||||
|
||||
- name: header_total_amount_in_gbp
|
||||
data_type: numeric
|
||||
description: ""
|
||||
|
||||
- name: header_total_amount_wo_tax_local_curr
|
||||
data_type: numeric
|
||||
description: ""
|
||||
|
||||
- name: header_total_amount_wo_tax_in_gbp
|
||||
data_type: numeric
|
||||
description: ""
|
||||
|
||||
- name: header_total_tax_local_curr
|
||||
data_type: numeric
|
||||
description: ""
|
||||
|
||||
- name: header_total_tax_in_gbp
|
||||
data_type: numeric
|
||||
description: ""
|
||||
|
||||
- name: header_total_due_local_curr
|
||||
data_type: numeric
|
||||
description: ""
|
||||
|
||||
- name: header_total_due_in_gbp
|
||||
data_type: numeric
|
||||
description: ""
|
||||
|
||||
- name: id_contact
|
||||
data_type: character varying
|
||||
description: ""
|
||||
|
||||
- name: id_deal
|
||||
data_type: text
|
||||
description: ""
|
||||
|
||||
- name: contact_name
|
||||
data_type: character varying
|
||||
description: ""
|
||||
|
||||
|
||||
|
||||
|
|
@ -5,6 +5,7 @@ select
|
|||
id_contact as id_contact,
|
||||
reference as reference,
|
||||
invoice_number as invoice_number,
|
||||
invoice_issued_at_utc as invoice_issued_at_utc,
|
||||
invoice_issued_date_utc as invoice_issued_date_utc,
|
||||
invoice_due_date_utc as invoice_due_date_utc,
|
||||
was_fully_paid_on_date_utc as was_fully_paid_on_date_utc,
|
||||
|
|
|
|||
|
|
@ -5,7 +5,8 @@ with
|
|||
{{ adapter.quote("InvoiceID") }} as id_invoice,
|
||||
{{ adapter.quote("Reference") }} as reference,
|
||||
{{ adapter.quote("InvoiceNumber") }} as invoice_number,
|
||||
{{ adapter.quote("Date") }} as invoice_issued_date_utc,
|
||||
{{ adapter.quote("Date") }} as invoice_issued_at_utc,
|
||||
cast({{ adapter.quote("Date") }} as date) as invoice_issued_date_utc,
|
||||
{{ adapter.quote("DueDate") }} as invoice_due_date_utc,
|
||||
{{ adapter.quote("FullyPaidOnDate") }} as was_fully_paid_on_date_utc,
|
||||
{{ adapter.quote("Type") }} as invoice_type,
|
||||
|
|
|
|||
Loading…
Add table
Add a link
Reference in a new issue