Re: Strange workaround for slow query

From: Yeb Havinga <yebhavinga(at)gmail(dot)com>
To: sverhagen(at)wps-nl(dot)com
Cc: pgsql-performance(at)postgresql(dot)org
Subject: Re: Strange workaround for slow query
Date: 2010-03-10 10:11:17
Message-ID: 4B977045.6040604@gmail.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-performance

sverhagen(at)wps-nl(dot)com wrote:
>
> Hi,
>
>
> EXPLAIN SELECT * FROM events_events LEFT OUTER JOIN events_event_types ON
> eventType_id=events_event_types.id WHERE severity=20 AND (eventType_id
> IN (71)) ORDER BY datetime DESC limit 50;
> QUERY PLAN
> -------------------------------------------------------------------------------------------------------------------------------------------
> Limit (cost=3.23..200.31 rows=50 width=131)
> -> Nested Loop (cost=3.23..49139.16 rows=12466 width=131)
> -> Index Scan Backward using events_events_eventtype_id_datetime_ind
> on events_events (cost=0.00..48886.61 rows=12466 width=93)
> Index Cond: (eventtype_id = 71)
> -> Materialize (cost=3.23..3.24 rows=1 width=38)
> -> Seq Scan on events_event_types (cost=0.00..3.23 rows=1 width=38)
> Filter: ((id = 71) AND (severity = 20))
>
>
> EXPLAIN SELECT * FROM events_events LEFT OUTER JOIN events_event_types ON
> eventType_id=events_event_types.id WHERE severity=70 AND (eventType_id
> IN (71, 999)) ORDER BY datetime DESC LIMIT 50;
> QUERY PLAN
> ------------------------------------------------------------------------------------------------------------------------------------------------------------
> Limit (cost=27290.24..27290.37 rows=50 width=131)
> -> Sort (cost=27290.24..27303.15 rows=5164 width=131)
> Sort Key: events_events.datetime
> -> Nested Loop (cost=22.95..27118.70 rows=5164 width=131)
> -> Seq Scan on events_event_types (cost=0.00..3.02 rows=17 width=38)
> Filter: (severity = 70)
> -> Bitmap Heap Scan on events_events (cost=22.95..1589.94 rows=408
> width=93)
> Recheck Cond: ((events_events.eventtype_id = ANY
> ('{71,999}'::bigint[])) AND (events_events.eventtype_id =
> events_event_types.id))
> -> Bitmap Index Scan on test_events_events_eventtype_id_severity_ind
> (cost=0.00..22.85 rows=408 width=0)
> Index Cond: ((events_events.eventtype_id = ANY ('{71,999}'::bigint[]))
> AND (events_events.eventtype_id = events_event_types.id))
>
Thanks - I'm sorry that I was not more specific earlier, but what would
be *really* helpful is the output of explain analyze, since that also
shows actual time, # rows and # loops of the inner nestloop. I'm
wondering though why you do a left outer join. From the \d output in the
previous mail, events_event.eventtype_id has a not null constraint and a
fk to events_event_types.id, so an inner join would be appropriate.
Outer joins limits the amount of join orders the planner considers, so a
better plan might arise when the join is changed to inner.

regards
Yeb Havinga

In response to

Responses

Browse pgsql-performance by date

  From Date Subject
Next Message sverhagen 2010-03-10 10:35:18 Re: Strange workaround for slow query
Previous Message sverhagen 2010-03-10 09:27:40 Re: Strange workaround for slow query