From: | Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us> |
---|---|
To: | "Kevin Grittner" <Kevin(dot)Grittner(at)wicourts(dot)gov> |
Cc: | "Nikolas Everett" <nik9000(at)gmail(dot)com>, sthomas(at)peak6(dot)com, "pgsql-performance(at)postgresql(dot)org" <pgsql-performance(at)postgresql(dot)org> |
Subject: | Re: Best way to get the latest revision from a table |
Date: | 2011-01-14 23:40:43 |
Message-ID: | 14113.1295048443@sss.pgh.pa.us |
Views: | Raw Message | Whole Thread | Download mbox | Resend email |
Thread: | |
Lists: | pgsql-performance |
"Kevin Grittner" <Kevin(dot)Grittner(at)wicourts(dot)gov> writes:
> Shaun Thomas <sthomas(at)peak6(dot)com> wrote:
>> This actually looks like a perfect candidate for DISTINCT ON.
>>
>> SELECT DISTINCT ON (a, b) a, b, revision
>> FROM test
>> ORDER BY a, b DESC;
> I wouldn't say perfect. It runs about eight times slower than what
> I suggested and returns a fairly random value for revision instead
> of the max(revision).
Shaun's example is a bit off: normally, when using DISTINCT ON, you want
an ORDER BY key that uses all the given DISTINCT keys and then some
more. To get the max revision for each a/b combination it ought to be
SELECT DISTINCT ON (a, b) a, b, revision
FROM test
ORDER BY a, b, revision DESC;
As for speed, either one might be faster in a particular situation.
regards, tom lane
From | Date | Subject | |
---|---|---|---|
Next Message | Kevin Grittner | 2011-01-15 00:59:50 | Re: Best way to get the latest revision from a table |
Previous Message | Kevin Grittner | 2011-01-14 23:33:27 | Re: Best way to get the latest revision from a table |