data-dwh-dbt-project/models/intermediate/xero/int_xero__sales_denom_mart.sql
2025-06-02 15:58:01 +02:00

187 lines
7 KiB
SQL

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") }}),
stg_seed__accounting_aggregations as (
select * from {{ ref("stg_seed__accounting_aggregations") }}
),
amount_due_deals as (
select c.id_deal, i.total_due_in_gbp
from int_xero__invoices i
left join int_xero__contacts c on c.id_contact = i.id_contact
where i.invoice_status = 'AUTHORISED' and c.id_deal is not null
union all
select c.id_deal, cn.remaining_credit_in_gbp * -1
from int_xero__credit_notes cn
left join int_xero__contacts c on c.id_contact = cn.id_contact
where cn.credit_note_status = 'AUTHORISED' and c.id_deal is not null
),
outstanding_deals as (
select
id_deal,
sum(total_due_in_gbp) as total_outstanding_in_gbp,
case
when sum(total_due_in_gbp) < 0
then 'Outstanding Resolutions'
when sum(total_due_in_gbp) >= 0
then 'Outstanding Invoices'
end as outstanding_type
from amount_due_deals
group by id_deal
)
select
ili.id_line_item as id_line_item,
ili.id_item as id_item,
'invoice' as document_class,
ili.id_account,
ili.account_code,
ili.account_name,
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.is_invoice_posted_in_hyperline as is_document_posted_in_hyperline,
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,
case
when i.is_invoice_posted_in_hyperline = true
-- If the invoice is posted in Hyperline, we want to use the last day of the
-- previous month
then (date_trunc('month', invoice_issued_date_utc) - interval '1 day')::date
-- If the invoice is not posted in Hyperline, we want to use the last day of
-- the current month
else
(
date_trunc('month', invoice_issued_date_utc)
+ interval '1 month'
- interval '1 day'
)::date
end as document_is_effective_at_end_of_month_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,
od.total_outstanding_in_gbp,
od.outstanding_type as outstanding_type,
c.id_contact as id_contact,
c.id_deal as id_deal,
c.contact_name as contact_name,
aa.root_aggregation as accounting_root_aggregation,
aa.kpis_aggregation as accounting_kpis_aggregation,
aa.financial_l1_aggregation as accounting_financial_l1_aggregation,
aa.financial_l2_aggregation as accounting_financial_l2_aggregation,
aa.financial_l3_aggregation as accounting_financial_l3_aggregation
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
left join stg_seed__accounting_aggregations aa on aa.account_code = ili.account_code
left join
outstanding_deals od on od.id_deal = c.id_deal and i.invoice_status = 'AUTHORISED'
union all
select
cnli.id_line_item,
cnli.id_item,
'credit note' as document_class,
cnli.id_account,
cnli.account_code,
cnli.account_name,
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.is_credit_note_posted_in_hyperline as is_document_posted_in_hyperline,
cn.reference,
cn.credit_note_number,
cn.credit_note_issued_at_utc,
cn.credit_note_issued_date_utc,
case
when cn.is_credit_note_posted_in_hyperline = true
-- If the credit note is posted in Hyperline, we want to use the last day of the
-- previous month
then (date_trunc('month', credit_note_issued_date_utc) - interval '1 day')::date
-- If the credit note is not posted in Hyperline, we want to use the last day of
-- the current month
else
(
date_trunc('month', credit_note_issued_date_utc)
+ interval '1 month'
- interval '1 day'
)::date
end,
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,
od.total_outstanding_in_gbp,
od.outstanding_type as outstanding_type,
c.id_contact,
c.id_deal,
c.contact_name,
aa.root_aggregation,
aa.kpis_aggregation,
aa.financial_l1_aggregation,
aa.financial_l2_aggregation,
aa.financial_l3_aggregation
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
left join stg_seed__accounting_aggregations aa on aa.account_code = cnli.account_code
left join
outstanding_deals od
on od.id_deal = c.id_deal
and cn.credit_note_status = 'AUTHORISED'