From 1546ec3b2a4d37e71029b5d7e6bbeff152b77809 Mon Sep 17 00:00:00 2001 From: Taylor Vesely Date: Thu, 21 Sep 2017 11:25:21 -0700 Subject: [PATCH] Add gp_stat_replication view In order to view the primary segments' replication stream data from their pg_stat_replication view, we currently need to connect to the primary segment individually via utility mode. To make life easier, we introduce a function that will fetch each primary segment's replication stream data and wrap it with a view named gp_stat_replication. It will now be possible to view all the cluster replication information from the master in a regular psql session. Authors: Taylor Vesely and Jimmy Yih --- src/backend/catalog/system_views.sql | 29 +++++++++++++++++++ src/test/walrep/Makefile | 4 ++- .../expected/replication_views_mirrored.out | 22 ++++++++++++++ .../expected/replication_views_mirrorless.out | 19 ++++++++++++ .../walrep/sql/replication_views_mirrored.sql | 8 +++++ .../sql/replication_views_mirrorless.sql | 8 +++++ 6 files changed, 89 insertions(+), 1 deletion(-) create mode 100644 src/test/walrep/expected/replication_views_mirrored.out create mode 100644 src/test/walrep/expected/replication_views_mirrorless.out create mode 100644 src/test/walrep/sql/replication_views_mirrored.sql create mode 100644 src/test/walrep/sql/replication_views_mirrorless.sql diff --git a/src/backend/catalog/system_views.sql b/src/backend/catalog/system_views.sql index f8d2651a6a..4609a8926e 100644 --- a/src/backend/catalog/system_views.sql +++ b/src/backend/catalog/system_views.sql @@ -407,6 +407,35 @@ CREATE VIEW pg_stat_replication AS WHERE S.usesysid = U.oid AND S.procpid = W.pid; +CREATE FUNCTION pg_stat_get_master_replication() RETURNS SETOF RECORD AS +$$ + SELECT pg_catalog.gp_execution_segment() AS gp_segment_id, * + FROM pg_catalog.pg_stat_replication +$$ +LANGUAGE SQL EXECUTE ON MASTER; + +CREATE FUNCTION pg_stat_get_segment_replication() RETURNS SETOF RECORD AS +$$ + SELECT pg_catalog.gp_execution_segment() AS gp_segment_id, * + FROM pg_catalog.pg_stat_replication +$$ +LANGUAGE SQL EXECUTE ON ALL SEGMENTS; + +CREATE VIEW gp_stat_replication AS + SELECT * FROM pg_stat_get_master_replication() AS R + (gp_segment_id integer, procpid integer, usesysid oid, + usename name, application_name text, client_addr inet, + client_port integer, backend_start timestamptz, state text, + sent_location text, write_location text, flush_location text, + replay_location text, sync_priority integer, sync_state text) + UNION ALL + SELECT * FROM pg_stat_get_segment_replication() AS R + (gp_segment_id integer, procpid integer, usesysid oid, + usename name, application_name text, client_addr inet, + client_port integer, backend_start timestamptz, state text, + sent_location text, write_location text, flush_location text, + replay_location text, sync_priority integer, sync_state text); + CREATE VIEW pg_stat_database AS SELECT D.oid AS datid, diff --git a/src/test/walrep/Makefile b/src/test/walrep/Makefile index 1ccae5cdce..785edbd9de 100644 --- a/src/test/walrep/Makefile +++ b/src/test/walrep/Makefile @@ -13,7 +13,9 @@ REGRESS = setup walreceiver # walsender-walreceiver connection only ifeq ($(enable_segwalrep), yes) ifeq ($(WITH_MIRRORS), false) -REGRESS += generate_ao_xlog generate_aoco_xlog +REGRESS += generate_ao_xlog generate_aoco_xlog replication_views_mirrorless +else +REGRESS += replication_views_mirrored endif endif REGRESS_OPTS = --dbname="walrep_regression" diff --git a/src/test/walrep/expected/replication_views_mirrored.out b/src/test/walrep/expected/replication_views_mirrored.out new file mode 100644 index 0000000000..00274c65ff --- /dev/null +++ b/src/test/walrep/expected/replication_views_mirrored.out @@ -0,0 +1,22 @@ +-- Check how many WAL replication mirrors are up and synced +SELECT count(*) FROM gp_segment_configuration where preferred_role='m' and mode='s'; + count +------- + 3 +(1 row) + +-- Check pg_stat_replication view (this assumes standby master has not been created) +SELECT * FROM pg_stat_replication; + procpid | usesysid | usename | application_name | client_addr | client_port | backend_start | state | sent_location | write_location | flush_location | replay_location | sync_priority | sync_state +---------+----------+---------+------------------+-------------+-------------+---------------+-------+---------------+----------------+----------------+-----------------+---------------+------------ +(0 rows) + +-- Check pg_stat_replication view of master and primary segments +SELECT gp_segment_id, application_name, state, sync_state FROM gp_stat_replication; + gp_segment_id | application_name | state | sync_state +---------------+------------------+-----------+------------ + 0 | walreceiver | streaming | sync + 1 | walreceiver | streaming | sync + 2 | walreceiver | streaming | sync +(3 rows) + diff --git a/src/test/walrep/expected/replication_views_mirrorless.out b/src/test/walrep/expected/replication_views_mirrorless.out new file mode 100644 index 0000000000..d2913236e6 --- /dev/null +++ b/src/test/walrep/expected/replication_views_mirrorless.out @@ -0,0 +1,19 @@ +-- Check how many WAL replication mirrors are up and synced +SELECT count(*) FROM gp_segment_configuration where preferred_role='m' and mode='s'; + count +------- + 0 +(1 row) + +-- Check pg_stat_replication view (this assumes standby master has not been created) +SELECT * FROM pg_stat_replication; + procpid | usesysid | usename | application_name | client_addr | client_port | backend_start | state | sent_location | write_location | flush_location | replay_location | sync_priority | sync_state +---------+----------+---------+------------------+-------------+-------------+---------------+-------+---------------+----------------+----------------+-----------------+---------------+------------ +(0 rows) + +-- Check pg_stat_replication view of master and primary segments +SELECT gp_segment_id, application_name, state, sync_state FROM gp_stat_replication; + gp_segment_id | application_name | state | sync_state +---------------+------------------+-------+------------ +(0 rows) + diff --git a/src/test/walrep/sql/replication_views_mirrored.sql b/src/test/walrep/sql/replication_views_mirrored.sql new file mode 100644 index 0000000000..0daf7765fe --- /dev/null +++ b/src/test/walrep/sql/replication_views_mirrored.sql @@ -0,0 +1,8 @@ +-- Check how many WAL replication mirrors are up and synced +SELECT count(*) FROM gp_segment_configuration where preferred_role='m' and mode='s'; + +-- Check pg_stat_replication view (this assumes standby master has not been created) +SELECT * FROM pg_stat_replication; + +-- Check pg_stat_replication view of master and primary segments +SELECT gp_segment_id, application_name, state, sync_state FROM gp_stat_replication; diff --git a/src/test/walrep/sql/replication_views_mirrorless.sql b/src/test/walrep/sql/replication_views_mirrorless.sql new file mode 100644 index 0000000000..0daf7765fe --- /dev/null +++ b/src/test/walrep/sql/replication_views_mirrorless.sql @@ -0,0 +1,8 @@ +-- Check how many WAL replication mirrors are up and synced +SELECT count(*) FROM gp_segment_configuration where preferred_role='m' and mode='s'; + +-- Check pg_stat_replication view (this assumes standby master has not been created) +SELECT * FROM pg_stat_replication; + +-- Check pg_stat_replication view of master and primary segments +SELECT gp_segment_id, application_name, state, sync_state FROM gp_stat_replication; -- GitLab