data-dwh-dbt-project/models/intermediate/xero/int_xero__sales_monthly_trends.sql
Oriol Roqué Paniagua 1a4a9fac37 Merged PR 4578: Propagates the month attribution from invoicing data
# Description

Following the changes of the month attribution on invoicing data depending if the document is posted on Xero or in Hyperline, this PR ensures that the 2 affected areas capture this change.

This means:
* Xero - Sales Monthly Trends
* KPIs - Invoiced Revenue

# Checklist

- [X] The edited models and dependants run properly with production data.
- [X] The edited models are sufficiently documented.
- [X] The edited models contain PK tests, and I've ran and passed them.
- [X] I have checked for DRY opportunities with other models and docs.
- [X] I've picked the right materialization for the affected models.

# Other

- [ ] Check if a full-refresh is required after this PR is merged.

Related work items: #28158
2025-03-04 14:13:53 +00:00

164 lines
7.1 KiB
SQL

with
int_xero__sales_denom_mart as (
select * from {{ ref("int_xero__sales_denom_mart") }}
),
-- This ensures that we will have future records for comparison over time,
-- even if a deal or another category stops being invoiced
first_invoiced_month_per_category as (
select
coalesce(document_status, 'UNSET') as document_status,
coalesce(document_type, 'UNSET') as document_type,
coalesce(id_deal, 'UNSET') as id_deal,
coalesce(
accounting_financial_l1_aggregation, 'UNSET'
) as accounting_financial_l1_aggregation,
coalesce(
accounting_financial_l2_aggregation, 'UNSET'
) as accounting_financial_l2_aggregation,
coalesce(
accounting_financial_l3_aggregation, 'UNSET'
) as accounting_financial_l3_aggregation,
min(
date_trunc('month', document_is_effective_at_end_of_month_utc)::date
) as first_invoiced_month_utc
from int_xero__sales_denom_mart
where document_is_effective_at_end_of_month_utc is not null
group by 1, 2, 3, 4, 5, 6
),
unique_months as (
select distinct
date_trunc('month', document_is_effective_at_end_of_month_utc)::date
as document_issued_month_utc
from int_xero__sales_denom_mart
where document_is_effective_at_end_of_month_utc is not null
),
category_skeleton as (
select distinct
fimpc.document_status,
fimpc.document_type,
fimpc.id_deal,
fimpc.accounting_financial_l1_aggregation,
fimpc.accounting_financial_l2_aggregation,
fimpc.accounting_financial_l3_aggregation,
um.document_issued_month_utc,
case
when extract(month from um.document_issued_month_utc) >= 4
then extract(year from um.document_issued_month_utc) + 1 -- Fiscal Year labeled by the next year
else extract(year from um.document_issued_month_utc) -- Fiscal Year labeled by the current year
end as fiscal_year,
-- Previous Fiscal Year (for YTD comparison)
case
when extract(month from um.document_issued_month_utc) >= 4
then extract(year from um.document_issued_month_utc) -- Previous Fiscal Year labeled by the current year
else extract(year from um.document_issued_month_utc) - 1 -- Previous Fiscal Year labeled by last year
end as previous_fiscal_year
from unique_months um
left join
first_invoiced_month_per_category fimpc
on fimpc.first_invoiced_month_utc <= um.document_issued_month_utc
),
aggregated_amount_wo_taxes_in_gbp as (
select
date_trunc('month', document_is_effective_at_end_of_month_utc)::date
as document_issued_month_utc,
coalesce(document_status, 'UNSET') as document_status,
coalesce(document_type, 'UNSET') as document_type,
coalesce(id_deal, 'UNSET') as id_deal,
coalesce(
accounting_financial_l1_aggregation, 'UNSET'
) as accounting_financial_l1_aggregation,
coalesce(
accounting_financial_l2_aggregation, 'UNSET'
) as accounting_financial_l2_aggregation,
coalesce(
accounting_financial_l3_aggregation, 'UNSET'
) as accounting_financial_l3_aggregation,
sum(line_amount_wo_taxes_in_gbp) as amount_wo_taxes_in_gbp
from int_xero__sales_denom_mart
where document_is_effective_at_end_of_month_utc is not null
group by 1, 2, 3, 4, 5, 6, 7
),
monthly_data_with_lag as (
select
-- Time-based dimensions --
cs.document_issued_month_utc,
cs.fiscal_year,
cs.previous_fiscal_year,
-- Document-based dimensions --
cs.document_status,
cs.document_type,
-- Deal-based dimensions --
cs.id_deal,
-- Accounting-based dimensions --
cs.accounting_financial_l1_aggregation,
cs.accounting_financial_l2_aggregation,
cs.accounting_financial_l3_aggregation,
-- Metrics --
aawtig.amount_wo_taxes_in_gbp,
-- Previous month amount
lag(aawtig.amount_wo_taxes_in_gbp) over (
partition by
cs.document_status,
cs.document_type,
cs.id_deal,
cs.accounting_financial_l1_aggregation,
cs.accounting_financial_l2_aggregation,
cs.accounting_financial_l3_aggregation
order by cs.document_issued_month_utc
) as previous_month_amount_wo_taxes_in_gbp,
-- Previous year amount (same month last year)
lag(aawtig.amount_wo_taxes_in_gbp, 12) over (
partition by
cs.document_status,
cs.document_type,
cs.id_deal,
cs.accounting_financial_l1_aggregation,
cs.accounting_financial_l2_aggregation,
cs.accounting_financial_l3_aggregation
order by cs.document_issued_month_utc
) as previous_year_amount_wo_taxes_in_gbp
from category_skeleton cs
left join
aggregated_amount_wo_taxes_in_gbp aawtig
on cs.document_issued_month_utc = aawtig.document_issued_month_utc
and cs.document_status = aawtig.document_status
and cs.document_type = aawtig.document_type
and cs.id_deal = aawtig.id_deal
and cs.accounting_financial_l1_aggregation
= aawtig.accounting_financial_l1_aggregation
and cs.accounting_financial_l2_aggregation
= aawtig.accounting_financial_l2_aggregation
and cs.accounting_financial_l3_aggregation
= aawtig.accounting_financial_l3_aggregation
)
select
*,
-- Year-to-Date (YTD) within the current fiscal year
sum(amount_wo_taxes_in_gbp) over (
partition by
document_status,
document_type,
id_deal,
accounting_financial_l1_aggregation,
accounting_financial_l2_aggregation,
accounting_financial_l3_aggregation,
fiscal_year
order by document_issued_month_utc
rows between unbounded preceding and current row
) as ytd_amount_wo_taxes_in_gbp,
-- Previous Year YTD (Same running total but for the previous fiscal year)
sum(previous_year_amount_wo_taxes_in_gbp) over (
partition by
document_status,
document_type,
id_deal,
accounting_financial_l1_aggregation,
accounting_financial_l2_aggregation,
accounting_financial_l3_aggregation,
fiscal_year
order by document_issued_month_utc
rows between unbounded preceding and current row
) as previous_year_ytd_amount_wo_taxes_in_gbp
from monthly_data_with_lag