Thread: unique index with several columns

unique index with several columns

From
"Voillequin, Jean-Marc"
Date:

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.
-----------------------------------------

RE: unique index with several columns

From
"Voillequin, Jean-Marc"
Date:

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 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.
-----------------------------------------

Re: unique index with several columns

From
"David G. Johnston"
Date:
On Fri, Mar 4, 2022 at 8:07 AM Voillequin, Jean-Marc <Jean-Marc.Voillequin@moodys.com> wrote:

 

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.



You just said you wanted nulls to be considered equal to each other...

Not tested but these should work in conjunction with each other:

CREATE UNIQUE INDEX idx ON t (c1, c2) WHERE c1 IS NOT NULL AND c2 IS NOT NULL;
CREATE UNIQUE INDEX idx2 ON t (c1) WHERE c2 IS NULL AND c1 IS NOT NULL;
CREATE UNIQUE INDEX idx3 ON t (c2) WHERE c1 IS NULL AND c2 IS NOT NULL;
--CREATE INDEX idx4 ON t (c1, c2) WHERE c1 IS NULL AND c2 IS NULL; (pointless...but symmetric with the others)

Hopefully this helps.

David J.

AW: unique index with several columns

From
Marc Mamin
Date:
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. 
-----------------------------------------



RE: unique index with several columns

From
"Voillequin, Jean-Marc"
Date:

Yes, it helps, thank you.

But I have many tables with many indexes and many columns!

Tons of combinations…

 

From: David G. Johnston <david.g.johnston@gmail.com>
Sent: Friday, March 4, 2022 4:32 PM
To: Voillequin, Jean-Marc <Jean-Marc.Voillequin@moodys.com>
Cc: pgsql-sql@lists.postgresql.org
Subject: Re: unique index with several columns

 

 

CAUTION: This email originated from outside of Moody's. Do not click links or open attachments unless you recognize the sender and know the content is safe.

 

On Fri, Mar 4, 2022 at 8:07 AM Voillequin, Jean-Marc <Jean-Marc.Voillequin@moodys.com> wrote:

 

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.

 

 

You just said you wanted nulls to be considered equal to each other...

 

Not tested but these should work in conjunction with each other:

 

CREATE UNIQUE INDEX idx ON t (c1, c2) WHERE c1 IS NOT NULL AND c2 IS NOT NULL;

CREATE UNIQUE INDEX idx2 ON t (c1) WHERE c2 IS NULL AND c1 IS NOT NULL;

CREATE UNIQUE INDEX idx3 ON t (c2) WHERE c1 IS NULL AND c2 IS NOT NULL;

--CREATE INDEX idx4 ON t (c1, c2) WHERE c1 IS NULL AND c2 IS NULL; (pointless...but symmetric with the others)

 

Hopefully this helps.

 

David J.

 

-----------------------------------------
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.
-----------------------------------------

Re: unique index with several columns

From
Alexey M Boltenkov
Date:
You need the new v15 feature:

NULLS [NOT] DISTINCT
Specifies whether for a unique index, null values should be considered distinct (not equal). The default is that they are distinct, so that a unique index could contain multiple null values in a column.

https://www.postgresql.org/docs/devel/sql-createindex.html


On 03/04/22 19:11, Voillequin, Jean-Marc wrote:

Yes, it helps, thank you.

But I have many tables with many indexes and many columns!

Tons of combinations…

 

From: David G. Johnston <david.g.johnston@gmail.com>
Sent: Friday, March 4, 2022 4:32 PM
To: Voillequin, Jean-Marc <Jean-Marc.Voillequin@moodys.com>
Cc: pgsql-sql@lists.postgresql.org
Subject: Re: unique index with several columns

 

 

CAUTION: This email originated from outside of Moody's. Do not click links or open attachments unless you recognize the sender and know the content is safe.

 

On Fri, Mar 4, 2022 at 8:07 AM Voillequin, Jean-Marc <Jean-Marc.Voillequin@moodys.com> wrote:

 

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.

 

 

You just said you wanted nulls to be considered equal to each other...

 

