data-dwh-dbt-project/models/intermediate/xero/int_xero__invoice_line_items.sql
Oriol Roqué Paniagua b16cb172b6 Merged PR 2349: Retrieve account for xero invoices, credit notes and sales denom mart
Discussing with Jamie on how I can retrieve the information from Xero for E-deposit and Guesty, he told me that these go to a dedicated account. Since these are invoiced, they do not go to the bank transactions.
Specifically:
- 220 - E-Deposit Fees
- 219 - Guesty Fees
- 221 - Guesty Administration fee

After debugging the data (and getting confirmation from Jamie that indeed we were having invoices on e-deposit), I see that this info is available in the original json from staging. This PR aims just to retrieve these 3 fields:
- id_account
- account_code
- account_name

This will be used later on to retrieve the rest of API KPIs

Related work items: #18719
2024-07-18 15:47:14 +00:00

71 lines
No EOL
2.9 KiB
SQL

with int_xero__invoices as (select * from {{ ref("int_xero__invoices") }}),
stg_xero__accounts as (select * from {{ ref("stg_xero__accounts") }})
select
i.id_invoice,
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 * 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,
(jsonb_array_elements(i.line_items) ->> 'AccountID') as id_account,
(jsonb_array_elements(i.line_items) ->> 'AccountCode') as account_code
) j
left join stg_xero__accounts a on j.account_code = a.account_code