Merged PR 4009: Adding PMS info for Account Margin report
# Description Adding PMS info for Account Margin report. I added a boolean with if they have an active PMS integration or not and the name or names of the PMSs. I see a lot of changes made in `int_monthly_aggregated_metrics_history_by_deal_by_time_window`, probably because of the formatting when saving. # 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. Adding PMS info for Account Margin report
This commit is contained in:
commit
580b194be7
7 changed files with 227 additions and 79 deletions
|
|
@ -85,6 +85,8 @@ select
|
||||||
-- DEAL STATIC ATTRIBUTES --
|
-- DEAL STATIC ATTRIBUTES --
|
||||||
ikdd.id_deal,
|
ikdd.id_deal,
|
||||||
ikdd.main_deal_name,
|
ikdd.main_deal_name,
|
||||||
|
ikdd.has_active_pms,
|
||||||
|
ikdd.active_pms_list,
|
||||||
ikdd.main_billing_country_iso_3_per_deal,
|
ikdd.main_billing_country_iso_3_per_deal,
|
||||||
|
|
||||||
-- DEAL LIFECYCLE --
|
-- DEAL LIFECYCLE --
|
||||||
|
|
|
||||||
|
|
@ -3,14 +3,14 @@ with
|
||||||
int_monthly_aggregated_metrics_history_by_deal as (
|
int_monthly_aggregated_metrics_history_by_deal as (
|
||||||
select * from {{ ref("int_monthly_aggregated_metrics_history_by_deal") }}
|
select * from {{ ref("int_monthly_aggregated_metrics_history_by_deal") }}
|
||||||
),
|
),
|
||||||
int_hubspot__deal as (
|
int_hubspot__deal as (select * from {{ ref("int_hubspot__deal") }}),
|
||||||
select * from {{ ref("int_hubspot__deal") }}
|
|
||||||
),
|
|
||||||
metric_aggregation_all_history as (
|
metric_aggregation_all_history as (
|
||||||
select
|
select
|
||||||
date,
|
date,
|
||||||
id_deal,
|
id_deal,
|
||||||
main_deal_name,
|
main_deal_name,
|
||||||
|
has_active_pms,
|
||||||
|
active_pms_list,
|
||||||
main_billing_country_iso_3_per_deal,
|
main_billing_country_iso_3_per_deal,
|
||||||
deal_lifecycle_state,
|
deal_lifecycle_state,
|
||||||
'All History' as time_window,
|
'All History' as time_window,
|
||||||
|
|
@ -41,12 +41,24 @@ with
|
||||||
}},
|
}},
|
||||||
{{
|
{{
|
||||||
calculate_aggregation_between_preceeding_x_and_y(
|
calculate_aggregation_between_preceeding_x_and_y(
|
||||||
"total_guest_payments_in_gbp", "sum", "id_deal", "date", "", 1, True
|
"total_guest_payments_in_gbp",
|
||||||
|
"sum",
|
||||||
|
"id_deal",
|
||||||
|
"date",
|
||||||
|
"",
|
||||||
|
1,
|
||||||
|
True,
|
||||||
)
|
)
|
||||||
}},
|
}},
|
||||||
{{
|
{{
|
||||||
calculate_aggregation_between_preceeding_x_and_y(
|
calculate_aggregation_between_preceeding_x_and_y(
|
||||||
"xero_operator_net_fees_in_gbp", "sum", "id_deal", "date", "", 1, True
|
"xero_operator_net_fees_in_gbp",
|
||||||
|
"sum",
|
||||||
|
"id_deal",
|
||||||
|
"date",
|
||||||
|
"",
|
||||||
|
1,
|
||||||
|
True,
|
||||||
)
|
)
|
||||||
}},
|
}},
|
||||||
{{
|
{{
|
||||||
|
|
@ -62,7 +74,7 @@ with
|
||||||
"date",
|
"date",
|
||||||
"",
|
"",
|
||||||
1,
|
1,
|
||||||
True
|
True,
|
||||||
)
|
)
|
||||||
}},
|
}},
|
||||||
{{
|
{{
|
||||||
|
|
@ -73,7 +85,7 @@ with
|
||||||
"date",
|
"date",
|
||||||
"",
|
"",
|
||||||
1,
|
1,
|
||||||
True
|
True,
|
||||||
)
|
)
|
||||||
}},
|
}},
|
||||||
{{
|
{{
|
||||||
|
|
@ -84,7 +96,7 @@ with
|
||||||
"date",
|
"date",
|
||||||
"",
|
"",
|
||||||
1,
|
1,
|
||||||
True
|
True,
|
||||||
)
|
)
|
||||||
}},
|
}},
|
||||||
{{
|
{{
|
||||||
|
|
@ -100,7 +112,7 @@ with
|
||||||
"date",
|
"date",
|
||||||
"",
|
"",
|
||||||
1,
|
1,
|
||||||
True
|
True,
|
||||||
)
|
)
|
||||||
}}
|
}}
|
||||||
from int_monthly_aggregated_metrics_history_by_deal
|
from int_monthly_aggregated_metrics_history_by_deal
|
||||||
|
|
@ -110,6 +122,8 @@ with
|
||||||
date,
|
date,
|
||||||
id_deal,
|
id_deal,
|
||||||
main_deal_name,
|
main_deal_name,
|
||||||
|
has_active_pms,
|
||||||
|
active_pms_list,
|
||||||
main_billing_country_iso_3_per_deal,
|
main_billing_country_iso_3_per_deal,
|
||||||
deal_lifecycle_state,
|
deal_lifecycle_state,
|
||||||
'Previous 12 months' as time_window,
|
'Previous 12 months' as time_window,
|
||||||
|
|
@ -159,7 +173,8 @@ with
|
||||||
"sum",
|
"sum",
|
||||||
"id_deal",
|
"id_deal",
|
||||||
"date",
|
"date",
|
||||||
12, 1
|
12,
|
||||||
|
1,
|
||||||
)
|
)
|
||||||
}},
|
}},
|
||||||
{{
|
{{
|
||||||
|
|
@ -168,12 +183,18 @@ with
|
||||||
"sum",
|
"sum",
|
||||||
"id_deal",
|
"id_deal",
|
||||||
"date",
|
"date",
|
||||||
12, 1
|
12,
|
||||||
|
1,
|
||||||
)
|
)
|
||||||
}},
|
}},
|
||||||
{{
|
{{
|
||||||
calculate_aggregation_between_preceeding_x_and_y(
|
calculate_aggregation_between_preceeding_x_and_y(
|
||||||
"xero_host_resolution_payment_count", "sum", "id_deal", "date", 12, 1
|
"xero_host_resolution_payment_count",
|
||||||
|
"sum",
|
||||||
|
"id_deal",
|
||||||
|
"date",
|
||||||
|
12,
|
||||||
|
1,
|
||||||
)
|
)
|
||||||
}},
|
}},
|
||||||
{{
|
{{
|
||||||
|
|
@ -187,7 +208,8 @@ with
|
||||||
"sum",
|
"sum",
|
||||||
"id_deal",
|
"id_deal",
|
||||||
"date",
|
"date",
|
||||||
12, 1
|
12,
|
||||||
|
1,
|
||||||
)
|
)
|
||||||
}}
|
}}
|
||||||
|
|
||||||
|
|
@ -198,6 +220,8 @@ with
|
||||||
date,
|
date,
|
||||||
id_deal,
|
id_deal,
|
||||||
main_deal_name,
|
main_deal_name,
|
||||||
|
has_active_pms,
|
||||||
|
active_pms_list,
|
||||||
main_billing_country_iso_3_per_deal,
|
main_billing_country_iso_3_per_deal,
|
||||||
deal_lifecycle_state,
|
deal_lifecycle_state,
|
||||||
'Previous 6 months' as time_window,
|
'Previous 6 months' as time_window,
|
||||||
|
|
@ -247,7 +271,8 @@ with
|
||||||
"sum",
|
"sum",
|
||||||
"id_deal",
|
"id_deal",
|
||||||
"date",
|
"date",
|
||||||
6, 1
|
6,
|
||||||
|
1,
|
||||||
)
|
)
|
||||||
}},
|
}},
|
||||||
{{
|
{{
|
||||||
|
|
@ -256,12 +281,18 @@ with
|
||||||
"sum",
|
"sum",
|
||||||
"id_deal",
|
"id_deal",
|
||||||
"date",
|
"date",
|
||||||
6, 1
|
6,
|
||||||
|
1,
|
||||||
)
|
)
|
||||||
}},
|
}},
|
||||||
{{
|
{{
|
||||||
calculate_aggregation_between_preceeding_x_and_y(
|
calculate_aggregation_between_preceeding_x_and_y(
|
||||||
"xero_host_resolution_payment_count", "sum", "id_deal", "date", 6, 1
|
"xero_host_resolution_payment_count",
|
||||||
|
"sum",
|
||||||
|
"id_deal",
|
||||||
|
"date",
|
||||||
|
6,
|
||||||
|
1,
|
||||||
)
|
)
|
||||||
}},
|
}},
|
||||||
{{
|
{{
|
||||||
|
|
@ -275,7 +306,8 @@ with
|
||||||
"sum",
|
"sum",
|
||||||
"id_deal",
|
"id_deal",
|
||||||
"date",
|
"date",
|
||||||
6, 1
|
6,
|
||||||
|
1,
|
||||||
)
|
)
|
||||||
}}
|
}}
|
||||||
|
|
||||||
|
|
@ -286,6 +318,8 @@ with
|
||||||
date,
|
date,
|
||||||
id_deal,
|
id_deal,
|
||||||
main_deal_name,
|
main_deal_name,
|
||||||
|
has_active_pms,
|
||||||
|
active_pms_list,
|
||||||
main_billing_country_iso_3_per_deal,
|
main_billing_country_iso_3_per_deal,
|
||||||
deal_lifecycle_state,
|
deal_lifecycle_state,
|
||||||
'Previous 3 months' as time_window,
|
'Previous 3 months' as time_window,
|
||||||
|
|
@ -335,7 +369,8 @@ with
|
||||||
"sum",
|
"sum",
|
||||||
"id_deal",
|
"id_deal",
|
||||||
"date",
|
"date",
|
||||||
3, 1
|
3,
|
||||||
|
1,
|
||||||
)
|
)
|
||||||
}},
|
}},
|
||||||
{{
|
{{
|
||||||
|
|
@ -344,12 +379,18 @@ with
|
||||||
"sum",
|
"sum",
|
||||||
"id_deal",
|
"id_deal",
|
||||||
"date",
|
"date",
|
||||||
3, 1
|
3,
|
||||||
|
1,
|
||||||
)
|
)
|
||||||
}},
|
}},
|
||||||
{{
|
{{
|
||||||
calculate_aggregation_between_preceeding_x_and_y(
|
calculate_aggregation_between_preceeding_x_and_y(
|
||||||
"xero_host_resolution_payment_count", "sum", "id_deal", "date", 3, 1
|
"xero_host_resolution_payment_count",
|
||||||
|
"sum",
|
||||||
|
"id_deal",
|
||||||
|
"date",
|
||||||
|
3,
|
||||||
|
1,
|
||||||
)
|
)
|
||||||
}},
|
}},
|
||||||
{{
|
{{
|
||||||
|
|
@ -363,7 +404,8 @@ with
|
||||||
"sum",
|
"sum",
|
||||||
"id_deal",
|
"id_deal",
|
||||||
"date",
|
"date",
|
||||||
3, 1
|
3,
|
||||||
|
1,
|
||||||
)
|
)
|
||||||
}}
|
}}
|
||||||
|
|
||||||
|
|
@ -374,6 +416,8 @@ with
|
||||||
date,
|
date,
|
||||||
id_deal,
|
id_deal,
|
||||||
main_deal_name,
|
main_deal_name,
|
||||||
|
has_active_pms,
|
||||||
|
active_pms_list,
|
||||||
main_billing_country_iso_3_per_deal,
|
main_billing_country_iso_3_per_deal,
|
||||||
deal_lifecycle_state,
|
deal_lifecycle_state,
|
||||||
'Previous month' as time_window,
|
'Previous month' as time_window,
|
||||||
|
|
@ -423,7 +467,8 @@ with
|
||||||
"sum",
|
"sum",
|
||||||
"id_deal",
|
"id_deal",
|
||||||
"date",
|
"date",
|
||||||
1, 1
|
1,
|
||||||
|
1,
|
||||||
)
|
)
|
||||||
}},
|
}},
|
||||||
{{
|
{{
|
||||||
|
|
@ -432,12 +477,18 @@ with
|
||||||
"sum",
|
"sum",
|
||||||
"id_deal",
|
"id_deal",
|
||||||
"date",
|
"date",
|
||||||
1, 1
|
1,
|
||||||
|
1,
|
||||||
)
|
)
|
||||||
}},
|
}},
|
||||||
{{
|
{{
|
||||||
calculate_aggregation_between_preceeding_x_and_y(
|
calculate_aggregation_between_preceeding_x_and_y(
|
||||||
"xero_host_resolution_payment_count", "sum", "id_deal", "date", 1, 1
|
"xero_host_resolution_payment_count",
|
||||||
|
"sum",
|
||||||
|
"id_deal",
|
||||||
|
"date",
|
||||||
|
1,
|
||||||
|
1,
|
||||||
)
|
)
|
||||||
}},
|
}},
|
||||||
{{
|
{{
|
||||||
|
|
@ -451,7 +502,8 @@ with
|
||||||
"sum",
|
"sum",
|
||||||
"id_deal",
|
"id_deal",
|
||||||
"date",
|
"date",
|
||||||
1, 1
|
1,
|
||||||
|
1,
|
||||||
)
|
)
|
||||||
}}
|
}}
|
||||||
|
|
||||||
|
|
@ -473,7 +525,7 @@ with
|
||||||
select *
|
select *
|
||||||
from metric_aggregation_previous_1_month
|
from metric_aggregation_previous_1_month
|
||||||
)
|
)
|
||||||
select
|
select
|
||||||
-- Primary key
|
-- Primary key
|
||||||
mabd.date,
|
mabd.date,
|
||||||
mabd.id_deal,
|
mabd.id_deal,
|
||||||
|
|
@ -485,6 +537,8 @@ with
|
||||||
|
|
||||||
-- Deal attributes
|
-- Deal attributes
|
||||||
mabd.main_deal_name,
|
mabd.main_deal_name,
|
||||||
|
mabd.has_active_pms,
|
||||||
|
mabd.active_pms_list,
|
||||||
mabd.main_billing_country_iso_3_per_deal,
|
mabd.main_billing_country_iso_3_per_deal,
|
||||||
mabd.deal_lifecycle_state,
|
mabd.deal_lifecycle_state,
|
||||||
d.deal_hubspot_stage,
|
d.deal_hubspot_stage,
|
||||||
|
|
@ -493,19 +547,27 @@ with
|
||||||
d.cancellation_date_utc,
|
d.cancellation_date_utc,
|
||||||
|
|
||||||
-- Windowed metrics
|
-- Windowed metrics
|
||||||
coalesce(mabd.sum_created_bookings,0) as created_bookings,
|
coalesce(mabd.sum_created_bookings, 0) as created_bookings,
|
||||||
coalesce(mabd.avg_listings_booked_in_month,0) as listings_booked_in_month,
|
coalesce(mabd.avg_listings_booked_in_month, 0) as listings_booked_in_month,
|
||||||
coalesce(mabd.sum_total_revenue_in_gbp,0) as total_revenue_in_gbp,
|
coalesce(mabd.sum_total_revenue_in_gbp, 0) as total_revenue_in_gbp,
|
||||||
coalesce(mabd.sum_revenue_retained_in_gbp,0) as revenue_retained_in_gbp,
|
coalesce(mabd.sum_revenue_retained_in_gbp, 0) as revenue_retained_in_gbp,
|
||||||
coalesce(mabd.sum_xero_waiver_paid_back_to_host_in_gbp,0) as waiver_paid_back_to_host_in_gbp,
|
coalesce(
|
||||||
coalesce(mabd.sum_xero_operator_net_fees_in_gbp,0)
|
mabd.sum_xero_waiver_paid_back_to_host_in_gbp, 0
|
||||||
+ coalesce(mabd.sum_xero_apis_net_fees_in_gbp,0) as invoiced_revenue_in_gbp,
|
) as waiver_paid_back_to_host_in_gbp,
|
||||||
coalesce(mabd.sum_total_guest_payments_in_gbp,0) as guest_payments_in_gbp,
|
coalesce(mabd.sum_xero_operator_net_fees_in_gbp, 0)
|
||||||
coalesce(mabd.sum_total_guest_payments_in_gbp,0)
|
+ coalesce(mabd.sum_xero_apis_net_fees_in_gbp, 0) as invoiced_revenue_in_gbp,
|
||||||
+ coalesce(mabd.sum_xero_waiver_paid_back_to_host_in_gbp,0) as guest_revenue_retained_in_gbp,
|
coalesce(mabd.sum_total_guest_payments_in_gbp, 0) as guest_payments_in_gbp,
|
||||||
coalesce(mabd.sum_xero_host_resolution_payment_count,0) as host_resolution_payment_count,
|
coalesce(mabd.sum_total_guest_payments_in_gbp, 0) + coalesce(
|
||||||
coalesce(mabd.sum_xero_host_resolution_amount_paid_in_gbp,0) as host_resolution_amount_paid_in_gbp,
|
mabd.sum_xero_waiver_paid_back_to_host_in_gbp, 0
|
||||||
coalesce(mabd.sum_revenue_retained_post_resolutions_in_gbp,0)
|
) as guest_revenue_retained_in_gbp,
|
||||||
as revenue_retained_post_resolutions_in_gbp
|
coalesce(
|
||||||
from metric_aggregation_by_deal mabd
|
mabd.sum_xero_host_resolution_payment_count, 0
|
||||||
left join int_hubspot__deal d on mabd.id_deal = d.id_deal
|
) as host_resolution_payment_count,
|
||||||
|
coalesce(
|
||||||
|
mabd.sum_xero_host_resolution_amount_paid_in_gbp, 0
|
||||||
|
) as host_resolution_amount_paid_in_gbp,
|
||||||
|
coalesce(
|
||||||
|
mabd.sum_revenue_retained_post_resolutions_in_gbp, 0
|
||||||
|
) as revenue_retained_post_resolutions_in_gbp
|
||||||
|
from metric_aggregation_by_deal mabd
|
||||||
|
left join int_hubspot__deal d on mabd.id_deal = d.id_deal
|
||||||
|
|
|
||||||
|
|
@ -359,6 +359,19 @@ models:
|
||||||
tests:
|
tests:
|
||||||
- not_null
|
- not_null
|
||||||
|
|
||||||
|
- name: has_active_pms
|
||||||
|
data_type: boolean
|
||||||
|
description: |
|
||||||
|
Does the deal have an active associated PMS.
|
||||||
|
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: main_billing_country_iso_3_per_deal
|
- name: main_billing_country_iso_3_per_deal
|
||||||
data_type: string
|
data_type: string
|
||||||
description: |
|
description: |
|
||||||
|
|
@ -1467,6 +1480,19 @@ models:
|
||||||
tests:
|
tests:
|
||||||
- not_null
|
- not_null
|
||||||
|
|
||||||
|
- name: has_active_pms
|
||||||
|
data_type: boolean
|
||||||
|
description: |
|
||||||
|
Does the deal have an active associated PMS.
|
||||||
|
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: main_billing_country_iso_3_per_deal
|
- name: main_billing_country_iso_3_per_deal
|
||||||
data_type: string
|
data_type: string
|
||||||
description: |
|
description: |
|
||||||
|
|
|
||||||
|
|
@ -12,14 +12,46 @@ with
|
||||||
first_created_date_utc as deal_start_date,
|
first_created_date_utc as deal_start_date,
|
||||||
main_billing_country_iso_3_per_deal
|
main_billing_country_iso_3_per_deal
|
||||||
from {{ ref("int_core__deal") }}
|
from {{ ref("int_core__deal") }}
|
||||||
)
|
),
|
||||||
select
|
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.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,
|
||||||
cd.main_billing_country_iso_3_per_deal,
|
cd.main_billing_country_iso_3_per_deal,
|
||||||
min(
|
min(
|
||||||
coalesce(hd.deal_start_date, cd.deal_start_date)
|
coalesce(hd.deal_start_date, cd.deal_start_date)
|
||||||
) as effective_deal_start_date_utc
|
) as effective_deal_start_date_utc
|
||||||
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
|
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
|
||||||
|
|
|
||||||
|
|
@ -450,6 +450,17 @@ 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.
|
||||||
tests:
|
tests:
|
||||||
- not_null
|
- not_null
|
||||||
|
- name: has_active_pms
|
||||||
|
data_type: boolean
|
||||||
|
description: |
|
||||||
|
Does the deal have an active associated PMS.
|
||||||
|
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: main_billing_country_iso_3_per_deal
|
- name: main_billing_country_iso_3_per_deal
|
||||||
data_type: string
|
data_type: string
|
||||||
description: |
|
description: |
|
||||||
|
|
|
||||||
|
|
@ -11,6 +11,8 @@ select
|
||||||
metric_from_date as metric_from_date,
|
metric_from_date as metric_from_date,
|
||||||
metric_to_date as metric_to_date,
|
metric_to_date as metric_to_date,
|
||||||
main_deal_name as main_deal_name,
|
main_deal_name as main_deal_name,
|
||||||
|
has_active_pms as has_active_pms,
|
||||||
|
active_pms_list as active_pms_list,
|
||||||
main_billing_country_iso_3_per_deal as main_billing_country_iso_3_per_deal,
|
main_billing_country_iso_3_per_deal as main_billing_country_iso_3_per_deal,
|
||||||
deal_lifecycle_state as deal_lifecycle_state,
|
deal_lifecycle_state as deal_lifecycle_state,
|
||||||
deal_hubspot_stage as deal_hubspot_stage,
|
deal_hubspot_stage as deal_hubspot_stage,
|
||||||
|
|
|
||||||
|
|
@ -1435,6 +1435,19 @@ models:
|
||||||
tests:
|
tests:
|
||||||
- not_null
|
- not_null
|
||||||
|
|
||||||
|
- name: has_active_pms
|
||||||
|
data_type: boolean
|
||||||
|
description: |
|
||||||
|
Does the deal have an active associated PMS.
|
||||||
|
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: main_billing_country_iso_3_per_deal
|
- name: main_billing_country_iso_3_per_deal
|
||||||
data_type: string
|
data_type: string
|
||||||
description: |
|
description: |
|
||||||
|
|
|
||||||
Loading…
Add table
Add a link
Reference in a new issue