Re: uniqueness constraint with NULLs - Mailing list pgsql-sql

From Craig Ringer
Subject Re: uniqueness constraint with NULLs
Date
Msg-id 1246275150.11346.27.camel@ayaki
Whole thread Raw
In response to uniqueness constraint with NULLs  (Robert Edwards <bob@cs.anu.edu.au>)
Responses Re: uniqueness constraint with NULLs
Re: uniqueness constraint with NULLs
List pgsql-sql
On Mon, 2009-06-29 at 15:42 +1000, Robert Edwards wrote:

> Can anyone suggest a way that I can impose uniqueness on a and b when
> c is NULL?

One way is to add an additional partial index on (a,b):

CREATE INDEX bobtest_ab_unique ON bobtest(a,b) WHERE (c IS NULL);

... however, if you want to do the same sort of thing for all
permutations (a, null, null), (b, null, null), (c, null, null), (a, b,
null), (a, c, null), (b, c, null), (a, b, c)that'll be a LOT of indexes.

In that case you might be better off just using a trigger function like
(untested but should be about right):

CREATE OR REPLACE FUNCTION bobtest_unique_trigger() RETURNS trigger AS
$$
declare conflicting_id integer;
begin if TG_OP = 'INSERT' or TG_OP = 'UPDATE' then   select into conflicting_id from bobtest   where (NOT new.a IS
DISTINCTFROM a)     and (NOT new.b IS DISTINCT FROM b)     and (NOT new.c IS DISTINCT FROM c);   if found then
raiseexception 'Unique violation in bobest: inserted row
 
conflicts with row id=%',conflicting_id;   end if; end if;
end;
$$ LANGUAGE 'plpgsql';

... which enforces uniqueness considering nulls.

> In the real app., c is a date field and I require it to be NULL for
> some rows.

Oh. Er, In that case, the partial unique index is your best bet (but 'a'
and 'b' should ne NOT NULL, right).

> in case I am missing some other solution that
> doesn't involve the use of triggers etc.

Sometimes a trigger is the right solution.

-- 
Craig Ringer



pgsql-sql by date:

Previous
From: Mario Splivalo
Date:
Subject: date_trunc should be called date_round?
Next
From: Tom Lane
Date:
Subject: Re: uniqueness constraint with NULLs