From 8299471c37fff0b0f5a777a12f920125310c0efe Mon Sep 17 00:00:00 2001 From: Tom Lane Date: Fri, 19 Aug 2016 17:13:47 -0400 Subject: [PATCH] Use LEFT JOINs in some system views in case referenced row doesn't exist. In particular, left join to pg_authid so that rows in pg_stat_activity don't disappear if the session's owning user has been dropped. Also convert a few joins to pg_database to left joins, in the same spirit, though that case might be harder to hit. We were doing this in other views already, so it was a bit inconsistent that these views didn't. Oskari Saarenmaa, with some further tweaking by me Discussion: <56E87CD8.60007@ohmu.fi> --- src/backend/catalog/system_views.sql | 20 +++++++++----------- src/include/catalog/catversion.h | 2 +- src/test/regress/expected/rules.out | 20 +++++++++----------- 3 files changed, 19 insertions(+), 23 deletions(-) diff --git a/src/backend/catalog/system_views.sql b/src/backend/catalog/system_views.sql index 4fc5d5a065..ada214274f 100644 --- a/src/backend/catalog/system_views.sql +++ b/src/backend/catalog/system_views.sql @@ -642,9 +642,9 @@ CREATE VIEW pg_stat_activity AS S.backend_xid, s.backend_xmin, S.query - FROM pg_database D, pg_stat_get_activity(NULL) AS S, pg_authid U - WHERE S.datid = D.oid AND - S.usesysid = U.oid; + FROM pg_stat_get_activity(NULL) AS S + LEFT JOIN pg_database AS D ON (S.datid = D.oid) + LEFT JOIN pg_authid AS U ON (S.usesysid = U.oid); CREATE VIEW pg_stat_replication AS SELECT @@ -664,10 +664,9 @@ CREATE VIEW pg_stat_replication AS W.replay_location, W.sync_priority, W.sync_state - FROM pg_stat_get_activity(NULL) AS S, pg_authid U, - pg_stat_get_wal_senders() AS W - WHERE S.usesysid = U.oid AND - S.pid = W.pid; + FROM pg_stat_get_activity(NULL) AS S + JOIN pg_stat_get_wal_senders() AS W ON (S.pid = W.pid) + LEFT JOIN pg_authid AS U ON (S.usesysid = U.oid); CREATE VIEW pg_stat_wal_receiver AS SELECT @@ -813,7 +812,7 @@ CREATE VIEW pg_stat_progress_vacuum AS S.param4 AS heap_blks_vacuumed, S.param5 AS index_vacuum_count, S.param6 AS max_dead_tuples, S.param7 AS num_dead_tuples FROM pg_stat_get_progress_info('VACUUM') AS S - JOIN pg_database D ON S.datid = D.oid; + LEFT JOIN pg_database D ON S.datid = D.oid; CREATE VIEW pg_user_mappings AS SELECT @@ -832,12 +831,11 @@ CREATE VIEW pg_user_mappings AS NULL END AS umoptions FROM pg_user_mapping U - LEFT JOIN pg_authid A ON (A.oid = U.umuser) JOIN - pg_foreign_server S ON (U.umserver = S.oid); + JOIN pg_foreign_server S ON (U.umserver = S.oid) + LEFT JOIN pg_authid A ON (A.oid = U.umuser); REVOKE ALL on pg_user_mapping FROM public; - CREATE VIEW pg_replication_origin_status AS SELECT * FROM pg_show_replication_origin_status(); diff --git a/src/include/catalog/catversion.h b/src/include/catalog/catversion.h index fb356bf3cd..26f6126002 100644 --- a/src/include/catalog/catversion.h +++ b/src/include/catalog/catversion.h @@ -53,6 +53,6 @@ */ /* yyyymmddN */ -#define CATALOG_VERSION_NO 201608171 +#define CATALOG_VERSION_NO 201608191 #endif diff --git a/src/test/regress/expected/rules.out b/src/test/regress/expected/rules.out index 8157324fee..00700f28dc 100644 --- a/src/test/regress/expected/rules.out +++ b/src/test/regress/expected/rules.out @@ -1664,10 +1664,9 @@ pg_stat_activity| SELECT s.datid, s.backend_xid, s.backend_xmin, s.query - FROM pg_database d, - pg_stat_get_activity(NULL::integer) s(datid, pid, usesysid, application_name, state, query, wait_event_type, wait_event, xact_start, query_start, backend_start, state_change, client_addr, client_hostname, client_port, backend_xid, backend_xmin, ssl, sslversion, sslcipher, sslbits, sslcompression, sslclientdn), - pg_authid u - WHERE ((s.datid = d.oid) AND (s.usesysid = u.oid)); + FROM ((pg_stat_get_activity(NULL::integer) s(datid, pid, usesysid, application_name, state, query, wait_event_type, wait_event, xact_start, query_start, backend_start, state_change, client_addr, client_hostname, client_port, backend_xid, backend_xmin, ssl, sslversion, sslcipher, sslbits, sslcompression, sslclientdn) + LEFT JOIN pg_database d ON ((s.datid = d.oid))) + LEFT JOIN pg_authid u ON ((s.usesysid = u.oid))); pg_stat_all_indexes| SELECT c.oid AS relid, i.oid AS indexrelid, n.nspname AS schemaname, @@ -1776,7 +1775,7 @@ pg_stat_progress_vacuum| SELECT s.pid, s.param6 AS max_dead_tuples, s.param7 AS num_dead_tuples FROM (pg_stat_get_progress_info('VACUUM'::text) s(pid, datid, relid, param1, param2, param3, param4, param5, param6, param7, param8, param9, param10) - JOIN pg_database d ON ((s.datid = d.oid))); + LEFT JOIN pg_database d ON ((s.datid = d.oid))); pg_stat_replication| SELECT s.pid, s.usesysid, u.rolname AS usename, @@ -1793,10 +1792,9 @@ pg_stat_replication| SELECT s.pid, w.replay_location, w.sync_priority, w.sync_state - FROM pg_stat_get_activity(NULL::integer) s(datid, pid, usesysid, application_name, state, query, wait_event_type, wait_event, xact_start, query_start, backend_start, state_change, client_addr, client_hostname, client_port, backend_xid, backend_xmin, ssl, sslversion, sslcipher, sslbits, sslcompression, sslclientdn), - pg_authid u, - pg_stat_get_wal_senders() w(pid, state, sent_location, write_location, flush_location, replay_location, sync_priority, sync_state) - WHERE ((s.usesysid = u.oid) AND (s.pid = w.pid)); + FROM ((pg_stat_get_activity(NULL::integer) s(datid, pid, usesysid, application_name, state, query, wait_event_type, wait_event, xact_start, query_start, backend_start, state_change, client_addr, client_hostname, client_port, backend_xid, backend_xmin, ssl, sslversion, sslcipher, sslbits, sslcompression, sslclientdn) + JOIN pg_stat_get_wal_senders() w(pid, state, sent_location, write_location, flush_location, replay_location, sync_priority, sync_state) ON ((s.pid = w.pid))) + LEFT JOIN pg_authid u ON ((s.usesysid = u.oid))); pg_stat_ssl| SELECT s.pid, s.ssl, s.sslversion AS version, @@ -2155,8 +2153,8 @@ pg_user_mappings| SELECT u.oid AS umid, ELSE NULL::text[] END AS umoptions FROM ((pg_user_mapping u - LEFT JOIN pg_authid a ON ((a.oid = u.umuser))) - JOIN pg_foreign_server s ON ((u.umserver = s.oid))); + JOIN pg_foreign_server s ON ((u.umserver = s.oid))) + LEFT JOIN pg_authid a ON ((a.oid = u.umuser))); pg_views| SELECT n.nspname AS schemaname, c.relname AS viewname, pg_get_userbyid(c.relowner) AS viewowner,