Re: subselect requires offset 0 for good performance.

From: Vik Fearing <vik(dot)fearing(at)dalibo(dot)com>
To: Scott Marlowe <scott(dot)marlowe(at)gmail(dot)com>
Cc: Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us>, "pgsql-performance(at)postgresql(dot)org" <pgsql-performance(at)postgresql(dot)org>
Subject: Re: subselect requires offset 0 for good performance.
Date: 2013-08-02 07:37:44
Message-ID: 51FB61C8.4090206@dalibo.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-performance

On 08/02/2013 03:22 AM, Scott Marlowe wrote:
> On Thu, Aug 1, 2013 at 5:44 PM, Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us> wrote:
>> Scott Marlowe <scott(dot)marlowe(at)gmail(dot)com> writes:
>>> I am running 8.4.15 and can try 8.4.17 if some patch has been applied
>>> to it to address this issue. I just want to know should I
>>> A: upgrade to 8.4.17
>>> or
>>> B: create a self contained test case.
>> A quick look at the release notes shows no planner fixes in 8.4.16 or
>> 8.4.17, so it would be rather surprising if (A) helps.
> OK. I was doing some initial testing and if I select out the 4 columns
> into a test table the query runs fast. If I select all the columns
> into a test table it runs slow, so it appears table width affects
> this. Will have more to report tomorrow on it.

I don't know what your query is, but here's one I was working on
yesterday that shows the problem. It may not be the smallest test case
possible, but it works.

EXPLAIN ANALYZE
WITH RECURSIVE
x (start_time) AS
(
SELECT generate_series(1, 1000000)
),
t (time, timeround) AS
(
SELECT time, time - time % 900000 AS timeround
FROM (SELECT min(start_time) AS time FROM x) AS tmp
UNION ALL
SELECT time, time - time % 900000
FROM (SELECT (SELECT min(start_time) AS time
FROM x
WHERE start_time >= t.timeround + 900000)
FROM t
WHERE t.time IS NOT NULL OFFSET 0
) tmp
)
SELECT count(*) FROM t WHERE time IS NOT NULL;

If you remove the OFFSET 0, you'll see two more subplans (because "time"
is referenced three times). The difference is much more noticeable if
you make the x CTE its own table.

Vik

PS: This query is emulating a LooseIndexScan.
http://wiki.postgresql.org/wiki/Loose_indexscan

In response to

Responses

Browse pgsql-performance by date

  From Date Subject
Next Message slapo 2013-08-02 13:43:16 Sub-optimal plan for a paginated query on a view with another view inside of it.
Previous Message Alvaro Herrera 2013-08-02 03:19:15 Re: Looks like merge join planning time is too big, 55 seconds