Re: Sorting items in aggregate function

From: Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us>
To: Michael Fuhr <mike(at)fuhr(dot)org>
Cc: Steven Murdoch <psql+Steven(dot)Murdoch(at)cl(dot)cam(dot)ac(dot)uk>, pgsql-sql(at)postgresql(dot)org
Subject: Re: Sorting items in aggregate function
Date: 2006-09-12 20:37:55
Message-ID: 21365.1158093475@sss.pgh.pa.us
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-sql

Michael Fuhr <mike(at)fuhr(dot)org> writes:
> On Tue, Sep 12, 2006 at 04:46:28PM +0100, Steven Murdoch wrote:
>> Here is an example of a setup and what I could like to achieve. Does
>> anyone have suggestions on what is the best way to get the desired
>> result?

> Use the aggregate over an ordered subquery:

> SELECT name, trim(concat(code || ' ')) AS codes
> FROM (
> SELECT a.name, b.code
> FROM a
> LEFT JOIN ab ON a.id = ab.a_id
> LEFT JOIN b ON ab.b_id = b.id
> ORDER BY b.code
> ) AS s
> GROUP BY name
> ORDER BY name;

Note that if you need to GROUP in the outer query, it's best to sort the
inner query's output first by the outer query's grouping:

SELECT name, trim(concat(code || ' ')) AS codes
FROM (
SELECT a.name, b.code
FROM a
LEFT JOIN ab ON a.id = ab.a_id
LEFT JOIN b ON ab.b_id = b.id
ORDER BY a.name, b.code
^^^^^^^^^^^^^^
) AS s
GROUP BY name
ORDER BY name;

This way will still work if the planner decides to use a GroupAggregate
(which in fact it probably will, if it sees it can avoid another sort
step). The way Michael showed will only work if the plan uses
HashAggregate --- if the planner decides it needs Sort+GroupAggregate
in the outer query, the re-sort will probably destroy the ordering
by b.code.

regards, tom lane

In response to

Responses

Browse pgsql-sql by date

  From Date Subject
Next Message Osvaldo Rosario Kussama 2006-09-12 20:54:12 Re: Sorting items in aggregate function
Previous Message Emi Lu 2006-09-12 19:24:49 How to get all users under a group