change in new deals
This commit is contained in:
parent
1ced79ca0a
commit
d6426b0066
3 changed files with 46 additions and 14 deletions
|
|
@ -38,24 +38,32 @@ with
|
||||||
select
|
select
|
||||||
coalesce(hd.id_deal, cd.id_deal) as id_deal,
|
coalesce(hd.id_deal, cd.id_deal) as id_deal,
|
||||||
coalesce(hd.main_deal_name, cd.main_deal_name) as main_deal_name,
|
coalesce(hd.main_deal_name, cd.main_deal_name) as main_deal_name,
|
||||||
|
case
|
||||||
|
when hd.id_deal is not null then true else false
|
||||||
|
end as is_deal_in_hubspot,
|
||||||
coalesce(cd.has_active_pms, false) as has_active_pms,
|
coalesce(cd.has_active_pms, false) as has_active_pms,
|
||||||
cd.active_pms_list,
|
cd.active_pms_list,
|
||||||
cd.main_billing_country_iso_3_per_deal,
|
cd.main_billing_country_iso_3_per_deal,
|
||||||
case
|
case
|
||||||
when upper(hd.deal_pipeline) in ('API SALES') then 'API' else 'PLATFORM'
|
when upper(hd.deal_pipeline) in ('API SALES') then 'API' else 'PLATFORM'
|
||||||
end as client_type,
|
end as client_type,
|
||||||
hd.deal_start_date as effective_deal_start_date_utc,
|
min(
|
||||||
hd.deal_start_month as effective_deal_start_month,
|
coalesce(hd.deal_start_date, cd.deal_start_date)
|
||||||
|
) as effective_deal_start_date_utc,
|
||||||
|
min(
|
||||||
|
coalesce(hd.deal_start_month, cd.deal_start_month)
|
||||||
|
) as effective_deal_start_month,
|
||||||
min(hd.deal_cancellation_date) as hubspot_deal_cancellation_date_utc,
|
min(hd.deal_cancellation_date) as hubspot_deal_cancellation_date_utc,
|
||||||
min(hd.deal_cancellation_month) as hubspot_deal_cancellation_month,
|
min(hd.deal_cancellation_month) as hubspot_deal_cancellation_month,
|
||||||
min(hd.hubspot_listing_segmentation) as hubspot_listing_segmentation
|
min(hd.hubspot_listing_segmentation) as hubspot_listing_segmentation
|
||||||
from hubspot_deals hd
|
from hubspot_deals hd
|
||||||
full outer join core_deals cd on hd.id_deal = cd.id_deal
|
full outer join core_deals cd on hd.id_deal = cd.id_deal
|
||||||
group by 1, 2, 3, 4, 5, 6, 7, 8
|
group by 1, 2, 3, 4, 5, 6, 7
|
||||||
)
|
)
|
||||||
select
|
select
|
||||||
cd.id_deal,
|
cd.id_deal,
|
||||||
cd.main_deal_name,
|
cd.main_deal_name,
|
||||||
|
cd.is_deal_in_hubspot,
|
||||||
cd.has_active_pms,
|
cd.has_active_pms,
|
||||||
cd.active_pms_list,
|
cd.active_pms_list,
|
||||||
cd.client_type,
|
cd.client_type,
|
||||||
|
|
|
||||||
|
|
@ -46,6 +46,7 @@ with
|
||||||
select
|
select
|
||||||
ikdd.id_deal,
|
ikdd.id_deal,
|
||||||
ikdd.client_type,
|
ikdd.client_type,
|
||||||
|
ikdd.is_deal_in_hubspot,
|
||||||
ikdd.effective_deal_start_date_utc as created_date_utc
|
ikdd.effective_deal_start_date_utc as created_date_utc
|
||||||
from int_kpis__dimension_deals ikdd
|
from int_kpis__dimension_deals ikdd
|
||||||
),
|
),
|
||||||
|
|
@ -53,6 +54,7 @@ with
|
||||||
select
|
select
|
||||||
d.date,
|
d.date,
|
||||||
ikdd.id_deal,
|
ikdd.id_deal,
|
||||||
|
ikdd.is_deal_in_hubspot,
|
||||||
min(ikdd.client_type) as client_type,
|
min(ikdd.client_type) as client_type,
|
||||||
min(ikdd.created_date_utc) as creation_date_utc,
|
min(ikdd.created_date_utc) as creation_date_utc,
|
||||||
min(b.created_date_utc) as first_time_booked_date_utc,
|
min(b.created_date_utc) as first_time_booked_date_utc,
|
||||||
|
|
@ -64,12 +66,13 @@ with
|
||||||
booked_days_per_deal b
|
booked_days_per_deal b
|
||||||
on ikdd.id_deal = b.id_deal
|
on ikdd.id_deal = b.id_deal
|
||||||
and d.date >= b.created_date_utc
|
and d.date >= b.created_date_utc
|
||||||
group by d.date, ikdd.id_deal
|
group by d.date, ikdd.id_deal, ikdd.is_deal_in_hubspot
|
||||||
),
|
),
|
||||||
deal_historic_features as (
|
deal_historic_features as (
|
||||||
select
|
select
|
||||||
hhbf.date,
|
hhbf.date,
|
||||||
hhbf.id_deal,
|
hhbf.id_deal,
|
||||||
|
hhbf.is_deal_in_hubspot,
|
||||||
hhbf.creation_date_utc,
|
hhbf.creation_date_utc,
|
||||||
hhbf.first_time_booked_date_utc,
|
hhbf.first_time_booked_date_utc,
|
||||||
hhbf.last_time_booked_date_utc,
|
hhbf.last_time_booked_date_utc,
|
||||||
|
|
@ -155,16 +158,23 @@ select
|
||||||
second_to_last_time_booked_date_utc,
|
second_to_last_time_booked_date_utc,
|
||||||
cancellation_date_utc,
|
cancellation_date_utc,
|
||||||
case
|
case
|
||||||
-- 01-New: The deal has been created this month.
|
-- 01-New: The deal has been created this month according to the data in
|
||||||
|
-- hubspot.
|
||||||
-- Additionally, the deal has not been offboarded in hubspot.
|
-- Additionally, the deal has not been offboarded in hubspot.
|
||||||
when deal_was_created_this_month and not deal_has_been_offboarded
|
when
|
||||||
|
deal_was_created_this_month
|
||||||
|
and not deal_has_been_offboarded
|
||||||
|
and is_deal_in_hubspot
|
||||||
then '01-New'
|
then '01-New'
|
||||||
-- 02-Never Booked: The deal is not API, has been created before this month
|
-- 02-Never Booked: The deal is not API, has been created before this month, or
|
||||||
-- and has not had any booking. Additionally, the deal has not been offboarded
|
-- it doesn't exist in hubspot, and has not had any booking.
|
||||||
-- in hubspot.
|
-- Additionally, the deal has not been offboarded in hubspot.
|
||||||
when
|
when
|
||||||
not deal_has_at_least_one_booking
|
not deal_has_at_least_one_booking
|
||||||
and not deal_was_created_this_month
|
and (
|
||||||
|
not deal_was_created_this_month
|
||||||
|
or (deal_was_created_this_month and not is_deal_in_hubspot)
|
||||||
|
)
|
||||||
and not deal_has_been_offboarded
|
and not deal_has_been_offboarded
|
||||||
and not is_api_deal
|
and not is_api_deal
|
||||||
then '02-Never Booked'
|
then '02-Never Booked'
|
||||||
|
|
@ -174,14 +184,22 @@ select
|
||||||
-- been less than 12 months since the last booking and has not been offboarded
|
-- been less than 12 months since the last booking and has not been offboarded
|
||||||
when
|
when
|
||||||
-- API deals --
|
-- API deals --
|
||||||
is_api_deal
|
(
|
||||||
and not deal_was_created_this_month
|
is_api_deal
|
||||||
and not deal_has_been_offboarded
|
and (
|
||||||
|
not deal_was_created_this_month
|
||||||
|
or (deal_was_created_this_month and not is_deal_in_hubspot)
|
||||||
|
)
|
||||||
|
and not deal_has_been_offboarded
|
||||||
|
)
|
||||||
-- Platform deals --
|
-- Platform deals --
|
||||||
or (
|
or (
|
||||||
not is_api_deal
|
not is_api_deal
|
||||||
and deal_has_at_least_one_booking
|
and deal_has_at_least_one_booking
|
||||||
and not deal_was_created_this_month
|
and (
|
||||||
|
not deal_was_created_this_month
|
||||||
|
or (deal_was_created_this_month and not is_deal_in_hubspot)
|
||||||
|
)
|
||||||
and has_been_booked_within_last_12_months
|
and has_been_booked_within_last_12_months
|
||||||
and not deal_has_been_offboarded
|
and not deal_has_been_offboarded
|
||||||
-- not reactivated
|
-- not reactivated
|
||||||
|
|
|
||||||
|
|
@ -449,6 +449,12 @@ models:
|
||||||
in both systems, Hubspot data will take precedence in terms of deal name.
|
in both systems, Hubspot data will take precedence in terms of deal name.
|
||||||
data_tests:
|
data_tests:
|
||||||
- not_null
|
- not_null
|
||||||
|
- name: is_deal_in_hubspot
|
||||||
|
data_type: boolean
|
||||||
|
description: |
|
||||||
|
Does the deal exist in HubSpot.
|
||||||
|
data_tests:
|
||||||
|
- not_null
|
||||||
- name: has_active_pms
|
- name: has_active_pms
|
||||||
data_type: boolean
|
data_type: boolean
|
||||||
description: |
|
description: |
|
||||||
|
|
|
||||||
Loading…
Add table
Add a link
Reference in a new issue