Lists: | pgsql-general |
---|
From: | Glen Huang <hey(dot)hgl(at)gmail(dot)com> |
---|---|
To: | pgsql-general(at)postgresql(dot)org |
Subject: | How to create unique index on multiple columns where the combination doesn't matter? |
Date: | 2017-03-22 16:54:34 |
Message-ID: | [email protected] |
Views: | Whole Thread | Raw Message | Download mbox | Resend email |
Lists: | pgsql-general |
Hello,
If I have a table like
CREATE TABLE relationship (
obj1 INTEGER NOT NULL REFERENCES object,
obj2 INTEGER NOT NULL REFERENCES object,
obj3 INTEGER NOT NULL REFERENCES object,
...
)
And I want to constrain that if 1,2,3 is already in the table, rows like 1,3,2 or 2,1,3 shouldn't be allowed.
Is there a general solution to this problem?
Sorry if the question is too basic, but I couldn't find the answer in the doc, at least not in the chapter on unique index.
From: | "David G(dot) Johnston" <david(dot)g(dot)johnston(at)gmail(dot)com> |
---|---|
To: | Glen Huang <hey(dot)hgl(at)gmail(dot)com> |
Cc: | "pgsql-general(at)postgresql(dot)org" <pgsql-general(at)postgresql(dot)org> |
Subject: | Re: How to create unique index on multiple columns where the combination doesn't matter? |
Date: | 2017-03-22 17:04:46 |
Message-ID: | CAKFQuwa9ZER4yPfXgHAoX18O_qTj07ZVKvkAPYVeajYyPzTd5w@mail.gmail.com |
Views: | Whole Thread | Raw Message | Download mbox | Resend email |
Lists: | pgsql-general |
On Wed, Mar 22, 2017 at 9:54 AM, Glen Huang <hey(dot)hgl(at)gmail(dot)com> wrote:
> Hello,
>
> If I have a table like
>
> CREATE TABLE relationship (
> obj1 INTEGER NOT NULL REFERENCES object,
> obj2 INTEGER NOT NULL REFERENCES object,
> obj3 INTEGER NOT NULL REFERENCES object,
> ...
> )
>
> And I want to constrain that if 1,2,3 is already in the table, rows like
> 1,3,2 or 2,1,3 shouldn't be allowed.
>
> Is there a general solution to this problem?
>
> Sorry if the question is too basic, but I couldn't find the answer in the
> doc, at least not in the chapter on unique index.
>
The most direct option to consider is a exclusion constraint.
https://www.postgresql.org/docs/current/static/ddl-constraints.html (bottom
of page)
David J.
From: | Glen Huang <hey(dot)hgl(at)gmail(dot)com> |
---|---|
To: | "David G(dot) Johnston" <david(dot)g(dot)johnston(at)gmail(dot)com> |
Cc: | Glen Huang <hey(dot)hgl(at)gmail(dot)com>, "pgsql-general(at)postgresql(dot)org" <pgsql-general(at)postgresql(dot)org> |
Subject: | Re: How to create unique index on multiple columns where the combination doesn't matter? |
Date: | 2017-03-23 03:53:22 |
Message-ID: | [email protected] |
Views: | Whole Thread | Raw Message | Download mbox | Resend email |
Lists: | pgsql-general |
Thanks.
Didn't realize it could be implemented with a exclusion constraint. The comparing between any two row definitely sounds like the right direction. But I'm still having a hard time figuring out how i should write the `exclude_element WITH operator` part, which I think, should detect if specified columns consist of the same items, regardless the order? could `exclude_element` contains multiple columns? (from the syntax it looks like it's impossible) And is there such an operator to compare multiple columns?
> On 23 Mar 2017, at 1:04 AM, David G. Johnston <david(dot)g(dot)johnston(at)gmail(dot)com> wrote:
>
> On Wed, Mar 22, 2017 at 9:54 AM, Glen Huang <hey(dot)hgl(at)gmail(dot)com <mailto:hey(dot)hgl(at)gmail(dot)com>> wrote:
> Hello,
>
> If I have a table like
>
> CREATE TABLE relationship (
> obj1 INTEGER NOT NULL REFERENCES object,
> obj2 INTEGER NOT NULL REFERENCES object,
> obj3 INTEGER NOT NULL REFERENCES object,
> ...
> )
>
> And I want to constrain that if 1,2,3 is already in the table, rows like 1,3,2 or 2,1,3 shouldn't be allowed.
>
> Is there a general solution to this problem?
>
> Sorry if the question is too basic, but I couldn't find the answer in the doc, at least not in the chapter on unique index.
>
> The most direct option to consider is a exclusion constraint.
>
> https://www.postgresql.org/docs/current/static/ddl-constraints.html <https://www.postgresql.org/docs/current/static/ddl-constraints.html> (bottom of page)
>
> David J.
From: | "David G(dot) Johnston" <david(dot)g(dot)johnston(at)gmail(dot)com> |
---|---|
To: | Glen Huang <hey(dot)hgl(at)gmail(dot)com> |
Cc: | "pgsql-general(at)postgresql(dot)org" <pgsql-general(at)postgresql(dot)org> |
Subject: | Re: How to create unique index on multiple columns where the combination doesn't matter? |
Date: | 2017-03-23 04:09:59 |
Message-ID: | CAKFQuwZvAtAeZeF82tGom9hOoz-g5oeBpbSLVPMMa2KUMm2BWw@mail.gmail.com |
Views: | Whole Thread | Raw Message | Download mbox | Resend email |
Lists: | pgsql-general |
Maybe try combining them into a single array then performing array
comparisons...
On Wednesday, March 22, 2017, Glen Huang <hey(dot)hgl(at)gmail(dot)com> wrote:
> Thanks.
>
> Didn't realize it could be implemented with a exclusion constraint. The
> comparing between any two row definitely sounds like the right direction.
> But I'm still having a hard time figuring out how i should write the
> `exclude_element WITH operator` part, which I think, should detect if
> specified columns consist of the same items, regardless the order? could
> `exclude_element` contains multiple columns? (from the syntax it looks like
> it's impossible) And is there such an operator to compare multiple columns?
>
> On 23 Mar 2017, at 1:04 AM, David G. Johnston <david(dot)g(dot)johnston(at)gmail(dot)com
> <javascript:_e(%7B%7D,'cvml','david(dot)g(dot)johnston(at)gmail(dot)com');>> wrote:
>
> On Wed, Mar 22, 2017 at 9:54 AM, Glen Huang <hey(dot)hgl(at)gmail(dot)com
> <javascript:_e(%7B%7D,'cvml','hey(dot)hgl(at)gmail(dot)com');>> wrote:
>
>> Hello,
>>
>> If I have a table like
>>
>> CREATE TABLE relationship (
>> obj1 INTEGER NOT NULL REFERENCES object,
>> obj2 INTEGER NOT NULL REFERENCES object,
>> obj3 INTEGER NOT NULL REFERENCES object,
>> ...
>> )
>>
>> And I want to constrain that if 1,2,3 is already in the table, rows like
>> 1,3,2 or 2,1,3 shouldn't be allowed.
>>
>> Is there a general solution to this problem?
>>
>> Sorry if the question is too basic, but I couldn't find the answer in the
>> doc, at least not in the chapter on unique index.
>>
>
> The most direct option to consider is a exclusion constraint.
>
> https://www.postgresql.org/docs/current/static/ddl-constraints.html
> (bottom of page)
>
> David J.
>
>
>
From: | Andreas Kretschmer <akretschmer(at)spamfence(dot)net> |
---|---|
To: | pgsql-general(at)postgresql(dot)org |
Subject: | Re: How to create unique index on multiple columns where the combination doesn't matter? |
Date: | 2017-03-23 06:01:44 |
Message-ID: | 20170323060144.GA5930@tux |
Views: | Whole Thread | Raw Message | Download mbox | Resend email |
Lists: | pgsql-general |
Glen Huang <hey(dot)hgl(at)gmail(dot)com> wrote:
> Hello,
>
> If I have a table like
>
> CREATE TABLE relationship (
> obj1 INTEGER NOT NULL REFERENCES object,
> obj2 INTEGER NOT NULL REFERENCES object,
> obj3 INTEGER NOT NULL REFERENCES object,
> ...
> )
>
> And I want to constrain that if 1,2,3 is already in the table, rows like 1,3,2 or 2,1,3 shouldn't be allowed.
>
> Is there a general solution to this problem?
Sure.
test=*# create extension intarray;
CREATE EXTENSION
test=*# create table foo(c1 int, c2 int, c3 int);
CREATE TABLE
test=*# create unique index index_unique_foo on
foo(sort(array[c1,c2,c3],'asc'));
CREATE INDEX
test=*# insert into foo values (1,2,3);
INSERT 0 1
test=*# insert into foo values (3,2,1);
FEHLER: doppelter Schlüsselwert verletzt Unique-Constraint
»index_unique_foo«
DETAIL: Schlüssel »(sort(ARRAY[c1, c2, c3], 'asc'::text))=({1,2,3})«
existiert bereits.
test=*#
(sorry for german messages, it means error, dublicate entry ...)
Regards, Andreas Kretschmer
--
Andreas Kretschmer
http://www.2ndQuadrant.com/
PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services
From: | Alban Hertroys <haramrae(at)gmail(dot)com> |
---|---|
To: | Glen Huang <hey(dot)hgl(at)gmail(dot)com> |
Cc: | pgsql-general(at)postgresql(dot)org |
Subject: | Re: How to create unique index on multiple columns where the combination doesn't matter? |
Date: | 2017-03-23 07:56:24 |
Message-ID: | [email protected] |
Views: | Whole Thread | Raw Message | Download mbox | Resend email |
Lists: | pgsql-general |
> On 22 Mar 2017, at 17:54, Glen Huang <hey(dot)hgl(at)gmail(dot)com> wrote:
>
> Hello,
>
> If I have a table like
>
> CREATE TABLE relationship (
> obj1 INTEGER NOT NULL REFERENCES object,
> obj2 INTEGER NOT NULL REFERENCES object,
> obj3 INTEGER NOT NULL REFERENCES object,
> ...
> )
>
> And I want to constrain that if 1,2,3 is already in the table, rows like 1,3,2 or 2,1,3 shouldn't be allowed.
>
> Is there a general solution to this problem?
Does the order of the values of (obj1, obj2, obj3) in relationship matter? If not, you could swap them around on INSERT/UPDATE to be in sorted order. I'd probably go with a BEFORE INSERT OR UPDATE trigger.
In addition, to prevent unsorted entry, on obj2 add CHECK (obj2 > obj1) and on obj3 add CHECK (obj3 > obj2).
Now you can create a normal PK or unique key on (obj1, obj2, obj3) as the order of their values is not variable anymore.
Alban Hertroys
--
If you can't see the forest for the trees,
cut the trees and you'll find there is no forest.
From: | Glen Huang <heyhgl(at)gmail(dot)com> |
---|---|
To: | Alban Hertroys <haramrae(at)gmail(dot)com> |
Cc: | pgsql-general(at)postgresql(dot)org |
Subject: | Re: How to create unique index on multiple columns where the combination doesn't matter? |
Date: | 2017-03-24 06:47:20 |
Message-ID: | [email protected] |
Views: | Whole Thread | Raw Message | Download mbox | Resend email |
Lists: | pgsql-general |
Yes, the order doesn't matter, and this approach sounds like a good idea. I'll try it out, thanks.
> On 23 Mar 2017, at 3:56 PM, Alban Hertroys <haramrae(at)gmail(dot)com> wrote:
>
>>
>> On 22 Mar 2017, at 17:54, Glen Huang <hey(dot)hgl(at)gmail(dot)com> wrote:
>>
>> Hello,
>>
>> If I have a table like
>>
>> CREATE TABLE relationship (
>> obj1 INTEGER NOT NULL REFERENCES object,
>> obj2 INTEGER NOT NULL REFERENCES object,
>> obj3 INTEGER NOT NULL REFERENCES object,
>> ...
>> )
>>
>> And I want to constrain that if 1,2,3 is already in the table, rows like 1,3,2 or 2,1,3 shouldn't be allowed.
>>
>> Is there a general solution to this problem?
>
> Does the order of the values of (obj1, obj2, obj3) in relationship matter? If not, you could swap them around on INSERT/UPDATE to be in sorted order. I'd probably go with a BEFORE INSERT OR UPDATE trigger.
>
> In addition, to prevent unsorted entry, on obj2 add CHECK (obj2 > obj1) and on obj3 add CHECK (obj3 > obj2).
>
> Now you can create a normal PK or unique key on (obj1, obj2, obj3) as the order of their values is not variable anymore.
>
> Alban Hertroys
> --
> If you can't see the forest for the trees,
> cut the trees and you'll find there is no forest.