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
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;
*/
/* yyyymmddN */
-#define CATALOG_VERSION_NO 201905141
+#define CATALOG_VERSION_NO 201905221
#endif
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,