Re: Retrieve most recent 1 record from joined table

From: Thomas Kellerer <spam_eater(at)gmx(dot)net>
To: pgsql-sql(at)postgresql(dot)org
Subject: Re: Retrieve most recent 1 record from joined table
Date: 2014-08-25 05:59:18
Message-ID: ltejbl$s1k$1@ger.gmane.org
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-sql

agharta schrieb am 22.08.2014 um 10:05:
> Joining the tables, how to get ONLY most recent record per table3(t3_date)??
>
> Query example:
>
> select * from table1 as t1
> inner join table2 t2 on (t1.t1_id = t2.t1_id and t2.t2_value like('%ab%') )
> inner join table3 t3 on (t2.t2_id = t3.t2_id and t3.t3_date <= timestamp '2014-08-20')
> order by t3.t2_id, t3.t3_date desc
>

This seems to be slightly faster, especially with the following index:

create index idx_t3_combined on table3 (t2_id, t3_date desc, t3_id);

select *
from table1 as t1
join table2 t2 on t1.t1_id = t2.t1_id and t2.t2_value like '%ab%'
join (
select distinct on (t2_id) t3_id,
t3_date,
t2_id
from table3
order by t2_id, t3_date desc
) t3 on t3.t2_id = t2.t2_id
order by t3.t2_id, t3.t3_date desc
;

I also had to increase the work_mem in order to avoid disk based sorting for the joins

In response to

Browse pgsql-sql by date

  From Date Subject
Next Message agharta 2014-08-27 09:04:33 Re: Retrieve most recent 1 record from joined table
Previous Message Hector Menchaca 2014-08-23 23:38:39 Re: postgres json: How to query map keys to get children