├── .github └── workflows │ ├── powa_archivist.yml │ ├── powa_archivist_git.yml │ └── regression.yml ├── .gitignore ├── CHANGELOG.md ├── LICENSE ├── META.json ├── Makefile ├── README.md ├── debian ├── changelog ├── control ├── control.in ├── copyright ├── pgversions ├── rules ├── source │ └── format ├── tests │ ├── control │ └── installcheck └── watch ├── expected └── pg_track_settings.out ├── pg_track_settings--1.0.0--1.0.1.sql ├── pg_track_settings--1.0.0.sql ├── pg_track_settings--1.0.1--1.1.0.sql ├── pg_track_settings--1.0.1.sql ├── pg_track_settings--1.1.0.sql ├── pg_track_settings--2.0.0--2.0.1.sql ├── pg_track_settings--2.0.0.sql ├── pg_track_settings--2.0.1--2.1.0.sql ├── pg_track_settings--2.0.1.sql ├── pg_track_settings--2.1.0--2.1.2.sql ├── pg_track_settings--2.1.0.sql ├── pg_track_settings--2.1.2.sql ├── pg_track_settings.control └── test └── sql └── pg_track_settings.sql /.github/workflows/powa_archivist.yml: -------------------------------------------------------------------------------- 1 | name: Trigger build and push of powa-archivist image 2 | 3 | on: 4 | push: 5 | # https://docs.github.com/en/actions/using-workflows/workflow-syntax-for-github-actions#filter-pattern-cheat-sheet 6 | tags-ignore: 7 | - 'debian/*' 8 | 9 | env: 10 | TARGET_ORG: "powa-team" 11 | TARGET_REPO: "powa-podman" 12 | EVENT_TYPE: "powa-archivist" 13 | 14 | jobs: 15 | trigger_build: 16 | name: Trigger build and push of powa-archivist in powa-podman repo 17 | runs-on: ubuntu-latest 18 | steps: 19 | - name: Trigger the powa-archivist-git repository dispatch 20 | run: | 21 | # Set variables 22 | org="${{ env.TARGET_ORG }}" 23 | repo="${{ env.TARGET_REPO }}" 24 | event_type="${{ env.EVENT_TYPE }}" 25 | 26 | curl -L \ 27 | -X POST \ 28 | -H "Accept: application/vnd.github+json" \ 29 | -H "Authorization: Bearer ${{ secrets.DISPATCH_TOKEN }}" \ 30 | -H "X-GitHub-Api-Version: 2022-11-28" \ 31 | https://api.github.com/repos/${org}/${repo}/dispatches \ 32 | -d "{\"event_type\": \"${event_type}\"}" 33 | -------------------------------------------------------------------------------- /.github/workflows/powa_archivist_git.yml: -------------------------------------------------------------------------------- 1 | name: Trigger build and push of powa-archivist-git image 2 | 3 | on: 4 | push: 5 | branches: [master] 6 | 7 | env: 8 | TARGET_ORG: "powa-team" 9 | TARGET_REPO: "powa-podman" 10 | EVENT_TYPE: "powa-archivist-git" 11 | 12 | jobs: 13 | trigger_build: 14 | name: Trigger build and push of powa-archivist-git in powa-podman repo 15 | runs-on: ubuntu-latest 16 | steps: 17 | - name: Trigger the powa-archivist-git repository dispatch 18 | run: | 19 | # Set variables 20 | org="${{ env.TARGET_ORG }}" 21 | repo="${{ env.TARGET_REPO }}" 22 | event_type="${{ env.EVENT_TYPE }}" 23 | 24 | curl -vL \ 25 | -X POST \ 26 | -H "Accept: application/vnd.github+json" \ 27 | -H "Authorization: Bearer ${{ secrets.DISPATCH_TOKEN }}" \ 28 | -H "X-GitHub-Api-Version: 2022-11-28" \ 29 | https://api.github.com/repos/${org}/${repo}/dispatches \ 30 | -d "{\"event_type\": \"${event_type}\"}" 31 | -------------------------------------------------------------------------------- /.github/workflows/regression.yml: -------------------------------------------------------------------------------- 1 | name: Build 2 | 3 | on: [push, pull_request] 4 | 5 | jobs: 6 | build: 7 | runs-on: ubuntu-latest 8 | 9 | defaults: 10 | run: 11 | shell: sh 12 | 13 | strategy: 14 | matrix: 15 | # support 9.5 and later (9.4 doesn't have regrole) 16 | pgversion: [ 9.5, 9.6, 10, 11, 12, 13, 14, 15, 16 ] 17 | 18 | env: 19 | PGVERSION: ${{ matrix.pgversion }} 20 | 21 | steps: 22 | - name: checkout 23 | uses: actions/checkout@v4 24 | 25 | - name: install pg 26 | run: | 27 | sudo /usr/share/postgresql-common/pgdg/apt.postgresql.org.sh -v $PGVERSION -p -i 28 | sudo -u postgres createuser -s "$USER" 29 | 30 | - name: build 31 | run: | 32 | make PROFILE="-Werror" 33 | sudo -E make install 34 | 35 | - name: test 36 | run: | 37 | make installcheck 38 | 39 | - name: show regression diffs 40 | if: ${{ failure() }} 41 | run: | 42 | cat regression.diffs 43 | -------------------------------------------------------------------------------- /.gitignore: -------------------------------------------------------------------------------- 1 | .*.sw* 2 | pg_track_settings-*.zip 3 | results/ 4 | -------------------------------------------------------------------------------- /CHANGELOG.md: -------------------------------------------------------------------------------- 1 | Changelog 2 | ========= 3 | 4 | 2023-05-13 2.1.2: 5 | ----------------- 6 | 7 | - Fix concurrent remote snapshot (Julien Rouhaud) 8 | - Fix role / db setting snapshot when all previous settings have been removed 9 | (Julien Rouhaud, per report from github user sajiljosephs) 10 | 11 | 2022-09-21 2.1.1: 12 | ------------------ 13 | 14 | - Fix regression tests on PG 11 an earlier (Christoph Berg) 15 | - Run regression tests in a GitHub workflow (Christoph Berg) 16 | 17 | 2022-09-20 2.1.0: 18 | ------------------ 19 | 20 | - Allow installation in a custom schema (Julien Rouhaud) 21 | - debian packaging improvements (Chrstoph Berg) 22 | - Make the extension compatible with EDB fork of postgres (Julien Rouhaud, per 23 | report from github user manishnew09 and help from Thomas Reiss) 24 | - various regression testss improvements (Julien Rouhaud) 25 | 26 | 2020-10-02 2.0.1: 27 | ------------------ 28 | 29 | - Fix handling of dropped pg_db_role_setting entries. Thanks to Adrien 30 | Nayrat for the report. 31 | 32 | 2019-09-05 2.0.0: 33 | ------------------ 34 | 35 | - Add support for remote snapshot mode that will be available with powa 4 36 | (thanks to github user Ikrar-k for testing and bug reporting) 37 | - Add pg_track_reboot_log function 38 | 39 | 2018-07-15 version 1.0.1: 40 | ------------------------- 41 | 42 | **Bug fixes**: 43 | 44 | - Fix issue leading to duplicated role settings changes when several 45 | roles exists (Adrien Nayrat). 46 | 47 | 2015-12-06 version 1.0.0: 48 | ------------------------- 49 | 50 | - First version of pg_track_settings. 51 | -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | Copyright (c) 2015-2024, Julien Rouhaud 2 | 3 | Permission to use, copy, modify, and distribute this software and its 4 | documentation for any purpose, without fee, and without a written agreement is 5 | hereby granted, provided that the above copyright notice and this paragraph and 6 | the following two paragraphs appear in all copies. 7 | 8 | IN NO EVENT SHALL Julien Rouhaud BE LIABLE TO ANY PARTY FOR DIRECT, INDIRECT, 9 | SPECIAL, INCIDENTAL, OR CONSEQUENTIAL DAMAGES, INCLUDING LOST PROFITS, ARISING 10 | OUT OF THE USE OF THIS SOFTWARE AND ITS DOCUMENTATION, EVEN IF Julien Rouhaud 11 | HAS BEEN ADVISED OF THE POSSIBILITY OF SUCH DAMAGE. 12 | 13 | Julien Rouhaud SPECIFICALLY DISCLAIMS ANY WARRANTIES, INCLUDING, BUT NOT 14 | LIMITED TO, THE IMPLIED WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A 15 | PARTICULAR PURPOSE. THE SOFTWARE PROVIDED HEREUNDER IS ON AN "AS IS" BASIS, AND 16 | Julien Rouhaud HAS NO OBLIGATIONS TO PROVIDE MAINTENANCE, SUPPORT, UPDATES, 17 | ENHANCEMENTS, OR MODIFICATIONS. 18 | -------------------------------------------------------------------------------- /META.json: -------------------------------------------------------------------------------- 1 | { 2 | "name": "pg_track_settings", 3 | "abstract": "A simple extension which keep track of postgresql settings modifications", 4 | "version": "__VERSION__", 5 | "maintainer": "Julien Rouhaud ", 6 | "license": "postgresql", 7 | "release_status": "stable", 8 | "provides": { 9 | "pg_track_settings": { 10 | "abstract": "A simple extension which keep track of postgresql settings modifications", 11 | "file": "pg_track_settings.sql", 12 | "docfile": "README.md", 13 | "version": "__VERSION__" 14 | } 15 | }, 16 | "resources": { 17 | "bugtracker": { 18 | "web": "http://github.com/rjuju/pg_track_settings/issues/" 19 | }, 20 | "repository": { 21 | "url": "git://github.com/rjuju/pg_track_settings.git", 22 | "web": "http://github.com/rjuju/pg_track_settings/", 23 | "type": "git" 24 | } 25 | }, 26 | "prereqs": { 27 | "runtime": { 28 | "requires": { 29 | "PostgreSQL": "9.1.0" 30 | } 31 | } 32 | }, 33 | "generated_by": "Julien Rouhaud", 34 | "meta-spec": { 35 | "version": "1.0.0", 36 | "url": "http://pgxn.org/meta/spec.txt" 37 | }, 38 | "tags": [ 39 | "monitoring", 40 | "administration" 41 | ] 42 | } 43 | -------------------------------------------------------------------------------- /Makefile: -------------------------------------------------------------------------------- 1 | EXTENSION = pg_track_settings 2 | EXTVERSION = $(shell grep default_version $(EXTENSION).control | sed -e "s/default_version[[:space:]]*=[[:space:]]*'\([^']*\)'/\1/") 3 | TESTS = $(wildcard test/sql/*.sql) 4 | REGRESS = $(patsubst test/sql/%.sql,%,$(TESTS)) 5 | REGRESS_OPTS = --inputdir=test 6 | DOCS = $(wildcard README.md) 7 | 8 | DATA = $(wildcard *--*.sql) 9 | 10 | PG_CONFIG = pg_config 11 | PGXS = $(shell $(PG_CONFIG) --pgxs) 12 | 13 | include $(PGXS) 14 | 15 | 16 | all: 17 | 18 | release-zip: all 19 | git archive --format zip --prefix=${EXTENSION}-${EXTVERSION}/ --output ./${EXTENSION}-${EXTVERSION}.zip HEAD 20 | unzip ./${EXTENSION}-$(EXTVERSION).zip 21 | rm ./${EXTENSION}-$(EXTVERSION).zip 22 | rm ./${EXTENSION}-$(EXTVERSION)/.gitignore 23 | sed -i -e "s/__VERSION__/$(EXTVERSION)/g" ./${EXTENSION}-$(EXTVERSION)/META.json 24 | zip -r ./${EXTENSION}-$(EXTVERSION).zip ./${EXTENSION}-$(EXTVERSION)/ 25 | rm -rf ./${EXTENSION}-$(EXTVERSION) 26 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | pg_track_settings 2 | ================= 3 | 4 | pg_track_settings is a small extension that helps you keep track of 5 | postgresql settings configuration. 6 | 7 | It provides a function (**pg_track_settings_snapshot()**), that must be called 8 | regularly. At each call, it will store the settings that have been changed 9 | since last call. It will also track the postgresql start time if it's different 10 | from the last one. 11 | 12 | This extension tracks both overall settings (the **pg_settings** view) and 13 | overloaded settings (the **pg_db_role_setting** table). 14 | 15 | Usage 16 | ----- 17 | 18 | - Create the extension in any database: 19 | 20 | CREATE EXTENSION pg_track_settings; 21 | 22 | Then make sure the **pg_track_settings_snapshot()** function called. Cron or 23 | PoWA can be used for that. 24 | 25 | Functions 26 | --------- 27 | 28 | - `pg_track_settings_snapshot()`: collect the current settings value. 29 | - `pg_track_settings(timestamptz)`: return all settings at the specified timestamp. Current time is used if no timestamped specified. 30 | - `pg_track_settings_diff(timestamptz, timestamptz)`: return all settings that have changed between the two specified timestamps. 31 | - `pg_track_settings_log(text)`: return the history of a specific setting. 32 | - `pg_track_db_role_settings(timestamptz)`: return all overloaded settings at the specified timestamp. Current time is used if no timestamped specified. 33 | - `pg_track_db_role_settings_diff(timestamptz, timestamptz)`: return all overloaded settings that have changed between the two specified timestamps. 34 | - `pg_track_db_role_settings_log(text)`: return the history of a specific overloaded setting. 35 | 36 | Example 37 | ------- 38 | Call a first time the snapshot function to get the initial values: 39 | 40 | postgres=# select pg_track_settings_snapshot() 41 | ---------------------------- 42 | t 43 | (1 row) 44 | 45 | A first snapshot is now taken: 46 | 47 | postgres=# select DISTINCT ts FROM pg_track_settings_history ; 48 | ts 49 | ------------------------------- 50 | 2015-01-25 01:00:37.449846+01 51 | (1 row) 52 | 53 | Let's assume the configuration changed, and reload the conf: 54 | 55 | postgres=# select pg_reload_conf(); 56 | pg_reload_conf 57 | ---------------- 58 | t 59 | (1 row) 60 | 61 | Call again the snapshot function: 62 | 63 | postgres=# select * from pg_track_settings_snapshot(); 64 | pg_track_settings_snapshot 65 | ---------------------------- 66 | t 67 | (1 row) 68 | 69 | Now, we can check what settings changed: 70 | 71 | postgres=# SELECT * FROM pg_track_settings_diff(now() - interval '2 minutes', now()); 72 | name | from_setting | from_exists | to_setting | to_exists 73 | ---------------------+--------------|-------------|------------|---------- 74 | checkpoint_segments | 30 | t | 35 | t 75 | (1 row) 76 | 77 | And the detailed history of this setting: 78 | 79 | postgres=# SELECT * FROM pg_track_settings_log('checkpoint_segments'); 80 | ts | name | setting_exists | setting 81 | -------------------------------+---------------------+----------------+--------- 82 | 2015-01-25 01:01:42.581682+01 | checkpoint_segments | t | 35 83 | 2015-01-25 01:00:37.449846+01 | checkpoint_segments | t | 30 84 | (2 rows) 85 | 86 | And you can retrieve all the PostgreSQL configuration at a specific timestamp: 87 | 88 | 89 | postgres=# SELECT * FROM pg_track_settings('2015-01-25 01:01:00'); 90 | name | setting 91 | ------------------------------+--------- 92 | [...] 93 | checkpoint_completion_target | 0.9 94 | checkpoint_segments | 30 95 | checkpoint_timeout | 300 96 | [...] 97 | 98 | The same functions are provided for per role and/or database settings ( 99 | **ALTER ROLE ... SET**, **ALTER ROLE ... IN DATABASE ... SET** and 100 | **ALTER DATABASE ... SET** commands): 101 | 102 | - pg\_track\_db\_role\_settings\_diff() 103 | - pg\_track\_db\_role\_settings\_log() 104 | - pg\_track\_db\_role\_settings() 105 | 106 | We also have the history of postgres start time: 107 | 108 | postgres=# SELECT * FROM pg_reboot; 109 | ts 110 | ------------------------------- 111 | 2015-01-25 00:39:43.609195+01 112 | (1 row) 113 | 114 | Please also note that all the history will be saved in a pg\_dump / pg\_dumpall 115 | backup. If you need the clear this history, the function 116 | **pg\_track\_settings\_reset()** will do that for you. 117 | -------------------------------------------------------------------------------- /debian/changelog: -------------------------------------------------------------------------------- 1 | pg-track-settings (2.1.2-2) unstable; urgency=medium 2 | 3 | * Team upload. 4 | * Upload for PostgreSQL 16. 5 | * Use ${postgresql:Depends}. 6 | 7 | -- Christoph Berg Sun, 17 Sep 2023 21:18:30 +0200 8 | 9 | pg-track-settings (2.1.2-1) unstable; urgency=medium 10 | 11 | * New upstream version. 12 | 13 | -- Julien Rouhaud Sat, 13 May 2023 15:50:49 +0800 14 | 15 | pg-track-settings (2.1.1-3) unstable; urgency=medium 16 | 17 | [ Debian Janitor ] 18 | * Remove constraints unnecessary since buster (oldstable): 19 | + Build-Depends: Drop versioned constraint on postgresql-server-dev-all. 20 | 21 | -- Christoph Berg Wed, 02 Nov 2022 12:24:17 +0100 22 | 23 | pg-track-settings (2.1.1-2) unstable; urgency=medium 24 | 25 | * Team upload for PostgreSQL 15. 26 | 27 | -- Christoph Berg Fri, 21 Oct 2022 11:04:29 +0200 28 | 29 | pg-track-settings (2.1.1-1) unstable; urgency=medium 30 | 31 | * Team upload with new upstream version. 32 | 33 | -- Christoph Berg Wed, 21 Sep 2022 14:20:44 +0200 34 | 35 | pg-track-settings (2.1.0-1) unstable; urgency=medium 36 | 37 | * New upstream version. 38 | 39 | -- Julien Rouhaud Tue, 20 Sep 2022 11:58:27 +0800 40 | 41 | pg-track-settings (2.0.1-2) unstable; urgency=medium 42 | 43 | * Team upload for PostgreSQL 14. 44 | 45 | -- Christoph Berg Fri, 15 Oct 2021 15:54:21 +0200 46 | 47 | pg-track-settings (2.0.1-1) unstable; urgency=medium 48 | 49 | * New upstream version. 50 | 51 | -- Julien Rouhaud Mon, 16 Nov 2020 16:46:05 +0100 52 | 53 | pg-track-settings (2.0.0-3) unstable; urgency=medium 54 | 55 | * Team upload. 56 | * Testsuite wants to run as postgres, so require root for autopkgtest. 57 | 58 | -- Christoph Berg Tue, 27 Oct 2020 10:59:52 +0100 59 | 60 | pg-track-settings (2.0.0-2) unstable; urgency=medium 61 | 62 | * Team upload for PostgreSQL 13. 63 | * Use dh --with pgxs_loop. 64 | * R³: no. 65 | * debian/tests: Use 'make' instead of postgresql-server-dev-all. 66 | 67 | -- Christoph Berg Mon, 19 Oct 2020 11:56:59 +0200 68 | 69 | pg-track-settings (2.0.0-1) unstable; urgency=medium 70 | 71 | * Initial release. 72 | 73 | -- Julien Rouhaud Fri, 07 Aug 2020 16:19:41 +0200 74 | -------------------------------------------------------------------------------- /debian/control: -------------------------------------------------------------------------------- 1 | Source: pg-track-settings 2 | Section: database 3 | Priority: optional 4 | Maintainer: Julien Rouhaud 5 | Standards-Version: 4.6.2 6 | Build-Depends: debhelper-compat (= 13), postgresql-server-dev-all 7 | Rules-Requires-Root: no 8 | Homepage: https://powa.readthedocs.io/ 9 | Vcs-Browser: https://github.com/rjuju/pg_track_settings 10 | Vcs-Git: https://github.com/rjuju/pg_track_settings.git 11 | 12 | Package: postgresql-16-pg-track-settings 13 | Architecture: all 14 | Depends: ${misc:Depends}, ${postgresql:Depends} 15 | Description: PostgreSQL extension tracking of configuration settings 16 | pg_track_settings is a small PostgreSQL extension that helps you keep track of 17 | PostgreSQL settings configuration. 18 | . 19 | It provides a function (pg_track_settings_snapshot()), that must be called 20 | regularly. At each call, it will store the settings that have been changed 21 | since last call. It will also track the postgresql start time if it's 22 | different from the last one. 23 | . 24 | This extension tracks both overall settings (the pg_settings view) and 25 | overloaded settings (the pg_db_role_setting table). 26 | -------------------------------------------------------------------------------- /debian/control.in: -------------------------------------------------------------------------------- 1 | Source: pg-track-settings 2 | Section: database 3 | Priority: optional 4 | Maintainer: Julien Rouhaud 5 | Standards-Version: 4.6.2 6 | Build-Depends: debhelper-compat (= 13), postgresql-server-dev-all 7 | Rules-Requires-Root: no 8 | Homepage: https://powa.readthedocs.io/ 9 | Vcs-Browser: https://github.com/rjuju/pg_track_settings 10 | Vcs-Git: https://github.com/rjuju/pg_track_settings.git 11 | 12 | Package: postgresql-PGVERSION-pg-track-settings 13 | Architecture: all 14 | Depends: ${misc:Depends}, ${postgresql:Depends} 15 | Description: PostgreSQL extension tracking of configuration settings 16 | pg_track_settings is a small PostgreSQL extension that helps you keep track of 17 | PostgreSQL settings configuration. 18 | . 19 | It provides a function (pg_track_settings_snapshot()), that must be called 20 | regularly. At each call, it will store the settings that have been changed 21 | since last call. It will also track the postgresql start time if it's 22 | different from the last one. 23 | . 24 | This extension tracks both overall settings (the pg_settings view) and 25 | overloaded settings (the pg_db_role_setting table). 26 | -------------------------------------------------------------------------------- /debian/copyright: -------------------------------------------------------------------------------- 1 | Copyright (c) 2015-2024, Julien Rouhaud 2 | 3 | Permission to use, copy, modify, and distribute this software and its 4 | documentation for any purpose, without fee, and without a written agreement is 5 | hereby granted, provided that the above copyright notice and this paragraph and 6 | the following two paragraphs appear in all copies. 7 | 8 | IN NO EVENT SHALL Julien Rouhaud BE LIABLE TO ANY PARTY FOR DIRECT, INDIRECT, 9 | SPECIAL, INCIDENTAL, OR CONSEQUENTIAL DAMAGES, INCLUDING LOST PROFITS, ARISING 10 | OUT OF THE USE OF THIS SOFTWARE AND ITS DOCUMENTATION, EVEN IF Julien Rouhaud 11 | HAS BEEN ADVISED OF THE POSSIBILITY OF SUCH DAMAGE. 12 | 13 | Julien Rouhaud SPECIFICALLY DISCLAIMS ANY WARRANTIES, INCLUDING, BUT NOT 14 | LIMITED TO, THE IMPLIED WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A 15 | PARTICULAR PURPOSE. THE SOFTWARE PROVIDED HEREUNDER IS ON AN "AS IS" BASIS, AND 16 | Julien Rouhaud HAS NO OBLIGATIONS TO PROVIDE MAINTENANCE, SUPPORT, UPDATES, 17 | ENHANCEMENTS, OR MODIFICATIONS. 18 | -------------------------------------------------------------------------------- /debian/pgversions: -------------------------------------------------------------------------------- 1 | 9.4+ 2 | -------------------------------------------------------------------------------- /debian/rules: -------------------------------------------------------------------------------- 1 | #!/usr/bin/make -f 2 | 3 | PKGVER = $(shell dpkg-parsechangelog | awk -F '[:-]' '/^Version:/ { print substr($$2, 2) }') 4 | EXCLUDE = --exclude-vcs --exclude=debian 5 | 6 | override_dh_installdocs: 7 | dh_installdocs --all README.md 8 | rm -rvf debian/*/usr/share/doc/postgresql-doc-* 9 | 10 | override_dh_pgxs_test: 11 | # defer testing to autopkgtest, tests want to run as postgres 12 | 13 | orig: debian/control clean 14 | cd .. && tar czf pg-track-settings_$(PKGVER).orig.tar.gz $(EXCLUDE) pg-track-settings-$(PKGVER) 15 | 16 | %: 17 | dh $@ --with pgxs_loop 18 | -------------------------------------------------------------------------------- /debian/source/format: -------------------------------------------------------------------------------- 1 | 3.0 (quilt) 2 | -------------------------------------------------------------------------------- /debian/tests/control: -------------------------------------------------------------------------------- 1 | Depends: @, make 2 | Tests: installcheck 3 | Restrictions: allow-stderr, needs-root 4 | -------------------------------------------------------------------------------- /debian/tests/installcheck: -------------------------------------------------------------------------------- 1 | #!/bin/sh 2 | 3 | set -eu 4 | 5 | pg_buildext installcheck 6 | -------------------------------------------------------------------------------- /debian/watch: -------------------------------------------------------------------------------- 1 | version=3 2 | https://github.com/rjuju/pg_track_settings/tags .*/([0-9.]*).tar.gz 3 | -------------------------------------------------------------------------------- /expected/pg_track_settings.out: -------------------------------------------------------------------------------- 1 | SET search_path = ''; 2 | SET timezone TO 'Europe/Paris'; 3 | -- Remove any known per db setting set by pg_regress 4 | DO $$ 5 | DECLARE 6 | dbname text = current_database(); 7 | s text; 8 | BEGIN 9 | FOREACH s IN ARRAY ARRAY['lc_messages', 'lc_monetary', 'lc_numeric', 'lc_time', 10 | 'bytea_output', 'timezone_abbreviations'] 11 | LOOP 12 | EXECUTE format('ALTER DATABASE %I RESET %s', dbname, s); 13 | END LOOP; 14 | END; 15 | $$ LANGUAGE plpgsql; 16 | -- There shouldn't be any db/role setting left. It's unfortunately not 17 | -- guaranteed to be the case if the regression tests are run on a non-default 18 | -- cluster. 19 | SELECT d.datname, s.setconfig 20 | FROM pg_db_role_setting s 21 | JOIN pg_database d on s.setdatabase = d.oid; 22 | datname | setconfig 23 | ---------+----------- 24 | (0 rows) 25 | 26 | CREATE SCHEMA "PGTS"; 27 | -- Extension should be installable in a custom schema 28 | CREATE EXTENSION pg_track_settings WITH SCHEMA "PGTS"; 29 | -- But not relocatable 30 | ALTER EXTENSION pg_track_settings SET SCHEMA public; 31 | ERROR: extension "pg_track_settings" does not support SET SCHEMA 32 | -- Check the relations that aren't dumped 33 | WITH ext AS ( 34 | SELECT c.oid, c.relname 35 | FROM pg_depend d 36 | JOIN pg_extension e ON d.refclassid = 'pg_extension'::regclass 37 | AND e.oid = d.refobjid 38 | AND e.extname = 'pg_track_settings' 39 | JOIN pg_class c ON d.classid = 'pg_class'::regclass 40 | AND c.oid = d.objid 41 | ), 42 | dmp AS ( 43 | SELECT unnest(extconfig) AS oid 44 | FROM pg_extension 45 | WHERE extname = 'pg_track_settings' 46 | ) 47 | SELECT ext.relname 48 | FROM ext 49 | LEFT JOIN dmp USING (oid) 50 | WHERE dmp.oid IS NULL 51 | ORDER BY ext.relname::text COLLATE "C"; 52 | relname 53 | ------------------------------------ 54 | pg_track_settings_rds_src_tmp 55 | pg_track_settings_reboot_src_tmp 56 | pg_track_settings_settings_src_tmp 57 | (3 rows) 58 | 59 | -- Check that all objects are stored in the expected schema 60 | WITH ext AS ( 61 | SELECT pg_describe_object(d.classid, d.objid, d.objsubid) AS descr 62 | FROM pg_depend d 63 | JOIN pg_extension e ON d.refclassid = 'pg_extension'::regclass 64 | AND e.oid = d.refobjid 65 | AND e.extname = 'pg_track_settings' 66 | ) 67 | SELECT descr FROM ext 68 | WHERE descr NOT like '%"PGTS".%' 69 | ORDER BY descr COLLATE "C"; 70 | descr 71 | ------- 72 | (0 rows) 73 | 74 | -- test main config history 75 | SELECT COUNT(*) FROM "PGTS".pg_track_settings_history; 76 | count 77 | ------- 78 | 0 79 | (1 row) 80 | 81 | SET work_mem = '10MB'; 82 | SELECT * FROM "PGTS".pg_track_settings_snapshot(); 83 | pg_track_settings_snapshot 84 | ---------------------------- 85 | t 86 | (1 row) 87 | 88 | SELECT pg_catalog.pg_sleep(1); 89 | pg_sleep 90 | ---------- 91 | 92 | (1 row) 93 | 94 | SET work_mem = '5MB'; 95 | SELECT * FROM "PGTS".pg_track_settings_snapshot(); 96 | pg_track_settings_snapshot 97 | ---------------------------- 98 | t 99 | (1 row) 100 | 101 | SELECT name, setting_exists, setting, setting_pretty FROM "PGTS".pg_track_settings_log('work_mem') ORDER BY ts ASC; 102 | name | setting_exists | setting | setting_pretty 103 | ----------+----------------+---------+---------------- 104 | work_mem | t | 10240 | 10MB 105 | work_mem | t | 5120 | 5MB 106 | (2 rows) 107 | 108 | SELECT name, from_setting, from_exists, to_setting, to_exists, from_setting_pretty, to_setting_pretty FROM "PGTS".pg_track_settings_diff(now() - interval '500 ms', now()); 109 | name | from_setting | from_exists | to_setting | to_exists | from_setting_pretty | to_setting_pretty 110 | ----------+--------------+-------------+------------+-----------+---------------------+------------------- 111 | work_mem | 10240 | t | 5120 | t | 10MB | 5MB 112 | (1 row) 113 | 114 | -- test pg_db_role_settings 115 | ALTER DATABASE postgres SET work_mem = '1MB'; 116 | SELECT * FROM "PGTS".pg_track_settings_snapshot(); 117 | pg_track_settings_snapshot 118 | ---------------------------- 119 | t 120 | (1 row) 121 | 122 | ALTER ROLE postgres SET work_mem = '2MB'; 123 | SELECT * FROM "PGTS".pg_track_settings_snapshot(); 124 | pg_track_settings_snapshot 125 | ---------------------------- 126 | t 127 | (1 row) 128 | 129 | ALTER ROLE postgres IN DATABASE postgres SET work_mem = '3MB'; 130 | SELECT * FROM "PGTS".pg_track_settings_snapshot(); 131 | pg_track_settings_snapshot 132 | ---------------------------- 133 | t 134 | (1 row) 135 | 136 | SELECT * FROM "PGTS".pg_track_settings_snapshot(); 137 | pg_track_settings_snapshot 138 | ---------------------------- 139 | t 140 | (1 row) 141 | 142 | SELECT COALESCE(datname, '-') AS datname, setrole::regrole, name, setting_exists, setting FROM "PGTS".pg_track_db_role_settings_log('work_mem') s LEFT JOIN pg_database d ON d.oid = s.setdatabase ORDER BY ts ASC; 143 | datname | setrole | name | setting_exists | setting 144 | ----------+----------+----------+----------------+--------- 145 | postgres | - | work_mem | t | 1MB 146 | - | postgres | work_mem | t | 2MB 147 | postgres | postgres | work_mem | t | 3MB 148 | (3 rows) 149 | 150 | SELECT COALESCE(datname, '-') AS datname, setrole::regrole, name, from_setting, from_exists, to_setting, to_exists FROM "PGTS".pg_track_db_role_settings_diff(now() - interval '10 min', now()) s LEFT JOIN pg_database d ON d.oid = s.setdatabase WHERE name = 'work_mem' ORDER BY 1, 2, 3; 151 | datname | setrole | name | from_setting | from_exists | to_setting | to_exists 152 | ----------+----------+----------+--------------+-------------+------------+----------- 153 | - | postgres | work_mem | | f | 2MB | t 154 | postgres | - | work_mem | | f | 1MB | t 155 | postgres | postgres | work_mem | | f | 3MB | t 156 | (3 rows) 157 | 158 | ALTER DATABASE postgres RESET work_mem; 159 | SELECT * FROM "PGTS".pg_track_settings_snapshot(); 160 | pg_track_settings_snapshot 161 | ---------------------------- 162 | t 163 | (1 row) 164 | 165 | ALTER ROLE postgres RESET work_mem; 166 | SELECT * FROM "PGTS".pg_track_settings_snapshot(); 167 | pg_track_settings_snapshot 168 | ---------------------------- 169 | t 170 | (1 row) 171 | 172 | ALTER ROLE postgres IN DATABASE postgres RESET work_mem; 173 | SELECT * FROM "PGTS".pg_track_settings_snapshot(); 174 | pg_track_settings_snapshot 175 | ---------------------------- 176 | t 177 | (1 row) 178 | 179 | -- test pg_reboot 180 | SELECT COUNT(*) FROM "PGTS".pg_reboot; 181 | count 182 | ------- 183 | 1 184 | (1 row) 185 | 186 | SELECT now() - ts > interval '2 second' FROM "PGTS".pg_reboot; 187 | ?column? 188 | ---------- 189 | t 190 | (1 row) 191 | 192 | SELECT now() - ts > interval '2 second' FROM "PGTS".pg_track_reboot_log(); 193 | ?column? 194 | ---------- 195 | t 196 | (1 row) 197 | 198 | -- test the reset 199 | SELECT * FROM "PGTS".pg_track_settings_reset(); 200 | pg_track_settings_reset 201 | ------------------------- 202 | 203 | (1 row) 204 | 205 | SELECT COUNT(*) FROM "PGTS".pg_track_settings_history; 206 | count 207 | ------- 208 | 0 209 | (1 row) 210 | 211 | SELECT COUNT(*) FROM "PGTS".pg_track_settings_log('work_mem'); 212 | count 213 | ------- 214 | 0 215 | (1 row) 216 | 217 | SELECT COUNT(*) FROM "PGTS".pg_track_settings_diff(now() - interval '1 hour', now()); 218 | count 219 | ------- 220 | 0 221 | (1 row) 222 | 223 | SELECT COUNT(*) FROM "PGTS".pg_track_db_role_settings_log('work_mem'); 224 | count 225 | ------- 226 | 0 227 | (1 row) 228 | 229 | SELECT COUNT(*) FROM "PGTS".pg_track_db_role_settings_diff(now() - interval '1 hour', now()); 230 | count 231 | ------- 232 | 0 233 | (1 row) 234 | 235 | SELECT COUNT(*) FROM "PGTS".pg_reboot; 236 | count 237 | ------- 238 | 0 239 | (1 row) 240 | 241 | -------------------------- 242 | -- test remote snapshot -- 243 | -------------------------- 244 | -- fake general settings 245 | INSERT INTO "PGTS".pg_track_settings_settings_src_tmp 246 | (srvid, ts, name, setting, current_setting) 247 | VALUES 248 | (1, '2019-01-01 00:00:00 CET', 'work_mem', '0', '1MB'), 249 | (2, '2019-01-02 00:00:00 CET', 'work_mem', '0', '2MB'); 250 | -- fake rds settings 251 | INSERT INTO "PGTS".pg_track_settings_rds_src_tmp 252 | (srvid, ts, name, setting, setdatabase, setrole) 253 | VALUES 254 | (1, '2019-01-01 00:00:00 CET', 'work_mem', '1MB', 123, 0), 255 | (2, '2019-01-02 00:00:00 CET', 'work_mem', '2MB', 456, 0); 256 | -- fake reboot settings 257 | INSERT INTO "PGTS".pg_track_settings_reboot_src_tmp 258 | (srvid, ts, postmaster_ts) 259 | VALUES 260 | (1, '2019-01-01 00:01:00 CET', '2019-01-01 00:00:00 CET'), 261 | (2, '2019-01-02 00:01:00 CET', '2019-01-02 00:00:00 CET'); 262 | SELECT "PGTS".pg_track_settings_snapshot_settings(1); 263 | pg_track_settings_snapshot_settings 264 | ------------------------------------- 265 | t 266 | (1 row) 267 | 268 | SELECT "PGTS".pg_track_settings_snapshot_rds(1); 269 | pg_track_settings_snapshot_rds 270 | -------------------------------- 271 | t 272 | (1 row) 273 | 274 | SELECT "PGTS".pg_track_settings_snapshot_reboot(1); 275 | pg_track_settings_snapshot_reboot 276 | ----------------------------------- 277 | t 278 | (1 row) 279 | 280 | -- snapshot of remote server 1 shouldn't impact data for server 2 281 | SELECT srvid, count(*) FROM "PGTS".pg_track_settings_settings_src_tmp GROUP BY srvid; 282 | srvid | count 283 | -------+------- 284 | 2 | 1 285 | (1 row) 286 | 287 | SELECT srvid, count(*) FROM "PGTS".pg_track_settings_rds_src_tmp GROUP BY srvid; 288 | srvid | count 289 | -------+------- 290 | 2 | 1 291 | (1 row) 292 | 293 | SELECT srvid, count(*) FROM "PGTS".pg_track_settings_reboot_src_tmp GROUP BY srvid; 294 | srvid | count 295 | -------+------- 296 | 2 | 1 297 | (1 row) 298 | 299 | -- fake general settings 300 | INSERT INTO "PGTS".pg_track_settings_settings_src_tmp 301 | (srvid, ts, name, setting, current_setting) 302 | VALUES 303 | -- previously untreated data that should be discarded 304 | (1, '2019-01-02 00:00:00 CET', 'work_mem', '5120', '5MB'), 305 | -- data that should be processed 306 | (1, '2019-01-02 01:00:00 CET', 'work_mem', '10240', '10MB'), 307 | (1, '2019-01-02 01:00:00 CET', 'something', 'someval', 'someval'); 308 | -- fake rds settings 309 | INSERT INTO "PGTS".pg_track_settings_rds_src_tmp 310 | (srvid, ts, name, setting, setdatabase, setrole) 311 | VALUES 312 | -- previously untreated data that should be discarded 313 | (1, '2019-01-02 00:00:00 CET', 'work_mem', '5MB', 123, 0), 314 | -- data that should be processed 315 | (1, '2019-01-02 01:00:00 CET', 'work_mem', '10MB', 123, 0), 316 | (1, '2019-01-02 01:00:00 CET', 'something', 'someval', 0, 456); 317 | -- fake reboot settings 318 | INSERT INTO "PGTS".pg_track_settings_reboot_src_tmp 319 | (srvid, ts, postmaster_ts) 320 | VALUES 321 | -- previously untreated data that should not be discarded 322 | (1, '2019-01-02 00:01:00 CET', '2019-01-02 00:00:00 CET'), 323 | -- data that should also be processed 324 | (1, '2019-01-02 02:01:00 CET', '2019-01-02 01:00:00 CET'); 325 | SELECT "PGTS".pg_track_settings_snapshot_settings(1); 326 | pg_track_settings_snapshot_settings 327 | ------------------------------------- 328 | t 329 | (1 row) 330 | 331 | SELECT "PGTS".pg_track_settings_snapshot_rds(1); 332 | pg_track_settings_snapshot_rds 333 | -------------------------------- 334 | t 335 | (1 row) 336 | 337 | SELECT "PGTS".pg_track_settings_snapshot_reboot(1); 338 | pg_track_settings_snapshot_reboot 339 | ----------------------------------- 340 | t 341 | (1 row) 342 | 343 | -- test raw data 344 | SELECT * FROM "PGTS".pg_track_settings_list ORDER BY 1, 2; 345 | srvid | name 346 | -------+----------- 347 | 1 | something 348 | 1 | work_mem 349 | (2 rows) 350 | 351 | SELECT * FROM "PGTS".pg_track_settings_history ORDER BY 1, 2, 3; 352 | srvid | ts | name | setting | is_dropped | setting_pretty 353 | -------+------------------------------+-----------+---------+------------+---------------- 354 | 1 | Tue Jan 01 00:00:00 2019 CET | work_mem | 0 | f | 1MB 355 | 1 | Wed Jan 02 01:00:00 2019 CET | something | someval | f | someval 356 | 1 | Wed Jan 02 01:00:00 2019 CET | work_mem | 10240 | f | 10MB 357 | (3 rows) 358 | 359 | SELECT * FROM "PGTS".pg_track_db_role_settings_list ORDER BY 1, 2; 360 | srvid | name | setdatabase | setrole 361 | -------+-----------+-------------+--------- 362 | 1 | something | 0 | 456 363 | 1 | work_mem | 123 | 0 364 | (2 rows) 365 | 366 | SELECT * FROM "PGTS".pg_track_db_role_settings_history ORDER BY 1, 2, 3; 367 | srvid | ts | name | setdatabase | setrole | setting | is_dropped 368 | -------+------------------------------+-----------+-------------+---------+---------+------------ 369 | 1 | Tue Jan 01 00:00:00 2019 CET | work_mem | 123 | 0 | 1MB | f 370 | 1 | Wed Jan 02 01:00:00 2019 CET | something | 0 | 456 | someval | f 371 | 1 | Wed Jan 02 01:00:00 2019 CET | work_mem | 123 | 0 | 10MB | f 372 | (3 rows) 373 | 374 | SELECT * FROM "PGTS".pg_reboot ORDER BY 1, 2; 375 | srvid | ts 376 | -------+------------------------------ 377 | 1 | Tue Jan 01 00:00:00 2019 CET 378 | 1 | Wed Jan 02 00:00:00 2019 CET 379 | 1 | Wed Jan 02 01:00:00 2019 CET 380 | (3 rows) 381 | 382 | -- test functions 383 | SELECT name, setting_exists, setting, setting_pretty 384 | FROM "PGTS".pg_track_settings_log('work_mem', 1) 385 | ORDER BY ts ASC; 386 | name | setting_exists | setting | setting_pretty 387 | ----------+----------------+---------+---------------- 388 | work_mem | t | 0 | 1MB 389 | work_mem | t | 10240 | 10MB 390 | (2 rows) 391 | 392 | SELECT name, from_setting, from_exists, to_setting, to_exists, 393 | from_setting_pretty, to_setting_pretty 394 | FROM "PGTS".pg_track_settings_diff('2019-01-01 01:00:00 CET', 395 | '2019-01-02 02:00:00 CET', 1); 396 | name | from_setting | from_exists | to_setting | to_exists | from_setting_pretty | to_setting_pretty 397 | -----------+--------------+-------------+------------+-----------+---------------------+------------------- 398 | something | | f | someval | t | | someval 399 | work_mem | 0 | t | 10240 | t | 1MB | 10MB 400 | (2 rows) 401 | 402 | SELECT * 403 | FROM "PGTS".pg_track_db_role_settings_log('work_mem', 1) s 404 | ORDER BY ts ASC; 405 | ts | setdatabase | setrole | name | setting_exists | setting 406 | ------------------------------+-------------+---------+----------+----------------+--------- 407 | Tue Jan 01 00:00:00 2019 CET | 123 | 0 | work_mem | t | 1MB 408 | Wed Jan 02 01:00:00 2019 CET | 123 | 0 | work_mem | t | 10MB 409 | (2 rows) 410 | 411 | SELECT * 412 | FROM "PGTS".pg_track_db_role_settings_diff('2018-12-31 02:00:00 CET', 413 | '2019-01-02 03:00:00 CET', 1) s 414 | WHERE name = 'work_mem' ORDER BY 1, 2, 3; 415 | setdatabase | setrole | name | from_setting | from_exists | to_setting | to_exists 416 | -------------+---------+----------+--------------+-------------+------------+----------- 417 | 123 | 0 | work_mem | | f | 10MB | t 418 | (1 row) 419 | 420 | SELECT * FROM "PGTS".pg_track_reboot_log(1); 421 | ts 422 | ------------------------------ 423 | Tue Jan 01 00:00:00 2019 CET 424 | Wed Jan 02 00:00:00 2019 CET 425 | Wed Jan 02 01:00:00 2019 CET 426 | (3 rows) 427 | 428 | -- snapshot the pending server 2 429 | SELECT "PGTS".pg_track_settings_snapshot_settings(2); 430 | pg_track_settings_snapshot_settings 431 | ------------------------------------- 432 | t 433 | (1 row) 434 | 435 | SELECT "PGTS".pg_track_settings_snapshot_rds(2); 436 | pg_track_settings_snapshot_rds 437 | -------------------------------- 438 | t 439 | (1 row) 440 | 441 | SELECT "PGTS".pg_track_settings_snapshot_reboot(2); 442 | pg_track_settings_snapshot_reboot 443 | ----------------------------------- 444 | t 445 | (1 row) 446 | 447 | -- check that all data have been deleted after processing 448 | SELECT COUNT(*) FROM "PGTS".pg_track_settings_settings_src_tmp; 449 | count 450 | ------- 451 | 0 452 | (1 row) 453 | 454 | SELECT COUNT(*) FROM "PGTS".pg_track_settings_rds_src_tmp; 455 | count 456 | ------- 457 | 0 458 | (1 row) 459 | 460 | SELECT COUNT(*) FROM "PGTS".pg_track_settings_reboot_src_tmp; 461 | count 462 | ------- 463 | 0 464 | (1 row) 465 | 466 | -- test the reset 467 | SELECT * FROM "PGTS".pg_track_settings_reset(1); 468 | pg_track_settings_reset 469 | ------------------------- 470 | 471 | (1 row) 472 | 473 | SELECT srvid, COUNT(*) FROM "PGTS".pg_track_settings_history GROUP BY srvid; 474 | srvid | count 475 | -------+------- 476 | 2 | 1 477 | (1 row) 478 | 479 | SELECT COUNT(*) FROM "PGTS".pg_track_settings_log('work_mem', 1); 480 | count 481 | ------- 482 | 0 483 | (1 row) 484 | 485 | SELECT COUNT(*) FROM "PGTS".pg_track_settings_diff('-infinity', 'infinity', 1); 486 | count 487 | ------- 488 | 0 489 | (1 row) 490 | 491 | SELECT COUNT(*) FROM "PGTS".pg_track_db_role_settings_log('work_mem', 1); 492 | count 493 | ------- 494 | 0 495 | (1 row) 496 | 497 | SELECT COUNT(*) FROM "PGTS".pg_track_db_role_settings_diff('-infinity', 'infinity', 1); 498 | count 499 | ------- 500 | 0 501 | (1 row) 502 | 503 | SELECT srvid, COUNT(*) FROM "PGTS".pg_track_db_role_settings_history GROUP BY srvid; 504 | srvid | count 505 | -------+------- 506 | 2 | 1 507 | (1 row) 508 | 509 | SELECT srvid, COUNT(*) FROM "PGTS".pg_reboot GROUP BY srvid; 510 | srvid | count 511 | -------+------- 512 | 2 | 1 513 | (1 row) 514 | 515 | -------------------------------------------------------------------------------- /pg_track_settings--1.0.0--1.0.1.sql: -------------------------------------------------------------------------------- 1 | -- This program is open source, licensed under the PostgreSQL License. 2 | -- For license terms, see the LICENSE file. 3 | -- 4 | -- Copyright (C) 2015-2022: Julien Rouhaud 5 | 6 | -- complain if script is sourced in psql, rather than via ALTER EXTENSION 7 | \echo Use "ALTER EXTENSION pg_track_settings" to load this file. \quit 8 | 9 | SET client_encoding = 'UTF8'; 10 | 11 | CREATE OR REPLACE FUNCTION pg_track_settings_snapshot() RETURNS boolean AS 12 | $_$ 13 | BEGIN 14 | -- Handle dropped GUC 15 | WITH dropped AS ( 16 | SELECT l.name 17 | FROM pg_track_settings_list l 18 | LEFT JOIN pg_settings s ON s.name = l.name 19 | WHERE s.name IS NULL 20 | ), 21 | mark_dropped AS ( 22 | INSERT INTO pg_track_settings_history (ts, name, setting, is_dropped) 23 | SELECT now(), name, NULL, true 24 | FROM dropped 25 | ) 26 | DELETE FROM pg_track_settings_list l 27 | USING dropped d 28 | WHERE d.name = l.name; 29 | 30 | -- Insert missing settings 31 | INSERT INTO pg_track_settings_list (name) 32 | SELECT name 33 | FROM pg_settings s 34 | WHERE NOT EXISTS (SELECT 1 35 | FROM pg_track_settings_list l 36 | WHERE l.name = s.name 37 | ); 38 | 39 | -- Detect changed GUC, insert new vals 40 | WITH last_snapshot AS ( 41 | SELECT name, setting 42 | FROM ( 43 | SELECT name, setting, row_number() OVER (PARTITION BY NAME ORDER BY ts DESC) rownum 44 | FROM pg_track_settings_history 45 | ) all_snapshots 46 | WHERE rownum = 1 47 | ) 48 | INSERT INTO pg_track_settings_history (ts, name, setting) 49 | SELECT now(), s.name, s.setting 50 | FROM pg_settings s 51 | LEFT JOIN last_snapshot l ON l.name = s.name 52 | WHERE l.name IS NULL 53 | OR l.setting IS DISTINCT FROM s.setting; 54 | 55 | -- Handle dropped db_role_setting 56 | WITH rds AS ( 57 | SELECT setdatabase, setrole, 58 | (regexp_split_to_array(unnest(setconfig),'=')::text[])[1] as name, 59 | (regexp_split_to_array(unnest(setconfig),'=')::text[])[2] as setting 60 | FROM pg_db_role_setting 61 | ), 62 | dropped AS ( 63 | SELECT l.setdatabase, l.setrole, l.name 64 | FROM pg_track_db_role_settings_list l 65 | LEFT JOIN rds s ON ( 66 | s.setdatabase = l.setdatabase 67 | AND s.setrole = l.setrole 68 | AND s.name = l.name 69 | ) 70 | WHERE s.setdatabase IS NULL 71 | AND s.setrole IS NULL 72 | AND s.name IS NULL 73 | ), 74 | mark_dropped AS ( 75 | INSERT INTO pg_track_db_role_settings_history 76 | (ts, setdatabase, setrole, name, setting, is_dropped) 77 | SELECT now(), setdatabase, setrole, name, NULL, true 78 | FROM dropped 79 | ) 80 | DELETE FROM pg_track_db_role_settings_list l 81 | USING dropped d 82 | WHERE 83 | d.setdatabase = l.setdatabase 84 | AND d.setrole = l.setrole 85 | AND d.name = l.name; 86 | 87 | -- Insert missing settings 88 | WITH rds AS ( 89 | SELECT setdatabase, setrole, 90 | (regexp_split_to_array(unnest(setconfig),'=')::text[])[1] as name, 91 | (regexp_split_to_array(unnest(setconfig),'=')::text[])[2] as setting 92 | FROM pg_db_role_setting 93 | ) 94 | INSERT INTO pg_track_db_role_settings_list 95 | (setdatabase, setrole, name) 96 | SELECT setdatabase, setrole, name 97 | FROM rds s 98 | WHERE NOT EXISTS (SELECT 1 99 | FROM pg_track_db_role_settings_list l 100 | WHERE 101 | l.setdatabase = s.setdatabase 102 | AND l.setrole = l.setrole 103 | AND l.name = s.name 104 | ); 105 | 106 | -- Detect changed GUC, insert new vals 107 | WITH rds AS ( 108 | SELECT setdatabase, setrole, 109 | (regexp_split_to_array(unnest(setconfig),'=')::text[])[1] as name, 110 | (regexp_split_to_array(unnest(setconfig),'=')::text[])[2] as setting 111 | FROM pg_db_role_setting 112 | ), 113 | last_snapshot AS ( 114 | SELECT setdatabase, setrole, name, setting 115 | FROM ( 116 | SELECT setdatabase, setrole, name, setting, 117 | row_number() OVER (PARTITION BY name, setdatabase, setrole ORDER BY ts DESC) rownum 118 | FROM pg_track_db_role_settings_history 119 | ) all_snapshots 120 | WHERE rownum = 1 121 | ) 122 | INSERT INTO pg_track_db_role_settings_history 123 | (ts, setdatabase, setrole, name, setting) 124 | SELECT now(), s.setdatabase, s.setrole, s.name, s.setting 125 | FROM rds s 126 | LEFT JOIN last_snapshot l ON 127 | l.setdatabase = s.setdatabase 128 | AND l.setrole = s.setrole 129 | AND l.name = s.name 130 | WHERE l.setdatabase IS NULL 131 | AND l.setrole IS NULL 132 | AND l.name IS NULL 133 | OR l.setting IS DISTINCT FROM s.setting; 134 | 135 | -- Detect is postmaster restarted since last call 136 | WITH last_reboot AS ( 137 | SELECT t FROM pg_postmaster_start_time() t 138 | ) 139 | INSERT INTO pg_reboot (ts) 140 | SELECT t FROM last_reboot lr 141 | WHERE NOT EXISTS (SELECT 1 142 | FROM pg_reboot r 143 | WHERE r.ts = lr.t 144 | ); 145 | 146 | RETURN true; 147 | END; 148 | $_$ 149 | LANGUAGE plpgsql; 150 | 151 | CREATE OR REPLACE FUNCTION pg_track_db_role_settings(_ts timestamp with time zone DEFAULT now()) 152 | RETURNS TABLE (setdatabase oid, setrole oid, name text, setting text) AS 153 | $_$ 154 | BEGIN 155 | RETURN QUERY 156 | SELECT s.setdatabase, s.setrole, s.name, s.setting 157 | FROM ( 158 | SELECT h.setdatabase, h.setrole, h.name, h.setting, h.is_dropped, 159 | row_number() OVER (PARTITION BY h.name, h.setdatabase, h.setrole ORDER BY h.ts DESC) AS rownum 160 | FROM pg_track_db_role_settings_history h 161 | WHERE ts <= _ts 162 | ) s 163 | WHERE s.rownum = 1 164 | AND NOT s.is_dropped 165 | ORDER BY s.setdatabase, s.setrole, s.name; 166 | END; 167 | $_$ 168 | LANGUAGE plpgsql; 169 | -------------------------------------------------------------------------------- /pg_track_settings--1.0.0.sql: -------------------------------------------------------------------------------- 1 | -- This program is open source, licensed under the PostgreSQL License. 2 | -- For license terms, see the LICENSE file. 3 | -- 4 | -- Copyright (C) 2015-2024: Julien Rouhaud 5 | 6 | -- complain if script is sourced in psql, rather than via CREATE EXTENSION 7 | \echo Use "CREATE EXTENSION pg_track_settings" to load this file. \quit 8 | 9 | SET client_encoding = 'UTF8'; 10 | 11 | CREATE TABLE pg_track_settings_list ( 12 | name text PRIMARY KEY 13 | ); 14 | SELECT pg_catalog.pg_extension_config_dump('pg_track_settings_list', ''); 15 | 16 | CREATE TABLE pg_track_settings_history ( 17 | ts timestamp with time zone, 18 | name text, 19 | setting text, 20 | is_dropped boolean NOT NULL DEFAULT false, 21 | PRIMARY KEY(ts, name) 22 | ); 23 | SELECT pg_catalog.pg_extension_config_dump('pg_track_settings_history', ''); 24 | 25 | CREATE TABLE pg_track_db_role_settings_list ( 26 | name text, 27 | setdatabase oid, 28 | setrole oid, 29 | PRIMARY KEY (name, setdatabase, setrole) 30 | ); 31 | SELECT pg_catalog.pg_extension_config_dump('pg_track_db_role_settings_list', ''); 32 | 33 | CREATE TABLE pg_track_db_role_settings_history ( 34 | ts timestamp with time zone, 35 | name text, 36 | setdatabase oid, 37 | setrole oid, 38 | setting text, 39 | is_dropped boolean NOT NULL DEFAULT false, 40 | PRIMARY KEY(ts, name, setdatabase, setrole) 41 | ); 42 | SELECT pg_catalog.pg_extension_config_dump('pg_track_db_role_settings_history', ''); 43 | 44 | CREATE TABLE pg_reboot ( 45 | ts timestamp with time zone PRIMARY KEY 46 | ); 47 | SELECT pg_catalog.pg_extension_config_dump('pg_reboot', ''); 48 | 49 | CREATE OR REPLACE FUNCTION pg_track_settings_snapshot() RETURNS boolean AS 50 | $_$ 51 | BEGIN 52 | -- Handle dropped GUC 53 | WITH dropped AS ( 54 | SELECT l.name 55 | FROM pg_track_settings_list l 56 | LEFT JOIN pg_settings s ON s.name = l.name 57 | WHERE s.name IS NULL 58 | ), 59 | mark_dropped AS ( 60 | INSERT INTO pg_track_settings_history (ts, name, setting, is_dropped) 61 | SELECT now(), name, NULL, true 62 | FROM dropped 63 | ) 64 | DELETE FROM pg_track_settings_list l 65 | USING dropped d 66 | WHERE d.name = l.name; 67 | 68 | -- Insert missing settings 69 | INSERT INTO pg_track_settings_list (name) 70 | SELECT name 71 | FROM pg_settings s 72 | WHERE NOT EXISTS (SELECT 1 73 | FROM pg_track_settings_list l 74 | WHERE l.name = s.name 75 | ); 76 | 77 | -- Detect changed GUC, insert new vals 78 | WITH last_snapshot AS ( 79 | SELECT name, setting 80 | FROM ( 81 | SELECT name, setting, row_number() OVER (PARTITION BY NAME ORDER BY ts DESC) rownum 82 | FROM pg_track_settings_history 83 | ) all_snapshots 84 | WHERE rownum = 1 85 | ) 86 | INSERT INTO pg_track_settings_history (ts, name, setting) 87 | SELECT now(), s.name, s.setting 88 | FROM pg_settings s 89 | LEFT JOIN last_snapshot l ON l.name = s.name 90 | WHERE l.name IS NULL 91 | OR l.setting IS DISTINCT FROM s.setting; 92 | 93 | -- Handle dropped db_role_setting 94 | WITH rds AS ( 95 | SELECT setdatabase, setrole, 96 | (regexp_split_to_array(unnest(setconfig),'=')::text[])[1] as name, 97 | (regexp_split_to_array(unnest(setconfig),'=')::text[])[2] as setting 98 | FROM pg_db_role_setting 99 | ), 100 | dropped AS ( 101 | SELECT l.setdatabase, l.setrole, l.name 102 | FROM pg_track_db_role_settings_list l 103 | LEFT JOIN rds s ON ( 104 | s.setdatabase = l.setdatabase 105 | AND s.setrole = l.setrole 106 | AND s.name = l.name 107 | ) 108 | WHERE s.setdatabase IS NULL 109 | AND s.setrole IS NULL 110 | AND s.name IS NULL 111 | ), 112 | mark_dropped AS ( 113 | INSERT INTO pg_track_db_role_settings_history 114 | (ts, setdatabase, setrole, name, setting, is_dropped) 115 | SELECT now(), setdatabase, setrole, name, NULL, true 116 | FROM dropped 117 | ) 118 | DELETE FROM pg_track_db_role_settings_list l 119 | USING dropped d 120 | WHERE 121 | d.setdatabase = l.setdatabase 122 | AND d.setrole = l.setrole 123 | AND d.name = l.name; 124 | 125 | -- Insert missing settings 126 | WITH rds AS ( 127 | SELECT setdatabase, setrole, 128 | (regexp_split_to_array(unnest(setconfig),'=')::text[])[1] as name, 129 | (regexp_split_to_array(unnest(setconfig),'=')::text[])[2] as setting 130 | FROM pg_db_role_setting 131 | ) 132 | INSERT INTO pg_track_db_role_settings_list 133 | (setdatabase, setrole, name) 134 | SELECT setdatabase, setrole, name 135 | FROM rds s 136 | WHERE NOT EXISTS (SELECT 1 137 | FROM pg_track_db_role_settings_list l 138 | WHERE 139 | l.setdatabase = s.setdatabase 140 | AND l.setrole = l.setrole 141 | AND l.name = s.name 142 | ); 143 | 144 | -- Detect changed GUC, insert new vals 145 | WITH rds AS ( 146 | SELECT setdatabase, setrole, 147 | (regexp_split_to_array(unnest(setconfig),'=')::text[])[1] as name, 148 | (regexp_split_to_array(unnest(setconfig),'=')::text[])[2] as setting 149 | FROM pg_db_role_setting 150 | ), 151 | last_snapshot AS ( 152 | SELECT setdatabase, setrole, name, setting 153 | FROM ( 154 | SELECT setdatabase, setrole, name, setting, 155 | row_number() OVER (PARTITION BY NAME ORDER BY ts DESC) rownum 156 | FROM pg_track_db_role_settings_history 157 | ) all_snapshots 158 | WHERE rownum = 1 159 | ) 160 | INSERT INTO pg_track_db_role_settings_history 161 | (ts, setdatabase, setrole, name, setting) 162 | SELECT now(), s.setdatabase, s.setrole, s.name, s.setting 163 | FROM rds s 164 | LEFT JOIN last_snapshot l ON 165 | l.setdatabase = s.setdatabase 166 | AND l.setrole = s.setrole 167 | AND l.name = s.name 168 | WHERE l.setdatabase IS NULL 169 | AND l.setrole IS NULL 170 | AND l.name IS NULL 171 | OR l.setting IS DISTINCT FROM s.setting; 172 | 173 | -- Detect is postmaster restarted since last call 174 | WITH last_reboot AS ( 175 | SELECT t FROM pg_postmaster_start_time() t 176 | ) 177 | INSERT INTO pg_reboot (ts) 178 | SELECT t FROM last_reboot lr 179 | WHERE NOT EXISTS (SELECT 1 180 | FROM pg_reboot r 181 | WHERE r.ts = lr.t 182 | ); 183 | 184 | RETURN true; 185 | END; 186 | $_$ 187 | LANGUAGE plpgsql; 188 | 189 | CREATE OR REPLACE FUNCTION pg_track_settings(_ts timestamp with time zone DEFAULT now()) 190 | RETURNS TABLE (name text, setting text) AS 191 | $_$ 192 | BEGIN 193 | RETURN QUERY 194 | SELECT s.name, s.setting 195 | FROM ( 196 | SELECT h.name, h.setting, h.is_dropped, row_number() OVER (PARTITION BY h.name ORDER BY h.ts DESC) AS rownum 197 | FROM pg_track_settings_history h 198 | WHERE ts <= _ts 199 | ) s 200 | WHERE s.rownum = 1 201 | AND NOT s.is_dropped 202 | ORDER BY s.name; 203 | END; 204 | $_$ 205 | LANGUAGE plpgsql; 206 | 207 | CREATE OR REPLACE FUNCTION pg_track_db_role_settings(_ts timestamp with time zone DEFAULT now()) 208 | RETURNS TABLE (setdatabase oid, setrole oid, name text, setting text) AS 209 | $_$ 210 | BEGIN 211 | RETURN QUERY 212 | SELECT s.setdatabase, s.setrole, s.name, s.setting 213 | FROM ( 214 | SELECT h.setdatabase, h.setrole, h.name, h.setting, h.is_dropped, 215 | row_number() OVER (PARTITION BY h.name ORDER BY h.ts DESC) AS rownum 216 | FROM pg_track_db_role_settings_history h 217 | WHERE ts <= _ts 218 | ) s 219 | WHERE s.rownum = 1 220 | AND NOT s.is_dropped 221 | ORDER BY s.setdatabase, s.setrole, s.name; 222 | END; 223 | $_$ 224 | LANGUAGE plpgsql; 225 | 226 | CREATE OR REPLACE FUNCTION pg_track_settings_diff(_from timestamp with time zone, _to timestamp with time zone) 227 | RETURNS TABLE (name text, from_setting text, from_exists boolean, to_setting text, to_exists boolean) AS 228 | $_$ 229 | BEGIN 230 | RETURN QUERY 231 | SELECT COALESCE(s1.name, s2.name), 232 | s1.setting AS from_setting, 233 | CASE WHEN s1.setting IS NULL THEN false ELSE true END, 234 | s2.setting AS to_setting, 235 | CASE WHEN s2.setting IS NULL THEN false ELSE true END 236 | FROM pg_track_settings(_from) s1 237 | FULL OUTER JOIN pg_track_settings(_to) s2 ON s2.name = s1.name 238 | WHERE s1.setting IS DISTINCT FROM s2.setting 239 | ORDER BY 1; 240 | END; 241 | $_$ 242 | LANGUAGE plpgsql; 243 | 244 | CREATE OR REPLACE FUNCTION pg_track_db_role_settings_diff(_from timestamp with time zone, _to timestamp with time zone) 245 | RETURNS TABLE (setdatabase oid, setrole oid, name text, from_setting text, from_exists boolean, to_setting text, to_exists boolean) AS 246 | $_$ 247 | BEGIN 248 | RETURN QUERY 249 | SELECT COALESCE(s1.setdatabase, s2.setdatabase), 250 | COALESCE(s1.setrole, s2.setrole), 251 | COALESCE(s1.name, s2.name), 252 | s1.setting AS from_setting, 253 | CASE WHEN s1.setting IS NULL THEN false ELSE true END, 254 | s2.setting AS to_setting, 255 | CASE WHEN s2.setting IS NULL THEN false ELSE true END 256 | FROM pg_track_db_role_settings(_from) s1 257 | FULL OUTER JOIN pg_track_db_role_settings(_to) s2 ON 258 | s2.setdatabase = s1.setdatabase 259 | AND s2.setrole = s1.setrole 260 | AND s2.name = s1.name 261 | WHERE 262 | s1.setdatabase IS DISTINCT FROM s2.setdatabase 263 | AND s1.setrole IS DISTINCT FROM s2.setrole 264 | AND s1.setting IS DISTINCT FROM s2.setting 265 | ORDER BY 1, 2, 3; 266 | END; 267 | $_$ 268 | LANGUAGE plpgsql; 269 | 270 | CREATE OR REPLACE FUNCTION pg_track_settings_log(_name text) 271 | RETURNS TABLE (ts timestamp with time zone, name text, setting_exists boolean, setting text) AS 272 | $_$ 273 | BEGIN 274 | RETURN QUERY 275 | SELECT h.ts, h.name, NOT h.is_dropped, h.setting 276 | FROM pg_track_settings_history h 277 | WHERE h.name = _name 278 | ORDER BY ts DESC; 279 | END; 280 | $_$ 281 | LANGUAGE plpgsql; 282 | 283 | CREATE OR REPLACE FUNCTION pg_track_db_role_settings_log(_name text) 284 | RETURNS TABLE (ts timestamp with time zone, setdatabase oid, setrole oid, name text, setting_exists boolean, setting text) AS 285 | $_$ 286 | BEGIN 287 | RETURN QUERY 288 | SELECT h.ts, h.setdatabase, h.setrole, h.name, NOT h.is_dropped, h.setting 289 | FROM pg_track_db_role_settings_history h 290 | WHERE h.name = _name 291 | ORDER BY ts, setdatabase, setrole DESC; 292 | END; 293 | $_$ 294 | LANGUAGE plpgsql; 295 | 296 | CREATE OR REPLACE FUNCTION pg_track_settings_reset() 297 | RETURNS void AS 298 | $_$ 299 | BEGIN 300 | TRUNCATE pg_track_settings_list; 301 | TRUNCATE pg_track_settings_history; 302 | TRUNCATE pg_track_db_role_settings_list; 303 | TRUNCATE pg_track_db_role_settings_history; 304 | TRUNCATE pg_reboot; 305 | END; 306 | $_$ 307 | LANGUAGE plpgsql; 308 | -------------------------------------------------------------------------------- /pg_track_settings--1.0.1--1.1.0.sql: -------------------------------------------------------------------------------- 1 | -- This program is open source, licensed under the PostgreSQL License. 2 | -- For license terms, see the LICENSE file. 3 | -- 4 | -- Copyright (C) 2015-2022: Julien Rouhaud 5 | 6 | -- complain if script is sourced in psql, rather than via ALTER EXTENSION 7 | \echo Use "ALTER EXTENSION pg_track_settings" to load this file. \quit 8 | 9 | SET client_encoding = 'UTF8'; 10 | 11 | ALTER TABLE pg_track_settings_history ALTER COLUMN name SET NOT NULL; 12 | ALTER TABLE pg_track_settings_history ADD COLUMN setting_pretty text; 13 | 14 | CREATE OR REPLACE FUNCTION pg_track_settings_snapshot() RETURNS boolean AS 15 | $_$ 16 | BEGIN 17 | -- Handle dropped GUC 18 | WITH dropped AS ( 19 | SELECT l.name 20 | FROM pg_track_settings_list l 21 | LEFT JOIN pg_settings s ON s.name = l.name 22 | WHERE s.name IS NULL 23 | ), 24 | mark_dropped AS ( 25 | INSERT INTO pg_track_settings_history (ts, name, setting, 26 | setting_pretty, is_dropped) 27 | SELECT now(), name, NULL, NULL, true 28 | FROM dropped 29 | ) 30 | DELETE FROM pg_track_settings_list l 31 | USING dropped d 32 | WHERE d.name = l.name; 33 | 34 | -- Insert missing settings 35 | INSERT INTO pg_track_settings_list (name) 36 | SELECT name 37 | FROM pg_settings s 38 | WHERE NOT EXISTS (SELECT 1 39 | FROM pg_track_settings_list l 40 | WHERE l.name = s.name 41 | ); 42 | 43 | -- Detect changed GUC, insert new vals 44 | WITH last_snapshot AS ( 45 | SELECT name, setting 46 | FROM ( 47 | SELECT name, setting, row_number() OVER (PARTITION BY NAME ORDER BY ts DESC) rownum 48 | FROM pg_track_settings_history 49 | ) all_snapshots 50 | WHERE rownum = 1 51 | ) 52 | INSERT INTO pg_track_settings_history (ts, name, setting, setting_pretty) 53 | SELECT now(), s.name, s.setting, pg_catalog.current_setting(s.name) 54 | FROM pg_settings s 55 | LEFT JOIN last_snapshot l ON l.name = s.name 56 | WHERE l.name IS NULL 57 | OR l.setting IS DISTINCT FROM s.setting; 58 | 59 | -- Handle dropped db_role_setting 60 | WITH rds AS ( 61 | SELECT setdatabase, setrole, 62 | (regexp_split_to_array(unnest(setconfig),'=')::text[])[1] as name, 63 | (regexp_split_to_array(unnest(setconfig),'=')::text[])[2] as setting 64 | FROM pg_db_role_setting 65 | ), 66 | dropped AS ( 67 | SELECT l.setdatabase, l.setrole, l.name 68 | FROM pg_track_db_role_settings_list l 69 | LEFT JOIN rds s ON ( 70 | s.setdatabase = l.setdatabase 71 | AND s.setrole = l.setrole 72 | AND s.name = l.name 73 | ) 74 | WHERE s.setdatabase IS NULL 75 | AND s.setrole IS NULL 76 | AND s.name IS NULL 77 | ), 78 | mark_dropped AS ( 79 | INSERT INTO pg_track_db_role_settings_history 80 | (ts, setdatabase, setrole, name, setting, is_dropped) 81 | SELECT now(), setdatabase, setrole, name, NULL, true 82 | FROM dropped 83 | ) 84 | DELETE FROM pg_track_db_role_settings_list l 85 | USING dropped d 86 | WHERE 87 | d.setdatabase = l.setdatabase 88 | AND d.setrole = l.setrole 89 | AND d.name = l.name; 90 | 91 | -- Insert missing settings 92 | WITH rds AS ( 93 | SELECT setdatabase, setrole, 94 | (regexp_split_to_array(unnest(setconfig),'=')::text[])[1] as name, 95 | (regexp_split_to_array(unnest(setconfig),'=')::text[])[2] as setting 96 | FROM pg_db_role_setting 97 | ) 98 | INSERT INTO pg_track_db_role_settings_list 99 | (setdatabase, setrole, name) 100 | SELECT setdatabase, setrole, name 101 | FROM rds s 102 | WHERE NOT EXISTS (SELECT 1 103 | FROM pg_track_db_role_settings_list l 104 | WHERE 105 | l.setdatabase = s.setdatabase 106 | AND l.setrole = l.setrole 107 | AND l.name = s.name 108 | ); 109 | 110 | -- Detect changed GUC, insert new vals 111 | WITH rds AS ( 112 | SELECT setdatabase, setrole, 113 | (regexp_split_to_array(unnest(setconfig),'=')::text[])[1] as name, 114 | (regexp_split_to_array(unnest(setconfig),'=')::text[])[2] as setting 115 | FROM pg_db_role_setting 116 | ), 117 | last_snapshot AS ( 118 | SELECT setdatabase, setrole, name, setting 119 | FROM ( 120 | SELECT setdatabase, setrole, name, setting, 121 | row_number() OVER (PARTITION BY name, setdatabase, setrole ORDER BY ts DESC) rownum 122 | FROM pg_track_db_role_settings_history 123 | ) all_snapshots 124 | WHERE rownum = 1 125 | ) 126 | INSERT INTO pg_track_db_role_settings_history 127 | (ts, setdatabase, setrole, name, setting) 128 | SELECT now(), s.setdatabase, s.setrole, s.name, s.setting 129 | FROM rds s 130 | LEFT JOIN last_snapshot l ON 131 | l.setdatabase = s.setdatabase 132 | AND l.setrole = s.setrole 133 | AND l.name = s.name 134 | WHERE l.setdatabase IS NULL 135 | AND l.setrole IS NULL 136 | AND l.name IS NULL 137 | OR l.setting IS DISTINCT FROM s.setting; 138 | 139 | -- Detect is postmaster restarted since last call 140 | WITH last_reboot AS ( 141 | SELECT t FROM pg_postmaster_start_time() t 142 | ) 143 | INSERT INTO pg_reboot (ts) 144 | SELECT t FROM last_reboot lr 145 | WHERE NOT EXISTS (SELECT 1 146 | FROM pg_reboot r 147 | WHERE r.ts = lr.t 148 | ); 149 | 150 | RETURN true; 151 | END; 152 | $_$ 153 | LANGUAGE plpgsql; 154 | /* end of pg_track_settings_snapshot() */ 155 | 156 | DROP FUNCTION pg_track_settings(timestamp with time zone); 157 | CREATE OR REPLACE FUNCTION pg_track_settings(_ts timestamp with time zone DEFAULT now()) 158 | RETURNS TABLE (name text, setting text, setting_pretty text) AS 159 | $_$ 160 | BEGIN 161 | RETURN QUERY 162 | SELECT s.name, s.setting, s.setting_pretty 163 | FROM ( 164 | SELECT h.name, h.setting, h.setting_pretty, h.is_dropped, 165 | row_number() OVER (PARTITION BY h.name ORDER BY h.ts DESC) AS rownum 166 | FROM pg_track_settings_history h 167 | WHERE ts <= _ts 168 | ) s 169 | WHERE s.rownum = 1 170 | AND NOT s.is_dropped 171 | ORDER BY s.name; 172 | END; 173 | $_$ 174 | LANGUAGE plpgsql; 175 | 176 | DROP FUNCTION pg_track_settings_diff(timestamp with time zone,timestamp with time zone); 177 | CREATE OR REPLACE FUNCTION pg_track_settings_diff(_from timestamp with time zone, _to timestamp with time zone) 178 | RETURNS TABLE (name text, from_setting text, from_exists boolean, 179 | to_setting text, to_exists boolean, 180 | from_setting_pretty text, to_setting_pretty text) AS 181 | $_$ 182 | BEGIN 183 | RETURN QUERY 184 | SELECT COALESCE(s1.name, s2.name), 185 | s1.setting AS from_setting, 186 | CASE WHEN s1.setting IS NULL THEN false ELSE true END, 187 | s2.setting AS to_setting, 188 | CASE WHEN s2.setting IS NULL THEN false ELSE true END, 189 | s1.setting_pretty AS from_setting_pretty, 190 | s2.setting_pretty AS to_setting_pretty 191 | FROM pg_track_settings(_from) s1 192 | FULL OUTER JOIN pg_track_settings(_to) s2 ON s2.name = s1.name 193 | WHERE s1.setting IS DISTINCT FROM s2.setting 194 | ORDER BY 1; 195 | END; 196 | $_$ 197 | LANGUAGE plpgsql; 198 | 199 | DROP FUNCTION pg_track_settings_log(text); 200 | CREATE OR REPLACE FUNCTION pg_track_settings_log(_name text) 201 | RETURNS TABLE (ts timestamp with time zone, name text, setting_exists boolean, 202 | setting text, setting_pretty text) AS 203 | $_$ 204 | BEGIN 205 | RETURN QUERY 206 | SELECT h.ts, h.name, NOT h.is_dropped, h.setting, h.setting_pretty 207 | FROM pg_track_settings_history h 208 | WHERE h.name = _name 209 | ORDER BY ts DESC; 210 | END; 211 | $_$ 212 | LANGUAGE plpgsql; 213 | -------------------------------------------------------------------------------- /pg_track_settings--1.0.1.sql: -------------------------------------------------------------------------------- 1 | -- This program is open source, licensed under the PostgreSQL License. 2 | -- For license terms, see the LICENSE file. 3 | -- 4 | -- Copyright (C) 2015-2024: Julien Rouhaud 5 | 6 | -- complain if script is sourced in psql, rather than via CREATE EXTENSION 7 | \echo Use "CREATE EXTENSION pg_track_settings" to load this file. \quit 8 | 9 | SET client_encoding = 'UTF8'; 10 | 11 | CREATE TABLE pg_track_settings_list ( 12 | name text PRIMARY KEY 13 | ); 14 | SELECT pg_catalog.pg_extension_config_dump('pg_track_settings_list', ''); 15 | 16 | CREATE TABLE pg_track_settings_history ( 17 | ts timestamp with time zone, 18 | name text, 19 | setting text, 20 | is_dropped boolean NOT NULL DEFAULT false, 21 | PRIMARY KEY(ts, name) 22 | ); 23 | SELECT pg_catalog.pg_extension_config_dump('pg_track_settings_history', ''); 24 | 25 | CREATE TABLE pg_track_db_role_settings_list ( 26 | name text, 27 | setdatabase oid, 28 | setrole oid, 29 | PRIMARY KEY (name, setdatabase, setrole) 30 | ); 31 | SELECT pg_catalog.pg_extension_config_dump('pg_track_db_role_settings_list', ''); 32 | 33 | CREATE TABLE pg_track_db_role_settings_history ( 34 | ts timestamp with time zone, 35 | name text, 36 | setdatabase oid, 37 | setrole oid, 38 | setting text, 39 | is_dropped boolean NOT NULL DEFAULT false, 40 | PRIMARY KEY(ts, name, setdatabase, setrole) 41 | ); 42 | SELECT pg_catalog.pg_extension_config_dump('pg_track_db_role_settings_history', ''); 43 | 44 | CREATE TABLE pg_reboot ( 45 | ts timestamp with time zone PRIMARY KEY 46 | ); 47 | SELECT pg_catalog.pg_extension_config_dump('pg_reboot', ''); 48 | 49 | CREATE OR REPLACE FUNCTION pg_track_settings_snapshot() RETURNS boolean AS 50 | $_$ 51 | BEGIN 52 | -- Handle dropped GUC 53 | WITH dropped AS ( 54 | SELECT l.name 55 | FROM pg_track_settings_list l 56 | LEFT JOIN pg_settings s ON s.name = l.name 57 | WHERE s.name IS NULL 58 | ), 59 | mark_dropped AS ( 60 | INSERT INTO pg_track_settings_history (ts, name, setting, is_dropped) 61 | SELECT now(), name, NULL, true 62 | FROM dropped 63 | ) 64 | DELETE FROM pg_track_settings_list l 65 | USING dropped d 66 | WHERE d.name = l.name; 67 | 68 | -- Insert missing settings 69 | INSERT INTO pg_track_settings_list (name) 70 | SELECT name 71 | FROM pg_settings s 72 | WHERE NOT EXISTS (SELECT 1 73 | FROM pg_track_settings_list l 74 | WHERE l.name = s.name 75 | ); 76 | 77 | -- Detect changed GUC, insert new vals 78 | WITH last_snapshot AS ( 79 | SELECT name, setting 80 | FROM ( 81 | SELECT name, setting, row_number() OVER (PARTITION BY NAME ORDER BY ts DESC) rownum 82 | FROM pg_track_settings_history 83 | ) all_snapshots 84 | WHERE rownum = 1 85 | ) 86 | INSERT INTO pg_track_settings_history (ts, name, setting) 87 | SELECT now(), s.name, s.setting 88 | FROM pg_settings s 89 | LEFT JOIN last_snapshot l ON l.name = s.name 90 | WHERE l.name IS NULL 91 | OR l.setting IS DISTINCT FROM s.setting; 92 | 93 | -- Handle dropped db_role_setting 94 | WITH rds AS ( 95 | SELECT setdatabase, setrole, 96 | (regexp_split_to_array(unnest(setconfig),'=')::text[])[1] as name, 97 | (regexp_split_to_array(unnest(setconfig),'=')::text[])[2] as setting 98 | FROM pg_db_role_setting 99 | ), 100 | dropped AS ( 101 | SELECT l.setdatabase, l.setrole, l.name 102 | FROM pg_track_db_role_settings_list l 103 | LEFT JOIN rds s ON ( 104 | s.setdatabase = l.setdatabase 105 | AND s.setrole = l.setrole 106 | AND s.name = l.name 107 | ) 108 | WHERE s.setdatabase IS NULL 109 | AND s.setrole IS NULL 110 | AND s.name IS NULL 111 | ), 112 | mark_dropped AS ( 113 | INSERT INTO pg_track_db_role_settings_history 114 | (ts, setdatabase, setrole, name, setting, is_dropped) 115 | SELECT now(), setdatabase, setrole, name, NULL, true 116 | FROM dropped 117 | ) 118 | DELETE FROM pg_track_db_role_settings_list l 119 | USING dropped d 120 | WHERE 121 | d.setdatabase = l.setdatabase 122 | AND d.setrole = l.setrole 123 | AND d.name = l.name; 124 | 125 | -- Insert missing settings 126 | WITH rds AS ( 127 | SELECT setdatabase, setrole, 128 | (regexp_split_to_array(unnest(setconfig),'=')::text[])[1] as name, 129 | (regexp_split_to_array(unnest(setconfig),'=')::text[])[2] as setting 130 | FROM pg_db_role_setting 131 | ) 132 | INSERT INTO pg_track_db_role_settings_list 133 | (setdatabase, setrole, name) 134 | SELECT setdatabase, setrole, name 135 | FROM rds s 136 | WHERE NOT EXISTS (SELECT 1 137 | FROM pg_track_db_role_settings_list l 138 | WHERE 139 | l.setdatabase = s.setdatabase 140 | AND l.setrole = l.setrole 141 | AND l.name = s.name 142 | ); 143 | 144 | -- Detect changed GUC, insert new vals 145 | WITH rds AS ( 146 | SELECT setdatabase, setrole, 147 | (regexp_split_to_array(unnest(setconfig),'=')::text[])[1] as name, 148 | (regexp_split_to_array(unnest(setconfig),'=')::text[])[2] as setting 149 | FROM pg_db_role_setting 150 | ), 151 | last_snapshot AS ( 152 | SELECT setdatabase, setrole, name, setting 153 | FROM ( 154 | SELECT setdatabase, setrole, name, setting, 155 | row_number() OVER (PARTITION BY name, setdatabase, setrole ORDER BY ts DESC) rownum 156 | FROM pg_track_db_role_settings_history 157 | ) all_snapshots 158 | WHERE rownum = 1 159 | ) 160 | INSERT INTO pg_track_db_role_settings_history 161 | (ts, setdatabase, setrole, name, setting) 162 | SELECT now(), s.setdatabase, s.setrole, s.name, s.setting 163 | FROM rds s 164 | LEFT JOIN last_snapshot l ON 165 | l.setdatabase = s.setdatabase 166 | AND l.setrole = s.setrole 167 | AND l.name = s.name 168 | WHERE l.setdatabase IS NULL 169 | AND l.setrole IS NULL 170 | AND l.name IS NULL 171 | OR l.setting IS DISTINCT FROM s.setting; 172 | 173 | -- Detect is postmaster restarted since last call 174 | WITH last_reboot AS ( 175 | SELECT t FROM pg_postmaster_start_time() t 176 | ) 177 | INSERT INTO pg_reboot (ts) 178 | SELECT t FROM last_reboot lr 179 | WHERE NOT EXISTS (SELECT 1 180 | FROM pg_reboot r 181 | WHERE r.ts = lr.t 182 | ); 183 | 184 | RETURN true; 185 | END; 186 | $_$ 187 | LANGUAGE plpgsql; 188 | 189 | CREATE OR REPLACE FUNCTION pg_track_settings(_ts timestamp with time zone DEFAULT now()) 190 | RETURNS TABLE (name text, setting text) AS 191 | $_$ 192 | BEGIN 193 | RETURN QUERY 194 | SELECT s.name, s.setting 195 | FROM ( 196 | SELECT h.name, h.setting, h.is_dropped, row_number() OVER (PARTITION BY h.name ORDER BY h.ts DESC) AS rownum 197 | FROM pg_track_settings_history h 198 | WHERE ts <= _ts 199 | ) s 200 | WHERE s.rownum = 1 201 | AND NOT s.is_dropped 202 | ORDER BY s.name; 203 | END; 204 | $_$ 205 | LANGUAGE plpgsql; 206 | 207 | CREATE OR REPLACE FUNCTION pg_track_db_role_settings(_ts timestamp with time zone DEFAULT now()) 208 | RETURNS TABLE (setdatabase oid, setrole oid, name text, setting text) AS 209 | $_$ 210 | BEGIN 211 | RETURN QUERY 212 | SELECT s.setdatabase, s.setrole, s.name, s.setting 213 | FROM ( 214 | SELECT h.setdatabase, h.setrole, h.name, h.setting, h.is_dropped, 215 | row_number() OVER (PARTITION BY h.name, h.setdatabase, h.setrole ORDER BY h.ts DESC) AS rownum 216 | FROM pg_track_db_role_settings_history h 217 | WHERE ts <= _ts 218 | ) s 219 | WHERE s.rownum = 1 220 | AND NOT s.is_dropped 221 | ORDER BY s.setdatabase, s.setrole, s.name; 222 | END; 223 | $_$ 224 | LANGUAGE plpgsql; 225 | 226 | CREATE OR REPLACE FUNCTION pg_track_settings_diff(_from timestamp with time zone, _to timestamp with time zone) 227 | RETURNS TABLE (name text, from_setting text, from_exists boolean, to_setting text, to_exists boolean) AS 228 | $_$ 229 | BEGIN 230 | RETURN QUERY 231 | SELECT COALESCE(s1.name, s2.name), 232 | s1.setting AS from_setting, 233 | CASE WHEN s1.setting IS NULL THEN false ELSE true END, 234 | s2.setting AS to_setting, 235 | CASE WHEN s2.setting IS NULL THEN false ELSE true END 236 | FROM pg_track_settings(_from) s1 237 | FULL OUTER JOIN pg_track_settings(_to) s2 ON s2.name = s1.name 238 | WHERE s1.setting IS DISTINCT FROM s2.setting 239 | ORDER BY 1; 240 | END; 241 | $_$ 242 | LANGUAGE plpgsql; 243 | 244 | CREATE OR REPLACE FUNCTION pg_track_db_role_settings_diff(_from timestamp with time zone, _to timestamp with time zone) 245 | RETURNS TABLE (setdatabase oid, setrole oid, name text, from_setting text, from_exists boolean, to_setting text, to_exists boolean) AS 246 | $_$ 247 | BEGIN 248 | RETURN QUERY 249 | SELECT COALESCE(s1.setdatabase, s2.setdatabase), 250 | COALESCE(s1.setrole, s2.setrole), 251 | COALESCE(s1.name, s2.name), 252 | s1.setting AS from_setting, 253 | CASE WHEN s1.setting IS NULL THEN false ELSE true END, 254 | s2.setting AS to_setting, 255 | CASE WHEN s2.setting IS NULL THEN false ELSE true END 256 | FROM pg_track_db_role_settings(_from) s1 257 | FULL OUTER JOIN pg_track_db_role_settings(_to) s2 ON 258 | s2.setdatabase = s1.setdatabase 259 | AND s2.setrole = s1.setrole 260 | AND s2.name = s1.name 261 | WHERE 262 | s1.setdatabase IS DISTINCT FROM s2.setdatabase 263 | AND s1.setrole IS DISTINCT FROM s2.setrole 264 | AND s1.setting IS DISTINCT FROM s2.setting 265 | ORDER BY 1, 2, 3; 266 | END; 267 | $_$ 268 | LANGUAGE plpgsql; 269 | 270 | CREATE OR REPLACE FUNCTION pg_track_settings_log(_name text) 271 | RETURNS TABLE (ts timestamp with time zone, name text, setting_exists boolean, setting text) AS 272 | $_$ 273 | BEGIN 274 | RETURN QUERY 275 | SELECT h.ts, h.name, NOT h.is_dropped, h.setting 276 | FROM pg_track_settings_history h 277 | WHERE h.name = _name 278 | ORDER BY ts DESC; 279 | END; 280 | $_$ 281 | LANGUAGE plpgsql; 282 | 283 | CREATE OR REPLACE FUNCTION pg_track_db_role_settings_log(_name text) 284 | RETURNS TABLE (ts timestamp with time zone, setdatabase oid, setrole oid, name text, setting_exists boolean, setting text) AS 285 | $_$ 286 | BEGIN 287 | RETURN QUERY 288 | SELECT h.ts, h.setdatabase, h.setrole, h.name, NOT h.is_dropped, h.setting 289 | FROM pg_track_db_role_settings_history h 290 | WHERE h.name = _name 291 | ORDER BY ts, setdatabase, setrole DESC; 292 | END; 293 | $_$ 294 | LANGUAGE plpgsql; 295 | 296 | CREATE OR REPLACE FUNCTION pg_track_settings_reset() 297 | RETURNS void AS 298 | $_$ 299 | BEGIN 300 | TRUNCATE pg_track_settings_list; 301 | TRUNCATE pg_track_settings_history; 302 | TRUNCATE pg_track_db_role_settings_list; 303 | TRUNCATE pg_track_db_role_settings_history; 304 | TRUNCATE pg_reboot; 305 | END; 306 | $_$ 307 | LANGUAGE plpgsql; 308 | -------------------------------------------------------------------------------- /pg_track_settings--1.1.0.sql: -------------------------------------------------------------------------------- 1 | -- This program is open source, licensed under the PostgreSQL License. 2 | -- For license terms, see the LICENSE file. 3 | -- 4 | -- Copyright (C) 2015-2022: Julien Rouhaud 5 | 6 | -- complain if script is sourced in psql, rather than via CREATE EXTENSION 7 | \echo Use "CREATE EXTENSION pg_track_settings" to load this file. \quit 8 | 9 | SET client_encoding = 'UTF8'; 10 | 11 | CREATE TABLE pg_track_settings_list ( 12 | name text PRIMARY KEY 13 | ); 14 | SELECT pg_catalog.pg_extension_config_dump('pg_track_settings_list', ''); 15 | 16 | CREATE TABLE pg_track_settings_history ( 17 | ts timestamp with time zone, 18 | name text NOT NULL, 19 | setting text, 20 | is_dropped boolean NOT NULL DEFAULT false, 21 | setting_pretty text, 22 | PRIMARY KEY(ts, name) 23 | ); 24 | SELECT pg_catalog.pg_extension_config_dump('pg_track_settings_history', ''); 25 | 26 | CREATE TABLE pg_track_db_role_settings_list ( 27 | name text, 28 | setdatabase oid, 29 | setrole oid, 30 | PRIMARY KEY (name, setdatabase, setrole) 31 | ); 32 | SELECT pg_catalog.pg_extension_config_dump('pg_track_db_role_settings_list', ''); 33 | 34 | CREATE TABLE pg_track_db_role_settings_history ( 35 | ts timestamp with time zone, 36 | name text, 37 | setdatabase oid, 38 | setrole oid, 39 | setting text, 40 | is_dropped boolean NOT NULL DEFAULT false, 41 | PRIMARY KEY(ts, name, setdatabase, setrole) 42 | ); 43 | SELECT pg_catalog.pg_extension_config_dump('pg_track_db_role_settings_history', ''); 44 | 45 | CREATE TABLE pg_reboot ( 46 | ts timestamp with time zone PRIMARY KEY 47 | ); 48 | SELECT pg_catalog.pg_extension_config_dump('pg_reboot', ''); 49 | 50 | CREATE OR REPLACE FUNCTION pg_track_settings_snapshot() RETURNS boolean AS 51 | $_$ 52 | BEGIN 53 | -- Handle dropped GUC 54 | WITH dropped AS ( 55 | SELECT l.name 56 | FROM pg_track_settings_list l 57 | LEFT JOIN pg_settings s ON s.name = l.name 58 | WHERE s.name IS NULL 59 | ), 60 | mark_dropped AS ( 61 | INSERT INTO pg_track_settings_history (ts, name, setting, 62 | setting_pretty, is_dropped) 63 | SELECT now(), name, NULL, NULL, true 64 | FROM dropped 65 | ) 66 | DELETE FROM pg_track_settings_list l 67 | USING dropped d 68 | WHERE d.name = l.name; 69 | 70 | -- Insert missing settings 71 | INSERT INTO pg_track_settings_list (name) 72 | SELECT name 73 | FROM pg_settings s 74 | WHERE NOT EXISTS (SELECT 1 75 | FROM pg_track_settings_list l 76 | WHERE l.name = s.name 77 | ); 78 | 79 | -- Detect changed GUC, insert new vals 80 | WITH last_snapshot AS ( 81 | SELECT name, setting 82 | FROM ( 83 | SELECT name, setting, row_number() OVER (PARTITION BY NAME ORDER BY ts DESC) rownum 84 | FROM pg_track_settings_history 85 | ) all_snapshots 86 | WHERE rownum = 1 87 | ) 88 | INSERT INTO pg_track_settings_history (ts, name, setting, setting_pretty) 89 | SELECT now(), s.name, s.setting, pg_catalog.current_setting(s.name) 90 | FROM pg_settings s 91 | LEFT JOIN last_snapshot l ON l.name = s.name 92 | WHERE l.name IS NULL 93 | OR l.setting IS DISTINCT FROM s.setting; 94 | 95 | -- Handle dropped db_role_setting 96 | WITH rds AS ( 97 | SELECT setdatabase, setrole, 98 | (regexp_split_to_array(unnest(setconfig),'=')::text[])[1] as name, 99 | (regexp_split_to_array(unnest(setconfig),'=')::text[])[2] as setting 100 | FROM pg_db_role_setting 101 | ), 102 | dropped AS ( 103 | SELECT l.setdatabase, l.setrole, l.name 104 | FROM pg_track_db_role_settings_list l 105 | LEFT JOIN rds s ON ( 106 | s.setdatabase = l.setdatabase 107 | AND s.setrole = l.setrole 108 | AND s.name = l.name 109 | ) 110 | WHERE s.setdatabase IS NULL 111 | AND s.setrole IS NULL 112 | AND s.name IS NULL 113 | ), 114 | mark_dropped AS ( 115 | INSERT INTO pg_track_db_role_settings_history 116 | (ts, setdatabase, setrole, name, setting, is_dropped) 117 | SELECT now(), setdatabase, setrole, name, NULL, true 118 | FROM dropped 119 | ) 120 | DELETE FROM pg_track_db_role_settings_list l 121 | USING dropped d 122 | WHERE 123 | d.setdatabase = l.setdatabase 124 | AND d.setrole = l.setrole 125 | AND d.name = l.name; 126 | 127 | -- Insert missing settings 128 | WITH rds AS ( 129 | SELECT setdatabase, setrole, 130 | (regexp_split_to_array(unnest(setconfig),'=')::text[])[1] as name, 131 | (regexp_split_to_array(unnest(setconfig),'=')::text[])[2] as setting 132 | FROM pg_db_role_setting 133 | ) 134 | INSERT INTO pg_track_db_role_settings_list 135 | (setdatabase, setrole, name) 136 | SELECT setdatabase, setrole, name 137 | FROM rds s 138 | WHERE NOT EXISTS (SELECT 1 139 | FROM pg_track_db_role_settings_list l 140 | WHERE 141 | l.setdatabase = s.setdatabase 142 | AND l.setrole = l.setrole 143 | AND l.name = s.name 144 | ); 145 | 146 | -- Detect changed GUC, insert new vals 147 | WITH rds AS ( 148 | SELECT setdatabase, setrole, 149 | (regexp_split_to_array(unnest(setconfig),'=')::text[])[1] as name, 150 | (regexp_split_to_array(unnest(setconfig),'=')::text[])[2] as setting 151 | FROM pg_db_role_setting 152 | ), 153 | last_snapshot AS ( 154 | SELECT setdatabase, setrole, name, setting 155 | FROM ( 156 | SELECT setdatabase, setrole, name, setting, 157 | row_number() OVER (PARTITION BY name, setdatabase, setrole ORDER BY ts DESC) rownum 158 | FROM pg_track_db_role_settings_history 159 | ) all_snapshots 160 | WHERE rownum = 1 161 | ) 162 | INSERT INTO pg_track_db_role_settings_history 163 | (ts, setdatabase, setrole, name, setting) 164 | SELECT now(), s.setdatabase, s.setrole, s.name, s.setting 165 | FROM rds s 166 | LEFT JOIN last_snapshot l ON 167 | l.setdatabase = s.setdatabase 168 | AND l.setrole = s.setrole 169 | AND l.name = s.name 170 | WHERE l.setdatabase IS NULL 171 | AND l.setrole IS NULL 172 | AND l.name IS NULL 173 | OR l.setting IS DISTINCT FROM s.setting; 174 | 175 | -- Detect is postmaster restarted since last call 176 | WITH last_reboot AS ( 177 | SELECT t FROM pg_postmaster_start_time() t 178 | ) 179 | INSERT INTO pg_reboot (ts) 180 | SELECT t FROM last_reboot lr 181 | WHERE NOT EXISTS (SELECT 1 182 | FROM pg_reboot r 183 | WHERE r.ts = lr.t 184 | ); 185 | 186 | RETURN true; 187 | END; 188 | $_$ 189 | LANGUAGE plpgsql; 190 | /* end of pg_track_settings_snapshot() */ 191 | 192 | CREATE OR REPLACE FUNCTION pg_track_settings(_ts timestamp with time zone DEFAULT now()) 193 | RETURNS TABLE (name text, setting text, setting_pretty text) AS 194 | $_$ 195 | BEGIN 196 | RETURN QUERY 197 | SELECT s.name, s.setting, s.setting_pretty 198 | FROM ( 199 | SELECT h.name, h.setting, h.setting_pretty, h.is_dropped, 200 | row_number() OVER (PARTITION BY h.name ORDER BY h.ts DESC) AS rownum 201 | FROM pg_track_settings_history h 202 | WHERE ts <= _ts 203 | ) s 204 | WHERE s.rownum = 1 205 | AND NOT s.is_dropped 206 | ORDER BY s.name; 207 | END; 208 | $_$ 209 | LANGUAGE plpgsql; 210 | 211 | CREATE OR REPLACE FUNCTION pg_track_db_role_settings(_ts timestamp with time zone DEFAULT now()) 212 | RETURNS TABLE (setdatabase oid, setrole oid, name text, setting text) AS 213 | $_$ 214 | BEGIN 215 | RETURN QUERY 216 | SELECT s.setdatabase, s.setrole, s.name, s.setting 217 | FROM ( 218 | SELECT h.setdatabase, h.setrole, h.name, h.setting, h.is_dropped, 219 | row_number() OVER (PARTITION BY h.name, h.setdatabase, h.setrole ORDER BY h.ts DESC) AS rownum 220 | FROM pg_track_db_role_settings_history h 221 | WHERE ts <= _ts 222 | ) s 223 | WHERE s.rownum = 1 224 | AND NOT s.is_dropped 225 | ORDER BY s.setdatabase, s.setrole, s.name; 226 | END; 227 | $_$ 228 | LANGUAGE plpgsql; 229 | 230 | CREATE OR REPLACE FUNCTION pg_track_settings_diff(_from timestamp with time zone, _to timestamp with time zone) 231 | RETURNS TABLE (name text, from_setting text, from_exists boolean, 232 | to_setting text, to_exists boolean, 233 | from_setting_pretty text, to_setting_pretty text) AS 234 | $_$ 235 | BEGIN 236 | RETURN QUERY 237 | SELECT COALESCE(s1.name, s2.name), 238 | s1.setting AS from_setting, 239 | CASE WHEN s1.setting IS NULL THEN false ELSE true END, 240 | s2.setting AS to_setting, 241 | CASE WHEN s2.setting IS NULL THEN false ELSE true END, 242 | s1.setting_pretty AS from_setting_pretty, 243 | s2.setting_pretty AS to_setting_pretty 244 | FROM pg_track_settings(_from) s1 245 | FULL OUTER JOIN pg_track_settings(_to) s2 ON s2.name = s1.name 246 | WHERE s1.setting IS DISTINCT FROM s2.setting 247 | ORDER BY 1; 248 | END; 249 | $_$ 250 | LANGUAGE plpgsql; 251 | 252 | CREATE OR REPLACE FUNCTION pg_track_db_role_settings_diff(_from timestamp with time zone, _to timestamp with time zone) 253 | RETURNS TABLE (setdatabase oid, setrole oid, name text, 254 | from_setting text, from_exists boolean, to_setting text, to_exists boolean) 255 | AS 256 | $_$ 257 | BEGIN 258 | RETURN QUERY 259 | SELECT COALESCE(s1.setdatabase, s2.setdatabase), 260 | COALESCE(s1.setrole, s2.setrole), 261 | COALESCE(s1.name, s2.name), 262 | s1.setting AS from_setting, 263 | CASE WHEN s1.setting IS NULL THEN false ELSE true END, 264 | s2.setting AS to_setting, 265 | CASE WHEN s2.setting IS NULL THEN false ELSE true END 266 | FROM pg_track_db_role_settings(_from) s1 267 | FULL OUTER JOIN pg_track_db_role_settings(_to) s2 ON 268 | s2.setdatabase = s1.setdatabase 269 | AND s2.setrole = s1.setrole 270 | AND s2.name = s1.name 271 | WHERE 272 | s1.setdatabase IS DISTINCT FROM s2.setdatabase 273 | AND s1.setrole IS DISTINCT FROM s2.setrole 274 | AND s1.setting IS DISTINCT FROM s2.setting 275 | ORDER BY 1, 2, 3; 276 | END; 277 | $_$ 278 | LANGUAGE plpgsql; 279 | 280 | CREATE OR REPLACE FUNCTION pg_track_settings_log(_name text) 281 | RETURNS TABLE (ts timestamp with time zone, name text, setting_exists boolean, 282 | setting text, setting_pretty text) AS 283 | $_$ 284 | BEGIN 285 | RETURN QUERY 286 | SELECT h.ts, h.name, NOT h.is_dropped, h.setting, h.setting_pretty 287 | FROM pg_track_settings_history h 288 | WHERE h.name = _name 289 | ORDER BY ts DESC; 290 | END; 291 | $_$ 292 | LANGUAGE plpgsql; 293 | 294 | CREATE OR REPLACE FUNCTION pg_track_db_role_settings_log(_name text) 295 | RETURNS TABLE (ts timestamp with time zone, setdatabase oid, setrole oid, 296 | name text, setting_exists boolean, setting text) AS 297 | $_$ 298 | BEGIN 299 | RETURN QUERY 300 | SELECT h.ts, h.setdatabase, h.setrole, h.name, NOT h.is_dropped, h.setting 301 | FROM pg_track_db_role_settings_history h 302 | WHERE h.name = _name 303 | ORDER BY ts, setdatabase, setrole DESC; 304 | END; 305 | $_$ 306 | LANGUAGE plpgsql; 307 | 308 | CREATE OR REPLACE FUNCTION pg_track_settings_reset() 309 | RETURNS void AS 310 | $_$ 311 | BEGIN 312 | TRUNCATE pg_track_settings_list; 313 | TRUNCATE pg_track_settings_history; 314 | TRUNCATE pg_track_db_role_settings_list; 315 | TRUNCATE pg_track_db_role_settings_history; 316 | TRUNCATE pg_reboot; 317 | END; 318 | $_$ 319 | LANGUAGE plpgsql; 320 | -------------------------------------------------------------------------------- /pg_track_settings--2.0.0--2.0.1.sql: -------------------------------------------------------------------------------- 1 | -- This program is open source, licensed under the PostgreSQL License. 2 | -- For license terms, see the LICENSE file. 3 | -- 4 | -- Copyright (C) 2015-2022: Julien Rouhaud 5 | 6 | -- complain if script is sourced in psql, rather than via ALTER EXTENSION 7 | \echo Use "ALTER EXTENSION pg_track_settings" to load this file. \quit 8 | 9 | SET LOCAL client_encoding = 'UTF8'; 10 | 11 | CREATE OR REPLACE FUNCTION pg_track_settings_snapshot_rds(_srvid integer) 12 | RETURNS boolean AS 13 | $_$ 14 | DECLARE 15 | _snap_ts timestamp with time zone; 16 | BEGIN 17 | SELECT max(ts) INTO _snap_ts 18 | FROM public.pg_track_settings_rds_src(_srvid); 19 | 20 | -- this function should have been called for previously saved data. If 21 | -- not, probably somethig went wrong, so discard those data 22 | IF (_srvid != 0) THEN 23 | DELETE FROM public.pg_track_settings_rds_src_tmp 24 | WHERE ts != _snap_ts; 25 | END IF; 26 | 27 | -- Handle dropped db_role_setting 28 | WITH rds AS ( 29 | SELECT * FROM public.pg_track_settings_rds_src(_srvid) 30 | ), 31 | dropped AS ( 32 | SELECT _snap_ts AS ts, l.setdatabase, l.setrole, l.name 33 | FROM public.pg_track_db_role_settings_list l 34 | LEFT JOIN rds s ON ( 35 | s.setdatabase = l.setdatabase 36 | AND s.setrole = l.setrole 37 | AND s.name = l.name 38 | ) 39 | WHERE l.srvid = _srvid 40 | AND s.setdatabase IS NULL 41 | AND s.setrole IS NULL 42 | AND s.name IS NULL 43 | ), 44 | mark_dropped AS ( 45 | INSERT INTO public.pg_track_db_role_settings_history 46 | (srvid, ts, setdatabase, setrole, name, setting, is_dropped) 47 | SELECT _srvid, ts, d.setdatabase, d.setrole, d.name, NULL, true 48 | FROM dropped AS d 49 | ) 50 | DELETE FROM public.pg_track_db_role_settings_list l 51 | USING dropped d 52 | WHERE 53 | l.srvid = _srvid 54 | AND d.setdatabase = l.setdatabase 55 | AND d.setrole = l.setrole 56 | AND d.name = l.name; 57 | 58 | -- Insert missing settings 59 | WITH rds AS ( 60 | SELECT * FROM public.pg_track_settings_rds_src(_srvid) 61 | ) 62 | INSERT INTO public.pg_track_db_role_settings_list 63 | (srvid, setdatabase, setrole, name) 64 | SELECT _srvid, setdatabase, setrole, name 65 | FROM rds s 66 | WHERE NOT EXISTS (SELECT 1 67 | FROM public.pg_track_db_role_settings_list l 68 | WHERE 69 | l.srvid = _srvid 70 | AND l.setdatabase = s.setdatabase 71 | AND l.setrole = l.setrole 72 | AND l.name = s.name 73 | ); 74 | 75 | -- Detect changed GUC, insert new vals 76 | WITH rds AS ( 77 | SELECT * FROM public.pg_track_settings_rds_src(_srvid) 78 | ), 79 | last_snapshot AS ( 80 | SELECT setdatabase, setrole, name, setting 81 | FROM ( 82 | SELECT setdatabase, setrole, name, setting, 83 | row_number() OVER (PARTITION BY name, setdatabase, setrole ORDER BY ts DESC) AS rownum 84 | FROM public.pg_track_db_role_settings_history 85 | WHERE srvid = _srvid 86 | ) all_snapshots 87 | WHERE rownum = 1 88 | ) 89 | INSERT INTO public.pg_track_db_role_settings_history 90 | (srvid, ts, setdatabase, setrole, name, setting) 91 | SELECT _srvid, s.ts, s.setdatabase, s.setrole, s.name, s.setting 92 | FROM rds s 93 | LEFT JOIN last_snapshot l ON 94 | l.setdatabase = s.setdatabase 95 | AND l.setrole = s.setrole 96 | AND l.name = s.name 97 | WHERE (l.setdatabase IS NULL 98 | AND l.setrole IS NULL 99 | AND l.name IS NULL) 100 | OR (l.setting IS DISTINCT FROM s.setting); 101 | 102 | IF (_srvid != 0) THEN 103 | DELETE FROM public.pg_track_settings_rds_src_tmp 104 | WHERE srvid = _srvid; 105 | END IF; 106 | 107 | RETURN true; 108 | END; 109 | $_$ 110 | LANGUAGE plpgsql; /* end of pg_track_settings_snapshot_rds() */ 111 | -------------------------------------------------------------------------------- /pg_track_settings--2.0.0.sql: -------------------------------------------------------------------------------- 1 | -- This program is open source, licensed under the PostgreSQL License. 2 | -- For license terms, see the LICENSE file. 3 | -- 4 | -- Copyright (C) 2015-2022: Julien Rouhaud 5 | 6 | -- complain if script is sourced in psql, rather than via CREATE EXTENSION 7 | \echo Use "CREATE EXTENSION pg_track_settings" to load this file. \quit 8 | 9 | SET client_encoding = 'UTF8'; 10 | 11 | CREATE UNLOGGED TABLE public.pg_track_settings_settings_src_tmp ( 12 | srvid integer NOT NULL, 13 | ts timestamp with time zone NOT NULL, 14 | name text NOT NULL, 15 | setting text, 16 | current_setting text 17 | ); 18 | -- no need to backup this table 19 | 20 | CREATE TABLE public.pg_track_settings_list ( 21 | srvid integer NOT NULL, 22 | name text, 23 | PRIMARY KEY (srvid, name) 24 | ); 25 | SELECT pg_catalog.pg_extension_config_dump('public.pg_track_settings_list', ''); 26 | 27 | CREATE TABLE public.pg_track_settings_history ( 28 | srvid integer NOT NULL, 29 | ts timestamp with time zone, 30 | name text NOT NULL, 31 | setting text, 32 | is_dropped boolean NOT NULL DEFAULT false, 33 | setting_pretty text, 34 | PRIMARY KEY(srvid, ts, name) 35 | ); 36 | SELECT pg_catalog.pg_extension_config_dump('public.pg_track_settings_history', ''); 37 | 38 | CREATE UNLOGGED TABLE public.pg_track_settings_rds_src_tmp ( 39 | srvid integer NOT NULL, 40 | ts timestamp with time zone NOT NULL, 41 | name text NOT NULL, 42 | setting text, 43 | setdatabase oid NOT NULL, 44 | setrole oid NOT NULL 45 | ); 46 | -- no need to backup this table 47 | 48 | CREATE TABLE public.pg_track_db_role_settings_list ( 49 | srvid integer, 50 | name text, 51 | setdatabase oid, 52 | setrole oid, 53 | PRIMARY KEY (srvid, name, setdatabase, setrole) 54 | ); 55 | SELECT pg_catalog.pg_extension_config_dump('public.pg_track_db_role_settings_list', ''); 56 | 57 | CREATE TABLE public.pg_track_db_role_settings_history ( 58 | srvid INTEGER NOT NULL, 59 | ts timestamp with time zone, 60 | name text, 61 | setdatabase oid, 62 | setrole oid, 63 | setting text, 64 | is_dropped boolean NOT NULL DEFAULT false, 65 | PRIMARY KEY(srvid, ts, name, setdatabase, setrole) 66 | ); 67 | SELECT pg_catalog.pg_extension_config_dump('public.pg_track_db_role_settings_history', ''); 68 | 69 | CREATE UNLOGGED TABLE public.pg_track_settings_reboot_src_tmp ( 70 | srvid integer NOT NULL, 71 | ts timestamp with time zone NOT NULL, 72 | postmaster_ts timestamp with time zone NOT NULL 73 | ); 74 | -- no need to backup this table 75 | 76 | CREATE TABLE public.pg_reboot ( 77 | srvid integer NOT NULL, 78 | ts timestamp with time zone, 79 | PRIMARY KEY (srvid, ts) 80 | ); 81 | SELECT pg_catalog.pg_extension_config_dump('public.pg_reboot', ''); 82 | 83 | ---------------------- 84 | -- source functions -- 85 | ---------------------- 86 | CREATE OR REPLACE FUNCTION pg_track_settings_settings_src ( 87 | IN _srvid integer, 88 | OUT ts timestamp with time zone, 89 | OUT name text, 90 | OUT setting text, 91 | OUT current_setting text 92 | ) 93 | RETURNS SETOF record AS $PROC$ 94 | BEGIN 95 | IF (_srvid = 0) THEN 96 | RETURN QUERY SELECT now(), 97 | s.name, s.setting, pg_catalog.current_setting(s.name) 98 | FROM pg_catalog.pg_settings s; 99 | ELSE 100 | RETURN QUERY SELECT s.ts, 101 | s.name, s.setting, s.current_setting 102 | FROM public.pg_track_settings_settings_src_tmp s; 103 | END IF; 104 | END; 105 | $PROC$ LANGUAGE plpgsql; /* end of pg_track_settings_settings_src */ 106 | 107 | CREATE OR REPLACE FUNCTION pg_track_settings_rds_src ( 108 | IN _srvid integer, 109 | OUT ts timestamp with time zone, 110 | OUT name text, 111 | OUT setting text, 112 | OUT setdatabase oid, 113 | OUT setrole oid 114 | ) 115 | RETURNS SETOF record AS $PROC$ 116 | BEGIN 117 | IF (_srvid = 0) THEN 118 | RETURN QUERY SELECT now(), 119 | (regexp_split_to_array(unnest(s.setconfig),'=')::text[])[1] AS name, 120 | (regexp_split_to_array(unnest(s.setconfig),'=')::text[])[2] AS setting, 121 | s.setdatabase, s.setrole 122 | FROM pg_catalog.pg_db_role_setting s; 123 | ELSE 124 | RETURN QUERY SELECT s.ts, 125 | s.name, s.setting, s.setdatabase, s.setrole 126 | FROM public.pg_track_settings_rds_src_tmp s; 127 | END IF; 128 | END; 129 | $PROC$ LANGUAGE plpgsql; /* end of pg_track_settings_rds_src */ 130 | 131 | CREATE OR REPLACE FUNCTION pg_track_settings_reboot_src ( 132 | IN _srvid integer, 133 | OUT ts timestamp with time zone, 134 | OUT postmaster_ts timestamp with time zone 135 | ) 136 | RETURNS SETOF record AS $PROC$ 137 | BEGIN 138 | IF (_srvid = 0) THEN 139 | RETURN QUERY SELECT now(), 140 | pg_postmaster_start_time(); 141 | ELSE 142 | RETURN QUERY SELECT s.ts, 143 | s.postmaster_ts 144 | FROM public.pg_track_settings_reboot_src_tmp s; 145 | END IF; 146 | END; 147 | $PROC$ LANGUAGE plpgsql; /* end of pg_track_settings_reboot_src */ 148 | 149 | ------------------------ 150 | -- snapshot functions -- 151 | ------------------------ 152 | CREATE OR REPLACE FUNCTION pg_track_settings_snapshot_settings(_srvid integer) 153 | RETURNS boolean AS 154 | $_$ 155 | DECLARE 156 | _snap_ts timestamp with time zone = NULL; 157 | BEGIN 158 | SELECT max(ts) INTO _snap_ts 159 | FROM public.pg_track_settings_settings_src(_srvid); 160 | 161 | -- this function should have been called for previously saved data. If 162 | -- not, probably somethig went wrong, so discard those data 163 | IF (_srvid != 0) THEN 164 | DELETE FROM public.pg_track_settings_settings_src_tmp 165 | WHERE ts != _snap_ts; 166 | END IF; 167 | 168 | -- Handle dropped GUC 169 | WITH src AS ( 170 | SELECT * FROM public.pg_track_settings_settings_src(_srvid) 171 | ), 172 | dropped AS ( 173 | SELECT s.ts, l.srvid, l.name 174 | FROM public.pg_track_settings_list l 175 | LEFT JOIN src s ON s.name = l.name 176 | WHERE l.srvid = _srvid 177 | AND s.name IS NULL 178 | ), 179 | mark_dropped AS ( 180 | INSERT INTO public.pg_track_settings_history (srvid, ts, name, setting, 181 | setting_pretty, is_dropped) 182 | SELECT srvid, COALESCE(_snap_ts, now()), name, NULL, NULL, true 183 | FROM dropped 184 | ) 185 | DELETE FROM public.pg_track_settings_list l 186 | USING dropped d 187 | WHERE d.name = l.name 188 | AND d.srvid = l.srvid 189 | AND l.srvid = _srvid; 190 | 191 | -- Insert missing settings 192 | INSERT INTO public.pg_track_settings_list (srvid, name) 193 | SELECT _srvid, name 194 | FROM public.pg_track_settings_settings_src(_srvid) s 195 | WHERE NOT EXISTS (SELECT 1 196 | FROM public.pg_track_settings_list l 197 | WHERE l.srvid = _srvid 198 | AND l.name = s.name 199 | ); 200 | 201 | -- Detect changed GUC, insert new vals 202 | WITH src AS ( 203 | SELECT * FROM public.pg_track_settings_settings_src(_srvid) 204 | ), last_snapshot AS ( 205 | SELECT srvid, name, setting 206 | FROM ( 207 | SELECT srvid, name, setting, 208 | row_number() OVER (PARTITION BY NAME ORDER BY ts DESC) AS rownum 209 | FROM public.pg_track_settings_history h 210 | WHERE h.srvid = _srvid 211 | ) all_snapshots 212 | WHERE rownum = 1 213 | ) 214 | INSERT INTO public.pg_track_settings_history 215 | (srvid, ts, name, setting, setting_pretty) 216 | SELECT _srvid, s.ts, s.name, s.setting, s.current_setting 217 | FROM src s 218 | LEFT JOIN last_snapshot l ON l.name = s.name 219 | WHERE ( 220 | l.name IS NULL 221 | OR l.setting IS DISTINCT FROM s.setting 222 | ); 223 | 224 | IF (_srvid != 0) THEN 225 | DELETE FROM public.pg_track_settings_settings_src_tmp 226 | WHERE srvid = _srvid; 227 | END IF; 228 | 229 | RETURN true; 230 | END; 231 | $_$ 232 | LANGUAGE plpgsql; /* end of pg_track_settings_snapshot_settings() */ 233 | 234 | CREATE OR REPLACE FUNCTION pg_track_settings_snapshot_rds(_srvid integer) 235 | RETURNS boolean AS 236 | $_$ 237 | DECLARE 238 | _snap_ts timestamp with time zone; 239 | BEGIN 240 | SELECT max(ts) INTO _snap_ts 241 | FROM public.pg_track_settings_rds_src(_srvid); 242 | 243 | -- this function should have been called for previously saved data. If 244 | -- not, probably somethig went wrong, so discard those data 245 | IF (_srvid != 0) THEN 246 | DELETE FROM public.pg_track_settings_rds_src_tmp 247 | WHERE ts != _snap_ts; 248 | END IF; 249 | 250 | -- Handle dropped db_role_setting 251 | WITH rds AS ( 252 | SELECT * FROM public.pg_track_settings_rds_src(_srvid) 253 | ), 254 | dropped AS ( 255 | SELECT s.ts, l.setdatabase, l.setrole, l.name 256 | FROM public.pg_track_db_role_settings_list l 257 | LEFT JOIN rds s ON ( 258 | s.setdatabase = l.setdatabase 259 | AND s.setrole = l.setrole 260 | AND s.name = l.name 261 | ) 262 | WHERE l.srvid = _srvid 263 | AND s.setdatabase IS NULL 264 | AND s.setrole IS NULL 265 | AND s.name IS NULL 266 | ), 267 | mark_dropped AS ( 268 | INSERT INTO public.pg_track_db_role_settings_history 269 | (srvid, ts, setdatabase, setrole, name, setting, is_dropped) 270 | SELECT _srvid, ts, d.setdatabase, d.setrole, d.name, NULL, true 271 | FROM dropped AS d 272 | ) 273 | DELETE FROM public.pg_track_db_role_settings_list l 274 | USING dropped d 275 | WHERE 276 | l.srvid = _srvid 277 | AND d.setdatabase = l.setdatabase 278 | AND d.setrole = l.setrole 279 | AND d.name = l.name; 280 | 281 | -- Insert missing settings 282 | WITH rds AS ( 283 | SELECT * FROM public.pg_track_settings_rds_src(_srvid) 284 | ) 285 | INSERT INTO public.pg_track_db_role_settings_list 286 | (srvid, setdatabase, setrole, name) 287 | SELECT _srvid, setdatabase, setrole, name 288 | FROM rds s 289 | WHERE NOT EXISTS (SELECT 1 290 | FROM public.pg_track_db_role_settings_list l 291 | WHERE 292 | l.srvid = _srvid 293 | AND l.setdatabase = s.setdatabase 294 | AND l.setrole = l.setrole 295 | AND l.name = s.name 296 | ); 297 | 298 | -- Detect changed GUC, insert new vals 299 | WITH rds AS ( 300 | SELECT * FROM public.pg_track_settings_rds_src(_srvid) 301 | ), 302 | last_snapshot AS ( 303 | SELECT setdatabase, setrole, name, setting 304 | FROM ( 305 | SELECT setdatabase, setrole, name, setting, 306 | row_number() OVER (PARTITION BY name, setdatabase, setrole ORDER BY ts DESC) AS rownum 307 | FROM public.pg_track_db_role_settings_history 308 | WHERE srvid = _srvid 309 | ) all_snapshots 310 | WHERE rownum = 1 311 | ) 312 | INSERT INTO public.pg_track_db_role_settings_history 313 | (srvid, ts, setdatabase, setrole, name, setting) 314 | SELECT _srvid, s.ts, s.setdatabase, s.setrole, s.name, s.setting 315 | FROM rds s 316 | LEFT JOIN last_snapshot l ON 317 | l.setdatabase = s.setdatabase 318 | AND l.setrole = s.setrole 319 | AND l.name = s.name 320 | WHERE (l.setdatabase IS NULL 321 | AND l.setrole IS NULL 322 | AND l.name IS NULL) 323 | OR (l.setting IS DISTINCT FROM s.setting); 324 | 325 | IF (_srvid != 0) THEN 326 | DELETE FROM public.pg_track_settings_rds_src_tmp 327 | WHERE srvid = _srvid; 328 | END IF; 329 | 330 | RETURN true; 331 | END; 332 | $_$ 333 | LANGUAGE plpgsql; /* end of pg_track_settings_snapshot_rds() */ 334 | 335 | CREATE OR REPLACE FUNCTION public.pg_track_settings_snapshot_reboot(_srvid integer) 336 | RETURNS boolean AS 337 | $_$ 338 | BEGIN 339 | -- Detect is postmaster restarted since last call 340 | WITH last_reboot AS ( 341 | SELECT t.postmaster_ts 342 | FROM public.pg_track_settings_reboot_src(_srvid) t 343 | ) 344 | INSERT INTO public.pg_reboot (srvid, ts) 345 | SELECT _srvid, lr.postmaster_ts FROM last_reboot lr 346 | WHERE NOT EXISTS (SELECT 1 347 | FROM public.pg_reboot r 348 | WHERE r.srvid = _srvid 349 | AND r.ts = lr.postmaster_ts 350 | AND r.srvid = _srvid 351 | ); 352 | 353 | IF (_srvid != 0) THEN 354 | DELETE FROM public.pg_track_settings_reboot_src_tmp 355 | WHERE srvid = _srvid; 356 | END IF; 357 | 358 | RETURN true; 359 | END; 360 | $_$ 361 | LANGUAGE plpgsql; /* end of pg_track_settings_snapshot_reboot() */ 362 | 363 | -- global function doing all the work for local instance, kept for backward 364 | -- compatibility 365 | CREATE OR REPLACE FUNCTION pg_track_settings_snapshot() 366 | RETURNS boolean AS 367 | $_$ 368 | BEGIN 369 | PERFORM public.pg_track_settings_snapshot_settings(0); 370 | PERFORM public.pg_track_settings_snapshot_rds(0); 371 | PERFORM public.pg_track_settings_snapshot_reboot(0); 372 | 373 | RETURN true; 374 | END; 375 | $_$ 376 | LANGUAGE plpgsql; 377 | /* end of pg_track_settings_snapshot() */ 378 | 379 | CREATE OR REPLACE FUNCTION public.pg_track_settings( 380 | _ts timestamp with time zone DEFAULT now(), 381 | _srvid integer DEFAULT 0) 382 | RETURNS TABLE (name text, setting text, setting_pretty text) AS 383 | $_$ 384 | BEGIN 385 | RETURN QUERY 386 | SELECT s.name, s.setting, s.setting_pretty 387 | FROM ( 388 | SELECT h.name, h.setting, h.setting_pretty, h.is_dropped, 389 | row_number() OVER (PARTITION BY h.name ORDER BY h.ts DESC) AS rownum 390 | FROM public.pg_track_settings_history h 391 | WHERE h.srvid = _srvid 392 | AND h.ts <= _ts 393 | ) s 394 | WHERE s.rownum = 1 395 | AND NOT s.is_dropped 396 | ORDER BY s.name; 397 | END; 398 | $_$ 399 | LANGUAGE plpgsql; 400 | 401 | CREATE OR REPLACE FUNCTION public.pg_track_db_role_settings( 402 | _ts timestamp with time zone DEFAULT now(), 403 | _srvid integer DEFAULT 0) 404 | RETURNS TABLE (setdatabase oid, setrole oid, name text, setting text) AS 405 | $_$ 406 | BEGIN 407 | RETURN QUERY 408 | SELECT s.setdatabase, s.setrole, s.name, s.setting 409 | FROM ( 410 | SELECT h.setdatabase, h.setrole, h.name, h.setting, h.is_dropped, 411 | row_number() OVER (PARTITION BY h.name, h.setdatabase, h.setrole ORDER BY h.ts DESC) AS rownum 412 | FROM public.pg_track_db_role_settings_history h 413 | WHERE h.srvid = _srvid 414 | AND h.ts <= _ts 415 | ) s 416 | WHERE s.rownum = 1 417 | AND NOT s.is_dropped 418 | ORDER BY s.setdatabase, s.setrole, s.name; 419 | END; 420 | $_$ 421 | LANGUAGE plpgsql; 422 | 423 | CREATE OR REPLACE FUNCTION public.pg_track_settings_diff( 424 | _from timestamp with time zone, 425 | _to timestamp with time zone, 426 | _srvid integer DEFAULT 0) 427 | RETURNS TABLE (name text, from_setting text, from_exists boolean, 428 | to_setting text, to_exists boolean, 429 | from_setting_pretty text, to_setting_pretty text) AS 430 | $_$ 431 | BEGIN 432 | RETURN QUERY 433 | SELECT COALESCE(s1.name, s2.name), 434 | s1.setting AS from_setting, 435 | CASE WHEN s1.setting IS NULL THEN false ELSE true END, 436 | s2.setting AS to_setting, 437 | CASE WHEN s2.setting IS NULL THEN false ELSE true END, 438 | s1.setting_pretty AS from_setting_pretty, 439 | s2.setting_pretty AS to_setting_pretty 440 | FROM public.pg_track_settings(_from, _srvid) s1 441 | FULL OUTER JOIN public.pg_track_settings(_to, _srvid) s2 ON s2.name = s1.name 442 | WHERE s1.setting IS DISTINCT FROM s2.setting 443 | ORDER BY 1; 444 | END; 445 | $_$ 446 | LANGUAGE plpgsql; 447 | 448 | CREATE OR REPLACE FUNCTION public.pg_track_db_role_settings_diff( 449 | _from timestamp with time zone, 450 | _to timestamp with time zone, 451 | _srvid integer DEFAULT 0) 452 | RETURNS TABLE (setdatabase oid, setrole oid, name text, 453 | from_setting text, from_exists boolean, to_setting text, to_exists boolean) 454 | AS 455 | $_$ 456 | BEGIN 457 | RETURN QUERY 458 | SELECT COALESCE(s1.setdatabase, s2.setdatabase), 459 | COALESCE(s1.setrole, s2.setrole), 460 | COALESCE(s1.name, s2.name), 461 | s1.setting AS from_setting, 462 | CASE WHEN s1.setting IS NULL THEN false ELSE true END, 463 | s2.setting AS to_setting, 464 | CASE WHEN s2.setting IS NULL THEN false ELSE true END 465 | FROM public.pg_track_db_role_settings(_from, _srvid) s1 466 | FULL OUTER JOIN public.pg_track_db_role_settings(_to, _srvid) s2 ON 467 | s2.setdatabase = s1.setdatabase 468 | AND s2.setrole = s1.setrole 469 | AND s2.name = s1.name 470 | WHERE 471 | s1.setdatabase IS DISTINCT FROM s2.setdatabase 472 | AND s1.setrole IS DISTINCT FROM s2.setrole 473 | AND s1.setting IS DISTINCT FROM s2.setting 474 | ORDER BY 1, 2, 3; 475 | END; 476 | $_$ 477 | LANGUAGE plpgsql; 478 | 479 | CREATE OR REPLACE FUNCTION pg_track_settings_log( 480 | _name text, 481 | _srvid integer DEFAULT 0) 482 | RETURNS TABLE (ts timestamp with time zone, name text, setting_exists boolean, 483 | setting text, setting_pretty text) AS 484 | $_$ 485 | BEGIN 486 | RETURN QUERY 487 | SELECT h.ts, h.name, NOT h.is_dropped, h.setting, h.setting_pretty 488 | FROM public.pg_track_settings_history h 489 | WHERE h.srvid = _srvid 490 | AND h.name = _name 491 | ORDER BY ts DESC; 492 | END; 493 | $_$ 494 | LANGUAGE plpgsql; 495 | 496 | CREATE OR REPLACE FUNCTION pg_track_db_role_settings_log( 497 | _name text, 498 | _srvid integer DEFAULT 0) 499 | RETURNS TABLE (ts timestamp with time zone, setdatabase oid, setrole oid, 500 | name text, setting_exists boolean, setting text) AS 501 | $_$ 502 | BEGIN 503 | RETURN QUERY 504 | SELECT h.ts, h.setdatabase, h.setrole, h.name, NOT h.is_dropped, h.setting 505 | FROM public.pg_track_db_role_settings_history h 506 | WHERE h.srvid = _srvid 507 | AND h.name = _name 508 | ORDER BY ts, setdatabase, setrole DESC; 509 | END; 510 | $_$ 511 | LANGUAGE plpgsql; 512 | 513 | CREATE OR REPLACE FUNCTION pg_track_reboot_log(_srvid integer DEFAULT 0) 514 | RETURNS TABLE (ts timestamp with time zone) AS 515 | $_$ 516 | BEGIN 517 | RETURN QUERY 518 | SELECT r.ts 519 | FROM public.pg_reboot r 520 | WHERE r.srvid = _srvid 521 | ORDER BY r.ts; 522 | END; 523 | $_$ 524 | LANGUAGE plpgsql; 525 | 526 | CREATE OR REPLACE FUNCTION public.pg_track_settings_reset(_srvid integer DEFAULT 0) 527 | RETURNS void AS 528 | $_$ 529 | BEGIN 530 | DELETE FROM public.pg_track_settings_settings_src_tmp WHERE srvid = _srvid; 531 | DELETE FROM public.pg_track_settings_rds_src_tmp WHERE srvid = _srvid; 532 | DELETE FROM public.pg_track_settings_reboot_src_tmp WHERE srvid = _srvid; 533 | DELETE FROM public.pg_track_settings_list WHERE srvid = _srvid; 534 | DELETE FROM public.pg_track_settings_history WHERE srvid = _srvid; 535 | DELETE FROM public.pg_track_db_role_settings_list WHERE srvid = _srvid; 536 | DELETE FROM public.pg_track_db_role_settings_history WHERE srvid = _srvid; 537 | DELETE FROM public.pg_reboot WHERE srvid = _srvid; 538 | END; 539 | $_$ 540 | LANGUAGE plpgsql; 541 | -------------------------------------------------------------------------------- /pg_track_settings--2.0.1--2.1.0.sql: -------------------------------------------------------------------------------- 1 | -- This program is open source, licensed under the PostgreSQL License. 2 | -- For license terms, see the LICENSE file. 3 | -- 4 | -- Copyright (C) 2015-2022: Julien Rouhaud 5 | 6 | -- complain if script is sourced in psql, rather than via ALTER EXTENSION 7 | \echo Use "ALTER EXTENSION pg_track_settings" to load this file. \quit 8 | 9 | SET LOCAL client_encoding = 'UTF8'; 10 | 11 | CREATE OR REPLACE FUNCTION @extschema@.pg_track_settings_snapshot_settings(_srvid integer) 12 | RETURNS boolean AS 13 | $_$ 14 | DECLARE 15 | _snap_ts timestamp with time zone = NULL; 16 | BEGIN 17 | SELECT max(ts) INTO _snap_ts 18 | FROM @extschema@.pg_track_settings_settings_src(_srvid); 19 | 20 | -- this function should have been called for previously saved data. If 21 | -- not, probably somethig went wrong, so discard those data 22 | IF (_srvid != 0) THEN 23 | DELETE FROM @extschema@.pg_track_settings_settings_src_tmp 24 | WHERE ts != _snap_ts; 25 | END IF; 26 | 27 | -- Handle dropped GUC 28 | WITH src AS ( 29 | SELECT * FROM @extschema@.pg_track_settings_settings_src(_srvid) 30 | ), 31 | dropped AS ( 32 | SELECT s.ts, l.srvid, l.name 33 | FROM @extschema@.pg_track_settings_list l 34 | LEFT JOIN src s ON s.name = l.name 35 | WHERE l.srvid = _srvid 36 | AND s.name IS NULL 37 | ), 38 | mark_dropped AS ( 39 | INSERT INTO @extschema@.pg_track_settings_history (srvid, ts, name, setting, 40 | setting_pretty, is_dropped) 41 | SELECT srvid, COALESCE(_snap_ts, now()), name, NULL, NULL, true 42 | FROM dropped 43 | ) 44 | DELETE FROM @extschema@.pg_track_settings_list l 45 | USING dropped d 46 | WHERE d.name = l.name 47 | AND d.srvid = l.srvid 48 | AND l.srvid = _srvid; 49 | 50 | -- Insert missing settings 51 | INSERT INTO @extschema@.pg_track_settings_list (srvid, name) 52 | SELECT _srvid, name 53 | FROM @extschema@.pg_track_settings_settings_src(_srvid) s 54 | WHERE NOT EXISTS (SELECT 1 55 | FROM @extschema@.pg_track_settings_list l 56 | WHERE l.srvid = _srvid 57 | AND l.name = s.name 58 | ); 59 | 60 | -- Detect changed GUC, insert new vals 61 | WITH src AS ( 62 | SELECT * FROM @extschema@.pg_track_settings_settings_src(_srvid) 63 | ), last_snapshot AS ( 64 | SELECT srvid, name, setting 65 | FROM ( 66 | SELECT srvid, name, setting, 67 | row_number() OVER (PARTITION BY NAME ORDER BY ts DESC) AS rn 68 | FROM @extschema@.pg_track_settings_history h 69 | WHERE h.srvid = _srvid 70 | ) all_snapshots 71 | WHERE all_snapshots.rn = 1 72 | ) 73 | INSERT INTO @extschema@.pg_track_settings_history 74 | (srvid, ts, name, setting, setting_pretty) 75 | SELECT _srvid, s.ts, s.name, s.setting, s.current_setting 76 | FROM src s 77 | LEFT JOIN last_snapshot l ON l.name = s.name 78 | WHERE ( 79 | l.name IS NULL 80 | OR l.setting IS DISTINCT FROM s.setting 81 | ); 82 | 83 | IF (_srvid != 0) THEN 84 | DELETE FROM @extschema@.pg_track_settings_settings_src_tmp 85 | WHERE srvid = _srvid; 86 | END IF; 87 | 88 | RETURN true; 89 | END; 90 | $_$ 91 | LANGUAGE plpgsql; /* end of pg_track_settings_snapshot_settings() */ 92 | 93 | CREATE OR REPLACE FUNCTION @extschema@.pg_track_settings_snapshot_rds(_srvid integer) 94 | RETURNS boolean AS 95 | $_$ 96 | DECLARE 97 | _snap_ts timestamp with time zone; 98 | BEGIN 99 | SELECT max(ts) INTO _snap_ts 100 | FROM @extschema@.pg_track_settings_rds_src(_srvid); 101 | 102 | -- this function should have been called for previously saved data. If 103 | -- not, probably somethig went wrong, so discard those data 104 | IF (_srvid != 0) THEN 105 | DELETE FROM @extschema@.pg_track_settings_rds_src_tmp 106 | WHERE ts != _snap_ts; 107 | END IF; 108 | 109 | -- Handle dropped db_role_setting 110 | WITH rds AS ( 111 | SELECT * FROM @extschema@.pg_track_settings_rds_src(_srvid) 112 | ), 113 | dropped AS ( 114 | SELECT _snap_ts AS ts, l.setdatabase, l.setrole, l.name 115 | FROM @extschema@.pg_track_db_role_settings_list l 116 | LEFT JOIN rds s ON ( 117 | s.setdatabase = l.setdatabase 118 | AND s.setrole = l.setrole 119 | AND s.name = l.name 120 | ) 121 | WHERE l.srvid = _srvid 122 | AND s.setdatabase IS NULL 123 | AND s.setrole IS NULL 124 | AND s.name IS NULL 125 | ), 126 | mark_dropped AS ( 127 | INSERT INTO @extschema@.pg_track_db_role_settings_history 128 | (srvid, ts, setdatabase, setrole, name, setting, is_dropped) 129 | SELECT _srvid, ts, d.setdatabase, d.setrole, d.name, NULL, true 130 | FROM dropped AS d 131 | ) 132 | DELETE FROM @extschema@.pg_track_db_role_settings_list l 133 | USING dropped d 134 | WHERE 135 | l.srvid = _srvid 136 | AND d.setdatabase = l.setdatabase 137 | AND d.setrole = l.setrole 138 | AND d.name = l.name; 139 | 140 | -- Insert missing settings 141 | WITH rds AS ( 142 | SELECT * FROM @extschema@.pg_track_settings_rds_src(_srvid) 143 | ) 144 | INSERT INTO @extschema@.pg_track_db_role_settings_list 145 | (srvid, setdatabase, setrole, name) 146 | SELECT _srvid, setdatabase, setrole, name 147 | FROM rds s 148 | WHERE NOT EXISTS (SELECT 1 149 | FROM @extschema@.pg_track_db_role_settings_list l 150 | WHERE 151 | l.srvid = _srvid 152 | AND l.setdatabase = s.setdatabase 153 | AND l.setrole = l.setrole 154 | AND l.name = s.name 155 | ); 156 | 157 | -- Detect changed GUC, insert new vals 158 | WITH rds AS ( 159 | SELECT * FROM @extschema@.pg_track_settings_rds_src(_srvid) 160 | ), 161 | last_snapshot AS ( 162 | SELECT setdatabase, setrole, name, setting 163 | FROM ( 164 | SELECT setdatabase, setrole, name, setting, 165 | row_number() OVER (PARTITION BY name, setdatabase, setrole ORDER BY ts DESC) AS rn 166 | FROM @extschema@.pg_track_db_role_settings_history 167 | WHERE srvid = _srvid 168 | ) all_snapshots 169 | WHERE all_snapshots.rn = 1 170 | ) 171 | INSERT INTO @extschema@.pg_track_db_role_settings_history 172 | (srvid, ts, setdatabase, setrole, name, setting) 173 | SELECT _srvid, s.ts, s.setdatabase, s.setrole, s.name, s.setting 174 | FROM rds s 175 | LEFT JOIN last_snapshot l ON 176 | l.setdatabase = s.setdatabase 177 | AND l.setrole = s.setrole 178 | AND l.name = s.name 179 | WHERE (l.setdatabase IS NULL 180 | AND l.setrole IS NULL 181 | AND l.name IS NULL) 182 | OR (l.setting IS DISTINCT FROM s.setting); 183 | 184 | IF (_srvid != 0) THEN 185 | DELETE FROM @extschema@.pg_track_settings_rds_src_tmp 186 | WHERE srvid = _srvid; 187 | END IF; 188 | 189 | RETURN true; 190 | END; 191 | $_$ 192 | LANGUAGE plpgsql; /* end of pg_track_settings_snapshot_rds() */ 193 | 194 | CREATE OR REPLACE FUNCTION @extschema@.pg_track_settings( 195 | _ts timestamp with time zone DEFAULT now(), 196 | _srvid integer DEFAULT 0) 197 | RETURNS TABLE (name text, setting text, setting_pretty text) AS 198 | $_$ 199 | BEGIN 200 | RETURN QUERY 201 | SELECT s.name, s.setting, s.setting_pretty 202 | FROM ( 203 | SELECT h.name, h.setting, h.setting_pretty, h.is_dropped, 204 | row_number() OVER (PARTITION BY h.name ORDER BY h.ts DESC) AS rn 205 | FROM @extschema@.pg_track_settings_history h 206 | WHERE h.srvid = _srvid 207 | AND h.ts <= _ts 208 | ) s 209 | WHERE s.rn = 1 210 | AND NOT s.is_dropped 211 | ORDER BY s.name; 212 | END; 213 | $_$ 214 | LANGUAGE plpgsql; 215 | 216 | CREATE OR REPLACE FUNCTION @extschema@.pg_track_db_role_settings( 217 | _ts timestamp with time zone DEFAULT now(), 218 | _srvid integer DEFAULT 0) 219 | RETURNS TABLE (setdatabase oid, setrole oid, name text, setting text) AS 220 | $_$ 221 | BEGIN 222 | RETURN QUERY 223 | SELECT s.setdatabase, s.setrole, s.name, s.setting 224 | FROM ( 225 | SELECT h.setdatabase, h.setrole, h.name, h.setting, h.is_dropped, 226 | row_number() OVER (PARTITION BY h.name, h.setdatabase, h.setrole ORDER BY h.ts DESC) AS rn 227 | FROM @extschema@.pg_track_db_role_settings_history h 228 | WHERE h.srvid = _srvid 229 | AND h.ts <= _ts 230 | ) s 231 | WHERE s.rn = 1 232 | AND NOT s.is_dropped 233 | ORDER BY s.setdatabase, s.setrole, s.name; 234 | END; 235 | $_$ 236 | LANGUAGE plpgsql; 237 | -------------------------------------------------------------------------------- /pg_track_settings--2.0.1.sql: -------------------------------------------------------------------------------- 1 | -- This program is open source, licensed under the PostgreSQL License. 2 | -- For license terms, see the LICENSE file. 3 | -- 4 | -- Copyright (C) 2015-2022: Julien Rouhaud 5 | 6 | -- complain if script is sourced in psql, rather than via CREATE EXTENSION 7 | \echo Use "CREATE EXTENSION pg_track_settings" to load this file. \quit 8 | 9 | SET client_encoding = 'UTF8'; 10 | 11 | CREATE UNLOGGED TABLE public.pg_track_settings_settings_src_tmp ( 12 | srvid integer NOT NULL, 13 | ts timestamp with time zone NOT NULL, 14 | name text NOT NULL, 15 | setting text, 16 | current_setting text 17 | ); 18 | -- no need to backup this table 19 | 20 | CREATE TABLE public.pg_track_settings_list ( 21 | srvid integer NOT NULL, 22 | name text, 23 | PRIMARY KEY (srvid, name) 24 | ); 25 | SELECT pg_catalog.pg_extension_config_dump('public.pg_track_settings_list', ''); 26 | 27 | CREATE TABLE public.pg_track_settings_history ( 28 | srvid integer NOT NULL, 29 | ts timestamp with time zone, 30 | name text NOT NULL, 31 | setting text, 32 | is_dropped boolean NOT NULL DEFAULT false, 33 | setting_pretty text, 34 | PRIMARY KEY(srvid, ts, name) 35 | ); 36 | SELECT pg_catalog.pg_extension_config_dump('public.pg_track_settings_history', ''); 37 | 38 | CREATE UNLOGGED TABLE public.pg_track_settings_rds_src_tmp ( 39 | srvid integer NOT NULL, 40 | ts timestamp with time zone NOT NULL, 41 | name text NOT NULL, 42 | setting text, 43 | setdatabase oid NOT NULL, 44 | setrole oid NOT NULL 45 | ); 46 | -- no need to backup this table 47 | 48 | CREATE TABLE public.pg_track_db_role_settings_list ( 49 | srvid integer, 50 | name text, 51 | setdatabase oid, 52 | setrole oid, 53 | PRIMARY KEY (srvid, name, setdatabase, setrole) 54 | ); 55 | SELECT pg_catalog.pg_extension_config_dump('public.pg_track_db_role_settings_list', ''); 56 | 57 | CREATE TABLE public.pg_track_db_role_settings_history ( 58 | srvid INTEGER NOT NULL, 59 | ts timestamp with time zone, 60 | name text, 61 | setdatabase oid, 62 | setrole oid, 63 | setting text, 64 | is_dropped boolean NOT NULL DEFAULT false, 65 | PRIMARY KEY(srvid, ts, name, setdatabase, setrole) 66 | ); 67 | SELECT pg_catalog.pg_extension_config_dump('public.pg_track_db_role_settings_history', ''); 68 | 69 | CREATE UNLOGGED TABLE public.pg_track_settings_reboot_src_tmp ( 70 | srvid integer NOT NULL, 71 | ts timestamp with time zone NOT NULL, 72 | postmaster_ts timestamp with time zone NOT NULL 73 | ); 74 | -- no need to backup this table 75 | 76 | CREATE TABLE public.pg_reboot ( 77 | srvid integer NOT NULL, 78 | ts timestamp with time zone, 79 | PRIMARY KEY (srvid, ts) 80 | ); 81 | SELECT pg_catalog.pg_extension_config_dump('public.pg_reboot', ''); 82 | 83 | ---------------------- 84 | -- source functions -- 85 | ---------------------- 86 | CREATE OR REPLACE FUNCTION pg_track_settings_settings_src ( 87 | IN _srvid integer, 88 | OUT ts timestamp with time zone, 89 | OUT name text, 90 | OUT setting text, 91 | OUT current_setting text 92 | ) 93 | RETURNS SETOF record AS $PROC$ 94 | BEGIN 95 | IF (_srvid = 0) THEN 96 | RETURN QUERY SELECT now(), 97 | s.name, s.setting, pg_catalog.current_setting(s.name) 98 | FROM pg_catalog.pg_settings s; 99 | ELSE 100 | RETURN QUERY SELECT s.ts, 101 | s.name, s.setting, s.current_setting 102 | FROM public.pg_track_settings_settings_src_tmp s; 103 | END IF; 104 | END; 105 | $PROC$ LANGUAGE plpgsql; /* end of pg_track_settings_settings_src */ 106 | 107 | CREATE OR REPLACE FUNCTION pg_track_settings_rds_src ( 108 | IN _srvid integer, 109 | OUT ts timestamp with time zone, 110 | OUT name text, 111 | OUT setting text, 112 | OUT setdatabase oid, 113 | OUT setrole oid 114 | ) 115 | RETURNS SETOF record AS $PROC$ 116 | BEGIN 117 | IF (_srvid = 0) THEN 118 | RETURN QUERY SELECT now(), 119 | (regexp_split_to_array(unnest(s.setconfig),'=')::text[])[1] AS name, 120 | (regexp_split_to_array(unnest(s.setconfig),'=')::text[])[2] AS setting, 121 | s.setdatabase, s.setrole 122 | FROM pg_catalog.pg_db_role_setting s; 123 | ELSE 124 | RETURN QUERY SELECT s.ts, 125 | s.name, s.setting, s.setdatabase, s.setrole 126 | FROM public.pg_track_settings_rds_src_tmp s; 127 | END IF; 128 | END; 129 | $PROC$ LANGUAGE plpgsql; /* end of pg_track_settings_rds_src */ 130 | 131 | CREATE OR REPLACE FUNCTION pg_track_settings_reboot_src ( 132 | IN _srvid integer, 133 | OUT ts timestamp with time zone, 134 | OUT postmaster_ts timestamp with time zone 135 | ) 136 | RETURNS SETOF record AS $PROC$ 137 | BEGIN 138 | IF (_srvid = 0) THEN 139 | RETURN QUERY SELECT now(), 140 | pg_postmaster_start_time(); 141 | ELSE 142 | RETURN QUERY SELECT s.ts, 143 | s.postmaster_ts 144 | FROM public.pg_track_settings_reboot_src_tmp s; 145 | END IF; 146 | END; 147 | $PROC$ LANGUAGE plpgsql; /* end of pg_track_settings_reboot_src */ 148 | 149 | ------------------------ 150 | -- snapshot functions -- 151 | ------------------------ 152 | CREATE OR REPLACE FUNCTION pg_track_settings_snapshot_settings(_srvid integer) 153 | RETURNS boolean AS 154 | $_$ 155 | DECLARE 156 | _snap_ts timestamp with time zone = NULL; 157 | BEGIN 158 | SELECT max(ts) INTO _snap_ts 159 | FROM public.pg_track_settings_settings_src(_srvid); 160 | 161 | -- this function should have been called for previously saved data. If 162 | -- not, probably somethig went wrong, so discard those data 163 | IF (_srvid != 0) THEN 164 | DELETE FROM public.pg_track_settings_settings_src_tmp 165 | WHERE ts != _snap_ts; 166 | END IF; 167 | 168 | -- Handle dropped GUC 169 | WITH src AS ( 170 | SELECT * FROM public.pg_track_settings_settings_src(_srvid) 171 | ), 172 | dropped AS ( 173 | SELECT s.ts, l.srvid, l.name 174 | FROM public.pg_track_settings_list l 175 | LEFT JOIN src s ON s.name = l.name 176 | WHERE l.srvid = _srvid 177 | AND s.name IS NULL 178 | ), 179 | mark_dropped AS ( 180 | INSERT INTO public.pg_track_settings_history (srvid, ts, name, setting, 181 | setting_pretty, is_dropped) 182 | SELECT srvid, COALESCE(_snap_ts, now()), name, NULL, NULL, true 183 | FROM dropped 184 | ) 185 | DELETE FROM public.pg_track_settings_list l 186 | USING dropped d 187 | WHERE d.name = l.name 188 | AND d.srvid = l.srvid 189 | AND l.srvid = _srvid; 190 | 191 | -- Insert missing settings 192 | INSERT INTO public.pg_track_settings_list (srvid, name) 193 | SELECT _srvid, name 194 | FROM public.pg_track_settings_settings_src(_srvid) s 195 | WHERE NOT EXISTS (SELECT 1 196 | FROM public.pg_track_settings_list l 197 | WHERE l.srvid = _srvid 198 | AND l.name = s.name 199 | ); 200 | 201 | -- Detect changed GUC, insert new vals 202 | WITH src AS ( 203 | SELECT * FROM public.pg_track_settings_settings_src(_srvid) 204 | ), last_snapshot AS ( 205 | SELECT srvid, name, setting 206 | FROM ( 207 | SELECT srvid, name, setting, 208 | row_number() OVER (PARTITION BY NAME ORDER BY ts DESC) AS rownum 209 | FROM public.pg_track_settings_history h 210 | WHERE h.srvid = _srvid 211 | ) all_snapshots 212 | WHERE rownum = 1 213 | ) 214 | INSERT INTO public.pg_track_settings_history 215 | (srvid, ts, name, setting, setting_pretty) 216 | SELECT _srvid, s.ts, s.name, s.setting, s.current_setting 217 | FROM src s 218 | LEFT JOIN last_snapshot l ON l.name = s.name 219 | WHERE ( 220 | l.name IS NULL 221 | OR l.setting IS DISTINCT FROM s.setting 222 | ); 223 | 224 | IF (_srvid != 0) THEN 225 | DELETE FROM public.pg_track_settings_settings_src_tmp 226 | WHERE srvid = _srvid; 227 | END IF; 228 | 229 | RETURN true; 230 | END; 231 | $_$ 232 | LANGUAGE plpgsql; /* end of pg_track_settings_snapshot_settings() */ 233 | 234 | CREATE OR REPLACE FUNCTION pg_track_settings_snapshot_rds(_srvid integer) 235 | RETURNS boolean AS 236 | $_$ 237 | DECLARE 238 | _snap_ts timestamp with time zone; 239 | BEGIN 240 | SELECT max(ts) INTO _snap_ts 241 | FROM public.pg_track_settings_rds_src(_srvid); 242 | 243 | -- this function should have been called for previously saved data. If 244 | -- not, probably somethig went wrong, so discard those data 245 | IF (_srvid != 0) THEN 246 | DELETE FROM public.pg_track_settings_rds_src_tmp 247 | WHERE ts != _snap_ts; 248 | END IF; 249 | 250 | -- Handle dropped db_role_setting 251 | WITH rds AS ( 252 | SELECT * FROM public.pg_track_settings_rds_src(_srvid) 253 | ), 254 | dropped AS ( 255 | SELECT _snap_ts AS ts, l.setdatabase, l.setrole, l.name 256 | FROM public.pg_track_db_role_settings_list l 257 | LEFT JOIN rds s ON ( 258 | s.setdatabase = l.setdatabase 259 | AND s.setrole = l.setrole 260 | AND s.name = l.name 261 | ) 262 | WHERE l.srvid = _srvid 263 | AND s.setdatabase IS NULL 264 | AND s.setrole IS NULL 265 | AND s.name IS NULL 266 | ), 267 | mark_dropped AS ( 268 | INSERT INTO public.pg_track_db_role_settings_history 269 | (srvid, ts, setdatabase, setrole, name, setting, is_dropped) 270 | SELECT _srvid, ts, d.setdatabase, d.setrole, d.name, NULL, true 271 | FROM dropped AS d 272 | ) 273 | DELETE FROM public.pg_track_db_role_settings_list l 274 | USING dropped d 275 | WHERE 276 | l.srvid = _srvid 277 | AND d.setdatabase = l.setdatabase 278 | AND d.setrole = l.setrole 279 | AND d.name = l.name; 280 | 281 | -- Insert missing settings 282 | WITH rds AS ( 283 | SELECT * FROM public.pg_track_settings_rds_src(_srvid) 284 | ) 285 | INSERT INTO public.pg_track_db_role_settings_list 286 | (srvid, setdatabase, setrole, name) 287 | SELECT _srvid, setdatabase, setrole, name 288 | FROM rds s 289 | WHERE NOT EXISTS (SELECT 1 290 | FROM public.pg_track_db_role_settings_list l 291 | WHERE 292 | l.srvid = _srvid 293 | AND l.setdatabase = s.setdatabase 294 | AND l.setrole = l.setrole 295 | AND l.name = s.name 296 | ); 297 | 298 | -- Detect changed GUC, insert new vals 299 | WITH rds AS ( 300 | SELECT * FROM public.pg_track_settings_rds_src(_srvid) 301 | ), 302 | last_snapshot AS ( 303 | SELECT setdatabase, setrole, name, setting 304 | FROM ( 305 | SELECT setdatabase, setrole, name, setting, 306 | row_number() OVER (PARTITION BY name, setdatabase, setrole ORDER BY ts DESC) AS rownum 307 | FROM public.pg_track_db_role_settings_history 308 | WHERE srvid = _srvid 309 | ) all_snapshots 310 | WHERE rownum = 1 311 | ) 312 | INSERT INTO public.pg_track_db_role_settings_history 313 | (srvid, ts, setdatabase, setrole, name, setting) 314 | SELECT _srvid, s.ts, s.setdatabase, s.setrole, s.name, s.setting 315 | FROM rds s 316 | LEFT JOIN last_snapshot l ON 317 | l.setdatabase = s.setdatabase 318 | AND l.setrole = s.setrole 319 | AND l.name = s.name 320 | WHERE (l.setdatabase IS NULL 321 | AND l.setrole IS NULL 322 | AND l.name IS NULL) 323 | OR (l.setting IS DISTINCT FROM s.setting); 324 | 325 | IF (_srvid != 0) THEN 326 | DELETE FROM public.pg_track_settings_rds_src_tmp 327 | WHERE srvid = _srvid; 328 | END IF; 329 | 330 | RETURN true; 331 | END; 332 | $_$ 333 | LANGUAGE plpgsql; /* end of pg_track_settings_snapshot_rds() */ 334 | 335 | CREATE OR REPLACE FUNCTION public.pg_track_settings_snapshot_reboot(_srvid integer) 336 | RETURNS boolean AS 337 | $_$ 338 | BEGIN 339 | -- Detect is postmaster restarted since last call 340 | WITH last_reboot AS ( 341 | SELECT t.postmaster_ts 342 | FROM public.pg_track_settings_reboot_src(_srvid) t 343 | ) 344 | INSERT INTO public.pg_reboot (srvid, ts) 345 | SELECT _srvid, lr.postmaster_ts FROM last_reboot lr 346 | WHERE NOT EXISTS (SELECT 1 347 | FROM public.pg_reboot r 348 | WHERE r.srvid = _srvid 349 | AND r.ts = lr.postmaster_ts 350 | AND r.srvid = _srvid 351 | ); 352 | 353 | IF (_srvid != 0) THEN 354 | DELETE FROM public.pg_track_settings_reboot_src_tmp 355 | WHERE srvid = _srvid; 356 | END IF; 357 | 358 | RETURN true; 359 | END; 360 | $_$ 361 | LANGUAGE plpgsql; /* end of pg_track_settings_snapshot_reboot() */ 362 | 363 | -- global function doing all the work for local instance, kept for backward 364 | -- compatibility 365 | CREATE OR REPLACE FUNCTION pg_track_settings_snapshot() 366 | RETURNS boolean AS 367 | $_$ 368 | BEGIN 369 | PERFORM public.pg_track_settings_snapshot_settings(0); 370 | PERFORM public.pg_track_settings_snapshot_rds(0); 371 | PERFORM public.pg_track_settings_snapshot_reboot(0); 372 | 373 | RETURN true; 374 | END; 375 | $_$ 376 | LANGUAGE plpgsql; 377 | /* end of pg_track_settings_snapshot() */ 378 | 379 | CREATE OR REPLACE FUNCTION public.pg_track_settings( 380 | _ts timestamp with time zone DEFAULT now(), 381 | _srvid integer DEFAULT 0) 382 | RETURNS TABLE (name text, setting text, setting_pretty text) AS 383 | $_$ 384 | BEGIN 385 | RETURN QUERY 386 | SELECT s.name, s.setting, s.setting_pretty 387 | FROM ( 388 | SELECT h.name, h.setting, h.setting_pretty, h.is_dropped, 389 | row_number() OVER (PARTITION BY h.name ORDER BY h.ts DESC) AS rownum 390 | FROM public.pg_track_settings_history h 391 | WHERE h.srvid = _srvid 392 | AND h.ts <= _ts 393 | ) s 394 | WHERE s.rownum = 1 395 | AND NOT s.is_dropped 396 | ORDER BY s.name; 397 | END; 398 | $_$ 399 | LANGUAGE plpgsql; 400 | 401 | CREATE OR REPLACE FUNCTION public.pg_track_db_role_settings( 402 | _ts timestamp with time zone DEFAULT now(), 403 | _srvid integer DEFAULT 0) 404 | RETURNS TABLE (setdatabase oid, setrole oid, name text, setting text) AS 405 | $_$ 406 | BEGIN 407 | RETURN QUERY 408 | SELECT s.setdatabase, s.setrole, s.name, s.setting 409 | FROM ( 410 | SELECT h.setdatabase, h.setrole, h.name, h.setting, h.is_dropped, 411 | row_number() OVER (PARTITION BY h.name, h.setdatabase, h.setrole ORDER BY h.ts DESC) AS rownum 412 | FROM public.pg_track_db_role_settings_history h 413 | WHERE h.srvid = _srvid 414 | AND h.ts <= _ts 415 | ) s 416 | WHERE s.rownum = 1 417 | AND NOT s.is_dropped 418 | ORDER BY s.setdatabase, s.setrole, s.name; 419 | END; 420 | $_$ 421 | LANGUAGE plpgsql; 422 | 423 | CREATE OR REPLACE FUNCTION public.pg_track_settings_diff( 424 | _from timestamp with time zone, 425 | _to timestamp with time zone, 426 | _srvid integer DEFAULT 0) 427 | RETURNS TABLE (name text, from_setting text, from_exists boolean, 428 | to_setting text, to_exists boolean, 429 | from_setting_pretty text, to_setting_pretty text) AS 430 | $_$ 431 | BEGIN 432 | RETURN QUERY 433 | SELECT COALESCE(s1.name, s2.name), 434 | s1.setting AS from_setting, 435 | CASE WHEN s1.setting IS NULL THEN false ELSE true END, 436 | s2.setting AS to_setting, 437 | CASE WHEN s2.setting IS NULL THEN false ELSE true END, 438 | s1.setting_pretty AS from_setting_pretty, 439 | s2.setting_pretty AS to_setting_pretty 440 | FROM public.pg_track_settings(_from, _srvid) s1 441 | FULL OUTER JOIN public.pg_track_settings(_to, _srvid) s2 ON s2.name = s1.name 442 | WHERE s1.setting IS DISTINCT FROM s2.setting 443 | ORDER BY 1; 444 | END; 445 | $_$ 446 | LANGUAGE plpgsql; 447 | 448 | CREATE OR REPLACE FUNCTION public.pg_track_db_role_settings_diff( 449 | _from timestamp with time zone, 450 | _to timestamp with time zone, 451 | _srvid integer DEFAULT 0) 452 | RETURNS TABLE (setdatabase oid, setrole oid, name text, 453 | from_setting text, from_exists boolean, to_setting text, to_exists boolean) 454 | AS 455 | $_$ 456 | BEGIN 457 | RETURN QUERY 458 | SELECT COALESCE(s1.setdatabase, s2.setdatabase), 459 | COALESCE(s1.setrole, s2.setrole), 460 | COALESCE(s1.name, s2.name), 461 | s1.setting AS from_setting, 462 | CASE WHEN s1.setting IS NULL THEN false ELSE true END, 463 | s2.setting AS to_setting, 464 | CASE WHEN s2.setting IS NULL THEN false ELSE true END 465 | FROM public.pg_track_db_role_settings(_from, _srvid) s1 466 | FULL OUTER JOIN public.pg_track_db_role_settings(_to, _srvid) s2 ON 467 | s2.setdatabase = s1.setdatabase 468 | AND s2.setrole = s1.setrole 469 | AND s2.name = s1.name 470 | WHERE 471 | s1.setdatabase IS DISTINCT FROM s2.setdatabase 472 | AND s1.setrole IS DISTINCT FROM s2.setrole 473 | AND s1.setting IS DISTINCT FROM s2.setting 474 | ORDER BY 1, 2, 3; 475 | END; 476 | $_$ 477 | LANGUAGE plpgsql; 478 | 479 | CREATE OR REPLACE FUNCTION pg_track_settings_log( 480 | _name text, 481 | _srvid integer DEFAULT 0) 482 | RETURNS TABLE (ts timestamp with time zone, name text, setting_exists boolean, 483 | setting text, setting_pretty text) AS 484 | $_$ 485 | BEGIN 486 | RETURN QUERY 487 | SELECT h.ts, h.name, NOT h.is_dropped, h.setting, h.setting_pretty 488 | FROM public.pg_track_settings_history h 489 | WHERE h.srvid = _srvid 490 | AND h.name = _name 491 | ORDER BY ts DESC; 492 | END; 493 | $_$ 494 | LANGUAGE plpgsql; 495 | 496 | CREATE OR REPLACE FUNCTION pg_track_db_role_settings_log( 497 | _name text, 498 | _srvid integer DEFAULT 0) 499 | RETURNS TABLE (ts timestamp with time zone, setdatabase oid, setrole oid, 500 | name text, setting_exists boolean, setting text) AS 501 | $_$ 502 | BEGIN 503 | RETURN QUERY 504 | SELECT h.ts, h.setdatabase, h.setrole, h.name, NOT h.is_dropped, h.setting 505 | FROM public.pg_track_db_role_settings_history h 506 | WHERE h.srvid = _srvid 507 | AND h.name = _name 508 | ORDER BY ts, setdatabase, setrole DESC; 509 | END; 510 | $_$ 511 | LANGUAGE plpgsql; 512 | 513 | CREATE OR REPLACE FUNCTION pg_track_reboot_log(_srvid integer DEFAULT 0) 514 | RETURNS TABLE (ts timestamp with time zone) AS 515 | $_$ 516 | BEGIN 517 | RETURN QUERY 518 | SELECT r.ts 519 | FROM public.pg_reboot r 520 | WHERE r.srvid = _srvid 521 | ORDER BY r.ts; 522 | END; 523 | $_$ 524 | LANGUAGE plpgsql; 525 | 526 | CREATE OR REPLACE FUNCTION public.pg_track_settings_reset(_srvid integer DEFAULT 0) 527 | RETURNS void AS 528 | $_$ 529 | BEGIN 530 | DELETE FROM public.pg_track_settings_settings_src_tmp WHERE srvid = _srvid; 531 | DELETE FROM public.pg_track_settings_rds_src_tmp WHERE srvid = _srvid; 532 | DELETE FROM public.pg_track_settings_reboot_src_tmp WHERE srvid = _srvid; 533 | DELETE FROM public.pg_track_settings_list WHERE srvid = _srvid; 534 | DELETE FROM public.pg_track_settings_history WHERE srvid = _srvid; 535 | DELETE FROM public.pg_track_db_role_settings_list WHERE srvid = _srvid; 536 | DELETE FROM public.pg_track_db_role_settings_history WHERE srvid = _srvid; 537 | DELETE FROM public.pg_reboot WHERE srvid = _srvid; 538 | END; 539 | $_$ 540 | LANGUAGE plpgsql; 541 | -------------------------------------------------------------------------------- /pg_track_settings--2.1.0--2.1.2.sql: -------------------------------------------------------------------------------- 1 | -- This program is open source, licensed under the PostgreSQL License. 2 | -- For license terms, see the LICENSE file. 3 | -- 4 | -- Copyright (C) 2015-2024: Julien Rouhaud 5 | 6 | -- complain if script is sourced in psql, rather than via ALTER EXTENSION 7 | \echo Use "ALTER EXTENSION pg_track_settings" to load this file. \quit 8 | 9 | CREATE OR REPLACE FUNCTION @extschema@.pg_track_settings_settings_src ( 10 | IN _srvid integer, 11 | OUT ts timestamp with time zone, 12 | OUT name text, 13 | OUT setting text, 14 | OUT current_setting text 15 | ) 16 | RETURNS SETOF record AS $PROC$ 17 | BEGIN 18 | IF (_srvid = 0) THEN 19 | RETURN QUERY SELECT now(), 20 | s.name, s.setting, pg_catalog.current_setting(s.name) 21 | FROM pg_catalog.pg_settings s; 22 | ELSE 23 | RETURN QUERY SELECT s.ts, 24 | s.name, s.setting, s.current_setting 25 | FROM @extschema@.pg_track_settings_settings_src_tmp s 26 | WHERE srvid = _srvid; 27 | END IF; 28 | END; 29 | $PROC$ LANGUAGE plpgsql; /* end of pg_track_settings_settings_src */ 30 | 31 | CREATE OR REPLACE FUNCTION @extschema@.pg_track_settings_rds_src ( 32 | IN _srvid integer, 33 | OUT ts timestamp with time zone, 34 | OUT name text, 35 | OUT setting text, 36 | OUT setdatabase oid, 37 | OUT setrole oid 38 | ) 39 | RETURNS SETOF record AS $PROC$ 40 | BEGIN 41 | IF (_srvid = 0) THEN 42 | RETURN QUERY SELECT now(), 43 | (regexp_split_to_array(unnest(s.setconfig),'=')::text[])[1] AS name, 44 | (regexp_split_to_array(unnest(s.setconfig),'=')::text[])[2] AS setting, 45 | s.setdatabase, s.setrole 46 | FROM pg_catalog.pg_db_role_setting s; 47 | ELSE 48 | RETURN QUERY SELECT s.ts, 49 | s.name, s.setting, s.setdatabase, s.setrole 50 | FROM @extschema@.pg_track_settings_rds_src_tmp s 51 | WHERE srvid = _srvid; 52 | END IF; 53 | END; 54 | $PROC$ LANGUAGE plpgsql; /* end of pg_track_settings_rds_src */ 55 | 56 | CREATE OR REPLACE FUNCTION @extschema@.pg_track_settings_reboot_src ( 57 | IN _srvid integer, 58 | OUT ts timestamp with time zone, 59 | OUT postmaster_ts timestamp with time zone 60 | ) 61 | RETURNS SETOF record AS $PROC$ 62 | BEGIN 63 | IF (_srvid = 0) THEN 64 | RETURN QUERY SELECT now(), 65 | pg_postmaster_start_time(); 66 | ELSE 67 | RETURN QUERY SELECT s.ts, 68 | s.postmaster_ts 69 | FROM @extschema@.pg_track_settings_reboot_src_tmp s 70 | WHERE srvid = _srvid; 71 | END IF; 72 | END; 73 | $PROC$ LANGUAGE plpgsql; /* end of pg_track_settings_reboot_src */ 74 | 75 | CREATE OR REPLACE FUNCTION @extschema@.pg_track_settings_snapshot_settings(_srvid integer) 76 | RETURNS boolean AS 77 | $_$ 78 | DECLARE 79 | _snap_ts timestamp with time zone = NULL; 80 | BEGIN 81 | SELECT max(ts) INTO _snap_ts 82 | FROM @extschema@.pg_track_settings_settings_src(_srvid); 83 | 84 | -- this function should have been called for previously saved data. If 85 | -- not, probably somethig went wrong, so discard those data 86 | IF (_srvid != 0) THEN 87 | DELETE FROM @extschema@.pg_track_settings_settings_src_tmp 88 | WHERE ts != _snap_ts 89 | AND srvid = _srvid; 90 | END IF; 91 | 92 | -- Handle dropped GUC 93 | WITH src AS ( 94 | SELECT * FROM @extschema@.pg_track_settings_settings_src(_srvid) 95 | ), 96 | dropped AS ( 97 | SELECT s.ts, l.srvid, l.name 98 | FROM @extschema@.pg_track_settings_list l 99 | LEFT JOIN src s ON s.name = l.name 100 | WHERE l.srvid = _srvid 101 | AND s.name IS NULL 102 | ), 103 | mark_dropped AS ( 104 | INSERT INTO @extschema@.pg_track_settings_history (srvid, ts, name, setting, 105 | setting_pretty, is_dropped) 106 | SELECT srvid, COALESCE(_snap_ts, now()), name, NULL, NULL, true 107 | FROM dropped 108 | ) 109 | DELETE FROM @extschema@.pg_track_settings_list l 110 | USING dropped d 111 | WHERE d.name = l.name 112 | AND d.srvid = l.srvid 113 | AND l.srvid = _srvid; 114 | 115 | -- Insert missing settings 116 | INSERT INTO @extschema@.pg_track_settings_list (srvid, name) 117 | SELECT _srvid, name 118 | FROM @extschema@.pg_track_settings_settings_src(_srvid) s 119 | WHERE NOT EXISTS (SELECT 1 120 | FROM @extschema@.pg_track_settings_list l 121 | WHERE l.srvid = _srvid 122 | AND l.name = s.name 123 | ); 124 | 125 | -- Detect changed GUC, insert new vals 126 | WITH src AS ( 127 | SELECT * FROM @extschema@.pg_track_settings_settings_src(_srvid) 128 | ), last_snapshot AS ( 129 | SELECT srvid, name, setting 130 | FROM ( 131 | SELECT srvid, name, setting, 132 | row_number() OVER (PARTITION BY NAME ORDER BY ts DESC) AS rn 133 | FROM @extschema@.pg_track_settings_history h 134 | WHERE h.srvid = _srvid 135 | ) all_snapshots 136 | WHERE all_snapshots.rn = 1 137 | ) 138 | INSERT INTO @extschema@.pg_track_settings_history 139 | (srvid, ts, name, setting, setting_pretty) 140 | SELECT _srvid, s.ts, s.name, s.setting, s.current_setting 141 | FROM src s 142 | LEFT JOIN last_snapshot l ON l.name = s.name 143 | WHERE ( 144 | l.name IS NULL 145 | OR l.setting IS DISTINCT FROM s.setting 146 | ); 147 | 148 | IF (_srvid != 0) THEN 149 | DELETE FROM @extschema@.pg_track_settings_settings_src_tmp 150 | WHERE srvid = _srvid; 151 | END IF; 152 | 153 | RETURN true; 154 | END; 155 | $_$ 156 | LANGUAGE plpgsql; /* end of pg_track_settings_snapshot_settings() */ 157 | 158 | CREATE OR REPLACE FUNCTION @extschema@.pg_track_settings_snapshot_rds(_srvid integer) 159 | RETURNS boolean AS 160 | $_$ 161 | DECLARE 162 | _snap_ts timestamp with time zone; 163 | BEGIN 164 | -- If all pg_db_role_setting have been removed, we won't get a snapshot ts 165 | -- but we may still have to record that some settings have been removed. 166 | -- In that case simply use now(), as that extension doesn't guarantee the 167 | -- timestamp to be more precise than the snapshot interval, and there's 168 | -- isn't any better timestamp to use anyway. 169 | SELECT coalesce(max(ts), now()) INTO _snap_ts 170 | FROM @extschema@.pg_track_settings_rds_src(_srvid); 171 | 172 | -- this function should have been called for previously saved data. If 173 | -- not, probably somethig went wrong, so discard those data 174 | IF (_srvid != 0) THEN 175 | DELETE FROM @extschema@.pg_track_settings_rds_src_tmp 176 | WHERE ts != _snap_ts 177 | AND srvid = _srvid; 178 | END IF; 179 | 180 | -- Handle dropped db_role_setting 181 | WITH rds AS ( 182 | SELECT * FROM @extschema@.pg_track_settings_rds_src(_srvid) 183 | ), 184 | dropped AS ( 185 | SELECT _snap_ts AS ts, l.setdatabase, l.setrole, l.name 186 | FROM @extschema@.pg_track_db_role_settings_list l 187 | LEFT JOIN rds s ON ( 188 | s.setdatabase = l.setdatabase 189 | AND s.setrole = l.setrole 190 | AND s.name = l.name 191 | ) 192 | WHERE l.srvid = _srvid 193 | AND s.setdatabase IS NULL 194 | AND s.setrole IS NULL 195 | AND s.name IS NULL 196 | ), 197 | mark_dropped AS ( 198 | INSERT INTO @extschema@.pg_track_db_role_settings_history 199 | (srvid, ts, setdatabase, setrole, name, setting, is_dropped) 200 | SELECT _srvid, ts, d.setdatabase, d.setrole, d.name, NULL, true 201 | FROM dropped AS d 202 | ) 203 | DELETE FROM @extschema@.pg_track_db_role_settings_list l 204 | USING dropped d 205 | WHERE 206 | l.srvid = _srvid 207 | AND d.setdatabase = l.setdatabase 208 | AND d.setrole = l.setrole 209 | AND d.name = l.name; 210 | 211 | -- Insert missing settings 212 | WITH rds AS ( 213 | SELECT * FROM @extschema@.pg_track_settings_rds_src(_srvid) 214 | ) 215 | INSERT INTO @extschema@.pg_track_db_role_settings_list 216 | (srvid, setdatabase, setrole, name) 217 | SELECT _srvid, setdatabase, setrole, name 218 | FROM rds s 219 | WHERE NOT EXISTS (SELECT 1 220 | FROM @extschema@.pg_track_db_role_settings_list l 221 | WHERE 222 | l.srvid = _srvid 223 | AND l.setdatabase = s.setdatabase 224 | AND l.setrole = l.setrole 225 | AND l.name = s.name 226 | ); 227 | 228 | -- Detect changed GUC, insert new vals 229 | WITH rds AS ( 230 | SELECT * FROM @extschema@.pg_track_settings_rds_src(_srvid) 231 | ), 232 | last_snapshot AS ( 233 | SELECT setdatabase, setrole, name, setting 234 | FROM ( 235 | SELECT setdatabase, setrole, name, setting, 236 | row_number() OVER (PARTITION BY name, setdatabase, setrole ORDER BY ts DESC) AS rn 237 | FROM @extschema@.pg_track_db_role_settings_history 238 | WHERE srvid = _srvid 239 | ) all_snapshots 240 | WHERE all_snapshots.rn = 1 241 | ) 242 | INSERT INTO @extschema@.pg_track_db_role_settings_history 243 | (srvid, ts, setdatabase, setrole, name, setting) 244 | SELECT _srvid, s.ts, s.setdatabase, s.setrole, s.name, s.setting 245 | FROM rds s 246 | LEFT JOIN last_snapshot l ON 247 | l.setdatabase = s.setdatabase 248 | AND l.setrole = s.setrole 249 | AND l.name = s.name 250 | WHERE (l.setdatabase IS NULL 251 | AND l.setrole IS NULL 252 | AND l.name IS NULL) 253 | OR (l.setting IS DISTINCT FROM s.setting); 254 | 255 | IF (_srvid != 0) THEN 256 | DELETE FROM @extschema@.pg_track_settings_rds_src_tmp 257 | WHERE srvid = _srvid; 258 | END IF; 259 | 260 | RETURN true; 261 | END; 262 | $_$ 263 | LANGUAGE plpgsql; /* end of pg_track_settings_snapshot_rds() */ 264 | -------------------------------------------------------------------------------- /pg_track_settings--2.1.0.sql: -------------------------------------------------------------------------------- 1 | -- This program is open source, licensed under the PostgreSQL License. 2 | -- For license terms, see the LICENSE file. 3 | -- 4 | -- Copyright (C) 2015-2024: Julien Rouhaud 5 | 6 | -- complain if script is sourced in psql, rather than via CREATE EXTENSION 7 | \echo Use "CREATE EXTENSION pg_track_settings" to load this file. \quit 8 | 9 | SET client_encoding = 'UTF8'; 10 | 11 | CREATE UNLOGGED TABLE @extschema@.pg_track_settings_settings_src_tmp ( 12 | srvid integer NOT NULL, 13 | ts timestamp with time zone NOT NULL, 14 | name text NOT NULL, 15 | setting text, 16 | current_setting text 17 | ); 18 | -- no need to backup this table 19 | 20 | CREATE TABLE @extschema@.pg_track_settings_list ( 21 | srvid integer NOT NULL, 22 | name text, 23 | PRIMARY KEY (srvid, name) 24 | ); 25 | SELECT pg_catalog.pg_extension_config_dump('@extschema@.pg_track_settings_list', ''); 26 | 27 | CREATE TABLE @extschema@.pg_track_settings_history ( 28 | srvid integer NOT NULL, 29 | ts timestamp with time zone, 30 | name text NOT NULL, 31 | setting text, 32 | is_dropped boolean NOT NULL DEFAULT false, 33 | setting_pretty text, 34 | PRIMARY KEY(srvid, ts, name) 35 | ); 36 | SELECT pg_catalog.pg_extension_config_dump('@extschema@.pg_track_settings_history', ''); 37 | 38 | CREATE UNLOGGED TABLE @extschema@.pg_track_settings_rds_src_tmp ( 39 | srvid integer NOT NULL, 40 | ts timestamp with time zone NOT NULL, 41 | name text NOT NULL, 42 | setting text, 43 | setdatabase oid NOT NULL, 44 | setrole oid NOT NULL 45 | ); 46 | -- no need to backup this table 47 | 48 | CREATE TABLE @extschema@.pg_track_db_role_settings_list ( 49 | srvid integer, 50 | name text, 51 | setdatabase oid, 52 | setrole oid, 53 | PRIMARY KEY (srvid, name, setdatabase, setrole) 54 | ); 55 | SELECT pg_catalog.pg_extension_config_dump('@extschema@.pg_track_db_role_settings_list', ''); 56 | 57 | CREATE TABLE @extschema@.pg_track_db_role_settings_history ( 58 | srvid INTEGER NOT NULL, 59 | ts timestamp with time zone, 60 | name text, 61 | setdatabase oid, 62 | setrole oid, 63 | setting text, 64 | is_dropped boolean NOT NULL DEFAULT false, 65 | PRIMARY KEY(srvid, ts, name, setdatabase, setrole) 66 | ); 67 | SELECT pg_catalog.pg_extension_config_dump('@extschema@.pg_track_db_role_settings_history', ''); 68 | 69 | CREATE UNLOGGED TABLE @extschema@.pg_track_settings_reboot_src_tmp ( 70 | srvid integer NOT NULL, 71 | ts timestamp with time zone NOT NULL, 72 | postmaster_ts timestamp with time zone NOT NULL 73 | ); 74 | -- no need to backup this table 75 | 76 | CREATE TABLE @extschema@.pg_reboot ( 77 | srvid integer NOT NULL, 78 | ts timestamp with time zone, 79 | PRIMARY KEY (srvid, ts) 80 | ); 81 | SELECT pg_catalog.pg_extension_config_dump('@extschema@.pg_reboot', ''); 82 | 83 | ---------------------- 84 | -- source functions -- 85 | ---------------------- 86 | CREATE OR REPLACE FUNCTION @extschema@.pg_track_settings_settings_src ( 87 | IN _srvid integer, 88 | OUT ts timestamp with time zone, 89 | OUT name text, 90 | OUT setting text, 91 | OUT current_setting text 92 | ) 93 | RETURNS SETOF record AS $PROC$ 94 | BEGIN 95 | IF (_srvid = 0) THEN 96 | RETURN QUERY SELECT now(), 97 | s.name, s.setting, pg_catalog.current_setting(s.name) 98 | FROM pg_catalog.pg_settings s; 99 | ELSE 100 | RETURN QUERY SELECT s.ts, 101 | s.name, s.setting, s.current_setting 102 | FROM @extschema@.pg_track_settings_settings_src_tmp s; 103 | END IF; 104 | END; 105 | $PROC$ LANGUAGE plpgsql; /* end of pg_track_settings_settings_src */ 106 | 107 | CREATE OR REPLACE FUNCTION @extschema@.pg_track_settings_rds_src ( 108 | IN _srvid integer, 109 | OUT ts timestamp with time zone, 110 | OUT name text, 111 | OUT setting text, 112 | OUT setdatabase oid, 113 | OUT setrole oid 114 | ) 115 | RETURNS SETOF record AS $PROC$ 116 | BEGIN 117 | IF (_srvid = 0) THEN 118 | RETURN QUERY SELECT now(), 119 | (regexp_split_to_array(unnest(s.setconfig),'=')::text[])[1] AS name, 120 | (regexp_split_to_array(unnest(s.setconfig),'=')::text[])[2] AS setting, 121 | s.setdatabase, s.setrole 122 | FROM pg_catalog.pg_db_role_setting s; 123 | ELSE 124 | RETURN QUERY SELECT s.ts, 125 | s.name, s.setting, s.setdatabase, s.setrole 126 | FROM @extschema@.pg_track_settings_rds_src_tmp s; 127 | END IF; 128 | END; 129 | $PROC$ LANGUAGE plpgsql; /* end of pg_track_settings_rds_src */ 130 | 131 | CREATE OR REPLACE FUNCTION @extschema@.pg_track_settings_reboot_src ( 132 | IN _srvid integer, 133 | OUT ts timestamp with time zone, 134 | OUT postmaster_ts timestamp with time zone 135 | ) 136 | RETURNS SETOF record AS $PROC$ 137 | BEGIN 138 | IF (_srvid = 0) THEN 139 | RETURN QUERY SELECT now(), 140 | pg_postmaster_start_time(); 141 | ELSE 142 | RETURN QUERY SELECT s.ts, 143 | s.postmaster_ts 144 | FROM @extschema@.pg_track_settings_reboot_src_tmp s; 145 | END IF; 146 | END; 147 | $PROC$ LANGUAGE plpgsql; /* end of pg_track_settings_reboot_src */ 148 | 149 | ------------------------ 150 | -- snapshot functions -- 151 | ------------------------ 152 | CREATE OR REPLACE FUNCTION @extschema@.pg_track_settings_snapshot_settings(_srvid integer) 153 | RETURNS boolean AS 154 | $_$ 155 | DECLARE 156 | _snap_ts timestamp with time zone = NULL; 157 | BEGIN 158 | SELECT max(ts) INTO _snap_ts 159 | FROM @extschema@.pg_track_settings_settings_src(_srvid); 160 | 161 | -- this function should have been called for previously saved data. If 162 | -- not, probably somethig went wrong, so discard those data 163 | IF (_srvid != 0) THEN 164 | DELETE FROM @extschema@.pg_track_settings_settings_src_tmp 165 | WHERE ts != _snap_ts; 166 | END IF; 167 | 168 | -- Handle dropped GUC 169 | WITH src AS ( 170 | SELECT * FROM @extschema@.pg_track_settings_settings_src(_srvid) 171 | ), 172 | dropped AS ( 173 | SELECT s.ts, l.srvid, l.name 174 | FROM @extschema@.pg_track_settings_list l 175 | LEFT JOIN src s ON s.name = l.name 176 | WHERE l.srvid = _srvid 177 | AND s.name IS NULL 178 | ), 179 | mark_dropped AS ( 180 | INSERT INTO @extschema@.pg_track_settings_history (srvid, ts, name, setting, 181 | setting_pretty, is_dropped) 182 | SELECT srvid, COALESCE(_snap_ts, now()), name, NULL, NULL, true 183 | FROM dropped 184 | ) 185 | DELETE FROM @extschema@.pg_track_settings_list l 186 | USING dropped d 187 | WHERE d.name = l.name 188 | AND d.srvid = l.srvid 189 | AND l.srvid = _srvid; 190 | 191 | -- Insert missing settings 192 | INSERT INTO @extschema@.pg_track_settings_list (srvid, name) 193 | SELECT _srvid, name 194 | FROM @extschema@.pg_track_settings_settings_src(_srvid) s 195 | WHERE NOT EXISTS (SELECT 1 196 | FROM @extschema@.pg_track_settings_list l 197 | WHERE l.srvid = _srvid 198 | AND l.name = s.name 199 | ); 200 | 201 | -- Detect changed GUC, insert new vals 202 | WITH src AS ( 203 | SELECT * FROM @extschema@.pg_track_settings_settings_src(_srvid) 204 | ), last_snapshot AS ( 205 | SELECT srvid, name, setting 206 | FROM ( 207 | SELECT srvid, name, setting, 208 | row_number() OVER (PARTITION BY NAME ORDER BY ts DESC) AS rn 209 | FROM @extschema@.pg_track_settings_history h 210 | WHERE h.srvid = _srvid 211 | ) all_snapshots 212 | WHERE all_snapshots.rn = 1 213 | ) 214 | INSERT INTO @extschema@.pg_track_settings_history 215 | (srvid, ts, name, setting, setting_pretty) 216 | SELECT _srvid, s.ts, s.name, s.setting, s.current_setting 217 | FROM src s 218 | LEFT JOIN last_snapshot l ON l.name = s.name 219 | WHERE ( 220 | l.name IS NULL 221 | OR l.setting IS DISTINCT FROM s.setting 222 | ); 223 | 224 | IF (_srvid != 0) THEN 225 | DELETE FROM @extschema@.pg_track_settings_settings_src_tmp 226 | WHERE srvid = _srvid; 227 | END IF; 228 | 229 | RETURN true; 230 | END; 231 | $_$ 232 | LANGUAGE plpgsql; /* end of pg_track_settings_snapshot_settings() */ 233 | 234 | CREATE OR REPLACE FUNCTION @extschema@.pg_track_settings_snapshot_rds(_srvid integer) 235 | RETURNS boolean AS 236 | $_$ 237 | DECLARE 238 | _snap_ts timestamp with time zone; 239 | BEGIN 240 | SELECT max(ts) INTO _snap_ts 241 | FROM @extschema@.pg_track_settings_rds_src(_srvid); 242 | 243 | -- this function should have been called for previously saved data. If 244 | -- not, probably somethig went wrong, so discard those data 245 | IF (_srvid != 0) THEN 246 | DELETE FROM @extschema@.pg_track_settings_rds_src_tmp 247 | WHERE ts != _snap_ts; 248 | END IF; 249 | 250 | -- Handle dropped db_role_setting 251 | WITH rds AS ( 252 | SELECT * FROM @extschema@.pg_track_settings_rds_src(_srvid) 253 | ), 254 | dropped AS ( 255 | SELECT _snap_ts AS ts, l.setdatabase, l.setrole, l.name 256 | FROM @extschema@.pg_track_db_role_settings_list l 257 | LEFT JOIN rds s ON ( 258 | s.setdatabase = l.setdatabase 259 | AND s.setrole = l.setrole 260 | AND s.name = l.name 261 | ) 262 | WHERE l.srvid = _srvid 263 | AND s.setdatabase IS NULL 264 | AND s.setrole IS NULL 265 | AND s.name IS NULL 266 | ), 267 | mark_dropped AS ( 268 | INSERT INTO @extschema@.pg_track_db_role_settings_history 269 | (srvid, ts, setdatabase, setrole, name, setting, is_dropped) 270 | SELECT _srvid, ts, d.setdatabase, d.setrole, d.name, NULL, true 271 | FROM dropped AS d 272 | ) 273 | DELETE FROM @extschema@.pg_track_db_role_settings_list l 274 | USING dropped d 275 | WHERE 276 | l.srvid = _srvid 277 | AND d.setdatabase = l.setdatabase 278 | AND d.setrole = l.setrole 279 | AND d.name = l.name; 280 | 281 | -- Insert missing settings 282 | WITH rds AS ( 283 | SELECT * FROM @extschema@.pg_track_settings_rds_src(_srvid) 284 | ) 285 | INSERT INTO @extschema@.pg_track_db_role_settings_list 286 | (srvid, setdatabase, setrole, name) 287 | SELECT _srvid, setdatabase, setrole, name 288 | FROM rds s 289 | WHERE NOT EXISTS (SELECT 1 290 | FROM @extschema@.pg_track_db_role_settings_list l 291 | WHERE 292 | l.srvid = _srvid 293 | AND l.setdatabase = s.setdatabase 294 | AND l.setrole = l.setrole 295 | AND l.name = s.name 296 | ); 297 | 298 | -- Detect changed GUC, insert new vals 299 | WITH rds AS ( 300 | SELECT * FROM @extschema@.pg_track_settings_rds_src(_srvid) 301 | ), 302 | last_snapshot AS ( 303 | SELECT setdatabase, setrole, name, setting 304 | FROM ( 305 | SELECT setdatabase, setrole, name, setting, 306 | row_number() OVER (PARTITION BY name, setdatabase, setrole ORDER BY ts DESC) AS rn 307 | FROM @extschema@.pg_track_db_role_settings_history 308 | WHERE srvid = _srvid 309 | ) all_snapshots 310 | WHERE all_snapshots.rn = 1 311 | ) 312 | INSERT INTO @extschema@.pg_track_db_role_settings_history 313 | (srvid, ts, setdatabase, setrole, name, setting) 314 | SELECT _srvid, s.ts, s.setdatabase, s.setrole, s.name, s.setting 315 | FROM rds s 316 | LEFT JOIN last_snapshot l ON 317 | l.setdatabase = s.setdatabase 318 | AND l.setrole = s.setrole 319 | AND l.name = s.name 320 | WHERE (l.setdatabase IS NULL 321 | AND l.setrole IS NULL 322 | AND l.name IS NULL) 323 | OR (l.setting IS DISTINCT FROM s.setting); 324 | 325 | IF (_srvid != 0) THEN 326 | DELETE FROM @extschema@.pg_track_settings_rds_src_tmp 327 | WHERE srvid = _srvid; 328 | END IF; 329 | 330 | RETURN true; 331 | END; 332 | $_$ 333 | LANGUAGE plpgsql; /* end of pg_track_settings_snapshot_rds() */ 334 | 335 | CREATE OR REPLACE FUNCTION @extschema@.pg_track_settings_snapshot_reboot(_srvid integer) 336 | RETURNS boolean AS 337 | $_$ 338 | BEGIN 339 | -- Detect is postmaster restarted since last call 340 | WITH last_reboot AS ( 341 | SELECT t.postmaster_ts 342 | FROM @extschema@.pg_track_settings_reboot_src(_srvid) t 343 | ) 344 | INSERT INTO @extschema@.pg_reboot (srvid, ts) 345 | SELECT _srvid, lr.postmaster_ts FROM last_reboot lr 346 | WHERE NOT EXISTS (SELECT 1 347 | FROM @extschema@.pg_reboot r 348 | WHERE r.srvid = _srvid 349 | AND r.ts = lr.postmaster_ts 350 | AND r.srvid = _srvid 351 | ); 352 | 353 | IF (_srvid != 0) THEN 354 | DELETE FROM @extschema@.pg_track_settings_reboot_src_tmp 355 | WHERE srvid = _srvid; 356 | END IF; 357 | 358 | RETURN true; 359 | END; 360 | $_$ 361 | LANGUAGE plpgsql; /* end of pg_track_settings_snapshot_reboot() */ 362 | 363 | -- global function doing all the work for local instance, kept for backward 364 | -- compatibility 365 | CREATE OR REPLACE FUNCTION @extschema@.pg_track_settings_snapshot() 366 | RETURNS boolean AS 367 | $_$ 368 | BEGIN 369 | PERFORM @extschema@.pg_track_settings_snapshot_settings(0); 370 | PERFORM @extschema@.pg_track_settings_snapshot_rds(0); 371 | PERFORM @extschema@.pg_track_settings_snapshot_reboot(0); 372 | 373 | RETURN true; 374 | END; 375 | $_$ 376 | LANGUAGE plpgsql; 377 | /* end of pg_track_settings_snapshot() */ 378 | 379 | CREATE OR REPLACE FUNCTION @extschema@.pg_track_settings( 380 | _ts timestamp with time zone DEFAULT now(), 381 | _srvid integer DEFAULT 0) 382 | RETURNS TABLE (name text, setting text, setting_pretty text) AS 383 | $_$ 384 | BEGIN 385 | RETURN QUERY 386 | SELECT s.name, s.setting, s.setting_pretty 387 | FROM ( 388 | SELECT h.name, h.setting, h.setting_pretty, h.is_dropped, 389 | row_number() OVER (PARTITION BY h.name ORDER BY h.ts DESC) AS rn 390 | FROM @extschema@.pg_track_settings_history h 391 | WHERE h.srvid = _srvid 392 | AND h.ts <= _ts 393 | ) s 394 | WHERE s.rn = 1 395 | AND NOT s.is_dropped 396 | ORDER BY s.name; 397 | END; 398 | $_$ 399 | LANGUAGE plpgsql; 400 | 401 | CREATE OR REPLACE FUNCTION @extschema@.pg_track_db_role_settings( 402 | _ts timestamp with time zone DEFAULT now(), 403 | _srvid integer DEFAULT 0) 404 | RETURNS TABLE (setdatabase oid, setrole oid, name text, setting text) AS 405 | $_$ 406 | BEGIN 407 | RETURN QUERY 408 | SELECT s.setdatabase, s.setrole, s.name, s.setting 409 | FROM ( 410 | SELECT h.setdatabase, h.setrole, h.name, h.setting, h.is_dropped, 411 | row_number() OVER (PARTITION BY h.name, h.setdatabase, h.setrole ORDER BY h.ts DESC) AS rn 412 | FROM @extschema@.pg_track_db_role_settings_history h 413 | WHERE h.srvid = _srvid 414 | AND h.ts <= _ts 415 | ) s 416 | WHERE s.rn = 1 417 | AND NOT s.is_dropped 418 | ORDER BY s.setdatabase, s.setrole, s.name; 419 | END; 420 | $_$ 421 | LANGUAGE plpgsql; 422 | 423 | CREATE OR REPLACE FUNCTION @extschema@.pg_track_settings_diff( 424 | _from timestamp with time zone, 425 | _to timestamp with time zone, 426 | _srvid integer DEFAULT 0) 427 | RETURNS TABLE (name text, from_setting text, from_exists boolean, 428 | to_setting text, to_exists boolean, 429 | from_setting_pretty text, to_setting_pretty text) AS 430 | $_$ 431 | BEGIN 432 | RETURN QUERY 433 | SELECT COALESCE(s1.name, s2.name), 434 | s1.setting AS from_setting, 435 | CASE WHEN s1.setting IS NULL THEN false ELSE true END, 436 | s2.setting AS to_setting, 437 | CASE WHEN s2.setting IS NULL THEN false ELSE true END, 438 | s1.setting_pretty AS from_setting_pretty, 439 | s2.setting_pretty AS to_setting_pretty 440 | FROM @extschema@.pg_track_settings(_from, _srvid) s1 441 | FULL OUTER JOIN @extschema@.pg_track_settings(_to, _srvid) s2 ON s2.name = s1.name 442 | WHERE s1.setting IS DISTINCT FROM s2.setting 443 | ORDER BY 1; 444 | END; 445 | $_$ 446 | LANGUAGE plpgsql; 447 | 448 | CREATE OR REPLACE FUNCTION @extschema@.pg_track_db_role_settings_diff( 449 | _from timestamp with time zone, 450 | _to timestamp with time zone, 451 | _srvid integer DEFAULT 0) 452 | RETURNS TABLE (setdatabase oid, setrole oid, name text, 453 | from_setting text, from_exists boolean, to_setting text, to_exists boolean) 454 | AS 455 | $_$ 456 | BEGIN 457 | RETURN QUERY 458 | SELECT COALESCE(s1.setdatabase, s2.setdatabase), 459 | COALESCE(s1.setrole, s2.setrole), 460 | COALESCE(s1.name, s2.name), 461 | s1.setting AS from_setting, 462 | CASE WHEN s1.setting IS NULL THEN false ELSE true END, 463 | s2.setting AS to_setting, 464 | CASE WHEN s2.setting IS NULL THEN false ELSE true END 465 | FROM @extschema@.pg_track_db_role_settings(_from, _srvid) s1 466 | FULL OUTER JOIN @extschema@.pg_track_db_role_settings(_to, _srvid) s2 ON 467 | s2.setdatabase = s1.setdatabase 468 | AND s2.setrole = s1.setrole 469 | AND s2.name = s1.name 470 | WHERE 471 | s1.setdatabase IS DISTINCT FROM s2.setdatabase 472 | AND s1.setrole IS DISTINCT FROM s2.setrole 473 | AND s1.setting IS DISTINCT FROM s2.setting 474 | ORDER BY 1, 2, 3; 475 | END; 476 | $_$ 477 | LANGUAGE plpgsql; 478 | 479 | CREATE OR REPLACE FUNCTION @extschema@.pg_track_settings_log( 480 | _name text, 481 | _srvid integer DEFAULT 0) 482 | RETURNS TABLE (ts timestamp with time zone, name text, setting_exists boolean, 483 | setting text, setting_pretty text) AS 484 | $_$ 485 | BEGIN 486 | RETURN QUERY 487 | SELECT h.ts, h.name, NOT h.is_dropped, h.setting, h.setting_pretty 488 | FROM @extschema@.pg_track_settings_history h 489 | WHERE h.srvid = _srvid 490 | AND h.name = _name 491 | ORDER BY ts DESC; 492 | END; 493 | $_$ 494 | LANGUAGE plpgsql; 495 | 496 | CREATE OR REPLACE FUNCTION @extschema@.pg_track_db_role_settings_log( 497 | _name text, 498 | _srvid integer DEFAULT 0) 499 | RETURNS TABLE (ts timestamp with time zone, setdatabase oid, setrole oid, 500 | name text, setting_exists boolean, setting text) AS 501 | $_$ 502 | BEGIN 503 | RETURN QUERY 504 | SELECT h.ts, h.setdatabase, h.setrole, h.name, NOT h.is_dropped, h.setting 505 | FROM @extschema@.pg_track_db_role_settings_history h 506 | WHERE h.srvid = _srvid 507 | AND h.name = _name 508 | ORDER BY ts, setdatabase, setrole DESC; 509 | END; 510 | $_$ 511 | LANGUAGE plpgsql; 512 | 513 | CREATE OR REPLACE FUNCTION @extschema@.pg_track_reboot_log(_srvid integer DEFAULT 0) 514 | RETURNS TABLE (ts timestamp with time zone) AS 515 | $_$ 516 | BEGIN 517 | RETURN QUERY 518 | SELECT r.ts 519 | FROM @extschema@.pg_reboot r 520 | WHERE r.srvid = _srvid 521 | ORDER BY r.ts; 522 | END; 523 | $_$ 524 | LANGUAGE plpgsql; 525 | 526 | CREATE OR REPLACE FUNCTION @extschema@.pg_track_settings_reset(_srvid integer DEFAULT 0) 527 | RETURNS void AS 528 | $_$ 529 | BEGIN 530 | DELETE FROM @extschema@.pg_track_settings_settings_src_tmp WHERE srvid = _srvid; 531 | DELETE FROM @extschema@.pg_track_settings_rds_src_tmp WHERE srvid = _srvid; 532 | DELETE FROM @extschema@.pg_track_settings_reboot_src_tmp WHERE srvid = _srvid; 533 | DELETE FROM @extschema@.pg_track_settings_list WHERE srvid = _srvid; 534 | DELETE FROM @extschema@.pg_track_settings_history WHERE srvid = _srvid; 535 | DELETE FROM @extschema@.pg_track_db_role_settings_list WHERE srvid = _srvid; 536 | DELETE FROM @extschema@.pg_track_db_role_settings_history WHERE srvid = _srvid; 537 | DELETE FROM @extschema@.pg_reboot WHERE srvid = _srvid; 538 | END; 539 | $_$ 540 | LANGUAGE plpgsql; 541 | -------------------------------------------------------------------------------- /pg_track_settings--2.1.2.sql: -------------------------------------------------------------------------------- 1 | -- This program is open source, licensed under the PostgreSQL License. 2 | -- For license terms, see the LICENSE file. 3 | -- 4 | -- Copyright (C) 2015-2024: Julien Rouhaud 5 | 6 | -- complain if script is sourced in psql, rather than via CREATE EXTENSION 7 | \echo Use "CREATE EXTENSION pg_track_settings" to load this file. \quit 8 | 9 | CREATE UNLOGGED TABLE @extschema@.pg_track_settings_settings_src_tmp ( 10 | srvid integer NOT NULL, 11 | ts timestamp with time zone NOT NULL, 12 | name text NOT NULL, 13 | setting text, 14 | current_setting text 15 | ); 16 | -- no need to backup this table 17 | 18 | CREATE TABLE @extschema@.pg_track_settings_list ( 19 | srvid integer NOT NULL, 20 | name text, 21 | PRIMARY KEY (srvid, name) 22 | ); 23 | SELECT pg_catalog.pg_extension_config_dump('@extschema@.pg_track_settings_list', ''); 24 | 25 | CREATE TABLE @extschema@.pg_track_settings_history ( 26 | srvid integer NOT NULL, 27 | ts timestamp with time zone, 28 | name text NOT NULL, 29 | setting text, 30 | is_dropped boolean NOT NULL DEFAULT false, 31 | setting_pretty text, 32 | PRIMARY KEY(srvid, ts, name) 33 | ); 34 | SELECT pg_catalog.pg_extension_config_dump('@extschema@.pg_track_settings_history', ''); 35 | 36 | CREATE UNLOGGED TABLE @extschema@.pg_track_settings_rds_src_tmp ( 37 | srvid integer NOT NULL, 38 | ts timestamp with time zone NOT NULL, 39 | name text NOT NULL, 40 | setting text, 41 | setdatabase oid NOT NULL, 42 | setrole oid NOT NULL 43 | ); 44 | -- no need to backup this table 45 | 46 | CREATE TABLE @extschema@.pg_track_db_role_settings_list ( 47 | srvid integer, 48 | name text, 49 | setdatabase oid, 50 | setrole oid, 51 | PRIMARY KEY (srvid, name, setdatabase, setrole) 52 | ); 53 | SELECT pg_catalog.pg_extension_config_dump('@extschema@.pg_track_db_role_settings_list', ''); 54 | 55 | CREATE TABLE @extschema@.pg_track_db_role_settings_history ( 56 | srvid INTEGER NOT NULL, 57 | ts timestamp with time zone, 58 | name text, 59 | setdatabase oid, 60 | setrole oid, 61 | setting text, 62 | is_dropped boolean NOT NULL DEFAULT false, 63 | PRIMARY KEY(srvid, ts, name, setdatabase, setrole) 64 | ); 65 | SELECT pg_catalog.pg_extension_config_dump('@extschema@.pg_track_db_role_settings_history', ''); 66 | 67 | CREATE UNLOGGED TABLE @extschema@.pg_track_settings_reboot_src_tmp ( 68 | srvid integer NOT NULL, 69 | ts timestamp with time zone NOT NULL, 70 | postmaster_ts timestamp with time zone NOT NULL 71 | ); 72 | -- no need to backup this table 73 | 74 | CREATE TABLE @extschema@.pg_reboot ( 75 | srvid integer NOT NULL, 76 | ts timestamp with time zone, 77 | PRIMARY KEY (srvid, ts) 78 | ); 79 | SELECT pg_catalog.pg_extension_config_dump('@extschema@.pg_reboot', ''); 80 | 81 | ---------------------- 82 | -- source functions -- 83 | ---------------------- 84 | CREATE OR REPLACE FUNCTION @extschema@.pg_track_settings_settings_src ( 85 | IN _srvid integer, 86 | OUT ts timestamp with time zone, 87 | OUT name text, 88 | OUT setting text, 89 | OUT current_setting text 90 | ) 91 | RETURNS SETOF record AS $PROC$ 92 | BEGIN 93 | IF (_srvid = 0) THEN 94 | RETURN QUERY SELECT now(), 95 | s.name, s.setting, pg_catalog.current_setting(s.name) 96 | FROM pg_catalog.pg_settings s; 97 | ELSE 98 | RETURN QUERY SELECT s.ts, 99 | s.name, s.setting, s.current_setting 100 | FROM @extschema@.pg_track_settings_settings_src_tmp s 101 | WHERE srvid = _srvid; 102 | END IF; 103 | END; 104 | $PROC$ LANGUAGE plpgsql; /* end of pg_track_settings_settings_src */ 105 | 106 | CREATE OR REPLACE FUNCTION @extschema@.pg_track_settings_rds_src ( 107 | IN _srvid integer, 108 | OUT ts timestamp with time zone, 109 | OUT name text, 110 | OUT setting text, 111 | OUT setdatabase oid, 112 | OUT setrole oid 113 | ) 114 | RETURNS SETOF record AS $PROC$ 115 | BEGIN 116 | IF (_srvid = 0) THEN 117 | RETURN QUERY SELECT now(), 118 | (regexp_split_to_array(unnest(s.setconfig),'=')::text[])[1] AS name, 119 | (regexp_split_to_array(unnest(s.setconfig),'=')::text[])[2] AS setting, 120 | s.setdatabase, s.setrole 121 | FROM pg_catalog.pg_db_role_setting s; 122 | ELSE 123 | RETURN QUERY SELECT s.ts, 124 | s.name, s.setting, s.setdatabase, s.setrole 125 | FROM @extschema@.pg_track_settings_rds_src_tmp s 126 | WHERE srvid = _srvid; 127 | END IF; 128 | END; 129 | $PROC$ LANGUAGE plpgsql; /* end of pg_track_settings_rds_src */ 130 | 131 | CREATE OR REPLACE FUNCTION @extschema@.pg_track_settings_reboot_src ( 132 | IN _srvid integer, 133 | OUT ts timestamp with time zone, 134 | OUT postmaster_ts timestamp with time zone 135 | ) 136 | RETURNS SETOF record AS $PROC$ 137 | BEGIN 138 | IF (_srvid = 0) THEN 139 | RETURN QUERY SELECT now(), 140 | pg_postmaster_start_time(); 141 | ELSE 142 | RETURN QUERY SELECT s.ts, 143 | s.postmaster_ts 144 | FROM @extschema@.pg_track_settings_reboot_src_tmp s 145 | WHERE srvid = _srvid; 146 | END IF; 147 | END; 148 | $PROC$ LANGUAGE plpgsql; /* end of pg_track_settings_reboot_src */ 149 | 150 | ------------------------ 151 | -- snapshot functions -- 152 | ------------------------ 153 | CREATE OR REPLACE FUNCTION @extschema@.pg_track_settings_snapshot_settings(_srvid integer) 154 | RETURNS boolean AS 155 | $_$ 156 | DECLARE 157 | _snap_ts timestamp with time zone = NULL; 158 | BEGIN 159 | SELECT max(ts) INTO _snap_ts 160 | FROM @extschema@.pg_track_settings_settings_src(_srvid); 161 | 162 | -- this function should have been called for previously saved data. If 163 | -- not, probably somethig went wrong, so discard those data 164 | IF (_srvid != 0) THEN 165 | DELETE FROM @extschema@.pg_track_settings_settings_src_tmp 166 | WHERE ts != _snap_ts 167 | AND srvid = _srvid; 168 | END IF; 169 | 170 | -- Handle dropped GUC 171 | WITH src AS ( 172 | SELECT * FROM @extschema@.pg_track_settings_settings_src(_srvid) 173 | ), 174 | dropped AS ( 175 | SELECT s.ts, l.srvid, l.name 176 | FROM @extschema@.pg_track_settings_list l 177 | LEFT JOIN src s ON s.name = l.name 178 | WHERE l.srvid = _srvid 179 | AND s.name IS NULL 180 | ), 181 | mark_dropped AS ( 182 | INSERT INTO @extschema@.pg_track_settings_history (srvid, ts, name, setting, 183 | setting_pretty, is_dropped) 184 | SELECT srvid, COALESCE(_snap_ts, now()), name, NULL, NULL, true 185 | FROM dropped 186 | ) 187 | DELETE FROM @extschema@.pg_track_settings_list l 188 | USING dropped d 189 | WHERE d.name = l.name 190 | AND d.srvid = l.srvid 191 | AND l.srvid = _srvid; 192 | 193 | -- Insert missing settings 194 | INSERT INTO @extschema@.pg_track_settings_list (srvid, name) 195 | SELECT _srvid, name 196 | FROM @extschema@.pg_track_settings_settings_src(_srvid) s 197 | WHERE NOT EXISTS (SELECT 1 198 | FROM @extschema@.pg_track_settings_list l 199 | WHERE l.srvid = _srvid 200 | AND l.name = s.name 201 | ); 202 | 203 | -- Detect changed GUC, insert new vals 204 | WITH src AS ( 205 | SELECT * FROM @extschema@.pg_track_settings_settings_src(_srvid) 206 | ), last_snapshot AS ( 207 | SELECT srvid, name, setting 208 | FROM ( 209 | SELECT srvid, name, setting, 210 | row_number() OVER (PARTITION BY NAME ORDER BY ts DESC) AS rn 211 | FROM @extschema@.pg_track_settings_history h 212 | WHERE h.srvid = _srvid 213 | ) all_snapshots 214 | WHERE all_snapshots.rn = 1 215 | ) 216 | INSERT INTO @extschema@.pg_track_settings_history 217 | (srvid, ts, name, setting, setting_pretty) 218 | SELECT _srvid, s.ts, s.name, s.setting, s.current_setting 219 | FROM src s 220 | LEFT JOIN last_snapshot l ON l.name = s.name 221 | WHERE ( 222 | l.name IS NULL 223 | OR l.setting IS DISTINCT FROM s.setting 224 | ); 225 | 226 | IF (_srvid != 0) THEN 227 | DELETE FROM @extschema@.pg_track_settings_settings_src_tmp 228 | WHERE srvid = _srvid; 229 | END IF; 230 | 231 | RETURN true; 232 | END; 233 | $_$ 234 | LANGUAGE plpgsql; /* end of pg_track_settings_snapshot_settings() */ 235 | 236 | CREATE OR REPLACE FUNCTION @extschema@.pg_track_settings_snapshot_rds(_srvid integer) 237 | RETURNS boolean AS 238 | $_$ 239 | DECLARE 240 | _snap_ts timestamp with time zone; 241 | BEGIN 242 | -- If all pg_db_role_setting have been removed, we won't get a snapshot ts 243 | -- but we may still have to record that some settings have been removed. 244 | -- In that case simply use now(), as that extension doesn't guarantee the 245 | -- timestamp to be more precise than the snapshot interval, and there's 246 | -- isn't any better timestamp to use anyway. 247 | SELECT coalesce(max(ts), now()) INTO _snap_ts 248 | FROM @extschema@.pg_track_settings_rds_src(_srvid); 249 | 250 | -- this function should have been called for previously saved data. If 251 | -- not, probably somethig went wrong, so discard those data 252 | IF (_srvid != 0) THEN 253 | DELETE FROM @extschema@.pg_track_settings_rds_src_tmp 254 | WHERE ts != _snap_ts 255 | AND srvid = _srvid; 256 | END IF; 257 | 258 | -- Handle dropped db_role_setting 259 | WITH rds AS ( 260 | SELECT * FROM @extschema@.pg_track_settings_rds_src(_srvid) 261 | ), 262 | dropped AS ( 263 | SELECT _snap_ts AS ts, l.setdatabase, l.setrole, l.name 264 | FROM @extschema@.pg_track_db_role_settings_list l 265 | LEFT JOIN rds s ON ( 266 | s.setdatabase = l.setdatabase 267 | AND s.setrole = l.setrole 268 | AND s.name = l.name 269 | ) 270 | WHERE l.srvid = _srvid 271 | AND s.setdatabase IS NULL 272 | AND s.setrole IS NULL 273 | AND s.name IS NULL 274 | ), 275 | mark_dropped AS ( 276 | INSERT INTO @extschema@.pg_track_db_role_settings_history 277 | (srvid, ts, setdatabase, setrole, name, setting, is_dropped) 278 | SELECT _srvid, ts, d.setdatabase, d.setrole, d.name, NULL, true 279 | FROM dropped AS d 280 | ) 281 | DELETE FROM @extschema@.pg_track_db_role_settings_list l 282 | USING dropped d 283 | WHERE 284 | l.srvid = _srvid 285 | AND d.setdatabase = l.setdatabase 286 | AND d.setrole = l.setrole 287 | AND d.name = l.name; 288 | 289 | -- Insert missing settings 290 | WITH rds AS ( 291 | SELECT * FROM @extschema@.pg_track_settings_rds_src(_srvid) 292 | ) 293 | INSERT INTO @extschema@.pg_track_db_role_settings_list 294 | (srvid, setdatabase, setrole, name) 295 | SELECT _srvid, setdatabase, setrole, name 296 | FROM rds s 297 | WHERE NOT EXISTS (SELECT 1 298 | FROM @extschema@.pg_track_db_role_settings_list l 299 | WHERE 300 | l.srvid = _srvid 301 | AND l.setdatabase = s.setdatabase 302 | AND l.setrole = l.setrole 303 | AND l.name = s.name 304 | ); 305 | 306 | -- Detect changed GUC, insert new vals 307 | WITH rds AS ( 308 | SELECT * FROM @extschema@.pg_track_settings_rds_src(_srvid) 309 | ), 310 | last_snapshot AS ( 311 | SELECT setdatabase, setrole, name, setting 312 | FROM ( 313 | SELECT setdatabase, setrole, name, setting, 314 | row_number() OVER (PARTITION BY name, setdatabase, setrole ORDER BY ts DESC) AS rn 315 | FROM @extschema@.pg_track_db_role_settings_history 316 | WHERE srvid = _srvid 317 | ) all_snapshots 318 | WHERE all_snapshots.rn = 1 319 | ) 320 | INSERT INTO @extschema@.pg_track_db_role_settings_history 321 | (srvid, ts, setdatabase, setrole, name, setting) 322 | SELECT _srvid, s.ts, s.setdatabase, s.setrole, s.name, s.setting 323 | FROM rds s 324 | LEFT JOIN last_snapshot l ON 325 | l.setdatabase = s.setdatabase 326 | AND l.setrole = s.setrole 327 | AND l.name = s.name 328 | WHERE (l.setdatabase IS NULL 329 | AND l.setrole IS NULL 330 | AND l.name IS NULL) 331 | OR (l.setting IS DISTINCT FROM s.setting); 332 | 333 | IF (_srvid != 0) THEN 334 | DELETE FROM @extschema@.pg_track_settings_rds_src_tmp 335 | WHERE srvid = _srvid; 336 | END IF; 337 | 338 | RETURN true; 339 | END; 340 | $_$ 341 | LANGUAGE plpgsql; /* end of pg_track_settings_snapshot_rds() */ 342 | 343 | CREATE OR REPLACE FUNCTION @extschema@.pg_track_settings_snapshot_reboot(_srvid integer) 344 | RETURNS boolean AS 345 | $_$ 346 | BEGIN 347 | -- Detect is postmaster restarted since last call 348 | WITH last_reboot AS ( 349 | SELECT t.postmaster_ts 350 | FROM @extschema@.pg_track_settings_reboot_src(_srvid) t 351 | ) 352 | INSERT INTO @extschema@.pg_reboot (srvid, ts) 353 | SELECT _srvid, lr.postmaster_ts FROM last_reboot lr 354 | WHERE NOT EXISTS (SELECT 1 355 | FROM @extschema@.pg_reboot r 356 | WHERE r.srvid = _srvid 357 | AND r.ts = lr.postmaster_ts 358 | AND r.srvid = _srvid 359 | ); 360 | 361 | IF (_srvid != 0) THEN 362 | DELETE FROM @extschema@.pg_track_settings_reboot_src_tmp 363 | WHERE srvid = _srvid; 364 | END IF; 365 | 366 | RETURN true; 367 | END; 368 | $_$ 369 | LANGUAGE plpgsql; /* end of pg_track_settings_snapshot_reboot() */ 370 | 371 | -- global function doing all the work for local instance, kept for backward 372 | -- compatibility 373 | CREATE OR REPLACE FUNCTION @extschema@.pg_track_settings_snapshot() 374 | RETURNS boolean AS 375 | $_$ 376 | BEGIN 377 | PERFORM @extschema@.pg_track_settings_snapshot_settings(0); 378 | PERFORM @extschema@.pg_track_settings_snapshot_rds(0); 379 | PERFORM @extschema@.pg_track_settings_snapshot_reboot(0); 380 | 381 | RETURN true; 382 | END; 383 | $_$ 384 | LANGUAGE plpgsql; 385 | /* end of pg_track_settings_snapshot() */ 386 | 387 | CREATE OR REPLACE FUNCTION @extschema@.pg_track_settings( 388 | _ts timestamp with time zone DEFAULT now(), 389 | _srvid integer DEFAULT 0) 390 | RETURNS TABLE (name text, setting text, setting_pretty text) AS 391 | $_$ 392 | BEGIN 393 | RETURN QUERY 394 | SELECT s.name, s.setting, s.setting_pretty 395 | FROM ( 396 | SELECT h.name, h.setting, h.setting_pretty, h.is_dropped, 397 | row_number() OVER (PARTITION BY h.name ORDER BY h.ts DESC) AS rn 398 | FROM @extschema@.pg_track_settings_history h 399 | WHERE h.srvid = _srvid 400 | AND h.ts <= _ts 401 | ) s 402 | WHERE s.rn = 1 403 | AND NOT s.is_dropped 404 | ORDER BY s.name; 405 | END; 406 | $_$ 407 | LANGUAGE plpgsql; 408 | 409 | CREATE OR REPLACE FUNCTION @extschema@.pg_track_db_role_settings( 410 | _ts timestamp with time zone DEFAULT now(), 411 | _srvid integer DEFAULT 0) 412 | RETURNS TABLE (setdatabase oid, setrole oid, name text, setting text) AS 413 | $_$ 414 | BEGIN 415 | RETURN QUERY 416 | SELECT s.setdatabase, s.setrole, s.name, s.setting 417 | FROM ( 418 | SELECT h.setdatabase, h.setrole, h.name, h.setting, h.is_dropped, 419 | row_number() OVER (PARTITION BY h.name, h.setdatabase, h.setrole ORDER BY h.ts DESC) AS rn 420 | FROM @extschema@.pg_track_db_role_settings_history h 421 | WHERE h.srvid = _srvid 422 | AND h.ts <= _ts 423 | ) s 424 | WHERE s.rn = 1 425 | AND NOT s.is_dropped 426 | ORDER BY s.setdatabase, s.setrole, s.name; 427 | END; 428 | $_$ 429 | LANGUAGE plpgsql; 430 | 431 | CREATE OR REPLACE FUNCTION @extschema@.pg_track_settings_diff( 432 | _from timestamp with time zone, 433 | _to timestamp with time zone, 434 | _srvid integer DEFAULT 0) 435 | RETURNS TABLE (name text, from_setting text, from_exists boolean, 436 | to_setting text, to_exists boolean, 437 | from_setting_pretty text, to_setting_pretty text) AS 438 | $_$ 439 | BEGIN 440 | RETURN QUERY 441 | SELECT COALESCE(s1.name, s2.name), 442 | s1.setting AS from_setting, 443 | CASE WHEN s1.setting IS NULL THEN false ELSE true END, 444 | s2.setting AS to_setting, 445 | CASE WHEN s2.setting IS NULL THEN false ELSE true END, 446 | s1.setting_pretty AS from_setting_pretty, 447 | s2.setting_pretty AS to_setting_pretty 448 | FROM @extschema@.pg_track_settings(_from, _srvid) s1 449 | FULL OUTER JOIN @extschema@.pg_track_settings(_to, _srvid) s2 ON s2.name = s1.name 450 | WHERE s1.setting IS DISTINCT FROM s2.setting 451 | ORDER BY 1; 452 | END; 453 | $_$ 454 | LANGUAGE plpgsql; 455 | 456 | CREATE OR REPLACE FUNCTION @extschema@.pg_track_db_role_settings_diff( 457 | _from timestamp with time zone, 458 | _to timestamp with time zone, 459 | _srvid integer DEFAULT 0) 460 | RETURNS TABLE (setdatabase oid, setrole oid, name text, 461 | from_setting text, from_exists boolean, to_setting text, to_exists boolean) 462 | AS 463 | $_$ 464 | BEGIN 465 | RETURN QUERY 466 | SELECT COALESCE(s1.setdatabase, s2.setdatabase), 467 | COALESCE(s1.setrole, s2.setrole), 468 | COALESCE(s1.name, s2.name), 469 | s1.setting AS from_setting, 470 | CASE WHEN s1.setting IS NULL THEN false ELSE true END, 471 | s2.setting AS to_setting, 472 | CASE WHEN s2.setting IS NULL THEN false ELSE true END 473 | FROM @extschema@.pg_track_db_role_settings(_from, _srvid) s1 474 | FULL OUTER JOIN @extschema@.pg_track_db_role_settings(_to, _srvid) s2 ON 475 | s2.setdatabase = s1.setdatabase 476 | AND s2.setrole = s1.setrole 477 | AND s2.name = s1.name 478 | WHERE 479 | s1.setdatabase IS DISTINCT FROM s2.setdatabase 480 | AND s1.setrole IS DISTINCT FROM s2.setrole 481 | AND s1.setting IS DISTINCT FROM s2.setting 482 | ORDER BY 1, 2, 3; 483 | END; 484 | $_$ 485 | LANGUAGE plpgsql; 486 | 487 | CREATE OR REPLACE FUNCTION @extschema@.pg_track_settings_log( 488 | _name text, 489 | _srvid integer DEFAULT 0) 490 | RETURNS TABLE (ts timestamp with time zone, name text, setting_exists boolean, 491 | setting text, setting_pretty text) AS 492 | $_$ 493 | BEGIN 494 | RETURN QUERY 495 | SELECT h.ts, h.name, NOT h.is_dropped, h.setting, h.setting_pretty 496 | FROM @extschema@.pg_track_settings_history h 497 | WHERE h.srvid = _srvid 498 | AND h.name = _name 499 | ORDER BY ts DESC; 500 | END; 501 | $_$ 502 | LANGUAGE plpgsql; 503 | 504 | CREATE OR REPLACE FUNCTION @extschema@.pg_track_db_role_settings_log( 505 | _name text, 506 | _srvid integer DEFAULT 0) 507 | RETURNS TABLE (ts timestamp with time zone, setdatabase oid, setrole oid, 508 | name text, setting_exists boolean, setting text) AS 509 | $_$ 510 | BEGIN 511 | RETURN QUERY 512 | SELECT h.ts, h.setdatabase, h.setrole, h.name, NOT h.is_dropped, h.setting 513 | FROM @extschema@.pg_track_db_role_settings_history h 514 | WHERE h.srvid = _srvid 515 | AND h.name = _name 516 | ORDER BY ts, setdatabase, setrole DESC; 517 | END; 518 | $_$ 519 | LANGUAGE plpgsql; 520 | 521 | CREATE OR REPLACE FUNCTION @extschema@.pg_track_reboot_log(_srvid integer DEFAULT 0) 522 | RETURNS TABLE (ts timestamp with time zone) AS 523 | $_$ 524 | BEGIN 525 | RETURN QUERY 526 | SELECT r.ts 527 | FROM @extschema@.pg_reboot r 528 | WHERE r.srvid = _srvid 529 | ORDER BY r.ts; 530 | END; 531 | $_$ 532 | LANGUAGE plpgsql; 533 | 534 | CREATE OR REPLACE FUNCTION @extschema@.pg_track_settings_reset(_srvid integer DEFAULT 0) 535 | RETURNS void AS 536 | $_$ 537 | BEGIN 538 | DELETE FROM @extschema@.pg_track_settings_settings_src_tmp WHERE srvid = _srvid; 539 | DELETE FROM @extschema@.pg_track_settings_rds_src_tmp WHERE srvid = _srvid; 540 | DELETE FROM @extschema@.pg_track_settings_reboot_src_tmp WHERE srvid = _srvid; 541 | DELETE FROM @extschema@.pg_track_settings_list WHERE srvid = _srvid; 542 | DELETE FROM @extschema@.pg_track_settings_history WHERE srvid = _srvid; 543 | DELETE FROM @extschema@.pg_track_db_role_settings_list WHERE srvid = _srvid; 544 | DELETE FROM @extschema@.pg_track_db_role_settings_history WHERE srvid = _srvid; 545 | DELETE FROM @extschema@.pg_reboot WHERE srvid = _srvid; 546 | END; 547 | $_$ 548 | LANGUAGE plpgsql; 549 | -------------------------------------------------------------------------------- /pg_track_settings.control: -------------------------------------------------------------------------------- 1 | comment = 'Track settings changes' 2 | default_version = '2.1.2' 3 | module_pathname = '$libdir/pg_track_settings' 4 | superuser = false 5 | relocatable = false 6 | -------------------------------------------------------------------------------- /test/sql/pg_track_settings.sql: -------------------------------------------------------------------------------- 1 | SET search_path = ''; 2 | SET timezone TO 'Europe/Paris'; 3 | 4 | -- Remove any known per db setting set by pg_regress 5 | DO $$ 6 | DECLARE 7 | dbname text = current_database(); 8 | s text; 9 | BEGIN 10 | FOREACH s IN ARRAY ARRAY['lc_messages', 'lc_monetary', 'lc_numeric', 'lc_time', 11 | 'bytea_output', 'timezone_abbreviations'] 12 | LOOP 13 | EXECUTE format('ALTER DATABASE %I RESET %s', dbname, s); 14 | END LOOP; 15 | END; 16 | $$ LANGUAGE plpgsql; 17 | 18 | -- There shouldn't be any db/role setting left. It's unfortunately not 19 | -- guaranteed to be the case if the regression tests are run on a non-default 20 | -- cluster. 21 | SELECT d.datname, s.setconfig 22 | FROM pg_db_role_setting s 23 | JOIN pg_database d on s.setdatabase = d.oid; 24 | 25 | CREATE SCHEMA "PGTS"; 26 | -- Extension should be installable in a custom schema 27 | CREATE EXTENSION pg_track_settings WITH SCHEMA "PGTS"; 28 | -- But not relocatable 29 | ALTER EXTENSION pg_track_settings SET SCHEMA public; 30 | 31 | -- Check the relations that aren't dumped 32 | WITH ext AS ( 33 | SELECT c.oid, c.relname 34 | FROM pg_depend d 35 | JOIN pg_extension e ON d.refclassid = 'pg_extension'::regclass 36 | AND e.oid = d.refobjid 37 | AND e.extname = 'pg_track_settings' 38 | JOIN pg_class c ON d.classid = 'pg_class'::regclass 39 | AND c.oid = d.objid 40 | ), 41 | dmp AS ( 42 | SELECT unnest(extconfig) AS oid 43 | FROM pg_extension 44 | WHERE extname = 'pg_track_settings' 45 | ) 46 | SELECT ext.relname 47 | FROM ext 48 | LEFT JOIN dmp USING (oid) 49 | WHERE dmp.oid IS NULL 50 | ORDER BY ext.relname::text COLLATE "C"; 51 | 52 | -- Check that all objects are stored in the expected schema 53 | WITH ext AS ( 54 | SELECT pg_describe_object(d.classid, d.objid, d.objsubid) AS descr 55 | FROM pg_depend d 56 | JOIN pg_extension e ON d.refclassid = 'pg_extension'::regclass 57 | AND e.oid = d.refobjid 58 | AND e.extname = 'pg_track_settings' 59 | ) 60 | SELECT descr FROM ext 61 | WHERE descr NOT like '%"PGTS".%' 62 | ORDER BY descr COLLATE "C"; 63 | 64 | -- test main config history 65 | SELECT COUNT(*) FROM "PGTS".pg_track_settings_history; 66 | SET work_mem = '10MB'; 67 | SELECT * FROM "PGTS".pg_track_settings_snapshot(); 68 | SELECT pg_catalog.pg_sleep(1); 69 | SET work_mem = '5MB'; 70 | SELECT * FROM "PGTS".pg_track_settings_snapshot(); 71 | SELECT name, setting_exists, setting, setting_pretty FROM "PGTS".pg_track_settings_log('work_mem') ORDER BY ts ASC; 72 | SELECT name, from_setting, from_exists, to_setting, to_exists, from_setting_pretty, to_setting_pretty FROM "PGTS".pg_track_settings_diff(now() - interval '500 ms', now()); 73 | -- test pg_db_role_settings 74 | ALTER DATABASE postgres SET work_mem = '1MB'; 75 | SELECT * FROM "PGTS".pg_track_settings_snapshot(); 76 | ALTER ROLE postgres SET work_mem = '2MB'; 77 | SELECT * FROM "PGTS".pg_track_settings_snapshot(); 78 | ALTER ROLE postgres IN DATABASE postgres SET work_mem = '3MB'; 79 | SELECT * FROM "PGTS".pg_track_settings_snapshot(); 80 | SELECT * FROM "PGTS".pg_track_settings_snapshot(); 81 | SELECT COALESCE(datname, '-') AS datname, setrole::regrole, name, setting_exists, setting FROM "PGTS".pg_track_db_role_settings_log('work_mem') s LEFT JOIN pg_database d ON d.oid = s.setdatabase ORDER BY ts ASC; 82 | SELECT COALESCE(datname, '-') AS datname, setrole::regrole, name, from_setting, from_exists, to_setting, to_exists FROM "PGTS".pg_track_db_role_settings_diff(now() - interval '10 min', now()) s LEFT JOIN pg_database d ON d.oid = s.setdatabase WHERE name = 'work_mem' ORDER BY 1, 2, 3; 83 | ALTER DATABASE postgres RESET work_mem; 84 | SELECT * FROM "PGTS".pg_track_settings_snapshot(); 85 | ALTER ROLE postgres RESET work_mem; 86 | SELECT * FROM "PGTS".pg_track_settings_snapshot(); 87 | ALTER ROLE postgres IN DATABASE postgres RESET work_mem; 88 | SELECT * FROM "PGTS".pg_track_settings_snapshot(); 89 | -- test pg_reboot 90 | SELECT COUNT(*) FROM "PGTS".pg_reboot; 91 | SELECT now() - ts > interval '2 second' FROM "PGTS".pg_reboot; 92 | SELECT now() - ts > interval '2 second' FROM "PGTS".pg_track_reboot_log(); 93 | -- test the reset 94 | SELECT * FROM "PGTS".pg_track_settings_reset(); 95 | SELECT COUNT(*) FROM "PGTS".pg_track_settings_history; 96 | SELECT COUNT(*) FROM "PGTS".pg_track_settings_log('work_mem'); 97 | SELECT COUNT(*) FROM "PGTS".pg_track_settings_diff(now() - interval '1 hour', now()); 98 | SELECT COUNT(*) FROM "PGTS".pg_track_db_role_settings_log('work_mem'); 99 | SELECT COUNT(*) FROM "PGTS".pg_track_db_role_settings_diff(now() - interval '1 hour', now()); 100 | SELECT COUNT(*) FROM "PGTS".pg_reboot; 101 | -------------------------- 102 | -- test remote snapshot -- 103 | -------------------------- 104 | -- fake general settings 105 | INSERT INTO "PGTS".pg_track_settings_settings_src_tmp 106 | (srvid, ts, name, setting, current_setting) 107 | VALUES 108 | (1, '2019-01-01 00:00:00 CET', 'work_mem', '0', '1MB'), 109 | (2, '2019-01-02 00:00:00 CET', 'work_mem', '0', '2MB'); 110 | -- fake rds settings 111 | INSERT INTO "PGTS".pg_track_settings_rds_src_tmp 112 | (srvid, ts, name, setting, setdatabase, setrole) 113 | VALUES 114 | (1, '2019-01-01 00:00:00 CET', 'work_mem', '1MB', 123, 0), 115 | (2, '2019-01-02 00:00:00 CET', 'work_mem', '2MB', 456, 0); 116 | -- fake reboot settings 117 | INSERT INTO "PGTS".pg_track_settings_reboot_src_tmp 118 | (srvid, ts, postmaster_ts) 119 | VALUES 120 | (1, '2019-01-01 00:01:00 CET', '2019-01-01 00:00:00 CET'), 121 | (2, '2019-01-02 00:01:00 CET', '2019-01-02 00:00:00 CET'); 122 | 123 | SELECT "PGTS".pg_track_settings_snapshot_settings(1); 124 | SELECT "PGTS".pg_track_settings_snapshot_rds(1); 125 | SELECT "PGTS".pg_track_settings_snapshot_reboot(1); 126 | 127 | -- snapshot of remote server 1 shouldn't impact data for server 2 128 | SELECT srvid, count(*) FROM "PGTS".pg_track_settings_settings_src_tmp GROUP BY srvid; 129 | SELECT srvid, count(*) FROM "PGTS".pg_track_settings_rds_src_tmp GROUP BY srvid; 130 | SELECT srvid, count(*) FROM "PGTS".pg_track_settings_reboot_src_tmp GROUP BY srvid; 131 | 132 | -- fake general settings 133 | INSERT INTO "PGTS".pg_track_settings_settings_src_tmp 134 | (srvid, ts, name, setting, current_setting) 135 | VALUES 136 | -- previously untreated data that should be discarded 137 | (1, '2019-01-02 00:00:00 CET', 'work_mem', '5120', '5MB'), 138 | -- data that should be processed 139 | (1, '2019-01-02 01:00:00 CET', 'work_mem', '10240', '10MB'), 140 | (1, '2019-01-02 01:00:00 CET', 'something', 'someval', 'someval'); 141 | -- fake rds settings 142 | INSERT INTO "PGTS".pg_track_settings_rds_src_tmp 143 | (srvid, ts, name, setting, setdatabase, setrole) 144 | VALUES 145 | -- previously untreated data that should be discarded 146 | (1, '2019-01-02 00:00:00 CET', 'work_mem', '5MB', 123, 0), 147 | -- data that should be processed 148 | (1, '2019-01-02 01:00:00 CET', 'work_mem', '10MB', 123, 0), 149 | (1, '2019-01-02 01:00:00 CET', 'something', 'someval', 0, 456); 150 | -- fake reboot settings 151 | INSERT INTO "PGTS".pg_track_settings_reboot_src_tmp 152 | (srvid, ts, postmaster_ts) 153 | VALUES 154 | -- previously untreated data that should not be discarded 155 | (1, '2019-01-02 00:01:00 CET', '2019-01-02 00:00:00 CET'), 156 | -- data that should also be processed 157 | (1, '2019-01-02 02:01:00 CET', '2019-01-02 01:00:00 CET'); 158 | SELECT "PGTS".pg_track_settings_snapshot_settings(1); 159 | SELECT "PGTS".pg_track_settings_snapshot_rds(1); 160 | SELECT "PGTS".pg_track_settings_snapshot_reboot(1); 161 | -- test raw data 162 | SELECT * FROM "PGTS".pg_track_settings_list ORDER BY 1, 2; 163 | SELECT * FROM "PGTS".pg_track_settings_history ORDER BY 1, 2, 3; 164 | SELECT * FROM "PGTS".pg_track_db_role_settings_list ORDER BY 1, 2; 165 | SELECT * FROM "PGTS".pg_track_db_role_settings_history ORDER BY 1, 2, 3; 166 | SELECT * FROM "PGTS".pg_reboot ORDER BY 1, 2; 167 | 168 | -- test functions 169 | SELECT name, setting_exists, setting, setting_pretty 170 | FROM "PGTS".pg_track_settings_log('work_mem', 1) 171 | ORDER BY ts ASC; 172 | SELECT name, from_setting, from_exists, to_setting, to_exists, 173 | from_setting_pretty, to_setting_pretty 174 | FROM "PGTS".pg_track_settings_diff('2019-01-01 01:00:00 CET', 175 | '2019-01-02 02:00:00 CET', 1); 176 | SELECT * 177 | FROM "PGTS".pg_track_db_role_settings_log('work_mem', 1) s 178 | ORDER BY ts ASC; 179 | SELECT * 180 | FROM "PGTS".pg_track_db_role_settings_diff('2018-12-31 02:00:00 CET', 181 | '2019-01-02 03:00:00 CET', 1) s 182 | WHERE name = 'work_mem' ORDER BY 1, 2, 3; 183 | SELECT * FROM "PGTS".pg_track_reboot_log(1); 184 | 185 | -- snapshot the pending server 2 186 | SELECT "PGTS".pg_track_settings_snapshot_settings(2); 187 | SELECT "PGTS".pg_track_settings_snapshot_rds(2); 188 | SELECT "PGTS".pg_track_settings_snapshot_reboot(2); 189 | 190 | -- check that all data have been deleted after processing 191 | SELECT COUNT(*) FROM "PGTS".pg_track_settings_settings_src_tmp; 192 | SELECT COUNT(*) FROM "PGTS".pg_track_settings_rds_src_tmp; 193 | SELECT COUNT(*) FROM "PGTS".pg_track_settings_reboot_src_tmp; 194 | -- test the reset 195 | SELECT * FROM "PGTS".pg_track_settings_reset(1); 196 | SELECT srvid, COUNT(*) FROM "PGTS".pg_track_settings_history GROUP BY srvid; 197 | SELECT COUNT(*) FROM "PGTS".pg_track_settings_log('work_mem', 1); 198 | SELECT COUNT(*) FROM "PGTS".pg_track_settings_diff('-infinity', 'infinity', 1); 199 | SELECT COUNT(*) FROM "PGTS".pg_track_db_role_settings_log('work_mem', 1); 200 | SELECT COUNT(*) FROM "PGTS".pg_track_db_role_settings_diff('-infinity', 'infinity', 1); 201 | SELECT srvid, COUNT(*) FROM "PGTS".pg_track_db_role_settings_history GROUP BY srvid; 202 | SELECT srvid, COUNT(*) FROM "PGTS".pg_reboot GROUP BY srvid; 203 | --------------------------------------------------------------------------------