# Description I noticed this morning that after the name changes some exclusions have been messed up. I think is about time we handle this properly. Following what we did for `ytd_mtd_aggregated_main_metrics_overview`, I apply the same logic: the metric display configuration is handled for each metric in the configuration rather than by some crazy-complex-name-logic. I also took the opportunity to make Host Resolutions timely after a discussion with Chloe yesterday. Finance handles resolutions payments twice a week, and the "delay" in time is mostly coming from Resolutions accepting to pay someone vs. Finance handling the payment. In any case we're talking about a few days maximum difference, which I believe it's 1) process-related freshness, rather than data-related and 2) much better to have visibility in a timely manner rather than waiting for the 20th on next month. # 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. - [ ] I have checked for DRY opportunities with other models and docs. **Logic is common among YTD and MTD models. At some moment this can be improved** - [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: #28560
72 lines
2.4 KiB
SQL
72 lines
2.4 KiB
SQL
{% set production_dimensions = get_kpi_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'
|
|
)
|