Roman Neuhauser wrote:
# dev@xxxxxxxxxxxx / 2005-07-13 14:09:34 +0100:
Roman Neuhauser wrote:
callrec32=# \d fix.files
Table "fix.files"
Column | Type | Modifiers
--------+------------------------+-----------
dir | character varying(255) |
base | character varying(255) |
Indexes:
"base_storename_idx" btree (base, ((((dir)::text || '/'::text) ||
(base)::text)))
"ff_baseonly_idx" btree (base)
"ff_storename_idx" btree (((((dir)::text || '/'::text) ||
(base)::text)))
callrec32=# explain select fd.base from fix.dups fd join fix.files ff
using (base);
QUERY PLAN
----------------------------------------------------------------------------
Hash Join (cost=5340.00..292675.06 rows=176161 width=44)
Hash Cond: (("outer".base)::text = ("inner".base)::text)
-> Seq Scan on files ff (cost=0.00..117301.58 rows=5278458
width=41)
-> Hash (cost=3436.60..3436.60 rows=176160 width=44)
-> Seq Scan on dups fd (cost=0.00..3436.60 rows=176160
width=44)
(5 rows)
What happens to the plan if you SET enable_seqscan=false; first? It's
presumably getting the row-estimate right, so unless there's terrible
correlation on "base" in the files table I can only assume it's getting
the cost estimates horribly wrong.
callrec32=# SET enable_seqscan=false;
SET
callrec32=# explain select fd.base from fix.dups fd join fix.files ff using (base);
QUERY PLAN
--------------------------------------------------------------------------------------------
Nested Loop (cost=0.00..1066990.93 rows=176161 width=44)
-> Index Scan using dups_base_key on dups fd (cost=0.00..5570.86 rows=176160 width=44)
-> Index Scan using ff_baseonly_idx on files ff (cost=0.00..6.01 rows=1 width=41)
Index Cond: (("outer".base)::text = (ff.base)::text)
OK - so it thinks the cost of this plan will be about 1 million, whereas
the old plan was 290 thousand. The question is - why?
What are your planner settings? Ch 16.4.4.2 here
http://www.postgresql.org/docs/7.4/static/runtime-config.html#RUNTIME-CONFIG-QUERY
I'm guessing something to do with cpu_index_tuple_cost or random_page_cost.
--
Richard Huxton
Archonet Ltd
---------------------------(end of broadcast)---------------------------
TIP 9: In versions below 8.0, the planner will ignore your desire to
choose an index scan if your joining column's datatypes do not
match