Re: LIKE query on indexes

Lists: pgsql-performance
From: "Ibrahim Tekin" <itekin(at)gmail(dot)com>
To: pgsql-performance(at)postgresql(dot)org
Subject: LIKE query on indexes
Date: 2006-02-21 15:57:12
Message-ID: e4dcba670602210757n2caf7c15t2a93353c9081c51f@mail.gmail.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-performance

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?


From: Scott Marlowe <smarlowe(at)g2switchworks(dot)com>
To: Ibrahim Tekin <itekin(at)gmail(dot)com>
Cc: pgsql-performance(at)postgresql(dot)org
Subject: Re: LIKE query on indexes
Date: 2006-02-21 16:18:00
Message-ID: 1140538679.5777.3.camel@state.g2switchworks.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-performance

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. Note that you
then will NOT get locale specific matching and sorting.


From: Alvaro Herrera <alvherre(at)commandprompt(dot)com>
To: Scott Marlowe <smarlowe(at)g2switchworks(dot)com>
Cc: Ibrahim Tekin <itekin(at)gmail(dot)com>, pgsql-performance(at)postgresql(dot)org
Subject: Re: LIKE query on indexes
Date: 2006-02-21 16:34:16
Message-ID: 20060221163416.GC6541@surnet.cl
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-performance

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.


From: Scott Marlowe <smarlowe(at)g2switchworks(dot)com>
To: Alvaro Herrera <alvherre(at)commandprompt(dot)com>
Cc: Ibrahim Tekin <itekin(at)gmail(dot)com>, pgsql-performance(at)postgresql(dot)org
Subject: Re: LIKE query on indexes
Date: 2006-02-21 16:42:24
Message-ID: 1140540144.5777.5.camel@state.g2switchworks.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-performance

On Tue, 2006-02-21 at 10:34, Alvaro Herrera 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

Good point. I tend to view the world from the perspective of the 7.4
and before user...


From: mark(at)mark(dot)mielke(dot)cc
To: Ibrahim Tekin <itekin(at)gmail(dot)com>
Cc: pgsql-performance(at)postgresql(dot)org
Subject: Re: LIKE query on indexes
Date: 2006-02-21 17:40:48
Message-ID: 20060221174048.GA8108@mark.mielke.cc
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-performance

On Tue, Feb 21, 2006 at 05:57:12PM +0200, Ibrahim Tekin wrote:
> 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?

Is the query fast enough? How big is your table? What does explain
analyze select tell you?

Cheers,
mark

--
mark(at)mielke(dot)cc / markm(at)ncf(dot)ca / markm(at)nortel(dot)com __________________________
. . _ ._ . . .__ . . ._. .__ . . . .__ | Neighbourhood Coder
|\/| |_| |_| |/ |_ |\/| | |_ | |/ |_ |
| | | | | \ | \ |__ . | | .|. |__ |__ | \ |__ | Ottawa, Ontario, Canada

One ring to rule them all, one ring to find them, one ring to bring them all
and in the darkness bind them...

http://mark.mielke.cc/


From: "Ibrahim Tekin" <itekin(at)gmail(dot)com>
To: "mark(at)mark(dot)mielke(dot)cc" <mark(at)mark(dot)mielke(dot)cc>
Cc: pgsql-performance(at)postgresql(dot)org
Subject: Re: LIKE query on indexes
Date: 2006-02-21 20:12:17
Message-ID: e4dcba670602211212i523ad54bh404bc1097f90ef6f@mail.gmail.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-performance

my database encoding is unicode.
i have two table, one is 3.64gb on hdd and has 2.2 million records. it takes
140 secs to run on my AMD Turion 64 M 800MHz/1GB laptop.
second table is 1.2gb, 220000 records, and takes 56 secs to run.

explain says 'Seq Scan on mytable, ..'

On 2/21/06, mark(at)mark(dot)mielke(dot)cc <mark(at)mark(dot)mielke(dot)cc> wrote:
>
> On Tue, Feb 21, 2006 at 05:57:12PM +0200, Ibrahim Tekin wrote:
> > 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?
>
> Is the query fast enough? How big is your table? What does explain
> analyze select tell you?
>
> Cheers,
> mark
>
> --
> mark(at)mielke(dot)cc / markm(at)ncf(dot)ca / markm(at)nortel(dot)com
> __________________________
> . . _ ._ . . .__ . . ._. .__ . . . .__ | Neighbourhood Coder
> |\/| |_| |_| |/ |_ |\/| | |_ | |/ |_ |
> | | | | | \ | \ |__ . | | .|. |__ |__ | \ |__ | Ottawa, Ontario,
> Canada
>
> One ring to rule them all, one ring to find them, one ring to bring them
> all
> and in the darkness bind them...
>
> http://mark.mielke.cc/
>
>


From: "Ibrahim Tekin" <itekin(at)gmail(dot)com>
To: "Scott Marlowe" <smarlowe(at)g2switchworks(dot)com>, "Ibrahim Tekin" <itekin(at)gmail(dot)com>, pgsql-performance(at)postgresql(dot)org
Subject: Re: LIKE query on indexes
Date: 2006-02-21 20:28:09
Message-ID: e4dcba670602211228u2900be53mb0de28bd5e78b93f@mail.gmail.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-performance

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.
>


From: Brendan Duddridge <brendan(at)clickspace(dot)com>
To: Ibrahim Tekin <itekin(at)gmail(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-22 15:48:43
Message-ID: 78873B6F-1572-467C-8F98-9715FC8AC4AC@clickspace.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-performance

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.
>


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
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.
> >
>
>
>
>