From bedb78d386a47fd66b6cda2040e0a5fb545ee371 Mon Sep 17 00:00:00 2001 From: Tom Lane Date: Thu, 28 Apr 2005 21:47:18 +0000 Subject: Implement sharable row-level locks, and use them for foreign key references to eliminate unnecessary deadlocks. This commit adds SELECT ... FOR SHARE paralleling SELECT ... FOR UPDATE. The implementation uses a new SLRU data structure (managed much like pg_subtrans) to represent multiple- transaction-ID sets. When more than one transaction is holding a shared lock on a particular row, we create a MultiXactId representing that set of transactions and store its ID in the row's XMAX. This scheme allows an effectively unlimited number of row locks, just as we did before, while not costing any extra overhead except when a shared lock actually has to be shared. Still TODO: use the regular lock manager to control the grant order when multiple backends are waiting for a row lock. Alvaro Herrera and Tom Lane. --- doc/src/sgml/mvcc.sgml | 72 +++++++++++++++++++------------ doc/src/sgml/ref/grant.sgml | 9 ++-- doc/src/sgml/ref/lock.sgml | 6 +-- doc/src/sgml/ref/pg_resetxlog.sgml | 86 +++++++++++++++++++++++++------------ doc/src/sgml/ref/select.sgml | 87 ++++++++++++++++++++++++++------------ doc/src/sgml/ref/select_into.sgml | 4 +- doc/src/sgml/sql.sgml | 4 +- doc/src/sgml/storage.sgml | 8 +++- 8 files changed, 184 insertions(+), 92 deletions(-) (limited to 'doc/src') diff --git a/doc/src/sgml/mvcc.sgml b/doc/src/sgml/mvcc.sgml index 462fa99cb95..c88974a8d7c 100644 --- a/doc/src/sgml/mvcc.sgml +++ b/doc/src/sgml/mvcc.sgml @@ -1,5 +1,5 @@ @@ -253,11 +253,12 @@ $PostgreSQL: pgsql/doc/src/sgml/mvcc.sgml,v 2.49 2005/03/24 00:03:18 neilc Exp $ - UPDATE, DELETE, and SELECT - FOR UPDATE commands behave the same as SELECT + UPDATE, DELETE, SELECT + FOR UPDATE, and SELECT FOR SHARE commands + behave the same as SELECT in terms of searching for target rows: they will only find target rows that were committed as of the command start time. However, such a target - row may have already been updated (or deleted or marked for update) by + row may have already been updated (or deleted or locked) by another concurrent transaction by the time it is found. In this case, the would-be updater will wait for the first updating transaction to commit or roll back (if it is still in progress). If the first updater rolls back, @@ -268,7 +269,10 @@ $PostgreSQL: pgsql/doc/src/sgml/mvcc.sgml,v 2.49 2005/03/24 00:03:18 neilc Exp $ the row. The search condition of the command (the WHERE clause) is re-evaluated to see if the updated version of the row still matches the search condition. If so, the second updater proceeds with its operation, - starting from the updated version of the row. + starting from the updated version of the row. (In the case of + SELECT FOR UPDATE and SELECT FOR + SHARE, that means it is the updated version of the row that is + locked and returned to the client.) @@ -346,25 +350,26 @@ COMMIT; - UPDATE, DELETE, and SELECT - FOR UPDATE commands behave the same as SELECT + UPDATE, DELETE, SELECT + FOR UPDATE, and SELECT FOR SHARE commands + behave the same as SELECT in terms of searching for target rows: they will only find target rows that were committed as of the transaction start time. However, such a target - row may have already been updated (or deleted or marked for update) by + row may have already been updated (or deleted or locked) by another concurrent transaction by the time it is found. In this case, the serializable transaction will wait for the first updating transaction to commit or roll back (if it is still in progress). If the first updater rolls back, then its effects are negated and the serializable transaction can proceed with updating the originally found row. But if the first updater commits - (and actually updated or deleted the row, not just selected it for update) + (and actually updated or deleted the row, not just locked it) then the serializable transaction will be rolled back with the message ERROR: could not serialize access due to concurrent update - because a serializable transaction cannot modify rows changed by + because a serializable transaction cannot modify or lock rows changed by other transactions after the serializable transaction began. @@ -571,10 +576,12 @@ SELECT SUM(value) FROM mytab WHERE class = 2; - The SELECT FOR UPDATE command acquires a + The SELECT FOR UPDATE and + SELECT FOR SHARE commands acquire a lock of this mode on the target table(s) (in addition to ACCESS SHARE locks on any other tables - that are referenced but not selected ). + that are referenced but not selected + ). @@ -714,7 +721,7 @@ SELECT SUM(value) FROM mytab WHERE class = 2; Only an ACCESS EXCLUSIVE lock blocks a - SELECT (without ) + SELECT (without ) statement. @@ -725,25 +732,37 @@ SELECT SUM(value) FROM mytab WHERE class = 2; Row-Level Locks - In addition to table-level locks, there are row-level locks. - A row-level lock on a specific row is automatically acquired when the - row is updated (or deleted or marked for update). The lock is held - until the transaction commits or rolls back. - Row-level locks do not affect data - querying; they block writers to the same row - only. To acquire a row-level lock on a row without actually + In addition to table-level locks, there are row-level locks, which + can be exclusive or shared locks. An exclusive row-level lock on a + specific row is automatically acquired when the row is updated or + deleted. The lock is held until the transaction commits or rolls + back. Row-level locks do not affect data querying; they block + writers to the same row only. + + + + To acquire an exclusive row-level lock on a row without actually modifying the row, select the row with SELECT FOR - UPDATE. Note that once a particular row-level lock is - acquired, the transaction may update the row multiple times without + UPDATE. Note that once the row-level lock is acquired, + the transaction may update the row multiple times without fear of conflicts. + + To acquire a shared row-level lock on a row, select the row with + SELECT FOR SHARE. A shared lock does not prevent + other transactions from acquiring the same shared lock. However, + no transaction is allowed to update, delete, or exclusively lock a + row on which any other transaction holds a shared lock. Any attempt + to do so will block until the shared locks have been released. + + PostgreSQL doesn't remember any information about modified rows in memory, so it has no limit to the number of rows locked at one time. However, locking a row may cause a disk write; thus, for example, SELECT FOR - UPDATE will modify selected rows to mark them and so + UPDATE will modify selected rows to mark them locked, and so will result in disk writes. @@ -873,9 +892,10 @@ UPDATE accounts SET balance = balance - 100.00 WHERE acctnum = 22222; To ensure the current validity of a row and protect it against - concurrent updates one must use SELECT FOR - UPDATE or an appropriate LOCK TABLE - statement. (SELECT FOR UPDATE locks just the + concurrent updates one must use SELECT FOR UPDATE, + SELECT FOR SHARE, or an appropriate LOCK + TABLE statement. (SELECT FOR UPDATE + or SELECT FOR SHARE locks just the returned rows against concurrent updates, while LOCK TABLE locks the whole table.) This should be taken into account when porting applications to diff --git a/doc/src/sgml/ref/grant.sgml b/doc/src/sgml/ref/grant.sgml index 5e9adaa8051..45f384f4868 100644 --- a/doc/src/sgml/ref/grant.sgml +++ b/doc/src/sgml/ref/grant.sgml @@ -1,5 +1,5 @@ @@ -131,9 +131,10 @@ GRANT { CREATE | ALL [ PRIVILEGES ] } UPDATE - Allows of any column of the - specified table. SELECT ... FOR UPDATE - also requires this privilege (besides the + Allows of any + column of the specified table. SELECT ... FOR UPDATE + and SELECT ... FOR SHARE + also require this privilege (besides the SELECT privilege). For sequences, this privilege allows the use of the nextval and setval functions. diff --git a/doc/src/sgml/ref/lock.sgml b/doc/src/sgml/ref/lock.sgml index 3c762ac48b5..9dfa85b1807 100644 --- a/doc/src/sgml/ref/lock.sgml +++ b/doc/src/sgml/ref/lock.sgml @@ -1,5 +1,5 @@ @@ -177,8 +177,8 @@ where lockmode is one of: LOCK TABLE is concerned, differing only in the rules about which modes conflict with which. For information on how to acquire an actual row-level lock, see - and the in the SELECT + and the in the SELECT reference documentation. diff --git a/doc/src/sgml/ref/pg_resetxlog.sgml b/doc/src/sgml/ref/pg_resetxlog.sgml index 6651a0b588c..f5915adacd4 100644 --- a/doc/src/sgml/ref/pg_resetxlog.sgml +++ b/doc/src/sgml/ref/pg_resetxlog.sgml @@ -1,5 +1,5 @@ @@ -22,6 +22,7 @@ PostgreSQL documentation -n -o oid -x xid + -m mxid -l timelineid,fileid,seg datadir @@ -73,34 +74,65 @@ PostgreSQL documentation - The -o, -x, and -l switches allow - the next OID, next transaction ID, and WAL starting address values to + The -o, -x, -m, and -l + switches allow the next OID, next transaction ID, next multi-transaction + ID, and WAL starting address values to be set manually. These are only needed when pg_resetxlog is unable to determine appropriate values - by reading pg_control. A safe value for the - next transaction ID may be determined by looking for the numerically largest - file name in the directory pg_clog under the data directory, - adding one, - and then multiplying by 1048576. Note that the file names are in - hexadecimal. It is usually easiest to specify the switch value in - hexadecimal too. For example, if 0011 is the largest entry - in pg_clog, -x 0x1200000 will work (five trailing - zeroes provide the proper multiplier). - The WAL starting address should be - larger than any file name currently existing in - the directory pg_xlog under the data directory. - These names are also in hexadecimal and have three parts. The first - part is the timeline ID and should usually be kept the same. - Do not choose a value larger than 255 (0xFF) for the third - part; instead increment the second part and reset the third part to 0. - For example, if 00000001000000320000004A is the - largest entry in pg_xlog, -l 0x1,0x32,0x4B will - work; but if the largest entry is - 000000010000003A000000FF, choose -l 0x1,0x3B,0x0 - or more. - There is no comparably easy way to determine a next OID that's beyond - the largest one in the database, but fortunately it is not critical to - get the next-OID setting right. + by reading pg_control. Safe values may be determined as + follows: + + + + + A safe value for the next transaction ID (-x) + may be determined by looking for the numerically largest + file name in the directory pg_clog under the data directory, + adding one, + and then multiplying by 1048576. Note that the file names are in + hexadecimal. It is usually easiest to specify the switch value in + hexadecimal too. For example, if 0011 is the largest entry + in pg_clog, -x 0x1200000 will work (five + trailing zeroes provide the proper multiplier). + + + + + + A safe value for the next multi-transaction ID (-m) + may be determined by looking for the numerically largest + file name in the directory pg_multixact/offsets under the + data directory, adding one, and then multiplying by 65536. As above, + the file names are in hexadecimal, so the easiest way to do this is to + specify the switch value in hexadecimal and add four zeroes. + + + + + + The WAL starting address (-l) should be + larger than any file name currently existing in + the directory pg_xlog under the data directory. + These names are also in hexadecimal and have three parts. The first + part is the timeline ID and should usually be kept the same. + Do not choose a value larger than 255 (0xFF) for the third + part; instead increment the second part and reset the third part to 0. + For example, if 00000001000000320000004A is the + largest entry in pg_xlog, -l 0x1,0x32,0x4B will + work; but if the largest entry is + 000000010000003A000000FF, choose -l 0x1,0x3B,0x0 + or more. + + + + + + There is no comparably easy way to determine a next OID that's beyond + the largest one in the database, but fortunately it is not critical to + get the next-OID setting right. + + + diff --git a/doc/src/sgml/ref/select.sgml b/doc/src/sgml/ref/select.sgml index 78e591acd72..9b8b90bb167 100644 --- a/doc/src/sgml/ref/select.sgml +++ b/doc/src/sgml/ref/select.sgml @@ -1,5 +1,5 @@ @@ -30,7 +30,7 @@ SELECT [ ALL | DISTINCT [ ON ( expressionexpression [ ASC | DESC | USING operator ] [, ...] ] [ LIMIT { count | ALL } ] [ OFFSET start ] - [ FOR UPDATE [ OF table_name [, ...] ] ] + [ FOR { UPDATE | SHARE } [ OF table_name [, ...] ] ] where from_item can be one of: @@ -142,10 +142,11 @@ where from_item can be one of: - The FOR UPDATE clause causes the - SELECT statement to lock the selected rows - against concurrent updates. (See below.) + If the FOR UPDATE or FOR SHARE + clause is specified, the + SELECT statement locks the selected rows + against concurrent updates. (See below.) @@ -153,7 +154,8 @@ where from_item can be one of: You must have SELECT privilege on a table to - read its values. The use of FOR UPDATE requires + read its values. The use of FOR UPDATE or + FOR SHARE requires UPDATE privilege as well. @@ -503,7 +505,8 @@ HAVING condition select_statement is any SELECT statement without an ORDER - BY, LIMIT, or FOR UPDATE clause. + BY, LIMIT, FOR UPDATE, or + FOR SHARE clause. (ORDER BY and LIMIT can be attached to a subexpression if it is enclosed in parentheses. Without parentheses, these clauses will be taken to apply to the result of @@ -537,8 +540,9 @@ HAVING condition - Currently, FOR UPDATE may not be specified either for - a UNION result or for any input of a UNION. + Currently, FOR UPDATE and FOR SHARE may not be + specified either for a UNION result or for any input of a + UNION. @@ -552,7 +556,8 @@ HAVING condition select_statement is any SELECT statement without an ORDER - BY, LIMIT, or FOR UPDATE clause. + BY, LIMIT, FOR UPDATE, or + FOR SHARE clause. @@ -581,8 +586,9 @@ HAVING condition - Currently, FOR UPDATE may not be specified either for - an INTERSECT result or for any input of an INTERSECT. + Currently, FOR UPDATE and FOR SHARE may not be + specified either for an INTERSECT result or for any input of + an INTERSECT. @@ -596,7 +602,8 @@ HAVING condition select_statement is any SELECT statement without an ORDER - BY, LIMIT, or FOR UPDATE clause. + BY, LIMIT, FOR UPDATE, or + FOR SHARE clause. @@ -621,8 +628,9 @@ HAVING condition - Currently, FOR UPDATE may not be specified either for - an EXCEPT result or for any input of an EXCEPT. + Currently, FOR UPDATE and FOR SHARE may not be + specified either for an EXCEPT result or for any input of + an EXCEPT. @@ -789,8 +797,8 @@ OFFSET start - - <literal>FOR UPDATE</literal> Clause + + <literal>FOR UPDATE</literal>/<literal>FOR SHARE</literal> Clause The FOR UPDATE clause has this form: @@ -799,6 +807,13 @@ FOR UPDATE [ OF table_name [, ...] + + The closely related FOR SHARE clause has this form: + +FOR SHARE [ OF table_name [, ...] ] + + + FOR UPDATE causes the rows retrieved by the SELECT statement to be locked as though for @@ -817,26 +832,44 @@ FOR UPDATE [ OF table_name [, ...] - If specific tables are named in FOR UPDATE, + FOR SHARE behaves similarly, except that it + acquires a shared rather than exclusive lock on each retrieved + row. A shared lock blocks other transactions from performing + UPDATE, DELETE, or SELECT + FOR UPDATE on these rows, but it does not prevent them + from performing SELECT FOR SHARE. + + + + It is currently not allowed for a single SELECT + statement to include both FOR UPDATE and + FOR SHARE. + + + + If specific tables are named in FOR UPDATE + or FOR SHARE, then only rows coming from those tables are locked; any other tables used in the SELECT are simply read as usual. - FOR UPDATE cannot be used in contexts where - returned rows can't be clearly identified with individual table - rows; for example it can't be used with aggregation. + FOR UPDATE and FOR SHARE cannot be + used in contexts where returned rows can't be clearly identified with + individual table rows; for example they can't be used with aggregation. It is possible for a SELECT command using both - LIMIT and FOR UPDATE + LIMIT and FOR UPDATE/SHARE clauses to return fewer rows than specified by LIMIT. - This is because LIMIT selects a number of rows, - but might then block requesting a FOR UPDATE lock. - Once the SELECT unblocks, the query qualification might not - be met and the row not be returned by SELECT. + This is because LIMIT is applied first. The command + selects the specified number of rows, + but might then block trying to obtain lock on one or more of them. + Once the SELECT unblocks, the row might have been deleted + or updated so that it does not meet the query WHERE condition + anymore, in which case it will not be returned. diff --git a/doc/src/sgml/ref/select_into.sgml b/doc/src/sgml/ref/select_into.sgml index 9198a02e4c4..7e6a4807b7b 100644 --- a/doc/src/sgml/ref/select_into.sgml +++ b/doc/src/sgml/ref/select_into.sgml @@ -1,5 +1,5 @@ @@ -31,7 +31,7 @@ SELECT [ ALL | DISTINCT [ ON ( expressionexpression [ ASC | DESC | USING operator ] [, ...] ] [ LIMIT { count | ALL } ] [ OFFSET start ] - [ FOR UPDATE [ OF tablename [, ...] ] ] + [ FOR { UPDATE | SHARE } [ OF tablename [, ...] ] ] diff --git a/doc/src/sgml/sql.sgml b/doc/src/sgml/sql.sgml index 5ca4e2faca6..04a640929a7 100644 --- a/doc/src/sgml/sql.sgml +++ b/doc/src/sgml/sql.sgml @@ -1,5 +1,5 @@ @@ -866,7 +866,7 @@ SELECT [ ALL | DISTINCT [ ON ( expressionexpression [ ASC | DESC | USING operator ] [, ...] ] [ LIMIT { count | ALL } ] [ OFFSET start ] - [ FOR UPDATE [ OF class_name [, ...] ] ] + [ FOR { UPDATE | SHARE } [ OF class_name [, ...] ] ] diff --git a/doc/src/sgml/storage.sgml b/doc/src/sgml/storage.sgml index 31bf3c365dc..1076020f99a 100644 --- a/doc/src/sgml/storage.sgml +++ b/doc/src/sgml/storage.sgml @@ -1,5 +1,5 @@ @@ -74,6 +74,12 @@ Item Subdirectory containing transaction commit status data + + pg_multixact + Subdirectory containing multi-transaction status data + (used for shared row locks) + + pg_subtrans Subdirectory containing subtransaction status data -- cgit v1.2.3