Michael Fuhr <mike@fuhr.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