Not tested but these should work in conjunction with each other:

 

CREATE UNIQUE INDEX idx ON t (c1, c2) WHERE c1 IS NOT NULL AND c2 IS NOT NULL;

CREATE UNIQUE INDEX idx2 ON t (c1) WHERE c2 IS NULL AND c1 IS NOT NULL;

CREATE UNIQUE INDEX idx3 ON t (c2) WHERE c1 IS NULL AND c2 IS NOT NULL;

--CREATE INDEX idx4 ON t (c1, c2) WHERE c1 IS NULL AND c2 IS NULL; (pointless...but symmetric with the others)

 

Hopefully this helps.

 

David J.

 

-----------------------------------------
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.
-----------------------------------------


Re: unique index with several columns

From
Tom Lane
Date:
Alexey M Boltenkov <padrebolt@yandex.ru> writes:
> You need the new v15 feature:
> NULLS [NOT] DISTINCT

That won't replicate the behavior shown by the OP though.
In particular, not the weird inconsistency for all-null rows.

            regards, tom lane



RE: unique index with several columns

From
Klaus Kaisersberger
Date:
This should solve the task:

create unique index idx on t ((
    case
        when c1 is null and c2 is null then null
        when c1 is null and c2 is not null then '{c2}'
        when c1 is not null and c2 is null then '{c1}'
        else '{c1,c2}'
    end));

-----Original Message-----
From: Tom Lane <tgl@sss.pgh.pa.us> 
Sent: Friday, March 4, 2022 7:32 PM
To: Alexey M Boltenkov <padrebolt@yandex.ru>
Cc: Voillequin, Jean-Marc <Jean-Marc.Voillequin@moodys.com>; David G. Johnston <david.g.johnston@gmail.com>;
pgsql-sql@lists.postgresql.org
Subject: Re: unique index with several columns

Alexey M Boltenkov <padrebolt@yandex.ru> writes:
> You need the new v15 feature:
> NULLS [NOT] DISTINCT

That won't replicate the behavior shown by the OP though.
In particular, not the weird inconsistency for all-null rows.

            regards, tom lane



Re: unique index with several columns

From
"David G. Johnston"
Date:
The convention on these lists is to inline or bottom post.

On Fri, Mar 4, 2022 at 11:57 AM Klaus Kaisersberger <woodconsult@outlook.de> wrote:
This should solve the task:

create unique index idx on t ((
        case
                when c1 is null and c2 is null then null
                when c1 is null and c2 is not null then '{c2}'
                when c1 is not null and c2 is null then '{c1}'
                else '{c1,c2}'
        end));


I'm not sure what your '{c1}' syntax means but I'll take it you are suggesting to construct an array.  This seems to fail quite easily if the values of c1 and c2 overlap.

David J.

RE: unique index with several columns

From
Klaus Kaisersberger
Date:
Sorry, mixed the lines up:

create unique index idx on t ((
    case
        when c1 is null and c2 is null then null
        when c1 is null and c2 is not null then ARRAY[null,c2]
        when c1 is not null and c2 is null then ARRAY[c1,null]
        else ARRAY[c1,c2]
    end
));

This could be generically extended to an arbitrary number of columns by counting the number of null column values in a
separatefunction.
 


-----Original Message-----
From: Klaus Kaisersberger <woodconsult@outlook.de> 
Sent: Friday, March 4, 2022 7:57 PM
To: Tom Lane <tgl@sss.pgh.pa.us>; Alexey M Boltenkov <padrebolt@yandex.ru>
Cc: Voillequin, Jean-Marc <Jean-Marc.Voillequin@moodys.com>; David G. Johnston <david.g.johnston@gmail.com>;
pgsql-sql@lists.postgresql.org
Subject: RE: unique index with several columns

This should solve the task:

create unique index idx on t ((
    case
        when c1 is null and c2 is null then null
        when c1 is null and c2 is not null then '{c2}'
        when c1 is not null and c2 is null then '{c1}'
        else '{c1,c2}'
    end));

