Thread: Selecting rows with "static" ordering
Hello, I have a strange problem (or one that I've never had before anyway). I am searching for a list of "id's" for a given table (these id values are generated at run-time and held statically in an application-local variable). From that application, I want to retrieve all those rows, and I want them in the order they are currently stored in that variable. So take for example this foreign application variable: ids = "3,2,5,1,4" The application then executes this sql: select * from table where id in (3,2,5,1,4) As-is, of course, the above query will return the 5 records in a semi-random (i.e. unpredictable/unreliable) order. And I don't want to just "order by id" - I want to "order by id(3,2,5,1,4)" (if you see what I mean) Is there a "neat trick" that anyone knows for pulling this off in a single query? Basically right now I'm issuing 5 queries to the backend to ensure ordering but this horribly inefficient. Any input or advice would be appreciated, Steve
The best I can think of off the top of my head would still be multiple SQL, but at least it would be in one transaction block: BEGIN; SELECT '1' AS ordering, t1.* INTO TEMP TABLE work_table FROM t1 WHERE t1.id = '3'; SELECT '2' AS ordering, t1.* INTO TEMP TABLE work_table FROM t1 WHERE t1.id = '2'; SELECT '3' AS ordering, t1.* INTO TEMP TABLE work_table FROM t1 WHERE t1.id = '5'; SELECT '4' AS ordering, t1.* INTO TEMP TABLE work_table FROM t1 WHERE t1.id = '1'; SELECT '5' AS ordering, t1.* INTO TEMP TABLE work_table FROM t1 WHERE t1.id = '4'; SELECT t1.* FROM work_table ORDER BY ordering; COMMIT; Something to that effect...? It's at least makes it only 1 connection from the client to the database. -----Original Message----- From: pgsql-sql-owner@postgresql.org [mailto:pgsql-sql-owner@postgresql.org] On Behalf Of Steve Midgley Sent: Friday, 27 April 2007 10:01 To: pgsql-sql@postgresql.org Subject: [SQL] Selecting rows with "static" ordering Hello, I have a strange problem (or one that I've never had before anyway). I am searching for a list of "id's" for a given table (these id values are generated at run-time and held statically in an application-local variable). From that application, I want to retrieve all those rows, and I want them in the order they are currently stored in that variable. So take for example this foreign application variable: ids = "3,2,5,1,4" The application then executes this sql: select * from table where id in (3,2,5,1,4) As-is, of course, the above query will return the 5 records in a semi-random (i.e. unpredictable/unreliable) order. And I don't want to just "order by id" - I want to "order by id(3,2,5,1,4)" (if you see what I mean) Is there a "neat trick" that anyone knows for pulling this off in a single query? Basically right now I'm issuing 5 queries to the backend to ensure ordering but this horribly inefficient. Any input or advice would be appreciated, Steve ---------------------------(end of broadcast)--------------------------- TIP 7: You can help support the PostgreSQL project by donating at http://www.postgresql.org/about/donate *******************Confidentiality and Privilege Notice******************* The material contained in this message is privileged and confidential to the addressee. If you are not the addressee indicated in this message or responsible for delivery of the message to such person, you may not copy or deliver this message to anyone, and you should destroy it and kindly notify the sender by reply email. Information in this message that does not relate to the official business of Weatherbeeta must be treated as neither given nor endorsed by Weatherbeeta. Weatherbeeta, its employees, contractors or associates shall not be liable for direct, indirect or consequential loss arising from transmission of this message or any attachments
> them in the order they are currently stored in that variable. So take > > for example this foreign application variable: > > ids = "3,2,5,1,4" kludgy, but: 1. store your ids in a pg array 2. select from the array 3. on order by, write a function that takes the row.id and array as parameters, returning the id offset into the array __________________________________________________ Do You Yahoo!? Tired of spam? Yahoo! Mail has the best spam protection around http://mail.yahoo.com
On 4/26/07, Steve Midgley <public@misuse.org> wrote:
select *
from table
where id in (3, 2, 5, 1, 4)
order by
case when (id = 3) then 1
when (id = 2) then 2
when (id = 5) then 3
when (id = 1) then 4
when (id = 4) then 5
else null
end
;
--
==================================================================
Aaron Bono
Aranya Software Technologies, Inc.
http://www.aranya.com
http://codeelixir.com
==================================================================
So take
for example this foreign application variable:
ids = "3,2,5,1,4"
The application then executes this sql:
select * from table where id in (3,2,5,1,4)
As-is, of course, the above query will return the 5 records in a
semi-random (i.e. unpredictable/unreliable) order. And I don't want to
just "order by id" - I want to "order by id(3,2,5,1,4)" (if you see
what I mean)
select *
from table
where id in (3, 2, 5, 1, 4)
order by
case when (id = 3) then 1
when (id = 2) then 2
when (id = 5) then 3
when (id = 1) then 4
when (id = 4) then 5
else null
end
;
--
==================================================================
Aaron Bono
Aranya Software Technologies, Inc.
http://www.aranya.com
http://codeelixir.com
==================================================================
On 27/04/07, Aaron Bono <postgresql@aranya.com> wrote: > On 4/26/07, Steve Midgley <public@misuse.org> wrote: > > So take > > for example this foreign application variable: > > > > ids = "3,2,5,1,4" > > > > The application then executes this sql: > > > > select * from table where id in (3,2,5,1,4) > > > > As-is, of course, the above query will return the 5 records in a > > semi-random (i.e. unpredictable/unreliable) order. And I don't want to > > just "order by id" - I want to "order by id(3,2,5,1,4)" (if you see > > what I mean) > > > > > > select * > from table > where id in (3, 2, 5, 1, 4) > order by > case when (id = 3) then 1 > when (id = 2) then 2 > when (id = 5) then 3 > when (id = 1) then 4 > when (id = 4) then 5 > else null > end > ; > could you not use the values statment of psql 8.2 hmmm select * from table, values ((1,3),(2,2),(3,5),(4,1),(5,4)) as values where values.id=table.second order by values.first; never done it but I think it should work with a bit of playing arond... Peter.
At 8:01p -0400 on 26 Apr 2007, Steve Midgley wrote: > From that application, I want to retrieve all those rows, and I > want them in the order they are currently stored in that variable. > So take for example this foreign application variable: > > ids = "3,2,5,1,4" > > The application then executes this sql: > > select * from table where id in (3,2,5,1,4) > Is there a "neat trick" that anyone knows for pulling this off in a > single query? Basically right now I'm issuing 5 queries to the > backend to ensure ordering but this horribly inefficient. Why not do this particular ordering on the application side? With this example SQL, and assuming you've PRIMARY KEYed( id ), you're guaranteed to get a unique id for each tuple. Presumably, you've got the order you want stored within your application, so just pull it out of a hash in the order you need it. Or is it terribly more complicated than this? Kevin