Re: Slow Bitmap Index Scan

From: Scott Rankin <srankin(at)motus(dot)com>
To: Justin Pryzby <pryzby(at)telsasoft(dot)com>
Cc: "pgsql-performance(at)lists(dot)postgresql(dot)org" <pgsql-performance(at)lists(dot)postgresql(dot)org>, Eric Meaney <emeaney(at)motus(dot)com>
Subject: Re: Slow Bitmap Index Scan
Date: 2018-11-28 19:31:29
Message-ID: D6617547-272E-4274-900B-BD1ABFE40930@motus.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-performance


On 11/28/18, 2:18 PM, "Justin Pryzby" <pryzby(at)telsasoft(dot)com> wrote:

On Wed, Nov 28, 2018 at 07:08:53PM +0000, Scott Rankin wrote:
> We recently moved our production database systems from a 9.4 running on a self-managed EC2 instance to 9.6.10 on Amazon’s AWS (same RAM, CPU). After the move, we’re finding that certain queries that we run against a GIN full-text index have some occasionally very slow executions and I’m struggling to figure out what to do about it. I would be very grateful for any ideas!
>
> The setup we have is a 32-core, 244 GB RAM primary with a same-sized read replica. The queries are running off the replica, but performance is roughly the same between the master and the replica.
>
> Here’s a query that’s performing badly:

Can you compare or show the explain(analyze,buffers) for a fast query instance
vs slow query instance ? Is it slower due to index access or heap? Due to
cache misses ?

If I reduce the number of search terms in , I get this:

SELECT ls.location AS locationId FROM location_search ls WHERE ls.client = 83 AND search_field_tsvector @@ to_tsquery('9000:*'::text) AND ls.favorite = TRUE LIMIT 100

Limit (cost=13203.99..13627.40 rows=100 width=8) (actual time=66.568..66.759 rows=100 loops=1)
Buffers: shared hit=1975
-> Bitmap Heap Scan on location_search ls (cost=13203.99..13923.79 rows=170 width=8) (actual time=66.568..66.729 rows=100 loops=1)
Recheck Cond: ((search_field_tsvector @@ to_tsquery('9000:*'::text)) AND (client = 83))
Filter: favorite
Heap Blocks: exact=86
Buffers: shared hit=1975
-> BitmapAnd (cost=13203.99..13203.99 rows=170 width=0) (actual time=66.471..66.472 rows=0 loops=1)
Buffers: shared hit=1889
-> Bitmap Index Scan on location_search_tsvector_idx (cost=0.00..2235.02 rows=11570 width=0) (actual time=20.603..20.604 rows=29155 loops=1)
Index Cond: (search_field_tsvector @@ to_tsquery('9000:*'::text))
Buffers: shared hit=546
-> Bitmap Index Scan on location_search_client_idx (cost=0.00..10968.63 rows=442676 width=0) (actual time=40.682..40.682 rows=482415 loops=1)
Index Cond: (client = 83)
Buffers: shared hit=1343
Planning time: 0.181 ms
Execution time: 66.806 ms

I see almost no IO reads, and pg_stat_statements shows no cache misses.

Also, you have big ram - have you tried disabling KSM or THP ?
https://www.postgresql.org/message-id/20170718180152.GE17566%40telsasoft.com

Since this is Amazon RDS, we don't have any control over or access to the underlying OS. I know that huge_page support is on for these instances. I would hope that Amazon's already done that...

Justin

This email message contains information that Motus, LLC considers confidential and/or proprietary, or may later designate as confidential and proprietary. It is intended only for use of the individual or entity named above and should not be forwarded to any other persons or entities without the express consent of Motus, LLC, nor should it be used for any purpose other than in the course of any potential or actual business relationship with Motus, LLC. If the reader of this message is not the intended recipient, or the employee or agent responsible to deliver it to the intended recipient, you are hereby notified that any dissemination, distribution, or copying of this communication is strictly prohibited. If you have received this communication in error, please notify sender immediately and destroy the original message.

Internal Revenue Service regulations require that certain types of written advice include a disclaimer. To the extent the preceding message contains advice relating to a Federal tax issue, unless expressly stated otherwise the advice is not intended or written to be used, and it cannot be used by the recipient or any other taxpayer, for the purpose of avoiding Federal tax penalties, and was not written to support the promotion or marketing of any transaction or matter discussed herein.

In response to

Browse pgsql-performance by date

  From Date Subject
Next Message Justin Pryzby 2018-11-29 00:40:19 Re: Query with high planning time at version 11.1 compared versions 10.5 and 11.0
Previous Message Justin Pryzby 2018-11-28 19:17:53 Re: Slow Bitmap Index Scan