-----Original Message-----
From: Tom Lane <tgl@sss.pgh.pa.us> 
Sent: Friday, March 4, 2022 7:32 PM
To: Alexey M Boltenkov <padrebolt@yandex.ru>
Cc: Voillequin, Jean-Marc <Jean-Marc.Voillequin@moodys.com>; David G. Johnston <david.g.johnston@gmail.com>;
pgsql-sql@lists.postgresql.org
Subject: Re: unique index with several columns

Alexey M Boltenkov <padrebolt@yandex.ru> writes:
> You need the new v15 feature:
> NULLS [NOT] DISTINCT

That won't replicate the behavior shown by the OP though.
In particular, not the weird inconsistency for all-null rows.

            regards, tom lane



RE: unique index with several columns

From
Klaus Kaisersberger
Date:
Here a usable example for an arbitrary number of columns (might require casting the columns to e.g. bit varying before
makingthe arrays):
 
Just replace c1,c2 with your (casted) number of columns on index creation.

create function fn(cs anyelement)
    returns int
    as
        'select count(1) from unnest(cs) t(c) where c is not null;'
    language sql
    immutable;


create unique index idx on t ((
    case
        when fn(ARRAY[c1,c2])=0 then null
        else ARRAY[c1,c2]
    end
));


Result:

db=# insert into t(c1,c2) values (null,null);
INSERT 0 1
db=# insert into t(c1,c2) values (null,null);
INSERT 0 1
db=# insert into t(c1,c2) values (null,null);
INSERT 0 1
db=# insert into t(c1,c2) values (1,null);
INSERT 0 1

db=# insert into t(c1,c2) values (1,null);
ERROR:  duplicate key value violates unique constraint "idx"
DETAIL:  Key ((
CASE
    WHEN fn(ARRAY[c1, c2]) = 0 THEN NULL::integer[]
    ELSE ARRAY[c1, c2]
END))=({1,NULL}) already exists.

db=# insert into t(c1,c2) values (null,1);
INSERT 0 1

db=# insert into t(c1,c2) values (null,1);
ERROR:  duplicate key value violates unique constraint "idx"
DETAIL:  Key ((
CASE
    WHEN fn(ARRAY[c1, c2]) = 0 THEN NULL::integer[]
    ELSE ARRAY[c1, c2]
END))=({NULL,1}) already exists.
db=# insert into t(c1,c2) values (null,2);
INSERT 0 1

db=# insert into t(c1,c2) values (null,2);
ERROR:  duplicate key value violates unique constraint "idx"
DETAIL:  Key ((
CASE
    WHEN fn(ARRAY[c1, c2]) = 0 THEN NULL::integer[]
    ELSE ARRAY[c1, c2]
END))=({NULL,2}) already exists.

Re: unique index with several columns

From
Alexey M Boltenkov
Date:
On 03/04/22 21:32, Tom Lane wrote:
> Alexey M Boltenkov <padrebolt@yandex.ru> writes:
>> You need the new v15 feature:
>> NULLS [NOT] DISTINCT
> That won't replicate the behavior shown by the OP though.
> In particular, not the weird inconsistency for all-null rows.
>
>             regards, tom lane
>

But why?

# create table t(c1 char, c2 char);
CREATE TABLE
# create unique index idx on t(c1,c2) nulls not distinct where c1 is not 
null or c2 is not null;
CREATE INDEX
# insert into t(c1,c2) values (null,null);
INSERT 0 1
# insert into t(c1,c2) values (null,null);
INSERT 0 1
# insert into t(c1,c2) values ('a',null);
INSERT 0 1
# insert into t(c1,c2) values ('a',null);
ERROR:  23505: duplicate key value violates unique constraint "idx"
DETAIL:  Key (c1, c2)=(a, null) already exists.
SCHEMA NAME:  public
TABLE NAME:  t
CONSTRAINT NAME:  idx
LOCATION:  _bt_check_unique, nbtinsert.c:664
# \d+ t
                                                Table "public.t"
  Column │     Type     │ Collation │ Nullable │ Default │ Storage │ 
