AW: unique index with several columns - Mailing list pgsql-sql

From Marc Mamin
Subject AW: unique index with several columns
Date
Msg-id d931301d59d14c25a1a41e416ac4adf1@intershop.de
Whole thread Raw
In response to RE: unique index with several columns  ("Voillequin, Jean-Marc" <Jean-Marc.Voillequin@moodys.com>)
List pgsql-sql
you can use partial indexes:

create unique index idx  on t(coalesce(c1,''),coalesce(c2,'') )   where (coalesce(c1, c2) is not null);

  but '' is considered equals to null here ...


or more partial indexes which are  more likely to be considered by the planer:

create unique index idx_1 on t(c1) where (c2 is null );
create unique index idx_2 on t(c2) where (c1 is null);
create unique index idx_3 on t(c1, c2)  where (c1 is not null and c2 is not null);

hth,

Marc


________________________________________
Von: Voillequin, Jean-Marc <Jean-Marc.Voillequin@moodys.com>
Gesendet: Freitag, 4. März 2022 16:09:43
An: pgsql-sql@lists.postgresql.org
Betreff: RE: unique index with several columns

Sorry, the test case is:

On PG:

RRT=> create table t(c1 char, c2 char);
CREATE TABLE
RRT=> create unique index idx on t(c1,c2);
CREATE INDEX
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

The question is the same.

From: Voillequin, Jean-Marc
Sent: Friday, March 4, 2022 4:07 PM
To: pgsql-sql@lists.postgresql.org
Subject: unique index with several columns

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
notthe intended recipient or an employee or agent responsible for delivering this message to the intended recipient,
youare hereby notified that you have received this message in error and that any review, dissemination, distribution or
copyingof this message, or any attachment thereto, in whole or in part, is strictly prohibited. If you have received
thismessage 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
computervirus which may be transferred via this e-mail message. 
-----------------------------------------



pgsql-sql by date:

Previous
From: "David G. Johnston"
Date:
Subject: Re: unique index with several columns
Next
From: "Voillequin, Jean-Marc"
Date:
Subject: RE: unique index with several columns