Merged PR 3671: Refactor new dash user overview
# Description This query refactors the model `int_core__new_dash_user_overview` to optimize performance. The output of the model remains unaltered. The performance gains are obtained by preventing a monster-grade intermediate join with almost 100 million rows + a sequential order that the current `master` model causes. This refactor breaks down the query that caused that into multiple CTEs that pre-aggregate results, avoiding the dimensional explosion. # 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
This commit is contained in:
commit
96f061e122
1 changed files with 52 additions and 21 deletions
|
|
@ -11,31 +11,34 @@ with
|
||||||
int_core__accommodation_to_product_bundle as (
|
int_core__accommodation_to_product_bundle as (
|
||||||
select * from {{ ref("int_core__accommodation_to_product_bundle") }}
|
select * from {{ ref("int_core__accommodation_to_product_bundle") }}
|
||||||
),
|
),
|
||||||
|
upb_aggregation as (
|
||||||
user_aggregation as (
|
|
||||||
|
|
||||||
select
|
select
|
||||||
upb.id_user_host,
|
upb.id_user_host,
|
||||||
uh.id_deal,
|
|
||||||
uh.new_dash_version as user_migration_phase,
|
|
||||||
uh.user_in_new_dash_since_date_utc as user_estimated_migration_date_utc,
|
|
||||||
uh.company_name,
|
|
||||||
uh.first_name,
|
|
||||||
uh.last_name,
|
|
||||||
uh.email,
|
|
||||||
uh.account_currency_iso4217 as account_currency,
|
|
||||||
count(distinct upb.id_user_product_bundle) as total_user_product_bundles,
|
count(distinct upb.id_user_product_bundle) as total_user_product_bundles,
|
||||||
count(
|
count(
|
||||||
distinct case
|
distinct case
|
||||||
when upb.has_no_end_date then upb.id_user_product_bundle else null
|
when upb.has_no_end_date then upb.id_user_product_bundle else null
|
||||||
end
|
end
|
||||||
) as total_active_user_product_bundles,
|
) as total_active_user_product_bundles
|
||||||
|
from int_core__user_product_bundle upb
|
||||||
|
group by 1
|
||||||
|
),
|
||||||
|
accommodation_aggregation as (
|
||||||
|
select
|
||||||
|
upb.id_user_host,
|
||||||
count(distinct a.id_accommodation) as total_listings,
|
count(distinct a.id_accommodation) as total_listings,
|
||||||
count(
|
count(
|
||||||
distinct case
|
distinct case
|
||||||
when a.is_active = true then a.id_accommodation else null
|
when a.is_active = true then a.id_accommodation else null
|
||||||
end
|
end
|
||||||
) as total_active_listings,
|
) as total_active_listings
|
||||||
|
from int_core__user_product_bundle upb
|
||||||
|
left join int_core__accommodation a on upb.id_user_host = a.id_user_host
|
||||||
|
group by 1
|
||||||
|
),
|
||||||
|
atpb_aggregation as (
|
||||||
|
select
|
||||||
|
upb.id_user_host,
|
||||||
count(
|
count(
|
||||||
distinct case
|
distinct case
|
||||||
when
|
when
|
||||||
|
|
@ -54,7 +57,16 @@ with
|
||||||
then atpb.id_accommodation
|
then atpb.id_accommodation
|
||||||
else null
|
else null
|
||||||
end
|
end
|
||||||
) as total_listings_with_active_product_bundle_with_paid_service,
|
) as total_listings_with_active_product_bundle_with_paid_service
|
||||||
|
from int_core__user_product_bundle upb
|
||||||
|
left join
|
||||||
|
int_core__accommodation_to_product_bundle atpb
|
||||||
|
on upb.id_user_product_bundle = atpb.id_user_product_bundle
|
||||||
|
group by 1
|
||||||
|
),
|
||||||
|
btpb_aggregation as (
|
||||||
|
select
|
||||||
|
upb.id_user_host,
|
||||||
count(distinct btpb.id_booking) as total_bookings_with_product_bundle,
|
count(distinct btpb.id_booking) as total_bookings_with_product_bundle,
|
||||||
count(
|
count(
|
||||||
distinct case
|
distinct case
|
||||||
|
|
@ -66,16 +78,35 @@ with
|
||||||
end
|
end
|
||||||
) as total_bookings_with_product_bundle_with_paid_service
|
) as total_bookings_with_product_bundle_with_paid_service
|
||||||
from int_core__user_product_bundle upb
|
from int_core__user_product_bundle upb
|
||||||
inner join int_core__user_host uh on upb.id_user_host = uh.id_user_host
|
|
||||||
left join
|
left join
|
||||||
int_core__booking_to_product_bundle btpb
|
int_core__booking_to_product_bundle btpb
|
||||||
on upb.id_user_product_bundle = btpb.id_user_product_bundle
|
on upb.id_user_product_bundle = btpb.id_user_product_bundle
|
||||||
left join int_core__accommodation a on upb.id_user_host = a.id_user_host
|
group by 1
|
||||||
left join
|
),
|
||||||
int_core__accommodation_to_product_bundle atpb
|
user_aggregation as (
|
||||||
on upb.id_user_product_bundle = atpb.id_user_product_bundle
|
select
|
||||||
group by 1, 2, 3, 4, 5, 6, 7, 8, 9
|
upb.id_user_host,
|
||||||
|
uh.id_deal,
|
||||||
|
uh.new_dash_version as user_migration_phase,
|
||||||
|
uh.user_in_new_dash_since_date_utc as user_estimated_migration_date_utc,
|
||||||
|
uh.company_name,
|
||||||
|
uh.first_name,
|
||||||
|
uh.last_name,
|
||||||
|
uh.email,
|
||||||
|
uh.account_currency_iso4217 as account_currency,
|
||||||
|
upb.total_user_product_bundles,
|
||||||
|
upb.total_active_user_product_bundles,
|
||||||
|
a.total_listings,
|
||||||
|
a.total_active_listings,
|
||||||
|
atpb.total_listings_with_product_bundle_with_paid_service,
|
||||||
|
atpb.total_listings_with_active_product_bundle_with_paid_service,
|
||||||
|
btpb.total_bookings_with_product_bundle,
|
||||||
|
btpb.total_bookings_with_product_bundle_with_paid_service
|
||||||
|
from upb_aggregation upb
|
||||||
|
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 btpb_aggregation btpb on upb.id_user_host = btpb.id_user_host
|
||||||
|
left join int_core__user_host uh on upb.id_user_host = uh.id_user_host
|
||||||
)
|
)
|
||||||
select
|
select
|
||||||
id_user_host,
|
id_user_host,
|
||||||
|
|
|
||||||
Loading…
Add table
Add a link
Reference in a new issue