Re: LIKE query on indexes

From: "Ibrahim Tekin" <itekin(at)gmail(dot)com>
To: "Brendan Duddridge" <brendan(at)clickspace(dot)com>
Cc: "Scott Marlowe" <smarlowe(at)g2switchworks(dot)com>, pgsql-performance(at)postgresql(dot)org
Subject: Re: LIKE query on indexes
Date: 2006-02-23 12:52:35
Message-ID: e4dcba670602230452v58820b69n6dbbfcca8d6dadd@mail.gmail.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-performance

hi,

i ran a query with ILIKE but it doesn't use the index.

but i tried following method, and it worked. there is 3 extra lower()
overhead but i don't think it will effect the performance.

CREATE INDEX index_name ON mytable (lower(column) varchar_pattern_ops);

SELECT * FROM mytable WHERE lower(column) LIKE lower('beginswith%')

if insert operations are high in database. you use only this index to search
case sensitive.

say you want this:
SELECT * FROM mytable WHERE column LIKE 'beGinsWith%'

write this:
SELECT * FROM mytable WHERE lower(column) LIKE lower('beGinsWith%') AND
column LIKE 'beGinsWith%'

than query planner will search on index, than scan the resulting bitmap
heap.

On 2/22/06, Brendan Duddridge <brendan(at)clickspace(dot)com> wrote:
>
> Hi,
> Can this technique work with case insensitive ILIKE?
>
> It didn't seem to use the index when I used ILIKE instead of LIKE.
> Thanks,
> *
> *____________________________________________________________________
> *Brendan Duddridge* | CTO | 403-277-5591 x24 | brendan(at)clickspace(dot)com
> *
> *ClickSpace Interactive Inc.
> Suite L100, 239 - 10th Ave. SE
> Calgary, AB T2G 0V9
>
> http://www.clickspace.com
>
> On Feb 21, 2006, at 1:28 PM, Ibrahim Tekin wrote:
>
> this trick did the job.
> thanks.
>
> On 2/21/06, Alvaro Herrera <alvherre(at)commandprompt(dot)com> wrote:
> >
> > Scott Marlowe wrote:
> > > On Tue, 2006-02-21 at 09:57, Ibrahim Tekin wrote:
> > > > hi,
> > > > i have btree index on a text type field. i want see rows which
> > starts
> > > > with certain characters on that field. so i write a query like this:
> > > >
> > > > SELECT * FROM mytable WHERE myfield LIKE 'john%'
> > > >
> > > > since this condition is from start of the field, query planner
> > should
> > > > use index to find such elements but explain command shows me it will
> > > > do a sequential scan.
> > > >
> > > > is this lack of a feature or i am wrong somewhere?
> > >
> > > This is an artifact of how PostgreSQL handles locales other than
> > ASCII.
> > >
> > > If you want such a query to use an index, you need to back up your
> > > database, and re-initdb with --locale=C as an argument.
> >
> > ... or you can choose to create an index with the text_pattern_ops
> > operator class, which would be used in a LIKE constraint regardless of
> > locale.
> >
> > http://www.postgresql.org/docs/8.1/static/indexes-opclass.html
> >
> > --
> > Alvaro Herrera http://www.CommandPrompt.com/
> > The PostgreSQL Company - Command Prompt, Inc.
> >
>
>
>
>

In response to

Browse pgsql-performance by date

  From Date Subject
Next Message Ragnar 2006-02-23 13:03:26 Re: Created Index is not used
Previous Message Markus Schaber 2006-02-23 12:46:02 Re: Created Index is not used