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

From David Gagnon
Subject Why the planner is not using the INDEX .
Date
Msg-id 42C994BD.3000909@siunik.com
Whole thread Raw
In response to Re: ported application having performance issues  (John Mendenhall <john@surfutopia.net>)
Responses Re: Why the planner is not using the INDEX .
Re: Why the planner is not using the INDEX .
List pgsql-performance
Hi all,

  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;

I tried some stuff but I'm not able to change this behavior.  The IT and IR table may be quite huge (from 20k to 1600k rows) so I think doing a SEQ SCAN is not a good idea.. am I wrong?  Is this query plan is oki for you ?

Thanks for your help.

/David
 P.S.: I'm using postgresql 8.0.3 on windows and I change those setting in  my postgresql.conf :
shared_buffers = 12000        # min 16, at least max_connections*2, 8KB each
work_mem = 15000        # min 64, size in KB



pgsql-performance by date:

Previous
From: Alvaro Herrera
Date:
Subject: Re: plain inserts and deletes very slow
Next
From: Stephan Szabo
Date:
Subject: Re: Why the planner is not using the INDEX .