lots of currency stuff
This commit is contained in:
parent
908ec75d17
commit
bc4ca1cbc3
5 changed files with 139 additions and 8 deletions
|
|
@ -7,8 +7,38 @@ select
|
||||||
j.item_code,
|
j.item_code,
|
||||||
j.quantity::numeric,
|
j.quantity::numeric,
|
||||||
j.unit_amount::numeric,
|
j.unit_amount::numeric,
|
||||||
j.line_amount::numeric,
|
j.line_amount_local_curr::numeric,
|
||||||
j.tax_amount::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,
|
j.tax_type,
|
||||||
i.invoice_currency_iso_4217,
|
i.invoice_currency_iso_4217,
|
||||||
j.line_description
|
j.line_description
|
||||||
|
|
@ -22,8 +52,12 @@ cross join
|
||||||
(jsonb_array_elements(i.line_items) -> 'Item') ->> 'Name' as item_name,
|
(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) ->> 'Quantity') as quantity,
|
||||||
(jsonb_array_elements(i.line_items) ->> 'UnitAmount') as unit_amount,
|
(jsonb_array_elements(i.line_items) ->> 'UnitAmount') as unit_amount,
|
||||||
(jsonb_array_elements(i.line_items) ->> 'LineAmount') as line_amount,
|
(
|
||||||
(jsonb_array_elements(i.line_items) ->> 'TaxAmount') as tax_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) ->> 'TaxType') as tax_type,
|
||||||
(jsonb_array_elements(i.line_items) ->> 'Description') as line_description
|
(jsonb_array_elements(i.line_items) ->> 'Description') as line_description
|
||||||
) j
|
) j
|
||||||
|
|
|
||||||
|
|
@ -12,10 +12,19 @@ select
|
||||||
invoice_currency_iso_4217,
|
invoice_currency_iso_4217,
|
||||||
exchange_rate_to_gbp,
|
exchange_rate_to_gbp,
|
||||||
total_amount_local_curr,
|
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,
|
||||||
|
(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,
|
||||||
|
(total_tax_local_curr * exchange_rate_to_gbp)::numeric(18, 4) as total_tax_in_gbp,
|
||||||
total_due_local_curr,
|
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,
|
||||||
|
(total_paid_local_curr * exchange_rate_to_gbp)::numeric(18, 4) as total_paid_in_gbp,
|
||||||
invoice_status,
|
invoice_status,
|
||||||
full_contact_details,
|
full_contact_details,
|
||||||
payments,
|
payments,
|
||||||
|
|
|
||||||
|
|
@ -1,10 +1,91 @@
|
||||||
{{ config(materialized="view", unique_key="id_booking") }}
|
|
||||||
with
|
with
|
||||||
xero__invoices as (select * from {{ ref("xero__invoices") }}),
|
xero__invoices as (select * from {{ ref("xero__invoices") }}),
|
||||||
xero__contacts as (select * from {{ ref("xero__contacts") }}),
|
xero__contacts as (select * from {{ ref("xero__contacts") }}),
|
||||||
xero__invoice_line_items as (select * from {{ ref("xero__invoice_line_items") }})
|
xero__invoice_line_items as (select * from {{ ref("xero__invoice_line_items") }})
|
||||||
|
|
||||||
select li.*, i.*, c.*
|
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.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
|
from xero__invoice_line_items li
|
||||||
left join xero__invoices i on li.id_invoice = i.id_invoice
|
left join xero__invoices i on li.id_invoice = i.id_invoice
|
||||||
left join xero__contacts c on i.id_contact = c.id_contact
|
left join xero__contacts c on i.id_contact = c.id_contact
|
||||||
|
|
|
||||||
|
|
@ -10,8 +10,10 @@ select
|
||||||
item_code as item_code,
|
item_code as item_code,
|
||||||
quantity as quantity,
|
quantity as quantity,
|
||||||
unit_amount as unit_amount,
|
unit_amount as unit_amount,
|
||||||
line_amount as line_amount,
|
line_amount_local_curr as line_amount_local_curr,
|
||||||
tax_amount as tax_amount,
|
line_amount_in_gbp as line_amount_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,
|
tax_type as tax_type,
|
||||||
invoice_currency_iso_4217 as invoice_currency_iso_4217,
|
invoice_currency_iso_4217 as invoice_currency_iso_4217,
|
||||||
line_description as line_description
|
line_description as line_description
|
||||||
|
|
|
||||||
|
|
@ -12,10 +12,15 @@ select
|
||||||
invoice_currency_iso_4217 as invoice_currency_iso_4217,
|
invoice_currency_iso_4217 as invoice_currency_iso_4217,
|
||||||
exchange_rate_to_gbp as exchange_rate_to_gbp,
|
exchange_rate_to_gbp as exchange_rate_to_gbp,
|
||||||
total_amount_local_curr as total_amount_local_curr,
|
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_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_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_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_local_curr as total_paid_local_curr,
|
||||||
|
total_paid_in_gbp as total_paid_in_gbp,
|
||||||
invoice_status as invoice_status,
|
invoice_status as invoice_status,
|
||||||
has_errors as has_errors,
|
has_errors as has_errors,
|
||||||
is_discounted as is_discounted,
|
is_discounted as is_discounted,
|
||||||
|
|
|
||||||
Loading…
Add table
Add a link
Reference in a new issue