Re: how to "enumerate" rows ?

From: Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us>
To: Karsten Hilbert <Karsten(dot)Hilbert(at)gmx(dot)net>
Cc: pgsql-sql(at)postgresql(dot)org
Subject: Re: how to "enumerate" rows ?
Date: 2004-01-27 01:08:27
Message-ID: 7528.1075165707@sss.pgh.pa.us
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-sql

Karsten Hilbert <Karsten(dot)Hilbert(at)gmx(dot)net> writes:
>> Now, I need to enumerate the vaccinations per patient per
>> disease. They are intrinsically ordered by their date of
>> vaccination but I need to attach a number to them ...

The best, recommended way to do this is to plaster on the row numbers
in your client-side code. AFAIK there just isn't any way to do it in
standard SQL.

If you feel you really gotta have a server-side solution, the easiest
way is

CREATE TEMP SEQUENCE myseq;

SELECT nextval('myseq'), *
FROM (SELECT ... ORDER BY date_given) ss;

DROP SEQUENCE myseq;

(Alternatively, you can create a temp sequence once per session and just
reset it with setval() for each query.)

Note that you can *not* simplify this to

SELECT nextval('myseq'), ... ORDER BY date_given;

because if you do, the nextval() values may get computed before the
ORDER BY sorting occurs. Putting the ORDER BY into a sub-select makes
it work reliably.

This is not real portable since neither sequences nor ORDER BY in a
subselect are SQL-standard. It's also probably a good deal slower than
a simple client-side counter, because nextval() does a lot more than
just add one to a variable. But if you have to have it, there it is.

regards, tom lane

In response to

Browse pgsql-sql by date

  From Date Subject
Next Message azwa 2004-01-27 01:42:27 Re: time series data
Previous Message James Taylor 2004-01-27 00:50:06 Re: Label Security