Re: Possible to improve query plan?

From: Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us>
To: Jeremy Palmer <JPalmer(at)linz(dot)govt(dot)nz>
Cc: "pgsql-performance(at)postgresql(dot)org" <pgsql-performance(at)postgresql(dot)org>
Subject: Re: Possible to improve query plan?
Date: 2011-01-17 20:24:26
Message-ID: 20065.1295295866@sss.pgh.pa.us
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-performance

Jeremy Palmer <JPalmer(at)linz(dot)govt(dot)nz> writes:
> I've come to a dead end in trying to get a commonly used query to
> perform better.

> EXPLAIN
> SELECT * FROM (
> SELECT
> row_number() OVER (PARTITION BY id ORDER BY _revision_created DESC) as row_number,
> *
> FROM
> version_crs_coordinate_revision
> WHERE (
> (_revision_created <= 16 AND _revision_expired > 16 AND _revision_expired <= 40) OR
> (_revision_created > 16 AND _revision_created <= 40)
> )
> ) AS T
> WHERE row_number = 1;

If I'm not mistaken, that's a DB2-ish locution for a query with DISTINCT
ON, ie, you're looking for the row with highest _revision_created for
each value of id. It might perform well on DB2, but it's going to
mostly suck on Postgres --- we don't optimize window-function queries
very much at all at the moment. Try writing it with DISTINCT ON instead
of a window function, like so:

SELECT DISTINCT ON (id)
*
FROM
version_crs_coordinate_revision
WHERE (
(_revision_created <= 16 AND _revision_expired > 16 AND _revision_expired <= 40) OR
(_revision_created > 16 AND _revision_created <= 40)
)
ORDER BY id, _revision_created DESC;

You could also experiment with various forms of GROUP BY if you're loath
to use any Postgres-specific syntax.

regards, tom lane

In response to

Responses

Browse pgsql-performance by date

  From Date Subject
Next Message Kevin Grittner 2011-01-17 20:51:24 Re: Bad plan when join on function
Previous Message Pavel Stehule 2011-01-17 20:12:31 Re: Bad plan when join on function