NULL
in Unique Keys
Firebird’s SQL-compliant rules for UNIQUE
constraints allow one or more NULL
s in a column with a UNIQUE
constraint.This makes it possible to define a UNIQUE
constraint on a column that does not have the NOT NULL
constraint.
For UNIQUE
keys that span multiple columns, the logic is a little complicated:
-
Multiple rows having null in all the columns of the key are allowed
-
Multiple rows having keys with different combinations of nulls and non-null values are allowed
-
Multiple rows having the same key columns null and the rest filled with non-null values are allowed, provided the non-null values differ in at least one column
-
Multiple rows having the same key columns null and the rest filled with non-null values that are the same in every column will violate the constraint
The rules for uniqueness can be summarised thus:
In principle, all nulls are considered distinct.
However, if two rows have exactly the same key columns filled with non-null values, the NULL
columns are ignored and the uniqueness is determined on the non-null columns as though they constituted the entire key.
RECREATE TABLE t( x int, y int, z int, unique(x,y,z));
INSERT INTO t values( NULL, 1, 1 );
INSERT INTO t values( NULL, NULL, 1 );
INSERT INTO t values( NULL, NULL, NULL );
INSERT INTO t values( NULL, NULL, NULL ); -- Permitted
INSERT INTO t values( NULL, NULL, 1 ); -- Not permitted