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 ae56efe..de2b570 100644 --- a/models/intermediate/cross/int_monthly_growth_score_by_deal.sql +++ b/models/intermediate/cross/int_monthly_growth_score_by_deal.sql @@ -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 diff --git a/models/intermediate/cross/schema.yml b/models/intermediate/cross/schema.yml index f8d3fce..cc92a22 100644 --- a/models/intermediate/cross/schema.yml +++ b/models/intermediate/cross/schema.yml @@ -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 diff --git a/models/reporting/general/monthly_growth_score_by_deal.sql b/models/reporting/general/monthly_growth_score_by_deal.sql new file mode 100644 index 0000000..27a6a1f --- /dev/null +++ b/models/reporting/general/monthly_growth_score_by_deal.sql @@ -0,0 +1,61 @@ +with + int_monthly_growth_score_by_deal as ( + select * from {{ ref("int_monthly_growth_score_by_deal") }} + ) +select + date as date, + id_deal as id_deal, + + main_deal_name as main_deal_name, + main_billing_country_iso_3_per_deal as main_billing_country_iso_3_per_deal, + deal_lifecycle_state as deal_lifecycle_state, + + 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 as aggregated_revenue_from_first_day_month, + aggregated_revenue_to_first_day_month as aggregated_revenue_to_first_day_month, + + 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, + mom_revenue_growth as mom_revenue_growth, + mom_1_month_shift_revenue_growth as mom_1_month_shift_revenue_growth, + yoy_revenue_growth as yoy_revenue_growth, + yoy_1_month_shift_revenue_growth as yoy_1_month_shift_revenue_growth, + + given_month_created_bookings as given_month_created_bookings, + previous_1_month_created_bookings as previous_1_month_created_bookings, + previous_12_month_created_bookings as previous_12_month_created_bookings, + mom_created_bookings_growth as mom_created_bookings_growth, + yoy_created_bookings_growth as yoy_created_bookings_growth, + + given_month_listings_booked_in_month as given_month_listings_booked_in_month, + previous_1_month_listings_booked_in_month + as previous_1_month_listings_booked_in_month, + previous_12_month_listings_booked_in_month + as previous_12_month_listings_booked_in_month, + 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_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 + as effective_global_revenue_12_months_window, + deal_contribution_share_to_global_revenue + as deal_contribution_share_to_global_revenue, + deal_contribution_rank_to_global_revenue + as deal_contribution_rank_to_global_revenue, + + avg_mom_growth_score as avg_mom_growth_score, + avg_yoy_growth_score as avg_yoy_growth_score, + avg_growth_score as avg_growth_score, + weighted_avg_growth_score as weighted_avg_growth_score, + + categorisation_weighted_avg_growth_score as categorisation_weighted_avg_growth_score + +from int_monthly_growth_score_by_deal diff --git a/models/reporting/general/schema.yml b/models/reporting/general/schema.yml index 53a2ec7..6cac0b4 100644 --- a/models/reporting/general/schema.yml +++ b/models/reporting/general/schema.yml @@ -514,3 +514,520 @@ models: description: day monthly number of the given date. tests: - not_null + + - name: monthly_growth_score_by_deal + 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 + associated to it over the months, and that comparing how it is currently + performing vs. historical data we can determine whether the tendency is to + grow or to decay. This is specially useful for AMs to focus their effort + towards the clients that have a negative tendency. + + The computation of the growth score is based on 3 main indicators: + - Created bookings + - Listings booked in month + - Total revenue (in gbp) + + The main idea is, for each deal, to compare each of these metrics by + 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 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. + + However, this is not strictly true for Revenue because 1) we have an invoicing + delay and 2) in some cases, monthly revenue per deal can be negative. In this + specific cases, the YoY comparison is shifted by one month, and an effective + revenue value for the revenue share is computed, that cannot be lower than 0. + + In order to keep both a properly set up score and revenue consistency, both + a real revenue value and effective revenue value are present in this model, + while no MoM or YoY value is computed if negative revenue is found. + + Lastly, this model provides informative date fields, deal attributes, absolute + metric values and MoM & YoY relative incrementals to enrich reporting. + + tests: + - dbt_utils.unique_combination_of_columns: + combination_of_columns: + - date + - id_deal + + columns: + - name: date + data_type: date + description: | + Date corresponding to the last day of the month. Given month + metrics are inclusive to this date. Together with id_deal, it + acts as the primary key of this model. + tests: + - not_null + + - name: id_deal + data_type: string + description: | + Unique identifier of a Deal. Together with date, it acts as + the primary key of this model. + tests: + - not_null + + - name: main_deal_name + data_type: string + description: | + Main name for a Deal, representing the client. + tests: + - not_null + + - name: main_billing_country_iso_3_per_deal + data_type: string + description: | + Main billing country for this client. In some cases + it can be null. + + - name: deal_lifecycle_state + data_type: string + description: | + Identifier of the lifecycle state of a given deal + in a given month. + + - name: given_month_first_day_month + data_type: date + description: | + Informative field. It indicates the first day of the + month corresponding to date. + If date = 2024-09-30, this field will be 2024-09-01. + tests: + - not_null + + - name: previous_1_month_first_day_month + data_type: date + description: | + Informative field. It indicates the first day of the + previous month with respect to date. + If date = 2024-09-30, this field will be 2024-08-01. + 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: | + Informative field. It indicates the first day of the + month with respect to date, but on the previous year. + If date = 2024-09-30, this field will be 2023-09-01. + It can be null if no previous history for that + deal is found. + + - name: previous_13_month_first_day_month + data_type: date + description: | + Informative field. It indicates the first day of the + previous month with respect to date, but on the previous year. + If date = 2024-09-30, this field will be 2023-08-01. + It can be null if no previous history for that + deal is found. + + - name: aggregated_revenue_from_first_day_month + data_type: date + description: | + Informative field. It indicates the first day of the + month from the lower bound range in which the revenue + aggregation is computed. + The aggregation uses the previous 12 months in which we + know the revenue, thus: + If date = 2024-09-30, this field will be 2023-09-01. + It can be null if no previous history for that + deal is found. + + - name: aggregated_revenue_to_first_day_month + data_type: date + description: | + Informative field. It indicates the first day of the + month from the upper bound range in which the revenue + aggregation is computed. + The aggregation uses the previous 12 months in which we + know the revenue, thus: + If date = 2024-09-30, this field will be 2023-08-01. + It can be null if no previous history for that + deal is found. + + - name: given_month_revenue_in_gbp + data_type: decimal + description: | + Monthly value representing revenue in GBP + for a specific deal. This value corresponds to + the given month. This value can be negative, + but not null. + tests: + - not_null + + - name: previous_1_month_revenue_in_gbp + data_type: decimal + description: | + Monthly value representing revenue in GBP + for a specific deal. This value corresponds to + the previous month. + This value can be negative. + 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 + the monthly amount generated 12 months ago. + This value can be negative. + This value can be null, thus indicating that no + history is available. + + - name: previous_13_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 13 months ago. + This value can be negative. + This value can be null, thus indicating that no + history is available. + + - name: mom_revenue_growth + data_type: decimal + description: | + Relative increment of the revenue generated in the + current month with respect to the one generated in + the previous month. + It can be null if any revenue used in the computation + is null or it's negative. + tests: + - dbt_expectations.expect_column_values_to_be_between: + 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: | + Relative increment of the revenue generated in the + current month with respect to the one generated 12 + months ago. + It can be null if any revenue used in the computation + is null or it's negative. + tests: + - dbt_expectations.expect_column_values_to_be_between: + min_value: -1 + strictly: false + + - name: yoy_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 13 + 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: given_month_created_bookings + data_type: integer + description: | + Monthly value representing created bookings + for a specific deal. This value corresponds to + the given month. This value cannot be null. + tests: + - not_null + - dbt_expectations.expect_column_values_to_be_between: + min_value: 0 + strictly: false + + - name: previous_1_month_created_bookings + data_type: integer + description: | + Monthly value representing created bookings + for a specific deal. This value corresponds to + the previous month. + This value can be null, thus indicating that no + history is available. + tests: + - dbt_expectations.expect_column_values_to_be_between: + min_value: 0 + strictly: false + + - name: previous_12_month_created_bookings + data_type: integer + description: | + Monthly value representing created bookings + for a specific deal. This value corresponds to + monthly amount generated 12 months ago. + This value can be null, thus indicating that no + history is available. + tests: + - dbt_expectations.expect_column_values_to_be_between: + min_value: 0 + strictly: false + + - name: mom_created_bookings_growth + data_type: decimal + description: | + Relative increment of the bookings created in the + current month with respect to the ones created in + 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 + strictly: false + + - name: yoy_created_bookings_growth + data_type: decimal + description: | + Relative increment of the bookings created in the + current month with respect to the ones created 12 + months ago. + It can be null if the bookings created 12 months + ago are null. + This field is used for the growth score computation. + tests: + - dbt_expectations.expect_column_values_to_be_between: + min_value: -1 + strictly: false + + - name: given_month_listings_booked_in_month + data_type: integer + description: | + Monthly value representing the listings booked in month + for a specific deal. This value corresponds to + the given month. This value cannot be null. + tests: + - not_null + - dbt_expectations.expect_column_values_to_be_between: + min_value: 0 + strictly: false + + - name: previous_1_month_listings_booked_in_month + data_type: integer + description: | + Monthly value representing the listings booked in month + for a specific deal. This value corresponds to + the previous month. + This value can be null, thus indicating that no + history is available. + tests: + - dbt_expectations.expect_column_values_to_be_between: + min_value: 0 + strictly: false + + - name: previous_12_month_listings_booked_in_month + data_type: integer + description: | + Monthly value representing the listings booked in month + for a specific deal. This value corresponds to + monthly amount generated 12 months ago. + This value can be null, thus indicating that no + history is available. + tests: + - dbt_expectations.expect_column_values_to_be_between: + min_value: 0 + strictly: false + + - name: mom_listings_booked_in_month_growth + data_type: decimal + description: | + Relative increment of the the listings booked in month + in the current month with respect to the ones of + 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 + strictly: false + + - name: yoy_listings_booked_in_month_growth + data_type: decimal + description: | + Relative increment of the listings booked in month + in the current month with respect to the ones of 12 + months ago. + It can be null if the listings booked in month of 12 + months ago are null. + This field is used for the growth score computation. + tests: + - dbt_expectations.expect_column_values_to_be_between: + min_value: -1 + strictly: false + + - name: deal_revenue_12_months_window + data_type: decimal + description: | + Total aggregated revenue in GBP 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 can be negative if the sum is negative. + It cannot be null. + tests: + - not_null + + - name: effective_deal_revenue_12_months_window + data_type: decimal + description: | + Effective aggregated revenue in GBP 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. + All negative monthly revenue values are settled as 0, + thus this value should not be reported. + It is used for the deal contribution share with respect + to the global revenue. It cannot be null. + tests: + - not_null + - dbt_expectations.expect_column_values_to_be_between: + min_value: 0 + strictly: false + + - name: effective_global_revenue_12_months_window + data_type: decimal + description: | + Effective aggregated revenue in GBP generated by all deals + in the months from the period ranging from the + aggregated_revenue_from_first_day_month to + aggregated_revenue_to_first_day_month. + All negative monthly revenue values are settled as 0, + thus this value should not be reported. + It is used for the deal contribution share with respect + to the global revenue. 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_revenue + data_type: decimal + description: | + Represents the size of the deal in terms of revenue. In + other words, what's the percentage of the global revenue + 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_revenue + 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. + It cannot be null. + tests: + - not_null + + - 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 + bookings, YoY growth of listings booked in month and + YoY 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_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: | + It's the weighted version of avg_growth_score that + takes into account the client size by using the revenue + contribution share of that deal to the global amount. + It's the main indicator towards measuring both growth + (if positive) or decay (if negative) while weighting + 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