performance drop after upgrade (9.6 > 10)

Started by johannes graënover 8 years ago13 messages
#1johannes graën
johannes@selfnet.de

Hi,

I wrote a query that joins several tables usually returning less than
1000 rows, groups them and generates a JSON object of the result. In
9.6 is was a question of milliseconds for that query to return the
requested data. Now, after upgrading to 10, the query never returns -
at least it hasn't returned in the last hour.

To see what happens, I requested the query plan [1]https://explain.depesz.com/s/xsPP. It looks complex
and shows a lot of parallelization. I don't have the query plan from
9.6, but I remember it being considerably simpler.

Can anyone have a guess what altered the performance here so
dramatically? Is there a way to disable new parallelization features
just for this query to see if it makes any difference?

Best
Johannes

[1]: https://explain.depesz.com/s/xsPP

--
Sent via pgsql-performance mailing list (pgsql-performance@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-performance

#2Pavel Stehule
pavel.stehule@gmail.com
In reply to: johannes graën (#1)
Re: performance drop after upgrade (9.6 > 10)

2017-10-11 13:06 GMT+02:00 johannes graën <johannes@selfnet.de>:

Hi,

I wrote a query that joins several tables usually returning less than
1000 rows, groups them and generates a JSON object of the result. In
9.6 is was a question of milliseconds for that query to return the
requested data. Now, after upgrading to 10, the query never returns -
at least it hasn't returned in the last hour.

To see what happens, I requested the query plan [1]. It looks complex
and shows a lot of parallelization. I don't have the query plan from
9.6, but I remember it being considerably simpler.

Can anyone have a guess what altered the performance here so
dramatically? Is there a way to disable new parallelization features
just for this query to see if it makes any difference?

have you fresh statistics? After upgrade is necessary to run ANALYZE command

Regards

Pavel

Best

Show quoted text

Johannes

[1] https://explain.depesz.com/s/xsPP

--
Sent via pgsql-performance mailing list (pgsql-performance@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-performance

#3johannes graën
johannes@selfnet.de
In reply to: Pavel Stehule (#2)
Re: performance drop after upgrade (9.6 > 10)

On Wed, Oct 11, 2017 at 1:11 PM, Pavel Stehule <pavel.stehule@gmail.com> wrote:

have you fresh statistics? After upgrade is necessary to run ANALYZE command

Yes, that was missing indeed. I did ANALYZE but apparently on all
databases but this one. I could have guessed that
1,098,956,679,131,935,754,413,282,631,696,252,928 is not a reasonable
cost value.

Thanks, Pavel.

Best
Johannes

--
Sent via pgsql-performance mailing list (pgsql-performance@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-performance

#4johannes graën
johannes@selfnet.de
In reply to: johannes graën (#3)
Re: performance drop after upgrade (9.6 > 10)

Hi Pavel, *,

you were right with ANALYZing the DB first. However, even after doing
so, I frequently see Seq Scans where an index was used before. This
usually cooccurs with parallelization and looked different before
upgrading to 10. I can provide an example for 10 [1]https://explain.depesz.com/s/gXD3, but I cannot
generate a query plan for 9.6 anymore.

Any ideas what makes the new version more seqscanny?

[1]: https://explain.depesz.com/s/gXD3

--
Sent via pgsql-performance mailing list (pgsql-performance@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-performance

#5Justin Pryzby
pryzby@telsasoft.com
In reply to: johannes graën (#4)
Re: performance drop after upgrade (9.6 > 10)

On Tue, Oct 24, 2017 at 04:15:59PM +0200, johannes gra�n wrote:

upgrading to 10. I can provide an example for 10 [1], but I cannot
generate a query plan for 9.6 anymore.

You could (re)install PG96 alongside PG10 and run a copy of the DB (even from
your homedir, or on a difference server) and pg_dump |pg_restore the relevant
tables (just be sure to specify the alternate host/port/user/etc as needed for
the restore invocation).

Justin

--
Sent via pgsql-performance mailing list (pgsql-performance@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-performance

#6Johannes Graën
johannes@selfnet.de
In reply to: Justin Pryzby (#5)
Re: performance drop after upgrade (9.6 > 10)

On 2017-10-24 17:18, Justin Pryzby wrote:

You could (re)install PG96 alongside PG10 and run a copy of the DB (even from
your homedir, or on a difference server) and pg_dump |pg_restore the relevant
tables (just be sure to specify the alternate host/port/user/etc as needed for
the restore invocation).

I considered that but it is far too expensive just for getting the old
query plan. The database is more than 1 TB big and replaying it from a
dump to another server took us several days, primarily due to the heavy
use of materialized views that are calculated over all rows of some
large tables. As long as there is no safe pg_downgrade --link I'd rather
keep trying to improve query performance on the current version.

--
Sent via pgsql-performance mailing list (pgsql-performance@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-performance

#7Alvaro Herrera
alvherre@alvh.no-ip.org
In reply to: johannes graën (#4)
Re: performance drop after upgrade (9.6 > 10)

johannes gra�n wrote:

Hi Pavel, *,

you were right with ANALYZing the DB first. However, even after doing
so, I frequently see Seq Scans where an index was used before. This
usually cooccurs with parallelization and looked different before
upgrading to 10. I can provide an example for 10 [1], but I cannot
generate a query plan for 9.6 anymore.

https://wiki.postgresql.org/wiki/Slow_Query_Questions

--
�lvaro Herrera https://www.2ndQuadrant.com/
PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services

--
Sent via pgsql-performance mailing list (pgsql-performance@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-performance

#8Justin Pryzby
pryzby@telsasoft.com
In reply to: johannes graën (#4)
Re: performance drop after upgrade (9.6 > 10)

On Tue, Oct 24, 2017 at 04:15:59PM +0200, johannes gra�n wrote:

Hi Pavel, *,

you were right with ANALYZing the DB first. However, even after doing
so, I frequently see Seq Scans where an index was used before. This
usually cooccurs with parallelization and looked different before
upgrading to 10. I can provide an example for 10 [1], but I cannot
generate a query plan for 9.6 anymore.

Any ideas what makes the new version more seqscanny?

Is it because max_parallel_workers_per_gather now defaults to 2 ?

BTW, I would tentatively expect a change in default to be documented in the
release notes but can't see that it's.
77cd477c4ba885cfa1ba67beaa82e06f2e182b85

Justin

--
Sent via pgsql-performance mailing list (pgsql-performance@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-performance

#9Bruce Momjian
bruce@momjian.us
In reply to: Justin Pryzby (#8)
Re: [PERFORM] performance drop after upgrade (9.6 > 10)

On Thu, Oct 26, 2017 at 02:45:15PM -0500, Justin Pryzby wrote:

On Tue, Oct 24, 2017 at 04:15:59PM +0200, johannes gra�n wrote:

Hi Pavel, *,

you were right with ANALYZing the DB first. However, even after doing
so, I frequently see Seq Scans where an index was used before. This
usually cooccurs with parallelization and looked different before
upgrading to 10. I can provide an example for 10 [1], but I cannot
generate a query plan for 9.6 anymore.

Any ideas what makes the new version more seqscanny?

Is it because max_parallel_workers_per_gather now defaults to 2 ?

BTW, I would tentatively expect a change in default to be documented in the
release notes but can't see that it's.
77cd477c4ba885cfa1ba67beaa82e06f2e182b85

Oops, you are correct. The PG 10 release notes, which I wrote, should
have mentioned this. :-(

https://www.postgresql.org/docs/10/static/release-10.html

--
Bruce Momjian <bruce@momjian.us> http://momjian.us
EnterpriseDB http://enterprisedb.com

+ As you are, so once was I.  As I am, so you will be. +
+                      Ancient Roman grave inscription +
#10Justin Pryzby
pryzby@telsasoft.com
In reply to: Bruce Momjian (#9)
add default parallel query to v10 release notes? (Re: [PERFORM] performance drop after upgrade (9.6 > 10))

Moving to -hackers;

On Sun, Jan 28, 2018 at 06:53:10PM -0500, Bruce Momjian wrote:

On Thu, Oct 26, 2017 at 02:45:15PM -0500, Justin Pryzby wrote:

Is it because max_parallel_workers_per_gather now defaults to 2 ?

BTW, I would tentatively expect a change in default to be documented in the
release notes but can't see that it's.
77cd477c4ba885cfa1ba67beaa82e06f2e182b85

Oops, you are correct. The PG 10 release notes, which I wrote, should
have mentioned this. :-(

I just saw your January response to my October mail..

Maybe it's silly to update PG10 notes 9 months after release..
..but, any reason not to add to v10 release notes now (I don't know if the web
docs would be updated until the next point release?)

Justin

#11Bruce Momjian
bruce@momjian.us
In reply to: Justin Pryzby (#10)
1 attachment(s)
Re: add default parallel query to v10 release notes? (Re: [PERFORM] performance drop after upgrade (9.6 > 10))

On Thu, May 24, 2018 at 08:00:25PM -0500, Justin Pryzby wrote:

Moving to -hackers;

On Sun, Jan 28, 2018 at 06:53:10PM -0500, Bruce Momjian wrote:

On Thu, Oct 26, 2017 at 02:45:15PM -0500, Justin Pryzby wrote:

Is it because max_parallel_workers_per_gather now defaults to 2 ?

BTW, I would tentatively expect a change in default to be documented in the
release notes but can't see that it's.
77cd477c4ba885cfa1ba67beaa82e06f2e182b85

Oops, you are correct. The PG 10 release notes, which I wrote, should
have mentioned this. :-(

I just saw your January response to my October mail..

Maybe it's silly to update PG10 notes 9 months after release..
..but, any reason not to add to v10 release notes now (I don't know if the web
docs would be updated until the next point release?)

So I did some research on this, particularly to find out how it was
missed in the PG 10 release notes. It turns out that
max_parallel_workers_per_gather has always defaulted to 2 in head, and
this was changed to default to 0 in the 9.6 branch:

commit f85b1a84152f7bf019fd7a2c5eede97867dcddbb
Author: Robert Haas <rhaas@postgresql.org>
Date: Tue Aug 16 08:09:15 2016 -0400

Disable parallel query by default.

Per discussion, set the default value of max_parallel_workers_per_gather
to 0 in 9.6 only. We'll leave it enabled in master so that it gets
more testing and in the hope that it can be enable by default in v10.

Therefore, there was no commit to find in the PG 10 commit logs. :-O
Not sure how we can avoid this kind of problem in the future.

The attached patch adds a PG 10.0 release note item about this change.
I put it at the bottom since it is newly added.

--
Bruce Momjian <bruce@momjian.us> http://momjian.us
EnterpriseDB http://enterprisedb.com

+ As you are, so once was I.  As I am, so you will be. +
+                      Ancient Roman grave inscription +

Attachments:

parallel.difftext/x-diff; charset=us-asciiDownload
diff --git a/doc/src/sgml/release-10.sgml b/doc/src/sgml/release-10.sgml
new file mode 100644
index ea86b5e..5862cd8
*** a/doc/src/sgml/release-10.sgml
--- b/doc/src/sgml/release-10.sgml
*************** Branch: REL_10_STABLE [5159626af] 2017-1
*** 4065,4070 ****
--- 4065,4081 ----
         </para>
        </listitem>
  
+       <listitem>
+ <!--
+ This was disabled in the PG 9.6 branch so there is no commit here.
+ -->
+        <para>
+         Enable parallelism by default by changing the default setting
+         of <xref linkend="guc-max-parallel-workers-per-gather"/> to
+         <literal>2</literal>.
+        </para>
+       </listitem>
+ 
       </itemizedlist>
  
      </sect4>
#12Amit Kapila
amit.kapila16@gmail.com
In reply to: Bruce Momjian (#11)
Re: add default parallel query to v10 release notes? (Re: [PERFORM] performance drop after upgrade (9.6 > 10))

On Wed, Jun 20, 2018 at 8:43 PM, Bruce Momjian <bruce@momjian.us> wrote:

On Thu, May 24, 2018 at 08:00:25PM -0500, Justin Pryzby wrote:

So I did some research on this, particularly to find out how it was
missed in the PG 10 release notes. It turns out that
max_parallel_workers_per_gather has always defaulted to 2 in head, and
this was changed to default to 0 in the 9.6 branch:

commit f85b1a84152f7bf019fd7a2c5eede97867dcddbb
Author: Robert Haas <rhaas@postgresql.org>
Date: Tue Aug 16 08:09:15 2016 -0400

Disable parallel query by default.

Per discussion, set the default value of max_parallel_workers_per_gather
to 0 in 9.6 only. We'll leave it enabled in master so that it gets
more testing and in the hope that it can be enable by default in v10.

Therefore, there was no commit to find in the PG 10 commit logs. :-O
Not sure how we can avoid this kind of problem in the future.

The attached patch adds a PG 10.0 release note item about this change.

Your proposed text looks good to me.

--
With Regards,
Amit Kapila.
EnterpriseDB: http://www.enterprisedb.com

#13Bruce Momjian
bruce@momjian.us
In reply to: Amit Kapila (#12)
Re: add default parallel query to v10 release notes? (Re: [PERFORM] performance drop after upgrade (9.6 > 10))

On Fri, Jun 22, 2018 at 02:53:36PM +0530, Amit Kapila wrote:

On Wed, Jun 20, 2018 at 8:43 PM, Bruce Momjian <bruce@momjian.us> wrote:

On Thu, May 24, 2018 at 08:00:25PM -0500, Justin Pryzby wrote:

So I did some research on this, particularly to find out how it was
missed in the PG 10 release notes. It turns out that
max_parallel_workers_per_gather has always defaulted to 2 in head, and
this was changed to default to 0 in the 9.6 branch:

commit f85b1a84152f7bf019fd7a2c5eede97867dcddbb
Author: Robert Haas <rhaas@postgresql.org>
Date: Tue Aug 16 08:09:15 2016 -0400

Disable parallel query by default.

Per discussion, set the default value of max_parallel_workers_per_gather
to 0 in 9.6 only. We'll leave it enabled in master so that it gets
more testing and in the hope that it can be enable by default in v10.

Therefore, there was no commit to find in the PG 10 commit logs. :-O
Not sure how we can avoid this kind of problem in the future.

The attached patch adds a PG 10.0 release note item about this change.

Your proposed text looks good to me.

Done, thanks.

--
Bruce Momjian <bruce@momjian.us> http://momjian.us
EnterpriseDB http://enterprisedb.com

+ As you are, so once was I.  As I am, so you will be. +
+                      Ancient Roman grave inscription +