Merged PR 5012: Small refactor on Growth Score
# Description Small refactor on Growth Score model. It just handles the dimension deals attributes at the end instead of having these in each CTE. I also forced a partition ordered by deal AFTER the current ordering. This is a side effect because SQL randomly choses a value if the value being used to order was exactly the same (ex: revenue = 0). This was causing issues when auditing the refactor. # Checklist - [X] The edited models and dependants run properly with production data. - [X] The edited models are sufficiently documented. - [X] The edited models contain PK tests, and I've ran and passed them. - [ ] I have checked for DRY opportunities with other models and docs. - [ ] I've picked the right materialization for the affected models. # Other - [ ] Check if a full-refresh is required after this PR is merged. Related work items: #29374
This commit is contained in:
parent
6e354e7df1
commit
45514dcd6a
1 changed files with 18 additions and 27 deletions
|
|
@ -37,13 +37,7 @@ with
|
||||||
d.month,
|
d.month,
|
||||||
d.date,
|
d.date,
|
||||||
date_trunc('month', d.date)::date as first_day_month,
|
date_trunc('month', d.date)::date as first_day_month,
|
||||||
-- DEAL STATIC ATTRIBUTES --
|
d.dimension_value as id_deal,
|
||||||
ikdd.id_deal,
|
|
||||||
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 --
|
-- DEAL LIFECYCLE --
|
||||||
deal_lifecycle.deal_lifecycle_state,
|
deal_lifecycle.deal_lifecycle_state,
|
||||||
-- METRICS --
|
-- METRICS --
|
||||||
|
|
@ -53,7 +47,6 @@ with
|
||||||
coalesce(created_bookings.created_bookings, 0) as created_bookings,
|
coalesce(created_bookings.created_bookings, 0) as created_bookings,
|
||||||
coalesce(listings.listings_booked_in_month, 0) as listings_booked_in_month
|
coalesce(listings.listings_booked_in_month, 0) as listings_booked_in_month
|
||||||
from int_kpis__agg_dates_main_kpis d
|
from int_kpis__agg_dates_main_kpis d
|
||||||
left join int_kpis__dimension_deals ikdd on d.dimension_value = ikdd.id_deal
|
|
||||||
left join
|
left join
|
||||||
int_kpis__lifecycle_daily_deal deal_lifecycle
|
int_kpis__lifecycle_daily_deal deal_lifecycle
|
||||||
on d.date = deal_lifecycle.date
|
on d.date = deal_lifecycle.date
|
||||||
|
|
@ -95,14 +88,16 @@ with
|
||||||
) as effective_global_revenue_12_months_window,
|
) as effective_global_revenue_12_months_window,
|
||||||
row_number() over (
|
row_number() over (
|
||||||
partition by first_day_month
|
partition by first_day_month
|
||||||
order by deal_created_bookings_12_months_window desc
|
order by deal_created_bookings_12_months_window desc, id_deal
|
||||||
) as deal_contribution_rank_to_global_created_bookings,
|
) as deal_contribution_rank_to_global_created_bookings,
|
||||||
row_number() over (
|
row_number() over (
|
||||||
partition by first_day_month
|
partition by first_day_month
|
||||||
order by deal_avg_listings_booked_in_month_12_months_window desc
|
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,
|
) as deal_contribution_rank_to_global_avg_listings_booked_in_month,
|
||||||
row_number() over (
|
row_number() over (
|
||||||
partition by first_day_month order by deal_revenue_12_months_window desc
|
partition by first_day_month
|
||||||
|
order by deal_revenue_12_months_window desc, id_deal
|
||||||
) as deal_contribution_rank_to_global_revenue
|
) as deal_contribution_rank_to_global_revenue
|
||||||
from
|
from
|
||||||
(
|
(
|
||||||
|
|
@ -142,12 +137,7 @@ with
|
||||||
given_month.date,
|
given_month.date,
|
||||||
given_month.id_deal,
|
given_month.id_deal,
|
||||||
|
|
||||||
-- Deal Attributes
|
-- Deal Dynamic Attributes
|
||||||
given_month.client_type,
|
|
||||||
given_month.main_deal_name,
|
|
||||||
given_month.has_active_pms,
|
|
||||||
given_month.active_pms_list,
|
|
||||||
given_month.main_billing_country_iso_3_per_deal,
|
|
||||||
given_month.deal_lifecycle_state,
|
given_month.deal_lifecycle_state,
|
||||||
|
|
||||||
-- Dates - For Information Purposes
|
-- Dates - For Information Purposes
|
||||||
|
|
@ -297,11 +287,6 @@ with
|
||||||
m.date,
|
m.date,
|
||||||
m.id_deal,
|
m.id_deal,
|
||||||
|
|
||||||
m.client_type,
|
|
||||||
m.main_deal_name,
|
|
||||||
m.has_active_pms,
|
|
||||||
m.active_pms_list,
|
|
||||||
m.main_billing_country_iso_3_per_deal,
|
|
||||||
m.deal_lifecycle_state,
|
m.deal_lifecycle_state,
|
||||||
|
|
||||||
m.given_month_first_day_month,
|
m.given_month_first_day_month,
|
||||||
|
|
@ -404,12 +389,17 @@ select
|
||||||
gsc.date,
|
gsc.date,
|
||||||
gsc.id_deal,
|
gsc.id_deal,
|
||||||
|
|
||||||
gsc.client_type,
|
-- DEAL STATIC ATTRIBUTES --
|
||||||
gsc.main_deal_name,
|
ikdd.client_type,
|
||||||
gsc.has_active_pms,
|
ikdd.main_deal_name,
|
||||||
gsc.active_pms_list,
|
ikdd.has_active_pms,
|
||||||
gsc.main_billing_country_iso_3_per_deal,
|
ikdd.active_pms_list,
|
||||||
|
ikdd.main_billing_country_iso_3_per_deal,
|
||||||
|
|
||||||
|
-- DEAL LIFECYCLE --
|
||||||
gsc.deal_lifecycle_state,
|
gsc.deal_lifecycle_state,
|
||||||
|
|
||||||
|
-- DEAL HUBSPOT ATTRIBUTES --
|
||||||
d.deal_hubspot_stage,
|
d.deal_hubspot_stage,
|
||||||
d.account_manager,
|
d.account_manager,
|
||||||
d.live_date_utc,
|
d.live_date_utc,
|
||||||
|
|
@ -481,4 +471,5 @@ select
|
||||||
else 'UNSET'
|
else 'UNSET'
|
||||||
end as categorisation_weighted_avg_growth_score
|
end as categorisation_weighted_avg_growth_score
|
||||||
from growth_score_computation gsc
|
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
|
left join int_hubspot__deal d on gsc.id_deal = d.id_deal
|
||||||
|
|
|
||||||
Loading…
Add table
Add a link
Reference in a new issue