Thread: Fwd: Unexpected Multiple Records from Randomized Query
The query is as follows:
CREATE TABLE users (
id SERIAL PRIMARY KEY,
name VARCHAR(100),
email VARCHAR(100),
signup_date DATE
);
INSERT INTO users (name, email, signup_date)
SELECT
'User ' || i,
'user' || i || '@example.com',
NOW() - (random() * (365 * 5) || ' days')::interval
FROM generate_series(1, 1000000) AS s(i);
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?
I'm not sure if this is a conflict issue between the random() and trunc() functions, or if I have set up the test case incorrectly.
I am using PostgreSQL 15.4 version on Ubuntu 22.04 in a container environment. PostgreSQL was built by compiling the Source code.
Thank you for your time and consideration.
Best regards,
Myoungjun Kim
=?UTF-8?B?6rmA66qF7KSA?= <audwns525@gmail.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