Merged PR 5296: Drop Monthly Growth Score By Deal legacy models
# Description Drop Monthly Growth Score By Deal legacy models in Intermediate and Reporting. This includes schema entries. These models were already identified as to be deprecated on the 23rd May 2025, so, today. # Checklist - [X] Project compiles, no additional warning is raised. Related work items: #29826
This commit is contained in:
parent
e6819f05cc
commit
14c099b6b2
4 changed files with 0 additions and 1913 deletions
|
|
@ -1,475 +0,0 @@
|
|||
{{ config(materialized="table", unique_key=["date", "id_deal"]) }}
|
||||
with
|
||||
int_kpis__dimension_deals as (select * from {{ ref("int_kpis__dimension_deals") }}),
|
||||
int_hubspot__deal as (select * from {{ ref("int_hubspot__deal") }}),
|
||||
int_kpis__lifecycle_daily_deal as (
|
||||
select * from {{ ref("int_kpis__lifecycle_daily_deal") }}
|
||||
),
|
||||
int_kpis__agg_dates_main_kpis as (
|
||||
select *
|
||||
from {{ ref("int_kpis__agg_dates_main_kpis") }}
|
||||
where
|
||||
dimension in ('by_deal')
|
||||
and dimension_value <> 'UNSET'
|
||||
and is_end_of_month = true
|
||||
),
|
||||
created_bookings as (
|
||||
select *
|
||||
from {{ ref("int_kpis__agg_monthly_created_bookings") }}
|
||||
where dimension in ('by_deal') and dimension_value <> 'UNSET'
|
||||
),
|
||||
listings as (
|
||||
select *
|
||||
from {{ ref("int_kpis__agg_daily_listings") }}
|
||||
where
|
||||
dimension in ('by_deal')
|
||||
and dimension_value <> 'UNSET'
|
||||
and is_end_of_month = true
|
||||
),
|
||||
total_and_retained_revenue as (
|
||||
select *
|
||||
from {{ ref("int_kpis__agg_monthly_total_and_retained_revenue") }}
|
||||
where dimension in ('by_deal') and dimension_value <> 'UNSET'
|
||||
),
|
||||
deal_history_from_previous_months as (
|
||||
select
|
||||
d.year,
|
||||
d.month,
|
||||
d.date,
|
||||
date_trunc('month', d.date)::date as first_day_month,
|
||||
d.dimension_value as id_deal,
|
||||
-- DEAL LIFECYCLE --
|
||||
deal_lifecycle.deal_lifecycle_state,
|
||||
-- METRICS --
|
||||
coalesce(
|
||||
total_and_retained_revenue.total_revenue_in_gbp, 0
|
||||
) as revenue_in_gbp,
|
||||
coalesce(created_bookings.created_bookings, 0) as created_bookings,
|
||||
coalesce(listings.listings_booked_in_month, 0) as listings_booked_in_month
|
||||
from int_kpis__agg_dates_main_kpis d
|
||||
left join
|
||||
int_kpis__lifecycle_daily_deal deal_lifecycle
|
||||
on d.date = deal_lifecycle.date
|
||||
and d.dimension_value = deal_lifecycle.id_deal
|
||||
left join
|
||||
created_bookings
|
||||
on d.date = created_bookings.end_date
|
||||
and d.dimension_value = created_bookings.dimension_value
|
||||
left join
|
||||
listings
|
||||
on d.date = listings.date
|
||||
and d.dimension_value = listings.dimension_value
|
||||
left join
|
||||
total_and_retained_revenue
|
||||
on d.date = total_and_retained_revenue.end_date
|
||||
and d.dimension_value = total_and_retained_revenue.dimension_value
|
||||
|
||||
-- Do not show data of ongoing month
|
||||
where d.date < date_trunc('month', current_date)::date
|
||||
),
|
||||
revenue_12_months_window_aggregation_per_deal as (
|
||||
select
|
||||
first_day_month,
|
||||
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_avg_listings_booked_in_month_12_months_window,
|
||||
sum(deal_avg_listings_booked_in_month_12_months_window) over (
|
||||
partition by first_day_month
|
||||
) as global_avg_listings_booked_in_month_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, id_deal
|
||||
) as deal_contribution_rank_to_global_created_bookings,
|
||||
row_number() over (
|
||||
partition by first_day_month
|
||||
order by
|
||||
deal_avg_listings_booked_in_month_12_months_window desc, id_deal
|
||||
) as deal_contribution_rank_to_global_avg_listings_booked_in_month,
|
||||
row_number() over (
|
||||
partition by first_day_month
|
||||
order by deal_revenue_12_months_window desc, id_deal
|
||||
) as deal_contribution_rank_to_global_revenue
|
||||
from
|
||||
(
|
||||
select
|
||||
given_month.first_day_month,
|
||||
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(
|
||||
avg(previous_twelve_months.listings_booked_in_month), 0
|
||||
) as deal_avg_listings_booked_in_month_12_months_window,
|
||||
coalesce(
|
||||
sum(previous_twelve_months.revenue_in_gbp), 0
|
||||
) as deal_revenue_12_months_window,
|
||||
greatest(
|
||||
coalesce(sum(previous_twelve_months.revenue_in_gbp), 0), 0
|
||||
) as effective_deal_revenue_12_months_window
|
||||
from deal_history_from_previous_months as given_month
|
||||
-- Retrieve aggregated data from same deal from the previous twelve
|
||||
-- months
|
||||
left join
|
||||
deal_history_from_previous_months as previous_twelve_months
|
||||
on given_month.id_deal = previous_twelve_months.id_deal
|
||||
and previous_twelve_months.first_day_month + interval '12 months'
|
||||
>= given_month.first_day_month
|
||||
and given_month.first_day_month
|
||||
>= previous_twelve_months.first_day_month + interval '1 months'
|
||||
group by 1, 2
|
||||
) as aggregated_revenue_data_before_partition
|
||||
),
|
||||
metrics_attribution_to_given_month_per_deal as (
|
||||
select
|
||||
-- Primary Key (date, id_deal)
|
||||
given_month.date,
|
||||
given_month.id_deal,
|
||||
|
||||
-- Deal Dynamic Attributes
|
||||
given_month.deal_lifecycle_state,
|
||||
|
||||
-- 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_12m_window.from_first_day_month
|
||||
as aggregated_revenue_from_first_day_month,
|
||||
aggregated_12m_window.to_first_day_month
|
||||
as aggregated_revenue_to_first_day_month,
|
||||
|
||||
-- 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,
|
||||
-- no value is reported. This is because otherwise relative increments
|
||||
-- are wrong.
|
||||
greatest(given_month.revenue_in_gbp, 0)
|
||||
/ nullif(greatest(previous_1_month.revenue_in_gbp, 0), 0)
|
||||
- 1 as mom_revenue_growth,
|
||||
greatest(previous_1_month.revenue_in_gbp, 0)
|
||||
/ nullif(greatest(previous_2_month.revenue_in_gbp, 0), 0)
|
||||
- 1 as mom_1_month_shift_revenue_growth,
|
||||
greatest(given_month.revenue_in_gbp, 0)
|
||||
/ nullif(greatest(previous_12_month.revenue_in_gbp, 0), 0)
|
||||
- 1 as yoy_revenue_growth,
|
||||
greatest(previous_1_month.revenue_in_gbp, 0)
|
||||
/ nullif(greatest(previous_13_month.revenue_in_gbp, 0), 0)
|
||||
- 1 as yoy_1_month_shift_revenue_growth,
|
||||
|
||||
-- Created Bookings --
|
||||
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,
|
||||
cast(given_month.created_bookings as decimal)
|
||||
/ nullif(previous_1_month.created_bookings, 0)
|
||||
- 1 as mom_created_bookings_growth,
|
||||
cast(given_month.created_bookings as decimal)
|
||||
/ nullif(previous_12_month.created_bookings, 0)
|
||||
- 1 as yoy_created_bookings_growth,
|
||||
|
||||
-- Listings Booked in Month --
|
||||
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,
|
||||
cast(given_month.listings_booked_in_month as decimal)
|
||||
/ nullif(previous_1_month.listings_booked_in_month, 0)
|
||||
- 1 as mom_listings_booked_in_month_growth,
|
||||
cast(given_month.listings_booked_in_month as decimal)
|
||||
/ nullif(previous_12_month.listings_booked_in_month, 0)
|
||||
- 1 as yoy_listings_booked_in_month_growth,
|
||||
|
||||
-- 12 Months Window (Account Size) --
|
||||
-- Bookings --
|
||||
aggregated_12m_window.deal_created_bookings_12_months_window,
|
||||
aggregated_12m_window.global_created_bookings_12_months_window,
|
||||
coalesce(
|
||||
cast(
|
||||
aggregated_12m_window.deal_created_bookings_12_months_window
|
||||
as decimal
|
||||
) / nullif(
|
||||
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,
|
||||
|
||||
-- Listings --
|
||||
round(
|
||||
aggregated_12m_window.deal_avg_listings_booked_in_month_12_months_window,
|
||||
2
|
||||
) as deal_avg_listings_booked_in_month_12_months_window,
|
||||
round(
|
||||
aggregated_12m_window.global_avg_listings_booked_in_month_12_months_window,
|
||||
2
|
||||
) as global_avg_listings_booked_in_month_12_months_window,
|
||||
coalesce(
|
||||
cast(
|
||||
aggregated_12m_window.deal_avg_listings_booked_in_month_12_months_window
|
||||
as decimal
|
||||
) / nullif(
|
||||
aggregated_12m_window.global_avg_listings_booked_in_month_12_months_window,
|
||||
0
|
||||
),
|
||||
0
|
||||
) as deal_contribution_share_to_global_avg_listings_booked_in_month,
|
||||
aggregated_12m_window.deal_contribution_rank_to_global_avg_listings_booked_in_month,
|
||||
|
||||
-- Revenue --
|
||||
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_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
|
||||
left join
|
||||
deal_history_from_previous_months as previous_1_month
|
||||
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
|
||||
deal_history_from_previous_months as previous_12_month
|
||||
on previous_12_month.first_day_month + interval '12 months'
|
||||
= 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
|
||||
left join
|
||||
deal_history_from_previous_months as previous_13_month
|
||||
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 aggregation over 12 previous months
|
||||
left join
|
||||
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
|
||||
m.date,
|
||||
m.id_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,
|
||||
m.mom_revenue_growth,
|
||||
m.mom_1_month_shift_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_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_avg_listings_booked_in_month_12_months_window,
|
||||
m.global_avg_listings_booked_in_month_12_months_window,
|
||||
m.deal_contribution_share_to_global_avg_listings_booked_in_month,
|
||||
m.deal_contribution_rank_to_global_avg_listings_booked_in_month,
|
||||
|
||||
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,
|
||||
|
||||
round(
|
||||
100 * (
|
||||
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,
|
||||
6
|
||||
) as avg_mom_growth_score,
|
||||
|
||||
round(
|
||||
100 * (
|
||||
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,
|
||||
6
|
||||
) as avg_yoy_growth_score,
|
||||
|
||||
round(
|
||||
100 * (
|
||||
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,
|
||||
6
|
||||
) as avg_growth_score,
|
||||
round(
|
||||
1000 * (
|
||||
(
|
||||
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,
|
||||
6
|
||||
) as weighted_avg_growth_score
|
||||
|
||||
from metrics_attribution_to_given_month_per_deal m
|
||||
)
|
||||
select
|
||||
gsc.date,
|
||||
gsc.id_deal,
|
||||
|
||||
-- DEAL STATIC ATTRIBUTES --
|
||||
ikdd.client_type,
|
||||
ikdd.main_deal_name,
|
||||
ikdd.has_active_pms,
|
||||
ikdd.active_pms_list,
|
||||
ikdd.main_billing_country_iso_3_per_deal,
|
||||
|
||||
-- DEAL LIFECYCLE --
|
||||
gsc.deal_lifecycle_state,
|
||||
|
||||
-- DEAL HUBSPOT ATTRIBUTES --
|
||||
d.deal_hubspot_stage,
|
||||
d.account_manager,
|
||||
d.live_date_utc,
|
||||
d.cancellation_date_utc,
|
||||
|
||||
gsc.given_month_first_day_month,
|
||||
gsc.previous_1_month_first_day_month,
|
||||
gsc.previous_2_month_first_day_month,
|
||||
gsc.previous_12_month_first_day_month,
|
||||
gsc.previous_13_month_first_day_month,
|
||||
gsc.aggregated_revenue_from_first_day_month,
|
||||
gsc.aggregated_revenue_to_first_day_month,
|
||||
|
||||
gsc.given_month_revenue_in_gbp,
|
||||
gsc.previous_1_month_revenue_in_gbp,
|
||||
gsc.previous_2_month_revenue_in_gbp,
|
||||
gsc.previous_12_month_revenue_in_gbp,
|
||||
gsc.previous_13_month_revenue_in_gbp,
|
||||
gsc.mom_revenue_growth,
|
||||
gsc.mom_1_month_shift_revenue_growth,
|
||||
gsc.yoy_revenue_growth,
|
||||
gsc.yoy_1_month_shift_revenue_growth,
|
||||
|
||||
gsc.given_month_created_bookings,
|
||||
gsc.previous_1_month_created_bookings,
|
||||
gsc.previous_12_month_created_bookings,
|
||||
gsc.mom_created_bookings_growth,
|
||||
gsc.yoy_created_bookings_growth,
|
||||
|
||||
gsc.given_month_listings_booked_in_month,
|
||||
gsc.previous_1_month_listings_booked_in_month,
|
||||
gsc.previous_12_month_listings_booked_in_month,
|
||||
gsc.mom_listings_booked_in_month_growth,
|
||||
gsc.yoy_listings_booked_in_month_growth,
|
||||
|
||||
gsc.deal_created_bookings_12_months_window,
|
||||
gsc.global_created_bookings_12_months_window,
|
||||
gsc.deal_contribution_share_to_global_created_bookings,
|
||||
gsc.deal_contribution_rank_to_global_created_bookings,
|
||||
|
||||
gsc.deal_avg_listings_booked_in_month_12_months_window,
|
||||
gsc.global_avg_listings_booked_in_month_12_months_window,
|
||||
gsc.deal_contribution_share_to_global_avg_listings_booked_in_month,
|
||||
gsc.deal_contribution_rank_to_global_avg_listings_booked_in_month,
|
||||
|
||||
gsc.deal_revenue_12_months_window,
|
||||
gsc.effective_deal_revenue_12_months_window,
|
||||
gsc.effective_global_revenue_12_months_window,
|
||||
gsc.deal_contribution_share_to_global_revenue,
|
||||
gsc.deal_contribution_rank_to_global_revenue,
|
||||
gsc.avg_mom_growth_score,
|
||||
gsc.avg_yoy_growth_score,
|
||||
gsc.avg_growth_score,
|
||||
gsc.weighted_avg_growth_score,
|
||||
|
||||
-- Applies a categorisation based on the score value. These scores thresholds are
|
||||
-- opinionated
|
||||
case
|
||||
when gsc.weighted_avg_growth_score <= -1.0
|
||||
then 'MAJOR DECLINE'
|
||||
when gsc.weighted_avg_growth_score > -1.0 and gsc.weighted_avg_growth_score < 0
|
||||
then 'DECLINE'
|
||||
when gsc.weighted_avg_growth_score = 0
|
||||
then 'FLAT'
|
||||
when gsc.weighted_avg_growth_score > 0 and gsc.weighted_avg_growth_score < 1.0
|
||||
then 'GAIN'
|
||||
when gsc.weighted_avg_growth_score >= 1.0
|
||||
then 'MAJOR GAIN'
|
||||
else 'UNSET'
|
||||
end as categorisation_weighted_avg_growth_score
|
||||
from growth_score_computation gsc
|
||||
left join int_kpis__dimension_deals ikdd on gsc.id_deal = ikdd.id_deal
|
||||
left join int_hubspot__deal d on gsc.id_deal = d.id_deal
|
||||
|
|
@ -350,679 +350,6 @@ models:
|
|||
positive impact for Superhog, otherwise is equal to relative_increment.
|
||||
This value is specially created for formatting in PBI
|
||||
|
||||
- name: int_monthly_growth_score_by_deal
|
||||
deprecation_date: 2025-05-23 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
|
||||
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.
|
||||
|
||||
data_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.
|
||||
data_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.
|
||||
data_tests:
|
||||
- not_null
|
||||
|
||||
- name: client_type
|
||||
data_type: string
|
||||
description: |
|
||||
Type of client. It can be either PLATFORM or API.
|
||||
data_tests:
|
||||
- not_null
|
||||
- accepted_values:
|
||||
values:
|
||||
- PLATFORM
|
||||
- API
|
||||
|
||||
- name: main_deal_name
|
||||
data_type: string
|
||||
description: |
|
||||
Main name for a Deal, representing the client.
|
||||
data_tests:
|
||||
- not_null
|
||||
|
||||
- name: has_active_pms
|
||||
data_type: boolean
|
||||
description: |
|
||||
Does the deal have an active associated PMS.
|
||||
data_tests:
|
||||
- not_null
|
||||
|
||||
- name: active_pms_list
|
||||
data_type: string
|
||||
description: |
|
||||
Name of the active PMS associated with the deal. It can have more than
|
||||
one PMS associated with it. It can be null if it doesn't have any PMS associated.
|
||||
|
||||
- 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: deal_hubspot_stage
|
||||
data_type: string
|
||||
description: |
|
||||
Current hubspot stage for a given deal.
|
||||
|
||||
- name: account_manager
|
||||
data_type: string
|
||||
description: |
|
||||
Current Account Manager in charge of a given deal, according
|
||||
to Hubspot.
|
||||
|
||||
- name: live_date_utc
|
||||
data_type: date
|
||||
description: |
|
||||
Date in which the account has gone live, according to Hubspot.
|
||||
|
||||
- name: cancellation_date_utc
|
||||
data_type: date
|
||||
description: |
|
||||
Date in which the account has been offboarded, according to
|
||||
Hubspot.
|
||||
|
||||
- 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.
|
||||
data_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.
|
||||
data_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.
|
||||
data_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.
|
||||
data_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.
|
||||
data_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.
|
||||
data_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.
|
||||
data_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.
|
||||
data_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.
|
||||
data_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.
|
||||
data_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.
|
||||
data_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.
|
||||
data_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.
|
||||
data_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.
|
||||
data_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.
|
||||
data_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.
|
||||
data_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.
|
||||
data_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.
|
||||
data_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.
|
||||
data_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.
|
||||
data_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.
|
||||
If more than one deal have the same share, the order is
|
||||
not under control.
|
||||
It cannot be null.
|
||||
data_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.
|
||||
data_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 any 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.
|
||||
data_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.
|
||||
data_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.
|
||||
data_tests:
|
||||
- not_null
|
||||
|
||||
- name: deal_avg_listings_booked_in_month_12_months_window
|
||||
data_type: decimal
|
||||
description: |
|
||||
Average listings booked in month 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.
|
||||
data_tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_between:
|
||||
min_value: 0
|
||||
strictly: false
|
||||
|
||||
- name: global_avg_listings_booked_in_month_12_months_window
|
||||
data_type: decimal
|
||||
description: |
|
||||
Sum of the average listings booked in month by
|
||||
any 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 average listings booked in month.
|
||||
It cannot be null.
|
||||
data_tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_between:
|
||||
min_value: 0
|
||||
strictly: false
|
||||
|
||||
- name: deal_contribution_share_to_global_avg_listings_booked_in_month
|
||||
data_type: decimal
|
||||
description: |
|
||||
Represents the size of the deal in terms of average listings
|
||||
booked in month.
|
||||
In other words, what's the percentage of the global average listings
|
||||
booked in month that can be attributed to this deal.
|
||||
It cannot be null.
|
||||
data_tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_between:
|
||||
min_value: 0
|
||||
strictly: false
|
||||
|
||||
- name: deal_contribution_rank_to_global_avg_listings_booked_in_month
|
||||
data_type: decimal
|
||||
description: |
|
||||
Represents the ordered list of deals by descending size
|
||||
in terms of average listings booked in month.
|
||||
If more than one deal have the same share, the order is
|
||||
not under control.
|
||||
It cannot be null.
|
||||
data_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.
|
||||
data_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.
|
||||
data_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.
|
||||
data_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.
|
||||
data_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.
|
||||
data_tests:
|
||||
- not_null
|
||||
- accepted_values:
|
||||
values:
|
||||
- MAJOR DECLINE
|
||||
- DECLINE
|
||||
- FLAT
|
||||
- GAIN
|
||||
- MAJOR GAIN
|
||||
- UNSET
|
||||
|
||||
- name: int_edeposit_and_athena_verifications
|
||||
description:
|
||||
"This table holds records on verifications for Guesty and Edeposit bookings.
|
||||
|
|
|
|||
|
|
@ -1,85 +0,0 @@
|
|||
with
|
||||
int_monthly_growth_score_by_deal as (
|
||||
select * from {{ ref("int_monthly_growth_score_by_deal") }}
|
||||
)
|
||||
select
|
||||
date as date,
|
||||
date_trunc('month', date)::date as first_day_month,
|
||||
id_deal as id_deal,
|
||||
client_type as client_type,
|
||||
main_deal_name as main_deal_name,
|
||||
has_active_pms as has_active_pms,
|
||||
active_pms_list as active_pms_list,
|
||||
main_billing_country_iso_3_per_deal as main_billing_country_iso_3_per_deal,
|
||||
deal_lifecycle_state as deal_lifecycle_state,
|
||||
deal_hubspot_stage as deal_hubspot_stage,
|
||||
account_manager as account_manager,
|
||||
live_date_utc as live_date_utc,
|
||||
cancellation_date_utc as cancellation_date_utc,
|
||||
|
||||
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_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_avg_listings_booked_in_month_12_months_window
|
||||
as deal_avg_listings_booked_in_month_12_months_window,
|
||||
global_avg_listings_booked_in_month_12_months_window
|
||||
as global_avg_listings_booked_in_month_12_months_window,
|
||||
deal_contribution_share_to_global_avg_listings_booked_in_month
|
||||
as deal_contribution_share_to_global_avg_listings_booked_in_month,
|
||||
deal_contribution_rank_to_global_avg_listings_booked_in_month
|
||||
as deal_contribution_rank_to_global_avg_listings_booked_in_month,
|
||||
|
||||
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
|
||||
|
|
@ -458,686 +458,6 @@ models:
|
|||
positive impact for Truvi, otherwise is equal to relative_increment.
|
||||
This value is specially created for formatting in PBI
|
||||
|
||||
- name: monthly_growth_score_by_deal
|
||||
deprecation_date: 2025-05-23 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
|
||||
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.
|
||||
|
||||
data_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.
|
||||
data_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.
|
||||
data_tests:
|
||||
- not_null
|
||||
|
||||
- name: first_day_month
|
||||
data_type: date
|
||||
description: |
|
||||
First day of the month corresponding to the date field.
|
||||
data_tests:
|
||||
- not_null
|
||||
|
||||
- name: client_type
|
||||
data_type: string
|
||||
description: |
|
||||
Type of client. It can be either PLATFORM or API.
|
||||
data_tests:
|
||||
- not_null
|
||||
- accepted_values:
|
||||
values:
|
||||
- PLATFORM
|
||||
- API
|
||||
|
||||
- name: main_deal_name
|
||||
data_type: string
|
||||
description: |
|
||||
Main name for a Deal, representing the client.
|
||||
data_tests:
|
||||
- not_null
|
||||
|
||||
- name: has_active_pms
|
||||
data_type: boolean
|
||||
description: |
|
||||
Does the deal have an active associated PMS.
|
||||
data_tests:
|
||||
- not_null
|
||||
|
||||
- name: active_pms_list
|
||||
data_type: string
|
||||
description: |
|
||||
Name of the active PMS associated with the deal. It can have more than
|
||||
one PMS associated with it. It can be null if it doesn't have any PMS associated.
|
||||
|
||||
- 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: deal_hubspot_stage
|
||||
data_type: string
|
||||
description: |
|
||||
Current hubspot stage for a given deal.
|
||||
|
||||
- name: account_manager
|
||||
data_type: string
|
||||
description: |
|
||||
Current Account Manager in charge of a given deal, according
|
||||
to Hubspot.
|
||||
|
||||
- name: live_date_utc
|
||||
data_type: date
|
||||
description: |
|
||||
Date in which the account has gone live, according to Hubspot.
|
||||
|
||||
- name: cancellation_date_utc
|
||||
data_type: date
|
||||
description: |
|
||||
Date in which the account has been offboarded, according to
|
||||
Hubspot.
|
||||
|
||||
- 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.
|
||||
data_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.
|
||||
data_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.
|
||||
data_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.
|
||||
data_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.
|
||||
data_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.
|
||||
data_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.
|
||||
data_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.
|
||||
data_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.
|
||||
data_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.
|
||||
data_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.
|
||||
data_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.
|
||||
data_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.
|
||||
data_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.
|
||||
data_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.
|
||||
data_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.
|
||||
data_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.
|
||||
data_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.
|
||||
data_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.
|
||||
data_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.
|
||||
data_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.
|
||||
If more than one deal have the same share, the order is
|
||||
not under control.
|
||||
It cannot be null.
|
||||
data_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.
|
||||
data_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 any 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.
|
||||
data_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.
|
||||
data_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.
|
||||
data_tests:
|
||||
- not_null
|
||||
|
||||
- name: deal_avg_listings_booked_in_month_12_months_window
|
||||
data_type: decimal
|
||||
description: |
|
||||
Average listings booked in month 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.
|
||||
data_tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_between:
|
||||
min_value: 0
|
||||
strictly: false
|
||||
|
||||
- name: global_avg_listings_booked_in_month_12_months_window
|
||||
data_type: decimal
|
||||
description: |
|
||||
Sum of the average listings booked in month by
|
||||
any 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 average listings booked in month.
|
||||
It cannot be null.
|
||||
data_tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_between:
|
||||
min_value: 0
|
||||
strictly: false
|
||||
|
||||
- name: deal_contribution_share_to_global_avg_listings_booked_in_month
|
||||
data_type: decimal
|
||||
description: |
|
||||
Represents the size of the deal in terms of average listings
|
||||
booked in month.
|
||||
In other words, what's the percentage of the global average listings
|
||||
booked in month that can be attributed to this deal.
|
||||
It cannot be null.
|
||||
data_tests:
|
||||
- not_null
|
||||
- dbt_expectations.expect_column_values_to_be_between:
|
||||
min_value: 0
|
||||
strictly: false
|
||||
|
||||
- name: deal_contribution_rank_to_global_avg_listings_booked_in_month
|
||||
data_type: decimal
|
||||
description: |
|
||||
Represents the ordered list of deals by descending size
|
||||
in terms of average listings booked in month.
|
||||
If more than one deal have the same share, the order is
|
||||
not under control.
|
||||
It cannot be null.
|
||||
data_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.
|
||||
data_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.
|
||||
data_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.
|
||||
data_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.
|
||||
data_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.
|
||||
data_tests:
|
||||
- not_null
|
||||
- accepted_values:
|
||||
values:
|
||||
- MAJOR DECLINE
|
||||
- DECLINE
|
||||
- FLAT
|
||||
- GAIN
|
||||
- MAJOR GAIN
|
||||
- UNSET
|
||||
|
||||
- name: new_dash_booking_summary
|
||||
description: |
|
||||
This model contains enriched information aggregated at Booking level regarding
|
||||
|
|
|
|||
Loading…
Add table
Add a link
Reference in a new issue