From: | Richard Huxton <dev(at)archonet(dot)com> |
---|---|
To: | Ashish Karalkar <ashish_postgre(at)yahoo(dot)co(dot)in> |
Cc: | pggeneral <pgsql-general(at)postgresql(dot)org>, ashish(dot)karalkar(at)netcore(dot)co(dot)in |
Subject: | Re: Planner ignoring to use INDEX SCAN |
Date: | 2007-12-14 12:15:36 |
Message-ID: | 476273E8.7050601@archonet.com |
Views: | Raw Message | Whole Thread | Download mbox | Resend email |
Thread: | |
Lists: | pgsql-general |
Ashish Karalkar wrote:
>
> Richard Huxton <dev(at)archonet(dot)com> wrote: Ashish Karalkar wrote:
>> query which was taking seconds on the join of these two table
>> suddenly started taking 20/25 min
>
> Show the EXPLAIN ANALYSE of your problem query and someone will be able
> to tell you why.
>
> Here is the output from explain analyse:
Actually, this is the output from EXPLAIN not EXPLAIN ANALYSE. It
doesn't show what actually happened, just what the planner thought was
going to happen.
Are the row-estimates roughly accurate?
> table structures are more or less same with delivery being parent and sms_new being child having index on deliveryid in both tables.
>
> HashAggregate (cost=6153350.21..6153352.38 rows=174 width=32)
> -> Hash Join (cost=218058.30..6153259.97 rows=6016 width=32)
> Hash Cond: ("outer".deliveryid = "inner".deliveryid)
> -> Seq Scan on sms_new (cost=0.00..5240444.80 rows=138939341 width=8)
> Filter: ((otid)::text !~~ 'ERROR%'::text)
> -> Hash (cost=218057.87..218057.87 rows=174 width=32)
Well, it knows that it's going to be expensive (cost=5240444.80). Since
it thinks you'll only get 174 rows from the other side and 6016
matching, I can't see how an index could be calculated as more expensive.
Try issuing ENABLE seq_scan=off and re-running the EXPLAIN, let's see
what cost that comes up with.
Oh, and I take it sms_new is recently vacuumed and analysed?
--
Richard Huxton
Archonet Ltd
From | Date | Subject | |
---|---|---|---|
Next Message | André Volpato | 2007-12-14 12:18:10 | Re: Hash join in 8.3 |
Previous Message | Hannu Krosing | 2007-12-14 12:15:17 | Re: [GENERAL] Slow PITR restore |