Locks a table.
LOCK [TABLE] [ONLY] name [ * ] [, ...] [IN <lockmode> MODE] [NOWAIT] [MASTER ONLY]
where lockmode is one of:
ACCESS SHARE | ROW SHARE | ROW EXCLUSIVE | SHARE UPDATE EXCLUSIVE
| SHARE | SHARE ROW EXCLUSIVE | EXCLUSIVE | ACCESS EXCLUSIVE
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, Greenplum Database 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 roll 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.
The name (optionally schema-qualified) of an existing table to lock. If ONLY
is specified, only that table is locked. If ONLY
is not specified, the table and all its descendant tables (if any) are locked. Optionally, *
can be specified after the table name to explicitly indicate that descendant tables are included.
LOCK TABLE
command.
The lock mode specifies which locks this lock conflicts with. If no lock mode is specified, then ACCESS EXCLUSIVE
, the most restrictive mode, is used. Lock modes are as follows:
ACCESS EXCLUSIVE
lock mode only. The SELECT
command acquires a lock of this mode on referenced tables. In general, any query that only reads a table and does not modify it will acquire this lock mode.EXCLUSIVE
and ACCESS EXCLUSIVE
lock modes. The SELECT FOR SHARE
command automatically acquires a lock of this mode on the target table(s) (in addition to ACCESS SHARE
locks on any other tables that are referenced but not selected FOR SHARE
).SHARE
, SHARE ROW EXCLUSIVE
, EXCLUSIVE
, and ACCESS EXCLUSIVE
lock modes. The commands INSERT
and COPY
automatically acquire this lock mode on the target table (in addition to ACCESS SHARE
locks on any other referenced tables) See Note.SHARE UPDATE EXCLUSIVE
, SHARE
, SHARE ROW EXCLUSIVE
, EXCLUSIVE
, and ACCESS EXCLUSIVE
lock modes. This mode protects a table against concurrent schema changes and VACUUM
runs. Acquired by VACUUM
(without FULL
) on heap tables and ANALYZE
.ROW EXCLUSIVE
, SHARE UPDATE EXCLUSIVE
, SHARE ROW EXCLUSIVE, EXCLUSIVE
, and ACCESS EXCLUSIVE
lock modes. This mode protects a table against concurrent data changes. Acquired automatically by CREATE INDEX
.ROW EXCLUSIVE
, SHARE UPDATE EXCLUSIVE
, SHARE
, SHARE ROW EXCLUSIVE
, EXCLUSIVE
, and ACCESS EXCLUSIVE
lock modes. This lock mode is not automatically acquired by any Greenplum Database command.ROW SHARE
, ROW EXCLUSIVE
, SHARE UPDATE EXCLUSIVE
, SHARE
, SHARE ROW EXCLUSIVE
, EXCLUSIVE
, and ACCESS EXCLUSIVE
lock modes. This mode allows only concurrent ACCESS SHARE
locks, i.e., only reads from the table can proceed in parallel with a transaction holding this lock mode. This lock mode is automatically acquired for UPDATE
, SELECT FOR UPDATE
, and DELETE
in Greenplum Database (which is more restrictive locking than in regular PostgreSQL). See Note.ACCESS SHARE
, ROW SHARE
, ROW EXCLUSIVE
, SHARE UPDATE EXCLUSIVE
, SHARE
, SHARE``ROW EXCLUSIVE
, EXCLUSIVE
, and ACCESS EXCLUSIVE
). This mode guarantees that the holder is the only transaction accessing the table in any way. Acquired automatically by the ALTER TABLE
, DROP TABLE
, TRUNCATE
, REINDEX
, CLUSTER
, and VACUUM FULL
commands. This is the default lock mode for LOCK TABLE
statements that do not specify a mode explicitly. This lock is also briefly acquired by VACUUM
(without FULL
) on append-optimized tables during processing.NoteBy default Greenplum Database acquires the more restrictive
EXCLUSIVE
lock (rather thanROW EXCLUSIVE
in PostgreSQL) forUPDATE
,DELETE
, andSELECT...FOR UPDATE
operations on heap tables. When the Global Deadlock Detector is enabled the lock mode forUPDATE
andDELETE
operations on heap tables isROW EXCLUSIVE
. See Global Deadlock Detector. Greenplum always holds a table-level lock withSELECT...FOR UPDATE
statements.
LOCK TABLE
should not wait for any conflicting locks to be released: if the specified lock(s) cannot be acquired immediately without waiting, the transaction is cancelled.
Specifies that when a LOCK TABLE
command is issued, Greenplum Database will lock tables on the master only, rather than on the master and all of the segments. This is particularly useful for metadata-only operations.
NoteThis option is only supported in
ACCESS SHARE MODE
.
LOCK TABLE ... IN ACCESS SHARE MODE
requires SELECT
privileges on the target table. All other forms of LOCK
require table-level UPDATE
, DELETE
, or TRUNCATE
privileges.
LOCK TABLE
is useless outside of a transaction block: the lock would be held only to the completion of the LOCK
statement. Therefore, Greenplum Database reports an error if LOCK
is used outside of a transaction block. Use BEGIN
and END
to define a transaction block.
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. Keep in mind that all the lock modes have identical semantics so far as LOCK TABLE
is concerned, differing only in the rules about which modes conflict with which. For information on how to acquire an actual row-level lock, see the FOR UPDATE/FOR SHARE
clause in the SELECT reference documentation.
Obtain a SHARE
lock on the films
table when going to perform inserts into the films_user_comments
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 table when performing 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 the SQL standard, which instead uses SET TRANSACTION
to specify concurrency levels on transactions. Greenplum Database supports that too.
Except for ACCESS SHARE
, ACCESS EXCLUSIVE
, and SHARE UPDATE EXCLUSIVE
lock modes, the Greenplum Database lock modes and the LOCK TABLE
syntax are compatible with those present in Oracle.
BEGIN, SET TRANSACTION, SELECT
Parent topic: SQL Commands