LOCK
SQL - Language Statements
LOCK
Explicit lock of a table inside a transaction
1998-09-24
LOCK [ TABLE ] table
LOCK [ TABLE ] table IN [ ROW | ACCESS ] { SHARE | EXCLUSIVE } MODE
LOCK [ TABLE ] table IN SHARE ROW EXCLUSIVE MODE
1998-09-01
Inputs
table
The name of an existing table to lock.
SHARE MODE
EXCLUSIVE MODE
ROW SHARE MODE
ROW EXCLUSIVE MODE
ACCESS SHARE MODE
ACCESS EXCLUSIVE MODE
SHARE ROW EXCLUSIVE MODE
1998-09-24
Outputs
ERROR table: Table does not exist.
Message returned if table
does not exist.
1998-09-24
Description
By default, LOCK locks in exclusive mode a table inside
a transaction. Various options allow shared access, or row-level locking
control. The classic use for this is
the case where you want to select some data, then
update it inside a transaction.
If you don't explicit lock a table using LOCK statement, it will be
implicit locked only at the first
UPDATE, INSERT,
or DELETE operation.
If you don't exclusive lock the table before the select, some
other user may also read the selected data, and try and do
their own update, causing a deadlock while you both wait
for the other to release the select-induced shared lock so
you can get an exclusive lock to do the update.
Another example of deadlock is where one user locks one
table, and another user locks a second table. While both
keep their existing locks, the first user tries to lock
the second user's table, and the second user tries to lock
the first user's table. Both users deadlock waiting for
the tables to become available. The only solution to this
is for both users to lock tables in the same order, so
user's lock acquisitions and requests to not form a deadlock.
Postgres does detect deadlocks and will
rollback transactions to resolve the deadlock. Usually, at least one
of the deadlocked transactions will complete successfully.
1998-09-24
Notes
LOCK is a Postgres
language extension.
LOCK works only inside transactions.
Bug
If the locked table is dropped then it will be automatically
unlocked even if a transaction is still in progress.
Usage
--Explicit locking to prevent deadlock:
--
BEGIN WORK;
LOCK films;
SELECT * FROM films;
UPDATE films SET len = INTERVAL '100 minute'
WHERE len = INTERVAL '117 minute';
COMMIT WORK;
Compatibility
1998-09-24
SQL92
There is no LOCK TABLE in SQL92,
which instead uses SET TRANSACTION to specify
concurrency level on transactions. We support that too.