data-dwh-dbt-project/models/intermediate/xero/int_xero__credit_note_line_items.sql
2025-04-25 11:55:14 +02:00

80 lines
3.2 KiB
SQL

with
int_xero__credit_notes as (select * from {{ ref("int_xero__credit_notes") }}),
stg_xero__accounts as (select * from {{ ref("stg_xero__accounts") }})
select
cn.id_credit_note,
cn.credit_note_issued_at_utc,
cn.credit_note_status,
cn.id_contact,
j.id_line_item,
j.id_item,
j.item_code,
j.id_account,
j.account_code,
a.account_name,
j.quantity::numeric,
j.unit_amount::numeric,
j.line_amount_local_curr::numeric,
(j.line_amount_local_curr::numeric * cn.exchange_rate_to_gbp)::numeric(
18, 4
) as line_amount_in_gbp,
case
when cn.line_amount_tax_inclusiveness = 'Inclusive'
then j.line_amount_local_curr::numeric - j.tax_amount_local_curr::numeric
when cn.line_amount_tax_inclusiveness = 'Exclusive'
then j.line_amount_local_curr::numeric
when cn.line_amount_tax_inclusiveness = 'NoTax'
then j.line_amount_local_curr::numeric
else null
end as line_amount_wo_taxes_local_curr,
case
when cn.line_amount_tax_inclusiveness = 'Inclusive'
then
(j.line_amount_local_curr::numeric * cn.exchange_rate_to_gbp)::numeric(
18,
4
) - (j.tax_amount_local_curr::numeric * cn.exchange_rate_to_gbp)::numeric(
18, 4
)
when cn.line_amount_tax_inclusiveness = 'Exclusive'
then
(j.line_amount_local_curr::numeric * cn.exchange_rate_to_gbp)::numeric(
18, 4
)
when cn.line_amount_tax_inclusiveness = 'NoTax'
then
(j.line_amount_local_curr::numeric * cn.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 * cn.exchange_rate_to_gbp)::numeric(
18, 4
) as tax_amount_in_gbp,
j.tax_type,
cn.credit_note_currency_iso_4217,
j.line_description
from int_xero__credit_notes cn
cross join
lateral(
select
(jsonb_array_elements(cn.line_items) ->> 'LineItemID') as id_line_item,
(jsonb_array_elements(cn.line_items) -> 'Item') ->> 'ItemID' as id_item,
(jsonb_array_elements(cn.line_items) -> 'Item') ->> 'Code' as item_code,
(jsonb_array_elements(cn.line_items) -> 'Item') ->> 'Name' as item_name,
(jsonb_array_elements(cn.line_items) ->> 'Quantity') as quantity,
(jsonb_array_elements(cn.line_items) ->> 'UnitAmount') as unit_amount,
(
jsonb_array_elements(cn.line_items) ->> 'LineAmount'
) as line_amount_local_curr,
(
jsonb_array_elements(cn.line_items) ->> 'TaxAmount'
) as tax_amount_local_curr,
(jsonb_array_elements(cn.line_items) ->> 'TaxType') as tax_type,
(jsonb_array_elements(cn.line_items) ->> 'Description') as line_description,
(jsonb_array_elements(cn.line_items) ->> 'AccountID') as id_account,
(jsonb_array_elements(cn.line_items) ->> 'AccountCode') as account_code
) j
left join stg_xero__accounts a on j.account_code = a.account_code