On Thu, Dec 15, 2005 at 08:31:09PM -0500, Michael Avila wrote:
> What I want to do is find the latest status for each member. Actually I want
> to find all those with an status of "A". But it must be the current (latest)
> status. How do I find the most current date for each member in a pile of
> many records for many members with many status settings with one SQL
> statement?
Suppose you have this table:
SELECT * FROM memberstatus;
member_id | status_code | status_date
-----------+-------------+-------------
1 | a | 2005-01-01
2 | x | 2005-01-01
3 | x | 2005-01-01
4 | x | 2005-01-01
1 | x | 2005-12-15
2 | a | 2005-12-15
3 | y | 2005-12-15
4 | a | 2005-12-15
(8 rows)
Let's order the data so all of a member's records are shown together,
with the latest one first:
SELECT * FROM memberstatus
ORDER BY member_id, status_date DESC;
member_id | status_code | status_date
-----------+-------------+-------------
1 | x | 2005-12-15
1 | a | 2005-01-01
2 | a | 2005-12-15
2 | x | 2005-01-01
3 | y | 2005-12-15
3 | x | 2005-01-01
4 | a | 2005-12-15
4 | x | 2005-01-01
(8 rows)
One way to get only the first record for each member is to use
PostgreSQL's nonstandard DISTINCT ON construct:
SELECT DISTINCT ON (member_id) * FROM memberstatus
ORDER BY member_id, status_date DESC;
member_id | status_code | status_date
-----------+-------------+-------------
1 | x | 2005-12-15
2 | a | 2005-12-15
3 | y | 2005-12-15
4 | a | 2005-12-15
(4 rows)
We could put the above in a subquery and restrict the output to the
records we want:
SELECT * FROM (
SELECT DISTINCT ON (member_id) * FROM memberstatus
ORDER BY member_id, status_date DESC
) AS s
WHERE status_code = 'a'
ORDER BY member_id;
member_id | status_code | status_date
-----------+-------------+-------------
2 | a | 2005-12-15
4 | a | 2005-12-15
(2 rows)
This isn't the only way; search the archives for alternatives.
--
Michael Fuhr
---------------------------(end of broadcast)---------------------------
TIP 4: Have you searched our list archives?
http://archives.postgresql.org