modified host/deal logic
This commit is contained in:
parent
5c71791f10
commit
8898a2d150
4 changed files with 46 additions and 11 deletions
|
|
@ -2,6 +2,10 @@
|
|||
with
|
||||
int_core__unified_user as (select * from {{ ref("int_core__unified_user") }}),
|
||||
int_core__country as (select * from {{ ref("int_core__country") }}),
|
||||
stg_core__integration as (select * from {{ ref("stg_core__integration") }}),
|
||||
stg_core__integration_type as (
|
||||
select * from {{ ref("stg_core__integration_type") }}
|
||||
),
|
||||
|
||||
-- A Deal can have multiple users, which in turn can have different
|
||||
-- billing countries. We assume here that the main billing country
|
||||
|
|
@ -70,6 +74,22 @@ with
|
|||
from potential_name_per_deal
|
||||
) as ranked_names
|
||||
where rn = 1
|
||||
),
|
||||
-- PMS INTEGRATIONS
|
||||
integrations_per_user as (
|
||||
select
|
||||
uu.id_deal, sci.id_superhog_user as id_user, scit.display_name as active_pms
|
||||
from stg_core__integration sci
|
||||
left join
|
||||
stg_core__integration_type scit
|
||||
on sci.id_integration_type = scit.id_integration_type
|
||||
left join int_core__unified_user uu on sci.id_superhog_user = uu.id_user
|
||||
),
|
||||
integrations_per_deal as (
|
||||
|
||||
select id_deal, string_agg(distinct active_pms, ', ') as distinct_active_pms
|
||||
from integrations_per_user
|
||||
group by id_deal
|
||||
)
|
||||
select
|
||||
uu.id_deal,
|
||||
|
|
@ -78,11 +98,16 @@ select
|
|||
mbcpd.main_billing_country_name_per_deal,
|
||||
mbcpd.main_billing_country_iso_2_per_deal,
|
||||
mbcpd.main_billing_country_iso_3_per_deal,
|
||||
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,
|
||||
count(distinct uu.id_user) as users_with_this_id_deal,
|
||||
count(distinct uu.billing_country_iso_3) as billing_countries_for_this_id_deal,
|
||||
min(uu.created_date_utc) as first_created_date_utc
|
||||
from main_billing_country_per_deal mbcpd
|
||||
left join int_core__unified_user uu on uu.id_deal = mbcpd.id_deal
|
||||
left join unique_name_per_deal unpd on uu.id_deal = unpd.id_deal
|
||||
left join integrations_per_deal ipd on uu.id_deal = ipd.id_deal
|
||||
where mbcpd.id_deal is not null
|
||||
group by 1, 2, 3, 4, 5, 6
|
||||
group by 1, 2, 3, 4, 5, 6, 7, 8
|
||||
|
|
|
|||
|
|
@ -34,18 +34,18 @@ with
|
|||
),
|
||||
-- PMS INTEGRATIONS
|
||||
integrations_per_user as (
|
||||
select
|
||||
uu.id_deal, sci.id_superhog_user as id_user, scit.display_name as active_pms
|
||||
select sci.id_superhog_user as id_user_host, scit.display_name as active_pms
|
||||
from stg_core__integration sci
|
||||
left join
|
||||
stg_core__integration_type scit
|
||||
on sci.id_integration_type = scit.id_integration_type
|
||||
left join int_core__unified_user uu on sci.id_superhog_user = uu.id_user
|
||||
),
|
||||
integrations_per_deal as (
|
||||
select id_deal, string_agg(distinct active_pms, ', ') as distinct_active_pms
|
||||
integrations_per_host as (
|
||||
select
|
||||
id_user_host, string_agg(distinct active_pms, ', ') as distinct_active_pms
|
||||
from integrations_per_user
|
||||
group by id_deal
|
||||
group by id_user_host
|
||||
)
|
||||
select
|
||||
uu.id_user as id_user_host,
|
||||
|
|
@ -63,9 +63,9 @@ select
|
|||
uu.email,
|
||||
uu.id_deal,
|
||||
case
|
||||
when ipd.distinct_active_pms is null then false else true
|
||||
when iph.distinct_active_pms is null then false else true
|
||||
end as has_active_pms,
|
||||
ipd.distinct_active_pms as active_pms_list,
|
||||
iph.distinct_active_pms as active_pms_list,
|
||||
d.main_billing_country_name_per_deal,
|
||||
d.main_billing_country_iso_2_per_deal,
|
||||
d.main_billing_country_iso_3_per_deal,
|
||||
|
|
@ -89,4 +89,4 @@ from int_core__unified_user uu
|
|||
inner join unique_host_user uhu on uu.id_user = uhu.id_user
|
||||
left join int_core__new_dash_users ndu on uu.id_user = ndu.id_user_host
|
||||
left join int_core__deal d on uu.id_deal = d.id_deal
|
||||
left join integrations_per_deal ipd on uu.id_deal = ipd.id_deal
|
||||
left join integrations_per_host iph on uu.id_user = iph.id_user_host
|
||||
|
|
|
|||
|
|
@ -2854,6 +2854,17 @@ models:
|
|||
description: |
|
||||
ISO 3166-1 alpha-3 main country code in which the Deal is billed.
|
||||
In some cases it's null.
|
||||
- name: has_active_pms
|
||||
data_type: boolean
|
||||
description: |
|
||||
Does the deal have an active associated PMS.
|
||||
data_tests:
|
||||
- not_null
|
||||
- name: active_pms_list
|
||||
data_type: string
|
||||
description: |
|
||||
Name of the active PMS associated with the deal. It can have more than
|
||||
one PMS associated with it. It can be null if it doesn't have any PMS associated.
|
||||
- name: users_with_this_id_deal
|
||||
data_type: integer
|
||||
description: |
|
||||
|
|
|
|||
|
|
@ -32,8 +32,7 @@ with
|
|||
from {{ ref("int_core__deal") }}
|
||||
),
|
||||
integrations_per_deal as (
|
||||
select distinct id_deal, has_active_pms, active_pms_list
|
||||
from {{ ref("int_core__user_host") }}
|
||||
select id_deal, has_active_pms, active_pms_list from {{ ref("int_core__deal") }}
|
||||
),
|
||||
combined_deals as (
|
||||
select
|
||||
|
|
|
|||
Loading…
Add table
Add a link
Reference in a new issue