Merged PR 3137: Growth score to reporting
# Description Copies intermediate to reporting for growth score by deal. Schema is copy-paste from intermediate changing the model's name. # 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. - [NA] 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: #22635
This commit is contained in:
parent
a6191eba46
commit
eb213acb9e
4 changed files with 792 additions and 65 deletions
|
|
@ -74,6 +74,7 @@ with
|
|||
-- Dates - For Information Purposes
|
||||
given_month.first_day_month as given_month_first_day_month,
|
||||
previous_1_month.first_day_month as previous_1_month_first_day_month,
|
||||
previous_2_month.first_day_month as previous_2_month_first_day_month,
|
||||
previous_12_month.first_day_month as previous_12_month_first_day_month,
|
||||
previous_13_month.first_day_month as previous_13_month_first_day_month,
|
||||
aggregated_revenue.from_first_day_month
|
||||
|
|
@ -84,6 +85,7 @@ with
|
|||
-- Revenue --
|
||||
given_month.revenue_in_gbp as given_month_revenue_in_gbp,
|
||||
previous_1_month.revenue_in_gbp as previous_1_month_revenue_in_gbp,
|
||||
previous_2_month.revenue_in_gbp as previous_2_month_revenue_in_gbp,
|
||||
previous_12_month.revenue_in_gbp as previous_12_month_revenue_in_gbp,
|
||||
previous_13_month.revenue_in_gbp as previous_13_month_revenue_in_gbp,
|
||||
-- In these YoY and MoM computations, if negative revenue is found,
|
||||
|
|
@ -92,6 +94,9 @@ with
|
|||
nullif(greatest(given_month.revenue_in_gbp, 0), 0)
|
||||
/ nullif(greatest(previous_1_month.revenue_in_gbp, 0), 0)
|
||||
- 1 as mom_revenue_growth,
|
||||
nullif(greatest(previous_1_month.revenue_in_gbp, 0), 0)
|
||||
/ nullif(greatest(previous_2_month.revenue_in_gbp, 0), 0)
|
||||
- 1 as mom_1_month_shift_revenue_growth,
|
||||
nullif(greatest(given_month.revenue_in_gbp, 0), 0)
|
||||
/ nullif(greatest(previous_12_month.revenue_in_gbp, 0), 0)
|
||||
- 1 as yoy_revenue_growth,
|
||||
|
|
@ -146,6 +151,12 @@ with
|
|||
on previous_1_month.first_day_month + interval '1 months'
|
||||
= given_month.first_day_month
|
||||
and previous_1_month.id_deal = given_month.id_deal
|
||||
-- Retrieve monthly data from same deal and 2 months ago
|
||||
left join
|
||||
deal_history_from_previous_months as previous_2_month
|
||||
on previous_2_month.first_day_month + interval '2 months'
|
||||
= given_month.first_day_month
|
||||
and previous_2_month.id_deal = given_month.id_deal
|
||||
-- Retrieve monthly data from same deal and the equivalent
|
||||
-- month from last year
|
||||
left join
|
||||
|
|
@ -154,8 +165,7 @@ with
|
|||
= given_month.first_day_month
|
||||
and previous_12_month.id_deal = given_month.id_deal
|
||||
-- Retrieve monthly data from same deal and the equivalent
|
||||
-- month from last
|
||||
-- year and 1 month before
|
||||
-- month from last year and 1 month before
|
||||
left join
|
||||
deal_history_from_previous_months as previous_13_month
|
||||
on previous_13_month.first_day_month + interval '13 months'
|
||||
|
|
@ -166,62 +176,124 @@ with
|
|||
revenue_12_months_window_aggregation_per_deal aggregated_revenue
|
||||
on aggregated_revenue.id_deal = given_month.id_deal
|
||||
and aggregated_revenue.first_day_month = given_month.first_day_month
|
||||
),
|
||||
growth_score_computation as (
|
||||
select
|
||||
m.date,
|
||||
m.id_deal,
|
||||
|
||||
m.main_deal_name,
|
||||
m.main_billing_country_iso_3_per_deal,
|
||||
m.deal_lifecycle_state,
|
||||
|
||||
m.given_month_first_day_month,
|
||||
m.previous_1_month_first_day_month,
|
||||
m.previous_2_month_first_day_month,
|
||||
m.previous_12_month_first_day_month,
|
||||
m.previous_13_month_first_day_month,
|
||||
m.aggregated_revenue_from_first_day_month,
|
||||
m.aggregated_revenue_to_first_day_month,
|
||||
|
||||
m.given_month_revenue_in_gbp,
|
||||
m.previous_1_month_revenue_in_gbp,
|
||||
m.previous_2_month_revenue_in_gbp,
|
||||
m.previous_12_month_revenue_in_gbp,
|
||||
m.previous_13_month_revenue_in_gbp,
|
||||
cast(m.mom_revenue_growth as numeric(19, 6)) as mom_revenue_growth,
|
||||
cast(
|
||||
m.mom_1_month_shift_revenue_growth as numeric(19, 6)
|
||||
) as mom_1_month_shift_revenue_growth,
|
||||
cast(m.yoy_revenue_growth as numeric(19, 6)) as yoy_revenue_growth,
|
||||
cast(
|
||||
m.yoy_1_month_shift_revenue_growth as numeric(19, 6)
|
||||
) as yoy_1_month_shift_revenue_growth,
|
||||
|
||||
m.given_month_created_bookings,
|
||||
m.previous_1_month_created_bookings,
|
||||
m.previous_12_month_created_bookings,
|
||||
cast(
|
||||
m.mom_created_bookings_growth as numeric(19, 6)
|
||||
) as mom_created_bookings_growth,
|
||||
cast(
|
||||
m.yoy_created_bookings_growth as numeric(19, 6)
|
||||
) as yoy_created_bookings_growth,
|
||||
|
||||
m.given_month_listings_booked_in_month,
|
||||
m.previous_1_month_listings_booked_in_month,
|
||||
m.previous_12_month_listings_booked_in_month,
|
||||
cast(
|
||||
m.mom_listings_booked_in_month_growth as numeric(19, 6)
|
||||
) as mom_listings_booked_in_month_growth,
|
||||
cast(
|
||||
m.yoy_listings_booked_in_month_growth as numeric(19, 6)
|
||||
) as yoy_listings_booked_in_month_growth,
|
||||
|
||||
m.deal_revenue_12_months_window,
|
||||
m.effective_deal_revenue_12_months_window,
|
||||
m.effective_global_revenue_12_months_window,
|
||||
m.deal_contribution_share_to_global_revenue,
|
||||
m.deal_contribution_rank_to_global_revenue,
|
||||
|
||||
cast(
|
||||
(
|
||||
coalesce(m.mom_created_bookings_growth, 0)
|
||||
+ coalesce(m.mom_listings_booked_in_month_growth, 0)
|
||||
+ coalesce(m.mom_1_month_shift_revenue_growth, 0)
|
||||
)
|
||||
/ 3 as numeric(19, 6)
|
||||
) as avg_mom_growth_score,
|
||||
|
||||
cast(
|
||||
(
|
||||
coalesce(m.yoy_created_bookings_growth, 0)
|
||||
+ coalesce(m.yoy_listings_booked_in_month_growth, 0)
|
||||
+ coalesce(m.yoy_1_month_shift_revenue_growth, 0)
|
||||
)
|
||||
/ 3 as numeric(19, 6)
|
||||
) as avg_yoy_growth_score,
|
||||
cast(
|
||||
(
|
||||
coalesce(m.yoy_created_bookings_growth, 0)
|
||||
+ coalesce(m.yoy_listings_booked_in_month_growth, 0)
|
||||
+ coalesce(m.yoy_1_month_shift_revenue_growth, 0)
|
||||
+ coalesce(m.mom_created_bookings_growth, 0)
|
||||
+ coalesce(m.mom_listings_booked_in_month_growth, 0)
|
||||
+ coalesce(m.mom_1_month_shift_revenue_growth, 0)
|
||||
)
|
||||
/ 6 as numeric(19, 6)
|
||||
) as avg_growth_score,
|
||||
cast(
|
||||
(
|
||||
(
|
||||
coalesce(m.yoy_created_bookings_growth, 0)
|
||||
+ coalesce(m.yoy_listings_booked_in_month_growth, 0)
|
||||
+ coalesce(m.yoy_1_month_shift_revenue_growth, 0)
|
||||
+ coalesce(m.mom_created_bookings_growth, 0)
|
||||
+ coalesce(m.mom_listings_booked_in_month_growth, 0)
|
||||
+ coalesce(m.mom_1_month_shift_revenue_growth, 0)
|
||||
)
|
||||
/ 6
|
||||
)
|
||||
* deal_contribution_share_to_global_revenue as numeric(19, 6)
|
||||
) as weighted_avg_growth_score
|
||||
|
||||
from metrics_attribution_to_given_month_per_deal m
|
||||
)
|
||||
select
|
||||
m.date,
|
||||
m.id_deal,
|
||||
|
||||
m.main_deal_name,
|
||||
m.main_billing_country_iso_3_per_deal,
|
||||
m.deal_lifecycle_state,
|
||||
|
||||
m.given_month_first_day_month,
|
||||
m.previous_1_month_first_day_month,
|
||||
m.previous_12_month_first_day_month,
|
||||
m.previous_13_month_first_day_month,
|
||||
m.aggregated_revenue_from_first_day_month,
|
||||
m.aggregated_revenue_to_first_day_month,
|
||||
|
||||
m.given_month_revenue_in_gbp,
|
||||
m.previous_1_month_revenue_in_gbp,
|
||||
m.previous_12_month_revenue_in_gbp,
|
||||
m.previous_13_month_revenue_in_gbp,
|
||||
m.mom_revenue_growth,
|
||||
m.yoy_revenue_growth,
|
||||
m.yoy_1_month_shift_revenue_growth,
|
||||
|
||||
m.given_month_created_bookings,
|
||||
m.previous_1_month_created_bookings,
|
||||
m.previous_12_month_created_bookings,
|
||||
m.mom_created_bookings_growth,
|
||||
m.yoy_created_bookings_growth,
|
||||
|
||||
m.given_month_listings_booked_in_month,
|
||||
m.previous_1_month_listings_booked_in_month,
|
||||
m.previous_12_month_listings_booked_in_month,
|
||||
m.mom_listings_booked_in_month_growth,
|
||||
m.yoy_listings_booked_in_month_growth,
|
||||
|
||||
m.deal_revenue_12_months_window,
|
||||
m.effective_deal_revenue_12_months_window,
|
||||
m.effective_global_revenue_12_months_window,
|
||||
m.deal_contribution_share_to_global_revenue,
|
||||
m.deal_contribution_rank_to_global_revenue,
|
||||
|
||||
(
|
||||
coalesce(m.yoy_created_bookings_growth, 0)
|
||||
+ coalesce(m.yoy_listings_booked_in_month_growth, 0)
|
||||
+ coalesce(m.yoy_1_month_shift_revenue_growth, 0)
|
||||
)
|
||||
/ 3 as avg_growth_score,
|
||||
(
|
||||
(
|
||||
coalesce(m.yoy_created_bookings_growth, 0)
|
||||
+ coalesce(m.yoy_listings_booked_in_month_growth, 0)
|
||||
+ coalesce(m.yoy_1_month_shift_revenue_growth, 0)
|
||||
)
|
||||
/ 3
|
||||
)
|
||||
* deal_contribution_share_to_global_revenue as weighted_avg_growth_score
|
||||
|
||||
from metrics_attribution_to_given_month_per_deal m
|
||||
*,
|
||||
-- Applies a categorisation based on the score value. These scores thresholds are
|
||||
-- opinionated
|
||||
case
|
||||
when weighted_avg_growth_score <= -0.001
|
||||
then 'TOP LOSER'
|
||||
when weighted_avg_growth_score > -0.001 and weighted_avg_growth_score < 0
|
||||
then 'LOSER'
|
||||
when weighted_avg_growth_score = 0
|
||||
then 'FLAT'
|
||||
when weighted_avg_growth_score > 0 and weighted_avg_growth_score < 0.001
|
||||
then 'WINNER'
|
||||
when weighted_avg_growth_score >= 0.001
|
||||
then 'TOP WINNER'
|
||||
else 'UNSET'
|
||||
end as categorisation_weighted_avg_growth_score
|
||||
from growth_score_computation
|
||||
|
|
|
|||
|
|
@ -605,11 +605,12 @@ models:
|
|||
- Total revenue (in gbp)
|
||||
|
||||
The main idea is, for each deal, to compare each of these metrics by
|
||||
checking the latest monthly value vs. the monthly value of the equivalent
|
||||
month on the previous year - in other words, a year-on-year (YoY) comparison.
|
||||
checking the latest monthly value vs. 1) the monthly value of the equivalent
|
||||
month on the previous year and 2) the monthly value of the previous month
|
||||
- in other words, a year-on-year (YoY) and month-on-month (MoM) comparison.
|
||||
We do this comparison by doing a relative incremental.
|
||||
|
||||
The growth score is computed then by averaging the outcome of the 3 scores.
|
||||
The growth score is computed then by averaging the outcome of the 6 scores.
|
||||
Lastly, in order to provide a prioritisation sense, we have a weighted growth
|
||||
score that results from the multiplication of the growth score per the revenue
|
||||
weight a specific deal has provided in the previous 12 months.
|
||||
|
|
@ -687,6 +688,15 @@ models:
|
|||
It can be null if no previous history for that
|
||||
deal is found.
|
||||
|
||||
- name: previous_2_month_first_day_month
|
||||
data_type: date
|
||||
description: |
|
||||
Informative field. It indicates the first day of the
|
||||
month 2 months before with respect to date.
|
||||
If date = 2024-09-30, this field will be 2024-07-01.
|
||||
It can be null if no previous history for that
|
||||
deal is found.
|
||||
|
||||
- name: previous_12_month_first_day_month
|
||||
data_type: date
|
||||
description: |
|
||||
|
|
@ -749,12 +759,22 @@ models:
|
|||
This value can be null, thus indicating that no
|
||||
history is available.
|
||||
|
||||
- name: previous_2_month_revenue_in_gbp
|
||||
data_type: decimal
|
||||
description: |
|
||||
Monthly value representing revenue in GBP
|
||||
for a specific deal. This value corresponds to
|
||||
the monthly amount generated 2 months ago
|
||||
This value can be negative.
|
||||
This value can be null, thus indicating that no
|
||||
history is available.
|
||||
|
||||
- name: previous_12_month_revenue_in_gbp
|
||||
data_type: decimal
|
||||
description: |
|
||||
Monthly value representing revenue in GBP
|
||||
for a specific deal. This value corresponds to
|
||||
monthly amount generated 12 months ago.
|
||||
the monthly amount generated 12 months ago.
|
||||
This value can be negative.
|
||||
This value can be null, thus indicating that no
|
||||
history is available.
|
||||
|
|
@ -764,7 +784,7 @@ models:
|
|||
description: |
|
||||
Monthly value representing revenue in GBP
|
||||
for a specific deal. This value corresponds to
|
||||
monthly amount generated 13 months ago.
|
||||
the monthly amount generated 13 months ago.
|
||||
This value can be negative.
|
||||
This value can be null, thus indicating that no
|
||||
history is available.
|
||||
|
|
@ -782,6 +802,20 @@ models:
|
|||
min_value: -1
|
||||
strictly: false
|
||||
|
||||
- name: mom_1_month_shift_revenue_growth
|
||||
data_type: decimal
|
||||
description: |
|
||||
Relative increment of the revenue generated in the
|
||||
previous month with respect to the one generated 2
|
||||
months ago.
|
||||
It can be null if any revenue used in the computation
|
||||
is null or it's negative.
|
||||
This field is used for the growth score computation.
|
||||
tests:
|
||||
- dbt_expectations.expect_column_values_to_be_between:
|
||||
min_value: -1
|
||||
strictly: false
|
||||
|
||||
- name: yoy_revenue_growth
|
||||
data_type: decimal
|
||||
description: |
|
||||
|
|
@ -855,6 +889,7 @@ models:
|
|||
the previous month.
|
||||
It can be null if the bookings created in the
|
||||
previous month are null.
|
||||
This field is used for the growth score computation.
|
||||
tests:
|
||||
- dbt_expectations.expect_column_values_to_be_between:
|
||||
min_value: -1
|
||||
|
|
@ -920,6 +955,7 @@ models:
|
|||
the previous month.
|
||||
It can be null if the listings booked in month in the
|
||||
previous month are null.
|
||||
This field is used for the growth score computation.
|
||||
tests:
|
||||
- dbt_expectations.expect_column_values_to_be_between:
|
||||
min_value: -1
|
||||
|
|
@ -1007,7 +1043,18 @@ models:
|
|||
tests:
|
||||
- not_null
|
||||
|
||||
- name: avg_growth_score
|
||||
- name: avg_mom_growth_score
|
||||
data_type: decimal
|
||||
description: |
|
||||
Represents the average score of MoM growth of created
|
||||
bookings, MoM growth of listings booked in month and
|
||||
MoM shifted by one month of revenue.
|
||||
It indicates the tendency of growth of the deal without
|
||||
taking into account its revenue size. It cannot be null.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: avg_yoy_growth_score
|
||||
data_type: decimal
|
||||
description: |
|
||||
Represents the average score of YoY growth of created
|
||||
|
|
@ -1018,6 +1065,17 @@ models:
|
|||
tests:
|
||||
- not_null
|
||||
|
||||
- name: avg_growth_score
|
||||
data_type: decimal
|
||||
description: |
|
||||
Represents the average score of YoY and MoM growth of created
|
||||
bookings, YoY and MoM growth of listings booked in month and
|
||||
YoY and MoM shifted by one month of revenue.
|
||||
It indicates the tendency of growth of the deal without
|
||||
taking into account its revenue size. It cannot be null.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: weighted_avg_growth_score
|
||||
data_type: decimal
|
||||
description: |
|
||||
|
|
@ -1029,3 +1087,22 @@ models:
|
|||
the financial impact this deal tendency can have.
|
||||
tests:
|
||||
- not_null
|
||||
|
||||
- name: categorisation_weighted_avg_growth_score
|
||||
data_type: string
|
||||
description: |
|
||||
Discrete categorisation of weighted_avg_growth_score.
|
||||
It helps easily identifying which accounts are top losers,
|
||||
losers, flat, winners and top winners.
|
||||
Currently the categorisation is based on the score itself
|
||||
rather than selecting a top up/down.
|
||||
tests:
|
||||
- not_null
|
||||
- accepted_values:
|
||||
values:
|
||||
- TOP LOSER
|
||||
- LOSER
|
||||
- FLAT
|
||||
- WINNER
|
||||
- TOP WINNER
|
||||
- UNSET
|
||||
|
|
|
|||
Loading…
Add table
Add a link
Reference in a new issue