From: | Stephan Szabo <sszabo(at)megazone(dot)bigpanda(dot)com> |
---|---|
To: | Markus Bertheau <twanger(at)bluetwanger(dot)de> |
Cc: | Bruno Wolff III <bruno(at)wolff(dot)to>, pgsql-sql(at)postgresql(dot)org |
Subject: | Re: SELECT MAX(c) FROM (SELECT ... FOR UPDATE) AS foo |
Date: | 2004-08-17 15:09:19 |
Message-ID: | 20040817075821.V61699@megazone.bigpanda.com |
Views: | Raw Message | Whole Thread | Download mbox | Resend email |
Thread: | |
Lists: | pgsql-sql |
On Tue, 17 Aug 2004, Markus Bertheau wrote:
> , 17.08.2004, 16:12, Bruno Wolff III :
> > > SELECT MAX(position) FROM (SELECT position FROM classes WHERE name =
> > > 'foo' FOR UPDATE OF classes) AS foo
> > >
> > > It's clear which rows should be locked here, I think.
> >
> > Even if it was allowed, it probably wouldn't be good enough because it won't
> > protect against newly inserted records.
>
> Can you detail an example where this wouldn't be good enough?
Another transaction can come along and insert a row with name='foo' into
classes with a higher position value after you've done the above but
before you commit.
T1: begin;
T2: begin;
T1: select max(position) from (select position from classes where
name='foo' for update of classes) as foo;
-- say this gets 5
T2: insert into classes (name, position) values ('foo', 10);
-- This wouldn't be blocked by the for update lock.
T2: commit;
-- now if you were to do the T1 select above, you'd get a different
-- answer in read committed.
If we had predicate locking, I think you could probably manage these cases
in serializable mode, but for now I'm not sure anything less than a table
lock would do.
From | Date | Subject | |
---|---|---|---|
Next Message | Markus Bertheau | 2004-08-17 15:12:11 | Re: multi column foreign key for implicitly unique columns |
Previous Message | Stephan Szabo | 2004-08-17 15:06:05 | Re: multi column foreign key for implicitly unique columns |