]> granicus.if.org Git - postgresql/commitdiff
Fix O(N^2) performance issue in pg_publication_tables view.
authorTom Lane <tgl@sss.pgh.pa.us>
Wed, 22 May 2019 15:46:57 +0000 (11:46 -0400)
committerTom Lane <tgl@sss.pgh.pa.us>
Wed, 22 May 2019 15:47:02 +0000 (11:47 -0400)
The original coding of this view relied on a correlated IN sub-query.
Our planner is not very bright about correlated sub-queries, and even
if it were, there's no way for it to know that the output of
pg_get_publication_tables() is duplicate-free, making the de-duplicating
semantics of IN unnecessary.  Hence, rewrite as a LATERAL sub-query.
This provides circa 100X speedup for me with a few hundred published
tables (the whole regression database), and things would degrade as
roughly O(published_relations * all_relations) beyond that.

Because the rules.out expected output changes, force a catversion bump.
Ordinarily we might not want to do that post-beta1; but we already know
we'll be doing a catversion bump before beta2 to fix pg_statistic_ext
issues, so it's pretty much free to fix it now instead of waiting for v13.

Per report and fix suggestion from PegoraroF10.

Discussion: https://postgr.es/m/1551385426763-0.post@n3.nabble.com

src/backend/catalog/system_views.sql
src/include/catalog/catversion.h
src/test/regress/expected/rules.out

index 566100d6df22b753e56e76fba5c2b243ca998916..52a6c315840b7d074033b37b8c05f11727ad11e9 100644 (file)
@@ -258,9 +258,10 @@ CREATE VIEW pg_publication_tables AS
         P.pubname AS pubname,
         N.nspname AS schemaname,
         C.relname AS tablename
-    FROM pg_publication P, pg_class C
-         JOIN pg_namespace N ON (N.oid = C.relnamespace)
-    WHERE C.oid IN (SELECT relid FROM pg_get_publication_tables(P.pubname));
+    FROM pg_publication P,
+         LATERAL pg_get_publication_tables(P.pubname) GPT,
+         pg_class C JOIN pg_namespace N ON (N.oid = C.relnamespace)
+    WHERE C.oid = GPT.relid;
 
 CREATE VIEW pg_locks AS
     SELECT * FROM pg_lock_status() AS L;
index c5c06163aa3594ff2f28a17b801ca04fa8d0ed9e..474d48c8ee334fffaf9e69534dfcbde2a8c1dcbd 100644 (file)
@@ -53,6 +53,6 @@
  */
 
 /*                                                     yyyymmddN */
-#define CATALOG_VERSION_NO     201905141
+#define CATALOG_VERSION_NO     201905221
 
 #endif
index 0c392e51e21e1da8e1ba3f215d66b121448a8f8d..4363ca16633be1c68e78d32275c0adeb72182bbf 100644 (file)
@@ -1441,10 +1441,10 @@ pg_publication_tables| SELECT p.pubname,
     n.nspname AS schemaname,
     c.relname AS tablename
    FROM pg_publication p,
+    LATERAL pg_get_publication_tables((p.pubname)::text) gpt(relid),
     (pg_class c
      JOIN pg_namespace n ON ((n.oid = c.relnamespace)))
-  WHERE (c.oid IN ( SELECT pg_get_publication_tables.relid
-           FROM pg_get_publication_tables((p.pubname)::text) pg_get_publication_tables(relid)));
+  WHERE (c.oid = gpt.relid);
 pg_replication_origin_status| SELECT pg_show_replication_origin_status.local_id,
     pg_show_replication_origin_status.external_id,
     pg_show_replication_origin_status.remote_lsn,