Thread: BUG #16520: Deleting from non-existent column in CTE removes all rows
BUG #16520: Deleting from non-existent column in CTE removes all rows
From
PG Bug reporting form
Date:
The following bug has been logged on the website: Bug reference: 16520 Logged by: Jesse Lieberg Email address: jesse007@ymail.com PostgreSQL version: 12.3 Operating system: debian:buster-slim Description: Using the `postgres:12` docker image and given the following: ``` DROP TABLE IF EXISTS test; CREATE TABLE test ( id SERIAL, username varchar(32) ); INSERT INTO test (username) VALUES ('Jesse'), ('Jesse'), ('Scott'), ('Scott'), ('John'); ``` This will throw an error that the column does not exist: ``` WITH to_delete AS ( SELECT MIN(id), username FROM test GROUP BY username HAVING count(*) > 1 ) SELECT id FROM to_delete; ``` However, the this will not return an error and instead deletes all rows: ``` WITH to_delete AS ( SELECT MIN(id), username FROM test GROUP BY username HAVING count(*) > 1 ) DELETE FROM test WHERE id IN ( SELECT id FROM to_delete ); ``` More information: https://stackoverflow.com/q/62661721/3903479
PG Bug reporting form <noreply@postgresql.org> writes: > This will throw an error that the column does not exist: > ``` > WITH to_delete AS ( > SELECT MIN(id), username > FROM test > GROUP BY username > HAVING count(*) > 1 > ) > SELECT id > FROM to_delete; > ``` Sure, because the columns exposed by to_delete are named "min" and "username", not "id". > However, the this will not return an error and instead deletes all rows: > ``` > WITH to_delete AS ( > SELECT MIN(id), username > FROM test > GROUP BY username > HAVING count(*) > 1 > ) > DELETE FROM test > WHERE id IN ( > SELECT id > FROM to_delete > ); > ``` You've been bit by the standard SQL newbie trap that sub-selects allow outer references. That IN clause devolves to constant true (at least for non-null id values, and with to_delete known not empty), because it's just "id = id". regards, tom lane
Re: BUG #16520: Deleting from non-existent column in CTE removes all rows
From
"David G. Johnston"
Date:
On Tuesday, June 30, 2020, PG Bug reporting form <noreply@postgresql.org> wrote:
The following bug has been logged on the website:
Bug reference: 16520
Logged by: Jesse Lieberg
Email address: jesse007@ymail.com
PostgreSQL version: 12.3
Operating system: debian:buster-slim
Description:
However, the this will not return an error and instead deletes all rows:
```
WITH to_delete AS (
SELECT MIN(id), username
FROM test
GROUP BY username
HAVING count(*) > 1
)
DELETE FROM test
WHERE id IN (
SELECT id
FROM to_delete
);
Yes, because the column id does exist - you just omitted the table reference which ends up making the subquery query equivalent to: “select test.id from to_delete” which is mandatory, and generally useful, sql syntax.
David J.