Multi-column join + aggregate subquery resulting in infinite run time - Mailing list pgsql-novice
From | Steve Estes |
---|---|
Subject | Multi-column join + aggregate subquery resulting in infinite run time |
Date | |
Msg-id | CAJjrZPCQcL1u0GaUXhexwwAt8NWUxnKsr+vjKYuY2H45jv_y4g@mail.gmail.com Whole thread Raw |
Responses |
Re: Multi-column join + aggregate subquery resulting in infinite run time
|
List | pgsql-novice |
SELECT ad.acct_id, ad.entity_name, ad.address, acx.flag_infobase_match
FROM prod_account_details ad
INNER JOIN prod_customer_profiles acx ON ad.acct_id = acx.acct_id
AND ad.address = acx.match_input_address;
...returns the 532k matched records in 3.0 seconds.
SELECT ad.acct_id, ad.entity_name, ad.address, acx.flag_infobase_match, dl.num_records AS dl_count
FROM prod_account_details ad
INNER JOIN prod_customer_profiles acx ON ad.acct_id = acx.acct_id
AND ad.address = acx.match_input_address
INNER JOIN (SELECT count(*) AS num_records, acct_id FROM prod_dunning_letters GROUP BY acct_id ) dl ON ad.acct_id = dl.acct_id;
SELECT ad.acct_id, ad.entity_name, ad.address, acx.flag_infobase_match, dl.num_records AS dl_count
FROM prod_account_details ad
INNER JOIN prod_customer_profiles acx ON ad.acct_id = acx.acct_id
AND ad.address = acx.match_input_address
LEFT JOIN (SELECT count(*) AS num_records, acct_id FROM prod_dunning_letters GROUP BY acct_id ) dl ON ad.acct_id = dl.acct_id;
SELECT ad.acct_id, ad.entity_name, ad.address, acx.flag_infobase_match, dl.num_records AS dl_count
FROM prod_account_details ad
INNER JOIN prod_customer_profiles acx ON ad.acct_id = acx.acct_id
-- AND ad.address = acx.match_input_address
LEFT JOIN (SELECT count(*) AS num_records, acct_id FROM prod_dunning_letters GROUP BY acct_id ) dl ON ad.acct_id = dl.acct_id;
Workers Planned: 2
-> Parallel Hash Join (cost=101995.20..122944.22 rows=1 width=41)
Hash Cond: ((ad.acct_id = acx.acct_id) AND (ad.address = (acx.match_input_address)::text))
-> Parallel Seq Scan on prod_account_details ad (cost=0.00..14226.43 rows=224343 width=39)
-> Parallel Hash (cost=97096.88..97096.88 rows=224288 width=26)
-> Parallel Seq Scan on prod_customer_profiles acx (cost=0.00..97096.88 rows=224288 width=26)
Workers Planned: 2
-> Nested Loop (cost=21500.40..82636.33 rows=1 width=49)
-> Hash Join (cost=21500.40..40427.74 rows=56285 width=54)
Hash Cond: (ad.acct_id = prod_dunning_letters.acct_id)
-> Parallel Seq Scan on prod_account_details ad (cost=0.00..14226.43 rows=224343 width=39)
-> Hash (cost=19345.40..19345.40 rows=123920 width=15)
-> GroupAggregate (cost=0.42..18106.20 rows=123920 width=15)
Group Key: prod_dunning_letters.acct_id
-> Index Only Scan using prod_dunning_letters_acct_id_idx on prod_dunning_letters (cost=0.42..14269.36 rows=519529 width=7)
-> Index Scan using prod_customer_profiles_match_input_address_idx on prod_customer_profiles acx (cost=0.00..0.74 rows=1 width=26)
Index Cond: ((match_input_address)::text = ad.address)
Filter: (ad.acct_id = acct_id)
Join Filter: (ad.acct_id = prod_dunning_letters.acct_id)
-> Gather (cost=102995.20..123944.32 rows=1 width=41)
Workers Planned: 2
-> Parallel Hash Join (cost=101995.20..122944.22 rows=1 width=41)
Hash Cond: ((ad.acct_id = acx.acct_id) AND (ad.address = (acx.match_input_address)::text))
-> Parallel Seq Scan on prod_account_details ad (cost=0.00..14226.43 rows=224343 width=39)
-> Parallel Hash (cost=97096.88..97096.88 rows=224288 width=26)
-> Parallel Seq Scan on prod_customer_profiles acx (cost=0.00..97096.88 rows=224288 width=26)
-> GroupAggregate (cost=0.42..18106.20 rows=123920 width=15)
Group Key: prod_dunning_letters.acct_id
-> Index Only Scan using prod_dunning_letters_acct_id_idx on prod_dunning_letters (cost=0.42..14269.36 rows=519529 width=7)
pgsql-novice by date: