data-dwh-dbt-project/models/reporting/general/mtd_aggregated_metrics.sql
Oriol Roqué Paniagua ca5db795a3 Merged PR 4946: Allows By Deal dimension to be propagated within intermediate
# Description

To be able to compute By Deal KPIs  similarly as we do for Main KPIs we need to propagate the "By Deal" dimension first in intermediate. This does not impact reporting since there's a macro that already cuts the dimensions to be displayed, but I modified the name so it's clearer.

Changes:
* In `int_mtd_vs_previous_year_metrics`, I added a new `dimension_list`. This is applied to all initial CTEs that filter by dimension. Note that I added here the `by_deal` dimension.
* Modified the name of `get_kpi_dimensions_for_production` to `get_main_kpis_dimensions_for_production`. Now it's more explicit that this is the configuration for Main KPIs reporting. This affects both `business_kpis_configuration` and it's usage in `mtd_aggregated_metrics`.
* Modified the tests in `int_mtd_vs_previous_year_metrics` and `int_mtd_aggregated_metrics` to include the new dimension `by_deal`.
* It seems by adding this now autoformatting works again on this model! I'll tag all cases that are just because of autoformatting.

MD5 trick has been applied in `reporting.mtd_aggregated_metrics`.

# 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: #28998
2025-04-08 05:37:53 +00:00

72 lines
2.4 KiB
SQL

{% set production_dimensions = get_main_kpis_dimensions_for_production() %}
{{
config(
materialized="table",
indexes=[
{"columns": ["dimension"]},
{"columns": ["dimension", "date"]},
],
)
}}
with
dimensions as (
{% for dimension in production_dimensions %}
select
{{ dimension.dimension }} as dimension,
{{ dimension.dimension_display }} as dimension_display
{% if not loop.last %}
union all
{% endif %}
{% endfor %}
),
int_mtd_aggregated_metrics as (
select m.*, d.dimension_display
from {{ ref("int_mtd_aggregated_metrics") }} m
-- The following clause limits the display execution
-- to only include those dimensions configured to
-- appear for production purposes
inner join dimensions d on m.dimension = d.dimension
)
select
year as year,
month as month,
day as day,
case when is_end_of_month then 1 else 0 end as is_end_of_month,
case when is_current_month then 1 else 0 end as is_current_month,
case
when is_end_of_month_or_yesterday then 1 else 0
end as is_end_of_month_or_yesterday,
first_day_month as first_day_month,
date as date,
dimension_display as dimension,
dimension_value as dimension_value,
previous_year_date as previous_year_date,
order_by as order_by,
number_format as number_format,
metric as metric,
value as value,
previous_year_value as previous_year_value,
relative_increment as relative_increment,
relative_increment_with_sign_format as relative_increment_with_sign_format
from int_mtd_aggregated_metrics m
where
(
(
-- Not show current + previous month if the metric depends on
-- invoicing cycle and it is before the 20th of the month, if it
-- is the 20th of the month or after, only exclude the current
-- month.
display_exclusion = 'INVOICING'
and {{ is_date_before_20th_of_previous_month("date") }}
)
or (
-- Handle exclusion for Churn/MRR metrics: do not show them in the
-- current month.
display_exclusion = 'ONGOING_MONTH'
and date_trunc('month', m.date) < date_trunc('month', current_date)
)
-- Keep all history for the rest of metrics
or display_exclusion = 'NONE'
)