Thread: selecting latest record
Hi, I have a simple table price(id_product, price, date) which records price changes for each id_product. Each time a price changes a new tuple is created. What is the best way to select only the latest price of each id_product? Thanks,
Hello 2009/9/22 Louis-David Mitterrand <vindex+lists-pgsql-sql@apartia.org>: > Hi, > > I have a simple table > > price(id_product, price, date) > > which records price changes for each id_product. Each time a price > changes a new tuple is created. > > What is the best way to select only the latest price of each id_product? there are more ways - depends on what you wont. one way is SELECT * FROM price WHERE (id_product, date) = (SELECT id_product, max(date) FROM price GROUP BY id_product) Regards Pavel Stehule > > Thanks, > > -- > Sent via pgsql-sql mailing list (pgsql-sql@postgresql.org) > To make changes to your subscription: > http://www.postgresql.org/mailpref/pgsql-sql >
On Tue, Sep 22, 2009 at 11:56:54AM +0200, Pavel Stehule wrote: > > there are more ways - depends on what you wont. > > one way is > > SELECT * > FROM price > WHERE (id_product, date) = (SELECT id_product, max(date) > FROM price > GROUP BY > id_product) Nice. I didn't know one could have several args in a single WHERE clause. Thanks,
In response to Louis-David Mitterrand : > Hi, > > I have a simple table > > price(id_product, price, date) > > which records price changes for each id_product. Each time a price > changes a new tuple is created. > > What is the best way to select only the latest price of each id_product? There are several ways to do that, for instance with DISTINCT ON (only postgresql): test=*# select * from price ;id_product | price | datum ------------+-------+------------ 1 | 10 | 2009-09-01 1 | 12 | 2009-09-10 2 | 11 | 2009-09-10 2 | 8 | 2009-09-13 (4 rows) test=*# select distinct on (id_product) id_product, price from price order by id_product, datum desc;id_product | price ------------+------- 1 | 12 2 | 8 (2 rows) Andreas -- Andreas Kretschmer Kontakt: Heynitz: 035242/47150, D1: 0160/7141639 (mehr: -> Header)
Let's say there's an index on the date column: Does the where clause approach necessarily out perform the distinct on version? Hoping the OP has enough data to make analyse useful. A. Kretschmer wrote: > In response to Louis-David Mitterrand : > >> Hi, >> >> I have a simple table >> >> price(id_product, price, date) >> >> which records price changes for each id_product. Each time a price >> changes a new tuple is created. >> >> What is the best way to select only the latest price of each id_product? >> > > There are several ways to do that, for instance with DISTINCT ON (only > postgresql): > > test=*# select * from price ; > id_product | price | datum > ------------+-------+------------ > 1 | 10 | 2009-09-01 > 1 | 12 | 2009-09-10 > 2 | 11 | 2009-09-10 > 2 | 8 | 2009-09-13 > (4 rows) > > test=*# select distinct on (id_product) id_product, price from price order by id_product, datum desc; > id_product | price > ------------+------- > 1 | 12 > 2 | 8 > (2 rows) > > Andreas >