Re: index usage in not like

From: "A(dot) Kretschmer" <andreas(dot)kretschmer(at)schollglas(dot)com>
To: pgsql-performance(at)postgresql(dot)org
Subject: Re: index usage in not like
Date: 2010-02-18 12:43:44
Message-ID: 20100218124344.GH23676@a-kretschmer.de
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-performance

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

In response to

Browse pgsql-performance by date

  From Date Subject
Next Message Jeff 2010-02-18 13:35:43 Re: bgwriter tunables vs pg_stat_bgwriter
Previous Message Thom Brown 2010-02-18 12:40:23 Re: index usage in not like