LOCK -- Explicitly lock a table inside a transaction
LOCK [ TABLE ] name
LOCK [ TABLE ] name IN [ ROW | ACCESS ] { SHARE | EXCLUSIVE } MODE
LOCK [ TABLE ] name IN SHARE ROW EXCLUSIVE MODE
This is the least restrictive lock mode. It conflicts only with ACCESS EXCLUSIVE mode. It is used to protect a table from being modified by concurrent ALTER TABLE, DROP TABLE and VACUUM commands.
Conflicts with EXCLUSIVE and ACCESS EXCLUSIVE lock modes.
Conflicts with SHARE, SHARE ROW EXCLUSIVE, EXCLUSIVE and ACCESS EXCLUSIVE modes.
Conflicts with ROW EXCLUSIVE, SHARE ROW EXCLUSIVE, EXCLUSIVE and ACCESS EXCLUSIVE modes. This mode protects a table against concurrent updates.
Conflicts with ROW EXCLUSIVE, SHARE, SHARE ROW EXCLUSIVE, EXCLUSIVE and ACCESS EXCLUSIVE modes.
Conflicts with ROW SHARE, ROW EXCLUSIVE, SHARE, SHARE ROW EXCLUSIVE, EXCLUSIVE and ACCESS EXCLUSIVE modes.
Note: This lock mode is also acquired by an unqualified LOCK TABLE (i.e., the command without an explicit lock mode option).
LOCK TABLE controls concurrent access to a table for the duration of a transaction. Postgres always uses the least restrictive lock mode whenever possible. LOCK TABLE provides for cases when you might need more restrictive locking.
RDBMS locking uses the following terminology:
For example, an application runs a transaction at READ COMMITTED isolation level and needs to ensure the existence of data in a table for the duration of the transaction. To achieve this you could use SHARE lock mode over the table before querying. This will protect data from concurrent changes and provide any further read operations over the table with data in their actual current state, because SHARE lock mode conflicts with any ROW EXCLUSIVE one acquired by writers, and your LOCK TABLE name IN SHARE MODE statement will wait until any concurrent write operations commit or rollback. Note: To read data in their real current state when running a transaction at the SERIALIZABLE isolation level you have to execute a LOCK TABLE statement before executing any DML statement, when the transaction defines what concurrent changes will be visible to itself.
In addition to the requirements above, if a transaction is going to change data in a table, then SHARE ROW EXCLUSIVE lock mode should be acquired to prevent deadlock conditions when two concurrent transactions attempt to lock the table in SHARE mode and then try to change data in this table, both (implicitly) acquiring ROW EXCLUSIVE lock mode that conflicts with a concurrent SHARE lock.
To continue with the deadlock (when two transaction wait for one another) issue raised above, you should follow two general rules to prevent deadlock conditions:
For example, if one application updates row R1 and than updates row R2 (in the same transaction) then the second application shouldn't update row R2 if it's going to update row R1 later (in a single transaction). Instead, it should update rows R1 and R2 in the same order as the first application.
An example for this rule was given previously when discussing the use of SHARE ROW EXCLUSIVE mode rather than SHARE mode.
LOCK is a Postgres language extension.
Except for ACCESS SHARE/EXCLUSIVE lock modes, all other Postgres lock modes and the LOCK TABLE syntax are compatible with those present in Oracle.
LOCK works only inside transactions.
Illustrate a SHARE lock on a primary key table when going to perform inserts into a foreign key table:
BEGIN WORK;
LOCK TABLE films IN SHARE MODE;
SELECT id
FROM films
WHERE name = 'Star Wars: Episode I - The Phantom Menace';
-- Do ROLLBACK if record was not returned
INSERT INTO films_user_comments
VALUES (_id_, 'GREAT! I was waiting for it for so long!');
COMMIT WORK;
Take a SHARE ROW EXCLUSIVE lock on a primary key table when going
to perform a delete operation:
BEGIN WORK; LOCK TABLE films IN SHARE ROW EXCLUSIVE MODE;
DELETE FROM films_user_comments
WHERE id IN (SELECT id
FROM films
WHERE rating < 5);
DELETE FROM films
WHERE rating < 5;
COMMIT WORK;
There is no LOCK TABLE in SQL92, which instead uses SET TRANSACTION to specify concurrency levels on transactions. We support that too; see SET for details.