Roman Neuhauser wrote:
Because you don't have an index on "base" for the files table.
I added one, ran vacuum full analyze fix.files, and:
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)
Which is exactly what I expected. Using left prefix of a multicolumn
index normally works just fine, thank you.
Couldn't figure out what you meant here - had to go back and re-read
your index definitions. Sorry - missed the (base, ...) on the front of
base_storename_idx.
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.
--
Richard Huxton
Archonet Ltd
---------------------------(end of broadcast)---------------------------
TIP 6: explain analyze is your friend