Re: index usage in not like - Mailing list pgsql-performance

From Kenneth Marshall
Subject Re: index usage in not like
Date
Msg-id 20100218122622.GD8639@it.is.rice.edu
Whole thread Raw
In response to Re: index usage in not like  ("A. Kretschmer" <andreas.kretschmer@schollglas.com>)
Responses Re: index usage in not like  ("A. Kretschmer" <andreas.kretschmer@schollglas.com>)
List pgsql-performance
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


pgsql-performance by date:

Previous
From: "A. Kretschmer"
Date:
Subject: Re: index usage in not like
Next
From: Thom Brown
Date:
Subject: Re: index usage in not like