1
0
mirror of https://github.com/postgres/postgres.git synced 2025-07-28 23:42:10 +03:00

Add pg_constraint rows for not-null constraints

We now create contype='n' pg_constraint rows for not-null constraints on
user tables.  Only one such constraint is allowed for a column.

We propagate these constraints to other tables during operations such as
adding inheritance relationships, creating and attaching partitions and
creating tables LIKE other tables.  These related constraints mostly
follow the well-known rules of conislocal and coninhcount that we have
for CHECK constraints, with some adaptations: for example, as opposed to
CHECK constraints, we don't match not-null ones by name when descending
a hierarchy to alter or remove it, instead matching by the name of the
column that they apply to.  This means we don't require the constraint
names to be identical across a hierarchy.

The inheritance status of these constraints can be controlled: now we
can be sure that if a parent table has one, then all children will have
it as well.  They can optionally be marked NO INHERIT, and then children
are free not to have one.  (There's currently no support for altering a
NO INHERIT constraint into inheriting down the hierarchy, but that's a
desirable future feature.)

This also opens the door for having these constraints be marked NOT
VALID, as well as allowing UNIQUE+NOT NULL to be used for functional
dependency determination, as envisioned by commit e49ae8d3bc.  It's
likely possible to allow DEFERRABLE constraints as followup work, as
well.

psql shows these constraints in \d+, though we may want to reconsider if
this turns out to be too noisy.  Earlier versions of this patch hid
constraints that were on the same columns of the primary key, but I'm
not sure that that's very useful.  If clutter is a problem, we might be
better off inventing a new \d++ command and not showing the constraints
in \d+.

For now, we omit these constraints on system catalog columns, because
they're unlikely to achieve anything.

The main difference to the previous attempt at this (b0e96f3119) is
that we now require that such a constraint always exists when a primary
key is in the column; we didn't require this previously which had a
number of unpalatable consequences.  With this requirement, the code is
easier to reason about.  For example:

- We no longer have "throwaway constraints" during pg_dump.  We needed
  those for the case where a table had a PK without a not-null
  underneath, to prevent a slow scan of the data during restore of the
  PK creation, which was particularly problematic for pg_upgrade.

- We no longer have to cope with attnotnull being set spuriously in
  case a primary key is dropped indirectly (e.g., via DROP COLUMN).

Some bits of code in this patch were authored by Jian He.

Author: Álvaro Herrera <alvherre@alvh.no-ip.org>
Author: Bernd Helmle <mailings@oopsware.de>
Reviewed-by: 何建 (jian he) <jian.universality@gmail.com>
Reviewed-by: 王刚 (Tender Wang) <tndrwang@gmail.com>
Reviewed-by: Justin Pryzby <pryzby@telsasoft.com>
Reviewed-by: Peter Eisentraut <peter.eisentraut@enterprisedb.com>
Reviewed-by: Dean Rasheed <dean.a.rasheed@gmail.com>
Discussion: https://postgr.es/m/202408310358.sdhumtyuy2ht@alvherre.pgsql
This commit is contained in:
Álvaro Herrera
2024-11-08 13:28:48 +01:00
parent 075acdd933
commit 14e87ffa5c
57 changed files with 4257 additions and 829 deletions

View File

@ -1271,7 +1271,7 @@
<structfield>attnotnull</structfield> <type>bool</type>
</para>
<para>
This represents a not-null constraint.
This column has a not-null constraint.
</para></entry>
</row>
@ -2502,14 +2502,10 @@ SCRAM-SHA-256$<replaceable>&lt;iteration count&gt;</replaceable>:<replaceable>&l
</indexterm>
<para>
The catalog <structname>pg_constraint</structname> stores check, primary
key, unique, foreign key, and exclusion constraints on tables, as well as
not-null constraints on domains.
The catalog <structname>pg_constraint</structname> stores check, not-null,
primary key, unique, foreign key, and exclusion constraints on tables.
(Column constraints are not treated specially. Every column constraint is
equivalent to some table constraint.)
Not-null constraints on relations are represented in the
<link linkend="catalog-pg-attribute"><structname>pg_attribute</structname></link>
catalog, not here.
</para>
<para>
@ -2571,7 +2567,7 @@ SCRAM-SHA-256$<replaceable>&lt;iteration count&gt;</replaceable>:<replaceable>&l
<para>
<literal>c</literal> = check constraint,
<literal>f</literal> = foreign key constraint,
<literal>n</literal> = not-null constraint (domains only),
<literal>n</literal> = not-null constraint,
<literal>p</literal> = primary key constraint,
<literal>u</literal> = unique constraint,
<literal>t</literal> = constraint trigger,

