Обсуждение: Performance of LIKE/NOT LIKE when used in single query

Поиск
Список
Период
Сортировка

Performance of LIKE/NOT LIKE when used in single query

От
Ed Felstein
Дата:
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?  I can accomplish this in a multi-step process by separating the single query into two queries, populating a temporary table with the results of the LIKEs, then running the NOT LIKEs on the temporary table.  For various reasons, this is not the ideal solution for me.
Or is there another approach that would accomplish the same thing with the same level of performance?

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

От
"David G. Johnston"
Дата:


On Wednesday, June 8, 2016, Ed Felstein <efelstein@gmail.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?  I can accomplish this in a multi-step process by separating the single query into two queries, populating a temporary table with the results of the LIKEs, then running the NOT LIKEs on the temporary table.  For various reasons, this is not the ideal solution for me.
Or is there another approach that would accomplish the same thing with the same level of performance?


Try AND...where col like '' and col not like ''

Or a CTE (with)

With likeqry as ( select where like )
Select from likeqry where not like

(sorry for brevity but not at a pc)

David J. 

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

От
Jeff Janes
Дата:
On Tue, Jun 7, 2016 at 9:57 PM, Ed Felstein <efelstein@gmail.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