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
This commit is contained in:
Oriol Roqué Paniagua 2025-03-04 14:13:53 +00:00
parent 3f1e2ea1d9
commit 1a4a9fac37
2 changed files with 16 additions and 12 deletions

View file

@ -4,7 +4,7 @@
{{ config(materialized="table", unique_key=["date", "id_deal", "business_scope"]) }} {{ config(materialized="table", unique_key=["date", "id_deal", "business_scope"]) }}
select select
-- Unique Key -- -- Unique Key --
ixsdm.document_issued_date_utc as date, ixsdm.document_is_effective_at_end_of_month_utc as date,
coalesce(ixsdm.id_deal, 'UNSET') as id_deal, coalesce(ixsdm.id_deal, 'UNSET') as id_deal,
case case
when ikdd.client_type = 'API' when ikdd.client_type = 'API'
@ -17,11 +17,13 @@ select
case case
when when
icnddsd.id_deal is not null icnddsd.id_deal is not null
and date_trunc('month', ixsdm.document_issued_date_utc)::date and date_trunc(
>= date_trunc( 'month',
ixsdm.document_is_effective_at_end_of_month_utc
)::date >= date_trunc(
'month', icnddsd.min_user_in_new_dash_since_date_utc 'month', icnddsd.min_user_in_new_dash_since_date_utc
)::date )::date
and ixsdm.document_issued_date_utc and ixsdm.document_is_effective_at_end_of_month_utc
>= date({{ var("new_dash_first_invoicing_date") }}) >= date({{ var("new_dash_first_invoicing_date") }})
then 'New Dash' then 'New Dash'
else 'Old Dash' else 'Old Dash'
@ -123,7 +125,9 @@ select
-- considered as Other Invoiced Revenue. -- considered as Other Invoiced Revenue.
or ( or (
ixsdm.accounting_root_aggregation = 'Other Invoiced Revenue' ixsdm.accounting_root_aggregation = 'Other Invoiced Revenue'
and date_trunc('year', ixsdm.document_issued_date_utc)::date and date_trunc(
'year', ixsdm.document_is_effective_at_end_of_month_utc
)::date
= '2022-01-01'::date = '2022-01-01'::date
) )
then ixsdm.line_amount_wo_taxes_in_gbp then ixsdm.line_amount_wo_taxes_in_gbp
@ -179,7 +183,7 @@ left join {{ ref("int_kpis__dimension_deals") }} as ikdd on ixsdm.id_deal = ikdd
left join left join
{{ ref("int_kpis__dimension_daily_accommodation") }} as icmas {{ ref("int_kpis__dimension_daily_accommodation") }} as icmas
on ixsdm.id_deal = icmas.id_deal on ixsdm.id_deal = icmas.id_deal
and ixsdm.document_issued_date_utc = icmas.date and ixsdm.document_is_effective_at_end_of_month_utc = icmas.date
left join left join
{{ ref("int_core__new_dash_deal_since_date") }} as icnddsd {{ ref("int_core__new_dash_deal_since_date") }} as icnddsd
on ixsdm.id_deal = icnddsd.id_deal on ixsdm.id_deal = icnddsd.id_deal

View file

@ -19,18 +19,18 @@ with
accounting_financial_l3_aggregation, 'UNSET' accounting_financial_l3_aggregation, 'UNSET'
) as accounting_financial_l3_aggregation, ) as accounting_financial_l3_aggregation,
min( min(
date_trunc('month', document_issued_date_utc)::date date_trunc('month', document_is_effective_at_end_of_month_utc)::date
) as first_invoiced_month_utc ) as first_invoiced_month_utc
from int_xero__sales_denom_mart from int_xero__sales_denom_mart
where document_issued_date_utc is not null where document_is_effective_at_end_of_month_utc is not null
group by 1, 2, 3, 4, 5, 6 group by 1, 2, 3, 4, 5, 6
), ),
unique_months as ( unique_months as (
select distinct select distinct
date_trunc('month', document_issued_date_utc)::date date_trunc('month', document_is_effective_at_end_of_month_utc)::date
as document_issued_month_utc as document_issued_month_utc
from int_xero__sales_denom_mart from int_xero__sales_denom_mart
where document_issued_date_utc is not null where document_is_effective_at_end_of_month_utc is not null
), ),
category_skeleton as ( category_skeleton as (
select distinct select distinct
@ -59,7 +59,7 @@ with
), ),
aggregated_amount_wo_taxes_in_gbp as ( aggregated_amount_wo_taxes_in_gbp as (
select select
date_trunc('month', document_issued_date_utc)::date date_trunc('month', document_is_effective_at_end_of_month_utc)::date
as document_issued_month_utc, as document_issued_month_utc,
coalesce(document_status, 'UNSET') as document_status, coalesce(document_status, 'UNSET') as document_status,
coalesce(document_type, 'UNSET') as document_type, coalesce(document_type, 'UNSET') as document_type,
@ -75,7 +75,7 @@ with
) as accounting_financial_l3_aggregation, ) as accounting_financial_l3_aggregation,
sum(line_amount_wo_taxes_in_gbp) as amount_wo_taxes_in_gbp sum(line_amount_wo_taxes_in_gbp) as amount_wo_taxes_in_gbp
from int_xero__sales_denom_mart from int_xero__sales_denom_mart
where document_issued_date_utc is not null where document_is_effective_at_end_of_month_utc is not null
group by 1, 2, 3, 4, 5, 6, 7 group by 1, 2, 3, 4, 5, 6, 7
), ),
monthly_data_with_lag as ( monthly_data_with_lag as (