Обсуждение: Window function order changing order of whole query

Поиск
Список
Период
Сортировка

Window function order changing order of whole query

От
Thom Brown
Дата:
I tried posting this on the pgsql-sql but they don't seem to be posting successfully there, so I'm re-posting it here.

I've had a look at examples of lag and lead window functions with order by inside the OVER clause, and I'm confused as to why it influences the overall order in the output.

For example (for a table called category with incrementing id numbers up to 26):

SELECT id, lag(id) OVER (ORDER BY id DESC) FROM category;

This would yield:

id   lag
26   NULL
25   26
24   25

This is the equivalent of what we would get with:
SELECT id, lead(id) OVER (ORDER BY id ASC) FROM category ORDER BY id DESC;

I would expect the row order in the results not to be influenced by the OVER clause's ORDER BY as I thought that was just to determine how the aggregate window function's values would be output.  It's almost as if the main part of the query has inherited it's order from the OVER clause.

Am I missing something here?

Having a look around, it looks as if Postgres might be misbehaving.  According to this page, http://my.safaribooksonline.com/0596004818/sqlnut2-CHP-4-SECT-3, the ORDER BY in the window function's clause shouldn't be having this ordering effect:

"Furthermore, the order within these groups is defined by an ordering clause, but that order only affects function evaluation, and has no effect on the order in which rows are returned by the query."

The behaviour is unexpected from my perspective, but obviously there are workarounds.  Is anyone able to confirm any of this?

Thanks

Thom

Re: Window function order changing order of whole query

От
Martijn van Oosterhout
Дата:
On Mon, Oct 12, 2009 at 09:13:09AM +0100, Thom Brown wrote:
> I tried posting this on the pgsql-sql but they don't seem to be posting
> successfully there, so I'm re-posting it here.
>
> I've had a look at examples of lag and lead window functions with order by
> inside the OVER clause, and I'm confused as to why it influences the overall
> order in the output.

Given that you didn't specify an order for the outer query, postgres is
allowed to give you the rows in any order it likes. In this case that
happens to be the order you see. If you would like another order you
need to specify it.

> For example (for a table called category with incrementing id numbers up to
> 26):
>
> SELECT id, lag(id) OVER (ORDER BY id DESC) FROM category;
>
> This would yield:
>
> id   lag
> 26   NULL
> 25   26
> 24   25
>
> This is the equivalent of what we would get with:
> SELECT id, lead(id) OVER (ORDER BY id ASC) FROM category ORDER BY id DESC;

Have a nice day,
--
Martijn van Oosterhout   <kleptog@svana.org>   http://svana.org/kleptog/
> Please line up in a tree and maintain the heap invariant while
> boarding. Thank you for flying nlogn airlines.

Вложения