Merged PR 4228: First version of sales - monthly trends
# Description New model that aggregates in a monthly basis the information from Xero sales. The aggregation is done by several categories, most of them to be included as filters in PBI. Metrics represent the amount without taxes in: 1) the current month, 2) the previous month, 3) twelve months ago, 4) current year YTD (fiscal year) and 5) previous year YTD (fiscal year). It also propagates the model to reporting # 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. - [ ] I've picked the right materialization for the affected models. **I was hesitating between table or view. Table should speed up tests, but I intend to create a reporting table with a similar structure so probably a bit of waste of space. Anyway, not a big deal now** # Other - [ ] Check if a full-refresh is required after this PR is merged. Related work items: #26618
This commit is contained in:
parent
d793f610c9
commit
68952223ca
4 changed files with 364 additions and 0 deletions
164
models/intermediate/xero/int_xero__sales_monthly_trends.sql
Normal file
164
models/intermediate/xero/int_xero__sales_monthly_trends.sql
Normal file
|
|
@ -0,0 +1,164 @@
|
|||
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_issued_date_utc)::date
|
||||
) as first_invoiced_month_utc
|
||||
from int_xero__sales_denom_mart
|
||||
where document_issued_date_utc is not null
|
||||
group by 1, 2, 3, 4, 5, 6
|
||||
),
|
||||
unique_months as (
|
||||
select distinct
|
||||
date_trunc('month', document_issued_date_utc)::date
|
||||
as document_issued_month_utc
|
||||
from int_xero__sales_denom_mart
|
||||
where document_issued_date_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_issued_date_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_issued_date_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
|
||||
|
|
@ -285,3 +285,88 @@ models:
|
|||
data_type: character varying
|
||||
description: |
|
||||
The Level 3 aggregation for Financial reporting.
|
||||
|
||||
- name: int_xero__sales_monthly_trends
|
||||
description: |
|
||||
This model provides monthly aggregated sales and credit note data with
|
||||
fiscal year alignment and period-over-period comparisons.
|
||||
|
||||
The model is built by aggregating the `int_xero__sales_denom_mart` model
|
||||
at the monthly level, computing sales amounts without taxes in GBP, and
|
||||
incorporating key financial aggregations.
|
||||
|
||||
Additionally, it calculates prior period trends:
|
||||
- Previous month sales
|
||||
- Previous year (same month) sales
|
||||
- Year-to-date (YTD) sales for the current fiscal year
|
||||
- YTD sales for the previous fiscal year
|
||||
|
||||
The fiscal year is determined based on an April-March cycle, where a
|
||||
fiscal year is labeled by the year in which it ends (e.g., FY 2025
|
||||
represents April 2024 – March 2025).
|
||||
|
||||
columns:
|
||||
- name: document_issued_month_utc
|
||||
data_type: date
|
||||
description: "The first day of the month when the document was issued, truncated to the month level."
|
||||
data_tests:
|
||||
- not_null
|
||||
|
||||
- name: fiscal_year
|
||||
data_type: integer
|
||||
description: |
|
||||
"The fiscal year in which the document's issued month falls.
|
||||
The fiscal year runs from April to March and is labeled by the year in which it ends
|
||||
(e.g., FY 2025 represents April 2024 – March 2025)."
|
||||
|
||||
- name: previous_fiscal_year
|
||||
data_type: integer
|
||||
description: "The fiscal year prior to the current one, based on the April-March cycle."
|
||||
|
||||
- name: document_status
|
||||
data_type: text
|
||||
description: "The status of the document (e.g., PAID, VOIDED, AUTHORISED, etc.)."
|
||||
|
||||
- name: document_type
|
||||
data_type: text
|
||||
description: "The type of document, indicating whether it is an invoice or credit note."
|
||||
|
||||
- name: id_deal
|
||||
data_type: text
|
||||
description: "The deal associated with the transaction, if applicable. Defaults to 'UNSET' if not provided."
|
||||
|
||||
- name: accounting_financial_l1_aggregation
|
||||
data_type: text
|
||||
description: "The Level 1 aggregation for Financial reporting."
|
||||
|
||||
- name: accounting_financial_l2_aggregation
|
||||
data_type: text
|
||||
description: "The Level 2 aggregation for Financial reporting."
|
||||
|
||||
- name: accounting_financial_l3_aggregation
|
||||
data_type: text
|
||||
description: "The Level 3 aggregation for Financial reporting."
|
||||
|
||||
- name: amount_wo_taxes_in_gbp
|
||||
data_type: numeric
|
||||
description: "Total sales amount without taxes, converted to GBP, aggregated at the monthly level."
|
||||
|
||||
- name: previous_month_amount_wo_taxes_in_gbp
|
||||
data_type: numeric
|
||||
description: "The sales amount without taxes (GBP) for the previous month within the same category."
|
||||
|
||||
- name: previous_year_amount_wo_taxes_in_gbp
|
||||
data_type: numeric
|
||||
description: "The sales amount without taxes (GBP) for the same month in the previous year within the same category."
|
||||
|
||||
- name: ytd_amount_wo_taxes_in_gbp
|
||||
data_type: numeric
|
||||
description: |
|
||||
"Year-to-date (YTD) total of sales amount without taxes (GBP) from the start of the current fiscal
|
||||
year up to the current month."
|
||||
|
||||
- name: previous_year_ytd_amount_wo_taxes_in_gbp
|
||||
data_type: numeric
|
||||
description: |
|
||||
"Year-to-date (YTD) total of sales amount without taxes (GBP) from the start of the previous fiscal
|
||||
year up to the same month."
|
||||
|
|
|
|||
|
|
@ -1395,3 +1395,98 @@ models:
|
|||
data_type: character varying
|
||||
description: |
|
||||
The code and name of the account separated by a "-".
|
||||
|
||||
- name: xero__sales_monthly_trends
|
||||
description: |
|
||||
This model provides monthly aggregated sales and credit note data with
|
||||
fiscal year alignment and period-over-period comparisons.
|
||||
|
||||
The model is built by aggregating the `int_xero__sales_denom_mart` model
|
||||
at the monthly level, computing sales amounts without taxes in GBP, and
|
||||
incorporating key financial aggregations.
|
||||
|
||||
Additionally, it calculates prior period trends:
|
||||
- Previous month sales
|
||||
- Previous year (same month) sales
|
||||
- Year-to-date (YTD) sales for the current fiscal year
|
||||
- YTD sales for the previous fiscal year
|
||||
|
||||
The fiscal year is determined based on an April-March cycle, where a
|
||||
fiscal year is labeled by the year in which it ends (e.g., FY 2025
|
||||
represents April 2024 – March 2025).
|
||||
|
||||
columns:
|
||||
- name: document_issued_month_utc
|
||||
data_type: date
|
||||
description: "The first day of the month when the document was issued, truncated to the month level."
|
||||
data_tests:
|
||||
- not_null
|
||||
|
||||
- name: fiscal_year
|
||||
data_type: integer
|
||||
description: |
|
||||
"The fiscal year in which the document's issued month falls.
|
||||
The fiscal year runs from April to March and is labeled by the year in which it ends
|
||||
(e.g., FY 2025 represents April 2024 – March 2025)."
|
||||
data_tests:
|
||||
- not_null
|
||||
|
||||
- name: previous_fiscal_year
|
||||
data_type: integer
|
||||
description: "The fiscal year prior to the current one, based on the April-March cycle."
|
||||
data_tests:
|
||||
- not_null
|
||||
|
||||
- name: document_status
|
||||
data_type: text
|
||||
description: "The status of the document (e.g., PAID, VOIDED, AUTHORISED, etc.)."
|
||||
data_tests:
|
||||
- not_null
|
||||
|
||||
- name: document_type
|
||||
data_type: text
|
||||
description: "The type of document, indicating whether it is an invoice or credit note."
|
||||
data_tests:
|
||||
- not_null
|
||||
|
||||
- name: id_deal
|
||||
data_type: text
|
||||
description: "The deal associated with the transaction, if applicable. Defaults to 'UNSET' if not provided."
|
||||
data_tests:
|
||||
- not_null
|
||||
|
||||
- name: accounting_financial_l1_aggregation
|
||||
data_type: text
|
||||
description: "The Level 1 aggregation for Financial reporting."
|
||||
|
||||
- name: accounting_financial_l2_aggregation
|
||||
data_type: text
|
||||
description: "The Level 2 aggregation for Financial reporting."
|
||||
|
||||
- name: accounting_financial_l3_aggregation
|
||||
data_type: text
|
||||
description: "The Level 3 aggregation for Financial reporting."
|
||||
|
||||
- name: amount_wo_taxes_in_gbp
|
||||
data_type: numeric
|
||||
description: "Total sales amount without taxes, converted to GBP, aggregated at the monthly level."
|
||||
|
||||
- name: previous_month_amount_wo_taxes_in_gbp
|
||||
data_type: numeric
|
||||
description: "The sales amount without taxes (GBP) for the previous month within the same category."
|
||||
|
||||
- name: previous_year_amount_wo_taxes_in_gbp
|
||||
data_type: numeric
|
||||
description: "The sales amount without taxes (GBP) for the same month in the previous year within the same category."
|
||||
|
||||
- name: ytd_amount_wo_taxes_in_gbp
|
||||
data_type: numeric
|
||||
description: |
|
||||
"Year-to-date (YTD) total of sales amount without taxes (GBP) from the start of the current fiscal
|
||||
year up to the current month."
|
||||
|
||||
- name: previous_year_ytd_amount_wo_taxes_in_gbp
|
||||
data_type: numeric
|
||||
description: |
|
||||
"Year-to-date (YTD) total of sales amount without taxes (GBP) from the start of the previous fiscal
|
||||
year up to the same month."
|
||||
|
|
|
|||
20
models/reporting/xero/xero__sales_monthly_trends.sql
Normal file
20
models/reporting/xero/xero__sales_monthly_trends.sql
Normal file
|
|
@ -0,0 +1,20 @@
|
|||
with
|
||||
int_xero__sales_monthly_trends as (
|
||||
select * from {{ ref("int_xero__sales_monthly_trends") }}
|
||||
)
|
||||
select
|
||||
document_issued_month_utc as document_issued_month_utc,
|
||||
fiscal_year as fiscal_year,
|
||||
previous_fiscal_year as previous_fiscal_year,
|
||||
document_status as document_status,
|
||||
document_type as document_type,
|
||||
id_deal as id_deal,
|
||||
accounting_financial_l1_aggregation as accounting_financial_l1_aggregation,
|
||||
accounting_financial_l2_aggregation as accounting_financial_l2_aggregation,
|
||||
accounting_financial_l3_aggregation as accounting_financial_l3_aggregation,
|
||||
amount_wo_taxes_in_gbp as amount_wo_taxes_in_gbp,
|
||||
previous_month_amount_wo_taxes_in_gbp as previous_month_amount_wo_taxes_in_gbp,
|
||||
previous_year_amount_wo_taxes_in_gbp as previous_year_amount_wo_taxes_in_gbp,
|
||||
ytd_amount_wo_taxes_in_gbp as ytd_amount_wo_taxes_in_gbp,
|
||||
previous_year_ytd_amount_wo_taxes_in_gbp as previous_year_ytd_amount_wo_taxes_in_gbp
|
||||
from int_xero__sales_monthly_trends
|
||||
Loading…
Add table
Add a link
Reference in a new issue