Compression │ Stats target │ Description
════════╪══════════════╪═══════════╪══════════╪═════════╪══════════╪═════════════╪══════════════╪═════════════
  c1     │ character(1) │           │          │         │ extended 
│             │              │
  c2     │ character(1) │           │          │         │ extended 
│             │              │
Indexes:
     "idx" UNIQUE, btree (c1, c2) NULLS NOT DISTINCT WHERE c1 IS NOT 
NULL OR c2 IS NOT NULL
Access method: heap
# table t;
  c1 │ c2
════╪════
  ¤  │ ¤
  ¤  │ ¤
  a  │ ¤
(3 rows)




RE: unique index with several columns

From
"Voillequin, Jean-Marc"
Date:
Thanks a lot guys.

I'm waiting for the 15 release to implement Alexey solution.

But for now:
create unique index idx on t((array[c1,c2])) where not((c1,c2) is null);
will make the job

not((c1,c2) is null) is the tricky condition to check that not all fields are null...

Proof:
RRT=> create table t(c1 char,c2 char);
CREATE TABLE
RRT=> create unique index idx on t((array[c1,c2])) where not((c1,c2) is null);
CREATE INDEX
RRT=> insert into t values (null,null);
INSERT 0 1
RRT=> insert into t values (null,null);
INSERT 0 1
RRT=> insert into t values (null,'a');
INSERT 0 1
RRT=> insert into t values (null,'a');
ERROR:  duplicate key value violates unique constraint "idx"
DETAIL:  Key ((ARRAY[c1, c2]))=({NULL,a}) already exists.

Regards

-----Original Message-----
From: Alexey M Boltenkov <padrebolt@yandex.ru> 
Sent: Friday, March 4, 2022 9:47 PM
To: Tom Lane <tgl@sss.pgh.pa.us>
Cc: Voillequin, Jean-Marc <Jean-Marc.Voillequin@moodys.com>; David G. Johnston <david.g.johnston@gmail.com>;
pgsql-sql@lists.postgresql.org
Subject: Re: unique index with several columns

 

CAUTION: This email originated from outside of Moody's. Do not click links or open attachments unless you recognize the
senderand know the content is safe.
 

 

On 03/04/22 21:32, Tom Lane wrote:
> Alexey M Boltenkov <padrebolt@yandex.ru> writes:
>> You need the new v15 feature:
>> NULLS [NOT] DISTINCT
> That won't replicate the behavior shown by the OP though.
> In particular, not the weird inconsistency for all-null rows.
>
>             regards, tom lane
>

But why?

# create table t(c1 char, c2 char);
CREATE TABLE
# create unique index idx on t(c1,c2) nulls not distinct where c1 is not null or c2 is not null; CREATE INDEX # insert
intot(c1,c2) values (null,null); INSERT 0 1 # insert into t(c1,c2) values (null,null); INSERT 0 1 # insert into
t(c1,c2)values ('a',null); INSERT 0 1 # insert into t(c1,c2) values ('a',null);
 
ERROR:  23505: duplicate key value violates unique constraint "idx"
DETAIL:  Key (c1, c2)=(a, null) already exists.
SCHEMA NAME:  public
TABLE NAME:  t
CONSTRAINT NAME:  idx
LOCATION:  _bt_check_unique, nbtinsert.c:664 # \d+ t
                                                Table "public.t"
  Column │     Type     │ Collation │ Nullable │ Default │ Storage │ Compression │ Stats target │ Description
════════╪══════════════╪═══════════╪══════════╪═════════╪══════════╪═════════════╪══════════════╪═════════════
  c1     │ character(1) │           │          │         │ extended │             │              │
  c2     │ character(1) │           │          │         │ extended │             │              │
Indexes:
     "idx" UNIQUE, btree (c1, c2) NULLS NOT DISTINCT WHERE c1 IS NOT NULL OR c2 IS NOT NULL Access method: heap # table
t;
  c1 │ c2
════╪════
  ¤  │ ¤
  ¤  │ ¤
  a  │ ¤
(3 rows)

-----------------------------------------

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. 

-----------------------------------------