mirror of
https://github.com/postgres/postgres.git
synced 2025-06-11 20:28:21 +03:00
Add UNIQUE null treatment option
The SQL standard has been ambiguous about whether null values in unique constraints should be considered equal or not. Different implementations have different behaviors. In the SQL:202x draft, this has been formalized by making this implementation-defined and adding an option on unique constraint definitions UNIQUE [ NULLS [NOT] DISTINCT ] to choose a behavior explicitly. This patch adds this option to PostgreSQL. The default behavior remains UNIQUE NULLS DISTINCT. Making this happen in the btree code is pretty easy; most of the patch is just to carry the flag around to all the places that need it. The CREATE UNIQUE INDEX syntax extension is not from the standard, it's my own invention. I named all the internal flags, catalog columns, etc. in the negative ("nulls not distinct") so that the default PostgreSQL behavior is the default if the flag is false. Reviewed-by: Maxim Orlov <orlovmg@gmail.com> Reviewed-by: Pavel Borisov <pashkin.elfe@gmail.com> Discussion: https://www.postgresql.org/message-id/flat/84e5ee1b-387e-9a54-c326-9082674bde78@enterprisedb.com
This commit is contained in:
@ -4265,6 +4265,19 @@ SCRAM-SHA-256$<replaceable><iteration count></replaceable>:<replaceable>&l
|
||||
</para></entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry role="catalog_table_entry"><para role="column_definition">
|
||||
<structfield>indnullsnotdistinct</structfield> <type>bool</type>
|
||||
</para>
|
||||
<para>
|
||||
This value is only used for unique indexes. If false, this unique
|
||||
index will consider null values distinct (so the index can contain
|
||||
multiple null values in a column, the default PostgreSQL behavior). If
|
||||
it is true, it will consider null values to be equal (so the index can
|
||||
only contain one null value in a column).
|
||||
</para></entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry role="catalog_table_entry"><para role="column_definition">
|
||||
<structfield>indisprimary</structfield> <type>bool</type>
|
||||
|
@ -759,14 +759,33 @@ CREATE TABLE products (
|
||||
In general, a unique constraint is violated if there is more than
|
||||
one row in the table where the values of all of the
|
||||
columns included in the constraint are equal.
|
||||
However, two null values are never considered equal in this
|
||||
By default, two null values are not considered equal in this
|
||||
comparison. That means even in the presence of a
|
||||
unique constraint it is possible to store duplicate
|
||||
rows that contain a null value in at least one of the constrained
|
||||
columns. This behavior conforms to the SQL standard, but we have
|
||||
heard that other SQL databases might not follow this rule. So be
|
||||
careful when developing applications that are intended to be
|
||||
portable.
|
||||
columns. This behavior can be changed by adding the clause <literal>NULLS
|
||||
NOT DISTINCT</literal>, like
|
||||
<programlisting>
|
||||
CREATE TABLE products (
|
||||
product_no integer UNIQUE <emphasis>NULLS NOT DISTINCT</emphasis>,
|
||||
name text,
|
||||
price numeric
|
||||
);
|
||||
</programlisting>
|
||||
or
|
||||
<programlisting>
|
||||
CREATE TABLE products (
|
||||
product_no integer,
|
||||
name text,
|
||||
price numeric,
|
||||
UNIQUE <emphasis>NULLS NOT DISTINCT</emphasis> (product_no)
|
||||
);
|
||||
</programlisting>
|
||||
The default behavior can be specified explicitly using <literal>NULLS
|
||||
DISTINCT</literal>. The default null treatment in unique constraints is
|
||||
implementation-defined according to the SQL standard, and other
|
||||
implementations have a different behavior. So be careful when developing
|
||||
applications that are intended to be portable.
|
||||
</para>
|
||||
</sect2>
|
||||
|
||||
|
@ -6899,6 +6899,18 @@ ORDER BY c.ordinal_position;
|
||||
<literal>YES</literal>)
|
||||
</para></entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry role="catalog_table_entry"><para role="column_definition">
|
||||
<structfield>nulls_distinct</structfield> <type>yes_or_no</type>
|
||||
</para>
|
||||
<para>
|
||||
If the constraint is a unique constraint, then <literal>YES</literal>
|
||||
if the constraint treats nulls as distinct or <literal>NO</literal> if
|
||||
it treats nulls as not distinct, otherwise null for other types of
|
||||
constraints.
|
||||
</para></entry>
|
||||
</row>
|
||||
</tbody>
|
||||
</tgroup>
|
||||
</table>
|
||||
|
@ -103,7 +103,7 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
|
||||
DEFAULT <replaceable>default_expr</replaceable> |
|
||||
GENERATED ALWAYS AS ( <replaceable>generation_expr</replaceable> ) STORED |
|
||||
GENERATED { ALWAYS | BY DEFAULT } AS IDENTITY [ ( <replaceable>sequence_options</replaceable> ) ] |
|
||||
UNIQUE <replaceable class="parameter">index_parameters</replaceable> |
|
||||
UNIQUE [ NULLS [ NOT ] DISTINCT ] <replaceable class="parameter">index_parameters</replaceable> |
|
||||
PRIMARY KEY <replaceable class="parameter">index_parameters</replaceable> |
|
||||
REFERENCES <replaceable class="parameter">reftable</replaceable> [ ( <replaceable class="parameter">refcolumn</replaceable> ) ] [ MATCH FULL | MATCH PARTIAL | MATCH SIMPLE ]
|
||||
[ ON DELETE <replaceable class="parameter">referential_action</replaceable> ] [ ON UPDATE <replaceable class="parameter">referential_action</replaceable> ] }
|
||||
@ -113,7 +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 ] |
|
||||
UNIQUE ( <replaceable class="parameter">column_name</replaceable> [, ... ] ) <replaceable class="parameter">index_parameters</replaceable> |
|
||||
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> ) ] |
|
||||
FOREIGN KEY ( <replaceable class="parameter">column_name</replaceable> [, ... ] ) REFERENCES <replaceable class="parameter">reftable</replaceable> [ ( <replaceable class="parameter">refcolumn</replaceable> [, ... ] ) ]
|
||||
|
@ -24,6 +24,7 @@ PostgreSQL documentation
|
||||
CREATE [ UNIQUE ] INDEX [ CONCURRENTLY ] [ [ IF NOT EXISTS ] <replaceable class="parameter">name</replaceable> ] ON [ ONLY ] <replaceable class="parameter">table_name</replaceable> [ USING <replaceable class="parameter">method</replaceable> ]
|
||||
( { <replaceable class="parameter">column_name</replaceable> | ( <replaceable class="parameter">expression</replaceable> ) } [ COLLATE <replaceable class="parameter">collation</replaceable> ] [ <replaceable class="parameter">opclass</replaceable> [ ( <replaceable class="parameter">opclass_parameter</replaceable> = <replaceable class="parameter">value</replaceable> [, ... ] ) ] ] [ ASC | DESC ] [ NULLS { FIRST | LAST } ] [, ...] )
|
||||
[ INCLUDE ( <replaceable class="parameter">column_name</replaceable> [, ...] ) ]
|
||||
[ NULLS [ NOT ] DISTINCT ]
|
||||
[ WITH ( <replaceable class="parameter">storage_parameter</replaceable> [= <replaceable class="parameter">value</replaceable>] [, ... ] ) ]
|
||||
[ TABLESPACE <replaceable class="parameter">tablespace_name</replaceable> ]
|
||||
[ WHERE <replaceable class="parameter">predicate</replaceable> ]
|
||||
@ -334,6 +335,18 @@ CREATE [ UNIQUE ] INDEX [ CONCURRENTLY ] [ [ IF NOT EXISTS ] <replaceable class=
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
<varlistentry>
|
||||
<term><literal>NULLS DISTINCT</literal></term>
|
||||
<term><literal>NULLS NOT DISTINCT</literal></term>
|
||||
<listitem>
|
||||
<para>
|
||||
Specifies whether for a unique index, null values should be considered
|
||||
distinct (not equal). The default is that they are distinct, so that
|
||||
a unique index could contain multiple null values in a column.
|
||||
</para>
|
||||
</listitem>
|
||||
</varlistentry>
|
||||
|
||||
<varlistentry>
|
||||
<term><replaceable class="parameter">storage_parameter</replaceable></term>
|
||||
<listitem>
|
||||
|
@ -67,7 +67,7 @@ CREATE [ [ GLOBAL | LOCAL ] { TEMPORARY | TEMP } | UNLOGGED ] TABLE [ IF NOT EXI
|
||||
DEFAULT <replaceable>default_expr</replaceable> |
|
||||
GENERATED ALWAYS AS ( <replaceable>generation_expr</replaceable> ) STORED |
|
||||
GENERATED { ALWAYS | BY DEFAULT } AS IDENTITY [ ( <replaceable>sequence_options</replaceable> ) ] |
|
||||
UNIQUE <replaceable class="parameter">index_parameters</replaceable> |
|
||||
UNIQUE [ NULLS [ NOT ] DISTINCT ] <replaceable class="parameter">index_parameters</replaceable> |
|
||||
PRIMARY KEY <replaceable class="parameter">index_parameters</replaceable> |
|
||||
REFERENCES <replaceable class="parameter">reftable</replaceable> [ ( <replaceable class="parameter">refcolumn</replaceable> ) ] [ MATCH FULL | MATCH PARTIAL | MATCH SIMPLE ]
|
||||
[ ON DELETE <replaceable class="parameter">referential_action</replaceable> ] [ ON UPDATE <replaceable class="parameter">referential_action</replaceable> ] }
|
||||
@ -77,7 +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 ] |
|
||||
UNIQUE ( <replaceable class="parameter">column_name</replaceable> [, ... ] ) <replaceable class="parameter">index_parameters</replaceable> |
|
||||
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> ) ] |
|
||||
FOREIGN KEY ( <replaceable class="parameter">column_name</replaceable> [, ... ] ) REFERENCES <replaceable class="parameter">reftable</replaceable> [ ( <replaceable class="parameter">refcolumn</replaceable> [, ... ] ) ]
|
||||
@ -917,8 +917,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
|
||||
</varlistentry>
|
||||
|
||||
<varlistentry>
|
||||
<term><literal>UNIQUE</literal> (column constraint)</term>
|
||||
<term><literal>UNIQUE ( <replaceable class="parameter">column_name</replaceable> [, ... ] )</literal>
|
||||
<term><literal>UNIQUE [ NULLS [ NOT ] DISTINCT ]</literal> (column constraint)</term>
|
||||
<term><literal>UNIQUE [ NULLS [ NOT ] DISTINCT ] ( <replaceable class="parameter">column_name</replaceable> [, ... ] )</literal>
|
||||
<optional> <literal>INCLUDE ( <replaceable class="parameter">column_name</replaceable> [, ...])</literal> </optional> (table constraint)</term>
|
||||
|
||||
<listitem>
|
||||
@ -934,7 +934,8 @@ WITH ( MODULUS <replaceable class="parameter">numeric_literal</replaceable>, REM
|
||||
|
||||
<para>
|
||||
For the purpose of a unique constraint, null values are not
|
||||
considered equal.
|
||||
considered equal, unless <literal>NULLS NOT DISTINCT</literal> is
|
||||
specified.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
|
Reference in New Issue
Block a user