-
Notifications
You must be signed in to change notification settings - Fork 9
/
Copy pathpg_track_settings--2.1.0.sql
540 lines (500 loc) · 17.3 KB
/
pg_track_settings--2.1.0.sql
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
-- This program is open source, licensed under the PostgreSQL License.
-- For license terms, see the LICENSE file.
--
-- Copyright (C) 2015-2024: Julien Rouhaud
-- complain if script is sourced in psql, rather than via CREATE EXTENSION
\echo Use "CREATE EXTENSION pg_track_settings" to load this file. \quit
SET client_encoding = 'UTF8';
CREATE UNLOGGED TABLE @[email protected]_track_settings_settings_src_tmp (
srvid integer NOT NULL,
ts timestamp with time zone NOT NULL,
name text NOT NULL,
setting text,
current_setting text
);
-- no need to backup this table
CREATE TABLE @[email protected]_track_settings_list (
srvid integer NOT NULL,
name text,
PRIMARY KEY (srvid, name)
);
SELECT pg_catalog.pg_extension_config_dump('@[email protected]_track_settings_list', '');
CREATE TABLE @[email protected]_track_settings_history (
srvid integer NOT NULL,
ts timestamp with time zone,
name text NOT NULL,
setting text,
is_dropped boolean NOT NULL DEFAULT false,
setting_pretty text,
PRIMARY KEY(srvid, ts, name)
);
SELECT pg_catalog.pg_extension_config_dump('@[email protected]_track_settings_history', '');
CREATE UNLOGGED TABLE @[email protected]_track_settings_rds_src_tmp (
srvid integer NOT NULL,
ts timestamp with time zone NOT NULL,
name text NOT NULL,
setting text,
setdatabase oid NOT NULL,
setrole oid NOT NULL
);
-- no need to backup this table
CREATE TABLE @[email protected]_track_db_role_settings_list (
srvid integer,
name text,
setdatabase oid,
setrole oid,
PRIMARY KEY (srvid, name, setdatabase, setrole)
);
SELECT pg_catalog.pg_extension_config_dump('@[email protected]_track_db_role_settings_list', '');
CREATE TABLE @[email protected]_track_db_role_settings_history (
srvid INTEGER NOT NULL,
ts timestamp with time zone,
name text,
setdatabase oid,
setrole oid,
setting text,
is_dropped boolean NOT NULL DEFAULT false,
PRIMARY KEY(srvid, ts, name, setdatabase, setrole)
);
SELECT pg_catalog.pg_extension_config_dump('@[email protected]_track_db_role_settings_history', '');
CREATE UNLOGGED TABLE @[email protected]_track_settings_reboot_src_tmp (
srvid integer NOT NULL,
ts timestamp with time zone NOT NULL,
postmaster_ts timestamp with time zone NOT NULL
);
-- no need to backup this table
CREATE TABLE @[email protected]_reboot (
srvid integer NOT NULL,
ts timestamp with time zone,
PRIMARY KEY (srvid, ts)
);
SELECT pg_catalog.pg_extension_config_dump('@[email protected]_reboot', '');
----------------------
-- source functions --
----------------------
CREATE OR REPLACE FUNCTION @[email protected]_track_settings_settings_src (
IN _srvid integer,
OUT ts timestamp with time zone,
OUT name text,
OUT setting text,
OUT current_setting text
)
RETURNS SETOF record AS $PROC$
BEGIN
IF (_srvid = 0) THEN
RETURN QUERY SELECT now(),
s.name, s.setting, pg_catalog.current_setting(s.name)
FROM pg_catalog.pg_settings s;
ELSE
RETURN QUERY SELECT s.ts,
s.name, s.setting, s.current_setting
FROM @[email protected]_track_settings_settings_src_tmp s;
END IF;
END;
$PROC$ LANGUAGE plpgsql; /* end of pg_track_settings_settings_src */
CREATE OR REPLACE FUNCTION @[email protected]_track_settings_rds_src (
IN _srvid integer,
OUT ts timestamp with time zone,
OUT name text,
OUT setting text,
OUT setdatabase oid,
OUT setrole oid
)
RETURNS SETOF record AS $PROC$
BEGIN
IF (_srvid = 0) THEN
RETURN QUERY SELECT now(),
(regexp_split_to_array(unnest(s.setconfig),'=')::text[])[1] AS name,
(regexp_split_to_array(unnest(s.setconfig),'=')::text[])[2] AS setting,
s.setdatabase, s.setrole
FROM pg_catalog.pg_db_role_setting s;
ELSE
RETURN QUERY SELECT s.ts,
s.name, s.setting, s.setdatabase, s.setrole
FROM @[email protected]_track_settings_rds_src_tmp s;
END IF;
END;
$PROC$ LANGUAGE plpgsql; /* end of pg_track_settings_rds_src */
CREATE OR REPLACE FUNCTION @[email protected]_track_settings_reboot_src (
IN _srvid integer,
OUT ts timestamp with time zone,
OUT postmaster_ts timestamp with time zone
)
RETURNS SETOF record AS $PROC$
BEGIN
IF (_srvid = 0) THEN
RETURN QUERY SELECT now(),
pg_postmaster_start_time();
ELSE
RETURN QUERY SELECT s.ts,
s.postmaster_ts
FROM @[email protected]_track_settings_reboot_src_tmp s;
END IF;
END;
$PROC$ LANGUAGE plpgsql; /* end of pg_track_settings_reboot_src */
------------------------
-- snapshot functions --
------------------------
CREATE OR REPLACE FUNCTION @[email protected]_track_settings_snapshot_settings(_srvid integer)
RETURNS boolean AS
$_$
DECLARE
_snap_ts timestamp with time zone = NULL;
BEGIN
SELECT max(ts) INTO _snap_ts
FROM @[email protected]_track_settings_settings_src(_srvid);
-- this function should have been called for previously saved data. If
-- not, probably somethig went wrong, so discard those data
IF (_srvid != 0) THEN
DELETE FROM @[email protected]_track_settings_settings_src_tmp
WHERE ts != _snap_ts;
END IF;
-- Handle dropped GUC
WITH src AS (
SELECT * FROM @[email protected]_track_settings_settings_src(_srvid)
),
dropped AS (
SELECT s.ts, l.srvid, l.name
FROM @[email protected]_track_settings_list l
LEFT JOIN src s ON s.name = l.name
WHERE l.srvid = _srvid
AND s.name IS NULL
),
mark_dropped AS (
INSERT INTO @[email protected]_track_settings_history (srvid, ts, name, setting,
setting_pretty, is_dropped)
SELECT srvid, COALESCE(_snap_ts, now()), name, NULL, NULL, true
FROM dropped
)
DELETE FROM @[email protected]_track_settings_list l
USING dropped d
WHERE d.name = l.name
AND d.srvid = l.srvid
AND l.srvid = _srvid;
-- Insert missing settings
INSERT INTO @[email protected]_track_settings_list (srvid, name)
SELECT _srvid, name
FROM @[email protected]_track_settings_settings_src(_srvid) s
WHERE NOT EXISTS (SELECT 1
FROM @[email protected]_track_settings_list l
WHERE l.srvid = _srvid
AND l.name = s.name
);
-- Detect changed GUC, insert new vals
WITH src AS (
SELECT * FROM @[email protected]_track_settings_settings_src(_srvid)
), last_snapshot AS (
SELECT srvid, name, setting
FROM (
SELECT srvid, name, setting,
row_number() OVER (PARTITION BY NAME ORDER BY ts DESC) AS rn
FROM @[email protected]_track_settings_history h
WHERE h.srvid = _srvid
) all_snapshots
WHERE all_snapshots.rn = 1
)
INSERT INTO @[email protected]_track_settings_history
(srvid, ts, name, setting, setting_pretty)
SELECT _srvid, s.ts, s.name, s.setting, s.current_setting
FROM src s
LEFT JOIN last_snapshot l ON l.name = s.name
WHERE (
l.name IS NULL
OR l.setting IS DISTINCT FROM s.setting
);
IF (_srvid != 0) THEN
DELETE FROM @[email protected]_track_settings_settings_src_tmp
WHERE srvid = _srvid;
END IF;
RETURN true;
END;
$_$
LANGUAGE plpgsql; /* end of pg_track_settings_snapshot_settings() */
CREATE OR REPLACE FUNCTION @[email protected]_track_settings_snapshot_rds(_srvid integer)
RETURNS boolean AS
$_$
DECLARE
_snap_ts timestamp with time zone;
BEGIN
SELECT max(ts) INTO _snap_ts
FROM @[email protected]_track_settings_rds_src(_srvid);
-- this function should have been called for previously saved data. If
-- not, probably somethig went wrong, so discard those data
IF (_srvid != 0) THEN
DELETE FROM @[email protected]_track_settings_rds_src_tmp
WHERE ts != _snap_ts;
END IF;
-- Handle dropped db_role_setting
WITH rds AS (
SELECT * FROM @[email protected]_track_settings_rds_src(_srvid)
),
dropped AS (
SELECT _snap_ts AS ts, l.setdatabase, l.setrole, l.name
FROM @[email protected]_track_db_role_settings_list l
LEFT JOIN rds s ON (
s.setdatabase = l.setdatabase
AND s.setrole = l.setrole
AND s.name = l.name
)
WHERE l.srvid = _srvid
AND s.setdatabase IS NULL
AND s.setrole IS NULL
AND s.name IS NULL
),
mark_dropped AS (
INSERT INTO @[email protected]_track_db_role_settings_history
(srvid, ts, setdatabase, setrole, name, setting, is_dropped)
SELECT _srvid, ts, d.setdatabase, d.setrole, d.name, NULL, true
FROM dropped AS d
)
DELETE FROM @[email protected]_track_db_role_settings_list l
USING dropped d
WHERE
l.srvid = _srvid
AND d.setdatabase = l.setdatabase
AND d.setrole = l.setrole
AND d.name = l.name;
-- Insert missing settings
WITH rds AS (
SELECT * FROM @[email protected]_track_settings_rds_src(_srvid)
)
INSERT INTO @[email protected]_track_db_role_settings_list
(srvid, setdatabase, setrole, name)
SELECT _srvid, setdatabase, setrole, name
FROM rds s
WHERE NOT EXISTS (SELECT 1
FROM @[email protected]_track_db_role_settings_list l
WHERE
l.srvid = _srvid
AND l.setdatabase = s.setdatabase
AND l.setrole = l.setrole
AND l.name = s.name
);
-- Detect changed GUC, insert new vals
WITH rds AS (
SELECT * FROM @[email protected]_track_settings_rds_src(_srvid)
),
last_snapshot AS (
SELECT setdatabase, setrole, name, setting
FROM (
SELECT setdatabase, setrole, name, setting,
row_number() OVER (PARTITION BY name, setdatabase, setrole ORDER BY ts DESC) AS rn
FROM @[email protected]_track_db_role_settings_history
WHERE srvid = _srvid
) all_snapshots
WHERE all_snapshots.rn = 1
)
INSERT INTO @[email protected]_track_db_role_settings_history
(srvid, ts, setdatabase, setrole, name, setting)
SELECT _srvid, s.ts, s.setdatabase, s.setrole, s.name, s.setting
FROM rds s
LEFT JOIN last_snapshot l ON
l.setdatabase = s.setdatabase
AND l.setrole = s.setrole
AND l.name = s.name
WHERE (l.setdatabase IS NULL
AND l.setrole IS NULL
AND l.name IS NULL)
OR (l.setting IS DISTINCT FROM s.setting);
IF (_srvid != 0) THEN
DELETE FROM @[email protected]_track_settings_rds_src_tmp
WHERE srvid = _srvid;
END IF;
RETURN true;
END;
$_$
LANGUAGE plpgsql; /* end of pg_track_settings_snapshot_rds() */
CREATE OR REPLACE FUNCTION @[email protected]_track_settings_snapshot_reboot(_srvid integer)
RETURNS boolean AS
$_$
BEGIN
-- Detect is postmaster restarted since last call
WITH last_reboot AS (
SELECT t.postmaster_ts
FROM @[email protected]_track_settings_reboot_src(_srvid) t
)
INSERT INTO @[email protected]_reboot (srvid, ts)
SELECT _srvid, lr.postmaster_ts FROM last_reboot lr
WHERE NOT EXISTS (SELECT 1
FROM @[email protected]_reboot r
WHERE r.srvid = _srvid
AND r.ts = lr.postmaster_ts
AND r.srvid = _srvid
);
IF (_srvid != 0) THEN
DELETE FROM @[email protected]_track_settings_reboot_src_tmp
WHERE srvid = _srvid;
END IF;
RETURN true;
END;
$_$
LANGUAGE plpgsql; /* end of pg_track_settings_snapshot_reboot() */
-- global function doing all the work for local instance, kept for backward
-- compatibility
CREATE OR REPLACE FUNCTION @[email protected]_track_settings_snapshot()
RETURNS boolean AS
$_$
BEGIN
PERFORM @[email protected]_track_settings_snapshot_settings(0);
PERFORM @[email protected]_track_settings_snapshot_rds(0);
PERFORM @[email protected]_track_settings_snapshot_reboot(0);
RETURN true;
END;
$_$
LANGUAGE plpgsql;
/* end of pg_track_settings_snapshot() */
CREATE OR REPLACE FUNCTION @[email protected]_track_settings(
_ts timestamp with time zone DEFAULT now(),
_srvid integer DEFAULT 0)
RETURNS TABLE (name text, setting text, setting_pretty text) AS
$_$
BEGIN
RETURN QUERY
SELECT s.name, s.setting, s.setting_pretty
FROM (
SELECT h.name, h.setting, h.setting_pretty, h.is_dropped,
row_number() OVER (PARTITION BY h.name ORDER BY h.ts DESC) AS rn
FROM @[email protected]_track_settings_history h
WHERE h.srvid = _srvid
AND h.ts <= _ts
) s
WHERE s.rn = 1
AND NOT s.is_dropped
ORDER BY s.name;
END;
$_$
LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION @[email protected]_track_db_role_settings(
_ts timestamp with time zone DEFAULT now(),
_srvid integer DEFAULT 0)
RETURNS TABLE (setdatabase oid, setrole oid, name text, setting text) AS
$_$
BEGIN
RETURN QUERY
SELECT s.setdatabase, s.setrole, s.name, s.setting
FROM (
SELECT h.setdatabase, h.setrole, h.name, h.setting, h.is_dropped,
row_number() OVER (PARTITION BY h.name, h.setdatabase, h.setrole ORDER BY h.ts DESC) AS rn
FROM @[email protected]_track_db_role_settings_history h
WHERE h.srvid = _srvid
AND h.ts <= _ts
) s
WHERE s.rn = 1
AND NOT s.is_dropped
ORDER BY s.setdatabase, s.setrole, s.name;
END;
$_$
LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION @[email protected]_track_settings_diff(
_from timestamp with time zone,
_to timestamp with time zone,
_srvid integer DEFAULT 0)
RETURNS TABLE (name text, from_setting text, from_exists boolean,
to_setting text, to_exists boolean,
from_setting_pretty text, to_setting_pretty text) AS
$_$
BEGIN
RETURN QUERY
SELECT COALESCE(s1.name, s2.name),
s1.setting AS from_setting,
CASE WHEN s1.setting IS NULL THEN false ELSE true END,
s2.setting AS to_setting,
CASE WHEN s2.setting IS NULL THEN false ELSE true END,
s1.setting_pretty AS from_setting_pretty,
s2.setting_pretty AS to_setting_pretty
FROM @[email protected]_track_settings(_from, _srvid) s1
FULL OUTER JOIN @[email protected]_track_settings(_to, _srvid) s2 ON s2.name = s1.name
WHERE s1.setting IS DISTINCT FROM s2.setting
ORDER BY 1;
END;
$_$
LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION @[email protected]_track_db_role_settings_diff(
_from timestamp with time zone,
_to timestamp with time zone,
_srvid integer DEFAULT 0)
RETURNS TABLE (setdatabase oid, setrole oid, name text,
from_setting text, from_exists boolean, to_setting text, to_exists boolean)
AS
$_$
BEGIN
RETURN QUERY
SELECT COALESCE(s1.setdatabase, s2.setdatabase),
COALESCE(s1.setrole, s2.setrole),
COALESCE(s1.name, s2.name),
s1.setting AS from_setting,
CASE WHEN s1.setting IS NULL THEN false ELSE true END,
s2.setting AS to_setting,
CASE WHEN s2.setting IS NULL THEN false ELSE true END
FROM @[email protected]_track_db_role_settings(_from, _srvid) s1
FULL OUTER JOIN @[email protected]_track_db_role_settings(_to, _srvid) s2 ON
s2.setdatabase = s1.setdatabase
AND s2.setrole = s1.setrole
AND s2.name = s1.name
WHERE
s1.setdatabase IS DISTINCT FROM s2.setdatabase
AND s1.setrole IS DISTINCT FROM s2.setrole
AND s1.setting IS DISTINCT FROM s2.setting
ORDER BY 1, 2, 3;
END;
$_$
LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION @[email protected]_track_settings_log(
_name text,
_srvid integer DEFAULT 0)
RETURNS TABLE (ts timestamp with time zone, name text, setting_exists boolean,
setting text, setting_pretty text) AS
$_$
BEGIN
RETURN QUERY
SELECT h.ts, h.name, NOT h.is_dropped, h.setting, h.setting_pretty
FROM @[email protected]_track_settings_history h
WHERE h.srvid = _srvid
AND h.name = _name
ORDER BY ts DESC;
END;
$_$
LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION @[email protected]_track_db_role_settings_log(
_name text,
_srvid integer DEFAULT 0)
RETURNS TABLE (ts timestamp with time zone, setdatabase oid, setrole oid,
name text, setting_exists boolean, setting text) AS
$_$
BEGIN
RETURN QUERY
SELECT h.ts, h.setdatabase, h.setrole, h.name, NOT h.is_dropped, h.setting
FROM @[email protected]_track_db_role_settings_history h
WHERE h.srvid = _srvid
AND h.name = _name
ORDER BY ts, setdatabase, setrole DESC;
END;
$_$
LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION @[email protected]_track_reboot_log(_srvid integer DEFAULT 0)
RETURNS TABLE (ts timestamp with time zone) AS
$_$
BEGIN
RETURN QUERY
SELECT r.ts
FROM @[email protected]_reboot r
WHERE r.srvid = _srvid
ORDER BY r.ts;
END;
$_$
LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION @[email protected]_track_settings_reset(_srvid integer DEFAULT 0)
RETURNS void AS
$_$
BEGIN
DELETE FROM @[email protected]_track_settings_settings_src_tmp WHERE srvid = _srvid;
DELETE FROM @[email protected]_track_settings_rds_src_tmp WHERE srvid = _srvid;
DELETE FROM @[email protected]_track_settings_reboot_src_tmp WHERE srvid = _srvid;
DELETE FROM @[email protected]_track_settings_list WHERE srvid = _srvid;
DELETE FROM @[email protected]_track_settings_history WHERE srvid = _srvid;
DELETE FROM @[email protected]_track_db_role_settings_list WHERE srvid = _srvid;
DELETE FROM @[email protected]_track_db_role_settings_history WHERE srvid = _srvid;
DELETE FROM @[email protected]_reboot WHERE srvid = _srvid;
END;
$_$
LANGUAGE plpgsql;