From: | Mikey <mikeboscia(at)gmail(dot)com> |
---|---|
To: | "Tornroth, Phill" <ptornroth(at)intellidot(dot)net> |
Cc: | pgsql-sql(at)postgresql(dot)org |
Subject: | Re: multi-column unique constraints with nullable columns |
Date: | 2005-05-05 19:03:36 |
Message-ID: | 45caccdc05050512035b897fd3@mail.gmail.com |
Views: | Raw Message | Whole Thread | Download mbox | Resend email |
Thread: | |
Lists: | pgsql-sql |
It may be possible to bypass the NULL != NULL by using coalesce. Here
is an example:
<BEGIN SQL>
create table foo2 (
a integer not null,
b integer not null,
c integer null,
UNIQUE (a,b,c)
);
create function foo2_unique_func() RETURNS trigger AS '
DECLARE
isfound integer = 0;
BEGIN
isfound = (select count(*) from foo2 where
(new.a,new.b,coalesce(new.c::TEXT,''EmPtY'')) in (select
a,b,coalesce(c::TEXT,''EmPtY'')
from foo2));
RAISE NOTICE ''isfound: %'', isfound;
IF isfound > 0 THEN
RAISE EXCEPTION ''Columns a,b,c Must Be Unique values
(%,%,%)'', new.a, new.b, new.c;
ELSE
RETURN NEW;
END IF;
END; ' language 'plpgsql';
CREATE TRIGGER foo2_unique BEFORE INSERT OR UPDATE ON foo2
FOR EACH ROW EXECUTE PROCEDURE foo2_unique_func();
insert into foo2 values (1,300, null);
insert into foo2 values (1,300, null);
select * from foo2;
select * from foo2 where (1,300,coalesce(null::TEXT,'EmPtY')) in
(select a,b,coalesce(c::TEXT,'EmPtY') from foo2);
drop table foo2 cascade;
drop function foo2_unique_func() cascade;
<END SQL>
From | Date | Subject | |
---|---|---|---|
Next Message | Tornroth, Phill | 2005-05-05 19:06:29 | Re: multi-column unique constraints with nullable columns |
Previous Message | a3a18850 | 2005-05-05 17:58:04 | Re: HELP: aggregating insert rule for multirow inserts. |