From: | Josh Berkus <josh(at)agliodbs(dot)com> |
---|---|
To: | Andrew Perrin <clists(at)perrin(dot)socsci(dot)unc(dot)edu>, pgsql-sql(at)postgresql(dot)org |
Subject: | Re: Complicated "group by" question |
Date: | 2004-08-25 17:47:18 |
Message-ID: | 200408251047.18645.josh@agliodbs.com |
Views: | Raw Message | Whole Thread | Download mbox | Resend email |
Thread: | |
Lists: | pgsql-sql |
Andrew,
> I have a table of people ("reviewers"), a table of review assignments
> ("assign"), and a table of review acceptances ("accept"). I would like to
> be able to write a query to return the latest (e.g., max(assign_date))
> assignment for each reviewer, plus the acc_id field from "accept". I
> think I should be able to do this with a GROUP BY clause, but am having no
> luck.
Some vagueness: you didn't say whether you wanted to see two assignments if
they have the same, latest date. Nor did you specify whether you wanted to
see assignments that had not been accepted (the below assumes yes to both)
Hmmm ... one way, SQL-standard:
SELECT reviewer.name, assign_date, acc_id
FROM reviewers JOIN assign ON reviewer.id = assign.reviewer_id
LEFT OUTER JOIN accept ON assign.id = accept.assign_id
WHERE assign_date IN (SELECT max(ass2.assign_date) FROM assign ass2
WHERE ass2.reviewer_id = reviewers.id)
or for a bit faster execution on PG you cann replace that WHERE clause with:
WHERE assign_date IN (SELECT ass2.assign_date FROM assign ass2
WHERE ass2.reviewer_id = reviewers.id ORDER BY ass2.assign_date DESC LIMIT 1)
--
Josh Berkus
Aglio Database Solutions
San Francisco
From | Date | Subject | |
---|---|---|---|
Next Message | Jean-Luc Lachance | 2004-08-25 17:54:15 | Re: Complicated "group by" question |
Previous Message | Andrew Perrin | 2004-08-25 17:04:02 | Complicated "group by" question |