On 2025-04-20 08:28:22 -0700, Adrian Klaver wrote: > On 4/20/25 02:10, Peter J. Holzer wrote: > > I've just read Laurenz' blog post about the differences between Oracle > > and PostgreSQL[1]. > > > > One of the differences is that something like > > > > UPDATE tab SET id = id + 1; > > > > tends to fail on PostgreSQL because the the primary key constraint is > > checked for every row, so it will stumble over the temporary conflicts. > > > > The solution is to define the constraint as deferrable. > > > > But that got me to thinking about different ways ... > > > > There won't be a conflict if the ids are updated in descending order. > > Is there a way to force PostgreSQL to update the rows in a specific > > order? > > > > I came up with > > > > with a as (select id from t where id > 50 order by id desc) > > update t set id = a.id+1 from a where t.id = a.id; > > > > which works in my simple test case, but it doesn't look like it's > > guaranteed to work. The implicit join in «update t ... from a» could > > produce rows in any order, especially for large tables. > > My read of this
Your read of the query, the PostgreSQL source or the SQL standard? > is that for the duration of the query a temporary table a is create > that is ordered on `id desc` and that '... from a where t.id = a.id' > will apply that order to the selection of t.id. Yes, that's the intention. In as I wrote it did work in my simple tests. But is it guaranteed to work? Is there anything in the standard that says that the order has to be preserved? Or failing that, is that the way it's currently implemented and there are reasons to assume that it will never be changed? > As example: > > create table id_update(id integer primary key); > > insert into id_update select a from generate_series(1, 100000) as t(a); > INSERT 0 100000 > > -- id(s) are temporarily in order. > > update id_update set id = id where id between 50000 and 60000; > UPDATE 10001 > > -- The above move the 10001 values to 'end' of id_update > > with a as (select id from id_update where id > 100 order by id desc) update > id_update as t set id = a.id + 1 from a where t.id = a.id; > UPDATE 99900 I note that this produces a hash join: #v+ ╔═══════════════════════════════════════════════════════════════════════════════════════════════════════════════════════╗ ║ QUERY PLAN ║ ╟───────────────────────────────────────────────────────────────────────────────────────────────────────────────────────╢ ║ Update on id_update t (cost=3179.42..8662.63 rows=0 width=0) ║ ║ -> Hash Join (cost=3179.42..8662.63 rows=99899 width=38) ║ ║ Hash Cond: (a.id = t.id) ║ ║ -> Subquery Scan on a (cost=0.42..4971.64 rows=99899 width=32) ║ ║ -> Index Only Scan Backward using id_update_pkey on id_update (cost=0.42..3972.65 rows=99899 width=4) ║ ║ Index Cond: (id > 100) ║ ║ -> Hash (cost=1929.00..1929.00 rows=100000 width=10) ║ ║ -> Seq Scan on id_update t (cost=0.00..1929.00 rows=100000 width=10) ║ ╚═══════════════════════════════════════════════════════════════════════════════════════════════════════════════════════╝ #v- If the hash was the other way around it wouldn't work. So let's try if we can get the optimizer to flip the plan by changing the number of updated rows. [a few minutes later] #v+ hjp=> explain with a as (select id from id_update where id > 90000 order by id desc) update id_update as t set id = a.id + 1 from a where a.id = t.id; ╔════════════════════════════════════════════════════════════════════════════════════════════════════════════════════════════╗ ║ QUERY PLAN ║ ╟────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────────╢ ║ Update on id_update t (cost=732.53..2675.61 rows=0 width=0) ║ ║ -> Hash Join (cost=732.53..2675.61 rows=10006 width=38) ║ ║ Hash Cond: (t.id = a.id) ║ ║ -> Seq Scan on id_update t (cost=0.00..1443.00 rows=100000 width=10) ║ ║ -> Hash (cost=607.46..607.46 rows=10006 width=32) ║ ║ -> Subquery Scan on a (cost=0.29..607.46 rows=10006 width=32) ║ ║ -> Index Only Scan Backward using id_update_pkey on id_update (cost=0.29..507.40 rows=10006 width=4) ║ ║ Index Cond: (id > 90000) ║ ╚════════════════════════════════════════════════════════════════════════════════════════════════════════════════════════════╝ #v- Looks like we got it. And indeed: #v+ hjp=> with a as (select id from id_update where id > 90000 order by id desc) update id_update as t set id = a.id + 1 from a where a.id = t.id; ERROR: duplicate key value violates unique constraint "id_update_pkey" DETAIL: Key (id)=(90002) already exists. #v- So, obviously that isn't guaranteed to work. hjp -- _ | Peter J. Holzer | Story must make more sense than reality. |_|_) | | | | | h...@hjp.at | -- Charles Stross, "Creative writing __/ | http://www.hjp.at/ | challenge!"
signature.asc
Description: PGP signature