1
0
mirror of https://github.com/postgres/postgres.git synced 2025-06-20 15:22:23 +03:00

Enable CHECK constraints to be declared NOT VALID

This means that they can initially be added to a large existing table
without checking its initial contents, but new tuples must comply to
them; a separate pass invoked by ALTER TABLE / VALIDATE can verify
existing data and ensure it complies with the constraint, at which point
it is marked validated and becomes a normal part of the table ecosystem.

An non-validated CHECK constraint is ignored in the planner for
constraint_exclusion purposes; when validated, cached plans are
recomputed so that partitioning starts working right away.

This patch also enables domains to have unvalidated CHECK constraints
attached to them as well by way of ALTER DOMAIN / ADD CONSTRAINT / NOT
VALID, which can later be validated with ALTER DOMAIN / VALIDATE
CONSTRAINT.

Thanks to Thom Brown, Dean Rasheed and Jaime Casanova for the various
reviews, and Robert Hass for documentation wording improvement
suggestions.

This patch was sponsored by Enova Financial.
This commit is contained in:
Alvaro Herrera
2011-06-01 18:43:50 -04:00
parent b36927fbe9
commit 897795240c
19 changed files with 581 additions and 70 deletions

View File

@ -1899,7 +1899,7 @@
<entry><type>bool</type></entry>
<entry></entry>
<entry>Has the constraint been validated?
Currently, can only be false for foreign keys</entry>
Currently, can only be false for foreign keys and CHECK constraints</entry>
</row>
<row>

View File

@ -28,9 +28,11 @@ ALTER DOMAIN <replaceable class="PARAMETER">name</replaceable>
ALTER DOMAIN <replaceable class="PARAMETER">name</replaceable>
{ SET | DROP } NOT NULL
ALTER DOMAIN <replaceable class="PARAMETER">name</replaceable>
ADD <replaceable class="PARAMETER">domain_constraint</replaceable>
ADD <replaceable class="PARAMETER">domain_constraint</replaceable> [ NOT VALID ]
ALTER DOMAIN <replaceable class="PARAMETER">name</replaceable>
DROP CONSTRAINT <replaceable class="PARAMETER">constraint_name</replaceable> [ RESTRICT | CASCADE ]
ALTER DOMAIN <replaceable class="PARAMETER">name</replaceable>
VALIDATE CONSTRAINT <replaceable class="PARAMETER">constraint_name</replaceable>
ALTER DOMAIN <replaceable class="PARAMETER">name</replaceable>
OWNER TO <replaceable class="PARAMETER">new_owner</replaceable>
ALTER DOMAIN <replaceable class="PARAMETER">name</replaceable>
@ -70,13 +72,19 @@ ALTER DOMAIN <replaceable class="PARAMETER">name</replaceable>
</varlistentry>
<varlistentry>
<term>ADD <replaceable class="PARAMETER">domain_constraint</replaceable></term>
<term>ADD <replaceable class="PARAMETER">domain_constraint</replaceable> [ NOT VALID ]</term>
<listitem>
<para>
This form adds a new constraint to a domain using the same syntax as
<xref linkend="SQL-CREATEDOMAIN">.
This will only succeed if all columns using the domain satisfy the
new constraint.
When a new constraint is added to a domain, all columns using that
domain will be checked against the newly added constraint. These
checks can be suppressed by adding the new constraint using the
<literal>NOT VALID</literal> option; the constraint can later be made
valid using <command>ALTER DOMAIN ... VALIDATE CONSTRAINT</command>.
Newly inserted or updated rows are always checked against all
constraints, even those marked <literal>NOT VALID</literal>.
<literal>NOT VALID</> is only accepted for <literal>CHECK</> constraints.
</para>
</listitem>
</varlistentry>
@ -90,6 +98,17 @@ ALTER DOMAIN <replaceable class="PARAMETER">name</replaceable>
</listitem>
</varlistentry>
<varlistentry>
<term>VALIDATE CONSTRAINT</term>
<listitem>
<para>
This form validates a constraint previously added as
<literal>NOT VALID</>, that is, verify that all data in columns using the
domain satisfy the specified constraint.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>OWNER</term>
<listitem>
@ -155,6 +174,16 @@ ALTER DOMAIN <replaceable class="PARAMETER">name</replaceable>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="PARAMETER">NOT VALID</replaceable></term>
<listitem>
<para>
Do not verify existing column data for constraint validity.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>CASCADE</literal></term>
<listitem>
@ -250,9 +279,11 @@ ALTER DOMAIN zipcode SET SCHEMA customers;
<para>
<command>ALTER DOMAIN</command> conforms to the <acronym>SQL</acronym>
standard,
except for the <literal>OWNER</> and <literal>SET SCHEMA</> variants,
which are <productname>PostgreSQL</productname> extensions.
standard, except for the <literal>OWNER</>, <literal>SET SCHEMA</> and
<literal>VALIDATE CONSTRAINT</> variants, which are
<productname>PostgreSQL</productname> extensions. The <literal>NOT VALID</>
clause of the <literal>ADD CONSTRAINT</> variant is also a
<productname>PostgreSQL</productname> extension.
</para>
</refsect1>

View File

@ -240,12 +240,14 @@ ALTER TABLE <replaceable class="PARAMETER">name</replaceable>
This form adds a new constraint to a table using the same syntax as
<xref linkend="SQL-CREATETABLE">, plus the option <literal>NOT
VALID</literal>, which is currently only allowed for foreign key
constraints.
and CHECK constraints.
If the constraint is marked <literal>NOT VALID</literal>, the
potentially-lengthy initial check to verify that all rows in the table
satisfy the constraint is skipped. The constraint will still be
enforced against subsequent inserts or updates (that is, they'll fail
unless there is a matching row in the referenced table). But the
unless there is a matching row in the referenced table, in the case
of foreign keys; and they'll fail unless the new row matches the
specified check constraints). But the
database will not assume that the constraint holds for all rows in
the table, until it is validated by using the <literal>VALIDATE
CONSTRAINT</literal> option.
@ -308,10 +310,10 @@ ALTER TABLE <replaceable class="PARAMETER">name</replaceable>
<term><literal>VALIDATE CONSTRAINT</literal></term>
<listitem>
<para>
This form validates a foreign key constraint that was previously created
This form validates a foreign key or check constraint that was previously created
as <literal>NOT VALID</literal>, by scanning the table to ensure there
are no unmatched rows. Nothing happens if the constraint is
already marked valid.
are no rows for which the constraint is not satisfied.
Nothing happens if the constraint is already marked valid.
The value of separating validation from initial creation of the
constraint is that validation requires a lesser lock on the table
than constraint creation does.