postgresql/doc/src/sgml/ref/lock.sgml

504 lines
13 KiB
Plaintext

<!--
$Header: /cvsroot/pgsql/doc/src/sgml/ref/lock.sgml,v 1.30 2002/01/18 01:05:43 tgl Exp $
PostgreSQL documentation
-->
<refentry id="SQL-LOCK">
<refmeta>
<refentrytitle id="sql-lock-title">
LOCK
</refentrytitle>
<refmiscinfo>SQL - Language Statements</refmiscinfo>
</refmeta>
<refnamediv>
<refname>
LOCK
</refname>
<refpurpose>
explicitly lock a table
</refpurpose>
</refnamediv>
<refsynopsisdiv>
<refsynopsisdivinfo>
<date>2001-07-09</date>
</refsynopsisdivinfo>
<synopsis>
LOCK [ TABLE ] <replaceable class="PARAMETER">name</replaceable> [, ...]
LOCK [ TABLE ] <replaceable class="PARAMETER">name</replaceable> [, ...] IN <replaceable class="PARAMETER">lockmode</replaceable> MODE
where <replaceable class="PARAMETER">lockmode</replaceable> is one of:
ACCESS SHARE | ROW SHARE | ROW EXCLUSIVE | SHARE UPDATE EXCLUSIVE |
SHARE | SHARE ROW EXCLUSIVE | EXCLUSIVE | ACCESS EXCLUSIVE
</synopsis>
<refsect2 id="R2-SQL-LOCK-1">
<refsect2info>
<date>1999-06-09</date>
</refsect2info>
<title>
Inputs
</title>
<para>
<variablelist>
<varlistentry>
<term><replaceable class="PARAMETER">name</replaceable></term>
<listitem>
<para>
The name of an existing table to lock.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>ACCESS SHARE MODE</term>
<listitem>
<note>
<para>
This lock mode is acquired automatically over tables being queried.
</para>
</note>
<para>
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 <command>ALTER TABLE</command>,
<command>DROP TABLE</command> and <command>VACUUM FULL</command>
commands.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>ROW SHARE MODE</term>
<listitem>
<note>
<para>
Automatically acquired by <command>SELECT ... FOR UPDATE</command>.
</para>
</note>
<para>
Conflicts with EXCLUSIVE and ACCESS EXCLUSIVE lock modes.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>ROW EXCLUSIVE MODE</term>
<listitem>
<note>
<para>
Automatically acquired by <command>UPDATE</command>,
<command>DELETE</command>, and <command>INSERT</command>
statements.
</para>
</note>
<para>
Conflicts with SHARE, SHARE ROW EXCLUSIVE, EXCLUSIVE and
ACCESS EXCLUSIVE modes.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>SHARE UPDATE EXCLUSIVE MODE</term>
<listitem>
<note>
<para>
Automatically acquired by <command>VACUUM</command> (without
<option>FULL</option>).
</para>
</note>
<para>
Conflicts with SHARE UPDATE EXCLUSIVE, SHARE, SHARE ROW EXCLUSIVE,
EXCLUSIVE and
ACCESS EXCLUSIVE modes. This mode protects a table against
concurrent schema changes and VACUUMs.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>SHARE MODE</term>
<listitem>
<note>
<para>
Automatically acquired by <command>CREATE INDEX</command>.
Share-locks the entire table.
</para>
</note>
<para>
Conflicts with ROW EXCLUSIVE, SHARE UPDATE EXCLUSIVE,
SHARE ROW EXCLUSIVE, EXCLUSIVE and
ACCESS EXCLUSIVE modes. This mode protects a table against
concurrent data updates.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>SHARE ROW EXCLUSIVE MODE</term>
<listitem>
<note>
<para>
This is like EXCLUSIVE MODE, but allows ROW SHARE locks
by others.
</para>
</note>
<para>
Conflicts with ROW EXCLUSIVE, SHARE UPDATE EXCLUSIVE, SHARE,
SHARE ROW EXCLUSIVE, EXCLUSIVE and ACCESS EXCLUSIVE modes.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>EXCLUSIVE MODE</term>
<listitem>
<note>
<para>
This mode is yet more restrictive than SHARE ROW EXCLUSIVE.
It blocks all concurrent ROW SHARE/SELECT...FOR UPDATE queries.
</para>
</note>
<para>
Conflicts with ROW SHARE, ROW EXCLUSIVE, SHARE UPDATE EXCLUSIVE,
SHARE, SHARE ROW EXCLUSIVE,
EXCLUSIVE and ACCESS EXCLUSIVE modes.
This mode allows only concurrent ACCESS SHARE, i.e., only reads
from the table can proceed in parallel with a transaction holding
this lock mode.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>ACCESS EXCLUSIVE MODE</term>
<listitem>
<note>
<para>
Automatically acquired by <command>ALTER TABLE</command>,
<command>DROP TABLE</command>, <command>VACUUM FULL</command>
statements.
This is the most restrictive lock mode which
protects a locked table from any concurrent operations.
</para>
</note>
<note>
<para>
This lock mode is also acquired by an unqualified
<command>LOCK TABLE</command> (i.e., the command without an explicit
lock mode option).
</para>
</note>
<para>
Conflicts with all lock modes.
</para>
</listitem>
</varlistentry>
</variablelist>
</para>
</refsect2>
<refsect2 id="R2-SQL-LOCK-2">
<refsect2info>
<date>1998-09-24</date>
</refsect2info>
<title>
Outputs
</title>
<para>
<variablelist>
<varlistentry>
<term><computeroutput>
LOCK TABLE
</computeroutput></term>
<listitem>
<para>
The lock was successfully acquired.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><computeroutput>
ERROR <replaceable class="PARAMETER">name</replaceable>: Table does not exist.
</computeroutput></term>
<listitem>
<para>
Message returned if <replaceable class="PARAMETER">name</replaceable>
does not exist.
</para>
</listitem>
</varlistentry>
</variablelist>
</para>
</refsect2>
</refsynopsisdiv>
<refsect1 id="R1-SQL-LOCK-1">
<refsect1info>
<date>1998-09-24</date>
</refsect1info>
<title>
Description
</title>
<para>
<command>LOCK TABLE</command> controls concurrent access to a table
for the duration of a transaction.
<productname>PostgreSQL</productname> always uses the least restrictive
lock mode whenever possible. <command>LOCK TABLE</command>
provides for cases when you might need more restrictive locking.
</para>
<para>
<acronym>RDBMS</acronym> locking uses the following terminology:
<variablelist>
<varlistentry>
<term>EXCLUSIVE</term>
<listitem>
<para>
An exclusive lock prevents other locks of the same type from being
granted. (Note: ROW EXCLUSIVE mode does not follow this naming
convention perfectly, since it is shared at the level of the table;
it is exclusive only with respect to specific rows that are being
updated.)
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>SHARE</term>
<listitem>
<para>
A shared lock allows others to also hold the same type of lock,
but prevents the corresponding EXCLUSIVE lock from being granted.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>ACCESS</term>
<listitem>
<para>
Locks table schema.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>ROW</term>
<listitem>
<para>
Locks individual rows.
</para>
</listitem>
</varlistentry>
</variablelist>
</para>
<para>
For example, suppose 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 obtain SHARE lock mode over the
table before querying. This will prevent concurrent data changes
and ensure further read operations over the table see data in their
actual current state, because SHARE lock mode conflicts with any ROW
EXCLUSIVE lock acquired by writers, and your
<command>LOCK TABLE <replaceable class="PARAMETER">name</replaceable> IN SHARE MODE</command>
statement will wait until any concurrent write operations commit or
rollback. Thus, once you obtain the lock, there are no uncommitted
writes outstanding.
<note>
<para>
To read data in their actual current state when running a transaction
at the SERIALIZABLE isolation level, you have to execute the LOCK TABLE
statement before executing any DML statement. A serializable
transaction's view of data will be frozen when its first DML statement
begins.
</para>
</note>
</para>
<para>
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.
</para>
<para>
To continue with the deadlock (when two transactions wait for one another)
issue raised above, you should follow two general rules to prevent
deadlock conditions:
</para>
<itemizedlist>
<listitem>
<para>
Transactions have to acquire locks on the same objects in the same order.
</para>
<para>
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.
</para>
</listitem>
<listitem>
<para>
Transactions should acquire two conflicting lock modes only if
one of them is self-conflicting (i.e., may be held by only one
transaction at a time). If multiple lock modes are involved,
then transactions should always acquire the most restrictive mode first.
</para>
<para>
An example for this rule was given previously when discussing the
use of SHARE ROW EXCLUSIVE mode rather than SHARE mode.
</para>
</listitem>
</itemizedlist>
<note>
<para>
<productname>PostgreSQL</productname> does detect deadlocks and will
rollback at least one waiting transaction to resolve the deadlock.
</para>
</note>
<para>
When locking multiple tables, the command LOCK a, b; is equivalent to LOCK
a; LOCK b;. The tables are locked one-by-one in the order specified in the
<command>LOCK</command> command.
</para>
<refsect2 id="R2-SQL-LOCK-3">
<refsect2info>
<date>1999-06-08</date>
</refsect2info>
<title>
Notes
</title>
<para>
<literal>LOCK ... IN ACCESS SHARE MODE</> requires <literal>SELECT</>
privileges on the target table. All other forms of <command>LOCK</>
require <literal>UPDATE</> and/or <literal>DELETE</> privileges.
</para>
<para>
<command>LOCK</command> is useful only inside a transaction block
(<command>BEGIN</>...<command>COMMIT</>), since the lock is dropped
as soon as the transaction ends. A <command>LOCK</> command appearing
outside any transaction block forms a self-contained transaction, so the
lock will be dropped as soon as it is obtained.
</para>
</refsect2>
</refsect1>
<refsect1 id="R1-SQL-LOCK-2">
<title>
Usage
</title>
<para>
Illustrate a SHARE lock on a primary key table when going to perform
inserts into a foreign key table:
<programlisting>
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;
</programlisting>
</para>
<para>
Take a SHARE ROW EXCLUSIVE lock on a primary key table when going to perform
a delete operation:
<programlisting>
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;
</programlisting>
</para>
</refsect1>
<refsect1 id="R1-SQL-LOCK-3">
<title>
Compatibility
</title>
<refsect2 id="R2-SQL-LOCK-4">
<refsect2info>
<date>1998-09-24</date>
</refsect2info>
<title>
SQL92
</title>
<para>
There is no <command>LOCK TABLE</command> in <acronym>SQL92</acronym>,
which instead uses <command>SET TRANSACTION</command> to specify
concurrency levels on transactions. We support that too; see
<xref linkend="SQL-SET-TRANSACTION" endterm="SQL-SET-TRANSACTION-TITLE"> for details.
</para>
<para>
Except for ACCESS SHARE, ACCESS EXCLUSIVE, and SHARE UPDATE EXCLUSIVE lock
modes, the <productname>PostgreSQL</productname> lock modes and the
<command>LOCK TABLE</command> syntax are compatible with those
present in <productname>Oracle</productname>(TM).
</para>
</refsect2>
</refsect1>
</refentry>
<!-- Keep this comment at the end of the file
Local variables:
mode: sgml
sgml-omittag:nil
sgml-shorttag:t
sgml-minimize-attributes:nil
sgml-always-quote-attributes:t
sgml-indent-step:1
sgml-indent-data:t
sgml-parent-document:nil
sgml-default-dtd-file:"../reference.ced"
sgml-exposed-tags:nil
sgml-local-catalogs:"/usr/lib/sgml/catalog"
sgml-local-ecat-files:nil
End:
-->