From: | Richard Huxton <dev(at)archonet(dot)com> |
---|---|
To: | Kevin Houle <kevin(at)houle(dot)org>, pgsql-sql(at)postgresql(dot)org |
Subject: | Re: Dublicates pairs in a table. |
Date: | 2002-09-27 12:54:54 |
Message-ID: | 200209271354.54187.dev@archonet.com |
Views: | Raw Message | Whole Thread | Download mbox | Resend email |
Thread: | |
Lists: | pgsql-sql |
On Wednesday 25 Sep 2002 2:10 am, Kevin Houle wrote:
> I have the same issue with a table that currently holds well
> over 600,000 rows. The case you left out is this:
>
> INSERT INTO test (c1,c2) VALUES('a','c');
> INSERT INTO test (c1,c2) VALUES('c','a');
>
> I want that to fail, but I haven't been able to get it to fail
> using unique indexes. I presume ordering is significant. Instead,
> I am doing a SELECT prior to insert to insure the pair doesn't
> already exist. If you've been able to get order-independent
> pairs restricted to being unique using indexes, I'd like to know
> about it. :-)
Functional indexes sir - define a function that puts the columns into a sorted
order.
richardh=> CREATE TABLE foo (a text, b text);
CREATE
richardh=> CREATE UNIQUE INDEX foo_both_uniq ON foo ( ord_fn(a,b) );
ERROR: DefineIndex: index function must be marked iscachable
richardh=> \i ordfn.txt
DROP
CREATE
richardh=> CREATE UNIQUE INDEX foo_both_uniq ON foo ( ord_fn(a,b) );
CREATE
richardh=> insert into foo values ('aa','bb');
INSERT 332596 1
richardh=> insert into foo values ('aa','cc');
INSERT 332597 1
richardh=> insert into foo values ('bb','aa');
ERROR: Cannot insert a duplicate key into unique index foo_both_uniq
richardh=> insert into foo values ('aa','bb');
ERROR: Cannot insert a duplicate key into unique index foo_both_uniq
Function defined as:
CREATE FUNCTION ord_fn (text,text) RETURNS text AS '
SELECT (CASE
WHEN $1 < $2
THEN $1 || $2
ELSE $2 || $1
END) as t;
' LANGUAGE SQL WITH (iscachable);
--
Richard Huxton
From | Date | Subject | |
---|---|---|---|
Next Message | Mathieu Arnold | 2002-09-27 13:27:07 | Re: 7.3 schemas |
Previous Message | Ries van Twisk | 2002-09-27 12:40:06 | Re: Null not equal to '' (empty) |