Merged PR 5014: New Created Bookings Growth Score

# Description

After checking the current growth score model... I think I will decommission it for something simpler.

This PR introduces a new growth score purely based on Created Bookings, thus it won't work for API deals. For API deals I will do a similar Total Revenue comparison separately.

This uses the projected bookings at the end of the month, thus this is updated in a daily basis and it's timely.

# 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: #29374
This commit is contained in:
Oriol Roqué Paniagua 2025-04-24 07:10:39 +00:00
parent 45514dcd6a
commit a944a873d7
3 changed files with 284 additions and 0 deletions

View file

@ -0,0 +1,113 @@
{{ config(materialized="table", unique_key=["end_date", "id_deal"]) }}
with
int_kpis_projected__agg_monthly_created_bookings as (
select *
from {{ ref("int_kpis_projected__agg_monthly_created_bookings") }}
where dimension = 'by_deal' and dimension_value <> 'UNSET'
),
int_kpis__agg_monthly_created_bookings as (
select *
from {{ ref("int_kpis__agg_monthly_created_bookings") }}
where dimension = 'by_deal' and dimension_value <> 'UNSET'
),
created_bookings_per_month_with_projection as (
select
start_date,
end_date,
dimension_value as id_deal,
current_month_projected_created_bookings as current_month_created_bookings,
current_month_projected_created_bookings
/ sum(current_month_projected_created_bookings) over (
partition by end_date order by end_date
) as current_month_share_created_bookings,
historical_monthly_mean_absolute_error as projection_mean_absolute_error,
historical_monthly_mean_absolute_percentage_error
as projection_mean_absolute_percentage_error,
true as are_created_bookings_projected
from int_kpis_projected__agg_monthly_created_bookings
union all
select
start_date,
end_date,
dimension_value as id_deal,
created_bookings as current_month_created_bookings,
created_bookings / sum(created_bookings) over (
partition by end_date order by end_date
) as current_month_share_created_bookings,
null as projection_mean_absolute_error,
null as projection_mean_absolute_percentage_error,
false as are_created_bookings_projected
from int_kpis__agg_monthly_created_bookings
),
created_bookings_growth_score as (
select
start_date,
end_date,
id_deal,
-- Created Bookings (Absolute) --
current_month_created_bookings,
avg(current_month_created_bookings) over (
partition by id_deal
order by end_date asc
rows between 3 preceding and 1 preceding
) as prior_3_months_avg_monthly_created_bookings,
current_month_created_bookings / avg(current_month_created_bookings) over (
partition by id_deal
order by end_date asc
rows between 3 preceding and 1 preceding
)
- 1 as growth_vs_prior_3_avg_created_bookings,
-- Share of Created Bookings per Deal over Total --
current_month_share_created_bookings,
avg(current_month_share_created_bookings) over (
partition by id_deal
order by end_date asc
rows between 3 preceding and 1 preceding
) as prior_3_months_avg_monthly_share_created_bookings,
current_month_share_created_bookings
/ avg(current_month_share_created_bookings) over (
partition by id_deal
order by end_date asc
rows between 3 preceding and 1 preceding
)
- 1 as growth_vs_prior_3_avg_share_created_bookings,
-- Projection Reference --
projection_mean_absolute_error,
projection_mean_absolute_percentage_error,
are_created_bookings_projected
from created_bookings_per_month_with_projection
)
select
start_date,
end_date,
id_deal,
-- Created Bookings (Absolute) --
current_month_created_bookings,
prior_3_months_avg_monthly_created_bookings,
-- Share of Created Bookings per Deal over Total --
current_month_share_created_bookings,
prior_3_months_avg_monthly_share_created_bookings,
-- Specific Growth Scores --
growth_vs_prior_3_avg_created_bookings,
growth_vs_prior_3_avg_share_created_bookings,
-- Combined Growth Score --
least(
greatest(
coalesce(
(
growth_vs_prior_3_avg_created_bookings
+ growth_vs_prior_3_avg_share_created_bookings
)
/ 2,
0
),
-1
),
1
) as growth_score,
-- Projection Reference --
projection_mean_absolute_error,
projection_mean_absolute_percentage_error,
are_created_bookings_projected
from created_bookings_growth_score

View file

