Re: sequence query performance issues

From: "Peter Koczan" <pjkoczan(at)gmail(dot)com>
To: "Tom Lane" <tgl(at)sss(dot)pgh(dot)pa(dot)us>
Cc: "Richard Huxton" <dev(at)archonet(dot)com>, pgsql-performance <pgsql-performance(at)postgresql(dot)org>
Subject: Re: sequence query performance issues
Date: 2007-10-01 19:23:02
Message-ID: 4544e0330710011223q7676fd34mca7e82393510b2ec@mail.gmail.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-performance

> *light bulb* Ahhhhhhh, that's it. So, I guess the solution is either
> to cast the column or wait for 8.3 (which isn't a problem since the
> port won't be done until 8.3 is released anyway).

Just a quick bit of follow-up:

This query works and is equivalent to what I was trying to do (minus
the randomization and limiting):
=> select a.uid from generate_series(1000, 32000) as a(uid) where
a.uid::smallint not in (select uid from people where uid is not null);

It turns out that this and using coalesce are a wash in terms of
performance, usually coming within 10 ms of each other no matter what
limit and ordering constraints you put on the queries.

Peter

=> explain analyze select a.uid from generate_series(1000, 32767) as
a(uid) where a.uid not in (select coalesce(uid, 0) from people);
QUERY PLAN
-----------------------------------------------------------------------------------------------------------------------------
Function Scan on generate_series a (cost=718.41..733.41 rows=500
width=4) (actual time=68.742..186.340 rows=26808 loops=1)
Filter: (NOT (hashed subplan))
SubPlan
-> Seq Scan on people (cost=0.00..702.68 rows=6294 width=2)
(actual time=0.025..28.368 rows=6294 loops=1)
Total runtime: 286.311 ms
(5 rows)

=> explain analyze select a.uid from generate_series(1000, 32767) as
a(uid) where a.uid::smallint not in (select uid from people where uid
is not null);
QUERY PLAN
-----------------------------------------------------------------------------------------------------------------------------
Function Scan on generate_series a (cost=699.34..716.84 rows=500
width=4) (actual time=58.508..177.683 rows=26808 loops=1)
Filter: (NOT (hashed subplan))
SubPlan
-> Seq Scan on people (cost=0.00..686.94 rows=4958 width=2)
(actual time=0.017..23.123 rows=4971 loops=1)
Filter: (uid IS NOT NULL)
Total runtime: 277.699 ms
(6 rows)

In response to

Browse pgsql-performance by date

  From Date Subject
Next Message Decibel! 2007-10-02 15:57:18 Re: Linux mis-reporting memory
Previous Message Heikki Linnakangas 2007-09-29 08:05:18 Re: Non-blocking vacuum full