Skip to content

Commit bba282a

Browse files
committed
Add extension script files for 5.4dev.
1 parent 02c29dc commit bba282a

File tree

2 files changed

+194
-0
lines changed

2 files changed

+194
-0
lines changed

repmgr--5.3--5.4.sql

+2
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,2 @@
1+
-- complain if script is sourced in psql, rather than via CREAT EXTENSION
2+
\echo Use "CREATE EXTENSION repmgr" to load this file. \quit

repmgr--5.4.sql

+192
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,192 @@
1+
-- complain if script is sourced in psql, rather than via CREATE EXTENSION
2+
\echo Use "CREATE EXTENSION repmgr" to load this file. \quit
3+
4+
CREATE TABLE repmgr.nodes (
5+
node_id INTEGER PRIMARY KEY,
6+
upstream_node_id INTEGER NULL REFERENCES nodes (node_id) DEFERRABLE,
7+
active BOOLEAN NOT NULL DEFAULT TRUE,
8+
node_name TEXT NOT NULL,
9+
type TEXT NOT NULL CHECK (type IN('primary','standby','witness','bdr')),
10+
location TEXT NOT NULL DEFAULT 'default',
11+
priority INT NOT NULL DEFAULT 100,
12+
conninfo TEXT NOT NULL,
13+
repluser VARCHAR(63) NOT NULL,
14+
slot_name TEXT NULL,
15+
config_file TEXT NOT NULL
16+
);
17+
18+
SELECT pg_catalog.pg_extension_config_dump('repmgr.nodes', '');
19+
20+
CREATE TABLE repmgr.events (
21+
node_id INTEGER NOT NULL,
22+
event TEXT NOT NULL,
23+
successful BOOLEAN NOT NULL DEFAULT TRUE,
24+
event_timestamp TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP,
25+
details TEXT NULL
26+
);
27+
28+
SELECT pg_catalog.pg_extension_config_dump('repmgr.events', '');
29+
30+
CREATE TABLE repmgr.monitoring_history (
31+
primary_node_id INTEGER NOT NULL,
32+
standby_node_id INTEGER NOT NULL,
33+
last_monitor_time TIMESTAMP WITH TIME ZONE NOT NULL,
34+
last_apply_time TIMESTAMP WITH TIME ZONE,
35+
last_wal_primary_location PG_LSN NOT NULL,
36+
last_wal_standby_location PG_LSN,
37+
replication_lag BIGINT NOT NULL,
38+
apply_lag BIGINT NOT NULL
39+
);
40+
41+
CREATE INDEX idx_monitoring_history_time
42+
ON repmgr.monitoring_history (last_monitor_time, standby_node_id);
43+
44+
SELECT pg_catalog.pg_extension_config_dump('repmgr.monitoring_history', '');
45+
46+
CREATE VIEW repmgr.show_nodes AS
47+
SELECT n.node_id,
48+
n.node_name,
49+
n.active,
50+
n.upstream_node_id,
51+
un.node_name AS upstream_node_name,
52+
n.type,
53+
n.priority,
54+
n.conninfo
55+
FROM repmgr.nodes n
56+
LEFT JOIN repmgr.nodes un
57+
ON un.node_id = n.upstream_node_id;
58+
59+
CREATE TABLE repmgr.voting_term (
60+
term INT NOT NULL
61+
);
62+
63+
CREATE UNIQUE INDEX voting_term_restrict
64+
ON repmgr.voting_term ((TRUE));
65+
66+
CREATE RULE voting_term_delete AS
67+
ON DELETE TO repmgr.voting_term
68+
DO INSTEAD NOTHING;
69+
70+
71+
/* ================= */
72+
/* repmgrd functions */
73+
/* ================= */
74+
75+
/* monitoring functions */
76+
77+
CREATE FUNCTION set_local_node_id(INT)
78+
RETURNS VOID
79+
AS 'MODULE_PATHNAME', 'repmgr_set_local_node_id'
80+
LANGUAGE C STRICT;
81+
82+
CREATE FUNCTION get_local_node_id()
83+
RETURNS INT
84+
AS 'MODULE_PATHNAME', 'repmgr_get_local_node_id'
85+
LANGUAGE C STRICT;
86+
87+
CREATE FUNCTION standby_set_last_updated()
88+
RETURNS TIMESTAMP WITH TIME ZONE
89+
AS 'MODULE_PATHNAME', 'repmgr_standby_set_last_updated'
90+
LANGUAGE C STRICT;
91+
92+
CREATE FUNCTION standby_get_last_updated()
93+
RETURNS TIMESTAMP WITH TIME ZONE
94+
AS 'MODULE_PATHNAME', 'repmgr_standby_get_last_updated'
95+
LANGUAGE C STRICT;
96+
97+
CREATE FUNCTION set_upstream_last_seen(INT)
98+
RETURNS VOID
99+
AS 'MODULE_PATHNAME', 'repmgr_set_upstream_last_seen'
100+
LANGUAGE C STRICT;
101+
102+
CREATE FUNCTION get_upstream_last_seen()
103+
RETURNS INT
104+
AS 'MODULE_PATHNAME', 'repmgr_get_upstream_last_seen'
105+
LANGUAGE C STRICT;
106+
107+
CREATE FUNCTION get_upstream_node_id()
108+
RETURNS INT
109+
AS 'MODULE_PATHNAME', 'repmgr_get_upstream_node_id'
110+
LANGUAGE C STRICT;
111+
112+
CREATE FUNCTION set_upstream_node_id(INT)
113+
RETURNS VOID
114+
AS 'MODULE_PATHNAME', 'repmgr_set_upstream_node_id'
115+
LANGUAGE C STRICT;
116+
117+
/* failover functions */
118+
119+
CREATE FUNCTION notify_follow_primary(INT)
120+
RETURNS VOID
121+
AS 'MODULE_PATHNAME', 'repmgr_notify_follow_primary'
122+
LANGUAGE C STRICT;
123+
124+
CREATE FUNCTION get_new_primary()
125+
RETURNS INT
126+
AS 'MODULE_PATHNAME', 'repmgr_get_new_primary'
127+
LANGUAGE C STRICT;
128+
129+
CREATE FUNCTION reset_voting_status()
130+
RETURNS VOID
131+
AS 'MODULE_PATHNAME', 'repmgr_reset_voting_status'
132+
LANGUAGE C STRICT;
133+
134+
CREATE FUNCTION get_repmgrd_pid()
135+
RETURNS INT
136+
AS 'MODULE_PATHNAME', 'get_repmgrd_pid'
137+
LANGUAGE C STRICT;
138+
139+
CREATE FUNCTION get_repmgrd_pidfile()
140+
RETURNS TEXT
141+
AS 'MODULE_PATHNAME', 'get_repmgrd_pidfile'
142+
LANGUAGE C STRICT;
143+
144+
CREATE FUNCTION set_repmgrd_pid(INT, TEXT)
145+
RETURNS VOID
146+
AS 'MODULE_PATHNAME', 'set_repmgrd_pid'
147+
LANGUAGE C CALLED ON NULL INPUT;
148+
149+
CREATE FUNCTION repmgrd_is_running()
150+
RETURNS BOOL
151+
AS 'MODULE_PATHNAME', 'repmgrd_is_running'
152+
LANGUAGE C STRICT;
153+
154+
CREATE FUNCTION repmgrd_pause(BOOL)
155+
RETURNS VOID
156+
AS 'MODULE_PATHNAME', 'repmgrd_pause'
157+
LANGUAGE C STRICT;
158+
159+
CREATE FUNCTION repmgrd_is_paused()
160+
RETURNS BOOL
161+
AS 'MODULE_PATHNAME', 'repmgrd_is_paused'
162+
LANGUAGE C STRICT;
163+
164+
CREATE FUNCTION get_wal_receiver_pid()
165+
RETURNS INT
166+
AS 'MODULE_PATHNAME', 'repmgr_get_wal_receiver_pid'
167+
LANGUAGE C STRICT;
168+
169+
170+
171+
172+
/* views */
173+
174+
CREATE VIEW repmgr.replication_status AS
175+
SELECT m.primary_node_id, m.standby_node_id, n.node_name AS standby_name,
176+
n.type AS node_type, n.active, last_monitor_time,
177+
CASE WHEN n.type='standby' THEN m.last_wal_primary_location ELSE NULL END AS last_wal_primary_location,
178+
m.last_wal_standby_location,
179+
CASE WHEN n.type='standby' THEN pg_catalog.pg_size_pretty(m.replication_lag) ELSE NULL END AS replication_lag,
180+
CASE WHEN n.type='standby' THEN
181+
CASE WHEN replication_lag > 0 THEN age(now(), m.last_apply_time) ELSE '0'::INTERVAL END
182+
ELSE NULL
183+
END AS replication_time_lag,
184+
CASE WHEN n.type='standby' THEN pg_catalog.pg_size_pretty(m.apply_lag) ELSE NULL END AS apply_lag,
185+
AGE(NOW(), CASE WHEN pg_catalog.pg_is_in_recovery() THEN repmgr.standby_get_last_updated() ELSE m.last_monitor_time END) AS communication_time_lag
186+
FROM repmgr.monitoring_history m
187+
JOIN repmgr.nodes n ON m.standby_node_id = n.node_id
188+
WHERE (m.standby_node_id, m.last_monitor_time) IN (
189+
SELECT m1.standby_node_id, MAX(m1.last_monitor_time)
190+
FROM repmgr.monitoring_history m1 GROUP BY 1
191+
);
192+

0 commit comments

Comments
 (0)