planner not using index for like operator

Lists: pgsql-performance
From: "Sriram Dandapani" <sdandapani(at)counterpane(dot)com>
To: "Pgsql-Performance \(E-mail\)" <pgsql-performance(at)postgresql(dot)org>
Subject: planner not using index for like operator
Date: 2006-04-25 17:08:02
Message-ID: 6992E470F12A444BB787B5C937B9D4DF0406B241@ca-mail1.cis.local
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-performance

For the query

Select col1 from table1

Where col1 like '172.%'

The table has 133 million unique ip addresses. Col1 is indexed.

The optimizer is using a sequential scan

This is the explain analyze output

"Seq Scan on table1 (cost=0.00..2529284.80 rows=1 width=15) (actual
time=307591.339..565251.775 rows=524288 loops=1)"

" Filter: ((col1)::text ~~ '172.%'::text)"

"Total runtime: 565501.873 ms"

The number of affected rows (500K) is a small fraction of the total row
count.


From: "Dave Dutcher" <dave(at)tridecap(dot)com>
To: "'Sriram Dandapani'" <sdandapani(at)counterpane(dot)com>, "'Pgsql-Performance \(E-mail\)'" <pgsql-performance(at)postgresql(dot)org>
Subject: Re: planner not using index for like operator
Date: 2006-04-25 18:03:13
Message-ID: 000001c66892$8583d040$8300a8c0@tridecap.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-performance

If you are using a locale other than the C locale, you need to create
the index with an operator class to get index scans with like.

See here for details:

http://www.postgresql.org/docs/8.1/interactive/indexes-opclass.html

-----Original Message-----
From: pgsql-performance-owner(at)postgresql(dot)org
[mailto:pgsql-performance-owner(at)postgresql(dot)org] On Behalf Of Sriram
Dandapani
Sent: Tuesday, April 25, 2006 12:08 PM
To: Pgsql-Performance (E-mail)
Subject: [PERFORM] planner not using index for like operator

For the query

Select col1 from table1

Where col1 like '172.%'

The table has 133 million unique ip addresses. Col1 is indexed.

The optimizer is using a sequential scan

This is the explain analyze output

"Seq Scan on table1 (cost=0.00..2529284.80 rows=1 width=15) (actual
time=307591.339..565251.775 rows=524288 loops=1)"

" Filter: ((col1)::text ~~ '172.%'::text)"

"Total runtime: 565501.873 ms"

The number of affected rows (500K) is a small fraction of the total row
count.


From: "Jim C(dot) Nasby" <jnasby(at)pervasive(dot)com>
To: Sriram Dandapani <sdandapani(at)counterpane(dot)com>
Cc: "Pgsql-Performance (E-mail)" <pgsql-performance(at)postgresql(dot)org>
Subject: Re: planner not using index for like operator
Date: 2006-04-25 18:24:45
Message-ID: 20060425182444.GK97354@pervasive.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-performance

On Tue, Apr 25, 2006 at 10:08:02AM -0700, Sriram Dandapani wrote:
Here's the key:

> " Filter: ((col1)::text ~~ '172.%'::text)"

In order to do a like comparison, it has to convert col1 (which I'm
guessing is of type 'inet') to text, so there's no way it can use an
index on col1 (maybe a function index, but that's a different story).

Is there some reason you're not doing

WHERE col1 <<= '172/8'::inet

?
--
Jim C. Nasby, Sr. Engineering Consultant jnasby(at)pervasive(dot)com
Pervasive Software http://pervasive.com work: 512-231-6117
vcard: http://jim.nasby.net/pervasive.vcf cell: 512-569-9461