Thread: index usage in not like
"Not like" operation does not use index.
select * from vtiger_contactscf where lower(cf_1253) not like lower('Former%')
I created index on lower(cf_1253).
How can I ensure index usage in not like operation?
Anyone please help.
On 18 February 2010 11:55, AI Rumman <rummandba@gmail.com> wrote: > "Not like" operation does not use index. > > select * from vtiger_contactscf where lower(cf_1253) not like > lower('Former%') > > I created index on lower(cf_1253). > > How can I ensure index usage in not like operation? > Anyone please help. > How many rows do you have in your table? If there are relatively few, it probably guesses it to be cheaper to do a sequential scan and calculate lower values on-the-fly rather than bother with the index. Thom
> On Thu, Feb 18, 2010 at 6:00 PM, Thom Brown <thombrown@gmail.com> wrote: >> >> On 18 February 2010 11:55, AI Rumman <rummandba@gmail.com> wrote: >> > "Not like" operation does not use index. >> > >> > select * from vtiger_contactscf where lower(cf_1253) not like >> > lower('Former%') >> > >> > I created index on lower(cf_1253). >> > >> > How can I ensure index usage in not like operation? >> > Anyone please help. >> > >> >> How many rows do you have in your table? If there are relatively few, >> it probably guesses it to be cheaper to do a sequential scan and >> calculate lower values on-the-fly rather than bother with the index. >> >> Thom > On 18 February 2010 12:06, AI Rumman <rummandba@gmail.com> wrote: > vtigercrm504=# explain analyze select * from vtiger_contactscf where > lower(cf_1253) like 'customer'; > > QUERY > PLAN > ------------------------------------------------------------------------------------------------------------------------------------------------------------ > Index Scan using vtiger_contactscf_cf_1253_idx on vtiger_contactscf > (cost=0.00..146.54 rows=6093 width=179) (actual time=0.083..29.868 rows=5171 > loops=1) > Index Cond: (lower((cf_1253)::text) ~=~ 'customer'::character varying) > Filter: (lower((cf_1253)::text) ~~ 'customer'::text) > Total runtime: 34.956 ms > (4 rows) > vtigercrm504=# explain analyze select * from vtiger_contactscf where > lower(cf_1253) like 'customer'; > > QUERY > PLAN > ------------------------------------------------------------------------------------------------------------------------------------------------------------ > Index Scan using vtiger_contactscf_cf_1253_idx on vtiger_contactscf > (cost=0.00..146.54 rows=6093 width=179) (actual time=0.083..29.868 rows=5171 > loops=1) > Index Cond: (lower((cf_1253)::text) ~=~ 'customer'::character varying) > Filter: (lower((cf_1253)::text) ~~ 'customer'::text) > Total runtime: 34.956 ms > (4 rows) Could you do the same again for a "not like" query? Thom
In response to Thom Brown : > On 18 February 2010 11:55, AI Rumman <rummandba@gmail.com> wrote: > > "Not like" operation does not use index. > > > > select * from vtiger_contactscf where lower(cf_1253) not like > > lower('Former%') > > > > I created index on lower(cf_1253). > > > > How can I ensure index usage in not like operation? > > Anyone please help. > > > > How many rows do you have in your table? If there are relatively few, > it probably guesses it to be cheaper to do a sequential scan and > calculate lower values on-the-fly rather than bother with the index. That's one reason, an other reason, i think, is, that a btree-index can't search with an 'not like' - operator. test=*# insert into words select 'fucking example' from generate_series(1,10000); INSERT 0 10000 test=*# insert into words select 'abc' from generate_series(1,10); INSERT 0 10 test=*# explain select * from words where lower(w) like lower('a%') or lower(w) like lower('b%'); QUERY PLAN ------------------------------------------------------------------------------------- Bitmap Heap Scan on words (cost=1538.75..6933.39 rows=55643 width=36) Recheck Cond: ((lower(w) ~~ 'a%'::text) OR (lower(w) ~~ 'b%'::text)) Filter: ((lower(w) ~~ 'a%'::text) OR (lower(w) ~~ 'b%'::text)) -> BitmapOr (cost=1538.75..1538.75 rows=57432 width=0) -> Bitmap Index Scan on idx_words (cost=0.00..1027.04 rows=39073 width=0) Index Cond: ((lower(w) ~>=~ 'a'::text) AND (lower(w) ~<~ 'b'::text)) -> Bitmap Index Scan on idx_words (cost=0.00..483.90 rows=18359 width=0) Index Cond: ((lower(w) ~>=~ 'b'::text) AND (lower(w) ~<~ 'c'::text)) (8 rows) test=*# explain select * from words where lower(w) not like lower('a%') or lower(w) like lower('b%'); QUERY PLAN ------------------------------------------------------------------- Seq Scan on words (cost=0.00..10624.48 rows=282609 width=36) Filter: ((lower(w) !~~ 'a%'::text) OR (lower(w) ~~ 'b%'::text)) (2 rows) In other words: revert your where-condition from 'not like' to multiple 'like' conditions for all letters except 'f%'. Andreas -- Andreas Kretschmer Kontakt: Heynitz: 035242/47150, D1: 0160/7141639 (mehr: -> Header) GnuPG: 0x31720C99, 1006 CCB4 A326 1D42 6431 2EB0 389D 1DC2 3172 0C99
On Thu, Feb 18, 2010 at 01:18:10PM +0100, A. Kretschmer wrote: > In response to Thom Brown : > > On 18 February 2010 11:55, AI Rumman <rummandba@gmail.com> wrote: > > > "Not like" operation does not use index. > > > > > > select * from vtiger_contactscf where lower(cf_1253) not like > > > lower('Former%') > > > > > > I created index on lower(cf_1253). > > > > > > How can I ensure index usage in not like operation? > > > Anyone please help. > > > > > > > How many rows do you have in your table? If there are relatively few, > > it probably guesses it to be cheaper to do a sequential scan and > > calculate lower values on-the-fly rather than bother with the index. > > That's one reason, an other reason, i think, is, that a btree-index can't > search with an 'not like' - operator. > > > > test=*# insert into words select 'fucking example' from generate_series(1,10000); > INSERT 0 10000 > test=*# insert into words select 'abc' from generate_series(1,10); > INSERT 0 10 > test=*# explain select * from words where lower(w) like lower('a%') or lower(w) like lower('b%'); > QUERY PLAN > ------------------------------------------------------------------------------------- > Bitmap Heap Scan on words (cost=1538.75..6933.39 rows=55643 width=36) > Recheck Cond: ((lower(w) ~~ 'a%'::text) OR (lower(w) ~~ 'b%'::text)) > Filter: ((lower(w) ~~ 'a%'::text) OR (lower(w) ~~ 'b%'::text)) > -> BitmapOr (cost=1538.75..1538.75 rows=57432 width=0) > -> Bitmap Index Scan on idx_words (cost=0.00..1027.04 rows=39073 width=0) > Index Cond: ((lower(w) ~>=~ 'a'::text) AND (lower(w) ~<~ 'b'::text)) > -> Bitmap Index Scan on idx_words (cost=0.00..483.90 rows=18359 width=0) > Index Cond: ((lower(w) ~>=~ 'b'::text) AND (lower(w) ~<~ 'c'::text)) > (8 rows) > > test=*# explain select * from words where lower(w) not like lower('a%') or lower(w) like lower('b%'); > QUERY PLAN > ------------------------------------------------------------------- > Seq Scan on words (cost=0.00..10624.48 rows=282609 width=36) > Filter: ((lower(w) !~~ 'a%'::text) OR (lower(w) ~~ 'b%'::text)) > (2 rows) > > > In other words: revert your where-condition from 'not like' to multiple 'like' conditions for all letters except 'f%'. > > > Andreas The 'not like' condition is likely to be extremely non-selective which would cause a sequential scan to be used in any event whether or not an index could be used. Cheers, Ken
On 18 February 2010 12:18, A. Kretschmer <andreas.kretschmer@schollglas.com> wrote: > In response to Thom Brown : >> On 18 February 2010 11:55, AI Rumman <rummandba@gmail.com> wrote: >> > "Not like" operation does not use index. >> > >> > select * from vtiger_contactscf where lower(cf_1253) not like >> > lower('Former%') >> > >> > I created index on lower(cf_1253). >> > >> > How can I ensure index usage in not like operation? >> > Anyone please help. >> > >> >> How many rows do you have in your table? If there are relatively few, >> it probably guesses it to be cheaper to do a sequential scan and >> calculate lower values on-the-fly rather than bother with the index. > > That's one reason, an other reason, i think, is, that a btree-index can't > search with an 'not like' - operator. > Erm.. yes. Now that you say it, it's obvious. :S Thom
In response to Kenneth Marshall : > > > How many rows do you have in your table? If there are relatively few, > > > it probably guesses it to be cheaper to do a sequential scan and > > > calculate lower values on-the-fly rather than bother with the index. > > > > That's one reason, an other reason, i think, is, that a btree-index can't > > search with an 'not like' - operator. > > The 'not like' condition is likely to be extremely non-selective > which would cause a sequential scan to be used in any event whether > or not an index could be used. That's true, but i have an example where the 'not like' condition is extremely selective: ,----[ sql ] | test=*# select count(1) from words where lower(w) not like lower('f%'); | count | ------- | 10 | (1 row) | | test=*# select count(1) from words where lower(w) like lower('f%'); | count | ------- | 10000 | (1 row) `---- But the index can't use: ,----[ code ] | test=*# explain select * from words where lower(w) not like lower('f%'); | QUERY PLAN | ---------------------------------------------------------- | Seq Scan on words (cost=0.00..4396.15 rows=10 width=47) | Filter: (lower(w) !~~ 'f%'::text) | (2 rows) `---- And i think, the reason is: ,----[ quote from docu ] | B-trees can handle equality and range queries on data that can be sorted | into some ordering. In particular, the PostgreSQL query planner will | consider using a B-tree index whenever an indexed column is involved in | a comparison using one of these operators: | | < | <= | = | >= | > `---- Regards, Andreas -- Andreas Kretschmer Kontakt: Heynitz: 035242/47150, D1: 0160/7141639 (mehr: -> Header) GnuPG: 0x31720C99, 1006 CCB4 A326 1D42 6431 2EB0 389D 1DC2 3172 0C99