mirror of
https://github.com/postgres/postgres.git
synced 2025-07-30 11:03:19 +03:00
Reduce lock levels of some ALTER TABLE cmds
VALIDATE CONSTRAINT CLUSTER ON SET WITHOUT CLUSTER ALTER COLUMN SET STATISTICS ALTER COLUMN SET () ALTER COLUMN RESET () All other sub-commands use AccessExclusiveLock Simon Riggs and Noah Misch Reviews by Robert Haas and Andres Freund
This commit is contained in:
@ -865,7 +865,9 @@ ERROR: could not serialize access due to read/write dependencies among transact
|
||||
<para>
|
||||
Acquired by <command>VACUUM</command> (without <option>FULL</option>),
|
||||
<command>ANALYZE</>, <command>CREATE INDEX CONCURRENTLY</>, and
|
||||
some forms of <command>ALTER TABLE</command>.
|
||||
<command>ALTER TABLE VALIDATE</command> and other
|
||||
<command>ALTER TABLE</command> variants (for full details see
|
||||
<xref linkend="SQL-ALTERTABLE">).
|
||||
</para>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
@ -951,10 +953,11 @@ ERROR: could not serialize access due to read/write dependencies among transact
|
||||
</para>
|
||||
|
||||
<para>
|
||||
Acquired by the <command>ALTER TABLE</>, <command>DROP TABLE</>,
|
||||
Acquired by the <command>DROP TABLE</>,
|
||||
<command>TRUNCATE</command>, <command>REINDEX</command>,
|
||||
<command>CLUSTER</command>, and <command>VACUUM FULL</command>
|
||||
commands.
|
||||
commands. Many forms of <command>ALTER TABLE</> also acquire
|
||||
a lock at this level (see <xref linkend="SQL-ALTERTABLE">).
|
||||
This is also the default lock mode for <command>LOCK TABLE</command>
|
||||
statements that do not specify a mode explicitly.
|
||||
</para>
|
||||
|
@ -84,7 +84,10 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="PARAMETER">name</replaceable>
|
||||
|
||||
<para>
|
||||
<command>ALTER TABLE</command> changes the definition of an existing table.
|
||||
There are several subforms:
|
||||
There are several subforms described below. Note that the lock level required
|
||||
may differ for each subform. An <literal>ACCESS EXCLUSIVE</literal> lock is held
|
||||
unless explicitly noted. When multiple subcommands are listed, the lock
|
||||
held will be the strictest one required from any subcommand.
|
||||
|
||||
<variablelist>
|
||||
<varlistentry>
|
||||
@ -181,6 +184,9 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="PARAMETER">name</replaceable>
|
||||
<productname>PostgreSQL</productname> query planner, refer to
|
||||
<xref linkend="planner-stats">.
|
||||
</para>
|
||||
<para>
|
||||
SET STATISTICS acquires a <literal>SHARE UPDATE EXCLUSIVE</literal> lock.
|
||||
</para>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
@ -213,6 +219,10 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="PARAMETER">name</replaceable>
|
||||
of statistics by the <productname>PostgreSQL</productname> query
|
||||
planner, refer to <xref linkend="planner-stats">.
|
||||
</para>
|
||||
<para>
|
||||
Changing per-attribute options acquires a
|
||||
<literal>SHARE UPDATE EXCLUSIVE</literal> lock.
|
||||
</para>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
@ -338,11 +348,17 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="PARAMETER">name</replaceable>
|
||||
Nothing happens if the constraint is already marked valid.
|
||||
</para>
|
||||
<para>
|
||||
Validation can be a long process on larger tables and currently requires
|
||||
an <literal>ACCESS EXCLUSIVE</literal> lock. The value of separating
|
||||
Validation can be a long process on larger tables. The value of separating
|
||||
validation from initial creation is that you can defer validation to less
|
||||
busy times, or can be used to give additional time to correct pre-existing
|
||||
errors while preventing new errors.
|
||||
errors while preventing new errors. Note also that validation on its own
|
||||
does not prevent normal write commands against the table while it runs.
|
||||
</para>
|
||||
<para>
|
||||
Validation acquires only a <literal>SHARE UPDATE EXCLUSIVE</literal> lock
|
||||
on the table being altered. If the constraint is a foreign key then
|
||||
a <literal>ROW SHARE</literal> lock is also required on
|
||||
the table referenced by the constraint.
|
||||
</para>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
@ -408,6 +424,9 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="PARAMETER">name</replaceable>
|
||||
<xref linkend="SQL-CLUSTER">
|
||||
operations. It does not actually re-cluster the table.
|
||||
</para>
|
||||
<para>
|
||||
Changing cluster options acquires a <literal>SHARE UPDATE EXCLUSIVE</literal> lock.
|
||||
</para>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
@ -420,6 +439,9 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="PARAMETER">name</replaceable>
|
||||
index specification from the table. This affects
|
||||
future cluster operations that don't specify an index.
|
||||
</para>
|
||||
<para>
|
||||
Changing cluster options acquires a <literal>SHARE UPDATE EXCLUSIVE</literal> lock.
|
||||
</para>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
@ -1078,6 +1100,14 @@ ALTER TABLE distributors ADD CONSTRAINT distfk FOREIGN KEY (address) REFERENCES
|
||||
</programlisting>
|
||||
</para>
|
||||
|
||||
<para>
|
||||
To add a foreign key constraint to a table with the least impact on other work:
|
||||
<programlisting>
|
||||
ALTER TABLE distributors ADD CONSTRAINT distfk FOREIGN KEY (address) REFERENCES addresses (address) NOT VALID;
|
||||
ALTER TABLE distributors VALIDATE CONSTRAINT distfk;
|
||||
</programlisting>
|
||||
</para>
|
||||
|
||||
<para>
|
||||
To add a (multicolumn) unique constraint to a table:
|
||||
<programlisting>
|
||||
|
Reference in New Issue
Block a user