Thread: unique index on fields with possible null values

unique index on fields with possible null values

From
Dmitry Ruban
Date:
Hello pgsql-sql,

I'm trying to find a solution for unique index on fields with possible
null values.

Example table:

CREATE TABLE test (a integer NOT NULL,b integer NULL
);

As long as unique index can't check if there are records with null
values i found the only one solution for this problem:

CREATE UNIQUE INDEX test_uniq1 ON test (a, COALESCE(b,0));

Are there any other ways of doing this?

-- 
Best regards,Dmitry                          mailto:dmitry@ruban.biz



Re: unique index on fields with possible null values

From
Tom Lane
Date:
Dmitry Ruban <dmitry@ruban.biz> writes:
> I'm trying to find a solution for unique index on fields with possible
> null values.

You appear to be hoping that a unique index would constrain a column to
contain at most one null entry.  It doesn't work like that, and I
strongly urge you to reconsider what you're using null for.  I think you
are in for a world of hurt, well beyond this one particular point,
because the SQL spec's semantics for null are not designed around the
idea that it represents a single distinguishable value.  What it
represents is "unknown".
        regards, tom lane