Merged PR 5463: New Dash user categorisation + revamp model
# Description Fixes: * There was a data quality issue in which active listings with bundles were showing more listings than the total active listings. This has been fixed, plus a bunch of tests have been added to make sure this does not happen again. * There's a field that reaches the 63 character limit. I modified "paid" per "upgraded" which reduces this to intermediate model; however in reporting I need to keep as is to avoid breaking PBI. I did change the name of the field in the schema so tests/docs work well and explicitly mention this in the doc. This will need adaptation but can be done in the future. * There was tons of dead code tagged as to be deleted that was not deleted, not sure why or when. Anyway this is dropped now. It's not used in PBI except for the fact that columns are dropped in the data model, so we might have a bit of down time to just remove these. * Few fields were not displayed correctly in dbt docs. What's new: * New user categorisation as an alert-based system. This can be enhanced in the future but so far it covers hell of a lot of cases. This also includes data quality alerts (deal not in HS, or account defaults to MVP launch). * MVP Launch date moved to project yaml since it's a very standard date. # 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. - [X] I have checked for DRY opportunities with other models and docs. - [X] I've picked the right materialization for the affected models. # Other - [ ] Check if a full-refresh is required after this PR is merged. Related work items: #30407
This commit is contained in:
parent
11bdc7d4b3
commit
a8927b7a44
7 changed files with 321 additions and 154 deletions
|
|
@ -65,6 +65,9 @@ vars:
|
||||||
# KPIs Start Date. This is the date from which we start calculating KPIs.
|
# KPIs Start Date. This is the date from which we start calculating KPIs.
|
||||||
"kpis_start_date": "'2022-04-01'"
|
"kpis_start_date": "'2022-04-01'"
|
||||||
|
|
||||||
|
# New Dash MVP Launch Date. This is the first date considered for New Dash in many areas.
|
||||||
|
"new_dash_mvp_launch_date": "'2024-07-30'"
|
||||||
|
|
||||||
# New Dash First Invoicing Date. This is the first date considered for New Dash invoicing.
|
# New Dash First Invoicing Date. This is the first date considered for New Dash invoicing.
|
||||||
"new_dash_first_invoicing_date": "'2024-12-31'"
|
"new_dash_first_invoicing_date": "'2024-12-31'"
|
||||||
|
|
||||||
|
|
|
||||||
|
|
@ -1,3 +1,6 @@
|
||||||
|
{% set deal_lifecycle_state_with_data_quality_issues = "99-Not in HubSpot" %}
|
||||||
|
{% set deal_lifecycle_states_churned = ("05-Churning", "06-Inactive") %}
|
||||||
|
|
||||||
with
|
with
|
||||||
int_core__user_product_bundle as (
|
int_core__user_product_bundle as (
|
||||||
select * from {{ ref("int_core__user_product_bundle") }}
|
select * from {{ ref("int_core__user_product_bundle") }}
|
||||||
|
|
@ -44,27 +47,6 @@ with
|
||||||
atpb_aggregation as (
|
atpb_aggregation as (
|
||||||
select
|
select
|
||||||
upb.id_user_host,
|
upb.id_user_host,
|
||||||
-- To be deleted from here
|
|
||||||
count(
|
|
||||||
distinct case
|
|
||||||
when
|
|
||||||
atpb.user_product_bundle_name
|
|
||||||
not in ({{ var("default_service") }})
|
|
||||||
then atpb.id_accommodation
|
|
||||||
else null
|
|
||||||
end
|
|
||||||
) as total_listings_with_product_bundle_with_paid_service,
|
|
||||||
count(
|
|
||||||
distinct case
|
|
||||||
when
|
|
||||||
atpb.user_product_bundle_name
|
|
||||||
not in ({{ var("default_service") }})
|
|
||||||
and atpb.has_no_end_date = true
|
|
||||||
then atpb.id_accommodation
|
|
||||||
else null
|
|
||||||
end
|
|
||||||
) as total_listings_with_active_product_bundle_with_paid_service,
|
|
||||||
-- To be deleted until here
|
|
||||||
count(
|
count(
|
||||||
distinct case
|
distinct case
|
||||||
when
|
when
|
||||||
|
|
@ -90,12 +72,13 @@ with
|
||||||
then atpb.id_accommodation
|
then atpb.id_accommodation
|
||||||
else null
|
else null
|
||||||
end
|
end
|
||||||
) as total_active_listings_with_active_product_bundle_with_paid_service
|
) as total_active_listings_with_active_upgraded_product_bundle
|
||||||
from int_core__user_product_bundle upb
|
from int_core__user_product_bundle upb
|
||||||
left join
|
inner join
|
||||||
int_core__accommodation_to_product_bundle atpb
|
int_core__accommodation_to_product_bundle atpb
|
||||||
on upb.id_user_product_bundle = atpb.id_user_product_bundle
|
on upb.id_user_product_bundle = atpb.id_user_product_bundle
|
||||||
inner join int_core__accommodation a on upb.id_user_host = a.id_user_host
|
inner join
|
||||||
|
int_core__accommodation a on atpb.id_accommodation = a.id_accommodation
|
||||||
where a.is_active = true
|
where a.is_active = true
|
||||||
group by 1
|
group by 1
|
||||||
),
|
),
|
||||||
|
|
@ -111,7 +94,7 @@ with
|
||||||
then btpb.id_booking
|
then btpb.id_booking
|
||||||
else null
|
else null
|
||||||
end
|
end
|
||||||
) as total_bookings_with_product_bundle_with_paid_service
|
) as total_bookings_with_upgraded_product_bundle
|
||||||
from int_core__user_product_bundle upb
|
from int_core__user_product_bundle upb
|
||||||
left join
|
left join
|
||||||
int_core__booking_to_product_bundle btpb
|
int_core__booking_to_product_bundle btpb
|
||||||
|
|
@ -125,6 +108,7 @@ with
|
||||||
uh.has_user_moved_from_old_dash,
|
uh.has_user_moved_from_old_dash,
|
||||||
uh.new_dash_version as user_migration_phase,
|
uh.new_dash_version as user_migration_phase,
|
||||||
uh.user_in_new_dash_since_date_utc as user_estimated_migration_date_utc,
|
uh.user_in_new_dash_since_date_utc as user_estimated_migration_date_utc,
|
||||||
|
uh.has_new_dash_default_migration_date,
|
||||||
kldd.deal_lifecycle_state,
|
kldd.deal_lifecycle_state,
|
||||||
uh.has_active_pms,
|
uh.has_active_pms,
|
||||||
uh.active_pms_list,
|
uh.active_pms_list,
|
||||||
|
|
@ -137,68 +121,147 @@ with
|
||||||
upb.total_active_user_product_bundles,
|
upb.total_active_user_product_bundles,
|
||||||
a.total_listings,
|
a.total_listings,
|
||||||
a.total_active_listings,
|
a.total_active_listings,
|
||||||
atpb.total_active_listings_with_active_product_bundle,
|
coalesce(
|
||||||
atpb.total_active_listings_with_active_product_bundle_with_paid_service,
|
atpb.total_active_listings_with_active_product_bundle, 0
|
||||||
-- To be deleted from here
|
) as total_active_listings_with_active_product_bundle,
|
||||||
atpb.total_listings_with_product_bundle_with_paid_service,
|
coalesce(
|
||||||
atpb.total_listings_with_active_product_bundle_with_paid_service,
|
atpb.total_active_listings_with_active_upgraded_product_bundle, 0
|
||||||
-- To be deleted until here
|
) as total_active_listings_with_active_upgraded_product_bundle,
|
||||||
btpb.total_bookings_with_product_bundle,
|
btpb.total_bookings_with_product_bundle,
|
||||||
btpb.total_bookings_with_product_bundle_with_paid_service
|
btpb.total_bookings_with_upgraded_product_bundle
|
||||||
from upb_aggregation upb
|
from upb_aggregation upb
|
||||||
left join accommodation_aggregation a on upb.id_user_host = a.id_user_host
|
left join accommodation_aggregation a on upb.id_user_host = a.id_user_host
|
||||||
left join atpb_aggregation atpb on upb.id_user_host = atpb.id_user_host
|
left join atpb_aggregation atpb on upb.id_user_host = atpb.id_user_host
|
||||||
left join btpb_aggregation btpb on upb.id_user_host = btpb.id_user_host
|
left join btpb_aggregation btpb on upb.id_user_host = btpb.id_user_host
|
||||||
inner join int_core__user_host uh on upb.id_user_host = uh.id_user_host
|
inner join int_core__user_host uh on upb.id_user_host = uh.id_user_host
|
||||||
left join int_kpis__lifecycle_daily_deal kldd on uh.id_deal = kldd.id_deal
|
left join int_kpis__lifecycle_daily_deal kldd on uh.id_deal = kldd.id_deal
|
||||||
|
),
|
||||||
|
user_with_boolean_features as (
|
||||||
|
select
|
||||||
|
id_user_host,
|
||||||
|
id_deal,
|
||||||
|
has_user_moved_from_old_dash,
|
||||||
|
user_migration_phase,
|
||||||
|
user_estimated_migration_date_utc,
|
||||||
|
has_new_dash_default_migration_date,
|
||||||
|
deal_lifecycle_state,
|
||||||
|
has_active_pms,
|
||||||
|
active_pms_list,
|
||||||
|
company_name,
|
||||||
|
first_name,
|
||||||
|
last_name,
|
||||||
|
email,
|
||||||
|
account_currency,
|
||||||
|
total_user_product_bundles,
|
||||||
|
total_active_user_product_bundles,
|
||||||
|
total_listings,
|
||||||
|
total_active_listings,
|
||||||
|
total_active_listings_with_active_product_bundle,
|
||||||
|
total_active_listings_with_active_upgraded_product_bundle,
|
||||||
|
case
|
||||||
|
when total_active_listings > 0 then 1 else 0
|
||||||
|
end as has_active_listings,
|
||||||
|
case
|
||||||
|
when total_active_listings_with_active_product_bundle > 0 then 1 else 0
|
||||||
|
end as has_active_listings_with_active_product_bundle_applied,
|
||||||
|
case
|
||||||
|
when total_active_listings_with_active_upgraded_product_bundle > 0
|
||||||
|
then 1
|
||||||
|
else 0
|
||||||
|
end as has_active_listings_with_active_upgraded_service_applied,
|
||||||
|
total_bookings_with_product_bundle,
|
||||||
|
total_bookings_with_upgraded_product_bundle,
|
||||||
|
case
|
||||||
|
when total_bookings_with_product_bundle > 0 then 1 else 0
|
||||||
|
end as has_bookings_with_product_bundle,
|
||||||
|
case
|
||||||
|
when total_bookings_with_upgraded_product_bundle > 0 then 1 else 0
|
||||||
|
end as has_bookings_with_upgraded_product_bundle
|
||||||
|
from user_aggregation
|
||||||
)
|
)
|
||||||
select
|
select
|
||||||
id_user_host,
|
*,
|
||||||
id_deal,
|
|
||||||
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,
|
|
||||||
first_name,
|
|
||||||
last_name,
|
|
||||||
email,
|
|
||||||
account_currency,
|
|
||||||
total_user_product_bundles,
|
|
||||||
total_active_user_product_bundles,
|
|
||||||
total_listings,
|
|
||||||
total_active_listings,
|
|
||||||
total_active_listings_with_active_product_bundle,
|
|
||||||
total_active_listings_with_active_product_bundle_with_paid_service,
|
|
||||||
case when total_active_listings > 0 then 1 else 0 end as has_active_listings,
|
|
||||||
case
|
case
|
||||||
when total_active_listings_with_active_product_bundle > 0 then 1 else 0
|
-- 99 - DATA QUALITY ISSUES --
|
||||||
end as has_active_listings_with_active_product_bundle_applied,
|
when has_new_dash_default_migration_date
|
||||||
case
|
then '99 - Has Data Quality Issues'
|
||||||
when total_active_listings_with_active_product_bundle_with_paid_service > 0
|
when
|
||||||
then 1
|
deal_lifecycle_state = '{{ deal_lifecycle_state_with_data_quality_issues }}'
|
||||||
else 0
|
then '99 - Has Data Quality Issues'
|
||||||
end as has_active_listings_with_active_paid_service_applied,
|
-- 98 - DEAL ALREADY CHURNED --
|
||||||
-- To be deleted from here
|
when deal_lifecycle_state in {{ deal_lifecycle_states_churned }}
|
||||||
total_listings_with_product_bundle_with_paid_service,
|
then '98 - Has Churned'
|
||||||
total_listings_with_active_product_bundle_with_paid_service,
|
-- 00-08 - CATEGORISE THE USER BASED ON THE LISTING AND BOOKING BEHAVIOR --
|
||||||
case
|
-- No Listings
|
||||||
when total_listings_with_product_bundle_with_paid_service > 0 then 1 else 0
|
when total_listings = 0
|
||||||
end as has_listings_with_paid_service_applied,
|
then '01 - No Listings'
|
||||||
case
|
|
||||||
when total_listings_with_active_product_bundle_with_paid_service > 0
|
-- No Active Listings
|
||||||
then 1
|
when has_active_listings = 0
|
||||||
else 0
|
then '02 - No Active Listings'
|
||||||
end as has_listings_with_active_paid_service_applied,
|
|
||||||
-- To be deleted until here
|
-- No Bookings - Can only generate Basic Screening Bookings
|
||||||
total_bookings_with_product_bundle,
|
when
|
||||||
total_bookings_with_product_bundle_with_paid_service,
|
has_active_listings = 1
|
||||||
case
|
and has_bookings_with_product_bundle = 0
|
||||||
when total_bookings_with_product_bundle > 0 then 1 else 0
|
and has_active_listings_with_active_upgraded_service_applied = 0
|
||||||
end as has_bookings_with_product_bundle,
|
then '03 - No Bookings - No Upgraded Program in Listings'
|
||||||
case
|
|
||||||
when total_bookings_with_product_bundle_with_paid_service > 0 then 1 else 0
|
-- No Bookings - Can generate Upgraded Bookings
|
||||||
end as has_bookings_with_product_bundle_with_paid_service
|
when
|
||||||
from user_aggregation
|
has_active_listings = 1
|
||||||
|
and has_bookings_with_product_bundle = 0
|
||||||
|
and has_active_listings_with_active_upgraded_service_applied = 1
|
||||||
|
then '04 - No Bookings - Has Upgraded Program in Listings'
|
||||||
|
|
||||||
|
-- Only Basic Screening Bookings - Can only generate Basic Screening
|
||||||
|
-- Bookings
|
||||||
|
when
|
||||||
|
has_active_listings = 1
|
||||||
|
and has_bookings_with_product_bundle = 1
|
||||||
|
and has_bookings_with_upgraded_product_bundle = 0
|
||||||
|
and has_active_listings_with_active_upgraded_service_applied = 0
|
||||||
|
then '05 - Only Basic Screening Bookings - No Upgraded Program in Listings'
|
||||||
|
|
||||||
|
-- Only Basic Screening Bookings - Can generate Upgraded Bookings
|
||||||
|
when
|
||||||
|
has_active_listings = 1
|
||||||
|
and has_bookings_with_product_bundle = 1
|
||||||
|
and has_bookings_with_upgraded_product_bundle = 0
|
||||||
|
and has_active_listings_with_active_upgraded_service_applied = 1
|
||||||
|
then '06 - Only Basic Screening Bookings - Has Upgraded Program in Listings'
|
||||||
|
|
||||||
|
-- Has Upgraded Bookings - No longer can generate Upgraded Bookings
|
||||||
|
when
|
||||||
|
has_active_listings = 1
|
||||||
|
and has_bookings_with_product_bundle = 1
|
||||||
|
and has_bookings_with_upgraded_product_bundle = 1
|
||||||
|
and has_active_listings_with_active_upgraded_service_applied = 0
|
||||||
|
then '07 - Has Upgraded Bookings - No Upgraded Program in Listings'
|
||||||
|
|
||||||
|
-- Has Upgraded Bookings - Not all listings have Upgraded Program
|
||||||
|
when
|
||||||
|
has_active_listings = 1
|
||||||
|
and has_bookings_with_product_bundle = 1
|
||||||
|
and has_bookings_with_upgraded_product_bundle = 1
|
||||||
|
and has_active_listings_with_active_upgraded_service_applied = 1
|
||||||
|
and total_active_listings_with_active_upgraded_product_bundle
|
||||||
|
< total_active_listings
|
||||||
|
then
|
||||||
|
'08 - Has Upgraded Bookings - Not all Listings have Upgraded Program Applied'
|
||||||
|
|
||||||
|
-- No Alert - Has Upgraded Bookings - Can generate Upgraded Bookings
|
||||||
|
-- in all listings
|
||||||
|
when
|
||||||
|
has_active_listings = 1
|
||||||
|
and has_bookings_with_product_bundle = 1
|
||||||
|
and has_bookings_with_upgraded_product_bundle = 1
|
||||||
|
and has_active_listings_with_active_upgraded_service_applied = 1
|
||||||
|
and total_active_listings_with_active_upgraded_product_bundle
|
||||||
|
= total_active_listings
|
||||||
|
then '00 - No Alert'
|
||||||
|
else 'UNKNOWN'
|
||||||
|
|
||||||
|
end as user_categorisation
|
||||||
|
|
||||||
|
from user_with_boolean_features
|
||||||
|
|
|
||||||
|
|
@ -1,5 +1,3 @@
|
||||||
{% set new_dash_mvp_launch_date = "2024-07-30" %}
|
|
||||||
|
|
||||||
{{ config(materialized="table") }}
|
{{ config(materialized="table") }}
|
||||||
with
|
with
|
||||||
stg_core__claim as (select * from {{ ref("stg_core__claim") }}),
|
stg_core__claim as (select * from {{ ref("stg_core__claim") }}),
|
||||||
|
|
@ -53,12 +51,23 @@ select
|
||||||
coalesce(
|
coalesce(
|
||||||
nduwmd.new_dash_move_at_utc,
|
nduwmd.new_dash_move_at_utc,
|
||||||
greatest(
|
greatest(
|
||||||
u.joined_at_utc, cast(date('{{new_dash_mvp_launch_date}}') as timestamp)
|
u.joined_at_utc,
|
||||||
|
cast(date({{ var("new_dash_mvp_launch_date") }}) as timestamp)
|
||||||
)
|
)
|
||||||
) as user_in_new_dash_since_timestamp_at_utc,
|
) as user_in_new_dash_since_timestamp_at_utc,
|
||||||
coalesce(
|
coalesce(
|
||||||
date(nduwmd.new_dash_move_at_utc),
|
date(nduwmd.new_dash_move_at_utc),
|
||||||
greatest(u.joined_date_utc, date('{{new_dash_mvp_launch_date}}'))
|
greatest(u.joined_date_utc, date({{ var("new_dash_mvp_launch_date") }}))
|
||||||
) as user_in_new_dash_since_date_utc
|
) as user_in_new_dash_since_date_utc,
|
||||||
|
case
|
||||||
|
when
|
||||||
|
coalesce(
|
||||||
|
date(nduwmd.new_dash_move_at_utc),
|
||||||
|
greatest(u.joined_date_utc, date({{ var("new_dash_mvp_launch_date") }}))
|
||||||
|
)
|
||||||
|
= date({{ var("new_dash_mvp_launch_date") }})
|
||||||
|
then true
|
||||||
|
else false
|
||||||
|
end as is_default_migration_date
|
||||||
from new_dash_users_with_move_date nduwmd
|
from new_dash_users_with_move_date nduwmd
|
||||||
inner join stg_core__user u on nduwmd.id_user_host = u.id_user
|
inner join stg_core__user u on nduwmd.id_user_host = u.id_user
|
||||||
|
|
|
||||||
|
|
@ -84,7 +84,10 @@ select
|
||||||
ndu.new_dash_move_at_utc,
|
ndu.new_dash_move_at_utc,
|
||||||
ndu.new_dash_move_date_utc,
|
ndu.new_dash_move_date_utc,
|
||||||
ndu.user_in_new_dash_since_timestamp_at_utc,
|
ndu.user_in_new_dash_since_timestamp_at_utc,
|
||||||
ndu.user_in_new_dash_since_date_utc
|
ndu.user_in_new_dash_since_date_utc,
|
||||||
|
coalesce(
|
||||||
|
ndu.is_default_migration_date, false
|
||||||
|
) as has_new_dash_default_migration_date
|
||||||
from int_core__unified_user uu
|
from int_core__unified_user uu
|
||||||
inner join unique_host_user uhu on uu.id_user = uhu.id_user
|
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__new_dash_users ndu on uu.id_user = ndu.id_user_host
|
||||||
|
|
|
||||||
|
|
@ -1810,6 +1810,14 @@ models:
|
||||||
these users can be considered in New Dash. If the user
|
these users can be considered in New Dash. If the user
|
||||||
has moved from Old Dash, it will be the new_dash_move_at_utc.
|
has moved from Old Dash, it will be the new_dash_move_at_utc.
|
||||||
If not, it will correspond to the joined_at_utc.
|
If not, it will correspond to the joined_at_utc.
|
||||||
|
- name: has_new_dash_default_migration_date
|
||||||
|
data_type: boolean
|
||||||
|
description: |
|
||||||
|
Flag to determine if the user migration date corresponds to
|
||||||
|
the default migration date. True if the user has the default
|
||||||
|
migration date, false if the user has a custom migration date
|
||||||
|
or is not in New Dash.
|
||||||
|
If true it might represent a data quality issue.
|
||||||
|
|
||||||
- name: int_core__new_dash_users
|
- name: int_core__new_dash_users
|
||||||
description: |
|
description: |
|
||||||
|
|
@ -1862,6 +1870,12 @@ models:
|
||||||
these users can be considered in New Dash. If the user
|
these users can be considered in New Dash. If the user
|
||||||
has moved from Old Dash, it will be the new_dash_move_at_utc.
|
has moved from Old Dash, it will be the new_dash_move_at_utc.
|
||||||
If not, it will correspond to the joined_at_utc.
|
If not, it will correspond to the joined_at_utc.
|
||||||
|
- name: is_default_migration_date
|
||||||
|
data_type: boolean
|
||||||
|
description: |
|
||||||
|
Flag to determine if the user migration date corresponds to
|
||||||
|
the default migration date. It might represent a data quality
|
||||||
|
issue.
|
||||||
|
|
||||||
- name: int_core__user_product_bundle
|
- name: int_core__user_product_bundle
|
||||||
description: |
|
description: |
|
||||||
|
|
@ -2316,6 +2330,13 @@ models:
|
||||||
data_tests:
|
data_tests:
|
||||||
- not_null
|
- not_null
|
||||||
|
|
||||||
|
- name: has_new_dash_default_migration_date
|
||||||
|
data_type: boolean
|
||||||
|
description: |
|
||||||
|
Flag to determine if the user migration date corresponds to
|
||||||
|
the default migration date. It might represent a data quality
|
||||||
|
issue.
|
||||||
|
|
||||||
- name: deal_lifecycle_state
|
- name: deal_lifecycle_state
|
||||||
data_type: character varying
|
data_type: character varying
|
||||||
description: |
|
description: |
|
||||||
|
|
@ -2402,7 +2423,7 @@ models:
|
||||||
description: |
|
description: |
|
||||||
Count of active listings that currently have an active product bundle.
|
Count of active listings that currently have an active product bundle.
|
||||||
|
|
||||||
- name: total_active_listings_with_active_product_bundle_with_paid_service
|
- name: total_active_listings_with_active_upgraded_product_bundle
|
||||||
data_type: integer
|
data_type: integer
|
||||||
description: |
|
description: |
|
||||||
Count of active listings that currently have an active paid service
|
Count of active listings that currently have an active paid service
|
||||||
|
|
@ -2419,41 +2440,18 @@ models:
|
||||||
Integer-based flag version of
|
Integer-based flag version of
|
||||||
total_active_listings_with_active_product_bundle.
|
total_active_listings_with_active_product_bundle.
|
||||||
|
|
||||||
- name: has_active_listings_with_active_paid_service_applied
|
- name: has_active_listings_with_active_upgraded_service_applied
|
||||||
data_type: integer
|
data_type: integer
|
||||||
description: |
|
description: |
|
||||||
Integer-based flag version of
|
Integer-based flag version of
|
||||||
total_active_listings_with_active_product_bundle_with_paid_service.
|
total_active_listings_with_active_upgraded_product_bundle.
|
||||||
|
|
||||||
# To be deleted from here
|
|
||||||
- name: total_listings_with_product_bundle_with_paid_service
|
|
||||||
data_type: integer
|
|
||||||
description: |
|
|
||||||
Count of listings that have, or have had, a paid service
|
|
||||||
product bundle activated.
|
|
||||||
|
|
||||||
- name: total_listings_with_active_product_bundle_with_paid_service
|
|
||||||
data_type: integer
|
|
||||||
description: |
|
|
||||||
Count of listings that currently have an active paid service
|
|
||||||
product bundle.
|
|
||||||
|
|
||||||
- name: has_listings_with_paid_service_applied
|
|
||||||
data_type: integer
|
|
||||||
description: |
|
|
||||||
Integer-based flag version of total_listings_with_product_bundle_with_paid_service.
|
|
||||||
|
|
||||||
- name: has_listings_with_active_paid_service_applied
|
|
||||||
data_type: integer
|
|
||||||
description: |
|
|
||||||
Integer-based flag version of total_listings_with_active_product_bundle_with_paid_service.
|
|
||||||
# To be deleted until here
|
|
||||||
- name: total_bookings_with_product_bundle
|
- name: total_bookings_with_product_bundle
|
||||||
data_type: integer
|
data_type: integer
|
||||||
description: |
|
description: |
|
||||||
Count of bookings that have a product bundle associated.
|
Count of bookings that have a product bundle associated.
|
||||||
|
|
||||||
- name: total_bookings_with_product_bundle_with_paid_service
|
- name: total_bookings_with_upgraded_product_bundle
|
||||||
data_type: integer
|
data_type: integer
|
||||||
description: |
|
description: |
|
||||||
Count of bookings that have a product bundle associated that contain
|
Count of bookings that have a product bundle associated that contain
|
||||||
|
|
@ -2464,10 +2462,44 @@ models:
|
||||||
description: |
|
description: |
|
||||||
Integer-based flag version of total_bookings_with_product_bundle.
|
Integer-based flag version of total_bookings_with_product_bundle.
|
||||||
|
|
||||||
- name: has_bookings_with_product_bundle_with_paid_service
|
- name: has_bookings_with_upgraded_product_bundle
|
||||||
data_type: integer
|
data_type: integer
|
||||||
description: |
|
description: |
|
||||||
Integer-based flag version of total_bookings_with_product_bundle_with_paid_service.
|
Integer-based flag version of total_bookings_with_upgraded_product_bundle.
|
||||||
|
|
||||||
|
- name: user_categorisation
|
||||||
|
data_type: string
|
||||||
|
description: |
|
||||||
|
Alert-based categorisation of the user based on the activity or lack of it.
|
||||||
|
The possible values are:
|
||||||
|
- "00 - No Alert"
|
||||||
|
- "01 - No Listings"
|
||||||
|
- "02 - No Active Listings"
|
||||||
|
- "03 - No Bookings - No Upgraded Program in Listings"
|
||||||
|
- "04 - No Bookings - Has Upgraded Program in Listings"
|
||||||
|
- "05 - Only Basic Screening Bookings - No Upgraded Program in Listings"
|
||||||
|
- "06 - Only Basic Screening Bookings - Has Upgraded Program in Listings"
|
||||||
|
- "07 - Has Upgraded Bookings - No Upgraded Program in Listings"
|
||||||
|
- "08 - Has Upgraded Bookings - Not all Listings have Upgraded Program Applied"
|
||||||
|
- "98 - Has Churned"
|
||||||
|
- "99 - Has Data Quality Issues"
|
||||||
|
It cannot be null.
|
||||||
|
|
||||||
|
data_tests:
|
||||||
|
- not_null
|
||||||
|
- accepted_values:
|
||||||
|
values:
|
||||||
|
- "00 - No Alert"
|
||||||
|
- "01 - No Listings"
|
||||||
|
- "02 - No Active Listings"
|
||||||
|
- "03 - No Bookings - No Upgraded Program in Listings"
|
||||||
|
- "04 - No Bookings - Has Upgraded Program in Listings"
|
||||||
|
- "05 - Only Basic Screening Bookings - No Upgraded Program in Listings"
|
||||||
|
- "06 - Only Basic Screening Bookings - Has Upgraded Program in Listings"
|
||||||
|
- "07 - Has Upgraded Bookings - No Upgraded Program in Listings"
|
||||||
|
- "08 - Has Upgraded Bookings - Not all Listings have Upgraded Program Applied"
|
||||||
|
- "98 - Has Churned"
|
||||||
|
- "99 - Has Data Quality Issues"
|
||||||
|
|
||||||
- name: int_core__invoicing_price_plans_per_month
|
- name: int_core__invoicing_price_plans_per_month
|
||||||
description: |
|
description: |
|
||||||
|
|
|
||||||
|
|
@ -22,26 +22,18 @@ select
|
||||||
total_active_listings as total_active_listings,
|
total_active_listings as total_active_listings,
|
||||||
total_active_listings_with_active_product_bundle
|
total_active_listings_with_active_product_bundle
|
||||||
as total_active_listings_with_active_product_bundle,
|
as total_active_listings_with_active_product_bundle,
|
||||||
total_active_listings_with_active_product_bundle_with_paid_service
|
total_active_listings_with_active_upgraded_product_bundle
|
||||||
as total_active_listings_with_active_product_bundle_with_paid_service,
|
as total_active_listings_with_active_product_bundle_with_paid_service,
|
||||||
has_active_listings as has_active_listings,
|
has_active_listings as has_active_listings,
|
||||||
has_active_listings_with_active_product_bundle_applied
|
has_active_listings_with_active_product_bundle_applied
|
||||||
as has_active_listings_with_active_product_bundle_applied,
|
as has_active_listings_with_active_product_bundle_applied,
|
||||||
has_active_listings_with_active_paid_service_applied
|
has_active_listings_with_active_upgraded_service_applied
|
||||||
as has_active_listings_with_active_paid_service_applied,
|
as has_active_listings_with_active_paid_service_applied,
|
||||||
-- To be deleted from here
|
|
||||||
total_listings_with_product_bundle_with_paid_service
|
|
||||||
as total_listings_with_product_bundle_with_paid_service,
|
|
||||||
total_listings_with_active_product_bundle_with_paid_service
|
|
||||||
as total_listings_with_active_product_bundle_with_paid_service,
|
|
||||||
has_listings_with_paid_service_applied as has_listings_with_paid_service_applied,
|
|
||||||
has_listings_with_active_paid_service_applied
|
|
||||||
as has_listings_with_active_paid_service_applied,
|
|
||||||
-- To be deleted until here
|
|
||||||
total_bookings_with_product_bundle as total_bookings_with_product_bundle,
|
total_bookings_with_product_bundle as total_bookings_with_product_bundle,
|
||||||
total_bookings_with_product_bundle_with_paid_service
|
total_bookings_with_upgraded_product_bundle
|
||||||
as total_bookings_with_product_bundle_with_paid_service,
|
as total_bookings_with_product_bundle_with_paid_service,
|
||||||
has_bookings_with_product_bundle as has_bookings_with_product_bundle,
|
has_bookings_with_product_bundle as has_bookings_with_product_bundle,
|
||||||
has_bookings_with_product_bundle_with_paid_service
|
has_bookings_with_upgraded_product_bundle
|
||||||
as has_bookings_with_product_bundle_with_paid_service
|
as has_bookings_with_product_bundle_with_paid_service,
|
||||||
|
user_categorisation as user_categorisation
|
||||||
from int_core__new_dash_user_overview
|
from int_core__new_dash_user_overview
|
||||||
|
|
|
||||||
|
|
@ -1044,17 +1044,31 @@ models:
|
||||||
description: |
|
description: |
|
||||||
Count of product bundles that this user has or has had.
|
Count of product bundles that this user has or has had.
|
||||||
It contains both active and historic cases.
|
It contains both active and historic cases.
|
||||||
|
data_tests:
|
||||||
|
- not_null
|
||||||
|
- dbt_expectations.expect_column_values_to_be_between:
|
||||||
|
min_value: 0
|
||||||
|
|
||||||
- name: total_active_user_product_bundles
|
- name: total_active_user_product_bundles
|
||||||
data_type: integer
|
data_type: integer
|
||||||
description: |
|
description: |
|
||||||
Count of product bundles that this user currently has.
|
Count of product bundles that this user currently has.
|
||||||
It contains only currently active cases.
|
It contains only currently active cases.
|
||||||
|
data_tests:
|
||||||
|
- not_null
|
||||||
|
- dbt_expectations.expect_column_values_to_be_between:
|
||||||
|
min_value: 0
|
||||||
|
max_value: total_user_product_bundles
|
||||||
|
strictly: false
|
||||||
|
|
||||||
- name: total_listings
|
- name: total_listings
|
||||||
data_type: integer
|
data_type: integer
|
||||||
description: |
|
description: |
|
||||||
Count of listings that the user owns or has owned.
|
Count of listings that the user owns or has owned.
|
||||||
|
data_tests:
|
||||||
|
- not_null
|
||||||
|
- dbt_expectations.expect_column_values_to_be_between:
|
||||||
|
min_value: 0
|
||||||
|
|
||||||
- name: total_active_listings
|
- name: total_active_listings
|
||||||
data_type: integer
|
data_type: integer
|
||||||
|
|
@ -1063,78 +1077,129 @@ models:
|
||||||
It contains only those that can accept bookings (hard
|
It contains only those that can accept bookings (hard
|
||||||
activation - not to be confused with activity-based
|
activation - not to be confused with activity-based
|
||||||
segmentation).
|
segmentation).
|
||||||
|
data_tests:
|
||||||
|
- not_null
|
||||||
|
- dbt_expectations.expect_column_values_to_be_between:
|
||||||
|
min_value: 0
|
||||||
|
max_value: total_listings
|
||||||
|
strictly: false
|
||||||
|
|
||||||
- name: total_active_listings_with_active_product_bundle
|
- name: total_active_listings_with_active_product_bundle
|
||||||
data_type: integer
|
data_type: integer
|
||||||
description: |
|
description: |
|
||||||
Count of active listings that currently have an active product bundle.
|
Count of active listings that currently have an active product bundle.
|
||||||
|
data_tests:
|
||||||
|
- not_null
|
||||||
|
- dbt_expectations.expect_column_values_to_be_between:
|
||||||
|
min_value: 0
|
||||||
|
max_value: total_active_listings
|
||||||
|
strictly: false
|
||||||
|
|
||||||
- name: total_active_listings_with_active_product_bundle_with_paid_service
|
- name: total_active_listings_with_active_product_bundle_with_paid_serv
|
||||||
data_type: integer
|
data_type: integer
|
||||||
description: |
|
description: |
|
||||||
Count of active listings that currently have an active paid service
|
Count of active listings that currently have an active paid service
|
||||||
product bundle.
|
product bundle.
|
||||||
|
Note the name of this column is truncated to fit the maximum length
|
||||||
|
of column characters in Postgres.
|
||||||
|
data_tests:
|
||||||
|
- not_null
|
||||||
|
- dbt_expectations.expect_column_values_to_be_between:
|
||||||
|
min_value: 0
|
||||||
|
max_value: total_active_listings
|
||||||
|
strictly: false
|
||||||
|
|
||||||
- name: has_active_listings
|
- name: has_active_listings
|
||||||
data_type: integer
|
data_type: integer
|
||||||
description: |
|
description: |
|
||||||
Integer-based flag version of total_active_listings.
|
Integer-based flag version of total_active_listings.
|
||||||
|
data_tests:
|
||||||
|
- not_null
|
||||||
|
|
||||||
- name: has_active_listings_with_active_product_bundle_applied
|
- name: has_active_listings_with_active_product_bundle_applied
|
||||||
data_type: integer
|
data_type: integer
|
||||||
description: |
|
description: |
|
||||||
Integer-based flag version of
|
Integer-based flag version of
|
||||||
total_active_listings_with_active_product_bundle.
|
total_active_listings_with_active_product_bundle.
|
||||||
|
data_tests:
|
||||||
|
- not_null
|
||||||
|
|
||||||
- name: has_active_listings_with_active_paid_service_applied
|
- name: has_active_listings_with_active_paid_service_applied
|
||||||
data_type: integer
|
data_type: integer
|
||||||
description: |
|
description: |
|
||||||
Integer-based flag version of
|
Integer-based flag version of
|
||||||
total_active_listings_with_active_product_bundle_with_paid_service.
|
total_active_listings_with_active_product_bundle_with_paid_service.
|
||||||
|
data_tests:
|
||||||
|
- not_null
|
||||||
|
|
||||||
# To be deleted from here
|
|
||||||
- name: total_listings_with_product_bundle_with_paid_service
|
|
||||||
data_type: integer
|
|
||||||
description: |
|
|
||||||
Count of listings that have, or have had, a paid service
|
|
||||||
product bundle activated.
|
|
||||||
|
|
||||||
- name: total_listings_with_active_product_bundle_with_paid_service
|
|
||||||
data_type: integer
|
|
||||||
description: |
|
|
||||||
Count of listings that currently have an active paid service
|
|
||||||
product bundle.
|
|
||||||
|
|
||||||
- name: has_listings_with_paid_service_applied
|
|
||||||
data_type: integer
|
|
||||||
description: |
|
|
||||||
Integer-based flag version of total_listings_with_product_bundle_with_paid_service.
|
|
||||||
|
|
||||||
- name: has_listings_with_active_paid_service_applied
|
|
||||||
data_type: integer
|
|
||||||
description: |
|
|
||||||
Integer-based flag version of total_listings_with_active_product_bundle_with_paid_service.
|
|
||||||
# To be deleted until here
|
|
||||||
- name: total_bookings_with_product_bundle
|
- name: total_bookings_with_product_bundle
|
||||||
data_type: integer
|
data_type: integer
|
||||||
description: |
|
description: |
|
||||||
Count of bookings that have a product bundle associated.
|
Count of bookings that have a product bundle associated.
|
||||||
|
data_tests:
|
||||||
|
- not_null
|
||||||
|
- dbt_expectations.expect_column_values_to_be_between:
|
||||||
|
min_value: 0
|
||||||
|
|
||||||
- name: total_bookings_with_product_bundle_with_paid_service
|
- name: total_bookings_with_product_bundle_with_paid_service
|
||||||
data_type: integer
|
data_type: integer
|
||||||
description: |
|
description: |
|
||||||
Count of bookings that have a product bundle associated that contain
|
Count of bookings that have a product bundle associated that contain
|
||||||
a paid service.
|
a paid service.
|
||||||
|
data_tests:
|
||||||
|
- not_null
|
||||||
|
- dbt_expectations.expect_column_values_to_be_between:
|
||||||
|
min_value: 0
|
||||||
|
max_value: total_bookings_with_product_bundle
|
||||||
|
strictly: false
|
||||||
|
|
||||||
- name: has_bookings_with_product_bundle
|
- name: has_bookings_with_product_bundle
|
||||||
data_type: integer
|
data_type: integer
|
||||||
description: |
|
description: |
|
||||||
Integer-based flag version of total_bookings_with_product_bundle.
|
Integer-based flag version of total_bookings_with_product_bundle.
|
||||||
|
data_tests:
|
||||||
|
- not_null
|
||||||
|
|
||||||
- name: has_bookings_with_product_bundle_with_paid_service
|
- name: has_bookings_with_product_bundle_with_paid_service
|
||||||
data_type: integer
|
data_type: integer
|
||||||
description: |
|
description: |
|
||||||
Integer-based flag version of total_bookings_with_product_bundle_with_paid_service.
|
Integer-based flag version of total_bookings_with_product_bundle_with_paid_service.
|
||||||
|
data_tests:
|
||||||
|
- not_null
|
||||||
|
|
||||||
|
- name: user_categorisation
|
||||||
|
data_type: string
|
||||||
|
description: |
|
||||||
|
Alert-based categorisation of the user based on the activity or lack of it.
|
||||||
|
The possible values are:
|
||||||
|
- "00 - No Alert"
|
||||||
|
- "01 - No Listings"
|
||||||
|
- "02 - No Active Listings"
|
||||||
|
- "03 - No Bookings - No Upgraded Program in Listings"
|
||||||
|
- "04 - No Bookings - Has Upgraded Program in Listings"
|
||||||
|
- "05 - Only Basic Screening Bookings - No Upgraded Program in Listings"
|
||||||
|
- "06 - Only Basic Screening Bookings - Has Upgraded Program in Listings"
|
||||||
|
- "07 - Has Upgraded Bookings - No Upgraded Program in Listings"
|
||||||
|
- "08 - Has Upgraded Bookings - Not all Listings have Upgraded Program Applied"
|
||||||
|
- "98 - Has Churned"
|
||||||
|
- "99 - Has Data Quality Issues"
|
||||||
|
It cannot be null.
|
||||||
|
|
||||||
|
data_tests:
|
||||||
|
- not_null
|
||||||
|
- accepted_values:
|
||||||
|
values:
|
||||||
|
- "00 - No Alert"
|
||||||
|
- "01 - No Listings"
|
||||||
|
- "02 - No Active Listings"
|
||||||
|
- "03 - No Bookings - No Upgraded Program in Listings"
|
||||||
|
- "04 - No Bookings - Has Upgraded Program in Listings"
|
||||||
|
- "05 - Only Basic Screening Bookings - No Upgraded Program in Listings"
|
||||||
|
- "06 - Only Basic Screening Bookings - Has Upgraded Program in Listings"
|
||||||
|
- "07 - Has Upgraded Bookings - No Upgraded Program in Listings"
|
||||||
|
- "08 - Has Upgraded Bookings - Not all Listings have Upgraded Program Applied"
|
||||||
|
- "98 - Has Churned"
|
||||||
|
- "99 - Has Data Quality Issues"
|
||||||
|
|
||||||
- name: core__accommodations_activity
|
- name: core__accommodations_activity
|
||||||
description: |
|
description: |
|
||||||
|
|
|
||||||
Loading…
Add table
Add a link
Reference in a new issue