From 793dd8e729a8fbd3fca7e6722bb405bf710d2ced Mon Sep 17 00:00:00 2001 From: Tom Lane Date: Sat, 14 Aug 2004 22:18:23 +0000 Subject: [PATCH] Add discussion and example about predicate locking and why "serializable" mode isn't really serializable. I had thought this was covered already in our docs, but I sure can't find it. --- doc/src/sgml/mvcc.sgml | 114 ++++++++++++++++++++++++++++++++++++----- 1 file changed, 100 insertions(+), 14 deletions(-) diff --git a/doc/src/sgml/mvcc.sgml b/doc/src/sgml/mvcc.sgml index ebbdf6291f..e47d0094f2 100644 --- a/doc/src/sgml/mvcc.sgml +++ b/doc/src/sgml/mvcc.sgml @@ -1,5 +1,5 @@ @@ -394,6 +394,90 @@ ERROR: could not serialize access due to concurrent update a transaction executes several successive commands that must see identical views of the database. + + + Serializable Isolation versus True Serializability + + + serializability + + + + predicate locking + + + + The intuitive meaning (and mathematical definition) of + serializable execution is that any two successfully committed + concurrent transactions will appear to have executed strictly serially, + one after the other --- although which one appeared to occur first may + not be predictable in advance. It is important to realize that forbidding + the undesirable behaviors listed in + is not sufficient to guarantee true serializability, and in fact + PostgreSQL's Serializable mode does + not guarantee serializable execution in this sense. As an example, + consider a table mytab, initially containing + + class | value +-------+------- + 1 | 10 + 1 | 20 + 2 | 100 + 2 | 200 + + Suppose that serializable transaction A computes + +SELECT SUM(value) FROM mytab WHERE class = 1; + + and then inserts the result (30) as the value in a + new row with class = 2. Concurrently, serializable + transaction B computes + +SELECT SUM(value) FROM mytab WHERE class = 2; + + and obtains the result 300, which it inserts in a new row with + class = 1. Then both transactions commit. None of + the listed undesirable behaviors have occurred, yet we have a result + that could not have occurred in either order serially. If A had + executed before B, B would have computed the sum 330, not 300, and + similarly the other order would have resulted in a different sum + computed by A. + + + + To guarantee true mathematical serializability, it is necessary for + a database system to enforce predicate locking, which + means that a transaction cannot insert or modify a row that would + have matched the WHERE condition of a query in another concurrent + transaction. For example, once transaction A has executed the query + SELECT ... WHERE class = 1, a predicate-locking system + would forbid transaction B from inserting any new row with class 1 + until A has committed. + + + Essentially, a predicate-locking system prevents phantom reads + by restricting what is written, whereas MVCC prevents them by + restricting what is read. + + + Such a locking system is complex to + implement and extremely expensive in execution, since every session must + be aware of the details of every query executed by every concurrent + transaction. And this large expense is mostly wasted, since in + practice most applications do not do the sorts of things that could + result in problems. (Certainly the example above is rather contrived + and unlikely to represent real software.) Accordingly, + PostgreSQL does not implement predicate + locking, and so far as we are aware no other production DBMS does either. + + + + In those cases where the possibility of nonserializable execution + is a real hazard, problems can be prevented by appropriate use of + explicit locking. Further discussion appears in the following + sections. + + @@ -434,7 +518,8 @@ ERROR: could not serialize access due to concurrent update The list below shows the available lock modes and the contexts in which they are used automatically by - PostgreSQL. + PostgreSQL. You can also acquire any + of these locks explicitly with the command . Remember that all of these lock modes are table-level locks, even if the name contains the word row; the names of the lock modes are historical. @@ -736,8 +821,8 @@ UPDATE accounts SET balance = balance - 100.00 WHERE acctnum = 22222; The best defense against deadlocks is generally to avoid them by being certain that all applications using a database acquire - locks on multiple objects in a consistent order. That was the - reason for the previous deadlock example: if both transactions + locks on multiple objects in a consistent order. In the example + above, if both transactions had updated the rows in the same order, no deadlock would have occurred. One should also ensure that the first lock acquired on an object in a transaction is the highest mode that will be @@ -778,7 +863,7 @@ UPDATE accounts SET balance = balance - 100.00 WHERE acctnum = 22222; Another way to think about it is that each transaction sees a snapshot of the database contents, and concurrently executing transactions may very well see different snapshots. So the - whole concept of now is somewhat suspect anyway. + whole concept of now is somewhat ill-defined anyway. This is not normally a big problem if the client applications are isolated from each other, but if the clients can communicate via channels outside the database @@ -801,8 +886,8 @@ UPDATE accounts SET balance = balance - 100.00 WHERE acctnum = 22222; - Global validity checks require extra thought under MVCC. For - example, a banking application might wish to check that the sum of + Global validity checks require extra thought under MVCC. + For example, a banking application might wish to check that the sum of all credits in one table equals the sum of debits in another table, when both tables are being actively updated. Comparing the results of two successive SELECT sum(...) commands will not work reliably under @@ -824,9 +909,9 @@ UPDATE accounts SET balance = balance - 100.00 WHERE acctnum = 22222; Note also that if one is - relying on explicit locks to prevent concurrent changes, one should use + relying on explicit locking to prevent concurrent changes, one should use Read Committed mode, or in Serializable mode be careful to obtain the - lock(s) before performing queries. An explicit lock obtained in a + lock(s) before performing queries. A lock obtained by a serializable transaction guarantees that no other transactions modifying the table are still running, but if the snapshot seen by the transaction predates obtaining the lock, it may predate some now-committed @@ -834,7 +919,7 @@ UPDATE accounts SET balance = balance - 100.00 WHERE acctnum = 22222; frozen at the start of its first query or data-modification command (SELECT, INSERT, UPDATE, or DELETE), so - it's possible to obtain explicit locks before the snapshot is + it's possible to obtain locks explicitly before the snapshot is frozen. @@ -888,10 +973,11 @@ UPDATE accounts SET balance = balance - 100.00 WHERE acctnum = 22222; - Share/exclusive page-level locks are used for read/write - access. Locks are released after the page is processed. - Page-level locks provide better concurrency than index-level - ones but are liable to deadlocks. + Share/exclusive hash-bucket-level locks are used for read/write + access. Locks are released after the whole bucket is processed. + Bucket-level locks provide better concurrency than index-level + ones, but deadlock is possible since the locks are held longer + than one index operation. -- 2.40.0