Re: pgsql aggregate: conditional max

From: Michael Fuhr <mike(at)fuhr(dot)org>
To: Weimao Ke <wke(at)indiana(dot)edu>
Cc: pgsql-sql(at)postgresql(dot)org
Subject: Re: pgsql aggregate: conditional max
Date: 2006-03-12 05:42:12
Message-ID: 20060312054212.GA25423@winnie.fuhr.org
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-sql

On Sun, Mar 12, 2006 at 12:09:48AM -0500, Weimao Ke wrote:
> I want to group by "aid" and choose the category (i.e., "cat") with the
> largest "weight":
>
> aid | max_weighted_cat
> ----+---------------------
> a1 | Other
> a2 | Drama
> a3 | Adult

PostgreSQL has a non-standard DISTINCT ON clause that would work.
See the weather_reports example in the documentation for SELECT:

http://www.postgresql.org/docs/8.1/interactive/sql-select.html

Try this query against your example data:

SELECT DISTINCT ON (aid) aid, cat
FROM tablename
ORDER BY aid, weight DESC, cat;

If multiple rows for a given aid match that aid's max weight then
the above query will return the first matching row according to the
given sort order.

Some people object to DISTINCT ON because it's non-deterministic if
you don't order by enough columns. Here's something more standard;
it'll return all rows that match a given aid's max weight:

SELECT aid, cat
FROM tablename AS t
JOIN (SELECT aid, max(weight) AS weight
FROM tablename
GROUP BY aid) AS s USING (aid, weight);

--
Michael Fuhr

In response to

Responses

Browse pgsql-sql by date

  From Date Subject
Next Message Michael Fuhr 2006-03-12 05:48:54 Re: pgsql aggregate: conditional max
Previous Message Jeffrey Melloy 2006-03-12 05:34:57 Re: pgsql aggregate: conditional max