From 61339a7d586ea329af0f35384a5df4b6e5250824 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Oriol=20Roqu=C3=A9=20Paniagua?= Date: Tue, 15 Oct 2024 12:31:39 +0000 Subject: [PATCH] Merged PR 3171: Improvements on monthly growth score by deal # Description Main changes: * Includes 4 new fields to take into account 12 month created bookings. Specifically: `deal_created_bookings_12_months_window` `global_created_bookings_12_months_window` `deal_contribution_share_to_global_created_bookings` `deal_contribution_rank_to_global_created_bookings` This also renames a CTE, that was previously stating it was revenue. Same for inline comments. Also includes documentation of this fields. * Score range modification: Now, growth scores are multiplied by 100 and weighted score by 1000. This makes it easier to display and understand (Growth cannot be less than -100, threshold value is now -1, 0 and 1). I checked that the content already in production has not change (ex: we still have the same 15 top losers for September). # 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. - [NA] 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 --- .../int_monthly_growth_score_by_deal.sql | 69 +++++++++++++------ models/intermediate/cross/schema.yml | 58 +++++++++++++++- .../general/monthly_growth_score_by_deal.sql | 8 +++ models/reporting/general/schema.yml | 58 +++++++++++++++- 4 files changed, 168 insertions(+), 25 deletions(-) diff --git a/models/intermediate/cross/int_monthly_growth_score_by_deal.sql b/models/intermediate/cross/int_monthly_growth_score_by_deal.sql index de2b570..a92f3c1 100644 --- a/models/intermediate/cross/int_monthly_growth_score_by_deal.sql +++ b/models/intermediate/cross/int_monthly_growth_score_by_deal.sql @@ -26,11 +26,19 @@ with id_deal, from_first_day_month, to_first_day_month, + deal_created_bookings_12_months_window, + sum(deal_created_bookings_12_months_window) over ( + partition by first_day_month + ) as global_created_bookings_12_months_window, deal_revenue_12_months_window, effective_deal_revenue_12_months_window, sum(effective_deal_revenue_12_months_window) over ( partition by first_day_month ) as effective_global_revenue_12_months_window, + row_number() over ( + partition by first_day_month + order by deal_created_bookings_12_months_window desc + ) as deal_contribution_rank_to_global_created_bookings, row_number() over ( partition by first_day_month order by deal_revenue_12_months_window desc ) as deal_contribution_rank_to_global_revenue @@ -41,6 +49,9 @@ with given_month.id_deal, min(previous_twelve_months.first_day_month) as from_first_day_month, max(previous_twelve_months.first_day_month) as to_first_day_month, + coalesce( + sum(previous_twelve_months.created_bookings), 0 + ) as deal_created_bookings_12_months_window, coalesce( sum(previous_twelve_months.revenue_in_gbp), 0 ) as deal_revenue_12_months_window, @@ -77,9 +88,9 @@ with 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 + aggregated_12m_window.from_first_day_month as aggregated_revenue_from_first_day_month, - aggregated_revenue.to_first_day_month + aggregated_12m_window.to_first_day_month as aggregated_revenue_to_first_day_month, -- Revenue -- @@ -129,20 +140,32 @@ with / nullif(previous_12_month.listings_booked_in_month, 0) - 1 as yoy_listings_booked_in_month_growth, - -- Revenue 12 Months Window (Account Size) -- - aggregated_revenue.deal_revenue_12_months_window, - aggregated_revenue.effective_deal_revenue_12_months_window, - aggregated_revenue.effective_global_revenue_12_months_window, + -- 12 Months Window (Account Size) -- + aggregated_12m_window.deal_created_bookings_12_months_window, + aggregated_12m_window.global_created_bookings_12_months_window, coalesce( cast( - aggregated_revenue.effective_deal_revenue_12_months_window + aggregated_12m_window.deal_created_bookings_12_months_window as decimal ) / nullif( - aggregated_revenue.effective_global_revenue_12_months_window, 0 + aggregated_12m_window.global_created_bookings_12_months_window, 0 + ), + 0 + ) as deal_contribution_share_to_global_created_bookings, + aggregated_12m_window.deal_contribution_rank_to_global_created_bookings, + aggregated_12m_window.deal_revenue_12_months_window, + aggregated_12m_window.effective_deal_revenue_12_months_window, + aggregated_12m_window.effective_global_revenue_12_months_window, + coalesce( + cast( + aggregated_12m_window.effective_deal_revenue_12_months_window + as decimal + ) / nullif( + aggregated_12m_window.effective_global_revenue_12_months_window, 0 ), 0 ) as deal_contribution_share_to_global_revenue, - aggregated_revenue.deal_contribution_rank_to_global_revenue + aggregated_12m_window.deal_contribution_rank_to_global_revenue from deal_history_from_previous_months as given_month -- Retrieve monthly data from same deal and previous month @@ -171,11 +194,11 @@ with on previous_13_month.first_day_month + interval '13 months' = given_month.first_day_month and previous_13_month.id_deal = given_month.id_deal - -- Retrieve revenue aggregation over 12 previous months + -- Retrieve aggregation over 12 previous months left join - 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 + revenue_12_months_window_aggregation_per_deal aggregated_12m_window + on aggregated_12m_window.id_deal = given_month.id_deal + and aggregated_12m_window.first_day_month = given_month.first_day_month ), growth_score_computation as ( select @@ -228,13 +251,17 @@ with m.yoy_listings_booked_in_month_growth as numeric(19, 6) ) as yoy_listings_booked_in_month_growth, + m.deal_created_bookings_12_months_window, + m.global_created_bookings_12_months_window, + m.deal_contribution_share_to_global_created_bookings, + m.deal_contribution_rank_to_global_created_bookings, 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( + 100 * cast( ( coalesce(m.mom_created_bookings_growth, 0) + coalesce(m.mom_listings_booked_in_month_growth, 0) @@ -243,7 +270,7 @@ with / 3 as numeric(19, 6) ) as avg_mom_growth_score, - cast( + 100 * cast( ( coalesce(m.yoy_created_bookings_growth, 0) + coalesce(m.yoy_listings_booked_in_month_growth, 0) @@ -251,7 +278,7 @@ with ) / 3 as numeric(19, 6) ) as avg_yoy_growth_score, - cast( + 100 * cast( ( coalesce(m.yoy_created_bookings_growth, 0) + coalesce(m.yoy_listings_booked_in_month_growth, 0) @@ -262,7 +289,7 @@ with ) / 6 as numeric(19, 6) ) as avg_growth_score, - cast( + 1000 * cast( ( ( coalesce(m.yoy_created_bookings_growth, 0) @@ -284,15 +311,15 @@ select -- Applies a categorisation based on the score value. These scores thresholds are -- opinionated case - when weighted_avg_growth_score <= -0.001 + when weighted_avg_growth_score <= -1.0 then 'TOP LOSER' - when weighted_avg_growth_score > -0.001 and weighted_avg_growth_score < 0 + when weighted_avg_growth_score > -1.0 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 + when weighted_avg_growth_score > 0 and weighted_avg_growth_score < 1.0 then 'WINNER' - when weighted_avg_growth_score >= 0.001 + when weighted_avg_growth_score >= 1.0 then 'TOP WINNER' else 'UNSET' end as categorisation_weighted_avg_growth_score diff --git a/models/intermediate/cross/schema.yml b/models/intermediate/cross/schema.yml index c7e3e67..64bb5c5 100644 --- a/models/intermediate/cross/schema.yml +++ b/models/intermediate/cross/schema.yml @@ -1037,8 +1037,62 @@ models: data_type: integer description: | Represents the ordered list of deals by descending size - in terms of revenue. It cannot be null. If more than one - deal have the same share, the order is not under control. + in terms of revenue. + If more than one deal have the same share, the order is + not under control. + It cannot be null. + tests: + - not_null + + - name: deal_created_bookings_12_months_window + data_type: integer + description: | + Total created bookings generated by a deal + in the months from the period ranging from the + aggregated_revenue_from_first_day_month to + aggregated_revenue_to_first_day_month. + It cannot be null. + tests: + - not_null + - dbt_expectations.expect_column_values_to_be_between: + min_value: 0 + strictly: false + + - name: global_created_bookings_12_months_window + data_type: integer + description: | + Total created bookings generated by a deal + in the months from the period ranging from the + aggregated_revenue_from_first_day_month to + aggregated_revenue_to_first_day_month. + It is used for the deal contribution share with respect + to the global created bookings. It cannot be null. + tests: + - not_null + - dbt_expectations.expect_column_values_to_be_between: + min_value: 0 + strictly: false + + - name: deal_contribution_share_to_global_created_bookings + data_type: decimal + description: | + Represents the size of the deal in terms of created bookings. + In other words, what's the percentage of the global created + bookings that can be attributed to this deal. + It cannot be null. + tests: + - not_null + - dbt_expectations.expect_column_values_to_be_between: + min_value: 0 + strictly: false + + - name: deal_contribution_rank_to_global_created_bookings + data_type: integer + description: | + Represents the ordered list of deals by descending size + in terms of created bookings. + If more than one deal have the same share, the order is + not under control. It cannot be null. tests: - not_null diff --git a/models/reporting/general/monthly_growth_score_by_deal.sql b/models/reporting/general/monthly_growth_score_by_deal.sql index 27a6a1f..9c2263c 100644 --- a/models/reporting/general/monthly_growth_score_by_deal.sql +++ b/models/reporting/general/monthly_growth_score_by_deal.sql @@ -42,6 +42,14 @@ select mom_listings_booked_in_month_growth as mom_listings_booked_in_month_growth, yoy_listings_booked_in_month_growth as yoy_listings_booked_in_month_growth, + deal_created_bookings_12_months_window as deal_created_bookings_12_months_window, + global_created_bookings_12_months_window + as global_created_bookings_12_months_window, + deal_contribution_share_to_global_created_bookings + as deal_contribution_share_to_global_created_bookings, + deal_contribution_rank_to_global_created_bookings + as deal_contribution_rank_to_global_created_bookings, + deal_revenue_12_months_window as deal_revenue_12_months_window, effective_deal_revenue_12_months_window as effective_deal_revenue_12_months_window, effective_global_revenue_12_months_window diff --git a/models/reporting/general/schema.yml b/models/reporting/general/schema.yml index 6cac0b4..f7d62f6 100644 --- a/models/reporting/general/schema.yml +++ b/models/reporting/general/schema.yml @@ -962,8 +962,62 @@ models: data_type: integer description: | Represents the ordered list of deals by descending size - in terms of revenue. It cannot be null. If more than one - deal have the same share, the order is not under control. + in terms of revenue. + If more than one deal have the same share, the order is + not under control. + It cannot be null. + tests: + - not_null + + - name: deal_created_bookings_12_months_window + data_type: integer + description: | + Total created bookings generated by a deal + in the months from the period ranging from the + aggregated_revenue_from_first_day_month to + aggregated_revenue_to_first_day_month. + It cannot be null. + tests: + - not_null + - dbt_expectations.expect_column_values_to_be_between: + min_value: 0 + strictly: false + + - name: global_created_bookings_12_months_window + data_type: integer + description: | + Total created bookings generated by a deal + in the months from the period ranging from the + aggregated_revenue_from_first_day_month to + aggregated_revenue_to_first_day_month. + It is used for the deal contribution share with respect + to the global created bookings. It cannot be null. + tests: + - not_null + - dbt_expectations.expect_column_values_to_be_between: + min_value: 0 + strictly: false + + - name: deal_contribution_share_to_global_created_bookings + data_type: decimal + description: | + Represents the size of the deal in terms of created bookings. + In other words, what's the percentage of the global created + bookings that can be attributed to this deal. + It cannot be null. + tests: + - not_null + - dbt_expectations.expect_column_values_to_be_between: + min_value: 0 + strictly: false + + - name: deal_contribution_rank_to_global_created_bookings + data_type: integer + description: | + Represents the ordered list of deals by descending size + in terms of created bookings. + If more than one deal have the same share, the order is + not under control. It cannot be null. tests: - not_null