View File

@ -771,18 +771,39 @@ CREATE TABLE products (
name text <emphasis>NOT NULL</emphasis>,
price numeric
);
</programlisting>
An explicit constraint name can also be specified, for example:
<programlisting>
CREATE TABLE products (
product_no integer NOT NULL,
name text <emphasis>CONSTRAINT products_name_not_null</emphasis> NOT NULL,
price numeric
);
</programlisting>
</para>
<para>
A not-null constraint is always written as a column constraint. A
not-null constraint is functionally equivalent to creating a check
A not-null constraint is usually written as a column constraint. The
syntax for writing it as a table constraint is
<programlisting>
CREATE TABLE products (
product_no integer,
name text,
price numeric,
<emphasis>NOT NULL product_no</emphasis>,
<emphasis>NOT NULL name</emphasis>
);
</programlisting>
But this syntax is not standard and mainly intended for use by
<application>pg_dump</application>.
</para>
<para>
A not-null constraint is functionally equivalent to creating a check
constraint <literal>CHECK (<replaceable>column_name</replaceable>
IS NOT NULL)</literal>, but in
<productname>PostgreSQL</productname> creating an explicit
not-null constraint is more efficient. The drawback is that you
cannot give explicit names to not-null constraints created this
way.
not-null constraint is more efficient.
</para>
<para>
@ -799,6 +820,10 @@ CREATE TABLE products (
order the constraints are checked.
</para>
<para>
However, a column can have at most one explicit not-null constraint.
</para>
<para>
The <literal>NOT NULL</literal> constraint has an inverse: the
<literal>NULL</literal> constraint. This does not mean that the
@ -992,7 +1017,7 @@ CREATE TABLE example (
<para>
A table can have at most one primary key. (There can be any number
of unique and not-null constraints, which are functionally almost the
of unique constraints, which combined with not-null constraints are functionally almost the
same thing, but only one can be identified as the primary key.)
Relational database theory
dictates that every table must have a primary key. This rule is
@ -1652,11 +1677,16 @@ ALTER TABLE products ADD CHECK (name &lt;&gt; '');
ALTER TABLE products ADD CONSTRAINT some_name UNIQUE (product_no);
ALTER TABLE products ADD FOREIGN KEY (product_group_id) REFERENCES product_groups;
</programlisting>
To add a not-null constraint, which cannot be written as a table
constraint, use this syntax:
</para>
<para>
To add a not-null constraint, which is normally not written as a table
constraint, this special syntax is available:
<programlisting>
ALTER TABLE products ALTER COLUMN product_no SET NOT NULL;
</programlisting>
This command silently does nothing if the column already has a
not-null constraint.
</para>
<para>
@ -1697,12 +1727,15 @@ ALTER TABLE products DROP CONSTRAINT some_name;
</para>
<para>
This works the same for all constraint types except not-null
constraints. To drop a not-null constraint use:
Simplified syntax is available to drop a not-null constraint:
<programlisting>
ALTER TABLE products ALTER COLUMN product_no DROP NOT NULL;
</programlisting>
(Recall that not-null constraints do not have names.)
This mirrors the <literal>SET NOT NULL</literal> syntax for adding a
not-null constraint. This command will silently do nothing if the column
does not have a not-null constraint. (Recall that a column can have at
most one not-null constraint, so it is never ambiguous which constraint
this command acts on.)
</para>
</sect2>
@ -4446,12 +4479,10 @@ ALTER INDEX measurement_city_id_logdate_key
<para>
Both <literal>CHECK</literal> and <literal>NOT NULL</literal>
constraints of a partitioned table are always inherited by all its
partitions. <literal>CHECK</literal> constraints that are marked
<literal>NO INHERIT</literal> are not allowed to be created on
partitioned tables.
You cannot drop a <literal>NOT NULL</literal> constraint on a
partition's column if the same constraint is present in the parent
table.
partitions; it is not allowed to create <literal>NO INHERIT</literal>
constraints of those types.
You cannot drop a constraint of those types if the same constraint
is present in the parent table.
</para>
</listitem>

View File

@ -173,7 +173,8 @@ ALTER FOREIGN TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceab
<para>
This form adds a new constraint to a foreign table, using the same
syntax as <link linkend="sql-createforeigntable"><command>CREATE FOREIGN TABLE</command></link>.
Currently only <literal>CHECK</literal> constraints are supported.
Currently only <literal>CHECK</literal> and <literal>NOT NULL</literal>
constraints are supported.
</para>
<para>
@ -182,7 +183,8 @@ ALTER FOREIGN TABLE [ IF EXISTS ] <replaceable class="parameter">name</replaceab
declares that some new condition should be assumed to hold for all rows
in the foreign table. (See the discussion
in <link linkend="sql-createforeigntable"><command>CREATE FOREIGN TABLE</command></link>.)
If the constraint is marked <literal>NOT VALID</literal>, then it isn't
If the constraint is marked <literal>NOT VALID</literal> (allowed only for
the <literal>CHECK</literal> case), then it isn't
assumed to hold, but is only recorded for possible future use.
</para>
</listitem>

View File

@ -98,7 +98,7 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
<phrase>and <replaceable class="parameter">column_constraint</replaceable> is:</phrase>
[ CONSTRAINT <replaceable class="parameter">constraint_name</replaceable> ]
{ NOT NULL |
{ NOT NULL [ NO INHERIT ] |
NULL |
CHECK ( <replaceable class="parameter">expression</replaceable> ) [ NO INHERIT ] |
DEFAULT <replaceable>default_expr</replaceable> |
@ -114,6 +114,7 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
[ CONSTRAINT <replaceable class="parameter">constraint_name</replaceable> ]
{ CHECK ( <replaceable class="parameter">expression</replaceable> ) [ NO INHERIT ] |
NOT NULL <replaceable class="parameter">column_name</replaceable> [ NO INHERIT ] |
UNIQUE [ NULLS [ NOT ] DISTINCT ] ( <replaceable class="parameter">column_name</replaceable> [, ... ] ) <replaceable class="parameter">index_parameters</replaceable> |
PRIMARY KEY ( <replaceable class="parameter">column_name</replaceable> [, ... ] ) <replaceable class="parameter">index_parameters</replaceable> |
EXCLUDE [ USING <replaceable class="parameter">index_method</replaceable> ] ( <replaceable class="parameter">exclude_element</replaceable> WITH <replaceable class="parameter">operator</replaceable> [, ... ] ) <replaceable class="parameter">index_parameters</replaceable> [ WHERE ( <replaceable class="parameter">predicate</replaceable> ) ] |
@ -849,19 +850,16 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
table. Subsequently, queries against the parent will include records
of the target table. To be added as a child, the target table must
already contain all the same columns as the parent (it could have
additional columns, too). The columns must have matching data types,
and if they have <literal>NOT NULL</literal> constraints in the parent
then they must also have <literal>NOT NULL</literal> constraints in the
child.
additional columns, too). The columns must have matching data types.
</para>
<para>
There must also be matching child-table constraints for all
<literal>CHECK</literal> constraints of the parent, except those
marked non-inheritable (that is, created with <literal>ALTER TABLE ... ADD CONSTRAINT ... NO INHERIT</literal>)
in the parent, which are ignored; all child-table constraints matched
must not be marked non-inheritable.
Currently
In addition, all <literal>CHECK</literal> and <literal>NOT NULL</literal>
constraints on the parent must also exist on the child, except those
marked non-inheritable (that is, created with
<literal>ALTER TABLE ... ADD CONSTRAINT ... NO INHERIT</literal>), which
are ignored. All child-table constraints matched must not be marked
non-inheritable. Currently
<literal>UNIQUE</literal>, <literal>PRIMARY KEY</literal>, and
<literal>FOREIGN KEY</literal> constraints are not considered, but
this might change in the future.
@ -1793,11 +1791,17 @@ ALTER TABLE measurement
<title>Compatibility</title>
<para>
The forms <literal>ADD</literal> (without <literal>USING INDEX</literal>),
The forms <literal>ADD [COLUMN]</literal>,
<literal>DROP [COLUMN]</literal>, <literal>DROP IDENTITY</literal>, <literal>RESTART</literal>,
<literal>SET DEFAULT</literal>, <literal>SET DATA TYPE</literal> (without <literal>USING</literal>),
<literal>SET GENERATED</literal>, and <literal>SET <replaceable>sequence_option</replaceable></literal>
conform with the SQL standard. The other forms are
conform with the SQL standard.
The form <literal>ADD <replaceable>table_constraint</replaceable></literal>
conforms with the SQL standard when the <literal>USING INDEX</literal> and
<literal>NOT VALID</literal> clauses are omitted and the constraint type is
one of <literal>CHECK</literal>, <literal>UNIQUE</literal>, <literal>PRIMARY KEY</literal>,
or <literal>REFERENCES</literal>.
The other forms are
<productname>PostgreSQL</productname> extensions of the SQL standard.
Also, the ability to specify more than one manipulation in a single
<command>ALTER TABLE</command> command is an extension.

View File

@ -43,7 +43,7 @@ CREATE FOREIGN TABLE [ IF NOT EXISTS ] <replaceable class="parameter">table_name
<phrase>where <replaceable class="parameter">column_constraint</replaceable> is:</phrase>
[ CONSTRAINT <replaceable class="parameter">constraint_name</replaceable> ]
{ NOT NULL |
{ NOT NULL [ NO INHERIT ] |
NULL |
CHECK ( <replaceable class="parameter">expression</replaceable> ) [ NO INHERIT ] |
DEFAULT <replaceable>default_expr</replaceable> |
@ -52,6 +52,7 @@ CREATE FOREIGN TABLE [ IF NOT EXISTS ] <replaceable class="parameter">table_name
<phrase>and <replaceable class="parameter">table_constraint</replaceable> is:</phrase>
[ CONSTRAINT <replaceable class="parameter">constraint_name</replaceable> ]
NOT NULL <replaceable class="parameter">column_name</replaceable> [ NO INHERIT ] |
CHECK ( <replaceable class="parameter">expression</replaceable> ) [ NO INHERIT ]
<phrase>and <replaceable class="parameter">partition_bound_spec</replaceable> is:</phrase>
@ -203,11 +204,16 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</varlistentry>
<varlistentry>
<term><literal>NOT NULL</literal></term>
<term><literal>NOT NULL</literal> [ NO INHERIT ]</term>
<listitem>
<para>
The column is not allowed to contain null values.
</para>
<para>
A constraint marked with <literal>NO INHERIT</literal> will not propagate to
child tables.
</para>
</listitem>
</varlistentry>

View File

@ -61,7 +61,7 @@ CREATE [ [ GLOBAL | LOCAL ] { TEMPORARY | TEMP } | UNLOGGED ] TABLE [ IF NOT EXI
<phrase>where <replaceable class="parameter">column_constraint</replaceable> is:</phrase>
[ CONSTRAINT <replaceable class="parameter">constraint_name</replaceable> ]
{ NOT NULL |
{ NOT NULL [ NO INHERIT ] |
NULL |
CHECK ( <replaceable class="parameter">expression</replaceable> ) [ NO INHERIT ] |
DEFAULT <replaceable>default_expr</replaceable> |
@ -77,6 +77,7 @@ CREATE [ [ GLOBAL | LOCAL ] { TEMPORARY | TEMP } | UNLOGGED ] TABLE [ IF NOT EXI
[ CONSTRAINT <replaceable class="parameter">constraint_name</replaceable> ]
{ CHECK ( <replaceable class="parameter">expression</replaceable> ) [ NO INHERIT ] |
NOT NULL <replaceable class="parameter">column_name</replaceable> [ NO INHERIT ] |
UNIQUE [ NULLS [ NOT ] DISTINCT ] ( <replaceable class="parameter">column_name</replaceable> [, ... ] [, <replaceable class="parameter">column_name</replaceable> WITHOUT OVERLAPS ] ) <replaceable class="parameter">index_parameters</replaceable> |
PRIMARY KEY ( <replaceable class="parameter">column_name</replaceable> [, ... ] [, <replaceable class="parameter">column_name</replaceable> WITHOUT OVERLAPS ] ) <replaceable class="parameter">index_parameters</replaceable> |
EXCLUDE [ USING <replaceable class="parameter">index_method</replaceable> ] ( <replaceable class="parameter">exclude_element</replaceable> WITH <replaceable class="parameter">operator</replaceable> [, ... ] ) <replaceable class="parameter">index_parameters</replaceable> [ WHERE ( <replaceable class="parameter">predicate</replaceable> ) ] |
@ -818,11 +819,16 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
</varlistentry>
<varlistentry id="sql-createtable-parms-not-null">
<term><literal>NOT NULL</literal></term>
<term><literal>NOT NULL [ NO INHERIT ] </literal></term>
<listitem>
<para>
The column is not allowed to contain null values.
</para>
<para>
A constraint marked with <literal>NO INHERIT</literal> will not propagate to
child tables.
</para>
</listitem>
</varlistentry>
@ -2398,13 +2404,6 @@ CREATE TABLE cities_partdef
constraint, and index names must be unique across all relations within
the same schema.
</para>
<para>
Currently, <productname>PostgreSQL</productname> does not record names
for not-null constraints at all, so they are not
subject to the uniqueness restriction. This might change in a future
release.
</para>
</refsect2>
<refsect2>