├── .github └── workflows │ ├── pre-commit.yaml │ └── test.yaml ├── .gitignore ├── .pre-commit-config.yaml ├── LICENSE ├── Makefile ├── README.md ├── nix └── supa_audit │ ├── default.nix │ └── pgScript.nix ├── shell.nix ├── supa_audit--0.1.0--0.2.0.sql ├── supa_audit--0.2.0--0.2.1.sql ├── supa_audit--0.2.1--0.2.2.sql ├── supa_audit--0.2.2--0.2.3.sql ├── supa_audit--0.2.3--0.3.0.sql ├── supa_audit--0.3.0--0.3.1.sql ├── supa_audit--0.3.1.sql ├── supa_audit.control └── test ├── expected ├── detect_supabase.out ├── disable_idempotent.out ├── enable_and_disable_tracking.out ├── enable_idempotent.out ├── require_primary_key.out ├── simple_insert_update_delete_truncate.out └── track_table_schema_not_on_search_path.out ├── fixtures.sql └── sql ├── detect_supabase.sql ├── disable_idempotent.sql ├── enable_and_disable_tracking.sql ├── enable_idempotent.sql ├── require_primary_key.sql ├── simple_insert_update_delete_truncate.sql └── track_table_schema_not_on_search_path.sql /.github/workflows/pre-commit.yaml: -------------------------------------------------------------------------------- 1 | name: pre-commit 2 | 3 | on: [push] 4 | 5 | jobs: 6 | build: 7 | runs-on: ubuntu-latest 8 | 9 | steps: 10 | - name: checkout 11 | uses: actions/checkout@v2 12 | 13 | - name: set up python 3.8 14 | uses: actions/setup-python@v1 15 | with: 16 | python-version: 3.8 17 | 18 | - name: install pre-commit 19 | run: | 20 | python -m pip install --upgrade pip 21 | pip install pre-commit 22 | 23 | 24 | - name: run pre-commit hooks 25 | run: | 26 | pre-commit run --all-files 27 | -------------------------------------------------------------------------------- /.github/workflows/test.yaml: -------------------------------------------------------------------------------- 1 | name: test 2 | 3 | on: [push] 4 | 5 | jobs: 6 | test: 7 | 8 | runs-on: ubuntu-latest 9 | strategy: 10 | matrix: 11 | postgres-version: ['16', '15', '14', '13', '12'] 12 | 13 | steps: 14 | - uses: actions/checkout@v1 15 | - uses: cachix/install-nix-action@v13 16 | with: 17 | nix_path: nixpkgs=channel:nixos-unstable 18 | - name: Run tests pg_${{ matrix.postgres-version }} 19 | run: nix-shell --run "pg_${{ matrix.postgres-version }}_supa_audit make installcheck" 20 | -------------------------------------------------------------------------------- /.gitignore: -------------------------------------------------------------------------------- 1 | results/ 2 | __pycache__/ 3 | .python-version 4 | venv/ 5 | site/ 6 | regression.* 7 | .DS_Store 8 | *.egg-info/ 9 | *.json 10 | *.ipynb 11 | *.swp 12 | *.diff 13 | node_modules/ 14 | -------------------------------------------------------------------------------- /.pre-commit-config.yaml: -------------------------------------------------------------------------------- 1 | repos: 2 | 3 | - repo: https://github.com/Lucas-C/pre-commit-hooks 4 | rev: v1.1.10 5 | hooks: 6 | - id: remove-tabs 7 | name: Tabs-to-Spaces 8 | exclude: ^test/expected 9 | 10 | - repo: https://github.com/pre-commit/pre-commit-hooks 11 | rev: v4.0.1 12 | hooks: 13 | - id: trailing-whitespace 14 | exclude: ^test/expected 15 | - id: end-of-file-fixer 16 | exclude: ^test/expected 17 | - id: check-yaml 18 | - id: check-merge-conflict 19 | - id: check-added-large-files 20 | args: ['--maxkb=500'] 21 | - id: mixed-line-ending 22 | args: ['--fix=lf'] 23 | -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | Apache License 2 | Version 2.0, January 2004 3 | http://www.apache.org/licenses/ 4 | 5 | TERMS AND CONDITIONS FOR USE, REPRODUCTION, AND DISTRIBUTION 6 | 7 | 1. Definitions. 8 | 9 | "License" shall mean the terms and conditions for use, reproduction, 10 | and distribution as defined by Sections 1 through 9 of this document. 11 | 12 | "Licensor" shall mean the copyright owner or entity authorized by 13 | the copyright owner that is granting the License. 14 | 15 | "Legal Entity" shall mean the union of the acting entity and all 16 | other entities that control, are controlled by, or are under common 17 | control with that entity. For the purposes of this definition, 18 | "control" means (i) the power, direct or indirect, to cause the 19 | direction or management of such entity, whether by contract or 20 | otherwise, or (ii) ownership of fifty percent (50%) or more of the 21 | outstanding shares, or (iii) beneficial ownership of such entity. 22 | 23 | "You" (or "Your") shall mean an individual or Legal Entity 24 | exercising permissions granted by this License. 25 | 26 | "Source" form shall mean the preferred form for making modifications, 27 | including but not limited to software source code, documentation 28 | source, and configuration files. 29 | 30 | "Object" form shall mean any form resulting from mechanical 31 | transformation or translation of a Source form, including but 32 | not limited to compiled object code, generated documentation, 33 | and conversions to other media types. 34 | 35 | "Work" shall mean the work of authorship, whether in Source or 36 | Object form, made available under the License, as indicated by a 37 | copyright notice that is included in or attached to the work 38 | (an example is provided in the Appendix below). 39 | 40 | "Derivative Works" shall mean any work, whether in Source or Object 41 | form, that is based on (or derived from) the Work and for which the 42 | editorial revisions, annotations, elaborations, or other modifications 43 | represent, as a whole, an original work of authorship. For the purposes 44 | of this License, Derivative Works shall not include works that remain 45 | separable from, or merely link (or bind by name) to the interfaces of, 46 | the Work and Derivative Works thereof. 47 | 48 | "Contribution" shall mean any work of authorship, including 49 | the original version of the Work and any modifications or additions 50 | to that Work or Derivative Works thereof, that is intentionally 51 | submitted to Licensor for inclusion in the Work by the copyright owner 52 | or by an individual or Legal Entity authorized to submit on behalf of 53 | the copyright owner. For the purposes of this definition, "submitted" 54 | means any form of electronic, verbal, or written communication sent 55 | to the Licensor or its representatives, including but not limited to 56 | communication on electronic mailing lists, source code control systems, 57 | and issue tracking systems that are managed by, or on behalf of, the 58 | Licensor for the purpose of discussing and improving the Work, but 59 | excluding communication that is conspicuously marked or otherwise 60 | designated in writing by the copyright owner as "Not a Contribution." 61 | 62 | "Contributor" shall mean Licensor and any individual or Legal Entity 63 | on behalf of whom a Contribution has been received by Licensor and 64 | subsequently incorporated within the Work. 65 | 66 | 2. Grant of Copyright License. Subject to the terms and conditions of 67 | this License, each Contributor hereby grants to You a perpetual, 68 | worldwide, non-exclusive, no-charge, royalty-free, irrevocable 69 | copyright license to reproduce, prepare Derivative Works of, 70 | publicly display, publicly perform, sublicense, and distribute the 71 | Work and such Derivative Works in Source or Object form. 72 | 73 | 3. Grant of Patent License. Subject to the terms and conditions of 74 | this License, each Contributor hereby grants to You a perpetual, 75 | worldwide, non-exclusive, no-charge, royalty-free, irrevocable 76 | (except as stated in this section) patent license to make, have made, 77 | use, offer to sell, sell, import, and otherwise transfer the Work, 78 | where such license applies only to those patent claims licensable 79 | by such Contributor that are necessarily infringed by their 80 | Contribution(s) alone or by combination of their Contribution(s) 81 | with the Work to which such Contribution(s) was submitted. If You 82 | institute patent litigation against any entity (including a 83 | cross-claim or counterclaim in a lawsuit) alleging that the Work 84 | or a Contribution incorporated within the Work constitutes direct 85 | or contributory patent infringement, then any patent licenses 86 | granted to You under this License for that Work shall terminate 87 | as of the date such litigation is filed. 88 | 89 | 4. Redistribution. You may reproduce and distribute copies of the 90 | Work or Derivative Works thereof in any medium, with or without 91 | modifications, and in Source or Object form, provided that You 92 | meet the following conditions: 93 | 94 | (a) You must give any other recipients of the Work or 95 | Derivative Works a copy of this License; and 96 | 97 | (b) You must cause any modified files to carry prominent notices 98 | stating that You changed the files; and 99 | 100 | (c) You must retain, in the Source form of any Derivative Works 101 | that You distribute, all copyright, patent, trademark, and 102 | attribution notices from the Source form of the Work, 103 | excluding those notices that do not pertain to any part of 104 | the Derivative Works; and 105 | 106 | (d) If the Work includes a "NOTICE" text file as part of its 107 | distribution, then any Derivative Works that You distribute must 108 | include a readable copy of the attribution notices contained 109 | within such NOTICE file, excluding those notices that do not 110 | pertain to any part of the Derivative Works, in at least one 111 | of the following places: within a NOTICE text file distributed 112 | as part of the Derivative Works; within the Source form or 113 | documentation, if provided along with the Derivative Works; or, 114 | within a display generated by the Derivative Works, if and 115 | wherever such third-party notices normally appear. The contents 116 | of the NOTICE file are for informational purposes only and 117 | do not modify the License. You may add Your own attribution 118 | notices within Derivative Works that You distribute, alongside 119 | or as an addendum to the NOTICE text from the Work, provided 120 | that such additional attribution notices cannot be construed 121 | as modifying the License. 122 | 123 | You may add Your own copyright statement to Your modifications and 124 | may provide additional or different license terms and conditions 125 | for use, reproduction, or distribution of Your modifications, or 126 | for any such Derivative Works as a whole, provided Your use, 127 | reproduction, and distribution of the Work otherwise complies with 128 | the conditions stated in this License. 129 | 130 | 5. Submission of Contributions. Unless You explicitly state otherwise, 131 | any Contribution intentionally submitted for inclusion in the Work 132 | by You to the Licensor shall be under the terms and conditions of 133 | this License, without any additional terms or conditions. 134 | Notwithstanding the above, nothing herein shall supersede or modify 135 | the terms of any separate license agreement you may have executed 136 | with Licensor regarding such Contributions. 137 | 138 | 6. Trademarks. This License does not grant permission to use the trade 139 | names, trademarks, service marks, or product names of the Licensor, 140 | except as required for reasonable and customary use in describing the 141 | origin of the Work and reproducing the content of the NOTICE file. 142 | 143 | 7. Disclaimer of Warranty. Unless required by applicable law or 144 | agreed to in writing, Licensor provides the Work (and each 145 | Contributor provides its Contributions) on an "AS IS" BASIS, 146 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or 147 | implied, including, without limitation, any warranties or conditions 148 | of TITLE, NON-INFRINGEMENT, MERCHANTABILITY, or FITNESS FOR A 149 | PARTICULAR PURPOSE. You are solely responsible for determining the 150 | appropriateness of using or redistributing the Work and assume any 151 | risks associated with Your exercise of permissions under this License. 152 | 153 | 8. Limitation of Liability. In no event and under no legal theory, 154 | whether in tort (including negligence), contract, or otherwise, 155 | unless required by applicable law (such as deliberate and grossly 156 | negligent acts) or agreed to in writing, shall any Contributor be 157 | liable to You for damages, including any direct, indirect, special, 158 | incidental, or consequential damages of any character arising as a 159 | result of this License or out of the use or inability to use the 160 | Work (including but not limited to damages for loss of goodwill, 161 | work stoppage, computer failure or malfunction, or any and all 162 | other commercial damages or losses), even if such Contributor 163 | has been advised of the possibility of such damages. 164 | 165 | 9. Accepting Warranty or Additional Liability. While redistributing 166 | the Work or Derivative Works thereof, You may choose to offer, 167 | and charge a fee for, acceptance of support, warranty, indemnity, 168 | or other liability obligations and/or rights consistent with this 169 | License. However, in accepting such obligations, You may act only 170 | on Your own behalf and on Your sole responsibility, not on behalf 171 | of any other Contributor, and only if You agree to indemnify, 172 | defend, and hold each Contributor harmless for any liability 173 | incurred by, or claims asserted against, such Contributor by reason 174 | of your accepting any such warranty or additional liability. 175 | 176 | END OF TERMS AND CONDITIONS 177 | 178 | Copyright 2021 Supabase 179 | 180 | Licensed under the Apache License, Version 2.0 (the "License"); 181 | you may not use this file except in compliance with the License. 182 | You may obtain a copy of the License at 183 | 184 | http://www.apache.org/licenses/LICENSE-2.0 185 | 186 | Unless required by applicable law or agreed to in writing, software 187 | distributed under the License is distributed on an "AS IS" BASIS, 188 | WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. 189 | See the License for the specific language governing permissions and 190 | limitations under the License. 191 | -------------------------------------------------------------------------------- /Makefile: -------------------------------------------------------------------------------- 1 | EXTENSION = supa_audit 2 | DATA = $(wildcard *--*.sql) 3 | 4 | TESTS = $(wildcard test/sql/*.sql) 5 | REGRESS = $(patsubst test/sql/%.sql,%,$(TESTS)) 6 | REGRESS_OPTS = --use-existing --inputdir=test 7 | 8 | PG_CONFIG = pg_config 9 | PGXS := $(shell $(PG_CONFIG) --pgxs) 10 | include $(PGXS) 11 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # `supa_audit` 2 | 3 |
8 | 9 | --- 10 | 11 | **Source Code**: https://github.com/supabase/supa_audit 12 | 13 | --- 14 | 15 | The `supa_audit` PostgreSQL extension is a generic solution for tracking changes to tables' data over time. 16 | 17 | The audit table, `audit.record_version`, leverages each records primary key values to produce a stable `record_id::uuid`, enabling efficient (linear time) history queries. 18 | 19 | 20 | ## Usage 21 | 22 | ```sql 23 | create extension supa_audit cascade; 24 | 25 | create table public.account( 26 | id int primary key, 27 | name text not null 28 | ); 29 | 30 | -- Enable auditing 31 | select audit.enable_tracking('public.account'::regclass); 32 | 33 | -- Insert a record 34 | insert into public.account(id, name) 35 | values (1, 'Foo Barsworth'); 36 | 37 | -- Update a record 38 | update public.account 39 | set name = 'Foo Barsworht III' 40 | where id = 1; 41 | 42 | -- Delete a record 43 | delete from public.account 44 | where id = 1; 45 | 46 | -- Truncate the table 47 | truncate table public.account; 48 | 49 | -- Review the history 50 | select 51 | * 52 | from 53 | audit.record_version; 54 | 55 | /* 56 | id | record_id | old_record_id | op | ts | table_oid | table_schema | table_name | record | old_record 57 | ----+--------------------------------------+--------------------------------------+----------+---------------------------------+-----------+--------------+------------+----------------------------------------+------------------------------------ 58 | 1 | 57ca384e-f24c-5af5-b361-a057aeac506c | | INSERT | Thu Feb 10 17:02:25.621095 2022 | 16439 | public | account | {"id": 1, "name": "Foo Barsworth"} | 59 | 2 | 57ca384e-f24c-5af5-b361-a057aeac506c | 57ca384e-f24c-5af5-b361-a057aeac506c | UPDATE | Thu Feb 10 17:02:25.622151 2022 | 16439 | public | account | {"id": 1, "name": "Foo Barsworht III"} | {"id": 1, "name": "Foo Barsworth"} 60 | 3 | | 57ca384e-f24c-5af5-b361-a057aeac506c | DELETE | Thu Feb 10 17:02:25.622495 2022 | 16439 | public | account | | {"id": 1, "name": "Foo Barsworth III"} 61 | 4 | | | TRUNCATE | Thu Feb 10 17:02:25.622779 2022 | 16439 | public | account | | 62 | (4 rows) 63 | */ 64 | 65 | -- Disable auditing 66 | select audit.disable_tracking('public.account'::regclass); 67 | ``` 68 | 69 | ## Test 70 | 71 | ### Run the Tests 72 | 73 | ```sh 74 | nix-shell --run "pg_13_supa_audit make installcheck" 75 | ``` 76 | 77 | ### Adding Tests 78 | 79 | Tests are located in `test/sql/` and the expected output is in `test/expected/` 80 | 81 | The output of the most recent test run is stored in `results/`. 82 | 83 | When the output for a test in `results/` is correct, copy it to `test/expected/` and the test will pass. 84 | 85 | ## Interactive Prompt 86 | 87 | ```sh 88 | nix-shell --run "pg_13_supa_audit psql" 89 | ``` 90 | 91 | ## Performance 92 | 93 | 94 | ### Write Throughput 95 | Auditing tables reduces throughput of inserts, updates, and deletes. 96 | 97 | It is not recommended to enable tracking on tables with a peak write throughput over 3k ops/second. 98 | 99 | 100 | ### Querying 101 | 102 | When querying a table's history, filter on the indexed `table_oid` rather than the `table_name` and `schema_name` columns. 103 | 104 | ```sql 105 | select 106 | * 107 | from 108 | audit.record_version 109 | where 110 | table_oid = 'public.account'::regclass::oid; 111 | ``` 112 | -------------------------------------------------------------------------------- /nix/supa_audit/default.nix: -------------------------------------------------------------------------------- 1 | { stdenv, postgresql }: 2 | 3 | stdenv.mkDerivation { 4 | name = "supa_audit"; 5 | 6 | buildInputs = [ postgresql ]; 7 | 8 | src = ../../.; 9 | 10 | installPhase = '' 11 | install -D -t $out/share/postgresql/extension *.sql 12 | install -D -t $out/share/postgresql/extension *.control 13 | ''; 14 | } 15 | -------------------------------------------------------------------------------- /nix/supa_audit/pgScript.nix: -------------------------------------------------------------------------------- 1 | { postgresql, writeShellScriptBin } : 2 | 3 | let 4 | LOGMIN = builtins.getEnv "LOGMIN"; 5 | logMin = if builtins.stringLength LOGMIN == 0 then "WARNING" else LOGMIN; # warning is the default in pg 6 | ver = builtins.head (builtins.splitVersion postgresql.version); 7 | script = '' 8 | tmpdir="$(mktemp -d)" 9 | 10 | export PATH=${postgresql}/bin:"$PATH" 11 | export PGDATA="$tmpdir" 12 | export PGHOST="$tmpdir" 13 | export PGUSER=postgres 14 | export PGDATABASE=postgres 15 | 16 | trap 'pg_ctl stop -m i && rm -rf "$tmpdir"' sigint sigterm exit 17 | 18 | PGTZ=UTC initdb --no-locale --encoding=UTF8 --nosync -U "$PGUSER" 19 | 20 | options="-F -c listen_addresses=\"\" -c log_min_messages=${logMin} -k $PGDATA" 21 | 22 | pg_ctl start -o "$options" -o "$ext_options" 23 | 24 | createdb contrib_regression 25 | 26 | psql -v ON_ERROR_STOP=1 -f test/fixtures.sql -d contrib_regression 27 | "$@" 28 | ''; 29 | in 30 | writeShellScriptBin "pg_${ver}_supa_audit" script 31 | -------------------------------------------------------------------------------- /shell.nix: -------------------------------------------------------------------------------- 1 | let 2 | nixpkgs = builtins.fetchTarball { 3 | name = "2023-11"; 4 | url = "https://github.com/NixOS/nixpkgs/archive/057f9aecfb71c4437d2b27d3323df7f93c010b7e.tar.gz"; 5 | }; 6 | in with import nixpkgs {}; 7 | mkShell { 8 | buildInputs = 9 | let 10 | pgWithExt = { pg }: pg.withPackages (p: [ (callPackage ./nix/supa_audit { postgresql = pg; }) ]); 11 | pg_16_w_supa_audit = callPackage ./nix/supa_audit/pgScript.nix { postgresql = pgWithExt { pg = postgresql_16; }; }; 12 | pg_15_w_supa_audit = callPackage ./nix/supa_audit/pgScript.nix { postgresql = pgWithExt { pg = postgresql_15; }; }; 13 | pg_14_w_supa_audit = callPackage ./nix/supa_audit/pgScript.nix { postgresql = pgWithExt { pg = postgresql_14; }; }; 14 | pg_13_w_supa_audit = callPackage ./nix/supa_audit/pgScript.nix { postgresql = pgWithExt { pg = postgresql_13; }; }; 15 | pg_12_w_supa_audit = callPackage ./nix/supa_audit/pgScript.nix { postgresql = pgWithExt { pg = postgresql_12; }; }; 16 | in 17 | [ pg_16_w_supa_audit pg_15_w_supa_audit pg_14_w_supa_audit pg_13_w_supa_audit pg_12_w_supa_audit ]; 18 | } 19 | -------------------------------------------------------------------------------- /supa_audit--0.1.0--0.2.0.sql: -------------------------------------------------------------------------------- 1 | alter table audit.record_version alter column record set data type jsonb; 2 | alter table audit.record_version alter column old_record set data type jsonb; 3 | alter table audit.record_version alter column table_oid set data type oid; 4 | alter table audit.record_version alter column ts set data type timestamptz; 5 | -------------------------------------------------------------------------------- /supa_audit--0.2.0--0.2.1.sql: -------------------------------------------------------------------------------- 1 | drop index audit.record_version_old_record_id; 2 | 3 | create index record_version_old_record_id 4 | on audit.record_version(old_record_id) 5 | where old_record_id is not null; 6 | -------------------------------------------------------------------------------- /supa_audit--0.2.1--0.2.2.sql: -------------------------------------------------------------------------------- 1 | create or replace function audit.enable_tracking(regclass) 2 | returns void 3 | volatile 4 | security definer 5 | language plpgsql 6 | as $$ 7 | declare 8 | statement_row text = format(' 9 | create trigger audit_i_u_d 10 | before insert or update or delete 11 | on %s 12 | for each row 13 | execute procedure audit.insert_update_delete_trigger();', 14 | $1 15 | ); 16 | 17 | statement_stmt text = format(' 18 | create trigger audit_t 19 | before truncate 20 | on %s 21 | for each statement 22 | execute procedure audit.truncate_trigger();', 23 | $1 24 | ); 25 | 26 | pkey_cols text[] = audit.primary_key_columns($1); 27 | begin 28 | if pkey_cols = array[]::text[] then 29 | raise exception 'Table % can not be audited because it has no primary key', $1; 30 | end if; 31 | 32 | if not exists(select 1 from pg_trigger where tgrelid = $1 and tgname = 'audit_i_u_d') then 33 | execute statement_row; 34 | end if; 35 | 36 | if not exists(select 1 from pg_trigger where tgrelid = $1 and tgname = 'audit_t') then 37 | execute statement_stmt; 38 | end if; 39 | end; 40 | $$; 41 | 42 | create or replace function audit.disable_tracking(regclass) 43 | returns void 44 | volatile 45 | security definer 46 | language plpgsql 47 | as $$ 48 | declare 49 | statement_row text = format( 50 | 'drop trigger if exists audit_i_u_d on %s;', 51 | $1 52 | ); 53 | 54 | statement_stmt text = format( 55 | 'drop trigger if exists audit_t on %s;', 56 | $1 57 | ); 58 | begin 59 | execute statement_row; 60 | execute statement_stmt; 61 | end; 62 | $$; 63 | -------------------------------------------------------------------------------- /supa_audit--0.2.2--0.2.3.sql: -------------------------------------------------------------------------------- 1 | alter table audit.record_version alter column ts set default (now()); 2 | -------------------------------------------------------------------------------- /supa_audit--0.2.3--0.3.0.sql: -------------------------------------------------------------------------------- 1 | create or replace function audit.primary_key_columns(entity_oid oid) 2 | returns text[] 3 | stable 4 | security definer 5 | set search_path = '' 6 | language sql 7 | as $$ 8 | -- Looks up the names of a table's primary key columns 9 | select 10 | coalesce( 11 | array_agg(pa.attname::text order by pa.attnum), 12 | array[]::text[] 13 | ) column_names 14 | from 15 | pg_index pi 16 | join pg_attribute pa 17 | on pi.indrelid = pa.attrelid 18 | and pa.attnum = any(pi.indkey) 19 | 20 | where 21 | indrelid = $1 22 | and indisprimary 23 | $$; 24 | 25 | 26 | create or replace function audit.to_record_id(entity_oid oid, pkey_cols text[], rec jsonb) 27 | returns uuid 28 | stable 29 | language sql 30 | as $$ 31 | select 32 | case 33 | when rec is null then null 34 | when pkey_cols = array[]::text[] then uuid_generate_v4() 35 | else ( 36 | select 37 | uuid_generate_v5( 38 | 'fd62bc3d-8d6e-43c2-919c-802ba3762271', 39 | ( jsonb_build_array(to_jsonb($1)) || jsonb_agg($3 ->> key_) )::text 40 | ) 41 | from 42 | unnest($2) x(key_) 43 | ) 44 | end 45 | $$; 46 | 47 | 48 | create or replace function audit.insert_update_delete_trigger() 49 | returns trigger 50 | security definer 51 | -- can not use search_path = '' here because audit.to_record_id requires 52 | -- uuid_generate_v4, which may be installed in a user-defined schema 53 | language plpgsql 54 | as $$ 55 | declare 56 | pkey_cols text[] = audit.primary_key_columns(TG_RELID); 57 | 58 | record_jsonb jsonb = to_jsonb(new); 59 | record_id uuid = audit.to_record_id(TG_RELID, pkey_cols, record_jsonb); 60 | 61 | old_record_jsonb jsonb = to_jsonb(old); 62 | old_record_id uuid = audit.to_record_id(TG_RELID, pkey_cols, old_record_jsonb); 63 | begin 64 | 65 | insert into audit.record_version( 66 | record_id, 67 | old_record_id, 68 | op, 69 | table_oid, 70 | table_schema, 71 | table_name, 72 | record, 73 | old_record 74 | ) 75 | select 76 | record_id, 77 | old_record_id, 78 | TG_OP::audit.operation, 79 | TG_RELID, 80 | TG_TABLE_SCHEMA, 81 | TG_TABLE_NAME, 82 | record_jsonb, 83 | old_record_jsonb; 84 | 85 | return coalesce(new, old); 86 | end; 87 | $$; 88 | 89 | 90 | create or replace function audit.truncate_trigger() 91 | returns trigger 92 | security definer 93 | set search_path = '' 94 | language plpgsql 95 | as $$ 96 | begin 97 | insert into audit.record_version( 98 | op, 99 | table_oid, 100 | table_schema, 101 | table_name 102 | ) 103 | select 104 | TG_OP::audit.operation, 105 | TG_RELID, 106 | TG_TABLE_SCHEMA, 107 | TG_TABLE_NAME; 108 | 109 | return coalesce(old, new); 110 | end; 111 | $$; 112 | 113 | 114 | create or replace function audit.enable_tracking(regclass) 115 | returns void 116 | volatile 117 | security definer 118 | set search_path = '' 119 | language plpgsql 120 | as $$ 121 | declare 122 | statement_row text = format(' 123 | create trigger audit_i_u_d 124 | after insert or update or delete 125 | on %s 126 | for each row 127 | execute procedure audit.insert_update_delete_trigger();', 128 | $1 129 | ); 130 | 131 | statement_stmt text = format(' 132 | create trigger audit_t 133 | after truncate 134 | on %s 135 | for each statement 136 | execute procedure audit.truncate_trigger();', 137 | $1 138 | ); 139 | 140 | pkey_cols text[] = audit.primary_key_columns($1); 141 | begin 142 | if pkey_cols = array[]::text[] then 143 | raise exception 'Table % can not be audited because it has no primary key', $1; 144 | end if; 145 | 146 | if not exists(select 1 from pg_trigger where tgrelid = $1 and tgname = 'audit_i_u_d') then 147 | execute statement_row; 148 | end if; 149 | 150 | if not exists(select 1 from pg_trigger where tgrelid = $1 and tgname = 'audit_t') then 151 | execute statement_stmt; 152 | end if; 153 | end; 154 | $$; 155 | 156 | 157 | create or replace function audit.disable_tracking(regclass) 158 | returns void 159 | volatile 160 | security definer 161 | set search_path = '' 162 | language plpgsql 163 | as $$ 164 | declare 165 | statement_row text = format( 166 | 'drop trigger if exists audit_i_u_d on %s;', 167 | $1 168 | ); 169 | 170 | statement_stmt text = format( 171 | 'drop trigger if exists audit_t on %s;', 172 | $1 173 | ); 174 | begin 175 | execute statement_row; 176 | execute statement_stmt; 177 | end; 178 | $$; 179 | 180 | 181 | /* 182 | Transition Existing audit_i_u_d and audit_t triggers from "before" to "after" 183 | */ 184 | 185 | do $$ 186 | declare 187 | tab regclass; 188 | begin 189 | -- find all existing audit triggers 190 | for tab in select tgrelid::regclass from pg_trigger where tgname = 'audit_i_u_d' loop 191 | -- remove the "before" triggers" 192 | perform audit.disable_tracking(tab); 193 | -- create the "after" triggers 194 | perform audit.enable_tracking(tab); 195 | end loop; 196 | end 197 | $$; 198 | -------------------------------------------------------------------------------- /supa_audit--0.3.0--0.3.1.sql: -------------------------------------------------------------------------------- 1 | select pg_catalog.pg_extension_config_dump('audit.record_version', ''); 2 | select pg_catalog.pg_extension_config_dump('audit.record_version_id_seq', ''); 3 | -------------------------------------------------------------------------------- /supa_audit--0.3.1.sql: -------------------------------------------------------------------------------- 1 | -- SPDX-License-Identifier: Apache-2.0 2 | /* 3 | Generic Audit Trigger 4 | Linear Time Record Version History 5 | 6 | Date: 7 | 2022-02-03 8 | 9 | Purpose: 10 | Generic audit history for tables including an indentifier 11 | to enable indexed linear time lookup of a primary key's version history 12 | */ 13 | 14 | 15 | -- Namespace to "audit" 16 | create schema if not exists audit; 17 | 18 | 19 | -- Create enum type for SQL operations to reduce disk/memory usage vs text 20 | create type audit.operation as enum ( 21 | 'INSERT', 22 | 'UPDATE', 23 | 'DELETE', 24 | 'TRUNCATE' 25 | ); 26 | 27 | 28 | create table audit.record_version( 29 | -- unique auto-incrementing id 30 | id bigserial primary key, 31 | -- uniquely identifies a record by primary key [primary key + table_oid] 32 | record_id uuid, 33 | -- uniquely identifies a record before update/delete 34 | old_record_id uuid, 35 | -- INSERT/UPDATE/DELETE/TRUNCATE/SNAPSHOT 36 | op audit.operation not null, 37 | ts timestamptz not null default (now()), 38 | table_oid oid not null, 39 | table_schema name not null, 40 | table_name name not null, 41 | 42 | -- contents of the record 43 | record jsonb, 44 | -- previous record contents for UPDATE/DELETE 45 | old_record jsonb, 46 | 47 | -- at least one of record_id or old_record_id is populated, except for truncates 48 | check (coalesce(record_id, old_record_id) is not null or op = 'TRUNCATE'), 49 | 50 | -- record_id must be populated for insert and update 51 | check (op in ('INSERT', 'UPDATE') = (record_id is not null)), 52 | check (op in ('INSERT', 'UPDATE') = (record is not null)), 53 | 54 | -- old_record must be populated for update and delete 55 | check (op in ('UPDATE', 'DELETE') = (old_record_id is not null)), 56 | check (op in ('UPDATE', 'DELETE') = (old_record is not null)) 57 | ); 58 | 59 | -- mark the table as configuration data so it's included in database dumps and can be backed up 60 | select pg_catalog.pg_extension_config_dump('audit.record_version', ''); 61 | select pg_catalog.pg_extension_config_dump('audit.record_version_id_seq', ''); 62 | 63 | do $$ 64 | begin 65 | -- Detect if we're in a supabase project 66 | -- Ensure `auth.uid() -> uuid` and `auth.role() -> text` exist 67 | if ( 68 | select 69 | count(distinct f.proname) = 2 70 | from 71 | pg_proc f 72 | join pg_namespace nsp 73 | on f.pronamespace = nsp.oid 74 | join pg_type pt 75 | on f.prorettype = pt.oid 76 | where 77 | (nsp.nspname, f.proname, pt.typname) in ( 78 | ('auth', 'uid', 'uuid'), 79 | ('auth', 'role', 'text') 80 | ) 81 | and f.pronargs = 0 82 | ) 83 | then 84 | 85 | alter table audit.record_version add column auth_uid uuid default (auth.uid()); 86 | alter table audit.record_version add column auth_role text default (auth.role()); 87 | end if; 88 | end 89 | $$; 90 | 91 | 92 | create index record_version_record_id 93 | on audit.record_version(record_id) 94 | where record_id is not null; 95 | 96 | 97 | create index record_version_old_record_id 98 | on audit.record_version(old_record_id) 99 | where old_record_id is not null; 100 | 101 | 102 | create index record_version_ts 103 | on audit.record_version 104 | using brin(ts); 105 | 106 | 107 | create index record_version_table_oid 108 | on audit.record_version(table_oid); 109 | 110 | 111 | create or replace function audit.primary_key_columns(entity_oid oid) 112 | returns text[] 113 | stable 114 | security definer 115 | set search_path = '' 116 | language sql 117 | as $$ 118 | -- Looks up the names of a table's primary key columns 119 | select 120 | coalesce( 121 | array_agg(pa.attname::text order by pa.attnum), 122 | array[]::text[] 123 | ) column_names 124 | from 125 | pg_index pi 126 | join pg_attribute pa 127 | on pi.indrelid = pa.attrelid 128 | and pa.attnum = any(pi.indkey) 129 | 130 | where 131 | indrelid = $1 132 | and indisprimary 133 | $$; 134 | 135 | 136 | create or replace function audit.to_record_id(entity_oid oid, pkey_cols text[], rec jsonb) 137 | returns uuid 138 | stable 139 | language sql 140 | as $$ 141 | select 142 | case 143 | when rec is null then null 144 | when pkey_cols = array[]::text[] then uuid_generate_v4() 145 | else ( 146 | select 147 | uuid_generate_v5( 148 | 'fd62bc3d-8d6e-43c2-919c-802ba3762271', 149 | ( jsonb_build_array(to_jsonb($1)) || jsonb_agg($3 ->> key_) )::text 150 | ) 151 | from 152 | unnest($2) x(key_) 153 | ) 154 | end 155 | $$; 156 | 157 | 158 | create or replace function audit.insert_update_delete_trigger() 159 | returns trigger 160 | security definer 161 | -- can not use search_path = '' here because audit.to_record_id requires 162 | -- uuid_generate_v4, which may be installed in a user-defined schema 163 | language plpgsql 164 | as $$ 165 | declare 166 | pkey_cols text[] = audit.primary_key_columns(TG_RELID); 167 | 168 | record_jsonb jsonb = to_jsonb(new); 169 | record_id uuid = audit.to_record_id(TG_RELID, pkey_cols, record_jsonb); 170 | 171 | old_record_jsonb jsonb = to_jsonb(old); 172 | old_record_id uuid = audit.to_record_id(TG_RELID, pkey_cols, old_record_jsonb); 173 | begin 174 | 175 | insert into audit.record_version( 176 | record_id, 177 | old_record_id, 178 | op, 179 | table_oid, 180 | table_schema, 181 | table_name, 182 | record, 183 | old_record 184 | ) 185 | select 186 | record_id, 187 | old_record_id, 188 | TG_OP::audit.operation, 189 | TG_RELID, 190 | TG_TABLE_SCHEMA, 191 | TG_TABLE_NAME, 192 | record_jsonb, 193 | old_record_jsonb; 194 | 195 | return coalesce(new, old); 196 | end; 197 | $$; 198 | 199 | 200 | create or replace function audit.truncate_trigger() 201 | returns trigger 202 | security definer 203 | set search_path = '' 204 | language plpgsql 205 | as $$ 206 | begin 207 | insert into audit.record_version( 208 | op, 209 | table_oid, 210 | table_schema, 211 | table_name 212 | ) 213 | select 214 | TG_OP::audit.operation, 215 | TG_RELID, 216 | TG_TABLE_SCHEMA, 217 | TG_TABLE_NAME; 218 | 219 | return coalesce(old, new); 220 | end; 221 | $$; 222 | 223 | 224 | create or replace function audit.enable_tracking(regclass) 225 | returns void 226 | volatile 227 | security definer 228 | set search_path = '' 229 | language plpgsql 230 | as $$ 231 | declare 232 | statement_row text = format(' 233 | create trigger audit_i_u_d 234 | after insert or update or delete 235 | on %s 236 | for each row 237 | execute procedure audit.insert_update_delete_trigger();', 238 | $1 239 | ); 240 | 241 | statement_stmt text = format(' 242 | create trigger audit_t 243 | after truncate 244 | on %s 245 | for each statement 246 | execute procedure audit.truncate_trigger();', 247 | $1 248 | ); 249 | 250 | pkey_cols text[] = audit.primary_key_columns($1); 251 | begin 252 | if pkey_cols = array[]::text[] then 253 | raise exception 'Table % can not be audited because it has no primary key', $1; 254 | end if; 255 | 256 | if not exists(select 1 from pg_trigger where tgrelid = $1 and tgname = 'audit_i_u_d') then 257 | execute statement_row; 258 | end if; 259 | 260 | if not exists(select 1 from pg_trigger where tgrelid = $1 and tgname = 'audit_t') then 261 | execute statement_stmt; 262 | end if; 263 | end; 264 | $$; 265 | 266 | 267 | create or replace function audit.disable_tracking(regclass) 268 | returns void 269 | volatile 270 | security definer 271 | set search_path = '' 272 | language plpgsql 273 | as $$ 274 | declare 275 | statement_row text = format( 276 | 'drop trigger if exists audit_i_u_d on %s;', 277 | $1 278 | ); 279 | 280 | statement_stmt text = format( 281 | 'drop trigger if exists audit_t on %s;', 282 | $1 283 | ); 284 | begin 285 | execute statement_row; 286 | execute statement_stmt; 287 | end; 288 | $$; 289 | -------------------------------------------------------------------------------- /supa_audit.control: -------------------------------------------------------------------------------- 1 | comment = 'Generic table auditing' 2 | default_version = '0.3.1' 3 | relocatable = false 4 | requires = uuid-ossp 5 | -------------------------------------------------------------------------------- /test/expected/detect_supabase.out: -------------------------------------------------------------------------------- 1 | begin; 2 | drop extension supa_audit; 3 | create schema auth; 4 | create function auth.uid() 5 | returns uuid 6 | language sql 7 | as $$ select '76f99606-1b3f-41d1-806d-358b34db3b32'::uuid $$; 8 | create function auth.role() 9 | returns text 10 | language sql 11 | as $$ select 'anon' $$; 12 | create extension supa_audit; 13 | -- Check that the supabase auth_uid and auth_role columns are present 14 | select * from audit.record_version; 15 | id | record_id | old_record_id | op | ts | table_oid | table_schema | table_name | record | old_record | auth_uid | auth_role 16 | ----+-----------+---------------+----+----+-----------+--------------+------------+--------+------------+----------+----------- 17 | (0 rows) 18 | 19 | create table public.xyz(id int primary key); 20 | select audit.enable_tracking('public.xyz'::regclass); 21 | enable_tracking 22 | ----------------- 23 | 24 | (1 row) 25 | 26 | insert into public.xyz(id) values(1); 27 | -- Check that defaults populate 28 | select 29 | op, 30 | auth_uid, 31 | auth_role 32 | from 33 | audit.record_version; 34 | op | auth_uid | auth_role 35 | --------+--------------------------------------+----------- 36 | INSERT | 76f99606-1b3f-41d1-806d-358b34db3b32 | anon 37 | (1 row) 38 | 39 | rollback; 40 | -------------------------------------------------------------------------------- /test/expected/disable_idempotent.out: -------------------------------------------------------------------------------- 1 | begin; 2 | create table public.dummy( 3 | id int primary key 4 | ); 5 | select audit.enable_tracking('public.dummy'); 6 | enable_tracking 7 | ----------------- 8 | 9 | (1 row) 10 | 11 | select audit.disable_tracking('public.dummy'); 12 | disable_tracking 13 | ------------------ 14 | 15 | (1 row) 16 | 17 | select audit.disable_tracking('public.dummy'); 18 | NOTICE: trigger "audit_i_u_d" for relation "public.dummy" does not exist, skipping 19 | NOTICE: trigger "audit_t" for relation "public.dummy" does not exist, skipping 20 | disable_tracking 21 | ------------------ 22 | 23 | (1 row) 24 | 25 | select tgname 26 | from pg_trigger 27 | where tgrelid = 'public.dummy'::regclass; 28 | tgname 29 | -------- 30 | (0 rows) 31 | 32 | rollback; 33 | -------------------------------------------------------------------------------- /test/expected/enable_and_disable_tracking.out: -------------------------------------------------------------------------------- 1 | begin; 2 | create table public.dummy( 3 | id int primary key 4 | ); 5 | insert into public.dummy(id) 6 | values (1); 7 | select audit.enable_tracking('public.dummy'); 8 | enable_tracking 9 | ----------------- 10 | 11 | (1 row) 12 | 13 | insert into public.dummy(id) 14 | values (2); 15 | select audit.disable_tracking('public.dummy'); 16 | disable_tracking 17 | ------------------ 18 | 19 | (1 row) 20 | 21 | insert into public.dummy(id) 22 | values (3); 23 | -- Only record with id = 2 should be present 24 | with remap as ( 25 | select distinct on (u.id) 26 | u.id, 27 | row_number() over () stable_id 28 | from 29 | audit.record_version arv, 30 | unnest(array[arv.record_id, arv.old_record_id]) u(id) 31 | order by 32 | u.id asc 33 | ) 34 | select 35 | arv.id, 36 | r.stable_id as remapped_record_id, 37 | ro.stable_id as remapped_old_record_id, 38 | op, 39 | table_schema, 40 | table_name, 41 | record, 42 | old_record 43 | from 44 | audit.record_version arv 45 | left join remap r 46 | on arv.record_id = r.id 47 | left join remap ro 48 | on arv.old_record_id = ro.id; 49 | id | remapped_record_id | remapped_old_record_id | op | table_schema | table_name | record | old_record 50 | ----+--------------------+------------------------+--------+--------------+------------+-----------+------------ 51 | 1 | 1 | | INSERT | public | dummy | {"id": 2} | 52 | (1 row) 53 | 54 | rollback; 55 | -------------------------------------------------------------------------------- /test/expected/enable_idempotent.out: -------------------------------------------------------------------------------- 1 | begin; 2 | create table public.dummy( 3 | id int primary key 4 | ); 5 | select audit.enable_tracking('public.dummy'); 6 | enable_tracking 7 | ----------------- 8 | 9 | (1 row) 10 | 11 | select audit.enable_tracking('public.dummy'); 12 | enable_tracking 13 | ----------------- 14 | 15 | (1 row) 16 | 17 | select tgname 18 | from pg_trigger 19 | where tgrelid = 'public.dummy'::regclass; 20 | tgname 21 | ------------- 22 | audit_i_u_d 23 | audit_t 24 | (2 rows) 25 | 26 | rollback; 27 | -------------------------------------------------------------------------------- /test/expected/require_primary_key.out: -------------------------------------------------------------------------------- 1 | begin; 2 | -- prevent exceptions from failing the test 3 | set client_min_messages to error; 4 | set log_min_messages to panic; 5 | create table public.dummy( 6 | id int 7 | ); 8 | -- Should raise exception that there is no primary key 9 | select audit.enable_tracking('public.dummy'); 10 | ERROR: Table public.dummy can not be audited because it has no primary key 11 | CONTEXT: PL/pgSQL function audit.enable_tracking(regclass) line 24 at RAISE 12 | rollback; 13 | -------------------------------------------------------------------------------- /test/expected/simple_insert_update_delete_truncate.out: -------------------------------------------------------------------------------- 1 | begin; 2 | create table public.members( 3 | id int primary key, 4 | name text not null 5 | ); 6 | select audit.enable_tracking('public.members'); 7 | enable_tracking 8 | ----------------- 9 | 10 | (1 row) 11 | 12 | insert into public.members(id, name) 13 | values (1, 'foo'); 14 | update public.members 15 | set name = 'bar' 16 | where id = 1; 17 | delete from public.members; 18 | truncate table public.members; 19 | with remap as ( 20 | select distinct on (u.id) 21 | u.id, 22 | row_number() over () stable_id 23 | from 24 | audit.record_version arv, 25 | unnest(array[arv.record_id, arv.old_record_id]) u(id) 26 | order by 27 | u.id asc 28 | ) 29 | select 30 | arv.id, 31 | r.stable_id as remapped_record_id, 32 | ro.stable_id as remapped_old_record_id, 33 | op, 34 | table_schema, 35 | table_name, 36 | record, 37 | old_record 38 | from 39 | audit.record_version arv 40 | left join remap r 41 | on arv.record_id = r.id 42 | left join remap ro 43 | on arv.old_record_id = ro.id; 44 | id | remapped_record_id | remapped_old_record_id | op | table_schema | table_name | record | old_record 45 | ----+--------------------+------------------------+----------+--------------+------------+--------------------------+-------------------------- 46 | 2 | 3 | | INSERT | public | members | {"id": 1, "name": "foo"} | 47 | 3 | 3 | 3 | UPDATE | public | members | {"id": 1, "name": "bar"} | {"id": 1, "name": "foo"} 48 | 4 | | 3 | DELETE | public | members | | {"id": 1, "name": "bar"} 49 | 5 | | | TRUNCATE | public | members | | 50 | (4 rows) 51 | 52 | rollback; 53 | -------------------------------------------------------------------------------- /test/expected/track_table_schema_not_on_search_path.out: -------------------------------------------------------------------------------- 1 | begin; 2 | -- Check escaping rules for schemas not on the search path 3 | -- and tables containing capital letters 4 | create schema xyz; 5 | create table xyz."Members"( 6 | id int primary key, 7 | name text not null 8 | ); 9 | select audit.enable_tracking('xyz."Members"'); 10 | enable_tracking 11 | ----------------- 12 | 13 | (1 row) 14 | 15 | select audit.disable_tracking('xyz."Members"'); 16 | disable_tracking 17 | ------------------ 18 | 19 | (1 row) 20 | 21 | rollback; 22 | -------------------------------------------------------------------------------- /test/fixtures.sql: -------------------------------------------------------------------------------- 1 | -- Anything that needs to be executed prior to every test goes here 2 | create extension supa_audit cascade version '0.3.1'; 3 | -------------------------------------------------------------------------------- /test/sql/detect_supabase.sql: -------------------------------------------------------------------------------- 1 | begin; 2 | drop extension supa_audit; 3 | 4 | create schema auth; 5 | 6 | create function auth.uid() 7 | returns uuid 8 | language sql 9 | as $$ select '76f99606-1b3f-41d1-806d-358b34db3b32'::uuid $$; 10 | 11 | create function auth.role() 12 | returns text 13 | language sql 14 | as $$ select 'anon' $$; 15 | 16 | create extension supa_audit; 17 | 18 | -- Check that the supabase auth_uid and auth_role columns are present 19 | select * from audit.record_version; 20 | 21 | create table public.xyz(id int primary key); 22 | 23 | select audit.enable_tracking('public.xyz'::regclass); 24 | 25 | insert into public.xyz(id) values(1); 26 | 27 | -- Check that defaults populate 28 | select 29 | op, 30 | auth_uid, 31 | auth_role 32 | from 33 | audit.record_version; 34 | 35 | rollback; 36 | -------------------------------------------------------------------------------- /test/sql/disable_idempotent.sql: -------------------------------------------------------------------------------- 1 | begin; 2 | 3 | create table public.dummy( 4 | id int primary key 5 | ); 6 | 7 | 8 | select audit.enable_tracking('public.dummy'); 9 | 10 | 11 | select audit.disable_tracking('public.dummy'); 12 | select audit.disable_tracking('public.dummy'); 13 | 14 | 15 | select tgname 16 | from pg_trigger 17 | where tgrelid = 'public.dummy'::regclass; 18 | 19 | rollback; 20 | -------------------------------------------------------------------------------- /test/sql/enable_and_disable_tracking.sql: -------------------------------------------------------------------------------- 1 | begin; 2 | 3 | create table public.dummy( 4 | id int primary key 5 | ); 6 | 7 | 8 | insert into public.dummy(id) 9 | values (1); 10 | 11 | 12 | select audit.enable_tracking('public.dummy'); 13 | 14 | 15 | insert into public.dummy(id) 16 | values (2); 17 | 18 | 19 | select audit.disable_tracking('public.dummy'); 20 | 21 | 22 | insert into public.dummy(id) 23 | values (3); 24 | 25 | 26 | -- Only record with id = 2 should be present 27 | with remap as ( 28 | select distinct on (u.id) 29 | u.id, 30 | row_number() over () stable_id 31 | from 32 | audit.record_version arv, 33 | unnest(array[arv.record_id, arv.old_record_id]) u(id) 34 | order by 35 | u.id asc 36 | ) 37 | select 38 | arv.id, 39 | r.stable_id as remapped_record_id, 40 | ro.stable_id as remapped_old_record_id, 41 | op, 42 | table_schema, 43 | table_name, 44 | record, 45 | old_record 46 | from 47 | audit.record_version arv 48 | left join remap r 49 | on arv.record_id = r.id 50 | left join remap ro 51 | on arv.old_record_id = ro.id; 52 | rollback; 53 | -------------------------------------------------------------------------------- /test/sql/enable_idempotent.sql: -------------------------------------------------------------------------------- 1 | begin; 2 | 3 | create table public.dummy( 4 | id int primary key 5 | ); 6 | 7 | 8 | select audit.enable_tracking('public.dummy'); 9 | select audit.enable_tracking('public.dummy'); 10 | 11 | 12 | select tgname 13 | from pg_trigger 14 | where tgrelid = 'public.dummy'::regclass; 15 | 16 | rollback; 17 | -------------------------------------------------------------------------------- /test/sql/require_primary_key.sql: -------------------------------------------------------------------------------- 1 | begin; 2 | -- prevent exceptions from failing the test 3 | set client_min_messages to error; 4 | set log_min_messages to panic; 5 | 6 | create table public.dummy( 7 | id int 8 | ); 9 | 10 | 11 | -- Should raise exception that there is no primary key 12 | select audit.enable_tracking('public.dummy'); 13 | 14 | rollback; 15 | -------------------------------------------------------------------------------- /test/sql/simple_insert_update_delete_truncate.sql: -------------------------------------------------------------------------------- 1 | begin; 2 | 3 | create table public.members( 4 | id int primary key, 5 | name text not null 6 | ); 7 | 8 | select audit.enable_tracking('public.members'); 9 | 10 | insert into public.members(id, name) 11 | values (1, 'foo'); 12 | 13 | update public.members 14 | set name = 'bar' 15 | where id = 1; 16 | 17 | delete from public.members; 18 | 19 | truncate table public.members; 20 | 21 | with remap as ( 22 | select distinct on (u.id) 23 | u.id, 24 | row_number() over () stable_id 25 | from 26 | audit.record_version arv, 27 | unnest(array[arv.record_id, arv.old_record_id]) u(id) 28 | order by 29 | u.id asc 30 | ) 31 | select 32 | arv.id, 33 | r.stable_id as remapped_record_id, 34 | ro.stable_id as remapped_old_record_id, 35 | op, 36 | table_schema, 37 | table_name, 38 | record, 39 | old_record 40 | from 41 | audit.record_version arv 42 | left join remap r 43 | on arv.record_id = r.id 44 | left join remap ro 45 | on arv.old_record_id = ro.id; 46 | rollback; 47 | -------------------------------------------------------------------------------- /test/sql/track_table_schema_not_on_search_path.sql: -------------------------------------------------------------------------------- 1 | begin; 2 | -- Check escaping rules for schemas not on the search path 3 | -- and tables containing capital letters 4 | 5 | create schema xyz; 6 | 7 | create table xyz."Members"( 8 | id int primary key, 9 | name text not null 10 | ); 11 | 12 | select audit.enable_tracking('xyz."Members"'); 13 | select audit.disable_tracking('xyz."Members"'); 14 | 15 | rollback; 16 | --------------------------------------------------------------------------------