Name

LOCK Lock a table.

Synopsis

LOCK TABLE <name> [, ...] IN <lockmode> MODE [ NOWAIT ]

Where lockmode is one of:

ROW SHARE | ROW EXCLUSIVE | SHARE | SHARE ROW EXCLUSIVE | EXCLUSIVE

Description

LOCK TABLE obtains a table-level lock, waiting if necessary for any conflicting locks to be released. If you specify NOWAIT, LOCK TABLE doesn't wait to acquire the desired lock. If the lock can't be acquired immediately, the command is aborted and an error occurs. Once obtained, the lock is held for the remainder of the current transaction. There's no UNLOCK TABLE command; locks are always released at transaction end.

When acquiring locks for commands that reference tables, EDB Postgres Advanced Server 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 isolation level read committed and needs to ensure that data in a table remains stable for the rest of the transaction. To achieve this, you can obtain SHARE lock mode over the table before querying. This approach prevents concurrent data changes and ensures subsequent reads of the table see a stable view of committed data. That's because SHARE lock mode conflicts with the ROW EXCLUSIVE lock acquired by writers, and your LOCK TABLE name IN SHARE MODE statement waits until any concurrent holders of ROW EXCLUSIVE mode locks commit or roll back. Thus, once you obtain the lock, there are no uncommitted writes outstanding, and none can begin until you release the lock.

To achieve a similar effect when running a transaction at the isolation level serializable, you have to execute the LOCK TABLE statement before executing any data modification statement. A serializable transaction’s view of data is frozen when its first data modification statement begins. A later LOCK TABLE still prevents concurrent writes, but it won’t ensure that what the transaction reads corresponds to the latest committed values.

If a transaction of this sort changes the data in the table, then use SHARE ROW EXCLUSIVE lock mode instead of SHARE mode.

This approach 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 perform their updates. 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. If multiple lock modes are involved for a single object, then always have transactions acquire the most restrictive mode first.

Parameters

name

The name (optionally schema-qualified) of an existing table to lock.

The command LOCK TABLE a, b; is equivalent to LOCK TABLE a; LOCK TABLE b. The tables are locked one by one in the order specified in the LOCK TABLE command.

lockmode

Specifies the locks this lock conflicts with.

If you don't specify a lock mode, then the server uses the most restrictive mode: ACCESS EXCLUSIVE. ACCESS EXCLUSIVE isn't compatible with Oracle databases. In EDB Postgres Advanced Server, this configuration mode ensures that no other transaction can access the locked table.

NOWAIT

Specifies for LOCK TABLE not to wait for any conflicting locks to be released. If you can't immediately acquire the specified lock without waiting, the transaction is aborted.

Notes

All forms of LOCK require UPDATE or DELETE privileges.

LOCK TABLE is useful only inside a transaction block since the lock is dropped as soon as the transaction ends. A LOCK TABLE command appearing outside any transaction block forms a self-contained transaction, so the lock is dropped as soon as you obtain it.

LOCK TABLE deals only with table-level locks, and so the mode names involving ROW are all misnomers. These mode names are generally read as indicating the intention of the user to acquire row-level locks in the locked table. Also, ROW EXCLUSIVE mode is a sharable table lock. Keep in mind that all the lock modes have identical semantics as far as LOCK TABLE is concerned, differing only in the rules about the modes that conflict with each other.