RE: unique index with several columns

From: "Voillequin, Jean-Marc" <Jean-Marc(dot)Voillequin(at)moodys(dot)com>
To: Alexey M Boltenkov <padrebolt(at)yandex(dot)ru>, Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us>
Cc: "David G(dot) Johnston" <david(dot)g(dot)johnston(at)gmail(dot)com>, "pgsql-sql(at)lists(dot)postgresql(dot)org" <pgsql-sql(at)lists(dot)postgresql(dot)org>
Subject: RE: unique index with several columns
Date: 2022-03-08 16:59:08
Message-ID: MN2PR20MB2735C1F889FB7BB615C1C317BE099@MN2PR20MB2735.namprd20.prod.outlook.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-sql

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(at)yandex(dot)ru>
Sent: Friday, March 4, 2022 9:47 PM
To: Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us>
Cc: Voillequin, Jean-Marc <Jean-Marc(dot)Voillequin(at)moodys(dot)com>; David G. Johnston <david(dot)g(dot)johnston(at)gmail(dot)com>; pgsql-sql(at)lists(dot)postgresql(dot)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 03/04/22 21:32, Tom Lane wrote:
> Alexey M Boltenkov <padrebolt(at)yandex(dot)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)

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

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.

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

In response to

Browse pgsql-sql by date

  From Date Subject
Next Message Sebastien Flaesch 2022-03-08 17:24:18 Re: Best practice for naming temp table trigger functions
Previous Message David G. Johnston 2022-03-08 16:16:13 Re: Best practice for naming temp table trigger functions