[SQL] consistent random order
I am returning results ordered randomly using 'order by random()'. My issue has to do with page numbers in our web application. When I hit the 2nd page and retrieve results with an offset, ordering by random() isn't really what I want since I will often receive results that were on the 1st page (they get re-randomized). I'm looking for a way to order in a controled random order. Maybe a UDF. Ideally I would need to do this: ORDER BY myRandomUDF(1234) or ORDER BY myRandomUDF(2345) Where the argument acts like a seed that always returns a consistent pseudo-random set. That way, when I get to the 2nd page, i know i'm getting the dataset back in the same order that I had on page 1, and the offset works like normal. Is this even realistically possible? Thanks, Jeff Herrin
Re: [SQL] consistent random order
On 11/29/06, Jeff Herrin <[EMAIL PROTECTED]> wrote: I am returning results ordered randomly using 'order by random()'. My issue has to do with page numbers in our web application. When I hit the 2nd page and retrieve results with an offset, ordering by random() isn't really what I want since I will often receive results that were on the 1st page (they get re-randomized). I'm looking for a way to order in a controled random order. Maybe a UDF. Ideally I would need to do this: ORDER BY myRandomUDF(1234) or ORDER BY myRandomUDF(2345) Where the argument acts like a seed that always returns a consistent pseudo-random set. That way, when I get to the 2nd page, i know i'm getting the dataset back in the same order that I had on page 1, and the offset works like normal. Is this even realistically possible? Why not create a random seed between 1 and the number of possibilities in your web application when a user first hits the site, store that in the session and then increment it by 1 (do a modulus to wrap the numbers back to 1) and just select with an offset equal to this number? That way you get the first item chosen at random but the rest are sequential. If you want this somewhat random, create a "random" ordering field on the table and sort by that so the pages are not sorted by name or id or whatever else it may normally sort by. You could then take it further and use cookies so the next time that person comes to the site, the "random" page picks up where it left off. Just an idea... -- == Aaron Bono Aranya Software Technologies, Inc. http://www.aranya.com http://codeelixir.com ==
[SQL] Subselects in CHECK clause ...
I see that subselects are not directly supported in check clauses, but one can work around that by writing a stored function which returns boolean and performs the subselect. Are there any known gotchas with doing this? The CREATE TABLE docs regarding CHECK clauses states: "Currently, CHECK expressions cannot contain subqueries nor refer to variables other than columns of the current row." Is this due to someone not yet writing the necessary code to remove the subquery clause, or is there a more fundamental reason? James Robinson Socialserve.com ---(end of broadcast)--- TIP 4: Have you searched our list archives? http://archives.postgresql.org
Re: [SQL] consistent random order
Jeff Herrin <[EMAIL PROTECTED]> schrieb: > I am returning results ordered randomly using 'order by random()'. My issue > has > to do with page numbers in our web application. When I hit the 2nd page and > retrieve results with an offset, ordering by random() isn't really what I want > since I will often receive results that were on the 1st page (they get re- > randomized). > > I'm looking for a way to order in a controled random order. Maybe a UDF. I think you are searching for CURSORs. 18:25 < akretschmer> ??cursor 18:25 < rtfm_please> For information about cursor 18:25 < rtfm_please> see http://www.postgresql.org/docs/current/static/plpgsql-cursors.html 18:25 < rtfm_please> or http://www.postgresql.org/docs/current/static/sql-declare.html With a CURSOR, you get one result-set and can walk through this result. Andreas -- Really, I'm not out to destroy Microsoft. That will just be a completely unintentional side effect. (Linus Torvalds) "If I was god, I would recompile penguin with --enable-fly."(unknow) Kaufbach, Saxony, Germany, Europe. N 51.05082°, E 13.56889° ---(end of broadcast)--- TIP 7: You can help support the PostgreSQL project by donating at http://www.postgresql.org/about/donate
Re: [SQL] consistent random order
I need it a little more random than that. In both these scenarios, the same items will always follow each other. Jeff - Original Message - Why not create a random seed between 1 and the number of possibilities in your web application when a user first hits the site, store that in the session and then increment it by 1 (do a modulus to wrap the numbers back to 1) and just select with an offset equal to this number? That way you get the first item chosen at random but the rest are sequential. If you want this somewhat random, create a "random" ordering field on the table and sort by that so the pages are not sorted by name or id or whatever else it may normally sort by. You could then take it further and use cookies so the next time that person comes to the site, the "random" page picks up where it left off. Just an idea... -- == Aaron Bono Aranya Software Technologies, Inc. http://www.aranya.com http://codeelixir.com ==
Re: [SQL] consistent random order
I don't think cursors are going to help in this case. The order by random() is still going to give different result sets on different pages. Jeff - Original Message - From: Andreas Kretschmer <[EMAIL PROTECTED]> To: [email protected] Sent: Wednesday, November 29, 2006 12:27:42 PM GMT-0500 US/Eastern Subject: Re: [SQL] consistent random order Jeff Herrin <[EMAIL PROTECTED]> schrieb: > I am returning results ordered randomly using 'order by random()'. My issue > has > to do with page numbers in our web application. When I hit the 2nd page and > retrieve results with an offset, ordering by random() isn't really what I want > since I will often receive results that were on the 1st page (they get re- > randomized). > > I'm looking for a way to order in a controled random order. Maybe a UDF. I think you are searching for CURSORs. 18:25 < akretschmer> ??cursor 18:25 < rtfm_please> For information about cursor 18:25 < rtfm_please> see http://www.postgresql.org/docs/current/static/plpgsql-cursors.html 18:25 < rtfm_please> or http://www.postgresql.org/docs/current/static/sql-declare.html With a CURSOR, you get one result-set and can walk through this result. Andreas -- Really, I'm not out to destroy Microsoft. That will just be a completely unintentional side effect. (Linus Torvalds) "If I was god, I would recompile penguin with --enable-fly."(unknow) Kaufbach, Saxony, Germany, Europe. N 51.05082°, E 13.56889° ---(end of broadcast)--- TIP 7: You can help support the PostgreSQL project by donating at http://www.postgresql.org/about/donate ---(end of broadcast)--- TIP 9: In versions below 8.0, the planner will ignore your desire to choose an index scan if your joining column's datatypes do not match
Re: [SQL] Subselects in CHECK clause ...
On Wed, 29 Nov 2006, James Robinson wrote: > I see that subselects are not directly supported in check clauses, > but one can work around that by writing a stored function which > returns boolean and performs the subselect. Are there any known > gotchas with doing this? To completely get the constraint, you have to also apply constraints on the tables referenced in the function that prevent modifications on those tables from causing the constraint to be violated. For example, if you were to do an exists test on another table for a row that matches up with this row in some fashion (for a specialized referential integrity constraint) modifications on that other table could also cause the constraint to be violated, but that isn't caught by the CHECK function(...) case and you'll probably need triggers or other constraints on that table. ---(end of broadcast)--- TIP 3: Have you checked our extensive FAQ? http://www.postgresql.org/docs/faq
Re: [SQL] Subselects in CHECK clause ...
Gotcha. This is indeed to ensure a specialized ref integrity bit, against a column which "ought not ever change". Once some more old code goes away, then can fully normalize this area, making this check subselect bit go away, replaced by a regular FK. Hmm -- probably could even now make it a FK against a column which is not the pri key of the foreign table, and it'd work better and would ensure consistence against changes on the foreign table side, eh? Thanks! On Nov 29, 2006, at 12:53 PM, Stephan Szabo wrote: To completely get the constraint, you have to also apply constraints on the tables referenced in the function that prevent modifications on those tables from causing the constraint to be violated. For example, if you were to do an exists test on another table for a row that matches up with this row in some fashion (for a specialized referential integrity constraint) modifications on that other table could also cause the constraint to be violated, but that isn't caught by the CHECK function(...) case and you'll probably need triggers or other constraints on that table. James Robinson Socialserve.com ---(end of broadcast)--- TIP 2: Don't 'kill -9' the postmaster
[SQL] SQL command join question
Hi, I have three tables t1(a, b, c, d), t2(a, b, c, k), and t3(c, e). I need to outer join them as shown below, but only have all tuples from t1 as output. But the following syntax does not allow me to do so. SELECT t1.* FROM (t1 outer join t2 on (t1.a=t2.a and t1.b=t2.b)) t outer join t3 on (t1.c=t3.c); I'm getting the following error message: ERROR: invalid reference to FROM-clause entry for table "t1" HINT: There is an entry for table "t1", but it cannot be referenced from this part of the query. I'll be grateful if someone may help me with this. Thanks, Ehab _ Fixing up the home? Live Search can help http://imagine-windowslive.com/search/kits/default.aspx?kit=improve&locale=en-US&source=hmemailtaglinenov06&FORM=WLMTAG ---(end of broadcast)--- TIP 6: explain analyze is your friend
Re: [SQL] SQL command join question
Would this be more appropriate...? SELECT t1.* FROM t1 OUTER JOIN t2 ON (t1.a=t2.a AND t1.b=t2.b) OUTER JOIN t3 ON (t1.c=t3.c); -Original Message- From: [EMAIL PROTECTED] [mailto:[EMAIL PROTECTED] On Behalf Of Ehab Galal Sent: Thursday, 30 November 2006 11:42 To: [email protected] Subject: [SQL] SQL command join question Hi, I have three tables t1(a, b, c, d), t2(a, b, c, k), and t3(c, e). I need to outer join them as shown below, but only have all tuples from t1 as output. But the following syntax does not allow me to do so. SELECT t1.* FROM (t1 outer join t2 on (t1.a=t2.a and t1.b=t2.b)) t outer join t3 on (t1.c=t3.c); I'm getting the following error message: ERROR: invalid reference to FROM-clause entry for table "t1" HINT: There is an entry for table "t1", but it cannot be referenced from this part of the query. I'll be grateful if someone may help me with this. Thanks, Ehab _ Fixing up the home? Live Search can help http://imagine-windowslive.com/search/kits/default.aspx?kit=improve&locale=e n-US&source=hmemailtaglinenov06&FORM=WLMTAG ---(end of broadcast)--- TIP 6: explain analyze is your friend ***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 ---(end of broadcast)--- TIP 9: In versions below 8.0, the planner will ignore your desire to choose an index scan if your joining column's datatypes do not match
Re: [SQL] SQL command join question
On Wed, 29 Nov 2006, Ehab Galal wrote: > I have three tables t1(a, b, c, d), t2(a, b, c, k), and t3(c, e). I need to > outer join them as shown below, but only have all tuples from t1 as output. > But the following syntax does not allow me to do so. > > SELECT t1.* > FROM (t1 outer join t2 on (t1.a=t2.a and t1.b=t2.b)) t outer join t3 on > (t1.c=t3.c); I think you don't want to alias the output of the t1/t2 join to t if you're planning to continue referring to t1 in the rest of the query since I think the alias is going to hide the original t1 name. I'm not sure which outer join you were trying to use, but assuming left for now, I think something like SELECT t1.* FROM t1 left outer join t2 on (t1.a=t2.a and t1.b=t2.b ) left outer join t3 on (t1.c=t3.c); might work for you. ---(end of broadcast)--- TIP 3: Have you checked our extensive FAQ? http://www.postgresql.org/docs/faq
Re: [SQL] SQL command join question
> SELECT t1.* > FROM (t1 outer join t2 on (t1.a=t2.a and t1.b=t2.b)) t outer join t3 on ^^ > (t1.c=t3.c); ^^ -- which one t or t1? > I'm getting the following error message: > ERROR: invalid reference to FROM-clause entry for table "t1" > HINT: There is an entry for table "t1", but it cannot be referenced from > this part of the query. I am not use if I am about to give to the correct advice, but here is what stands out at me: when you specify an outer join, I believe that you have to specify whether it is a (left|right|full). Also you are using a "t" to alias the (t1 .. t2 on (...)). First of all, I am not sure this is good syntax, but if I am wrong I will have learned something new. That aside, if it is legal syntax, I don't believe that you can refer to any of it's enternal tables any more. So (t1.c=...) should really be (t.c=...). this is what I expect would work: select * from t1 left outer join t2 on ((t1.a,t1.b) = (t2.a,t2.b)) left outer join t3 on (t1.c = t3.c) ; Regards, Richard Broersma Jr. ---(end of broadcast)--- TIP 4: Have you searched our list archives? http://archives.postgresql.org
Re: [SQL] SQL command join question
"Ehab Galal" <[EMAIL PROTECTED]> writes: > SELECT t1.* > FROM (t1 outer join t2 on (t1.a=t2.a and t1.b=t2.b)) t outer join t3 on > (t1.c=t3.c); > ERROR: invalid reference to FROM-clause entry for table "t1" > HINT: There is an entry for table "t1", but it cannot be referenced from > this part of the query. Drop the alias on the outer join (the "t"). Per SQL spec, that masks table names (and aliases) within the join from the rest of the query. regards, tom lane ---(end of broadcast)--- TIP 7: You can help support the PostgreSQL project by donating at http://www.postgresql.org/about/donate
Re: [SQL] consistent random order
On Wed, Nov 29, 2006 at 12:32:56PM -0500, Jeff Herrin wrote: > I don't think cursors are going to help in this case. The order > by random() is still going to give different result sets on different > pages. Have you tried using setseed() to seed the random number generator to the same value before each query? -- Michael Fuhr ---(end of broadcast)--- TIP 3: Have you checked our extensive FAQ? http://www.postgresql.org/docs/faq
