Thread: Should from_collapse be switched off? (queries 10 times faster)
My queries get up to 10 times faster when I disable from_collapse (setting from_collapse_limit=1). After this finding, The pramatic solution is easy: it needs to be switched off. BUT: I found this perchance, accidentally (after the queries had been running for years). And this gives me some questions about documentation and best practices. I could not find any documentation or evaluation that would say that from_collapse can have detrimental effects. Even less, which type of queries may suffer from that. Since we cannot experimentally for all of our queries try out all kinds of options, if they might have significant (negative) effects, my understanding now is that, as a best practice, from_collapse should be switched off by default. And only after development it should be tested if activating it gives a positive improvement. Sadly, my knowledge does not reach into the internals. I can understand which *logical* result I should expect from an SQL statement. But I do not know how this is achieved internally. So, I have a very hard time when trying to understand output from EXPLAIN, or to make an educated guess on how the design of a query may influence execution strategy. I am usually happy when I found some SQL that would correctly produce the results I need. In short: I lack the experience to do manual optimization, or to see where manual optimization might be feasible. The manual section "Controlling the Planner with Explicit JOIN Clauses" gives a little discussion on the issue. But it seems only concerned about an increasing amount of cycles used for the planning activity, not about bad results from the optimization. Worse, it creates the impression that giving the planner maximum freedom is usually a good thing (at least until it takes too much cycles for the planner to evaluate all possibilities). In my case, planning uses 1 or 2% of the cycles needed for execution; that seems alright to me. And, as said above, I cannot see why my queries might be an atypical case (I don't think they are). If somebody would like to get a hands-on look onto the actual case, I'd be happy to put it online. rgds, PMc
Peter schrieb am 23.03.2018 um 11:03: > My queries get up to 10 times faster when I disable from_collapse > (setting from_collapse_limit=1). > > After this finding, The pramatic solution is easy: it needs to be > switched off. You should post some example queries together with the slow and fast plans. Ideally generated using "explain(analyze, buffers)" instead of a simple "explain" to see details on the execution Thomas
Peter wrote: > My queries get up to 10 times faster when I disable from_collapse > (setting from_collapse_limit=1). > > After this finding, The pramatic solution is easy: it needs to be > switched off. > > BUT: > I found this perchance, accidentally (after the queries had been > running for years). And this gives me some questions about > documentation and best practices. > > I could not find any documentation or evaluation that would say > that from_collapse can have detrimental effects. Even less, which > type of queries may suffer from that. https://www.postgresql.org/docs/current/static/explicit-joins.html states towards the end of the page that the search tree grows exponentially with the number of relations, and from_collapse_limit can be set to control that. > In my case, planning uses 1 or 2% of the cycles needed for > execution; that seems alright to me. > And, as said above, I cannot see why my queries might be an > atypical case (I don't think they are). > > If somebody would like to get a hands-on look onto the actual > case, I'd be happy to put it online. It seems like you are barking up the wrong tree. Your query does not take long because of the many relations in the FROM list, but because the optimizer makes a wrong choice. If you set from_collapse_limit to 1, you force the optimizer to join the tables in the order in which they appear in the query, and by accident this yields a better plan than the one generated if the optimizer is free to do what it thinks is best. The correct solution is *not* to set from_collapse_limit = 1, but to find and fix the problem that causes the optimizer to make a wrong choice. If you send the query and the output of EXPLAIN (ANALYZE, BUFFERS) SELECT ... we have a chance of telling you what's wrong. Yours, Laurenz Albe -- Cybertec | https://www.cybertec-postgresql.com
Laurenz Albe <laurenz.albe@cybertec.at> writes: > Peter wrote: >> I could not find any documentation or evaluation that would say >> that from_collapse can have detrimental effects. Even less, which >> type of queries may suffer from that. > https://www.postgresql.org/docs/current/static/explicit-joins.html > states towards the end of the page that the search tree grows > exponentially with the number of relations, and from_collapse_limit > can be set to control that. It's conceivable that the OP's problem is actually planning time (if the query joins sufficiently many tables) and that restricting the cost of the join plan search is really what he needs to do. Lacking any further information about the problem, we can't say. We can, however, point to https://wiki.postgresql.org/wiki/Slow_Query_Questions concerning how to ask this type of question effectively. regards, tom lane
The problem appeared when I found the queries suddenly taking longer than usual. Investigation showed that execution time greatly depends on the way the queries are invoked. Consider fn(x) simply a macro containing a plain SQL SELECT statement returning SETOF (further detail follows below): # SELECT fn(x); -> 6.3 sec. # SELECT a from fn(x) as a; -> 1.3 sec. Further investigation with auto_explain shows different plans being chosen. The slower one uses an Index Only Scan, which seems to perform bad. Slightly increasing random_page_cost solves this, but this seems the wrong way, because we are on SSD+ZFS, where random_page_cost actually should be DEcreased, as there is no difference if random or sequential. During this effort I accidentally came upon from_collapse_limit, and setting it off significantly changed things: # SET from_collapse_limit = 1; # SELECT fn(x); -> 0.6 sec. # SELECT a from fn(x) as a; -> 1.2 sec. The plans look different now (obviousely), and again the difference between the two invocations comes from an an Index Only Scan, but this time the Index Only Scan is faster. So now we can reduce random_page_cost in order to better reflect physical circumstances, and then both invocations will be fast. From here it looks like from_collapse is the problem. Now for the details: VACUUM ANALYZE is up to date, and all respective configurations are as default. The query itself contains three nested SELECTS working all on the same table. The table is 400'000 rows, 36 MB. (The machine is a pentium-3, which is my router - so don't be surprized about the comparatively long execution times.) This is the (critical part of the) query - let $1 be something like '2017-03-03': SELECT MAX(quotes.datum) AS ratedate, aktkurs.* FROM quotes, wpnames, places, (SELECT quotes.datum, close, quotes.wpname_id, places.waehrung FROM quotes, wpnames, places, (SELECT MAX(datum) AS datum, wpname_id FROM quotes WHERE datum <= $1 GROUP BY wpname_id) AS newest WHERE newest.datum = quotes.datum AND newest.wpname_id = quotes.wpname_id AND quotes.wpname_id = wpnames.id AND wpnames.place_id = places.id) AS aktkurs WHERE quotes.wpname_id = wpnames.id AND wpnames.place_id = places.id AND places.platz = 'WAEHR' AND wpnames.nummer = aktkurs.waehrung AND quotes.datum <= aktkurs.datum GROUP BY aktkurs.datum, aktkurs.close, aktkurs.wpname_id, aktkurs.waehrung Here are the (respective parts of the) tables: CREATE TABLE public.quotes -- rows = 405466, 36 MB ( id integer NOT NULL DEFAULT nextval('quotes_id_seq'::regclass), wpname_id integer NOT NULL, datum date NOT NULL, close double precision NOT NULL, CONSTRAINT quotes_pkey PRIMARY KEY (id), CONSTRAINT fk_rails_626c320689 FOREIGN KEY (wpname_id) REFERENCES public.wpnames (id) MATCH SIMPLE ON UPDATE NO ACTION ON DELETE NO ACTION ) CREATE INDEX quotes_wd_idx -- 8912 kB ON public.quotes USING btree (wpname_id, datum); CREATE TABLE public.wpnames -- rows = 357, 40 kB ( id integer NOT NULL DEFAULT nextval('wpnames_id_seq'::regclass), place_id integer NOT NULL, nummer text NOT NULL, name text NOT NULL, CONSTRAINT wpnames_pkey PRIMARY KEY (id), CONSTRAINT fk_rails_18eae07552 FOREIGN KEY (place_id) REFERENCES public.places (id) MATCH SIMPLE ON UPDATE NO ACTION ON DELETE NO ACTION ) CREATE TABLE public.places -- rows = 11, 8192 b ( id integer NOT NULL DEFAULT nextval('places_id_seq'::regclass), platz text NOT NULL, text text, waehrung character varying(3) NOT NULL, CONSTRAINT places_pkey PRIMARY KEY (id) ) Hint: the quotes table contains daily stock quotes AND forex quotes, and what the thing does is fetch the newest quotes before a given date (inmost SELECT), fetch the respective currency ("waehrung") from wpnames+places (next SELECT), and fetch the (date of the) respective newest forex quote (last SELECT). (A final outermost fourth select will then put it all together, but thats not part of the problem.) Finally, the execution plans: 6 sec. index only scan with from_collapse: https://explain.depesz.com/s/IPaT 1.3 sec. seq scan with from_collapse: https://explain.depesz.com/s/Bxys 1.2 sec. seq scan w/o from_collapse: https://explain.depesz.com/s/V02L 0.6 sec. index only scan w/o from_collapse: https://explain.depesz.com/s/8Xh Addendum: from the Guides for the mailing list, supplemental information as requested. As this concerns planner strategy, which is influenced by statistics, it appears difficult to me to create a proper test-case, because I would need to know from where the planner fetches the decision-relevant information - which is exactly my question: how does it get the clue to choose the bad plans? CPU: Intel Pentium III (945.02-MHz 686-class CPU) avail memory = 2089263104 (1992 MB) FreeBSD 11.1-RELEASE-p7 PostgreSQL 9.5.7 on i386-portbld-freebsd11.1, compiled by FreeBSD clang version 4.0.0 (tags/RELEASE_400/final 297347) (basedon LLVM 4.0.0), 32-bit name | current_setting | source ------------------------------+----------------------------------------+-------------------- application_name | psql | client archive_command | ~pgsql/autojobs/RedoLog.copy "%f" "%p" | configuration file archive_mode | on | configuration file autovacuum | off | configuration file autovacuum_naptime | 5min | configuration file checkpoint_completion_target | 0 | configuration file checkpoint_timeout | 10min | configuration file client_encoding | UTF8 | client DateStyle | German, DMY | configuration file default_text_search_config | pg_catalog.german | configuration file dynamic_shared_memory_type | posix | configuration file effective_cache_size | 1GB | configuration file effective_io_concurrency | 2 | configuration file full_page_writes | off | configuration file lc_messages | en_US.UTF-8 | configuration file lc_monetary | en_US.UTF-8 | configuration file lc_numeric | en_US.UTF-8 | configuration file lc_time | de_DE.UTF-8 | configuration file listen_addresses | 192.168.97.9,192.168.97.17 | configuration file log_checkpoints | on | configuration file log_connections | on | configuration file log_destination | syslog | configuration file log_disconnections | on | configuration file log_error_verbosity | terse | configuration file log_line_prefix | %u:%d[%r] | configuration file log_lock_waits | on | configuration file log_min_duration_statement | 1min | configuration file log_min_messages | info | configuration file log_temp_files | 10000kB | configuration file maintenance_work_mem | 350MB | configuration file max_connections | 60 | configuration file max_files_per_process | 200 | configuration file max_stack_depth | 60MB | configuration file max_wal_size | 1GB | configuration file min_wal_size | 80MB | configuration file shared_buffers | 180MB | configuration file synchronous_commit | on | configuration file temp_buffers | 80MB | configuration file unix_socket_permissions | 0777 | configuration file wal_buffers | 256kB | configuration file wal_level | archive | configuration file wal_writer_delay | 2s | configuration file work_mem | 350MB | configuration file
On Fri, Mar 23, 2018 at 12:41:35PM +0100, Laurenz Albe wrote: ! https://www.postgresql.org/docs/current/static/explicit-joins.html ! states towards the end of the page that the search tree grows ! exponentially with the number of relations, and from_collapse_limit ! can be set to control that. Yes, I read that page. ! > In my case, planning uses 1 or 2% of the cycles needed for ! > execution; that seems alright to me. ! > And, as said above, I cannot see why my queries might be an ! > atypical case (I don't think they are). ! > ! > If somebody would like to get a hands-on look onto the actual ! > case, I'd be happy to put it online. ! ! It seems like you are barking up the wrong tree. ! ! Your query does not take long because of the many relations in the ! FROM list, but because the optimizer makes a wrong choice. Exactly! And I am working hard in order to understand WHY this happens. ! The correct solution is *not* to set from_collapse_limit = 1, but ! to find and fix the problem that causes the optimizer to make a ! wrong choice. ! ! If you send the query and the output of ! EXPLAIN (ANALYZE, BUFFERS) SELECT ... ! we have a chance of telling you what's wrong. Your viewpoint would be preferrable, only I am lacking any idea on where there could be such a problem that would make up a root cause. I will gladly follow Your suggestion; data is underway. P.
On Fri, Mar 23, 2018 at 10:14:19AM -0400, Tom Lane wrote: ! It's conceivable that the OP's problem is actually planning time ! (if the query joins sufficiently many tables) and that restricting ! the cost of the join plan search is really what he needs to do. Negative. Plnning time 10 to 27 ms. Execution time 600 to 6300 ms. ! Lacking any further information about the problem, we can't say. ! We can, however, point to ! https://wiki.postgresql.org/wiki/Slow_Query_Questions ! concerning how to ask this type of question effectively. I strongly hope the data that I sent as followup will now suffice Your expectations. rgds, PMc
Peter wrote: > On Fri, Mar 23, 2018 at 10:14:19AM -0400, Tom Lane wrote: > > ! It's conceivable that the OP's problem is actually planning time > ! (if the query joins sufficiently many tables) and that restricting > ! the cost of the join plan search is really what he needs to do. > > Negative. Plnning time 10 to 27 ms. Execution time 600 to 6300 ms. > > ! Lacking any further information about the problem, we can't say. > ! We can, however, point to > ! https://wiki.postgresql.org/wiki/Slow_Query_Questions > ! concerning how to ask this type of question effectively. > > I strongly hope the data that I sent as followup will now > suffice Your expectations. Your reported execution times don't match the time reported in the EXPLAIN output... The cause of the long execution time is clear: The row count of the join between "places" (WHERE platz = 'WAEHR'), "wpnames" and "places AS places_1" is underestimated by a factor of 10 (1 row instead of 10). The nested loop join that is chosen as a consequence is now executed 10 times instead of the estimated 1 time, which is where almost all the execution time is spent. The question how to fix that is more complicated, and I cannot solve it off-hand with a complicated query like that. Setting "enable_nestloop = off" is as coarse as forcing "from_collapse = 1" and will negatively impact other queries - if it helps at all. You'll probably have to rewrite the query. Sorry that I cannot be of more help. Yours, Laurenz Albe -- Cybertec | https://www.cybertec-postgresql.com
Laurenz, thank You very much for Your comments! On Sun, Mar 25, 2018 at 07:12:08AM +0200, Laurenz Albe wrote: ! Your reported execution times don't match the time reported in the ! EXPLAIN output... Should these match? It seems the EXPLAIN (ANALYZE, BUFFERS) does additional things, not just execute the query. ! The cause of the long execution time is clear: ! ! The row count of the join between "places" (WHERE platz = 'WAEHR'), ! "wpnames" and "places AS places_1" is underestimated by a factor of 10 ! (1 row instead of 10). ! ! The nested loop join that is chosen as a consequence is now executed ! 10 times instead of the estimated 1 time, which is where almost all the ! execution time is spent. I've seen this, but do not fully understand it yet. ! Setting "enable_nestloop = off" is as coarse as forcing "from_collapse = 1" ! and will negatively impact other queries - if it helps at all. Since this query is already put into a function, I found I can easily set from_collapse=1 only for this function, by means of "ALTER FUNCTION ... SET ...", so it does only influence this query. It seems this is the most straight-forward solution here. rgds, P.
Peter wrote: > ! Your reported execution times don't match the time reported in the > ! EXPLAIN output... > > Should these match? > It seems the EXPLAIN (ANALYZE, BUFFERS) does additional things, not > just execute the query. True. I had assumed you were speaking about the duration of the EXPLAIN (ANALYZE). > ! Setting "enable_nestloop = off" is as coarse as forcing "from_collapse = 1" > ! and will negatively impact other queries - if it helps at all. > > Since this query is already put into a function, I found I can easily > set from_collapse=1 only for this function, by means of "ALTER > FUNCTION ... SET ...", so it does only influence this query. > It seems this is the most straight-forward solution here. It is an option, although not one that makes one happy. You might have to revisit the decision if the data distribution changes and the chosen query plan becomes inefficient. Yours, Laurenz Albe -- Cybertec | https://www.cybertec-postgresql.com