LOCK
Function
LOCK TABLE obtains a table-level lock.
GaussDB always tries to select the lock mode with minimum constraints when automatically requesting a lock for a statement referenced by a table. Use LOCK if users need a more strict lock mode. For example, suppose an application runs a transaction at the Read Committed isolation level and needs to ensure that data in a table remains stable in the duration of the transaction. To achieve this, you could obtain SHARE lock mode over the table before the query. This will prevent concurrent data changes and ensure subsequent reads of the table see a stable view of committed data. It is because the SHARE lock mode conflicts with the ROW EXCLUSIVE lock acquired by writers, and your LOCK TABLE name IN SHARE MODE statement will wait until any concurrent holders of ROW EXCLUSIVE mode locks commit or roll back. Therefore, once you obtain the lock, there are no uncommitted writes outstanding; furthermore none can begin until you release the lock.
The kernel can automatically cancel services when the scale-out redistribution tool waits for a lock.
Precautions
- LOCK TABLE is useless outside a transaction block: the lock would remain held only to the completion of the statement. If LOCK TABLE is out of any transaction block, an error is reported.
- If no lock mode is specified, then ACCESS EXCLUSIVE, the most restrictive mode, is used.
- LOCK TABLE ... IN ACCESS SHARE MODE requires the SELECT permission on the target table. All other forms of LOCK require table-level UPDATE and/or the DELETE permission.
- There is no UNLOCK TABLE statement. Locks are always released at transaction end.
- LOCK TABLE only deals with table-level locks, and so the mode names involving ROW are all misnomers. These mode names should generally be read as indicating the intention of the user to acquire row-level locks within the locked table. Also, ROW EXCLUSIVE mode is a shareable table lock. Note that all lock modes have the same semantics as long as LOCK TABLE is involved. The only difference lies in whether locks conflict with each other. For details about the rules, see Table 1.
- If the xc_maintenance_mode parameter is not enabled, an error is reported when an ACCESS EXCLUSIVE lock is applied for a system catalog.
- Only the redistribution tool can use the automatic CANCEL service interface.
Syntax
LOCK [ TABLE ] {[ ONLY ] name [, ...]| {name [ * ]} [, ...]} [ IN {ACCESS SHARE | ROW SHARE | ROW EXCLUSIVE | SHARE UPDATE EXCLUSIVE | SHARE | SHARE ROW EXCLUSIVE | EXCLUSIVE | ACCESS EXCLUSIVE} MODE ] [ NOWAIT ][CANCELABLE];
Parameter Description
Requested Lock Mode/Current Lock Mode |
ACCESS SHARE |
ROW SHARE |
ROW EXCLUSIVE |
SHARE UPDATE EXCLUSIVE |
SHARE |
SHARE ROW EXCLUSIVE |
EXCLUSIVE |
ACCESS EXCLUSIVE |
---|---|---|---|---|---|---|---|---|
ACCESS SHARE |
- |
- |
- |
- |
- |
- |
- |
X |
ROW SHARE |
- |
- |
- |
- |
- |
- |
X |
X |
ROW EXCLUSIVE |
- |
- |
- |
- |
X |
X |
X |
X |
SHARE UPDATE EXCLUSIVE |
- |
- |
- |
X |
X |
X |
X |
X |
SHARE |
- |
- |
X |
X |
- |
X |
X |
X |
SHARE ROW EXCLUSIVE |
- |
- |
X |
X |
X |
X |
X |
X |
EXCLUSIVE |
- |
X |
X |
X |
X |
X |
X |
X |
ACCESS EXCLUSIVE |
X |
X |
X |
X |
X |
X |
X |
X |
LOCK parameters are as follows:
- name
Specifies the name (optionally schema-qualified) of an existing table to lock.
Tables are locked one-by-one in the order specified in the LOCK TABLE statement.
Value range: an existing table name
You can use database links to perform operations on remote tables. For details, see DATABASE LINK.
- ONLY
If ONLY is specified, only that table is locked. If ONLY is not specified, the table and all its sub-tables are locked.
- ACCESS SHARE
Allows only read operations on a table. In general, any SQL statements that only read a table and do not modify it will acquire this lock mode. The SELECT statement acquires a lock of this mode on referenced tables.
- ROW SHARE
Allows concurrent read of a table but does not allow any other operations on the table.
SELECT FOR UPDATE and SELECT FOR SHARE automatically acquire the ROW SHARE lock on the target table and add the ACCESS SHARE lock to other referenced tables except FOR SHARE and FOR UPDATE.
For a partitioned table, SELECT FOR SHARE obtains the ROW EXCLUSIVE lock of the partition object on the DN for concurrency control.
- ROW EXCLUSIVE
Allows concurrent read of a table but does not allow modification of data in the table like ROW SHARE. UPDATE, DELETE, and INSERT automatically acquire the ROW SHARE lock on the target table and add the ACCESS SHARE lock to other referenced tables. Generally, all statements that modify table data acquire the ROW EXCLUSIVE lock for tables.
- SHARE UPDATE EXCLUSIVE
Protects a table against concurrent schema changes and VACUUM runs.
The VACUUM (without FULL), ANALYZE, and CREATE INDEX CONCURRENTLY statements automatically request this lock.
- SHARE
Allows concurrent queries of a table but does not allow modification of the table.
The CREATE INDEX (without CONCURRENTLY) statement automatically requests this lock.
- SHARE ROW EXCLUSIVE
Protects a table against concurrent data changes, and is self-exclusive so that only one session can hold it at a time.
No SQL statements automatically acquire this lock mode.
- EXCLUSIVE
Allows concurrent queries of the target table but does not allow any other operations.
This mode allows only concurrent ACCESS SHARE locks; that is, only reads from the table can proceed in parallel with a transaction holding this lock mode.
No SQL statements automatically acquire this lock mode on user tables. However, it will be acquired on some system catalogs in case of some operations.
- ACCESS EXCLUSIVE
Guarantees that the holder is the only transaction accessing the table in any way.
Acquired by the ALTER TABLE, DROP TABLE, TRUNCATE, REINDEX, CLUSTER, and VACUUM FULL statements.
This is also the default lock mode for LOCK TABLE statements that do not specify a mode explicitly.
- NOWAIT
Specifies that LOCK TABLE does not wait for any conflicting locks to be released. If the lock cannot be obtained immediately, the command exits and an error message is displayed.
If NOWAIT is not specified, LOCK TABLE obtains a table-level lock, waiting if necessary for any conflicting locks to be released.
- CANCELABLE
Allows the waiting thread to send CANCEL signals to the holding threads and waiting threads.
Only the redistribution tool can use this parameter. An error message is displayed when the parameter is used by users.
Examples
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 |
-- Create a schema. gaussdb=# CREATE SCHEMA tpcds; -- Create the tpcds.reason table. gaussdb=# CREATE TABLE tpcds.reason( r_reason_sk INTEGER NOT NULL, r_reason_id CHAR(16) NOT NULL, r_reason_desc INTEGER ); -- Insert multiple records into the table. gaussdb=# INSERT INTO tpcds.reason VALUES (1, 'AAAAAAAABAAAAAAA', '18'),(5, 'AAAAAAAACAAAAAAA', '362'),(7, 'AAAAAAAADAAAAAAA', '585'); -- Obtain a SHARE ROW EXCLUSIVE lock on a primary key table when going to perform a delete operation. gaussdb=# CREATE TABLE tpcds.reason_t1 AS TABLE tpcds.reason; gaussdb=# START TRANSACTION; gaussdb=# LOCK TABLE tpcds.reason_t1 IN SHARE ROW EXCLUSIVE MODE; gaussdb=# DELETE FROM tpcds.reason_t1 WHERE r_reason_desc IN(SELECT r_reason_desc FROM tpcds.reason_t1 WHERE r_reason_sk < 6 ); gaussdb=# DELETE FROM tpcds.reason_t1 WHERE r_reason_sk = 7; gaussdb=# COMMIT; -- Delete the tpcds.reason_t1 table. gaussdb=# DROP TABLE tpcds.reason_t1; -- Delete the table. gaussdb=# DROP TABLE tpcds.reason; -- Delete a schema. gaussdb=# DROP SCHEMA tpcds CASCADE; |
Feedback
Was this page helpful?
Provide feedbackThank you very much for your feedback. We will continue working to improve the documentation.See the reply and handling status in My Cloud VOC.
For any further questions, feel free to contact us through the chatbot.
Chatbot