Skip to content

HTTPS clone URL

Subversion checkout URL

You can clone with
or
.
Download ZIP
Browse files

Redefining repl_status view to improve performance, also add an

index on repl_monitor to speed up even more the view.
  • Loading branch information...
commit 4d26e4d21ec80c484458274baffb2e5eea560b08 1 parent 3f4ff5a
@Jaime2ndQuadrant Jaime2ndQuadrant authored
Showing with 25 additions and 14 deletions.
  1. +21 −9 repmgr.c
  2. +4 −5 repmgr.sql
View
30 repmgr.c
@@ -1911,16 +1911,16 @@ create_schema(PGconn *conn)
exit(ERR_BAD_CONFIG);
}
- /* and the view */
+ /* a view */
sqlquery_snprintf(sqlquery, "CREATE VIEW %s.repl_status AS "
- " WITH monitor_info AS (SELECT *, ROW_NUMBER() OVER (PARTITION BY primary_node, standby_node "
- " ORDER BY last_monitor_time desc) "
- " FROM %s.repl_monitor) "
- " SELECT primary_node, standby_node, last_monitor_time, last_wal_primary_location, "
- " last_wal_standby_location, pg_size_pretty(replication_lag) replication_lag, "
- " pg_size_pretty(apply_lag) apply_lag, age(now(), last_monitor_time) AS time_lag "
- " FROM monitor_info a "
- " WHERE row_number = 1", repmgr_schema, repmgr_schema);
+ " SELECT primary_node, standby_node, last_monitor_time, last_wal_primary_location, "
+ " last_wal_standby_location, pg_size_pretty(replication_lag) replication_lag, "
+ " pg_size_pretty(apply_lag) apply_lag, "
+ " age(now(), last_monitor_time) AS time_lag "
+ " FROM %s.repl_monitor "
+ " WHERE (standby_node, last_monitor_time) IN (SELECT standby_node, MAX(last_monitor_time) "
+ " FROM %s.repl_monitor GROUP BY 1)",
+ repmgr_schema, repmgr_schema, repmgr_schema);
log_debug(_("master register: %s\n"), sqlquery);
if (!PQexec(conn, sqlquery))
{
@@ -1930,6 +1930,18 @@ create_schema(PGconn *conn)
exit(ERR_BAD_CONFIG);
}
+ /* an index to improve performance of the view */
+ sqlquery_snprintf(sqlquery, "CREATE INDEX idx_repl_status_sort "
+ " ON %s.repl_monitor (last_monitor_time, standby_node) ");
+ log_debug(_("master register: %s\n"), sqlquery);
+ if (!PQexec(conn, sqlquery))
+ {
+ log_err(_("Cannot indexing table %s.repl_monitor: %s\n"),
+ repmgr_schema, PQerrorMessage(conn));
+ PQfinish(conn);
+ exit(ERR_BAD_CONFIG);
+ }
+
/* XXX Here we MUST try to load the repmgr_function.sql not hardcode it here */
sprintf(sqlquery,
"CREATE OR REPLACE FUNCTION public.repmgr_update_standby_location(text) RETURNS boolean "
View
9 repmgr.sql
@@ -34,6 +34,7 @@ CREATE TABLE repl_monitor (
);
ALTER TABLE repl_monitor OWNER TO repmgr;
+CREATE INDEX idx_repl_monitor_last_monitor_sort ON repl_monitor(last_monitor_time, standby_node);
/*
* This view shows the latest monitor info about every node.
@@ -46,14 +47,12 @@ ALTER TABLE repl_monitor OWNER TO repmgr;
* time_lag: how many seconds are we from being up-to-date with master
*/
CREATE VIEW repl_status AS
-WITH monitor_info AS (SELECT *, ROW_NUMBER() OVER (PARTITION BY primary_node, standby_node
- ORDER BY last_monitor_time desc)
- FROM repl_monitor)
SELECT primary_node, standby_node, last_monitor_time, last_wal_primary_location,
last_wal_standby_location, pg_size_pretty(replication_lag) replication_lag,
pg_size_pretty(apply_lag) apply_lag,
age(now(), last_monitor_time) AS time_lag
- FROM monitor_info a
- WHERE row_number = 1;
+ FROM repl_monitor
+WHERE (standby_node, last_monitor_time) IN (SELECT standby_node, MAX(last_monitor_time)
+ FROM repl_monitor GROUP BY 1);
ALTER VIEW repl_status OWNER TO repmgr;
Please sign in to comment.
Something went wrong with that request. Please try again.