Thread: How can unique columns being case-insensitive be accomplished?

How can unique columns being case-insensitive be accomplished?

From
"Jörg"
Date:
Hi folks,

I got an problem that's being on my mind for a couple of days. I've thought
about different solution methods, but everything seems to be worse than the
problem itself.

I got a very simple lookup table with only one column 'name'. Its data type
is VarChar(50) and it's unique, so there can't be any duplicate entries.
Problems is that unique is case-sensitive. Germans tend to capitalize the
first letter of every word. But if anone doesn't do that, or if he
accidentially acps any letter, then this forms a new valid entry. So there
could be two entries representing the same thing, e.g 'Phenytoin' and
'phenytoin'.

How can this problem be overcome? Any ideas?

One solution I found is a before-trigger that checks whether the table
already contains a similar entry:

CREATE FUNCTION test_drug () RETURNS OPAQUE AS '   BEGIN      IF (SELECT name from drug WHERE lower(name) =
lower(NEW.name))ISNULL
 
THEN           RETURN NEW;      ELSE           RAISE EXCEPTION ''Lookup table cannot have duplicate entries'';      END
IF;  END;
 
' LANGUAGE 'plpgsql';

CREATE TRIGGER drug_insert BEFORE UPDATE OR INSERT ON drug FOR EACH ROW EXECUTE PROCEDURE test_drug();

This solution seems pretty complicated to me. Worst thing is that I have to
write a test function for every lookup table, since I don't know how to
place the lookup table's name in the SELECT-statement. Any ideas for that?


Greetings,
Joerg




Re: How can unique columns being case-insensitive be accomplished?

From
Tom Lane
Date:
"J�rg" <mail2holly@gmx.de> writes:
> How can this problem be overcome? Any ideas?

Create a unique index on lower(name).
        regards, tom lane


Re: How can unique columns being case-insensitive be accomplished?

From
"Ross J. Reedstrom"
Date:
On Mon, Sep 16, 2002 at 09:38:46AM -0400, Tom Lane wrote:
> "J�rg" <mail2holly@gmx.de> writes:
> > How can this problem be overcome? Any ideas?
> 
> Create a unique index on lower(name).

I'm sure J�rg can follow this tip, but for the archives, I'll include
the full syntax:

CREATE UNIQUE INDEX drug_lwr_idx ON drug ( lower(name) )

Another trick would be to use your trigger to lower() the inserted/updated
names, rather than only as a test, combined with a regular unique index:

CREATE FUNCTION lower_drug () RETURNS OPAQUE AS '   BEGIN       NEW.name = lower(NEW.name);RETURN NEW;   END;
' LANGUAGE 'plpgsql';

CREATE TRIGGER drug_insert BEFORE UPDATE OR INSERT ON drug FOR EACH ROW EXECUTE PROCEDURE lower_drug();

That keeps your data nice and clean and consistent, otherwise
the first time a MixedCaseDrugName goes in, it'll keep the correct
'mixedcasedrugname' from being inserted, later.  Be very sure that lower()
gives you exactly the output you want, however.

Ross