1
0
mirror of https://github.com/postgres/postgres.git synced 2025-07-30 11:03:19 +03:00

Catalog not-null constraints

We now create contype='n' pg_constraint rows for not-null constraints.

We propagate these constraints to other tables during operations such as
adding inheritance relationships, creating and attaching partitions and
creating tables LIKE other tables.  We also spawn not-null constraints
for inheritance child tables when their parents have primary keys.
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 it,
instead matching by column name that they apply to.  This means we don't
require the constraint names to be identical across a hierarchy.

For now, we omit them for system catalogs.  Maybe this is worth
reconsidering.  We don't support NOT VALID nor DEFERRABLE clauses
either; these can be added as separate features later (this patch is
already large and complicated enough.)

psql shows these constraints in \d+.

pg_dump requires some ad-hoc hacks, particularly when dumping a primary
key.  We now create one "throwaway" not-null constraint for each column
in the PK together with the CREATE TABLE command, and once the PK is
created, all those throwaway constraints are removed.  This avoids
having to check each tuple for nullness when the dump restores the
primary key creation.

pg_upgrading from an older release requires a somewhat brittle procedure
to create a constraint state that matches what would be created if the
database were being created fresh in Postgres 17.  I have tested all the
scenarios I could think of, and it works correctly as far as I can tell,
but I could have neglected weird cases.

This patch has been very long in the making.  The first patch was
written by Bernd Helmle in 2010 to add a new pg_constraint.contype value
('n'), which I (Álvaro) then hijacked in 2011 and 2012, until that one
was killed by the realization that we ought to use contype='c' instead:
manufactured CHECK constraints.  However, later SQL standard
development, as well as nonobvious emergent properties of that design
(mostly, failure to distinguish them from "normal" CHECK constraints as
well as the performance implication of having to test the CHECK
expression) led us to reconsider this choice, so now the current
implementation uses contype='n' again.  During Postgres 16 this had
already been introduced by commit e056c557ae, but there were some
problems mainly with the pg_upgrade procedure that couldn't be fixed in
reasonable time, so it was reverted.

In 2016 Vitaly Burovoy also worked on this feature[1] but found no
consensus for his proposed approach, which was claimed to be closer to
the letter of the standard, requiring an additional pg_attribute column
to track the OID of the not-null constraint for that column.
[1] https://postgr.es/m/CAKOSWNkN6HSyatuys8xZxzRCR-KL1OkHS5-b9qd9bf1Rad3PLA@mail.gmail.com

Author: Álvaro Herrera <alvherre@alvh.no-ip.org>
Author: Bernd Helmle <mailings@oopsware.de>
Reviewed-by: Justin Pryzby <pryzby@telsasoft.com>
Reviewed-by: Peter Eisentraut <peter.eisentraut@enterprisedb.com>
Reviewed-by: Dean Rasheed <dean.a.rasheed@gmail.com>
This commit is contained in:
Alvaro Herrera
2023-08-25 13:31:24 +02:00
parent 9c13b6814a
commit b0e96f3119
50 changed files with 3933 additions and 769 deletions

View File

@ -1270,7 +1270,8 @@
<structfield>attnotnull</structfield> <type>bool</type>
</para>
<para>
This represents a not-null constraint.
This column is marked not-null, either by a not-null constraint
or a primary key.
</para></entry>
</row>
@ -2484,13 +2485,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.
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 are represented in the
<link linkend="catalog-pg-attribute"><structname>pg_attribute</structname></link>
catalog, not here.
</para>
<para>
@ -2552,6 +2550,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,
<literal>p</literal> = primary key constraint,
<literal>u</literal> = unique constraint,
<literal>t</literal> = constraint trigger,

View File

@ -650,18 +650,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>
@ -678,6 +699,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
@ -871,7 +896,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
@ -1531,11 +1556,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>
@ -1576,12 +1606,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>

View File

@ -113,6 +113,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> ) ] |
@ -1763,11 +1764,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

@ -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">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> ) ] |
@ -2314,13 +2315,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 <literal>NOT NULL</literal> constraints at all, so they are not
subject to the uniqueness restriction. This might change in a future
release.
</para>
</refsect2>
<refsect2>