From 0807dbb294738dd888416e0d75a456b6f336f467 Mon Sep 17 00:00:00 2001 From: "Thomas G. Lockhart" Date: Wed, 26 May 1999 17:27:39 +0000 Subject: [PATCH] Chapter on multi-version concurrency control from Vadim. Some wording changes from Vadim's original text doc. Processes cleanly, but may need fixup. --- doc/src/sgml/mvcc.sgml | 545 +++++++++++++++++++++++++++++++++++++++++ 1 file changed, 545 insertions(+) create mode 100644 doc/src/sgml/mvcc.sgml diff --git a/doc/src/sgml/mvcc.sgml b/doc/src/sgml/mvcc.sgml new file mode 100644 index 0000000000..edf0ef7088 --- /dev/null +++ b/doc/src/sgml/mvcc.sgml @@ -0,0 +1,545 @@ + + Multi-Version Concurrency Control + + + + Multi-Version Concurrency Control + (MVCC) + is an advanced technique for improving database performance in a + multi-user environment. + Vadim Mikheev provided + the implementation for Postgres. + + + + + Introduction + + + Unlike most other database systems which use locks for concurrency control, + Postgres + maintains data consistency by using a multiversion model. + This means that while querying database each transaction sees + a snapshot of data (a database version) + as it was some + time ago, regardless of the current state of data queried. + This protects the transaction from viewing inconsistent data that + could be caused by (other) concurrent transaction updates on the same + data rows, providing transaction isolation + for each database session. + + + + The main difference between multiversion and lock models is that + in MVCC locks acquired for querying (reading) data don't conflict + with locks acquired for writing data and so reading never blocks + writing and writing never blocks reading. + + + + + Transaction Isolation + + + The ANSI/ISO SQL + standard defines four levels of transaction + isolation in terms of three phenomena that must be prevented + between concurrent transactions. + These undesirable phenomena are: + + + + + dirty reads + + + + A transaction reads data written by concurrent uncommitted transaction. + + + + + + + non-repeatable reads + + + + A transaction re-reads data it has previously read and finds that data + has been modified by another committed transaction. + + + + + + + phantom read + + + + A transaction re-executes a query returning a set of rows that satisfy a + search condition and finds that additional rows satisfying the condition + has been inserted by another committed transaction. + + + + + + + + Accordingly, the four isolation levels are defined to be: + + + + Isolation Level + + + Dirty Read + + + Non-Repeatable Read + + + Phantom Read + + + + Read uncommitted + + + Possible + + + Possible + + + Possible + + + + + + Read committed + + + Not possible + + + Possible + + + Possible + + + + + + Repeatable read + + + Not possible + + + Not possible + + + Possible + + + + + + Serializable + + + Not possible + + + Not possible + + + Not possible + + + + + Postgres + offers the read committed and serializable isolation levels. + + + + + Read Committed Isolation Level + + + This is the default isolation level in Postgres. + When a transaction runs on this isolation level, a query sees only + data committed before the query began and never sees either dirty data or + concurrent transaction changes committed during query execution. + + + + If a row returned by a query while executing an + UPDATE statement + (or DELETE + or SELECT FOR UPDATE) + is being updated by a + concurrent uncommitted transaction then the second transaction + that tries to update this row will wait for the other transaction to + commit or rollback. In the case of rollback, the waiting transaction + can proceed to change the row. In the case of commit (and if the + row still exists; i.e. was not deleted by the other transaction), the + query will be re-executed for this row to check that new row + version satisfies query search condition. If the new row version + satisfies the query search condition then row will be + updated (or deleted or marked for update). + + + + Note that the results of execution of SELECT or INSERT (with a query) + statements will not be affected by concurrent transactions. + + + + + Serializable Isolation Level + + + This level provides the highest transaction isolation. When a + transaction is on the serializable level, + a query sees only data + committed before the transaction began and never see either dirty data + or concurrent transaction changes committed during transaction + execution. So, this level emulates serial transaction execution, + as if transactions would be executed one after another, serially, + rather than concurrently. + + + + If a row returned by query while executing + UPDATE/DELETE/SELECT FOR UPDATE + statement is being updated by + a concurrent uncommitted transaction then the second transaction + that tries to update this row will wait for the other transaction to + commit or rollback. In the case of rollback, the waiting transaction + can proceed to change the row. In the case of a concurrent + transaction commit, a serializable transaction will be rolled back + with the message + + +ERROR: Can't serialize access due to concurrent update + + + because a serializable transaction cannot modify rows changed by + other transactions after the serializable transaction began. + + + + + Note that results of execution of SELECT + or INSERT (with a query) + will not be affected by concurrent transactions. + + + + + + Locking and Tables + + + Postgres + provides various lock modes to control concurrent + access to data in tables. Some of these lock modes are acquired by + Postgres + automatically before statement execution, while others are + provided to be used by applications. All lock modes (except for + AccessShareLock) acquired in a transaction are held for the duration + of the transaction. + + + + In addition to locks, short-term share/exclusive latches are used + to control read/write access to table pages in shared buffer pool. + Latches are released immediately after a tuple is fetched or updated. + + + + Table-level locks + + + + + + AccessShareLock + + + + An internal lock mode acquiring automatically over tables + being queried. Postgres + releases these locks after statement is + done. + + + + Conflicts with AccessExclusiveLock only. + + + + + + + RowShareLock + + + + Acquired by SELECT FOR UPDATE + and LOCK TABLE + for statements. + + + + Conflicts with ExclusiveLock and AccessExclusiveLock modes. + + + + + + + RowExclusiveLock + + + + Acquired by UPDATE, DELETE, + INSERT and LOCK TABLE + for statements. + + + + Conflicts with ShareLock, ShareRowExclusiveLock, ExclusiveLock and + AccessExclusiveLock modes. + + + + + + + ShareLock + + + + Acquired by CREATE INDEX + and LOCK TABLE table + for + statements. + + + + Conflicts with RowExclusiveLock, ShareRowExclusiveLock, + ExclusiveLock and AccessExclusiveLock modes. + + + + + + + ShareRowExclusiveLock + + + + Acquired by LOCK TABLE for + statements. + + + + Conflicts with RowExclusiveLock, ShareLock, ShareRowExclusiveLock, + ExclusiveLock and AccessExclusiveLock modes. + + + + + + + ExclusiveLock + + + + Acquired by LOCK TABLE table + for statements. + + + + Conflicts with RowShareLock, RowExclusiveLock, ShareLock, + ShareRowExclusiveLock, ExclusiveLock and AccessExclusiveLock + modes. + + + + + + + AccessExclusiveLock + + + + Acquired by ALTER TABLE, + DROP TABLE, + VACUUM and LOCK TABLE + statements. + + + + Conflicts with RowShareLock, RowExclusiveLock, ShareLock, + ShareRowExclusiveLock, ExclusiveLock and AccessExclusiveLock + modes. + + + + Note that only AccessExclusiveLock blocks SELECT (without FOR + UPDATE) statement. + + + + + + + + + + + Row-level locks + + + These locks are acquired by means of modification of internal + fields of row being updated/deleted/marked for update. + Postgres + doesn't remember any information about modified rows in memory and + so hasn't limit for locked rows without lock escalation. + + + + However, take into account that SELECT FOR UPDATE will modify + selected rows to mark them and so will results in disk writes. + + + + Row-level locks don't affect data querying. They are used to block + writers to the same row only. + + + + + + Locking and Indices + + + Though Postgres + provides unblocking read/write access to table + data, it is not the case for all index access methods implemented + in Postgres. + + + + The various index types are handled as follows: + + + + + GiST and R-Tree indices + + + + Share/exclusive INDEX-level locks are used for read/write access. + Locks are released after statement is done. + + + + + + + Hash indices + + + + Share/exclusive PAGE-level locks are used for read/write access. + Locks are released after page is processed. + + + + Page-level locks produces better concurrency than index-level ones + but are subject to deadlocks. + + + + + + + Btree + + + + Short-term share/exclusive PAGE-level latches are used for + read/write access. Latches are released immediately after the index + tuple is inserted/fetched. + + + + Btree indices provide highest concurrency without deadlock + conditions. + + + + + + + + + Data consistency checks at the application level + + + Because readers in Postgres + don't lock data, regardless of + transaction isolation level, data read by one transaction can be + overwritten by another. In the other words, if a row is returned + by SELECT it doesn't mean that this row really + exists at the time it is returned (i.e. sometime after the + statement or transaction began) nor + that the row is protected from deletion/updation by concurrent + transactions before the current transaction commit or rollback. + + + + To ensure the actual existance of a row and protect it against + concurrent updates one must use SELECT FOR UPDATE or + an appropriate LOCK TABLE statement. + This should be taken into account when porting applications using + serializable mode to Postgres from other environments. + + + + Before version 6.5 Postgres + used read-locks and so the + above consideration is also the case + when upgrading to 6.5 (or higher) from previous + Postgres versions. + + + + + + +