Re: Why the planner is not using the INDEX . - Mailing list pgsql-performance

From David Gagnon
Subject Re: Why the planner is not using the INDEX .
Date
Msg-id 42C9D47E.7090103@siunik.com
Whole thread Raw
In response to Re: Why the planner is not using the INDEX .  (Stephan Szabo <sszabo@megazone.bigpanda.com>)
Responses Re: Why the planner is not using the INDEX .
Re: Why the planner is not using the INDEX .
Re: Why the planner is not using the INDEX .
List pgsql-performance
Thanks .. I miss that FK don't create indexed ...  since Primary key implicitly does ...

I'm a bit surprised of that behavior thought, since it means that if we delete a row from table A all tables (B,C,D) with FK pointing to this table (A) must be scanned. 
If there is no index on those tables it means we gone do all Sequantial scans. Than can cause significant performance problem!!!.

Is there a reason why implicit index aren't created when FK are declared.  I looked into the documentation and I haven't found a way to tell postgresql to automatically create an index when creating la FK.  Does it means I need to manage it EXPLICITLY with create index statement ?  Is there another way ?

Thanks for you help that simple answer will solve a lot of performance problem I have ...

/David


On Mon, 4 Jul 2005, David Gagnon wrote:
 
  If you can just help my understanding the choice of the planner.

Here is the Query:explain analyse SELECT IRNUM FROM IR       INNER JOIN IT ON  IT.ITIRNUM = ANY ('{1000, 2000}') AND
IT.ITYPNUM = 'M' AND IR.IRYPNUM = IT.ITYPNUM AND IR.IRNUM = IT.ITIRNUM       WHERE IRNUM = ANY ('{1000, 2000}') and IRYPNUM = 'M'

Here is the Query plan:

QUERY PLAN

Hash Join  (cost=1142.47..5581.75 rows=87 width=4) (actual
time=125.000..203.000 rows=2 loops=1) Hash Cond: ("outer".itirnum = "inner".irnum) ->  Seq Scan on it  (cost=0.00..3093.45 rows=31646 width=9) (actual
time=0.000..78.000 rows=2 loops=1)       Filter: ((itirnum = ANY ('{1000,2000}'::integer[])) AND
((itypnum)::text = 'M'::text))
 ->  Hash  (cost=1142.09..1142.09 rows=151 width=37) (actual
time=125.000..125.000 rows=0 loops=1)       ->  Index Scan using ir_pk on ir  (cost=0.00..1142.09 rows=151
width=37) (actual time=0.000..125.000 rows=2 loops=1)             Index Cond: ((irypnum)::text = 'M'::text)             Filter: (irnum = ANY ('{1000,2000}'::integer[]))
Total runtime: 203.000 ms   
 
    I don't understand why the planner do a Seq Scan (Seq Scan on table
IT ..) instead of passing by the followin index:   ALTER TABLE IT ADD CONSTRAINT IT_IR_FK foreign key (ITYPNUM,ITIRNUM)
references IR (IRYPNUM, IRNUM) ON UPDATE CASCADE;   
That doesn't create an index on IT.  Primary keys (and unique constraints)
create indexes, but not foreign keys.  Did you also create an index on
those fields?

Also it looks like it's way overestimating the number of rows that
condition would succeed for.  You might consider raising the statistics
targets on those columns and reanalyzing.
 

pgsql-performance by date:

Previous
From: Klint Gore
Date:
Subject: Re: plain inserts and deletes very slow
Next
From: Christopher Kings-Lynne
Date:
Subject: Re: Why the planner is not using the INDEX .