Re: Returning array of IDs as a sub-query with group-by

From: Ragnar <gnari(at)hive(dot)is>
To: Andreas Joseph Krogh <andreak(at)officenet(dot)no>
Cc: pgsql-sql(at)postgresql(dot)org
Subject: Re: Returning array of IDs as a sub-query with group-by
Date: 2007-08-25 21:02:19
Message-ID: 1188075739.12268.50.camel@localhost.localdomain
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-sql

On lau, 2007-08-25 at 17:55 +0200, Andreas Joseph Krogh wrote:
> On Saturday 25 August 2007 17:10:57 Andreas Joseph Krogh wrote:

[snip]

> > count | item_id | price | item_id_array
> > -------+---------+-------+---------------
> > 3 | 1 | 100 | {1,2,3}
> > 6 | 1 | 200 | {4,5,6,7,8,9}
> > 2 | 2 | 200 | {10,11}
> >
> > I tried this query which complains about an ungruoped column:
> >
> > SELECT COUNT(il.price), i.id AS item_id, il.price,
> > ARRAY(SELECT a.id FROM item_log a WHERE a.id = il.id) AS item_id_array
> > FROM item i, item_log il WHERE i.id = il.item_id GROUP BY il.price, i.id;
> >
> > ERROR: subquery uses ungrouped column "il.id" from outer query
> >
> > Any hints?
>
> I found the following CREATE AGGREGATE suggestion in the PG-docs:

[aggregate solution snipped]

> If someone knows of a way without introducing a new AGGREGATE I'm still
> interrested.

you can allways do the ARRAY(SELECT...) outside the grouping:
# select *,(select ARRAY(
SELECT a.id
FROM item_log as a
WHERE foo.item_id=a.item_id
AND foo.price=a.price
)
) AS item_id_array
from (
select count(*),item_id, price
from item_log
group by item_id, price
) as foo;

count | item_id | price | item_id_array
-------+---------+-------+---------------
3 | 1 | 100 | {1,2,3}
6 | 1 | 200 | {4,5,6,7,8,9}
2 | 2 | 200 | {10,11}
(3 rows)

but i suspect the aggregate will perform better

gnari

In response to

Responses

Browse pgsql-sql by date

  From Date Subject
Next Message Andreas Joseph Krogh 2007-08-25 22:42:56 Re: Returning array of IDs as a sub-query with group-by
Previous Message Andreas Joseph Krogh 2007-08-25 15:55:30 Re: Returning array of IDs as a sub-query with group-by