Re: uniqueness constraint with NULLs

From: Leo Mannhart <Leo(dot)Mannhart(at)beecom(dot)ch>
To: pgsql-sql(at)postgresql(dot)org
Subject: Re: uniqueness constraint with NULLs
Date: 2009-06-29 07:23:51
Message-ID: 1246260231.7296.2.camel@mars.lemaco.ch
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-sql

On Mon, 2009-06-29 at 17:08 +1000, Robert Edwards wrote:
> A. Kretschmer wrote:
> > In response to Robert Edwards :
> >> Can anyone suggest a way that I can impose uniqueness on a and b when
> >> c is NULL?
> >
> > Sure, use a functional index:
> >
> > test=# create table bobtest (a int, b int, c int);
> > CREATE TABLE
> > test=*# create unique index idx_bobtest on
> > bobtest(a,b,coalesce(c::text,'NULL'));
> > CREATE INDEX
> > test=*# insert into bobtest (a, b) values (1, 4);
> > INSERT 0 1
> > test=*# insert into bobtest (a, b, c) values (1, 4, NULL);
> > ERROR: duplicate key value violates unique constraint "idx_bobtest"
> > test=!#
> >
Why changing the datatype of coulumn "c"? Will this not probably disable
the use of the index? Why not only:

lem=# create table bobtest (a int, b int, c int);
CREATE TABLE
lem=# create unique index idc_bobtest on bobtest (a, b, coalesce(c, 1));
CREATE INDEX
lem=# insert into bobtest (a, b) values (1, 4);
INSERT 0 1
lem=# insert into bobtest (a, b) values (1, 4);
ERROR: duplicate key value violates unique constraint "idc_bobtest"
lem=# insert into bobtest (a, b, c) values (1, 4, null);
ERROR: duplicate key value violates unique constraint "idc_bobtest"
lem=#

> >
> > Regards, Andreas
>
> Beautiful!
>
> Many thanks,
>
> Bob Edwards.
>

In response to

Responses

Browse pgsql-sql by date

  From Date Subject
Next Message ivan marchesini 2009-06-29 07:47:25 Re: .psql_history": No such file
Previous Message Robert Edwards 2009-06-29 07:08:34 Re: uniqueness constraint with NULLs