strange order by behavior

Lists: pgsql-bugs
From: Jeffrey Melloy <jmelloy(at)visualdistortion(dot)org>
To: pgsql-bugs(at)postgresql(dot)org
Subject: strange order by behavior
Date: 2004-11-16 06:57:10
Message-ID: 4199A4C6.8060305@visualdistortion.org
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-bugs

I've run across a bug with order by:

select 1 as a order by a;
-- works

select 1 as a, 2 as b order by a;
-- works

select 1 as a, 2 as b order by a + b;
ERROR: column "a" does not exist

select * from (select 1 as a, 2 as b) stuff order by a + b;
-- works


From: Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us>
To: Jeffrey Melloy <jmelloy(at)visualdistortion(dot)org>
Cc: pgsql-bugs(at)postgresql(dot)org
Subject: Re: strange order by behavior
Date: 2004-11-17 05:14:57
Message-ID: 7238.1100668497@sss.pgh.pa.us
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-bugs

Jeffrey Melloy <jmelloy(at)visualdistortion(dot)org> writes:
> I've run across a bug with order by:
> select 1 as a order by a;
> -- works

> select 1 as a, 2 as b order by a + b;
> ERROR: column "a" does not exist

This isn't a bug, strangely enough. The "order by output-column-name"
syntax is a holdover from SQL92, in which ORDER BY items could only be
the names or numbers of SELECT output columns. The new SQL99 theory is
that ORDER BY items are expressions over the input columns, same as the
SELECT output expressions themselves. We have to walk a fine line in
deciding how much of each spec to support, and the line we've drawn is
that simple names will be sought as output column names, but any
expression more complex than a simple name is an expression over the
input columns.

regards, tom lane