Re: Performance of LIKE/NOT LIKE when used in single query

From: Jeff Janes <jeff(dot)janes(at)gmail(dot)com>
To: Ed Felstein <efelstein(at)gmail(dot)com>
Cc: "pgsql-performance(at)postgresql(dot)org" <pgsql-performance(at)postgresql(dot)org>
Subject: Re: Performance of LIKE/NOT LIKE when used in single query
Date: 2016-06-09 16:37:50
Message-ID: CAMkU=1wUJRXHf9YNWqC_KDywvmTYvmhvXq2oX+nzz5Z53YZH+A@mail.gmail.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-performance

On Tue, Jun 7, 2016 at 9:57 PM, Ed Felstein <efelstein(at)gmail(dot)com> wrote:
> Hello,
> First time poster here. Bear with me.
> Using PostgreSQL 9.5
> I have a situation where I have a LIKE and a NOT LIKE in the same query to
> identify strings in a varchar field. Since I am using wildcards, I have
> created a GIN index on the field in question, which makes LIKE '%xxxx%'
> searches run very fast. The problem is the NOT LIKE phrases, which (as
> would be expected) force a sequential scan. Being that we're talking about
> millions of records, this is not desirable.
> Here's the question...
> Is there a way, using a single query, to emulate the process of running the
> LIKE part first, then running the NOT LIKE just on those results?

Just do it. In my hands, the planner is smart enough to figure it out
for itself.

explain analyze select * from stuff where synonym like '%BAT%' and
synonym not like '%col not like%' ;

QUERY PLAN
-----------------------------------------------------------------------------------------------------------------------------------------
Bitmap Heap Scan on stuff (cost=16.10..63.08 rows=13 width=14)
(actual time=9.465..10.642 rows=23 loops=1)
Recheck Cond: (synonym ~~ '%BAT%'::text)
Rows Removed by Index Recheck: 76
Filter: (synonym !~~ '%col not like%'::text)
Heap Blocks: exact=57
-> Bitmap Index Scan on integrity_synonym_synonym_idx
(cost=0.00..16.10 rows=13 width=0) (actual time=8.847..8.847 rows=99
loops=1)
Index Cond: (synonym ~~ '%BAT%'::text)
Planning time: 18.261 ms
Execution time: 10.932 ms

So it is using the index for the positive match, and filtering those
results for the negative match, just as you wanted.

Cheers,

Jeff

In response to

Browse pgsql-performance by date

  From Date Subject
Next Message Merlin Moncure 2016-06-09 20:36:21 Re: array size exceeds the maximum allowed (1073741823) when building a json
Previous Message Glyn Astill 2016-06-09 15:32:42 Re: slony rpm help slony1-95-2.2.2-1.rhel6.x86_64