Merged PR 4948: Reporting model for mtd aggregated metrics by deal
# Description Creates a new model for reporting. It includes any relevant metric at Deal level in a similar format as we do for `mtd_aggregated_metrics`. Additionally, there's few Deal attributes - from Hubspot, segmentations, lifecycles, etc. In order to dynamically choose which metrics are relevant on a Deal level, I modified the configuration in `int_mtd_aggregated_metrics` so the extraction is under control. # 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. **Worth discussing the possibilities to include indexes in the future** # Other - [ ] Check if a full-refresh is required after this PR is merged. Related work items: #28998
This commit is contained in:
parent
ca5db795a3
commit
a67e3f46ba
5 changed files with 558 additions and 1 deletions
64
models/reporting/general/mtd_aggregated_metrics_by_deal.sql
Normal file
64
models/reporting/general/mtd_aggregated_metrics_by_deal.sql
Normal file
|
|
@ -0,0 +1,64 @@
|
|||
with
|
||||
int_mtd_aggregated_metrics_by_deal as (
|
||||
select * from {{ ref("int_mtd_aggregated_metrics_by_deal") }}
|
||||
)
|
||||
|
||||
select
|
||||
-- PRIMARY KEY --
|
||||
m.date as date,
|
||||
m.id_deal as id_deal,
|
||||
m.metric as metric,
|
||||
|
||||
-- TIME ATTRIBUTES --
|
||||
m.year as year,
|
||||
m.month as month,
|
||||
m.day as day,
|
||||
case when m.is_end_of_month then 1 else 0 end as is_end_of_month,
|
||||
case when m.is_current_month then 1 else 0 end as is_current_month,
|
||||
case
|
||||
when m.is_end_of_month_or_yesterday then 1 else 0
|
||||
end as is_end_of_month_or_yesterday,
|
||||
m.first_day_month as first_day_month,
|
||||
|
||||
-- MAIN DEAL ATTRIBUTES --
|
||||
m.deal as deal,
|
||||
m.active_accommodations_per_deal_segmentation
|
||||
as active_accommodations_per_deal_segmentation,
|
||||
m.main_billing_country_iso_3_per_deal as main_billing_country_iso_3_per_deal,
|
||||
|
||||
-- HUBSPOT ATTRIBUTES --
|
||||
m.account_manager as account_manager,
|
||||
|
||||
-- DEAL BUSINESS SCOPE
|
||||
m.business_scope as business_scope,
|
||||
|
||||
-- DEAL LIFECYCLE --
|
||||
m.deal_lifecycle_state as deal_lifecycle_state,
|
||||
|
||||
-- METRIC VALUES AND DISPLAY --
|
||||
m.order_by as order_by,
|
||||
m.number_format as number_format,
|
||||
m.value as value,
|
||||
m.previous_year_value as previous_year_value,
|
||||
m.relative_increment as relative_increment,
|
||||
m.relative_increment_with_sign_format as relative_increment_with_sign_format
|
||||
from int_mtd_aggregated_metrics_by_deal 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.
|
||||
m.display_exclusion = 'INVOICING'
|
||||
and {{ is_date_before_20th_of_previous_month("m.date") }}
|
||||
)
|
||||
or (
|
||||
-- Handle exclusion for Churn/MRR metrics: do not show them in the
|
||||
-- current month.
|
||||
m.display_exclusion = 'ONGOING_MONTH'
|
||||
and date_trunc('month', m.date) < date_trunc('month', current_date)
|
||||
)
|
||||
-- Keep all history for the rest of metrics
|
||||
or m.display_exclusion = 'NONE'
|
||||
)
|
||||
|
|
@ -455,7 +455,7 @@ models:
|
|||
data_type: numeric
|
||||
description: |
|
||||
Relative_increment value multiplied by -1 in case this metric's growth doesn't have a
|
||||
positive impact for Superhog, otherwise is equal to relative_increment.
|
||||
positive impact for Truvi, otherwise is equal to relative_increment.
|
||||
This value is specially created for formatting in PBI
|
||||
|
||||
- name: monthly_aggregated_metrics_history_by_deal
|
||||
|
|
@ -2323,3 +2323,188 @@ models:
|
|||
Relative difference between the current year YTD and the YTD target,
|
||||
with a sign to represent if the relative difference is good (positive) or bad
|
||||
(negative) for our business.
|
||||
|
||||
- name: mtd_aggregated_metrics_by_deal
|
||||
description: |
|
||||
This model aggregates the historic information of our business by providing
|
||||
different metrics at account level (by id_deal).
|
||||
Additionally it provides Deal attributes.
|
||||
|
||||
data_tests:
|
||||
- dbt_utils.unique_combination_of_columns:
|
||||
combination_of_columns:
|
||||
- date
|
||||
- metric
|
||||
- id_deal
|
||||
columns:
|
||||
- name: year
|
||||
data_type: int
|
||||
description: Year number of the given date.
|
||||
data_tests:
|
||||
- not_null
|
||||
|
||||
- name: month
|
||||
data_type: int
|
||||
description: Month number of the given date.
|
||||
data_tests:
|
||||
- not_null
|
||||
|
||||
- name: day
|
||||
data_type: int
|
||||
description: Day monthly number of the given date.
|
||||
data_tests:
|
||||
- not_null
|
||||
|
||||
- name: is_end_of_month
|
||||
data_type: boolean
|
||||
description: Is end of month, 1 for yes, 0 for no.
|
||||
data_tests:
|
||||
- not_null
|
||||
|
||||
- name: is_current_month
|
||||
data_type: boolean
|
||||
description: |
|
||||
Checks if the date is within the current executed month,
|
||||
1 for yes, 0 for no.
|
||||
data_tests:
|
||||
- not_null
|
||||
|
||||
- name: is_end_of_month_or_yesterday
|
||||
data_type: boolean
|
||||
description: |
|
||||
Checks if the date is end of month or yesterday,
|
||||
1 for yes, 0 for no.
|
||||
data_tests:
|
||||
- not_null
|
||||
|
||||
- name: first_day_month
|
||||
data_type: date
|
||||
description: |
|
||||
First day of the month corresponding to the date field.
|
||||
It comes from int_dates_mtd logic.
|
||||
data_tests:
|
||||
- not_null
|
||||
|
||||
- name: date
|
||||
data_type: date
|
||||
description: |
|
||||
Main date for the computation, that is used for filters.
|
||||
It comes from int_dates_mtd logic.
|
||||
data_tests:
|
||||
- not_null
|
||||
- latest_date_is_yesterday
|
||||
|
||||
- name: id_deal
|
||||
data_type: string
|
||||
description: |
|
||||
Unique ID for a deal, or account.
|
||||
data_tests:
|
||||
- not_null
|
||||
|
||||
- name: deal
|
||||
data_type: string
|
||||
description: |
|
||||
Combination of the ID and the Name of the deal.
|
||||
data_tests:
|
||||
- not_null
|
||||
|
||||
- name: active_accommodations_per_deal_segmentation
|
||||
data_type: string
|
||||
description: |
|
||||
Segment value based on the number of listings booked in 12 months
|
||||
for a given deal and date.
|
||||
data_tests:
|
||||
- not_null
|
||||
- accepted_values:
|
||||
values:
|
||||
- "0"
|
||||
- "01-05"
|
||||
- "06-20"
|
||||
- "21-60"
|
||||
- "61+"
|
||||
- "UNSET"
|
||||
|
||||
- name: main_billing_country_iso_3_per_deal
|
||||
data_type: string
|
||||
description: |
|
||||
ISO 3166-1 alpha-3 main country code in which the Deal is billed.
|
||||
In some cases it's null.
|
||||
|
||||
- name: business_scope
|
||||
data_type: string
|
||||
description: |
|
||||
Business scope identifying the metric source.
|
||||
data_tests:
|
||||
- not_null
|
||||
- accepted_values:
|
||||
values:
|
||||
- "Old Dash"
|
||||
- "New Dash"
|
||||
- "API"
|
||||
- "UNSET"
|
||||
|
||||
- name: account_manager
|
||||
data_type: string
|
||||
description: |
|
||||
Account manager of the deal.
|
||||
In some cases it's null.
|
||||
|
||||
- name: deal_lifecycle_state
|
||||
data_type: string
|
||||
description: |
|
||||
Lifecycle state of the deal.
|
||||
|
||||
- name: metric
|
||||
data_type: text
|
||||
description: Name of the business metric.
|
||||
data_tests:
|
||||
- not_null
|
||||
|
||||
- name: order_by
|
||||
data_type: integer
|
||||
description: |
|
||||
Order for displaying purposes. Null values are accepted, but keep
|
||||
in mind that then there's no default controlled display order.
|
||||
|
||||
- name: number_format
|
||||
data_type: text
|
||||
description: Allows for grouping and formatting for displaying purposes.
|
||||
data_tests:
|
||||
- accepted_values:
|
||||
values:
|
||||
[
|
||||
"integer",
|
||||
"percentage",
|
||||
"currency_gbp",
|
||||
"converted_metric_currency_gbp",
|
||||
]
|
||||
|
||||
- name: value
|
||||
data_type: numeric
|
||||
description: |
|
||||
Numeric value (integer or decimal) that corresponds to the MTD computation of the metric
|
||||
at a given date. Note that if the month is not in progress, then this value corresponds
|
||||
to the monthly figure.
|
||||
data_tests:
|
||||
- not_null
|
||||
|
||||
- name: previous_year_value
|
||||
data_type: numeric
|
||||
description: |
|
||||
Numeric value (integer or decimal) that corresponds to the MTD computation of the metric
|
||||
on the previous year at a given date.
|
||||
data_tests:
|
||||
- not_null
|
||||
|
||||
- name: relative_increment
|
||||
data_type: numeric
|
||||
description: |
|
||||
Numeric value that corresponds to the relative increment between value and previous year value,
|
||||
following the computation: value / previous_year_value - 1.
|
||||
|
||||
- name: relative_increment_with_sign_format
|
||||
data_type: numeric
|
||||
description: |
|
||||
Relative_increment value multiplied by -1 in case this metric's growth doesn't have a
|
||||
positive impact for Truvi, otherwise is equal to relative_increment.
|
||||
This value is specially created for formatting in PBI
|
||||
|
|
|
|||
Loading…
Add table
Add a link
Reference in a new issue