unique index with several columns - Mailing list pgsql-sql

From Voillequin, Jean-Marc
Subject unique index with several columns
Date
Msg-id MN2PR20MB2735507A85A89B7279AB6A2CBE059@MN2PR20MB2735.namprd20.prod.outlook.com
Whole thread Raw
Responses RE: unique index with several columns
Re: unique index with several columns
List pgsql-sql

Hello,

 

On PG:

 

RRT=> create table t(c1 char, c2 char);

ERROR:  relation "t" already exists

RRT=> create unique index idx on t(c1,c2);

ERROR:  relation "idx" already exists

RRT=> insert into t(c1,c2) values (null,null);

INSERT 0 1

RRT=> insert into t(c1,c2) values (null,null);

INSERT 0 1

RRT=> insert into t(c1,c2) values ('a',null);

INSERT 0 1

RRT=> insert into t(c1,c2) values ('a',null);

INSERT 0 1

 

On Oracle:

 

SQL> create table t(c1 char, c2 char);

Table created.

SQL> create unique index idx on t(c1,c2);

Index created.

SQL> insert into t(c1,c2) values (null,null);

1 row created.

SQL> insert into t(c1,c2) values (null,null);

1 row created.

SQL> insert into t(c1,c2) values ('a',null);

1 row created.

SQL> insert into t(c1,c2) values ('a',null);

insert into t(c1,c2) values ('a',null)

*

ERROR at line 1:

ORA-00001: unique constraint (RRT.IDX) violated

 

When one of the field is null, PG considers that the tuple is not the same:

('a',null) is not equal to ('a',null)

So, the unique constraint is not violated in PG.

 

But is there a way to have the same feature than Oracle?

 

I already tried with:

create unique index idx on t(coalesce(c1,''),coalesce(c2,''))

 

But in this case, I cannot insert several (null,null) without raising a duplicate key error.

 

Thanks & regards

-----------------------------------------
Moody's monitors email communications through its networks for regulatory compliance purposes and to protect its customers, employees and business and where allowed to do so by applicable law. The information contained in this e-mail message, and any attachment thereto, is confidential and may not be disclosed without our express permission. If you are not the intended recipient or an employee or agent responsible for delivering this message to the intended recipient, you are hereby notified that you have received this message in error and that any review, dissemination, distribution or copying of this message, or any attachment thereto, in whole or in part, is strictly prohibited. If you have received this message in error, please immediately notify us by telephone, fax or e-mail and delete the message and all of its attachments. Every effort is made to keep our network free from viruses. You should, however, review this e-mail message, as well as any attachment thereto, for viruses. We take no responsibility and have no liability for any computer virus which may be transferred via this e-mail message.
-----------------------------------------

pgsql-sql by date:

Previous
From: Steve Midgley
Date:
Subject: Re: Bug in tables column data in postgres database
Next
From: Kevin Tu
Date:
Subject: limits on the number of concurrent DBMS sessions per account