{{ config(materialized="table", unique_key="id_deal") }} with hubspot_deals as ( select id_deal, deal_name as main_deal_name, live_date_utc as deal_start_date from {{ ref("int_hubspot__deal") }} where live_date_utc is not null ), core_deals as ( select id_deal, main_deal_name, first_created_date_utc as deal_start_date, main_billing_country_iso_3_per_deal from {{ ref("int_core__deal") }} ), integrations_per_user as ( select icuh.id_deal, sci.id_superhog_user as id_user, scit.display_name as active_pms from {{ ref("stg_core__integration") }} sci left join {{ ref("stg_core__integration_type") }} scit on sci.id_integration_type = scit.id_integration_type left join {{ ref("int_core__user_host") }} icuh on sci.id_superhog_user = icuh.id_user_host where sci.is_active = true and icuh.is_missing_id_deal = false ), integrations_per_deal as ( select id_deal, string_agg(distinct active_pms, ', ') as distinct_active_pms from integrations_per_user group by id_deal ), combined_deals as ( select coalesce(hd.id_deal, cd.id_deal) as id_deal, coalesce(hd.main_deal_name, cd.main_deal_name) as main_deal_name, cd.main_billing_country_iso_3_per_deal, min( coalesce(hd.deal_start_date, cd.deal_start_date) ) as effective_deal_start_date_utc from hubspot_deals hd full outer join core_deals cd on hd.id_deal = cd.id_deal group by 1, 2, 3 ) select cd.id_deal, cd.main_deal_name, case when ipd.distinct_active_pms is null then false else true end as has_active_pms, ipd.distinct_active_pms as active_pms_list, cd.main_billing_country_iso_3_per_deal, cd.effective_deal_start_date_utc from combined_deals cd left join integrations_per_deal ipd on cd.id_deal = ipd.id_deal