Thread: Column Does Not Exist Error: Order by an Particular Cell of an Array

Column Does Not Exist Error: Order by an Particular Cell of an Array

From
David Muller
Date:

Hello,

I have a question about ordering records based on a particular cell of a one dimensional Array.


For example, say I create a simple table (that just stores integers)...

```

gears=> CREATE TABLE foo ( value integer PRIMARY KEY);

CREATE TABLE

gears=> insert into foo Values(1);

INSERT 0 1

gears=> insert into foo Values(2);

INSERT 0 1

gears=> select * from foo;

 value 

-------

     1

     2

(2 rows)

```



Now, say I want to run a SELECT statement that also annotates each row with a an array of values, and orders the results by that new SELECTed array -- in this example we simply annotate every row with an integer array like {4,5}:

```

gears=> select *, Array[4,5] as array_from_select from foo order by array_from_select;

 value | array_from_select 

-------+-------------------

     1 | {4,5}

     2 | {4,5}

(2 rows)

```


This appears to work OK (although, of course, since every row has {4,5} annotated to it, the ORDER BY clause is pretty meaningless). 


I'm confused, however, why I receive, "ERROR:  column "array_from_select" does not exist" when I try to order the results by a specific index of my newly selected array. For example, when I try to order the results by the first cell of the Array, I get...

```

gears=> select *, Array[4,5] as array_from_select from foo order by array_from_select[1];

ERROR:  column "array_from_select" does not exist

LINE 1: ...Array[4,5] as array_from_select from foo order by array_from...  

```


Thanks for you insights and time!


- David

Re: Column Does Not Exist Error: Order by an Particular Cell of an Array

From
Kevin Grittner
Date:
On Tue, Aug 2, 2016 at 11:48 AM, David Muller <dmuller@guidebook.com> wrote:

> gears=> select *, Array[4,5] as array_from_select from foo order by
> array_from_select[1];
>
> ERROR:  column "array_from_select" does not exist

array_from_select is not a column name, it is an alias.  The ways
in which an alias can be used in a query are somewhat limited --
you can order by the alias of a result column, but you can't use
the alias in arbitrary expressions.

You could do something like this:

test=# with x as (select *, Array[4,5] as array_from_select from foo)
test-# select * from x order by array_from_select[1];
 value | array_from_select
-------+-------------------
     1 | {4,5}
     2 | {4,5}
(2 rows)

In this case array_from_select becomes a column in the result set
of common table expression (CTE) x and *can* be used in
expressions.

--
Kevin Grittner
EDB: http://www.enterprisedb.com
The Enterprise PostgreSQL Company


Re: Column Does Not Exist Error: Order by an Particular Cell of an Array

From
David Muller
Date:
Ah, that makes sense -- thank you Kevin.

- David

On Tue, Aug 2, 2016 at 2:17 PM, Kevin Grittner <kgrittn@gmail.com> wrote:
On Tue, Aug 2, 2016 at 11:48 AM, David Muller <dmuller@guidebook.com> wrote:

> gears=> select *, Array[4,5] as array_from_select from foo order by
> array_from_select[1];
>
> ERROR:  column "array_from_select" does not exist

array_from_select is not a column name, it is an alias.  The ways
in which an alias can be used in a query are somewhat limited --
you can order by the alias of a result column, but you can't use
the alias in arbitrary expressions.

You could do something like this:

test=# with x as (select *, Array[4,5] as array_from_select from foo)
test-# select * from x order by array_from_select[1];
 value | array_from_select
-------+-------------------
     1 | {4,5}
     2 | {4,5}
(2 rows)

In this case array_from_select becomes a column in the result set
of common table expression (CTE) x and *can* be used in
expressions.

--
Kevin Grittner
EDB: http://www.enterprisedb.com
The Enterprise PostgreSQL Company