Thread: UNIQUE, btree index allows duplicate records, if some fields are null

UNIQUE, btree index allows duplicate records, if some fields are null

From
Bryce Nesbitt
Date:
This threw me for a loop.  Is this my fault, or a
problem in postgres?

I have a table with the following:   "eg_vehicle_event_pkey" PRIMARY KEY, btree (event_id)   "no_duplicate_events"
UNIQUE,btree (thing, other_thing,
 
"timestamp", number, other_number)

The "no_duplicate_events" constraint works fine, but if I insert records
where
"other_thing" is null, they all go in without complaint. I can insert as
many duplicates as I want.

I had expected two records, identical in all respects including the
null value, to be rejected by the constraint.

This is with:
PostgreSQL 7.4.1 on i686-pc-linux-gnu, compiled by GCC gcc (GCC) 3.2.3
20030502 (Red Hat Linux 3.2.3-20)



Re: UNIQUE, btree index allows duplicate records, if some fields are null

From
Tom Lane
Date:
Bryce Nesbitt <bryce1@obviously.com> writes:
> I have a table with the following:
>     "eg_vehicle_event_pkey" PRIMARY KEY, btree (event_id)
>     "no_duplicate_events" UNIQUE, btree (thing, other_thing,
> "timestamp", number, other_number)

> The "no_duplicate_events" constraint works fine, but if I insert records
> where
> "other_thing" is null, they all go in without complaint. I can insert as
> many duplicates as I want.

This is per SQL spec.  You're imagining that two nulls are considered
equal, which they are not.
        regards, tom lane