@ -453,6 +453,7 @@ models:
In some cases it's null.
- name: int_monthly_growth_score_by_deal
deprecation_date: 2025-05-10 08:00:00
description: |
The main goal of this model is to provide a growth score by deal and month.
The idea behind it is that each deal will have some business performance
@ -3223,3 +3224,172 @@ models:
A hypothetical perfect model would have an F2 score of 1.0, or 100%.
When precision and recall are far apart, the F2 score will be closer to the
lower of the two.
- name: int_created_bookings_growth_score_by_deal
description: |
This model computes the growth score of the created bookings for each deal.
The growth score is computed as the average between:
- The created bookings of a given month vs. the average of the previous
3 months.
- The share a deal has in terms of created bookings of a given month
if compared to the rest of the deals vs. the average of the previous 3
months.
The growth score is capped between -1 and 1.
It is important to note that if we check the current month, the count of
created bookings and the corresponding share will be based on the projection,
rather than the actual figure. In this case, the MAE and MAPE of the projected
value are indicated in the model.
While the growth score is computed at a monthly basis, the value will update
every day with the latest available projection.
data_tests:
- dbt_utils.unique_combination_of_columns:
combination_of_columns:
- end_date
- id_deal
- dbt_utils.unique_combination_of_columns:
combination_of_columns:
- start_date
- id_deal
columns:
- name: start_date
data_type: date
description: |
Start date of the period for which the growth score is computed.
data_tests:
- not_null
- name: end_date
data_type: date
description: |
End date of the period for which the growth score is computed.
data_tests:
- not_null
- name: id_deal
data_type: string
description: |
Unique ID for a deal, or account.
data_tests:
- not_null
- name: current_month_created_bookings
data_type: integer
description: |
Monthly created bookings. If the month is in progress
then this value corresponds to the projected figure.
This is indicated by "are_created_bookings_projected"
flag.
data_tests:
- not_null
- dbt_expectations.expect_column_values_to_be_between:
min_value: 0
strictly: false
- name: prior_3_months_avg_monthly_created_bookings
data_type: integer
description: |
Average of the created bookings for the previous 3 months.
If the selected range is from 1st April 2025 to 30th April 2025,
then this average will be based between 1st January 2025 to
31st March 2025.
data_tests:
- dbt_expectations.expect_column_values_to_be_between:
min_value: 0
strictly: false
- name: current_month_share_created_bookings
data_type: decimal
description: |
Share of the created bookings for a given deal in the current month.
If the month is in progress then this value corresponds to the
projected figure. This is indicated by "are_created_bookings_projected"
flag.
data_tests:
- not_null
- dbt_expectations.expect_column_values_to_be_between:
min_value: 0
strictly: false
- name: prior_3_months_avg_monthly_share_created_bookings
data_type: decimal
description: |
Average of the share of the created bookings for a given deal in the
previous 3 months. If the selected range is from 1st April 2025 to
30th April 2025, then this average will be based between 1st January
2025 to 31st March 2025.
data_tests:
- dbt_expectations.expect_column_values_to_be_between:
min_value: 0
strictly: false
- name: growth_vs_prior_3_avg_created_bookings
data_type: decimal
description: |
Growth score of the created bookings based purely on the relative
difference between the current month created bookings vs. the
prior 3 months average.
This is a subcomputation of the growth score, for information
purposes.
It can be null.
- name: growth_vs_prior_3_avg_share_created_bookings
data_type: decimal
description: |
Growth score of the created bookings based purely on the relative
difference between the current month share created bookings vs. the
prior 3 months average.
This is a subcomputation of the growth score, for information
purposes.
It can be null.
- name: growth_score
data_type: decimal
description: |
Growth score of the created bookings, based on the average between:
- The created bookings of a given month vs. the average of the previous
3 months.
- The share a deal has in terms of created bookings of a given month
if compared to the rest of the deals vs. the average of the previous 3
months.
The growth score is capped between -1 and 1.
It cannot be null.
data_tests:
- not_null
- dbt_expectations.expect_column_values_to_be_between:
min_value: -1
max_value: 1
strictly: false
- name: projection_mean_absolute_error
data_type: decimal
description: |
Mean absolute error of the projection of the created bookings.
It is null if the month is not in progress or value is projected
but there's no prior data to compare the projection against.
data_tests:
- dbt_expectations.expect_column_values_to_be_between:
min_value: 0
strictly: false
- name: projection_mean_absolute_percentage_error
data_type: decimal
description: |
Mean absolute percentage error of the projection of the created bookings.
It is null if the month is not in progress or value is projected
but there's no prior data to compare the projection against.
data_tests:
- dbt_expectations.expect_column_values_to_be_between:
min_value: 0
strictly: false
- name: are_created_bookings_projected
data_type: boolean
description: |
Flag indicating if the created bookings are projected or not.
If the month is in progress then this value corresponds to the
projected figure. This is indicated by "are_created_bookings_projected"
flag.
data_tests:
- not_null