Re: Fwd: Unexpected Multiple Records from Randomized Query

From: Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us>
To: 김명준 <audwns525(at)gmail(dot)com>
Cc: pgsql-general(at)lists(dot)postgresql(dot)org
Subject: Re: Fwd: Unexpected Multiple Records from Randomized Query
Date: 2024-02-23 15:09:25
Message-ID: 813880.1708700965@sss.pgh.pa.us
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-general

=?UTF-8?B?6rmA66qF7KSA?= <audwns525(at)gmail(dot)com> writes:
> explain analyze
> SELECT * FROM users WHERE name = 'User '||trunc(random()*100) ;

> I expected the result to return one record. However, in some cases, the
> result comes back with 2 or 3 records. What am I doing wrong?

random() is re-evaluated at each row, so it's not that surprising
if you sometimes get multiple matches. This is the same behavior
that you relied on to fill the table with not-all-the-same names.

The preferred way to avoid that is to stuff the random() call into
a CTE:

WITH x AS (SELECT random() AS r)
SELECT * FROM users, x WHERE name = 'User '||trunc(r*100) ;

or in this case better to shove the whole constant computation
into the CTE.

regards, tom lane

In response to

Browse pgsql-general by date

  From Date Subject
Next Message Peter J. Holzer 2024-02-24 16:43:32 Re: Postgres 16 missing from apt repo?
Previous Message Vick Khera 2024-02-23 14:32:47 Re: How to schema-qualify "IS DISTINCT FROM" on trigger definition? (I created a db that cannot be dump/restored)