laurenz.albe@xxxxxxxxxxx wrote:bryn@xxxxxxxxxxxx wrote: Oh. I was wrong, then. I'll say more on this below.
I can't follow you here, sorry. I tried this: k serial primary key, v int not null, constraint t_v_unq unique(v) initially deferred); -- RED start transaction isolation level read committed; insert into t(v) values (1), (2); select k, v from t order by k; -- BLUE start transaction isolation level read committed; insert into t(v) values (1), (3); select k, v from t order by k; -- RED commit; select k, v from t order by k; -- BLUE select k, v from t order by k; commit; select k, v from t order by k; The first "select" from the "BLUE" session at the very end produces this: k | v ---+--- 1 | 1 2 | 2 3 | 1 4 | 3 This doesn't surprise me. It's ultimately illegal. But not yet. (Before "RED" committed, "BLUE" didn't see the rows with "k = 1" and "k = 2". So it isn't seeing any other sessions uncommitted data—but only it's own uncommitted data.) Then, when "BLUE" commits, it (of course) gets this: ERROR: duplicate key value violates unique constraint "t_v_unq" DETAIL: Key (v)=(1) already exists. Then it sees (of course, again) only the rows with "k = 1" and "k = 2"—the same as what "RED" saw. It seems to be impossible to do a test in slow motion where "RED" and "BLUE" each issues "commit" at the exact same moment. So thinking about this scenario doesn't tell me if: (a) Each session runs its constraint check and the rest of what "commit" entails in a genuinely serialized fashion. OR (b) Each session first runs its constraint check (and some other stuff) non-serializedly—and only then runs the small part of the total "commit" action (the WAL part) serializedly. (This would result in bad data in the database at rest—just as my contrived misuse of "set constraints all immediate" left things in my "one or two admins" scenario.) I appreciate that this just is a different wording of what I wrote before—but now w.r.t. the system-implemented unique constraint use-case. The (a) scheme sounds correct. And the (b) scheme sounds wrong. Why would PG prefer to implement (b) rather than (a)? I'm clearly missing something.
Yes, I most certainly did think this. Where, in the PG doc, can I read the account of the proper mental model for the application programmer? It seems to be impossible to conduct an experiment that would disprove the hypothesis that one, or the other, of these mental models is correct.
Your post's testcase used the condition "at least one guard on duty" and used pessimistic locking to enforce this rule—while, I assume, all sessions use just the default "read committed" isolation level. It also showed how to enforce the rule by having any session that performs the risky de-assignment of a guard use the "serializable" isolation level. This solution is easier to write—but (as you imply) is less performant in a system where many concurrent sessions attempt the risky operation at the same time. You mention too that the client must implement a re-try strategy—and this complicates the overall programming exercise. (Sadly, retry cannot be encapsulated in PL/pgSQL because a block that has an exception handler cannot issue "commit" and yet serialization errors (typically?) occur only at commit time.) My testcase used a stricter rule: the table of staff must have exactly one or two rows where the job is "Admin". So, here, concurrent sessions can break the rule (when the txn starts with one "Admin") by updating different rows to make them "Admin" or by inserting different new "Admin" rows. I've convinced myself by experiment that an ordinary trigger can enforce this rule when contending sessions use "serializable" isolation. Am I right that you'd say that no pessimistic locking scheme can enforce the rule at lower isolation levels except the brute-force "lock table"? |