From: | Rod Taylor <rbt(at)rbt(dot)ca> |
---|---|
To: | Ulrich Meis <u(dot)meis(at)gmx(dot)de> |
Cc: | pgsql-bugs(at)postgresql(dot)org |
Subject: | Re: select where id=random()*something returns two results |
Date: | 2003-09-19 01:25:14 |
Message-ID: | 1063934713.40733.23.camel@jester |
Views: | Raw Message | Whole Thread | Download mbox | Resend email |
Thread: | |
Lists: | pgsql-bugs |
> select * from quotes where id=1+round(random()* cast ((select max(id)
> from quotes) as double precision));
> id | quote |
> author
> -----+-----------------------------------------------------------+------
> -----------
> 187 | Vergib Deinen Feinden, aber vergiss niemals ihre Namen. | John
> F. Kennedy
> 377 | Die Wirklichkeit ist nicht so oder so, sondern so und so. | Harry
> Mulisch
> (2 rows)
>
> I'm not really into databases, but this sounds wrong. Most of the time,
> I actually get 0 results.
Random is calculated per call (in this case per comparison). So, the
value you compare against for 187 is not the same as 377.
UPDATE table SET column = random(); will show the effect.
If you wrap randon() in a subselect, it will cause it to be evaluated
once:
SELECT * from quotes where id = 1+round((SELECT random()) * cast(....).
However, a much faster query for your purposes would be:
SELECT * FROM quotes ORDER BY random() LIMIT 1;
From | Date | Subject | |
---|---|---|---|
Next Message | Ulrich Meis | 2003-09-19 10:36:15 | Re: select where id=random()*something returns two results |
Previous Message | Kris Jurka | 2003-09-19 01:15:21 | Re: select where id=random()*something returns two results |