LOCK
Locks a table.
Synopsis
LOCK [TABLE] [ONLY] name [ * ] [, ...] [IN <lockmode> MODE] [NOWAIT] [COORDINATOR ONLY]
where lockmode is one of:
ACCESS SHARE | ROW SHARE | ROW EXCLUSIVE | SHARE UPDATE EXCLUSIVE
| SHARE | SHARE ROW EXCLUSIVE | EXCLUSIVE | ACCESS EXCLUSIVE
Description
LOCK TABLE
obtains a table-level lock, waiting if necessary for any conflicting locks to be released. If NOWAIT
is specified, LOCK TABLE
does not wait to acquire the desired lock: if it cannot be acquired immediately, the command is stopped and an error is emitted. Once obtained, the lock is held for the remainder of the current transaction. There is no UNLOCK TABLE
command; locks are always released at transaction end.
When acquiring locks automatically for commands that reference tables, Apache Cloudberry always uses the least restrictive lock mode possible. LOCK TABLE
provides for cases when you might need more restrictive locking. 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 for the duration of the transaction. To achieve this you could obtain SHARE
lock mode over the table before querying. This will prevent concurrent data changes and ensure subsequent reads of the table see a stable view of committed data, because 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 rolls back. Thus, once you obtain the lock, there are no uncommitted writes outstanding; furthermore none can begin until you release the lock.
To achieve a similar effect when running a transaction at the REPEATABLE READ
or SERIALIZABLE
isolation level, you have to run the LOCK TABLE
statement before running any SELECT
or data modification statement. A REPEATABLE READ
or SERIALIZABLE
transaction's view of data will be frozen when its first SELECT
or data modification statement begins. A LOCK TABLE
later in the transaction will still prevent concurrent writes — but it won't ensure that what the transaction reads corresponds to the latest committed values.
If a transaction of this sort is going to change the data in the table, then it should use SHARE ROW EXCLUSIVE
lock mode instead of SHARE
mode. This ensures that only one transaction of this type runs at a time. Without this, a deadlock is possible: two transactions might both acquire SHARE
mode, and then be unable to also acquire ROW EXCLUSIVE
mode to actually perform their updates. Note that a transaction's own locks never conflict, so a transaction can acquire ROW EXCLUSIVE
mode when it holds SHARE
mode — but not if anyone else holds SHARE
mode. To avoid deadlocks, make sure all transactions acquire locks on the same objects in the same order, and if multiple lock modes are involved for a single object, then transactions should always acquire the most restrictive mode first.