From 58dc823d278cb424b6173d9f81791fdf7a8bfdd8 Mon Sep 17 00:00:00 2001 From: Joaquin Ossa Date: Fri, 3 Jan 2025 11:23:06 +0100 Subject: [PATCH] Added boolean fields and counts per each deal source --- .../cross/int_deals_consolidation.sql | 84 ++++++++++++++----- 1 file changed, 65 insertions(+), 19 deletions(-) diff --git a/models/intermediate/cross/int_deals_consolidation.sql b/models/intermediate/cross/int_deals_consolidation.sql index 37aa850..98dc5f3 100644 --- a/models/intermediate/cross/int_deals_consolidation.sql +++ b/models/intermediate/cross/int_deals_consolidation.sql @@ -2,41 +2,87 @@ with int_xero__contacts as (select * from {{ ref("int_xero__contacts") }}), int_core__unified_user as (select * from {{ ref("int_core__unified_user") }}), int_hubspot__deal as (select * from {{ ref("int_hubspot__deal") }}), - ranked_core_deals as ( - select - id_deal, - company_name as core_company_name, - row_number() over (partition by id_deal order by company_name) as row_num + + core_deal_counts as ( + select id_deal, count(distinct company_name) as core_company_name_count from intermediate.int_core__unified_user where id_deal is not null + group by id_deal + ), + + ranked_core_deals as ( + select + u.id_deal, + u.company_name as core_company_name, + c.core_company_name_count, + row_number() over ( + partition by u.id_deal order by u.company_name + ) as row_num + from intermediate.int_core__unified_user u + left join core_deal_counts c on u.id_deal = c.id_deal + where u.id_deal is not null ), deals_core as ( - select id_deal, core_company_name from ranked_core_deals where row_num = 1 + select id_deal, core_company_name, core_company_name_count + from ranked_core_deals + where row_num = 1 ), - ranked_hubspot_deals as ( - select - id_deal, - deal_name as hubspot_deal_name, - row_number() over (partition by id_deal order by deal_name) as row_num + + hubspot_deal_counts as ( + select id_deal, count(distinct deal_name) as hubspot_deal_name_count from intermediate.int_hubspot__deal where id_deal is not null + group by id_deal + ), + + ranked_hubspot_deals as ( + select + h.id_deal, + h.deal_name as hubspot_deal_name, + c.hubspot_deal_name_count, + row_number() over (partition by h.id_deal order by h.deal_name) as row_num + from intermediate.int_hubspot__deal h + left join hubspot_deal_counts c on h.id_deal = c.id_deal + where h.id_deal is not null ), deals_hubspot as ( - select id_deal, hubspot_deal_name from ranked_hubspot_deals where row_num = 1 + select id_deal, hubspot_deal_name, hubspot_deal_name_count + from ranked_hubspot_deals + where row_num = 1 ), - ranked_xero_deals as ( - select - id_deal, - contact_name as xero_contact_name, - row_number() over (partition by id_deal order by contact_name) as row_num + + xero_contact_counts as ( + select id_deal, count(distinct contact_name) as xero_contact_name_count from intermediate.int_xero__contacts where id_deal is not null + group by id_deal + ), + + ranked_xero_deals as ( + select + x.id_deal, + x.contact_name as xero_contact_name, + c.xero_contact_name_count, + row_number() over ( + partition by x.id_deal order by x.contact_name + ) as row_num + from intermediate.int_xero__contacts x + left join xero_contact_counts c on x.id_deal = c.id_deal + where x.id_deal is not null ), deals_xero as ( - select id_deal, xero_contact_name from ranked_xero_deals where row_num = 1 + select id_deal, xero_contact_name, xero_contact_name_count + from ranked_xero_deals + where row_num = 1 ) -select * +select + *, + case when core_company_name is not null then true else false end as is_deal_in_core, + case + when hubspot_deal_name is not null then true else false + end as is_deal_in_hubspot, + case when xero_contact_name is not null then true else false end as is_deal_in_xero from deals_core full outer join deals_hubspot using (id_deal) full outer join deals_xero using (id_deal)