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>
This commit is contained in:
Tom Lane 2016-08-19 17:13:47 -04:00
parent 65a603e903
commit 8299471c37
3 changed files with 19 additions and 23 deletions

View File

@ -642,9 +642,9 @@ CREATE VIEW pg_stat_activity AS
S.backend_xid, S.backend_xid,
s.backend_xmin, s.backend_xmin,
S.query S.query
FROM pg_database D, pg_stat_get_activity(NULL) AS S, pg_authid U FROM pg_stat_get_activity(NULL) AS S
WHERE S.datid = D.oid AND LEFT JOIN pg_database AS D ON (S.datid = D.oid)
S.usesysid = U.oid; LEFT JOIN pg_authid AS U ON (S.usesysid = U.oid);
CREATE VIEW pg_stat_replication AS CREATE VIEW pg_stat_replication AS
SELECT SELECT
@ -664,10 +664,9 @@ CREATE VIEW pg_stat_replication AS
W.replay_location, W.replay_location,
W.sync_priority, W.sync_priority,
W.sync_state W.sync_state
FROM pg_stat_get_activity(NULL) AS S, pg_authid U, FROM pg_stat_get_activity(NULL) AS S
pg_stat_get_wal_senders() AS W JOIN pg_stat_get_wal_senders() AS W ON (S.pid = W.pid)
WHERE S.usesysid = U.oid AND LEFT JOIN pg_authid AS U ON (S.usesysid = U.oid);
S.pid = W.pid;
CREATE VIEW pg_stat_wal_receiver AS CREATE VIEW pg_stat_wal_receiver AS
SELECT 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.param4 AS heap_blks_vacuumed, S.param5 AS index_vacuum_count,
S.param6 AS max_dead_tuples, S.param7 AS num_dead_tuples S.param6 AS max_dead_tuples, S.param7 AS num_dead_tuples
FROM pg_stat_get_progress_info('VACUUM') AS S 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 CREATE VIEW pg_user_mappings AS
SELECT SELECT
@ -832,12 +831,11 @@ CREATE VIEW pg_user_mappings AS
NULL NULL
END AS umoptions END AS umoptions
FROM pg_user_mapping U FROM pg_user_mapping U
LEFT JOIN pg_authid A ON (A.oid = U.umuser) JOIN JOIN pg_foreign_server S ON (U.umserver = S.oid)
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; REVOKE ALL on pg_user_mapping FROM public;
CREATE VIEW pg_replication_origin_status AS CREATE VIEW pg_replication_origin_status AS
SELECT * SELECT *
FROM pg_show_replication_origin_status(); FROM pg_show_replication_origin_status();

View File

@ -53,6 +53,6 @@
*/ */
/* yyyymmddN */ /* yyyymmddN */
#define CATALOG_VERSION_NO 201608171 #define CATALOG_VERSION_NO 201608191
#endif #endif

View File

@ -1664,10 +1664,9 @@ pg_stat_activity| SELECT s.datid,
s.backend_xid, s.backend_xid,
s.backend_xmin, s.backend_xmin,
s.query s.query
FROM pg_database d, 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_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)))
pg_authid u LEFT JOIN pg_authid u ON ((s.usesysid = u.oid)));
WHERE ((s.datid = d.oid) AND (s.usesysid = u.oid));
pg_stat_all_indexes| SELECT c.oid AS relid, pg_stat_all_indexes| SELECT c.oid AS relid,
i.oid AS indexrelid, i.oid AS indexrelid,
n.nspname AS schemaname, n.nspname AS schemaname,
@ -1776,7 +1775,7 @@ pg_stat_progress_vacuum| SELECT s.pid,
s.param6 AS max_dead_tuples, s.param6 AS max_dead_tuples,
s.param7 AS num_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) 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, pg_stat_replication| SELECT s.pid,
s.usesysid, s.usesysid,
u.rolname AS usename, u.rolname AS usename,
@ -1793,10 +1792,9 @@ pg_stat_replication| SELECT s.pid,
w.replay_location, w.replay_location,
w.sync_priority, w.sync_priority,
w.sync_state 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), 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, 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)))
pg_stat_get_wal_senders() w(pid, state, sent_location, write_location, flush_location, replay_location, sync_priority, sync_state) LEFT JOIN pg_authid u ON ((s.usesysid = u.oid)));
WHERE ((s.usesysid = u.oid) AND (s.pid = w.pid));
pg_stat_ssl| SELECT s.pid, pg_stat_ssl| SELECT s.pid,
s.ssl, s.ssl,
s.sslversion AS version, s.sslversion AS version,
@ -2155,8 +2153,8 @@ pg_user_mappings| SELECT u.oid AS umid,
ELSE NULL::text[] ELSE NULL::text[]
END AS umoptions END AS umoptions
FROM ((pg_user_mapping u 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, pg_views| SELECT n.nspname AS schemaname,
c.relname AS viewname, c.relname AS viewname,
pg_get_userbyid(c.relowner) AS viewowner, pg_get_userbyid(c.relowner) AS viewowner,