Re: [SQL] Functional Indexes

From: Marc Howard Zuckman <marc(at)fallon(dot)classyad(dot)com>
To: Sascha Schumann <sas(at)schell(dot)de>
Cc: Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us>, Bryan White <bryan(at)arcamax(dot)com>, pgsql-sql(at)hub(dot)org, pgsql-hackers(at)postgreSQL(dot)org
Subject: Re: [SQL] Functional Indexes
Date: 1999-02-08 02:42:23
Message-ID: Pine.LNX.4.02A.9902072132100.20192-100000@fallon.classyad.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-hackers pgsql-sql

On Mon, 8 Feb 1999, Sascha Schumann wrote:

> On Sat, Feb 06, 1999 at 12:27:47PM -0500, Tom Lane wrote:
> > "Bryan White" <bryan(at)arcamax(dot)com> writes:
> > > The documentation for CREATE INDEX implies that functions are allowed in
> > > index definitions but when I execute:
> > > create unique index idxtest on customer (lower(email));
> > > the result is:
> > > ERROR: DefineIndex: (null) class not found
> > > Should this work? Do I have the syntax wrong?
> >
> > I tried this wih 6.4.2 and found that it was only accepted if I
> > explicitly identified which index operator class to use:
> >
> > play=> create table customer (email text);
> > CREATE
> > play=> create unique index idxtest on customer (lower(email));
> > ERROR: DefineIndex: class not found
> > play=> create unique index idxtest on customer (lower(email) text_ops);
> > CREATE
> > play=>
> >
> > That'll do as a workaround for Bryan, but isn't this a bug? Surely
> > the system ought to know what type the result of lower() is...
> >
> > regards, tom lane
>
> I still have a problem with that ... edited typescript follows
>
> funweb=> \d userdat
> Table = userdat
> +----------------------------------+----------------------------------+-------+
> | Field | Type | Length|
> +----------------------------------+----------------------------------+-------+
> | username | varchar() not null | 30 |
> ...
> +----------------------------------+----------------------------------+-------+
> Index: userdat_pkey
> funweb=> create unique index userdat_idx2 on userdat (lower(username)
> varchar_ops);
> ERROR: BuildFuncTupleDesc: function 'lower(varchar)' does not exist
>
> This error message looks very bogus to me.
>
> --
>
> Regards,
>
> Sascha Schumann |
> Consultant | finger sas(at)schell(dot)de
> | for PGP public key
>

I don't think lower is defined for varchar arguments. consider redefining
username as type text and using text_ops.

This method worked on my system:

stocks=> create table temptext (a text, b varchar(20));
CREATE
stocks=> create index itemptext on temptext using btree(lower(a) text_ops) ;
CREATE

Your error reproduced:

stocks=> create index i2temptext on temptext using btree(lower(b) text_ops) ;
ERROR: BuildFuncTupleDesc: function 'lower(varchar)' does not exist

Excerpt from function definitions( both return value and argument are text
types):

text |lower |text |lowercase

Marc Zuckman
marc(at)fallon(dot)classyad(dot)com

_\_\_\_\_\_\_\_\_\_\_\_\_\_\_\_\_\_\_\_\_\_\_\_\_\_\_\_\_\_\_\_
_ Visit The Home and Condo MarketPlace _
_ http://www.ClassyAd.com _
_ _
_ FREE basic property listings/advertisements and searches. _
_ _
_ Try our premium, yet inexpensive services for a real _
_ selling or buying edge! _
_\_\_\_\_\_\_\_\_\_\_\_\_\_\_\_\_\_\_\_\_\_\_\_\_\_\_\_\_\_\_\_

In response to

Browse pgsql-hackers by date

  From Date Subject
Next Message Bruce Momjian 1999-02-08 02:45:55 Re: [HACKERS] v6.4.3 ?
Previous Message Bruce Momjian 1999-02-08 02:41:47 Re: [HACKERS] v6.4.3 ?

Browse pgsql-sql by date

  From Date Subject
Next Message Tom Lane 1999-02-08 03:18:35 Re: [SQL] Functional Indexes
Previous Message Sascha Schumann 1999-02-08 00:28:26 Re: [SQL] Functional Indexes