Merged PR 4833: Added current deal lifecycle to new dash overview

# Description

Added current deal lifecycle to new dash overview

# 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.

Added current deal lifecycle to new dash overview

Related work items: #28873
This commit is contained in:
Joaquin Ossa 2025-03-28 08:20:58 +00:00
commit e4fb1af349
5 changed files with 50 additions and 1 deletions

View file

@ -10,6 +10,12 @@ with
int_core__accommodation_to_product_bundle as (
select * from {{ ref("int_core__accommodation_to_product_bundle") }}
),
int_kpis__lifecycle_daily_deal as (
select *
from {{ ref("int_kpis__lifecycle_daily_deal") }}
-- Only retrieve deals lifecycle from yesterday
where is_current_state = true
),
upb_aggregation as (
select
upb.id_user_host,
@ -89,6 +95,7 @@ with
uh.has_user_moved_from_old_dash,
uh.new_dash_version as user_migration_phase,
uh.user_in_new_dash_since_date_utc as user_estimated_migration_date_utc,
kldd.deal_lifecycle_state,
uh.has_active_pms,
uh.active_pms_list,
uh.company_name,
@ -112,6 +119,7 @@ with
int_core__user_host uh
on upb.id_user_host = uh.id_user_host
and uh.is_test_account = false
left join int_kpis__lifecycle_daily_deal kldd on uh.id_deal = kldd.id_deal
)
select
id_user_host,
@ -119,6 +127,7 @@ select
has_user_moved_from_old_dash,
user_migration_phase,
user_estimated_migration_date_utc,
deal_lifecycle_state,
has_active_pms,
active_pms_list,
company_name,

View file

@ -2559,6 +2559,24 @@ models:
data_tests:
- not_null
- name: deal_lifecycle_state
data_type: character varying
description: |
Contains the lifecycle state of a deal. The accepted values are:
01-New, 02-Never Booked, 04-Active, 05-Churning, 06-Inactive,
07-Reactivated, 99-Not in Husbpot.
data_tests:
- not_null
- accepted_values:
values:
- 01-New
- 02-Never Booked
- 04-Active
- 05-Churning
- 06-Inactive
- 07-Reactivated
- 99-Not in HubSpot
- name: has_active_pms
data_type: boolean
description: |

View file

@ -53,6 +53,7 @@ with
deal_historic_booking_dates as (
select
d.date,
d.is_yesterday,
ikdd.id_deal,
ikdd.is_deal_in_hubspot,
min(ikdd.client_type) as client_type,
@ -66,11 +67,12 @@ with
booked_days_per_deal b
on ikdd.id_deal = b.id_deal
and d.date >= b.created_date_utc
group by d.date, ikdd.id_deal, ikdd.is_deal_in_hubspot
group by d.date, d.is_yesterday, ikdd.id_deal, ikdd.is_deal_in_hubspot
),
deal_historic_features as (
select
hhbf.date,
case when hhbf.is_yesterday then true else false end as is_current_state,
hhbf.id_deal,
hhbf.is_deal_in_hubspot,
hhbf.creation_date_utc,
@ -151,6 +153,7 @@ with
)
select
date,
is_current_state,
id_deal,
creation_date_utc,
first_time_booked_date_utc,