Merged PR 1853: Xero Line Items
Pushes a few Xero models all the way from sync to reporting to enable some business overview stuff.
This commit is contained in:
commit
e1af049400
11 changed files with 1215 additions and 5 deletions
45
models/intermediate/xero/int_xero__contacts.sql
Normal file
45
models/intermediate/xero/int_xero__contacts.sql
Normal file
|
|
@ -0,0 +1,45 @@
|
|||
with stg_xero__contacts as (select * from {{ ref("stg_xero__contacts") }})
|
||||
select
|
||||
id_contact,
|
||||
account_number,
|
||||
case when account_number ~ '^[0-9]{10,11}$' then account_number else null end::text
|
||||
as id_deal,
|
||||
contact_name,
|
||||
is_customer,
|
||||
is_supplier,
|
||||
tax_number,
|
||||
contact_first_name,
|
||||
contact_last_name,
|
||||
phones,
|
||||
website,
|
||||
balances,
|
||||
discount,
|
||||
addresses,
|
||||
attachments,
|
||||
email_addresses,
|
||||
payment_terms,
|
||||
batch_payments,
|
||||
branding_theme,
|
||||
contact_groups,
|
||||
contact_number,
|
||||
contact_status,
|
||||
skyper_user_name,
|
||||
contact_persons,
|
||||
has_attachments,
|
||||
updated_at_utc,
|
||||
updated_date_utc,
|
||||
xero_network_key,
|
||||
default_currency_iso_4217,
|
||||
validation_errors,
|
||||
bank_account_details,
|
||||
has_validation_errors,
|
||||
tracking_category_name,
|
||||
account_payable_tax_type,
|
||||
tracking_category_option,
|
||||
sales_default_account_code,
|
||||
sales_tracking_categories,
|
||||
account_receivable_tax_type,
|
||||
purchases_default_account_code,
|
||||
purchases_tracking_categories,
|
||||
dwh_extracted_at_utc
|
||||
from stg_xero__contacts
|
||||
63
models/intermediate/xero/int_xero__invoice_line_items.sql
Normal file
63
models/intermediate/xero/int_xero__invoice_line_items.sql
Normal file
|
|
@ -0,0 +1,63 @@
|
|||
with int_xero__invoices as (select * from {{ ref("int_xero__invoices") }})
|
||||
|
||||
select
|
||||
i.id_invoice,
|
||||
j.id_line_item,
|
||||
j.id_item,
|
||||
j.item_code,
|
||||
j.quantity::numeric,
|
||||
j.unit_amount::numeric,
|
||||
j.line_amount_local_curr::numeric,
|
||||
(j.line_amount_local_curr::numeric * i.exchange_rate_to_gbp)::numeric(
|
||||
18, 4
|
||||
) as line_amount_in_gbp,
|
||||
case
|
||||
when i.line_amount_tax_inclusiveness = 'Inclusive'
|
||||
then j.line_amount_local_curr::numeric - j.tax_amount_local_curr::numeric
|
||||
when i.line_amount_tax_inclusiveness = 'Exclusive'
|
||||
then j.line_amount_local_curr::numeric
|
||||
when i.line_amount_tax_inclusiveness = 'NoTax'
|
||||
then j.line_amount_local_curr::numeric
|
||||
else null
|
||||
end as line_amount_wo_taxes_local_curr,
|
||||
case
|
||||
when i.line_amount_tax_inclusiveness = 'Inclusive'
|
||||
then
|
||||
(j.line_amount_local_curr::numeric * i.exchange_rate_to_gbp)::numeric(18, 4)
|
||||
- (j.tax_amount_local_curr::numeric * i.exchange_rate_to_gbp)::numeric(
|
||||
18, 4
|
||||
)
|
||||
when i.line_amount_tax_inclusiveness = 'Exclusive'
|
||||
then
|
||||
(j.line_amount_local_curr::numeric * i.exchange_rate_to_gbp)::numeric(18, 4)
|
||||
when i.line_amount_tax_inclusiveness = 'NoTax'
|
||||
then
|
||||
(j.line_amount_local_curr::numeric * i.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 * i.exchange_rate_to_gbp)::numeric(
|
||||
18, 4
|
||||
) as tax_amount_in_gbp,
|
||||
j.tax_type,
|
||||
i.invoice_currency_iso_4217,
|
||||
j.line_description
|
||||
from int_xero__invoices i
|
||||
cross join
|
||||
lateral(
|
||||
select
|
||||
(jsonb_array_elements(i.line_items) ->> 'LineItemID') as id_line_item,
|
||||
(jsonb_array_elements(i.line_items) -> 'Item') ->> 'ItemID' as id_item,
|
||||
(jsonb_array_elements(i.line_items) -> 'Item') ->> 'Code' as item_code,
|
||||
(jsonb_array_elements(i.line_items) -> 'Item') ->> 'Name' as item_name,
|
||||
(jsonb_array_elements(i.line_items) ->> 'Quantity') as quantity,
|
||||
(jsonb_array_elements(i.line_items) ->> 'UnitAmount') as unit_amount,
|
||||
(
|
||||
jsonb_array_elements(i.line_items) ->> 'LineAmount'
|
||||
) as line_amount_local_curr,
|
||||
(
|
||||
jsonb_array_elements(i.line_items) ->> 'TaxAmount'
|
||||
) as tax_amount_local_curr,
|
||||
(jsonb_array_elements(i.line_items) ->> 'TaxType') as tax_type,
|
||||
(jsonb_array_elements(i.line_items) ->> 'Description') as line_description
|
||||
) j
|
||||
51
models/intermediate/xero/int_xero__invoices.sql
Normal file
51
models/intermediate/xero/int_xero__invoices.sql
Normal file
|
|
@ -0,0 +1,51 @@
|
|||
with stg_xero__invoices as (select * from {{ ref("stg_xero__invoices") }})
|
||||
|
||||
select
|
||||
id_invoice,
|
||||
full_contact_details ->> 'ContactID' as id_contact,
|
||||
reference,
|
||||
invoice_number,
|
||||
invoice_issued_date_utc,
|
||||
invoice_due_date_utc,
|
||||
was_fully_paid_on_date_utc,
|
||||
invoice_type,
|
||||
invoice_currency_iso_4217,
|
||||
exchange_rate_to_gbp,
|
||||
total_amount_local_curr,
|
||||
(total_amount_local_curr * exchange_rate_to_gbp)::numeric(
|
||||
18, 4
|
||||
) as total_amount_in_gbp,
|
||||
total_amount_wo_tax_local_curr,
|
||||
(total_amount_wo_tax_local_curr * exchange_rate_to_gbp)::numeric(
|
||||
18, 4
|
||||
) as total_amount_wo_tax_in_gbp,
|
||||
total_tax_local_curr,
|
||||
(total_tax_local_curr * exchange_rate_to_gbp)::numeric(18, 4) as total_tax_in_gbp,
|
||||
total_due_local_curr,
|
||||
(total_due_local_curr * exchange_rate_to_gbp)::numeric(18, 4) as total_due_in_gbp,
|
||||
total_paid_local_curr,
|
||||
(total_paid_local_curr * exchange_rate_to_gbp)::numeric(18, 4) as total_paid_in_gbp,
|
||||
invoice_status,
|
||||
full_contact_details,
|
||||
payments,
|
||||
has_errors,
|
||||
line_items,
|
||||
credit_notes,
|
||||
prepayments,
|
||||
overpayments,
|
||||
is_discounted,
|
||||
date_string,
|
||||
due_date_string,
|
||||
has_been_sent_to_contact,
|
||||
total_discount,
|
||||
total_credited_local_curr,
|
||||
has_attachments,
|
||||
updated_at_utc,
|
||||
updated_date_utc,
|
||||
id_branding_theme,
|
||||
invoice_url,
|
||||
line_amount_tax_inclusiveness,
|
||||
payment_planned_date_utc,
|
||||
payment_expected_date_utc,
|
||||
dwh_extracted_at_utc
|
||||
from stg_xero__invoices
|
||||
|
|
@ -18,17 +18,18 @@ exposures:
|
|||
name: Pablo Martin
|
||||
email: pablo.martin@superhog.com
|
||||
|
||||
- name: host_booking_fees
|
||||
label: Host Booking Fees
|
||||
- name: host_fees
|
||||
label: Host Fees
|
||||
type: dashboard
|
||||
maturity: low
|
||||
url: https://app.powerbi.com/Redirect?action=OpenReport&appId=33e55130-3a65-4fe8-86f2-11979fb2258a&reportObjectId=01d5648d-1c0b-4a22-988d-75e1cd64b5e5&ctid=862842df-2998-4826-bea9-b726bc01d3a7&reportPage=ReportSectiona542e78b23000f1cd14a&pbi_source=appShareLink&portalSessionId=86206797-4512-4ecb-a946-da8d0b58a757
|
||||
description: |
|
||||
|
||||
A PBI report showcasing our revenue coming from booking fees with a transaction point of view.
|
||||
A PBI report showcasing our revenue coming from host fees with a transaction point of view.
|
||||
|
||||
depends_on:
|
||||
- ref('core__bookings')
|
||||
- ref('xero__denom_invoicing_mart')
|
||||
- ref('dates')
|
||||
|
||||
owner:
|
||||
|
|
|
|||
852
models/reporting/xero/schema.yaml
Normal file
852
models/reporting/xero/schema.yaml
Normal file
|
|
@ -0,0 +1,852 @@
|
|||
version: 2
|
||||
|
||||
models:
|
||||
- name: xero__invoices
|
||||
description: |
|
||||
Invoices that we have raised within our accounting books.
|
||||
|
||||
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
|
||||
|
||||
columns:
|
||||
- name: id_invoice
|
||||
data_type: character varying
|
||||
description: Xero's unique identifier for the invoice.
|
||||
|
||||
- name: id_contact
|
||||
data_type: text
|
||||
description: |
|
||||
The ID of the contact related to this invoice.
|
||||
|
||||
The customer if it's an Accounts Receivables one, the supplier if it's an Accounts Payables one.
|
||||
|
||||
You can use this to join with the contacts table.
|
||||
|
||||
- name: reference
|
||||
data_type: character varying
|
||||
description: |
|
||||
The Superhog-set reference for the invoices. Only relevant for
|
||||
records of invoice type (ACCREC).
|
||||
|
||||
- name: invoice_number
|
||||
data_type: character varying
|
||||
description: ""
|
||||
|
||||
- name: invoice_issued_date_utc
|
||||
data_type: timestamp with time zone
|
||||
description: Date on which the invoice was issued.
|
||||
|
||||
- name: invoice_due_date_utc
|
||||
data_type: timestamp with time zone
|
||||
description: The date were the invoice should be paid the latest.
|
||||
|
||||
- name: was_fully_paid_on_date_utc
|
||||
data_type: timestamp with time zone
|
||||
description: |
|
||||
The date on which the invoice was fully paid. If the invoice is still
|
||||
not fully paid, it returns null.
|
||||
|
||||
- name: invoice_type
|
||||
data_type: character varying
|
||||
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").
|
||||
|
||||
- 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.
|
||||
|
||||
- name: exchange_rate_to_gbp
|
||||
data_type: numeric
|
||||
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).
|
||||
|
||||
- name: total_amount_local_curr
|
||||
data_type: numeric
|
||||
description: The total amount to be paid, in the currency the invoice is denominated in.
|
||||
|
||||
- name: total_amount_in_gbp
|
||||
data_type: numeric
|
||||
description: The total amount to be paid, converted to GBP.
|
||||
|
||||
- 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.
|
||||
|
||||
- name: total_amount_wo_tax_in_gbp
|
||||
data_type: numeric
|
||||
description: The total amount to be paid minus taxes, converted to GBP.
|
||||
|
||||
- name: total_tax_local_curr
|
||||
data_type: numeric
|
||||
description: The total tax, in the currency the invoice is denominated in.
|
||||
|
||||
- name: total_tax_in_gbp
|
||||
data_type: numeric
|
||||
description: The total tax, converted to GBP.
|
||||
|
||||
- name: total_due_local_curr
|
||||
data_type: numeric
|
||||
description: The total amount outstanding right now, in the currency the invoice is denominated in.
|
||||
|
||||
- name: total_due_in_gbp
|
||||
data_type: numeric
|
||||
description: The total amount outstanding right now, converted to GBP.
|
||||
|
||||
- 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.
|
||||
|
||||
- name: total_paid_in_gbp
|
||||
data_type: numeric
|
||||
description: The total amount that has already been paid, in GBP.
|
||||
|
||||
- name: invoice_status
|
||||
data_type: character varying
|
||||
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
|
||||
|
||||
- name: has_errors
|
||||
data_type: boolean
|
||||
description: ""
|
||||
|
||||
- name: is_discounted
|
||||
data_type: boolean
|
||||
description: ""
|
||||
|
||||
- name: date_string
|
||||
data_type: timestamp with time zone
|
||||
description: ""
|
||||
|
||||
- name: due_date_string
|
||||
data_type: timestamp with time zone
|
||||
description: ""
|
||||
|
||||
- name: has_been_sent_to_contact
|
||||
data_type: boolean
|
||||
description: ""
|
||||
|
||||
- name: total_discount
|
||||
data_type: numeric
|
||||
description: ""
|
||||
|
||||
- name: total_credited_local_curr
|
||||
data_type: numeric
|
||||
description:
|
||||
Total amount credited by related credit notes, over-payments and
|
||||
pre-payments.
|
||||
|
||||
- name: has_attachments
|
||||
data_type: boolean
|
||||
description: Flag indicating if the invoice has an attachment.
|
||||
|
||||
- name: updated_at_utc
|
||||
data_type: timestamp with time zone
|
||||
description: ""
|
||||
|
||||
- name: updated_date_utc
|
||||
data_type: date
|
||||
description: ""
|
||||
|
||||
- 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).
|
||||
|
||||
- name: payment_planned_date_utc
|
||||
data_type: timestamp with time zone
|
||||
description: ""
|
||||
|
||||
- name: payment_expected_date_utc
|
||||
data_type: timestamp with time zone
|
||||
description: ""
|
||||
|
||||
- name: dwh_extracted_at_utc
|
||||
data_type: timestamp with time zone
|
||||
description: ""
|
||||
|
||||
- name: xero__invoice_line_items
|
||||
description: |
|
||||
Invoice line items. Every record corresponds to a Line Item in Xero.
|
||||
|
||||
A Line Item is a combination of a specific service or item being sold,
|
||||
together with its quantity, price, total amount and taxes.
|
||||
|
||||
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.
|
||||
|
||||
- name: id_line_item
|
||||
data_type: text
|
||||
description: Xero's unique identifier for the line item.
|
||||
|
||||
- name: id_item
|
||||
data_type: text
|
||||
description: Xero's unique identifier for the item of this line.
|
||||
|
||||
- name: item_code
|
||||
data_type: text
|
||||
description: A text based code that describes the Item.
|
||||
|
||||
- name: quantity
|
||||
data_type: numeric
|
||||
description: How much of the item is sold in its invoice.
|
||||
|
||||
- name: unit_amount
|
||||
data_type: numeric
|
||||
description: The price of each unit of the item.
|
||||
|
||||
- name: line_amount_local_curr
|
||||
data_type: numeric
|
||||
description: |
|
||||
The total value to be charged for this line, in local currency.
|
||||
|
||||
- name: line_amount_in_gbp
|
||||
data_type: numeric
|
||||
description: The total value to be charged for this line, in GBP.
|
||||
|
||||
- name: line_amount_wo_taxes_local_curr
|
||||
data_type: numeric
|
||||
description: |
|
||||
The total value to be charged for this line, minus taxes, in local
|
||||
currency.
|
||||
|
||||
In some cases, this will be the same value as the line amount. This
|
||||
depends on whether there is any tax in the invoice, and whether the
|
||||
invoice amounts are tax inclusive or tax exclusive. You can find this
|
||||
out in the details of the invoice this line item belongs to.
|
||||
|
||||
- name: line_amount_wo_taxes_in_gbp
|
||||
data_type: numeric
|
||||
description: |
|
||||
The total value to be charged for this line, minus taxes, in GBP.
|
||||
|
||||
In some cases, this will be the same value as the line amount. This
|
||||
depends on whether there is any tax in the invoice, and whether the
|
||||
invoice amounts are tax inclusive or tax exclusive. You can find this
|
||||
out in the details of the invoice this line item belongs to.
|
||||
|
||||
- name: tax_amount_local_curr
|
||||
data_type: numeric
|
||||
description: The total value of taxes for this line, in local currency.
|
||||
|
||||
- name: tax_amount_in_gbp
|
||||
data_type: numeric
|
||||
description: The total value of taxes for this line, in GBP.
|
||||
|
||||
- name: tax_type
|
||||
data_type: text
|
||||
description: ""
|
||||
|
||||
- name: invoice_currency_iso_4217
|
||||
data_type: character varying
|
||||
description: |
|
||||
The currency in which this line item amounts are defined.
|
||||
|
||||
Line items don't really have a currency definition of its own, this
|
||||
field is populated for your convenience when working with this data.
|
||||
The invoice currency is defined at the invoice level, and the values
|
||||
you see in this field should always be the same as the currency of
|
||||
the invoice this line item belongs to.
|
||||
|
||||
- name: line_description
|
||||
data_type: text
|
||||
description: A text description of the line item.
|
||||
- name: xero__contacts
|
||||
description: |
|
||||
Xero contacts identify other parties we transact with: customers, suppliers, employees, etc.
|
||||
|
||||
The most interesting contacts are our customers.
|
||||
columns:
|
||||
- name: id_contact
|
||||
data_type: character varying
|
||||
description: Xero's unique identifier for the contact.
|
||||
|
||||
- name: account_number
|
||||
data_type: character varying
|
||||
description: A Superhog set identifier. For customers, this is Hubspot's Deal Id.
|
||||
|
||||
- name: id_deal
|
||||
data_type: text
|
||||
description: |
|
||||
For those account numbers that look like a Deal Id, we extract them
|
||||
into this field. Other contacs will have a blank.
|
||||
|
||||
You can use this to find specific deal ids or even as a proxy bool to
|
||||
keep or remove deal id customers.
|
||||
|
||||
- name: contact_name
|
||||
data_type: character varying
|
||||
description: The name for the customer.
|
||||
|
||||
- name: is_customer
|
||||
data_type: boolean
|
||||
description: Flag that shows if the contact is a Superhog customer.
|
||||
|
||||
- name: is_supplier
|
||||
data_type: boolean
|
||||
description: Flag that shows if the contact is a Superhog supplier.
|
||||
|
||||
- name: tax_number
|
||||
data_type: character varying
|
||||
description: Tax number for this contact.
|
||||
|
||||
- name: contact_first_name
|
||||
data_type: character varying
|
||||
description: ""
|
||||
|
||||
- name: contact_last_name
|
||||
data_type: character varying
|
||||
description: ""
|
||||
|
||||
- name: phones
|
||||
data_type: jsonb
|
||||
description: ""
|
||||
|
||||
- name: website
|
||||
data_type: character varying
|
||||
description: ""
|
||||
|
||||
- name: balances
|
||||
data_type: jsonb
|
||||
description: ""
|
||||
|
||||
- name: discount
|
||||
data_type: numeric
|
||||
description: ""
|
||||
|
||||
- name: addresses
|
||||
data_type: jsonb
|
||||
description: ""
|
||||
|
||||
- name: attachments
|
||||
data_type: jsonb
|
||||
description: ""
|
||||
|
||||
- name: email_addresses
|
||||
data_type: character varying
|
||||
description: ""
|
||||
|
||||
- name: payment_terms
|
||||
data_type: jsonb
|
||||
description: ""
|
||||
|
||||
- name: batch_payments
|
||||
data_type: jsonb
|
||||
description: ""
|
||||
|
||||
- name: branding_theme
|
||||
data_type: jsonb
|
||||
description: ""
|
||||
|
||||
- name: contact_groups
|
||||
data_type: jsonb
|
||||
description: ""
|
||||
|
||||
- name: contact_number
|
||||
data_type: character varying
|
||||
description: ""
|
||||
|
||||
- name: contact_status
|
||||
data_type: character varying
|
||||
description: ""
|
||||
|
||||
- name: skyper_user_name
|
||||
data_type: character varying
|
||||
description: ""
|
||||
|
||||
- name: contact_persons
|
||||
data_type: jsonb
|
||||
description: ""
|
||||
|
||||
- name: has_attachments
|
||||
data_type: boolean
|
||||
description: ""
|
||||
|
||||
- name: updated_at_utc
|
||||
data_type: timestamp with time zone
|
||||
description: ""
|
||||
|
||||
- name: updated_date_utc
|
||||
data_type: date
|
||||
description: ""
|
||||
|
||||
- name: xero_network_key
|
||||
data_type: character varying
|
||||
description: ""
|
||||
|
||||
- name: default_currency_iso_4217
|
||||
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
|
||||
data_type: jsonb
|
||||
description: ""
|
||||
|
||||
- name: bank_account_details
|
||||
data_type: character varying
|
||||
description: ""
|
||||
|
||||
- name: has_validation_errors
|
||||
data_type: boolean
|
||||
description: ""
|
||||
|
||||
- name: tracking_category_name
|
||||
data_type: character varying
|
||||
description: ""
|
||||
|
||||
- name: account_payable_tax_type
|
||||
data_type: character varying
|
||||
description: ""
|
||||
|
||||
- name: tracking_category_option
|
||||
data_type: character varying
|
||||
description: ""
|
||||
|
||||
- name: sales_default_account_code
|
||||
data_type: character varying
|
||||
description: ""
|
||||
|
||||
- name: sales_tracking_categories
|
||||
data_type: jsonb
|
||||
description: ""
|
||||
|
||||
- name: account_receivable_tax_type
|
||||
data_type: character varying
|
||||
description: ""
|
||||
|
||||
- name: purchases_default_account_code
|
||||
data_type: character varying
|
||||
description: ""
|
||||
|
||||
- name: purchases_tracking_categories
|
||||
data_type: jsonb
|
||||
description: ""
|
||||
|
||||
- name: dwh_extracted_at_utc
|
||||
data_type: timestamp with time zone
|
||||
description: ""
|
||||
- name: xero__denom_invoicing_mart
|
||||
description: |
|
||||
This is denormalized table built upon contacts, invoice and invoice line
|
||||
items. It's just built to save you time in joining and for dealing with
|
||||
certain limitations in PBI.
|
||||
|
||||
The level of granularity is at line item. Line items there are joined
|
||||
with invoices by the id of the invoice present in the line item, and
|
||||
contacts are joined by the id of the contact present in the invoice.
|
||||
Be careful when aggregating figures: sums on the invoice line item level
|
||||
make sense, sums on the invoice level do not.
|
||||
|
||||
Data from the original entities is brought as is with no transformation.
|
||||
Please, when modelling here, try to respect this approach.
|
||||
|
||||
columns:
|
||||
- name: id_line_item
|
||||
data_type: text
|
||||
description: "Xero's unique identifier for the line item."
|
||||
|
||||
- name: id_item
|
||||
data_type: text
|
||||
description: "Xero's unique identifier for the item of this line."
|
||||
|
||||
- name: item_code
|
||||
data_type: text
|
||||
description: "A text based code that describes the Item."
|
||||
|
||||
- name: quantity
|
||||
data_type: numeric
|
||||
description: "How much of the item is sold in its invoice."
|
||||
|
||||
- name: unit_amount
|
||||
data_type: numeric
|
||||
description: "The price of each unit of the item."
|
||||
|
||||
- name: line_amount_local_curr
|
||||
data_type: numeric
|
||||
description: |
|
||||
The total value to be charged for this line, in local currency.
|
||||
|
||||
- name: line_amount_in_gbp
|
||||
data_type: numeric
|
||||
description: "The total value to be charged for this line, in GBP."
|
||||
|
||||
- name: line_amount_wo_taxes_local_curr
|
||||
data_type: numeric
|
||||
description: |
|
||||
|
||||
The total value to be charged for this line, minus taxes, in local
|
||||
currency.
|
||||
|
||||
In some cases, this will be the same value as the line amount. This
|
||||
depends on whether there is any tax in the invoice, and whether the
|
||||
invoice amounts are tax inclusive or tax exclusive. You can find this
|
||||
out in the details of the invoice this line item belongs to.
|
||||
|
||||
- name: line_amount_wo_taxes_in_gbp
|
||||
data_type: numeric
|
||||
description: |
|
||||
The total value to be charged for this line, minus taxes, in GBP.
|
||||
|
||||
In some cases, this will be the same value as the line amount. This
|
||||
depends on whether there is any tax in the invoice, and whether the
|
||||
invoice amounts are tax inclusive or tax exclusive. You can find this
|
||||
out in the details of the invoice this line item belongs to.
|
||||
|
||||
- name: tax_amount_local_curr
|
||||
data_type: numeric
|
||||
description: "The total value of taxes for this line, in local currency."
|
||||
|
||||
- name: tax_amount_in_gbp
|
||||
data_type: numeric
|
||||
description: "The total value of taxes for this line, in GBP."
|
||||
|
||||
- name: tax_type
|
||||
data_type: text
|
||||
description: ""
|
||||
|
||||
- name: line_description
|
||||
data_type: text
|
||||
description: "A text description of the line item."
|
||||
|
||||
- name: id_invoice
|
||||
data_type: character varying
|
||||
description: "Xero's unique identifier for the invoice."
|
||||
|
||||
- name: reference
|
||||
data_type: character varying
|
||||
description: |
|
||||
The Superhog-set reference for the invoices. Only relevant for
|
||||
records of invoice type (ACCREC).
|
||||
|
||||
- name: invoice_number
|
||||
data_type: character varying
|
||||
description: ""
|
||||
|
||||
- name: invoice_issued_date_utc
|
||||
data_type: timestamp with time zone
|
||||
description: "Date on which the invoice was issued."
|
||||
|
||||
- name: invoice_due_date_utc
|
||||
data_type: timestamp with time zone
|
||||
description: "The date were the invoice should be paid the latest."
|
||||
|
||||
- name: was_fully_paid_on_date_utc
|
||||
data_type: timestamp with time zone
|
||||
description: |
|
||||
The date on which the invoice was fully paid. If the invoice is still
|
||||
not fully paid, it returns null.
|
||||
|
||||
- name: invoice_type
|
||||
data_type: character varying
|
||||
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").
|
||||
|
||||
- name: invoice_currency_iso_4217
|
||||
data_type: character varying
|
||||
description: |
|
||||
The currency in which this line item amounts are defined.
|
||||
|
||||
Line items don't really have a currency definition of its own, this
|
||||
field is populated for your convenience when working with this data.
|
||||
The invoice currency is defined at the invoice level, and the values
|
||||
you see in this field should always be the same as the currency of
|
||||
the invoice this line item belongs to.
|
||||
|
||||
- name: exchange_rate_to_gbp
|
||||
data_type: numeric
|
||||
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).
|
||||
|
||||
- name: total_amount_local_curr
|
||||
data_type: numeric
|
||||
description: |
|
||||
The total amount to be paid, in the currency the invoice is
|
||||
denominated in.
|
||||
|
||||
- name: total_amount_in_gbp
|
||||
data_type: numeric
|
||||
description: "The total amount to be paid, converted to GBP."
|
||||
|
||||
- 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.
|
||||
|
||||
- name: total_amount_wo_tax_in_gbp
|
||||
data_type: numeric
|
||||
description: |
|
||||
The total amount to be paid minus taxes, converted to GBP.
|
||||
|
||||
- name: total_tax_local_curr
|
||||
data_type: numeric
|
||||
description: |
|
||||
The total tax, in the currency the invoice is denominated in.
|
||||
|
||||
- name: total_tax_in_gbp
|
||||
data_type: numeric
|
||||
description: "The total tax, converted to GBP."
|
||||
|
||||
- name: total_due_local_curr
|
||||
data_type: numeric
|
||||
description: |
|
||||
The total amount outstanding right now, in the currency the invoice
|
||||
is denominated in.
|
||||
|
||||
- name: total_due_in_gbp
|
||||
data_type: numeric
|
||||
description: |
|
||||
The total amount outstanding right now, converted to GBP.
|
||||
|
||||
- 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.
|
||||
|
||||
- name: total_paid_in_gbp
|
||||
data_type: numeric
|
||||
description: "The total amount that has already been paid, in GBP."
|
||||
|
||||
- name: invoice_status
|
||||
data_type: character varying
|
||||
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
|
||||
|
||||
- name: has_errors
|
||||
data_type: boolean
|
||||
description: ""
|
||||
|
||||
- name: is_discounted
|
||||
data_type: boolean
|
||||
description: ""
|
||||
|
||||
- name: date_string
|
||||
data_type: timestamp with time zone
|
||||
description: ""
|
||||
|
||||
- name: due_date_string
|
||||
data_type: timestamp with time zone
|
||||
description: ""
|
||||
|
||||
- name: has_been_sent_to_contact
|
||||
data_type: boolean
|
||||
description: ""
|
||||
|
||||
- name: total_discount
|
||||
data_type: numeric
|
||||
description: ""
|
||||
|
||||
- name: total_credited_local_curr
|
||||
data_type: numeric
|
||||
description: |
|
||||
Total amount credited by related credit notes,
|
||||
over-payments and pre-payments.
|
||||
|
||||
- name: has_attachments
|
||||
data_type: boolean
|
||||
description: ""
|
||||
|
||||
- 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).
|
||||
|
||||
- name: payment_planned_date_utc
|
||||
data_type: timestamp with time zone
|
||||
description: ""
|
||||
|
||||
- name: payment_expected_date_utc
|
||||
data_type: timestamp with time zone
|
||||
description: ""
|
||||
|
||||
- name: id_contact
|
||||
data_type: character varying
|
||||
description: "Xero's unique identifier for the contact."
|
||||
|
||||
- name: account_number
|
||||
data_type: character varying
|
||||
description: |
|
||||
A Superhog set identifier. For customers, this is Hubspot's Deal Id.
|
||||
|
||||
- name: id_deal
|
||||
data_type: text
|
||||
description: |
|
||||
For those account numbers that look like a Deal Id, we extract them
|
||||
into this field. Other contacs will have a blank.
|
||||
|
||||
You can use this to find specific deal ids or even as a proxy bool to
|
||||
keep or remove deal id customers.
|
||||
|
||||
- name: contact_name
|
||||
data_type: character varying
|
||||
description: "The name for the customer."
|
||||
|
||||
- name: is_customer
|
||||
data_type: boolean
|
||||
description: "Flag that shows if the contact is a Superhog customer."
|
||||
|
||||
- name: is_supplier
|
||||
data_type: boolean
|
||||
description: "Flag that shows if the contact is a Superhog supplier."
|
||||
|
||||
- name: tax_number
|
||||
data_type: character varying
|
||||
description: "Tax number for this contact."
|
||||
|
||||
- name: contact_first_name
|
||||
data_type: character varying
|
||||
description: ""
|
||||
|
||||
- name: contact_last_name
|
||||
data_type: character varying
|
||||
description: ""
|
||||
|
||||
- name: phones
|
||||
data_type: jsonb
|
||||
description: ""
|
||||
|
||||
- name: website
|
||||
data_type: character varying
|
||||
description: ""
|
||||
|
||||
- name: balances
|
||||
data_type: jsonb
|
||||
description: ""
|
||||
|
||||
- name: discount
|
||||
data_type: numeric
|
||||
description: ""
|
||||
|
||||
- name: addresses
|
||||
data_type: jsonb
|
||||
description: ""
|
||||
|
||||
- name: attachments
|
||||
data_type: jsonb
|
||||
description: ""
|
||||
|
||||
- name: email_addresses
|
||||
data_type: character varying
|
||||
description: ""
|
||||
|
||||
- name: payment_terms
|
||||
data_type: jsonb
|
||||
description: ""
|
||||
|
||||
- name: batch_payments
|
||||
data_type: jsonb
|
||||
description: ""
|
||||
|
||||
- name: branding_theme
|
||||
data_type: jsonb
|
||||
description: ""
|
||||
|
||||
- name: contact_groups
|
||||
data_type: jsonb
|
||||
description: ""
|
||||
|
||||
- name: contact_number
|
||||
data_type: character varying
|
||||
description: ""
|
||||
|
||||
- name: contact_status
|
||||
data_type: character varying
|
||||
description: ""
|
||||
|
||||
- name: skyper_user_name
|
||||
data_type: character varying
|
||||
description: ""
|
||||
|
||||
- name: contact_persons
|
||||
data_type: jsonb
|
||||
description: ""
|
||||
|
||||
- name: xero_network_key
|
||||
data_type: character varying
|
||||
description: ""
|
||||
|
||||
- name: default_currency_iso_4217
|
||||
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
|
||||
data_type: jsonb
|
||||
description: ""
|
||||
|
||||
- name: bank_account_details
|
||||
data_type: character varying
|
||||
description: ""
|
||||
|
||||
- name: has_validation_errors
|
||||
data_type: boolean
|
||||
description: ""
|
||||
|
||||
- name: tracking_category_name
|
||||
data_type: character varying
|
||||
description: ""
|
||||
|
||||
- name: account_payable_tax_type
|
||||
data_type: character varying
|
||||
description: ""
|
||||
|
||||
- name: tracking_category_option
|
||||
data_type: character varying
|
||||
description: ""
|
||||
|
||||
- name: sales_default_account_code
|
||||
data_type: character varying
|
||||
description: ""
|
||||
|
||||
- name: sales_tracking_categories
|
||||
data_type: jsonb
|
||||
description: ""
|
||||
|
||||
- name: account_receivable_tax_type
|
||||
data_type: character varying
|
||||
description: ""
|
||||
|
||||
- name: purchases_default_account_code
|
||||
data_type: character varying
|
||||
description: ""
|
||||
|
||||
- name: purchases_tracking_categories
|
||||
data_type: jsonb
|
||||
description: ""
|
||||
44
models/reporting/xero/xero__contacts.sql
Normal file
44
models/reporting/xero/xero__contacts.sql
Normal file
|
|
@ -0,0 +1,44 @@
|
|||
with int_xero__contacts as (select * from {{ ref("int_xero__contacts") }})
|
||||
select
|
||||
id_contact as id_contact,
|
||||
account_number as account_number,
|
||||
id_deal as id_deal,
|
||||
contact_name as contact_name,
|
||||
is_customer as is_customer,
|
||||
is_supplier as is_supplier,
|
||||
tax_number as tax_number,
|
||||
contact_first_name as contact_first_name,
|
||||
contact_last_name as contact_last_name,
|
||||
phones as phones,
|
||||
website as website,
|
||||
balances as balances,
|
||||
discount as discount,
|
||||
addresses as addresses,
|
||||
attachments as attachments,
|
||||
email_addresses as email_addresses,
|
||||
payment_terms as payment_terms,
|
||||
batch_payments as batch_payments,
|
||||
branding_theme as branding_theme,
|
||||
contact_groups as contact_groups,
|
||||
contact_number as contact_number,
|
||||
contact_status as contact_status,
|
||||
skyper_user_name as skyper_user_name,
|
||||
contact_persons as contact_persons,
|
||||
has_attachments as has_attachments,
|
||||
updated_at_utc as updated_at_utc,
|
||||
updated_date_utc as updated_date_utc,
|
||||
xero_network_key as xero_network_key,
|
||||
default_currency_iso_4217 as default_currency_iso_4217,
|
||||
validation_errors as validation_errors,
|
||||
bank_account_details as bank_account_details,
|
||||
has_validation_errors as has_validation_errors,
|
||||
tracking_category_name as tracking_category_name,
|
||||
account_payable_tax_type as account_payable_tax_type,
|
||||
tracking_category_option as tracking_category_option,
|
||||
sales_default_account_code as sales_default_account_code,
|
||||
sales_tracking_categories as sales_tracking_categories,
|
||||
account_receivable_tax_type as account_receivable_tax_type,
|
||||
purchases_default_account_code as purchases_default_account_code,
|
||||
purchases_tracking_categories as purchases_tracking_categories,
|
||||
dwh_extracted_at_utc as dwh_extracted_at_utc
|
||||
from int_xero__contacts
|
||||
93
models/reporting/xero/xero__denom_invoicing_mart.sql
Normal file
93
models/reporting/xero/xero__denom_invoicing_mart.sql
Normal file
|
|
@ -0,0 +1,93 @@
|
|||
with
|
||||
xero__invoices as (select * from {{ ref("xero__invoices") }}),
|
||||
xero__contacts as (select * from {{ ref("xero__contacts") }}),
|
||||
xero__invoice_line_items as (select * from {{ ref("xero__invoice_line_items") }})
|
||||
|
||||
select
|
||||
li.id_line_item,
|
||||
li.id_item,
|
||||
li.item_code,
|
||||
li.quantity,
|
||||
li.unit_amount,
|
||||
li.line_amount_local_curr,
|
||||
li.line_amount_in_gbp,
|
||||
li.line_amount_wo_taxes_local_curr,
|
||||
li.line_amount_wo_taxes_in_gbp,
|
||||
li.tax_amount_local_curr,
|
||||
li.tax_amount_in_gbp,
|
||||
li.tax_type,
|
||||
li.line_description,
|
||||
|
||||
i.id_invoice,
|
||||
i.reference,
|
||||
i.invoice_number,
|
||||
i.invoice_issued_date_utc,
|
||||
i.invoice_due_date_utc,
|
||||
i.was_fully_paid_on_date_utc,
|
||||
i.invoice_type,
|
||||
i.invoice_currency_iso_4217,
|
||||
i.exchange_rate_to_gbp,
|
||||
i.total_amount_local_curr,
|
||||
i.total_amount_in_gbp,
|
||||
i.total_amount_wo_tax_local_curr,
|
||||
i.total_amount_wo_tax_in_gbp,
|
||||
i.total_tax_local_curr,
|
||||
i.total_tax_in_gbp,
|
||||
i.total_due_local_curr,
|
||||
i.total_due_in_gbp,
|
||||
i.total_paid_local_curr,
|
||||
i.total_paid_in_gbp,
|
||||
i.invoice_status,
|
||||
i.has_errors,
|
||||
i.is_discounted,
|
||||
i.date_string,
|
||||
i.due_date_string,
|
||||
i.has_been_sent_to_contact,
|
||||
i.total_discount,
|
||||
i.total_credited_local_curr,
|
||||
i.has_attachments,
|
||||
i.line_amount_tax_inclusiveness,
|
||||
i.payment_planned_date_utc,
|
||||
i.payment_expected_date_utc,
|
||||
|
||||
c.id_contact,
|
||||
c.account_number,
|
||||
c.id_deal,
|
||||
c.contact_name,
|
||||
c.is_customer,
|
||||
c.is_supplier,
|
||||
c.tax_number,
|
||||
c.contact_first_name,
|
||||
c.contact_last_name,
|
||||
c.phones,
|
||||
c.website,
|
||||
c.balances,
|
||||
c.discount,
|
||||
c.addresses,
|
||||
c.attachments,
|
||||
c.email_addresses,
|
||||
c.payment_terms,
|
||||
c.batch_payments,
|
||||
c.branding_theme,
|
||||
c.contact_groups,
|
||||
c.contact_number,
|
||||
c.contact_status,
|
||||
c.skyper_user_name,
|
||||
c.contact_persons,
|
||||
c.xero_network_key,
|
||||
c.default_currency_iso_4217,
|
||||
c.validation_errors,
|
||||
c.bank_account_details,
|
||||
c.has_validation_errors,
|
||||
c.tracking_category_name,
|
||||
c.account_payable_tax_type,
|
||||
c.tracking_category_option,
|
||||
c.sales_default_account_code,
|
||||
c.sales_tracking_categories,
|
||||
c.account_receivable_tax_type,
|
||||
c.purchases_default_account_code,
|
||||
c.purchases_tracking_categories
|
||||
|
||||
from xero__invoice_line_items li
|
||||
left join xero__invoices i on li.id_invoice = i.id_invoice
|
||||
left join xero__contacts c on i.id_contact = c.id_contact
|
||||
22
models/reporting/xero/xero__invoice_line_items.sql
Normal file
22
models/reporting/xero/xero__invoice_line_items.sql
Normal file
|
|
@ -0,0 +1,22 @@
|
|||
with
|
||||
int_xero__invoice_line_items as (
|
||||
select * from {{ ref("int_xero__invoice_line_items") }}
|
||||
)
|
||||
|
||||
select
|
||||
id_invoice as id_invoice,
|
||||
id_line_item as id_line_item,
|
||||
id_item as id_item,
|
||||
item_code as item_code,
|
||||
quantity as quantity,
|
||||
unit_amount as unit_amount,
|
||||
line_amount_local_curr as line_amount_local_curr,
|
||||
line_amount_in_gbp as line_amount_in_gbp,
|
||||
line_amount_wo_taxes_local_curr,
|
||||
line_amount_wo_taxes_in_gbp,
|
||||
tax_amount_local_curr as tax_amount_local_curr,
|
||||
tax_amount_in_gbp as tax_amount_in_gbp,
|
||||
tax_type as tax_type,
|
||||
invoice_currency_iso_4217 as invoice_currency_iso_4217,
|
||||
line_description as line_description
|
||||
from int_xero__invoice_line_items li
|
||||
39
models/reporting/xero/xero__invoices.sql
Normal file
39
models/reporting/xero/xero__invoices.sql
Normal file
|
|
@ -0,0 +1,39 @@
|
|||
with int_xero__invoices as (select * from {{ ref("int_xero__invoices") }})
|
||||
|
||||
select
|
||||
id_invoice as id_invoice,
|
||||
id_contact as id_contact,
|
||||
reference as reference,
|
||||
invoice_number as invoice_number,
|
||||
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,
|
||||
invoice_type as invoice_type,
|
||||
invoice_currency_iso_4217 as invoice_currency_iso_4217,
|
||||
exchange_rate_to_gbp as exchange_rate_to_gbp,
|
||||
total_amount_local_curr as total_amount_local_curr,
|
||||
total_amount_in_gbp as total_amount_in_gbp,
|
||||
total_amount_wo_tax_local_curr as total_amount_wo_tax_local_curr,
|
||||
total_amount_wo_tax_in_gbp as total_amount_wo_tax_in_gbp,
|
||||
total_tax_local_curr as total_tax_local_curr,
|
||||
total_tax_in_gbp as total_tax_in_gbp,
|
||||
total_due_local_curr as total_due_local_curr,
|
||||
total_due_in_gbp as total_due_in_gbp,
|
||||
total_paid_local_curr as total_paid_local_curr,
|
||||
total_paid_in_gbp as total_paid_in_gbp,
|
||||
invoice_status as invoice_status,
|
||||
has_errors as has_errors,
|
||||
is_discounted as is_discounted,
|
||||
date_string as date_string,
|
||||
due_date_string as due_date_string,
|
||||
has_been_sent_to_contact as has_been_sent_to_contact,
|
||||
total_discount as total_discount,
|
||||
total_credited_local_curr as total_credited_local_curr,
|
||||
has_attachments as has_attachments,
|
||||
updated_at_utc as updated_at_utc,
|
||||
updated_date_utc as updated_date_utc,
|
||||
line_amount_tax_inclusiveness as line_amount_tax_inclusiveness,
|
||||
payment_planned_date_utc as payment_planned_date_utc,
|
||||
payment_expected_date_utc as payment_expected_date_utc,
|
||||
dwh_extracted_at_utc as dwh_extracted_at_utc
|
||||
from int_xero__invoices
|
||||
|
|
@ -313,7 +313,7 @@ models:
|
|||
|
||||
- name: has_attachments
|
||||
data_type: boolean
|
||||
description: Flag indicating if the invoice has an attahcment.
|
||||
description: Flag indicating if the invoice has an attachment.
|
||||
|
||||
- name: updated_at_utc
|
||||
data_type: timestamp with time zone
|
||||
|
|
|
|||
|
|
@ -17,7 +17,7 @@ with
|
|||
{{ adapter.quote("AmountDue") }} as total_due_local_curr,
|
||||
{{ adapter.quote("AmountPaid") }} as total_paid_local_curr,
|
||||
{{ adapter.quote("Status") }} as invoice_status,
|
||||
{{ adapter.quote("Contact") }} as contact,
|
||||
{{ adapter.quote("Contact") }} as full_contact_details,
|
||||
{{ adapter.quote("Payments") }} as payments,
|
||||
{{ adapter.quote("HasErrors") }} as has_errors,
|
||||
{{ adapter.quote("LineItems") }} as line_items,
|
||||
|
|
|
|||
Loading…
Add table
Add a link
Reference in a new issue