Merged PR 4444: Exposes ytd_mtd_aggregated_main_metrics_overview
# Description Exposes ytd_mtd_aggregated_main_metrics_overview in reporting. I changed a bit the logic for exclusion, I believe this is a bit more clear than how it's currently done for the mtd/monthly 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: #27609
This commit is contained in:
parent
7260368bad
commit
78ae3e0119
2 changed files with 196 additions and 0 deletions
|
|
@ -1917,3 +1917,145 @@ models:
|
|||
- name: is_deal_in_xero
|
||||
data_type: boolean
|
||||
description: "Flag to indicate if the deal is in Xero."
|
||||
|
||||
- name: ytd_mtd_aggregated_main_metrics_overview
|
||||
description: |
|
||||
This model provides a high-level overview of the main metrics for the month-to-date
|
||||
and financial year-to-date periods. Data is aggregated at metric level, and provides
|
||||
evolutions current month MTD vs. previous month EOM, current month MTD vs. previous
|
||||
year MTD and current YTD vs. previous YTD.
|
||||
|
||||
data_tests:
|
||||
- dbt_utils.unique_combination_of_columns:
|
||||
combination_of_columns:
|
||||
- date
|
||||
- dimension
|
||||
- dimension_value
|
||||
- metric_name
|
||||
- dbt_utils.unique_combination_of_columns:
|
||||
combination_of_columns:
|
||||
- date
|
||||
- dimension
|
||||
- dimension_value
|
||||
- id_metric
|
||||
|
||||
columns:
|
||||
- name: date
|
||||
data_type: date
|
||||
description: The date for the month-to-date and year-to-date metrics.
|
||||
data_tests:
|
||||
- not_null
|
||||
|
||||
- name: dimension
|
||||
data_type: string
|
||||
description: The dimension or granularity of the metrics.
|
||||
data_tests:
|
||||
- accepted_values:
|
||||
values:
|
||||
- global
|
||||
|
||||
- name: dimension_value
|
||||
data_type: string
|
||||
description: The value or segment available for the selected dimension.
|
||||
data_tests:
|
||||
- not_null
|
||||
|
||||
- name: calendar_year
|
||||
data_type: integer
|
||||
description: The calendar year associated with the data.
|
||||
data_tests:
|
||||
- not_null
|
||||
|
||||
- name: financial_year
|
||||
data_type: integer
|
||||
description: The financial year associated with the data.
|
||||
data_tests:
|
||||
- not_null
|
||||
|
||||
- name: previous_year_date
|
||||
data_type: date
|
||||
description: |
|
||||
The equivalent date in the previous year. It can be null if the
|
||||
metric is not available in the previous year
|
||||
|
||||
- name: id_metric
|
||||
data_type: integer
|
||||
description: |
|
||||
Unique ID for this metric. It is preferable to use this ID when
|
||||
building a report to ensure changes in the metric name do not
|
||||
affect the report.
|
||||
data_tests:
|
||||
- not_null
|
||||
|
||||
- name: metric_name
|
||||
data_type: string
|
||||
description: |
|
||||
Name of the metric. It is preferable to use the ID of the metric
|
||||
when building a report to ensure changes in the metric name do not
|
||||
affect the report.
|
||||
data_tests:
|
||||
- not_null
|
||||
|
||||
- name: is_latest_date
|
||||
data_type: integer
|
||||
description: |
|
||||
Flag to indicate if it's the latest consolidated information for this metric.
|
||||
Keep in mind that this can be different depending on the metric, as the invoicing
|
||||
cycle limits the availability of the latest data for some metrics.
|
||||
data_tests:
|
||||
- not_null
|
||||
|
||||
- name: current_month_mtd
|
||||
data_type: numeric
|
||||
description: |
|
||||
Value of the metric for the current month MTD.
|
||||
|
||||
- name: previous_month_eom
|
||||
data_type: numeric
|
||||
description: |
|
||||
Value of the metric for the previous month EOM.
|
||||
|
||||
- name: previous_year_mtd
|
||||
data_type: numeric
|
||||
description: |
|
||||
Value of the metric for the previous year MTD.
|
||||
|
||||
- name: current_year_ytd
|
||||
data_type: numeric
|
||||
description: |
|
||||
Value of the metric for the current year YTD.
|
||||
|
||||
- name: previous_year_ytd
|
||||
data_type: numeric
|
||||
description: |
|
||||
Value of the metric for the previous year YTD.
|
||||
|
||||
- name: diff_current_month_mtd_vs_previous_month_eom
|
||||
data_type: numeric
|
||||
description: |
|
||||
Difference between the current month MTD and the previous month EOM.
|
||||
|
||||
- name: diff_current_month_mtd_vs_previous_year_mtd
|
||||
data_type: numeric
|
||||
description: |
|
||||
Difference between the current month MTD and the previous year MTD.
|
||||
|
||||
- name: diff_current_ytd_vs_previous_ytd
|
||||
data_type: numeric
|
||||
description: |
|
||||
Difference between the current year YTD and the previous year YTD.
|
||||
|
||||
- name: rel_diff_current_month_mtd_vs_previous_month_eom
|
||||
data_type: numeric
|
||||
description: |
|
||||
Relative difference between the current month MTD and the previous month EOM.
|
||||
|
||||
- name: rel_diff_current_month_mtd_vs_previous_year_mtd
|
||||
data_type: numeric
|
||||
description: |
|
||||
Relative difference between the current month MTD and the previous year MTD.
|
||||
|
||||
- name: rel_diff_current_ytd_vs_previous_ytd
|
||||
data_type: numeric
|
||||
description: |
|
||||
Relative difference between the current year YTD and the previous year YTD.
|
||||
|
|
|
|||
|
|
@ -0,0 +1,54 @@
|
|||
with
|
||||
int_ytd_mtd_aggregated_main_metrics_overview as (
|
||||
select * from {{ ref("int_ytd_mtd_aggregated_main_metrics_overview") }}
|
||||
),
|
||||
latest_dates as (
|
||||
select dimension, id_metric, max(date) as latest_available_date
|
||||
from int_ytd_mtd_aggregated_main_metrics_overview
|
||||
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.
|
||||
requires_invoicing_data = true
|
||||
and {{ is_date_before_20th_of_previous_month("date") }}
|
||||
)
|
||||
-- Keep all history for the rest of metrics
|
||||
or requires_invoicing_data = false
|
||||
)
|
||||
-- To do: handle exclusion for Churn/MRR metrics once these are created
|
||||
group by dimension, id_metric
|
||||
)
|
||||
select
|
||||
m.calendar_year as calendar_year,
|
||||
m.financial_year as financial_year,
|
||||
m.date as date,
|
||||
case when m.date = ld.latest_available_date then 1 else 0 end as is_latest_date,
|
||||
m.previous_year_date as previous_year_date,
|
||||
m.dimension as dimension,
|
||||
m.dimension_value as dimension_value,
|
||||
m.id_metric as id_metric,
|
||||
m.metric_name as metric_name,
|
||||
m.current_month_mtd as current_month_mtd,
|
||||
m.previous_month_eom as previous_month_eom,
|
||||
m.previous_year_mtd as previous_year_mtd,
|
||||
m.current_year_ytd as current_year_ytd,
|
||||
m.previous_year_ytd as previous_year_ytd,
|
||||
m.diff_current_month_mtd_vs_previous_month_eom
|
||||
as diff_current_month_mtd_vs_previous_month_eom,
|
||||
m.diff_current_month_mtd_vs_previous_year_mtd
|
||||
as diff_current_month_mtd_vs_previous_year_mtd,
|
||||
m.diff_current_ytd_vs_previous_ytd as diff_current_ytd_vs_previous_ytd,
|
||||
m.rel_diff_current_month_mtd_vs_previous_month_eom
|
||||
as rel_diff_current_month_mtd_vs_previous_month_eom,
|
||||
m.rel_diff_current_month_mtd_vs_previous_year_mtd
|
||||
as rel_diff_current_month_mtd_vs_previous_year_mtd,
|
||||
m.rel_diff_current_ytd_vs_previous_ytd as rel_diff_current_ytd_vs_previous_ytd
|
||||
from int_ytd_mtd_aggregated_main_metrics_overview m
|
||||
inner join
|
||||
latest_dates ld
|
||||
on m.dimension = ld.dimension
|
||||
and m.id_metric = ld.id_metric
|
||||
and m.date <= ld.latest_available_date
|
||||
Loading…
Add table
Add a link
Reference in a new issue