BUG #5018: Window function alias

Lists: pgsql-bugs
From: "Marko Tiikkaja" <marko(dot)tiikkaja(at)cs(dot)helsinki(dot)fi>
To: pgsql-bugs(at)postgresql(dot)org
Subject: BUG #5018: Window function alias
Date: 2009-08-27 11:22:02
Message-ID: 200908271122.n7RBM2Cs083448@wwwmaster.postgresql.org
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-bugs


The following bug has been logged online:

Bug reference: 5018
Logged by: Marko Tiikkaja
Email address: marko(dot)tiikkaja(at)cs(dot)helsinki(dot)fi
PostgreSQL version: 8.4.0
Operating system: Linux
Description: Window function alias
Details:

I came across this:

=> SELECT lead(foo) OVER(ORDER BY foo) AS foo FROM (VALUES(0)) bar(foo);
ERROR: window functions not allowed in window definition

Changing the *column alias* to something else gives the expected answer. Is
this really the desired behaviour?


From: Heikki Linnakangas <heikki(dot)linnakangas(at)enterprisedb(dot)com>
To: Marko Tiikkaja <marko(dot)tiikkaja(at)cs(dot)helsinki(dot)fi>
Cc: pgsql-bugs(at)postgresql(dot)org
Subject: Re: BUG #5018: Window function alias
Date: 2009-08-27 13:19:44
Message-ID: 4A9687F0.2060501@enterprisedb.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-bugs

Marko Tiikkaja wrote:
> I came across this:
>
> => SELECT lead(foo) OVER(ORDER BY foo) AS foo FROM (VALUES(0)) bar(foo);
> ERROR: window functions not allowed in window definition
>
> Changing the *column alias* to something else gives the expected answer. Is
> this really the desired behaviour?

It makes sense if you refer another column:

SELECT foo*2 AS col1, lead(foo) OVER(ORDER BY col1) AS foo
FROM (VALUES(0), (1)) bar(foo);

I'm not sure what the SQL spec says about that, but it seems OK to me.

--
Heikki Linnakangas
EnterpriseDB http://www.enterprisedb.com


From: Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us>
To: Heikki Linnakangas <heikki(dot)linnakangas(at)enterprisedb(dot)com>
Cc: Marko Tiikkaja <marko(dot)tiikkaja(at)cs(dot)helsinki(dot)fi>, pgsql-bugs(at)postgresql(dot)org
Subject: Re: BUG #5018: Window function alias
Date: 2009-08-27 14:29:37
Message-ID: 3276.1251383377@sss.pgh.pa.us
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-bugs

Heikki Linnakangas <heikki(dot)linnakangas(at)enterprisedb(dot)com> writes:
> Marko Tiikkaja wrote:
>> I came across this:
>>
>> => SELECT lead(foo) OVER(ORDER BY foo) AS foo FROM (VALUES(0)) bar(foo);
>> ERROR: window functions not allowed in window definition
>>
>> Changing the *column alias* to something else gives the expected answer. Is
>> this really the desired behaviour?

> It makes sense if you refer another column:

> SELECT foo*2 AS col1, lead(foo) OVER(ORDER BY col1) AS foo
> FROM (VALUES(0), (1)) bar(foo);

> I'm not sure what the SQL spec says about that, but it seems OK to me.

I think it's a bug. If you change it to this, it doesn't complain:

regression=# SELECT lead(foo) OVER(ORDER BY foo) AS fool FROM (VALUES(0)) bar(foo);
fool
------

(1 row)

We're getting bit by interpreting window-function ORDER BY arguments
according to SQL92 rules, in which they could refer to output-column
aliases. This clearly has the potential to introduce circularity,
as here. I think it would probably be best if we use strict SQL99
interpretation: window function PARTITION/ORDER arguments cannot be
interpreted as output-column names or numbers.

regards, tom lane