Re: Any advice tuning this query ? - Mailing list pgsql-performance

From Jeff Janes
Subject Re: Any advice tuning this query ?
Date
Msg-id CAMkU=1wifZ_AHxv-KSrnvO0P8QzXk1TMQZKV-mypV_wu+qX_aw@mail.gmail.com
Whole thread Raw
In response to Any advice tuning this query ?  (Henrik Ekenberg <henrik@ekenberg.pw>)
List pgsql-performance
On Fri, Nov 11, 2016 at 7:19 AM, Henrik Ekenberg <henrik@ekenberg.pw> wrote:

Hi,

I have a select moving around a lot of data and takes times
Any advice tuning this query ?

EXPLAIN (ANALYZE ON, BUFFERS ON)


When accessing lots of data, sometimes the act of collecting timing on all of the actions makes the query take >2x times longer, or more, and distorts the timings it collects.

Try running the same query like:

EXPLAIN (ANALYZE ON, BUFFERS ON, timing off)

If the Execution times are very similar either way, then you don't have this problem.  But if they differ, then you can't depend on the results of the timings reported when timing is turned on.  Large sorts are particularly subject to this problem.

More than half the time (if the times are believable) goes to scanning the index activations_books_date.  You might be better off with a sort rather than an index scan.  You can test this by doing:

begin;
drop index activations_books_date;
<explain your query here>;
rollback;

Don't do that on production server, as it will block other access to the table for the duration.


You might also benefit from hash joins/aggregates, but you would have to set work_mem to a very large value get them.  I'd start by setting work_mem in your session to 1TB, and seeing if that changes the explain plan (just explain, not explain analyze!).  If that supports the hash joins/aggregates, then keeping lowering work_mem until you find the minimum that supports the hash plans.  Then ponder if it is safe to use that much work_mem "for real" given your RAM and level  of concurrent access.

Cheers,

Jeff

pgsql-performance by date:

Previous
From: "ldh@laurent-hasson.com"
Date:
Subject: Re: Inlining of functions (doing LIKE on an array)
Next
From: Tom Lane
Date:
Subject: Re: Inlining of functions (doing LIKE on an array)