Thread: How to select and result row number??
Hi,
I would like to select and also give numbering in each record.
Let say I have table 'City' with a 'cityname' column
what is the select statement so I can get result records like this
no cityname
---- --------------
1 NEW YORK
2 LOS ANGELES
3 HOUSTON
4 ....
5 ...
Thank you.
Yudie
Yudie wrote: > Hi, > > I would like to select and also give numbering in each record. > Let say I have table 'City' with a 'cityname' column > > what is the select statement so I can get result records like this > > no cityname > ---- -------------- > 1 NEW YORK > 2 LOS ANGELES > 3 HOUSTON > 4 .... > 5 ... Good question. The only easy answer I have is the creation of a temp table with a SERIAL column: CREATE TEMP TABLE out (cnt SERIAL, other_cols...);INSERT INTO out SELECT ... ORDER BY col;SELECT * FROM out; -- Bruce Momjian | http://candle.pha.pa.us pgman@candle.pha.pa.us | (610) 359-1001+ If your life is a hard drive, | 13 Roberts Road + Christ can be your backup. | Newtown Square, Pennsylvania19073
>>>>> "Yudie" == Yudie <yudie@axiontech.com> writes: Yudie> what is the select statement so I can get result records like this Yudie> no cityname Yudie> ---- -------------- Yudie> 1 NEW YORK Yudie> 2 LOS ANGELES Yudie> 3 HOUSTON Yudie> 4 .... Yudie> 5 ... This is not really a SQL type result; you are probably better of writing something in a procedural language. That said, something like this seems to work for 7.2: create sequence temp_counter; select nextval('temp_counter'), * from whatever; If you have an 'order by', the above will not work. You could then try either building a temporary table or using a subselect select nextval('temp_counter'), * from (select .... order by ...); roland -- PGP Key ID: 66 BC 3B CD Roland B. Roberts, PhD RL Enterprises roland@rlenter.com 76-15 113th Street, Apt 3B roland@astrofoto.org Forest Hills, NY 11375
On Mon, Sep 16, 2002 at 11:12:06PM -0400, Bruce Momjian wrote: > Yudie wrote: <wants numbered records> > Good question. The only easy answer I have is the creation of a temp > table with a SERIAL column: > > CREATE TEMP TABLE out (cnt SERIAL, other_cols...); > INSERT INTO out SELECT ... ORDER BY col; Hmm, this needs to be: INSERT INTO out (ther_cols...) SELECT ... ORDER BY col; So that the cnt column gets filled from the default. > SELECT * FROM out; On Tue, Sep 17, 2002 at 10:14:58AM -0400, Roland Roberts wrote: > create sequence temp_counter; > select nextval('temp_counter'), * from whatever; > > If you have an 'order by', the above will not work. You could then > try either building a temporary table or using a subselect > > select nextval('temp_counter'), * from (select .... order by ...); Approximately the same solution, but without saving the result in a temp table. Hmm, with the new dependency code, is the auto-sequence from a SERIAL in a temp table also a temp sequence? It get's put in the temp schema, right? Seems we have a workaround for those wanting numbered result sets. BTW, Bruce's solution could be useful for those times you want to batch a potentially large return set, but can't use cursors - the temp table will live as long as the connection does, so as long as your connection pool doesn't play round robin games on you, you can use the result count from the INSERT to calculate batch sizes, and use OFFSET and LIMIT on SELECTs from the temp table. Ross
"Ross J. Reedstrom" <reedstrm@rice.edu> writes: > Hmm, with the new dependency code, is the auto-sequence from a SERIAL > in a temp table also a temp sequence? It get's put in the temp schema, > right? Seems we have a workaround for those wanting numbered result > sets. That's the hard way; just do CREATE TEMP SEQUENCE ... works in prior releases too ... regards, tom lane
Ross J. Reedstrom wrote: > On Mon, Sep 16, 2002 at 11:12:06PM -0400, Bruce Momjian wrote: > > Yudie wrote: > <wants numbered records> > > > Good question. The only easy answer I have is the creation of a temp > > table with a SERIAL column: > > > > CREATE TEMP TABLE out (cnt SERIAL, other_cols...); > > INSERT INTO out SELECT ... ORDER BY col; > > Hmm, this needs to be: > > INSERT INTO out (ther_cols...) SELECT ... ORDER BY col; > > So that the cnt column gets filled from the default. Yes, thanks for the fix. > > create sequence temp_counter; > > select nextval('temp_counter'), * from whatever; > > > > If you have an 'order by', the above will not work. You could then > > try either building a temporary table or using a subselect > > > > select nextval('temp_counter'), * from (select .... order by ...); > > Approximately the same solution, but without saving the result in a temp > table. I thought about doing it this way. However, a subselect as a pseudotable is not guaranteed to return the data in any specific order, so I don't think this method work work reliably. At least that was my assumption. -- Bruce Momjian | http://candle.pha.pa.us pgman@candle.pha.pa.us | (610) 359-1001+ If your life is a hard drive, | 13 Roberts Road + Christ can be your backup. | Newtown Square, Pennsylvania19073
Bruce Momjian <pgman@candle.pha.pa.us> writes: >>> select nextval('temp_counter'), * from (select .... order by ...); >> >> Approximately the same solution, but without saving the result in a temp >> table. > I thought about doing it this way. However, a subselect as a > pseudotable is not guaranteed to return the data in any specific order, > so I don't think this method work work reliably. Say what? Given the ORDER BY in the subselect, it will. Of course, you can't do any grouping or other processing at the outer level, but the example as given is just fine. regards, tom lane
Tom Lane wrote: > Bruce Momjian <pgman@candle.pha.pa.us> writes: > >>> select nextval('temp_counter'), * from (select .... order by ...); > >> > >> Approximately the same solution, but without saving the result in a temp > >> table. > > > I thought about doing it this way. However, a subselect as a > > pseudotable is not guaranteed to return the data in any specific order, > > so I don't think this method work work reliably. > > Say what? Given the ORDER BY in the subselect, it will. > > Of course, you can't do any grouping or other processing at the outer > level, but the example as given is just fine. When you specify a table in FROM, there is no ordering to the table. Is it guaranteed that a subquery in FROM _does_ have an ordering. Does ANSI say it has an ordering? What if the subquery is involved in a join? -- Bruce Momjian | http://candle.pha.pa.us pgman@candle.pha.pa.us | (610) 359-1001+ If your life is a hard drive, | 13 Roberts Road + Christ can be your backup. | Newtown Square, Pennsylvania19073
Bruce Momjian <pgman@candle.pha.pa.us> writes: >> Say what? Given the ORDER BY in the subselect, it will. > When you specify a table in FROM, there is no ordering to the table. Is > it guaranteed that a subquery in FROM _does_ have an ordering. If you write ORDER BY, we'll implement it. > Does ANSI say it has an ordering? ANSI forbids ORDER BY in sub-selects, so they don't have to address the question. > What if the subquery is involved in a join? We are entitled to reorder its output for purposes of processing the join, then. But that's entirely irrelevant to the example as given. There is no reason to reorder the subselect output, and we won't. regards, tom lane