Re: best practices with index on varchar column

From: Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us>
To: PFC <lists(at)boutiquenumerique(dot)com>
Cc: "Layet Benjamin" <benjamin(at)moonfactory(dot)co(dot)jp>, pgsql-performance(at)postgresql(dot)org
Subject: Re: best practices with index on varchar column
Date: 2005-03-22 18:08:14
Message-ID: 10502.1111514894@sss.pgh.pa.us
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-performance

PFC <lists(at)boutiquenumerique(dot)com> writes:
>> Can I use an index on a varchar column to optimize the SELECT queries
>> that use " column LIKE 'header%' "?

> Yes

> Note that if you want case insensitive matching you need to make an index
> on lower(column) and SELECT WHERE lower(column) LIKE 'header%'

> Locales may bite you.

Yes. If your database locale is not "C" then the default btree index
behavior does not match up with what LIKE needs. In that case you need
a special index using the appropriate "pattern_ops" opclass, eg

CREATE INDEX test_index ON test_table (col varchar_pattern_ops);

or if you want case insensitive matching

CREATE INDEX test_index ON test_table (lower(col) varchar_pattern_ops);

and then write the queries with lower() as PFC illustrates. *Don't* use
ILIKE --- it basically can't use indexes at all.

For more info see
http://www.postgresql.org/docs/8.0/static/indexes-opclass.html

regards, tom lane

In response to

Browse pgsql-performance by date

  From Date Subject
Next Message Patrick Vedrines 2005-03-22 18:08:23 CPU 0.1% IOWAIT 99% for decisonnal queries
Previous Message Richard Huxton 2005-03-22 17:53:05 Re: What about utility to calculate planner cost constants?