Re: Most recent row

From: Adrian Klaver <adrian(dot)klaver(at)aklaver(dot)com>
To: "David G(dot) Johnston" <david(dot)g(dot)johnston(at)gmail(dot)com>, Gary Stainburn <gary(dot)stainburn(at)ringways(dot)co(dot)uk>
Cc: "pgsql-sql(at)postgresql(dot)org" <pgsql-sql(at)postgresql(dot)org>
Subject: Re: Most recent row
Date: 2017-05-05 16:02:24
Message-ID: bfb00eb6-6e2c-57e4-a28d-dcca96a894f6@aklaver.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-sql

On 05/05/2017 08:14 AM, David G. Johnston wrote:
> On Fri, May 5, 2017 at 1:25 AM, Gary Stainburn
> <gary(dot)stainburn(at)ringways(dot)co(dot)uk <mailto:gary(dot)stainburn(at)ringways(dot)co(dot)uk>>wrote:
>
> This question has been asked a few times, and Google returns a few
> different
> answers, but I am interested people's opinions and suggestions for
> the *best*
> wat to retrieve the most recent row from a table.
>
> My case is:
>
> create table people (
> p_id serial primary key,
> ......
> );
>
> create table assessments (
> p_id int4 not null references people(p_id),
> as_timestamp timestamp not null,
> ......
> );
>
> select p.*, (most recent) a.*
> from people p, assessments a
> ..
> ;
>
>
> ​I would start with something using DISTINCT ON and avoid redundant
> data. If performance starts to suck I would then probably add a field
> to people where you can record the most recent assessment id and which
> you would change via a trigger on assessments.
>
> (not tested)​
>
> ​SELECT DISTINCT ON (p) p, a
> FROM people p
> LEFT JOIN ​assessments a USING (p_id)
> ORDER BY p, a.as_timestamp DESC;
>
> David J.
>

My take:

create table people(p_id SERIAL PRIMARY KEY, name_first VARCHAR,
name_last VARCHAR);

create table assessments(p_id INTEGER NOT NULL REFERENCES people(p_id),
as_timestamp TIMESTAMP NOT NULL)

insert into people(name_first, name_last) values ('Daffy', 'Duck'),
('Mickey', 'Mouse'), ('Rocky', 'Squirrel');

insert into assessments (p_id, as_timestamp) values (1, '09/12/2016'),
(3, '10/01/2016'), (2, '11/14/2016'), (1, '12/27/2016'),
(2,'01/03/2017'),(3, '02/23/2017'), (1, '03/05/2017');

SELECT
*
FROM
people
JOIN (
SELECT
p_id,
max(as_timestamp) AS last_assessment
FROM
assessments
GROUP BY
p_id) AS max_ts ON people.p_id = max_ts.p_id
JOIN assessments AS a ON a.p_id = max_ts.p_id
AND a.as_timestamp = max_ts.last_assessment
ORDER BY
people.p_id;

p_id | name_first | name_last | p_id | max
------+------------+-----------+------+---------------------
1 | Daffy | Duck | 1 | 2017-03-05 00:00:00
2 | Mickey | Mouse | 2 | 2017-01-03 00:00:00
3 | Rocky | Squirrel | 3 | 2017-02-23 00:00:00
(3 rows)

--
Adrian Klaver
adrian(dot)klaver(at)aklaver(dot)com

In response to

Responses

Browse pgsql-sql by date

  From Date Subject
Next Message Michael Moore 2017-05-05 20:47:36 Re: Most recent row
Previous Message David G. Johnston 2017-05-05 15:14:28 Re: Most recent row