├── .editorconfig ├── .gitignore ├── .travis.yml ├── AUTHORS ├── CHANGES.md ├── Dockerfile ├── LICENSE ├── META.json ├── Makefile ├── README.md ├── docker-compose.yml ├── pg-audit-json.control ├── sql ├── pg-audit-json--1.0.0--1.0.1.sql ├── pg-audit-json--1.0.1--1.0.2.sql ├── pg-audit-json--1.0.1.sql ├── pg-audit-json--1.0.2.sql └── uninstall_pg-audit-json.sql └── test ├── expected ├── audit_test.out └── minus_test.out └── sql ├── audit_test.sql └── minus_test.sql /.editorconfig: -------------------------------------------------------------------------------- 1 | # 2 | # Development coding style guidelines 3 | # 4 | 5 | # Don't look any further for more editor configurations 6 | root = true 7 | 8 | [*] 9 | end_of_line = lf 10 | indent_style = space 11 | indent_size = 2 12 | insert_final_newline = false 13 | max_line_length = 80 14 | trim_trailing_whitespace=true 15 | 16 | [*.out] 17 | # Expected results need to match, including trailing spaces. 18 | trim_trailing_whitespace=false 19 | 20 | [Makefile] 21 | indent_style = tab 22 | -------------------------------------------------------------------------------- /.gitignore: -------------------------------------------------------------------------------- 1 | # Genrated by pg regress 2 | results/ 3 | regression.diffs 4 | regression.out 5 | 6 | -------------------------------------------------------------------------------- /.travis.yml: -------------------------------------------------------------------------------- 1 | # Global Config 2 | language: python 3 | sudo: required 4 | 5 | services: 6 | - postgresql 7 | 8 | addons: 9 | postgresql: "9.6" 10 | apt: 11 | packages: 12 | - postgresql-server-dev-9.6 13 | 14 | script: 15 | - sudo make install 16 | - sudo make installcheck PGHOST=localhost PGUSER=postgres 17 | 18 | # pg_regress only prints to files, so we need to print out contents on failure 19 | after_failure: 20 | - cat $TRAVIS_BUILD_DIR/regression.diffs 21 | -------------------------------------------------------------------------------- /AUTHORS: -------------------------------------------------------------------------------- 1 | Maintainer 2 | ---------- 3 | Marco Martinez (github: ) 4 | 5 | Original Author 6 | --------------- 7 | Craig Ringer (github: ) 8 | 9 | Contributors 10 | ------------ 11 | github: 3nids 12 | github: ADTC 13 | github: asenyshyn 14 | github: jhm713 15 | github: paulovieira 16 | github: nineinchnick 17 | -------------------------------------------------------------------------------- /CHANGES.md: -------------------------------------------------------------------------------- 1 | # Changelog 2 | 3 | ## [1.0.2] - 2020-06-21 4 | 5 | ### Changed 6 | - Allow backups to include table and id sequence 7 | - Allow development containers to specify Postgres version and extension version 8 | 9 | ## [1.0.1] - 2018-07-18 10 | 11 | Important fixes 12 | 13 | ### Added 14 | - Testing files run via Travis 15 | - Uninstall files 16 | - Necessary migration files 17 | 18 | ### Changed 19 | - Use prefixed runtime settings (PostgreSQL only allows custom settings in this way) 20 | - Additional README clarifications by @oetiker 21 | - Allow `audit.log` data to be `pg_dump`'ed 22 | 23 | ## [1.0.0] - 2017-09-12 24 | 25 | Initial fork 26 | 27 | ### Added 28 | - JSONB minus operators to determine diffs 29 | - Documentation 30 | - Converted to PGXN-compatble extension 31 | 32 | ### Changed 33 | - Use JSON instead of HSTORE 34 | - Renamed `event_id` to `id` 35 | - Added columns `application_name` and `application_user` that are populated 36 | via configurable runtime settings. 37 | 38 | [1.0.2]: https://github.com/m-martinez/pg-audit-json/compare/1.0.1...1.0.2 39 | [1.0.1]: https://github.com/m-martinez/pg-audit-json/compare/1.0.0...1.0.1 40 | [1.0.0]: https://github.com/m-martinez/pg-audit-json/compare/05137fa...1.0.0 41 | -------------------------------------------------------------------------------- /Dockerfile: -------------------------------------------------------------------------------- 1 | # 2 | # Development-only container 3 | # 4 | # 5 | 6 | ARG POSTGRES_VERSION=9.6 7 | FROM postgres:${POSTGRES_VERSION} 8 | 9 | RUN apt-get update && \ 10 | apt-get install -y make diffutils && \ 11 | apt-get clean && \ 12 | rm -rf /var/lib/apt/lists/* \ 13 | 14 | ARG PG_AUDIT_JSON_VERSION 15 | ENV PG_AUDIT_JSON_VERSION=${PG_AUDIT_JSON_VERSION:-1.0.2} 16 | WORKDIR /usr/local/src 17 | COPY . . 18 | RUN make install 19 | 20 | RUN echo "CREATE EXTENSION \"pg-audit-json\" WITH VERSION '${PG_AUDIT_JSON_VERSION}'" > /docker-entrypoint-initdb.d/000-initdb.sql 21 | -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | The following is "The PostgreSQL License", effectively equivalent to the BSD 2 | license. 3 | 4 | I, Craig Ringer, cede any copyright on this work to the PostgreSQL Global 5 | Development Group. 6 | 7 | ------ 8 | 9 | PostgreSQL Audit Trigger Example 10 | Copyright (c) 2013, PostgreSQL Global Development Group 11 | 12 | Permission to use, copy, modify, and distribute this software and its 13 | documentation for any purpose, without fee, and without a written agreement 14 | is hereby granted, provided that the above copyright notice and this 15 | paragraph and the following two paragraphs appear in all copies. 16 | 17 | IN NO EVENT SHALL THE UNIVERSITY OF CALIFORNIA BE LIABLE TO ANY PARTY FOR 18 | DIRECT, INDIRECT, SPECIAL, INCIDENTAL, OR CONSEQUENTIAL DAMAGES, INCLUDING 19 | LOST PROFITS, ARISING OUT OF THE USE OF THIS SOFTWARE AND ITS 20 | DOCUMENTATION, EVEN IF THE UNIVERSITY OF CALIFORNIA HAS BEEN ADVISED OF THE 21 | POSSIBILITY OF SUCH DAMAGE. 22 | 23 | THE UNIVERSITY OF CALIFORNIA SPECIFICALLY DISCLAIMS ANY WARRANTIES, 24 | INCLUDING, BUT NOT LIMITED TO, THE IMPLIED WARRANTIES OF MERCHANTABILITY 25 | AND FITNESS FOR A PARTICULAR PURPOSE. THE SOFTWARE PROVIDED HEREUNDER IS 26 | ON AN "AS IS" BASIS, AND THE UNIVERSITY OF CALIFORNIA HAS NO OBLIGATIONS TO 27 | PROVIDE MAINTENANCE, SUPPORT, UPDATES, ENHANCEMENTS, OR MODIFICATIONS. 28 | -------------------------------------------------------------------------------- /META.json: -------------------------------------------------------------------------------- 1 | { 2 | "name": "pg-audit-json", 3 | "abstract": "An audit history tracker", 4 | "version": "1.0.1", 5 | "maintainer": "Marco Martinez ", 6 | "license": "postgresql", 7 | "meta-spec": { 8 | "version": "1.0.0", 9 | "url": "http://pgxn.org/meta/spec.txt" 10 | } 11 | } 12 | -------------------------------------------------------------------------------- /Makefile: -------------------------------------------------------------------------------- 1 | # 2 | # Extension installer 3 | # 4 | # Usage: 5 | # > make && make install 6 | # 7 | # To run tests: 8 | # > make installcheck 9 | # 10 | # Copied from: 11 | # http://manager.pgxn.org/howto 12 | # 13 | 14 | EXTENSION = $(shell grep -m 1 '"name":' META.json | \ 15 | sed -e 's/[[:space:]]*"name":[[:space:]]*"\([^"]*\)",/\1/') 16 | EXTVERSION = $(shell grep -m 1 '"version":' META.json | \ 17 | sed -e 's/[[:space:]]*"version":[[:space:]]*"\([^"]*\)",\{0,1\}/\1/') 18 | 19 | DATA = $(filter-out $(wildcard sql/*--*.sql),$(wildcard sql/*.sql)) 20 | 21 | TESTS = $(wildcard test/sql/*.sql) 22 | REGRESS = $(patsubst test/sql/%.sql,%,$(TESTS)) 23 | REGRESS_OPTS = --inputdir=test 24 | PG_CONFIG = pg_config 25 | PG91 = $(shell $(PG_CONFIG) --version | grep -qE " 8\\.| 9\\.0" && echo no || echo yes) 26 | 27 | ifeq ($(PG91),yes) 28 | all: sql/$(EXTENSION)--$(EXTVERSION).sql 29 | 30 | sql/$(EXTENSION)--$(EXTVERSION).sql: sql/$(EXTENSION).sql 31 | cp $< $@ 32 | 33 | # TODO: This appears to copy the extenion file twice 34 | #DATA = $(wildcard sql/*--*.sql) sql/$(EXTENSION)--$(EXTVERSION).sql 35 | DATA = $(wildcard sql/*--*.sql) 36 | EXTRA_CLEAN = sql/$(EXTENSION)--$(EXTVERSION).sql 37 | endif 38 | 39 | PGXS := $(shell $(PG_CONFIG) --pgxs) 40 | include $(PGXS) 41 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | [![Build 2 | Status](https://travis-ci.org/m-martinez/pg-audit-json.svg?branch=master)](https://travis-ci.org/m-martinez/pg-audit-json) 3 | 4 | A simple, customizable table audit system for PostgreSQL implemented using 5 | triggers and JSONB for storing diffs. Additionally, if any column is also a 6 | JSON type, a recursive diff will be generated for changed fields. 7 | 8 | This trigger is a fork of [2ndQuadrant's audit trigger][1] implementation. 9 | 10 | [1]: https://github.com/2ndQuadrant/audit-trigger 11 | 12 | Significant changes made from original work: 13 | * Usage of JSONB instead of HSTORE 14 | * Slight table/column name differences 15 | * INSERT values are stored in the `changed_fields` instead of `row_data` to 16 | indicate that a new record is an entire change. 17 | 18 | 19 | ## Audit Table Reference 20 | 21 | Column | Type | Not Null | Description 22 | --- | --- | :---: | --- 23 | `id` | `BIGINT` | ☑ | Unique identifier for each auditable event 24 | `schema_name` | `TEXT` | ☑ | Database schema audited table for this event is in 25 | `table_name` | `TEXT` | ☑ | Non-schema-qualified table name of table event occured in 26 | `relid` | `OID` | ☑ | Table OID. Changes with drop/create. 27 | `session_user_name` | `TEXT` | ☑ | Login / session user whose statement caused the audited event 28 | `current_user_name` | `TEXT` | ☑ | Effective user that cased audited event (if authorization level changed) 29 | `action_tstamp_tx` | `TIMESTAMP` | ☑ | Transaction start timestamp for tx in which audited event occurred 30 | `action_tstamp_stm` | `TIMESTAMP` | ☑ | Statement start timestamp for tx in which audited event occurred 31 | `action_tstamp_clk` | `TIMESTAMP` | ☑ | Wall clock time at which audited event's trigger call occurred 32 | `transaction_id` | `BIGINT` | ☑ | Identifier of transaction that made the change.
Unique when paired with `action_tstamp_tx.` 33 | `client_addr` | `INET` | | IP address of client that issued query. Null for unix domain socket. 34 | `client_port` | `INTEGER` | | Port address of client that issued query.
Undefined for unix socket. 35 | `client_query` | `TEXT` | | Top-level query that caused this auditable event.
May be more than one. 36 | `application_name` | `TEXT` | | Client-set session application name when this audit event occurred. 37 | `application_user` | `TEXT` | | Client-set session application user when this audit event occurred.
This is useful if the application uses its own user-management and authorization system. 38 | `action` | `ENUM` | ☑ | Action type
`I` = insert
`D` = delete
`U` = update
`T` = truncate 39 | `row_data` | `JSONB` | | Record value. Null for statement-level trigger.
For INSERT this is null becuase there was nothing there before.
For DELETE and UPDATE it is the old tuple. 40 | `changed_fields` | `JSONB` | | New values of fields for INSERT or those changed by UPDATE (i.e a diff).
Null for DELETE. 41 | `statement_only` | `BOOLEAN` | ☑ | `t` if audit event is from an FOR EACH STATEMENT trigger
`f` for FOR EACH ROW 42 | 43 | 44 | ## Installation 45 | 46 | Requirements: 47 | * PostgreSQL Server 9.6+ (including developer header files) 48 | 49 | To install: 50 | 51 | ```bash 52 | git clone git@github.com:m-martinez/pg-audit-json 53 | cd pg-audit-json 54 | make install 55 | ``` 56 | 57 | It is highly recommended that you only install this extension using a 58 | postgres administrative account and not the account an application will 59 | be using to interact the database. 60 | 61 | In your postgres shell, activate the extension using: 62 | 63 | ```sql 64 | CREATE EXTENSION "pg-audit-json"; 65 | ``` 66 | 67 | To run the tests (replace PGHOST and PGUSER with your settings): 68 | 69 | ```bash 70 | make installcheck PGHOST=pgserver PGUSER=pguser 71 | ``` 72 | 73 | ## Usage 74 | 75 | ### Tracking a database table 76 | 77 | To track a user table, use the `audit.audit_table` function as the OWNER of the 78 | audit.log table. Here are a few examples: 79 | 80 | ```sql 81 | -- A simple table 82 | SELECT audit.audit_table('mytable'); 83 | 84 | -- A schema-qualified table 85 | SELECT audit.audit_table('myschema.mytable'); 86 | 87 | -- Ignore columns "foo" and "bar" 88 | SELECT audit.audit_table('mytable', true, true, '{foo,bar}'); 89 | ``` 90 | 91 | ### Setting application runtime variables 92 | 93 | This extension allows you to define two optional settings in your application 94 | runtime, which can be set as follows: 95 | 96 | ```sql 97 | SET LOCAL audit.application_name = 'my.fancy.app'; 98 | SET LOCAL audit.application_user_name = 'jdoe@foo.com'; 99 | ``` 100 | 101 | Setting | Description 102 | --- | --- 103 | `application_name` | The name of the application that will trigger audit events 104 | `appliation_user_name` | The effective application user 105 | 106 | 107 | ### pg_dump 108 | 109 | This extension is configured to allow `pg_dump` of the audit log data for 110 | situations where you would like to keep backups of application data. 111 | 112 | 113 | ### Upgrading 114 | 115 | If you already have this plugin installed in your system and would like to 116 | install any recent updates, do either the following: 117 | 118 | ```sql 119 | -- Use the latest 120 | ALTER EXTENSION "pg-audit-json" UPDATE; 121 | 122 | -- Or if you want to be more specific 123 | ALTER EXTENSION "pg-audit-json" UPDATE TO '1.0.1'; 124 | ``` 125 | 126 | 127 | ## Contributing 128 | 129 | This project provides and [editorconfig](http://editorconfig.org) to conform 130 | to a coding style. 131 | 132 | More information about PostgreSQL extensions 133 | * https://www.postgresql.org/docs/current/static/extend-pgxs.html 134 | * https://www.postgresql.org/docs/current/static/extend-extensions.html 135 | * http://manager.pgxn.org/howto 136 | 137 | ### Releasing 138 | 139 | Remember to update the version tags in the following files: 140 | * META.json 141 | * pg-audit-json.control 142 | 143 | 144 | ## Credits 145 | 146 | * https://github.com/2ndQuadrant/audit-trigger 147 | * http://wiki.postgresql.org/wiki/Audit_trigger_91plus 148 | * http://coussej.github.io/2016/05/24/A-Minus-Operator-For-PostgreSQLs-JSONB/ 149 | * http://schinckel.net/2014/09/29/adding-json%28b%29-operators-to-postgresql/ 150 | -------------------------------------------------------------------------------- /docker-compose.yml: -------------------------------------------------------------------------------- 1 | # 2 | # Sets up development services 3 | # 4 | version: "3.0" 5 | services: 6 | postgresql: 7 | build: . 8 | restart: always 9 | ports: 10 | - "5432:5432" 11 | tmpfs: /var/lib/postgresql/data 12 | volumes: 13 | - .:/usr/local/src 14 | -------------------------------------------------------------------------------- /pg-audit-json.control: -------------------------------------------------------------------------------- 1 | comment = 'An audit history tracker' 2 | default_version = '1.0.2' 3 | module_pathname = '$libdir/pg-audit-json' 4 | relocatable = false 5 | -------------------------------------------------------------------------------- /sql/pg-audit-json--1.0.0--1.0.1.sql: -------------------------------------------------------------------------------- 1 | SELECT pg_catalog.pg_extension_config_dump('audit.log', ''); 2 | -------------------------------------------------------------------------------- /sql/pg-audit-json--1.0.1--1.0.2.sql: -------------------------------------------------------------------------------- 1 | SELECT pg_catalog.pg_extension_config_dump('audit.log_id_seq', ''); 2 | -------------------------------------------------------------------------------- /sql/pg-audit-json--1.0.1.sql: -------------------------------------------------------------------------------- 1 | -- 2 | -- An audit history is important on most tables. Provide an audit trigger that 3 | -- logs to a dedicated audit table for the major relations. 4 | -- 5 | 6 | -- Complain if script is sourced in psql, rather than via CREATE EXTENSION 7 | \echo Use "CREATE EXTENSION pg-audit-json" to load this file. \quit 8 | 9 | -- 10 | -- Implements missing "-" JSONB operators that are available in HSTORE 11 | -- 12 | 13 | -- 14 | -- Implements "JSONB- TEXT[]" operation to remove a list of keys 15 | -- 16 | -- Note: This method will be a supported operation of PostgreSQL 10 17 | -- 18 | -- Credit: 19 | -- http://schinckel.net/2014/09/29/adding-json%28b%29-operators-to-postgresql/ 20 | -- 21 | CREATE OR REPLACE FUNCTION "jsonb_minus" ( "left" JSONB, "keys" TEXT[] ) 22 | RETURNS JSONB 23 | LANGUAGE SQL 24 | IMMUTABLE 25 | STRICT 26 | AS $$ 27 | SELECT 28 | CASE 29 | WHEN "left" ?| "keys" 30 | THEN COALESCE( 31 | (SELECT ('{' || 32 | string_agg(to_json("key")::TEXT || ':' || "value", ',') || 33 | '}') 34 | FROM jsonb_each("left") 35 | WHERE "key" <> ALL ("keys")), 36 | '{}' 37 | )::JSONB 38 | ELSE "left" 39 | END 40 | $$; 41 | 42 | CREATE OPERATOR - ( 43 | LEFTARG = JSONB, 44 | RIGHTARG = TEXT[], 45 | PROCEDURE = jsonb_minus 46 | ); 47 | 48 | COMMENT ON FUNCTION jsonb_minus(JSONB, TEXT[]) IS 'Delete specificed keys'; 49 | 50 | COMMENT ON OPERATOR - (JSONB, TEXT[]) IS 'Delete specified keys'; 51 | 52 | -- 53 | -- Implements "JSONB- JSONB" operation to recursively delete matching pairs. 54 | -- 55 | -- Credit: 56 | -- http://coussej.github.io/2016/05/24/A-Minus-Operator-For-PostgreSQLs-JSONB/ 57 | -- 58 | 59 | CREATE OR REPLACE FUNCTION "jsonb_minus" ( "left" JSONB, "right" JSONB ) 60 | RETURNS JSONB 61 | LANGUAGE SQL 62 | IMMUTABLE 63 | STRICT 64 | AS $$ 65 | SELECT 66 | COALESCE(json_object_agg( 67 | "key", 68 | CASE 69 | -- if the value is an object and the value of the second argument is 70 | -- not null, we do a recursion 71 | WHEN jsonb_typeof("value") = 'object' AND "right" -> "key" IS NOT NULL 72 | THEN jsonb_minus("value", "right" -> "key") 73 | -- for all the other types, we just return the value 74 | ELSE "value" 75 | END 76 | ), '{}')::JSONB 77 | FROM 78 | jsonb_each("left") 79 | WHERE 80 | "left" -> "key" <> "right" -> "key" 81 | OR "right" -> "key" IS NULL 82 | $$; 83 | 84 | CREATE OPERATOR - ( 85 | LEFTARG = JSONB, 86 | RIGHTARG = JSONB, 87 | PROCEDURE = jsonb_minus 88 | ); 89 | 90 | COMMENT ON FUNCTION jsonb_minus(JSONB, JSONB) 91 | IS 'Delete matching pairs in the right argument from the left argument'; 92 | 93 | COMMENT ON OPERATOR - (JSONB, JSONB) 94 | IS 'Delete matching pairs in the right argument from the left argument'; 95 | 96 | 97 | CREATE SCHEMA audit; 98 | REVOKE ALL ON SCHEMA audit FROM public; 99 | COMMENT ON SCHEMA audit 100 | IS 'Out-of-table audit/history logging tables and trigger functions'; 101 | 102 | -- 103 | -- Audited data. Lots of information is available, it's just a matter of how 104 | -- much you really want to record. See: 105 | -- 106 | -- http://www.postgresql.org/docs/9.1/static/functions-info.html 107 | -- 108 | -- Remember, every column you add takes up more audit table space and slows 109 | -- audit inserts. 110 | -- 111 | -- Every index you add has a big impact too, so avoid adding indexes to the 112 | -- audit table unless you REALLY need them. The hstore GIST indexes are 113 | -- particularly expensive. 114 | -- 115 | -- It is sometimes worth copying the audit table, or a coarse subset of it that 116 | -- you're interested in, into a temporary table where you CREATE any useful 117 | -- indexes and do your analysis. 118 | -- 119 | CREATE TABLE audit.log ( 120 | id BIGSERIAL PRIMARY KEY, 121 | schema_name TEXT NOT NULL, 122 | table_name TEXT NOT NULL, 123 | relid OID NOT NULL, 124 | session_user_name TEXT NOT NULL, 125 | current_user_name TEXT NOT NULL, 126 | action_tstamp_tx TIMESTAMP WITH TIME ZONE NOT NULL, 127 | action_tstamp_stm TIMESTAMP WITH TIME ZONE NOT NULL, 128 | action_tstamp_clk TIMESTAMP WITH TIME ZONE NOT NULL, 129 | transaction_id BIGINT NOT NULL, 130 | application_name TEXT, 131 | application_user_name TEXT, 132 | client_addr INET, 133 | client_port INTEGER, 134 | client_query TEXT, 135 | action TEXT NOT NULL CHECK (action IN ('I','D','U', 'T')), 136 | row_data JSONB, 137 | changed_fields JSONB, 138 | statement_only BOOLEAN NOT NULL 139 | ); 140 | 141 | REVOKE ALL ON audit.log FROM public; 142 | 143 | COMMENT ON TABLE audit.log 144 | IS 'History of auditable actions on audited tables'; 145 | COMMENT ON COLUMN audit.log.id 146 | IS 'Unique identifier for each auditable event'; 147 | COMMENT ON COLUMN audit.log.schema_name 148 | IS 'Database schema audited table for this event is in'; 149 | COMMENT ON COLUMN audit.log.table_name 150 | IS 'Non-schema-qualified table name of table event occured in'; 151 | COMMENT ON COLUMN audit.log.relid 152 | IS 'Table OID. Changes with drop/create. Get with ''tablename''::REGCLASS'; 153 | COMMENT ON COLUMN audit.log.session_user_name 154 | IS 'Login / session user whose statement caused the audited event'; 155 | COMMENT ON COLUMN audit.log.current_user_name 156 | IS 'Effective user that cased audited event (if authorization level changed)'; 157 | COMMENT ON COLUMN audit.log.action_tstamp_tx 158 | IS 'Transaction start timestamp for tx in which audited event occurred'; 159 | COMMENT ON COLUMN audit.log.action_tstamp_stm 160 | IS 'Statement start timestamp for tx in which audited event occurred'; 161 | COMMENT ON COLUMN audit.log.action_tstamp_clk 162 | IS 'Wall clock time at which audited event''s trigger call occurred'; 163 | COMMENT ON COLUMN audit.log.transaction_id 164 | IS 'Identifier of transaction that made the change. Unique when paired with action_tstamp_tx.'; 165 | COMMENT ON COLUMN audit.log.client_addr 166 | IS 'IP address of client that issued query. Null for unix domain socket.'; 167 | COMMENT ON COLUMN audit.log.client_port 168 | IS 'Port address of client that issued query. Undefined for unix socket.'; 169 | COMMENT ON COLUMN audit.log.client_query 170 | IS 'Top-level query that caused this auditable event. May be more than one.'; 171 | COMMENT ON COLUMN audit.log.application_name 172 | IS 'Client-set session application name when this audit event occurred.'; 173 | COMMENT ON COLUMN audit.log.application_user_name 174 | IS 'Client-set session application user when this audit event occurred.'; 175 | COMMENT ON COLUMN audit.log.action 176 | IS 'Action type; I = insert, D = delete, U = update, T = truncate'; 177 | COMMENT ON COLUMN audit.log.row_data 178 | IS 'Record value. Null for statement-level trigger. For INSERT this is null. For DELETE and UPDATE it is the old tuple.'; 179 | COMMENT ON COLUMN audit.log.changed_fields 180 | IS 'New values of fields for INSERT or changed by UPDATE. Null for DELETE'; 181 | COMMENT ON COLUMN audit.log.statement_only 182 | IS '''t'' if audit event is from an FOR EACH STATEMENT trigger, ''f'' for FOR EACH ROW'; 183 | 184 | CREATE INDEX log_relid_idx ON audit.log(relid); 185 | CREATE INDEX log_action_tstamp_tx_stm_idx ON audit.log(action_tstamp_stm); 186 | CREATE INDEX log_action_idx ON audit.log(action); 187 | 188 | -- 189 | -- Allow the user of the extension to create a backup of the audit log data 190 | -- 191 | SELECT pg_catalog.pg_extension_config_dump('audit.log', ''); 192 | 193 | CREATE OR REPLACE FUNCTION audit.if_modified_func() 194 | RETURNS TRIGGER 195 | LANGUAGE plpgsql 196 | SECURITY DEFINER 197 | SET search_path = pg_catalog, public 198 | AS $$ 199 | DECLARE 200 | audit_row audit.log; 201 | include_values BOOLEAN; 202 | log_diffs BOOLEAN; 203 | h_old JSONB; 204 | h_new JSONB; 205 | excluded_cols TEXT[] = ARRAY[]::TEXT[]; 206 | BEGIN 207 | IF TG_WHEN <> 'AFTER' THEN 208 | RAISE EXCEPTION 'audit.if_modified_func() may only run as an AFTER trigger'; 209 | END IF; 210 | 211 | audit_row = ROW( 212 | nextval('audit.log_id_seq'), -- id 213 | TG_TABLE_SCHEMA::TEXT, -- schema_name 214 | TG_TABLE_NAME::TEXT, -- table_name 215 | TG_RELID, -- relation OID for faster searches 216 | session_user::TEXT, -- session_user_name 217 | current_user::TEXT, -- current_user_name 218 | current_timestamp, -- action_tstamp_tx 219 | statement_timestamp(), -- action_tstamp_stm 220 | clock_timestamp(), -- action_tstamp_clk 221 | txid_current(), -- transaction ID 222 | current_setting('audit.application_name', true), -- client application 223 | current_setting('audit.application_user_name', true), -- client user name 224 | inet_client_addr(), -- client_addr 225 | inet_client_port(), -- client_port 226 | current_query(), -- top-level query or queries 227 | substring(TG_OP, 1, 1), -- action 228 | NULL, -- row_data 229 | NULL, -- changed_fields 230 | 'f' -- statement_only 231 | ); 232 | 233 | IF NOT TG_ARGV[0]::BOOLEAN IS DISTINCT FROM 'f'::BOOLEAN THEN 234 | audit_row.client_query = NULL; 235 | END IF; 236 | 237 | IF TG_ARGV[1] IS NOT NULL THEN 238 | excluded_cols = TG_ARGV[1]::TEXT[]; 239 | END IF; 240 | 241 | IF (TG_OP = 'INSERT' AND TG_LEVEL = 'ROW') THEN 242 | audit_row.changed_fields = to_jsonb(NEW.*) - excluded_cols; 243 | ELSIF (TG_OP = 'UPDATE' AND TG_LEVEL = 'ROW') THEN 244 | audit_row.row_data = to_jsonb(OLD.*) - excluded_cols; 245 | audit_row.changed_fields = 246 | (to_jsonb(NEW.*) - audit_row.row_data) - excluded_cols; 247 | IF audit_row.changed_fields = '{}'::JSONB THEN 248 | -- All changed fields are ignored. Skip this update. 249 | RETURN NULL; 250 | END IF; 251 | ELSIF (TG_OP = 'DELETE' AND TG_LEVEL = 'ROW') THEN 252 | audit_row.row_data = to_jsonb(OLD.*) - excluded_cols; 253 | ELSIF (TG_LEVEL = 'STATEMENT' AND 254 | TG_OP IN ('INSERT','UPDATE','DELETE','TRUNCATE')) THEN 255 | audit_row.statement_only = 't'; 256 | ELSE 257 | RAISE EXCEPTION '[audit.if_modified_func] - Trigger func added as trigger ' 258 | 'for unhandled case: %, %', TG_OP, TG_LEVEL; 259 | RETURN NULL; 260 | END IF; 261 | INSERT INTO audit.log VALUES (audit_row.*); 262 | RETURN NULL; 263 | END; 264 | $$; 265 | 266 | 267 | COMMENT ON FUNCTION audit.if_modified_func() IS $$ 268 | Track changes to a table at the statement and/or row level. 269 | 270 | Optional parameters to trigger in CREATE TRIGGER call: 271 | 272 | param 0: BOOLEAN, whether to log the query text. Default 't'. 273 | 274 | param 1: TEXT[], columns to ignore in updates. Default []. 275 | 276 | Updates to ignored cols are omitted from changed_fields. 277 | 278 | Updates with only ignored cols changed are not inserted 279 | into the audit log. 280 | 281 | Almost all the processing work is still done for updates 282 | that ignored. If you need to save the load, you need to use 283 | WHEN clause on the trigger instead. 284 | 285 | No warning or error is issued if ignored_cols contains columns 286 | that do not exist in the target table. This lets you specify 287 | a standard set of ignored columns. 288 | 289 | There is no parameter to disable logging of values. Add this trigger as 290 | a 'FOR EACH STATEMENT' rather than 'FOR EACH ROW' trigger if you do not 291 | want to log row values. 292 | 293 | Note that the user name logged is the login role for the session. The audit 294 | trigger cannot obtain the active role because it is reset by 295 | the SECURITY DEFINER invocation of the audit trigger its self. 296 | $$; 297 | 298 | --- 299 | --- Enables tracking on a table by generating and attaching a trigger 300 | --- 301 | CREATE OR REPLACE FUNCTION audit.audit_table( 302 | target_table REGCLASS, 303 | audit_rows BOOLEAN, 304 | audit_query_text BOOLEAN, 305 | ignored_cols TEXT[] 306 | ) 307 | RETURNS VOID 308 | LANGUAGE 'plpgsql' 309 | AS $$ 310 | DECLARE 311 | stm_targets TEXT = 'INSERT OR UPDATE OR DELETE OR TRUNCATE'; 312 | _q_txt TEXT; 313 | _ignored_cols_snip TEXT = ''; 314 | BEGIN 315 | EXECUTE 'DROP TRIGGER IF EXISTS audit_trigger_row ON ' || target_table::TEXT; 316 | EXECUTE 'DROP TRIGGER IF EXISTS audit_trigger_stm ON ' || target_table::TEXT; 317 | 318 | IF audit_rows THEN 319 | IF array_length(ignored_cols,1) > 0 THEN 320 | _ignored_cols_snip = ', ' || quote_literal(ignored_cols); 321 | END IF; 322 | _q_txt = 'CREATE TRIGGER audit_trigger_row ' 323 | 'AFTER INSERT OR UPDATE OR DELETE ON ' || 324 | target_table::TEXT || 325 | ' FOR EACH ROW EXECUTE PROCEDURE audit.if_modified_func(' || 326 | quote_literal(audit_query_text) || 327 | _ignored_cols_snip || 328 | ');'; 329 | RAISE NOTICE '%', _q_txt; 330 | EXECUTE _q_txt; 331 | stm_targets = 'TRUNCATE'; 332 | END IF; 333 | 334 | _q_txt = 'CREATE TRIGGER audit_trigger_stm AFTER ' || stm_targets || ' ON ' || 335 | target_table || 336 | ' FOR EACH STATEMENT EXECUTE PROCEDURE audit.if_modified_func('|| 337 | quote_literal(audit_query_text) || ');'; 338 | RAISE NOTICE '%', _q_txt; 339 | EXECUTE _q_txt; 340 | END; 341 | $$; 342 | 343 | COMMENT ON FUNCTION audit.audit_table(REGCLASS, BOOLEAN, BOOLEAN, TEXT[]) IS $$ 344 | Add auditing support to a table. 345 | 346 | Arguments: 347 | target_table: Table name, schema qualified if not on search_path 348 | audit_rows: Record each row change, or only audit at a statement level 349 | audit_query_text: Record the text of the client query that triggered 350 | the audit event? 351 | ignored_cols: Columns to exclude from update diffs, 352 | ignore updates that change only ignored cols. 353 | $$; 354 | 355 | -- 356 | -- Pg doesn't allow variadic calls with 0 params, so provide a wrapper 357 | -- 358 | CREATE OR REPLACE FUNCTION audit.audit_table( 359 | target_table REGCLASS, 360 | audit_rows BOOLEAN, 361 | audit_query_text BOOLEAN 362 | ) 363 | RETURNS VOID 364 | LANGUAGE SQL 365 | AS $$ 366 | SELECT audit.audit_table($1, $2, $3, ARRAY[]::TEXT[]); 367 | $$; 368 | 369 | -- 370 | -- And provide a convenience call wrapper for the simplest case 371 | -- of row-level logging with no excluded cols and query logging enabled. 372 | -- 373 | CREATE OR REPLACE FUNCTION audit.audit_table(target_table REGCLASS) 374 | RETURNS VOID 375 | LANGUAGE 'sql' 376 | AS $$ 377 | SELECT audit.audit_table($1, BOOLEAN 't', BOOLEAN 't'); 378 | $$; 379 | 380 | COMMENT ON FUNCTION audit.audit_table(REGCLASS) IS $$ 381 | Add auditing support to the given table. Row-level changes will be logged with 382 | full client query text. No cols are ignored. 383 | $$; 384 | -------------------------------------------------------------------------------- /sql/pg-audit-json--1.0.2.sql: -------------------------------------------------------------------------------- 1 | -- 2 | -- An audit history is important on most tables. Provide an audit trigger that 3 | -- logs to a dedicated audit table for the major relations. 4 | -- 5 | 6 | -- Complain if script is sourced in psql, rather than via CREATE EXTENSION 7 | \echo Use "CREATE EXTENSION pg-audit-json" to load this file. \quit 8 | 9 | -- 10 | -- Implements missing "-" JSONB operators that are available in HSTORE 11 | -- 12 | 13 | -- 14 | -- Implements "JSONB- TEXT[]" operation to remove a list of keys 15 | -- 16 | -- Note: This method will be a supported operation of PostgreSQL 10 17 | -- 18 | -- Credit: 19 | -- http://schinckel.net/2014/09/29/adding-json%28b%29-operators-to-postgresql/ 20 | -- 21 | CREATE OR REPLACE FUNCTION "jsonb_minus" ( "left" JSONB, "keys" TEXT[] ) 22 | RETURNS JSONB 23 | LANGUAGE SQL 24 | IMMUTABLE 25 | STRICT 26 | AS $$ 27 | SELECT 28 | CASE 29 | WHEN "left" ?| "keys" 30 | THEN COALESCE( 31 | (SELECT ('{' || 32 | string_agg(to_json("key")::TEXT || ':' || "value", ',') || 33 | '}') 34 | FROM jsonb_each("left") 35 | WHERE "key" <> ALL ("keys")), 36 | '{}' 37 | )::JSONB 38 | ELSE "left" 39 | END 40 | $$; 41 | 42 | CREATE OPERATOR - ( 43 | LEFTARG = JSONB, 44 | RIGHTARG = TEXT[], 45 | PROCEDURE = jsonb_minus 46 | ); 47 | 48 | COMMENT ON FUNCTION jsonb_minus(JSONB, TEXT[]) IS 'Delete specificed keys'; 49 | 50 | COMMENT ON OPERATOR - (JSONB, TEXT[]) IS 'Delete specified keys'; 51 | 52 | -- 53 | -- Implements "JSONB- JSONB" operation to recursively delete matching pairs. 54 | -- 55 | -- Credit: 56 | -- http://coussej.github.io/2016/05/24/A-Minus-Operator-For-PostgreSQLs-JSONB/ 57 | -- 58 | 59 | CREATE OR REPLACE FUNCTION "jsonb_minus" ( "left" JSONB, "right" JSONB ) 60 | RETURNS JSONB 61 | LANGUAGE SQL 62 | IMMUTABLE 63 | STRICT 64 | AS $$ 65 | SELECT 66 | COALESCE(json_object_agg( 67 | "key", 68 | CASE 69 | -- if the value is an object and the value of the second argument is 70 | -- not null, we do a recursion 71 | WHEN jsonb_typeof("value") = 'object' AND "right" -> "key" IS NOT NULL 72 | THEN jsonb_minus("value", "right" -> "key") 73 | -- for all the other types, we just return the value 74 | ELSE "value" 75 | END 76 | ), '{}')::JSONB 77 | FROM 78 | jsonb_each("left") 79 | WHERE 80 | "left" -> "key" <> "right" -> "key" 81 | OR "right" -> "key" IS NULL 82 | $$; 83 | 84 | CREATE OPERATOR - ( 85 | LEFTARG = JSONB, 86 | RIGHTARG = JSONB, 87 | PROCEDURE = jsonb_minus 88 | ); 89 | 90 | COMMENT ON FUNCTION jsonb_minus(JSONB, JSONB) 91 | IS 'Delete matching pairs in the right argument from the left argument'; 92 | 93 | COMMENT ON OPERATOR - (JSONB, JSONB) 94 | IS 'Delete matching pairs in the right argument from the left argument'; 95 | 96 | 97 | CREATE SCHEMA audit; 98 | REVOKE ALL ON SCHEMA audit FROM public; 99 | COMMENT ON SCHEMA audit 100 | IS 'Out-of-table audit/history logging tables and trigger functions'; 101 | 102 | -- 103 | -- Audited data. Lots of information is available, it's just a matter of how 104 | -- much you really want to record. See: 105 | -- 106 | -- http://www.postgresql.org/docs/9.1/static/functions-info.html 107 | -- 108 | -- Remember, every column you add takes up more audit table space and slows 109 | -- audit inserts. 110 | -- 111 | -- Every index you add has a big impact too, so avoid adding indexes to the 112 | -- audit table unless you REALLY need them. The hstore GIST indexes are 113 | -- particularly expensive. 114 | -- 115 | -- It is sometimes worth copying the audit table, or a coarse subset of it that 116 | -- you're interested in, into a temporary table where you CREATE any useful 117 | -- indexes and do your analysis. 118 | -- 119 | CREATE TABLE audit.log ( 120 | id BIGSERIAL PRIMARY KEY, 121 | schema_name TEXT NOT NULL, 122 | table_name TEXT NOT NULL, 123 | relid OID NOT NULL, 124 | session_user_name TEXT NOT NULL, 125 | current_user_name TEXT NOT NULL, 126 | action_tstamp_tx TIMESTAMP WITH TIME ZONE NOT NULL, 127 | action_tstamp_stm TIMESTAMP WITH TIME ZONE NOT NULL, 128 | action_tstamp_clk TIMESTAMP WITH TIME ZONE NOT NULL, 129 | transaction_id BIGINT NOT NULL, 130 | application_name TEXT, 131 | application_user_name TEXT, 132 | client_addr INET, 133 | client_port INTEGER, 134 | client_query TEXT, 135 | action TEXT NOT NULL CHECK (action IN ('I','D','U', 'T')), 136 | row_data JSONB, 137 | changed_fields JSONB, 138 | statement_only BOOLEAN NOT NULL 139 | ); 140 | 141 | REVOKE ALL ON audit.log FROM public; 142 | 143 | COMMENT ON TABLE audit.log 144 | IS 'History of auditable actions on audited tables'; 145 | COMMENT ON COLUMN audit.log.id 146 | IS 'Unique identifier for each auditable event'; 147 | COMMENT ON COLUMN audit.log.schema_name 148 | IS 'Database schema audited table for this event is in'; 149 | COMMENT ON COLUMN audit.log.table_name 150 | IS 'Non-schema-qualified table name of table event occured in'; 151 | COMMENT ON COLUMN audit.log.relid 152 | IS 'Table OID. Changes with drop/create. Get with ''tablename''::REGCLASS'; 153 | COMMENT ON COLUMN audit.log.session_user_name 154 | IS 'Login / session user whose statement caused the audited event'; 155 | COMMENT ON COLUMN audit.log.current_user_name 156 | IS 'Effective user that cased audited event (if authorization level changed)'; 157 | COMMENT ON COLUMN audit.log.action_tstamp_tx 158 | IS 'Transaction start timestamp for tx in which audited event occurred'; 159 | COMMENT ON COLUMN audit.log.action_tstamp_stm 160 | IS 'Statement start timestamp for tx in which audited event occurred'; 161 | COMMENT ON COLUMN audit.log.action_tstamp_clk 162 | IS 'Wall clock time at which audited event''s trigger call occurred'; 163 | COMMENT ON COLUMN audit.log.transaction_id 164 | IS 'Identifier of transaction that made the change. Unique when paired with action_tstamp_tx.'; 165 | COMMENT ON COLUMN audit.log.client_addr 166 | IS 'IP address of client that issued query. Null for unix domain socket.'; 167 | COMMENT ON COLUMN audit.log.client_port 168 | IS 'Port address of client that issued query. Undefined for unix socket.'; 169 | COMMENT ON COLUMN audit.log.client_query 170 | IS 'Top-level query that caused this auditable event. May be more than one.'; 171 | COMMENT ON COLUMN audit.log.application_name 172 | IS 'Client-set session application name when this audit event occurred.'; 173 | COMMENT ON COLUMN audit.log.application_user_name 174 | IS 'Client-set session application user when this audit event occurred.'; 175 | COMMENT ON COLUMN audit.log.action 176 | IS 'Action type; I = insert, D = delete, U = update, T = truncate'; 177 | COMMENT ON COLUMN audit.log.row_data 178 | IS 'Record value. Null for statement-level trigger. For INSERT this is null. For DELETE and UPDATE it is the old tuple.'; 179 | COMMENT ON COLUMN audit.log.changed_fields 180 | IS 'New values of fields for INSERT or changed by UPDATE. Null for DELETE'; 181 | COMMENT ON COLUMN audit.log.statement_only 182 | IS '''t'' if audit event is from an FOR EACH STATEMENT trigger, ''f'' for FOR EACH ROW'; 183 | 184 | CREATE INDEX log_relid_idx ON audit.log(relid); 185 | CREATE INDEX log_action_tstamp_tx_stm_idx ON audit.log(action_tstamp_stm); 186 | CREATE INDEX log_action_idx ON audit.log(action); 187 | 188 | -- 189 | -- Allow the user of the extension to create a backup of the audit log data 190 | -- 191 | SELECT pg_catalog.pg_extension_config_dump('audit.log', ''); 192 | SELECT pg_catalog.pg_extension_config_dump('audit.log_id_seq', ''); 193 | 194 | CREATE OR REPLACE FUNCTION audit.if_modified_func() 195 | RETURNS TRIGGER 196 | LANGUAGE plpgsql 197 | SECURITY DEFINER 198 | SET search_path = pg_catalog, public 199 | AS $$ 200 | DECLARE 201 | audit_row audit.log; 202 | include_values BOOLEAN; 203 | log_diffs BOOLEAN; 204 | h_old JSONB; 205 | h_new JSONB; 206 | excluded_cols TEXT[] = ARRAY[]::TEXT[]; 207 | BEGIN 208 | IF TG_WHEN <> 'AFTER' THEN 209 | RAISE EXCEPTION 'audit.if_modified_func() may only run as an AFTER trigger'; 210 | END IF; 211 | 212 | audit_row = ROW( 213 | nextval('audit.log_id_seq'), -- id 214 | TG_TABLE_SCHEMA::TEXT, -- schema_name 215 | TG_TABLE_NAME::TEXT, -- table_name 216 | TG_RELID, -- relation OID for faster searches 217 | session_user::TEXT, -- session_user_name 218 | current_user::TEXT, -- current_user_name 219 | current_timestamp, -- action_tstamp_tx 220 | statement_timestamp(), -- action_tstamp_stm 221 | clock_timestamp(), -- action_tstamp_clk 222 | txid_current(), -- transaction ID 223 | current_setting('audit.application_name', true), -- client application 224 | current_setting('audit.application_user_name', true), -- client user name 225 | inet_client_addr(), -- client_addr 226 | inet_client_port(), -- client_port 227 | current_query(), -- top-level query or queries 228 | substring(TG_OP, 1, 1), -- action 229 | NULL, -- row_data 230 | NULL, -- changed_fields 231 | 'f' -- statement_only 232 | ); 233 | 234 | IF NOT TG_ARGV[0]::BOOLEAN IS DISTINCT FROM 'f'::BOOLEAN THEN 235 | audit_row.client_query = NULL; 236 | END IF; 237 | 238 | IF TG_ARGV[1] IS NOT NULL THEN 239 | excluded_cols = TG_ARGV[1]::TEXT[]; 240 | END IF; 241 | 242 | IF (TG_OP = 'INSERT' AND TG_LEVEL = 'ROW') THEN 243 | audit_row.changed_fields = to_jsonb(NEW.*) - excluded_cols; 244 | ELSIF (TG_OP = 'UPDATE' AND TG_LEVEL = 'ROW') THEN 245 | audit_row.row_data = to_jsonb(OLD.*) - excluded_cols; 246 | audit_row.changed_fields = 247 | (to_jsonb(NEW.*) - audit_row.row_data) - excluded_cols; 248 | IF audit_row.changed_fields = '{}'::JSONB THEN 249 | -- All changed fields are ignored. Skip this update. 250 | RETURN NULL; 251 | END IF; 252 | ELSIF (TG_OP = 'DELETE' AND TG_LEVEL = 'ROW') THEN 253 | audit_row.row_data = to_jsonb(OLD.*) - excluded_cols; 254 | ELSIF (TG_LEVEL = 'STATEMENT' AND 255 | TG_OP IN ('INSERT','UPDATE','DELETE','TRUNCATE')) THEN 256 | audit_row.statement_only = 't'; 257 | ELSE 258 | RAISE EXCEPTION '[audit.if_modified_func] - Trigger func added as trigger ' 259 | 'for unhandled case: %, %', TG_OP, TG_LEVEL; 260 | RETURN NULL; 261 | END IF; 262 | INSERT INTO audit.log VALUES (audit_row.*); 263 | RETURN NULL; 264 | END; 265 | $$; 266 | 267 | 268 | COMMENT ON FUNCTION audit.if_modified_func() IS $$ 269 | Track changes to a table at the statement and/or row level. 270 | 271 | Optional parameters to trigger in CREATE TRIGGER call: 272 | 273 | param 0: BOOLEAN, whether to log the query text. Default 't'. 274 | 275 | param 1: TEXT[], columns to ignore in updates. Default []. 276 | 277 | Updates to ignored cols are omitted from changed_fields. 278 | 279 | Updates with only ignored cols changed are not inserted 280 | into the audit log. 281 | 282 | Almost all the processing work is still done for updates 283 | that ignored. If you need to save the load, you need to use 284 | WHEN clause on the trigger instead. 285 | 286 | No warning or error is issued if ignored_cols contains columns 287 | that do not exist in the target table. This lets you specify 288 | a standard set of ignored columns. 289 | 290 | There is no parameter to disable logging of values. Add this trigger as 291 | a 'FOR EACH STATEMENT' rather than 'FOR EACH ROW' trigger if you do not 292 | want to log row values. 293 | 294 | Note that the user name logged is the login role for the session. The audit 295 | trigger cannot obtain the active role because it is reset by 296 | the SECURITY DEFINER invocation of the audit trigger its self. 297 | $$; 298 | 299 | --- 300 | --- Enables tracking on a table by generating and attaching a trigger 301 | --- 302 | CREATE OR REPLACE FUNCTION audit.audit_table( 303 | target_table REGCLASS, 304 | audit_rows BOOLEAN, 305 | audit_query_text BOOLEAN, 306 | ignored_cols TEXT[] 307 | ) 308 | RETURNS VOID 309 | LANGUAGE 'plpgsql' 310 | AS $$ 311 | DECLARE 312 | stm_targets TEXT = 'INSERT OR UPDATE OR DELETE OR TRUNCATE'; 313 | _q_txt TEXT; 314 | _ignored_cols_snip TEXT = ''; 315 | BEGIN 316 | EXECUTE 'DROP TRIGGER IF EXISTS audit_trigger_row ON ' || target_table::TEXT; 317 | EXECUTE 'DROP TRIGGER IF EXISTS audit_trigger_stm ON ' || target_table::TEXT; 318 | 319 | IF audit_rows THEN 320 | IF array_length(ignored_cols,1) > 0 THEN 321 | _ignored_cols_snip = ', ' || quote_literal(ignored_cols); 322 | END IF; 323 | _q_txt = 'CREATE TRIGGER audit_trigger_row ' 324 | 'AFTER INSERT OR UPDATE OR DELETE ON ' || 325 | target_table::TEXT || 326 | ' FOR EACH ROW EXECUTE PROCEDURE audit.if_modified_func(' || 327 | quote_literal(audit_query_text) || 328 | _ignored_cols_snip || 329 | ');'; 330 | RAISE NOTICE '%', _q_txt; 331 | EXECUTE _q_txt; 332 | stm_targets = 'TRUNCATE'; 333 | END IF; 334 | 335 | _q_txt = 'CREATE TRIGGER audit_trigger_stm AFTER ' || stm_targets || ' ON ' || 336 | target_table || 337 | ' FOR EACH STATEMENT EXECUTE PROCEDURE audit.if_modified_func('|| 338 | quote_literal(audit_query_text) || ');'; 339 | RAISE NOTICE '%', _q_txt; 340 | EXECUTE _q_txt; 341 | END; 342 | $$; 343 | 344 | COMMENT ON FUNCTION audit.audit_table(REGCLASS, BOOLEAN, BOOLEAN, TEXT[]) IS $$ 345 | Add auditing support to a table. 346 | 347 | Arguments: 348 | target_table: Table name, schema qualified if not on search_path 349 | audit_rows: Record each row change, or only audit at a statement level 350 | audit_query_text: Record the text of the client query that triggered 351 | the audit event? 352 | ignored_cols: Columns to exclude from update diffs, 353 | ignore updates that change only ignored cols. 354 | $$; 355 | 356 | -- 357 | -- Pg doesn't allow variadic calls with 0 params, so provide a wrapper 358 | -- 359 | CREATE OR REPLACE FUNCTION audit.audit_table( 360 | target_table REGCLASS, 361 | audit_rows BOOLEAN, 362 | audit_query_text BOOLEAN 363 | ) 364 | RETURNS VOID 365 | LANGUAGE SQL 366 | AS $$ 367 | SELECT audit.audit_table($1, $2, $3, ARRAY[]::TEXT[]); 368 | $$; 369 | 370 | -- 371 | -- And provide a convenience call wrapper for the simplest case 372 | -- of row-level logging with no excluded cols and query logging enabled. 373 | -- 374 | CREATE OR REPLACE FUNCTION audit.audit_table(target_table REGCLASS) 375 | RETURNS VOID 376 | LANGUAGE 'sql' 377 | AS $$ 378 | SELECT audit.audit_table($1, BOOLEAN 't', BOOLEAN 't'); 379 | $$; 380 | 381 | COMMENT ON FUNCTION audit.audit_table(REGCLASS) IS $$ 382 | Add auditing support to the given table. Row-level changes will be logged with 383 | full client query text. No cols are ignored. 384 | $$; 385 | -------------------------------------------------------------------------------- /sql/uninstall_pg-audit-json.sql: -------------------------------------------------------------------------------- 1 | DROP FUNCTION jsonb_minus(JSONB, TEXT[]) CASCADE; 2 | DROP FUNCTION jsonb_minus(JSONB, JSONB) CASCADE; 3 | DROP SCHEMA audit CASCADE; 4 | -------------------------------------------------------------------------------- /test/expected/audit_test.out: -------------------------------------------------------------------------------- 1 | CREATE EXTENSION "pg-audit-json"; 2 | SET client_min_messages TO WARNING; 3 | CREATE TABLE foo ( 4 | id BIGSERIAL PRIMARY KEY, 5 | a INTEGER, 6 | b INTEGER, 7 | c INTEGER 8 | ); 9 | SELECT audit.audit_table('foo', true, true, '{id}'::text[]); 10 | audit_table 11 | ------------- 12 | 13 | (1 row) 14 | 15 | -- 16 | -- Basic INSERT/UPDATE/DELETE 17 | -- 18 | --- insert 19 | INSERT INTO foo (a, b, c) VALUES (1, 2, 3) RETURNING id AS record_id \gset 20 | SELECT row_data, changed_fields FROM audit.log ORDER BY id DESC LIMIT 1; 21 | row_data | changed_fields 22 | ----------+-------------------------- 23 | | {"a": 1, "b": 2, "c": 3} 24 | (1 row) 25 | 26 | --- update 27 | UPDATE foo SET b = 99 WHERE id = :record_id; 28 | SELECT row_data, changed_fields FROM audit.log ORDER BY id DESC LIMIT 1; 29 | row_data | changed_fields 30 | --------------------------+---------------- 31 | {"a": 1, "b": 2, "c": 3} | {"b": 99} 32 | (1 row) 33 | 34 | --- delete 35 | DELETE FROM foo WHERE id = :record_id; 36 | SELECT row_data, changed_fields FROM audit.log ORDER BY id DESC LIMIT 1; 37 | row_data | changed_fields 38 | ---------------------------+---------------- 39 | {"a": 1, "b": 99, "c": 3} | 40 | (1 row) 41 | 42 | -- 43 | -- With table modifications 44 | -- 45 | --- insert 46 | INSERT INTO foo (a, b, c) VALUES (4, 5, 6) RETURNING id AS record_id \gset 47 | SELECT row_data, changed_fields FROM audit.log ORDER BY id DESC LIMIT 1; 48 | row_data | changed_fields 49 | ----------+-------------------------- 50 | | {"a": 4, "b": 5, "c": 6} 51 | (1 row) 52 | 53 | --- add column to table and update record 54 | ALTER TABLE foo ADD COLUMN d INTEGER; 55 | UPDATE foo SET d = 7 WHERE id = :record_id; 56 | SELECT row_data, changed_fields FROM audit.log ORDER BY id DESC LIMIT 1; 57 | row_data | changed_fields 58 | -------------------------------------+---------------- 59 | {"a": 4, "b": 5, "c": 6, "d": null} | {"d": 7} 60 | (1 row) 61 | 62 | --- remove column from table and update record 63 | ALTER TABLE foo DROP COLUMN d; 64 | UPDATE foo SET c = 99 WHERE id = :record_id; 65 | SELECT row_data, changed_fields FROM audit.log ORDER BY id DESC LIMIT 1; 66 | row_data | changed_fields 67 | --------------------------+---------------- 68 | {"a": 4, "b": 5, "c": 6} | {"c": 99} 69 | (1 row) 70 | 71 | --- delete 72 | DELETE FROM foo WHERE id = :record_id; 73 | SELECT row_data, changed_fields FROM audit.log ORDER BY id DESC LIMIT 1; 74 | row_data | changed_fields 75 | ---------------------------+---------------- 76 | {"a": 4, "b": 5, "c": 99} | 77 | (1 row) 78 | 79 | DROP TABLE foo; 80 | DROP EXTENSION "pg-audit-json"; 81 | -------------------------------------------------------------------------------- /test/expected/minus_test.out: -------------------------------------------------------------------------------- 1 | CREATE EXTENSION "pg-audit-json"; 2 | -- Remove one key 3 | SELECT '{"a": 1, "b": 2, "c": 3}'::jsonb - '{a}'::text[]; 4 | ?column? 5 | ------------------ 6 | {"b": 2, "c": 3} 7 | (1 row) 8 | 9 | -- Remove multiple keys 10 | SELECT '{"a": 1, "b": 2, "c": 3}'::jsonb - '{a,c}'::text[]; 11 | ?column? 12 | ---------- 13 | {"b": 2} 14 | (1 row) 15 | 16 | -- Test usage scenario where NEW - OLD 17 | -- Removed c 18 | SELECT '{"a": 1, "b": 2}'::jsonb 19 | - '{"a": 1, "b": 2, "c": 3}'::jsonb; 20 | ?column? 21 | ---------- 22 | {} 23 | (1 row) 24 | 25 | -- Changed b 26 | SELECT '{"a": 1, "b": 99, "c": 3}'::jsonb 27 | - '{"a": 1, "b": 2, "c": 3}'::jsonb; 28 | ?column? 29 | ----------- 30 | {"b": 99} 31 | (1 row) 32 | 33 | -- Added d 34 | SELECT '{"a": 1, "b": 2, "c": 3, "d": 4}'::jsonb 35 | - '{"a": 1, "b": 2, "c": 3}'::jsonb; 36 | ?column? 37 | ---------- 38 | {"d": 4} 39 | (1 row) 40 | 41 | -- Recursive changed b->c 42 | SELECT '{"a":1, "b":{"c":321, "d":"test"}}'::jsonb 43 | - '{"a":1, "b":{"c":123, "d":"test"}}'::jsonb; 44 | ?column? 45 | ------------------- 46 | {"b": {"c": 321}} 47 | (1 row) 48 | 49 | DROP EXTENSION "pg-audit-json"; 50 | -------------------------------------------------------------------------------- /test/sql/audit_test.sql: -------------------------------------------------------------------------------- 1 | CREATE EXTENSION "pg-audit-json"; 2 | SET client_min_messages TO WARNING; 3 | 4 | CREATE TABLE foo ( 5 | id BIGSERIAL PRIMARY KEY, 6 | a INTEGER, 7 | b INTEGER, 8 | c INTEGER 9 | ); 10 | 11 | SELECT audit.audit_table('foo', true, true, '{id}'::text[]); 12 | 13 | -- 14 | -- Basic INSERT/UPDATE/DELETE 15 | -- 16 | 17 | --- insert 18 | INSERT INTO foo (a, b, c) VALUES (1, 2, 3) RETURNING id AS record_id \gset 19 | SELECT row_data, changed_fields FROM audit.log ORDER BY id DESC LIMIT 1; 20 | 21 | --- update 22 | UPDATE foo SET b = 99 WHERE id = :record_id; 23 | SELECT row_data, changed_fields FROM audit.log ORDER BY id DESC LIMIT 1; 24 | 25 | --- delete 26 | DELETE FROM foo WHERE id = :record_id; 27 | SELECT row_data, changed_fields FROM audit.log ORDER BY id DESC LIMIT 1; 28 | 29 | -- 30 | -- With table modifications 31 | -- 32 | 33 | --- insert 34 | INSERT INTO foo (a, b, c) VALUES (4, 5, 6) RETURNING id AS record_id \gset 35 | SELECT row_data, changed_fields FROM audit.log ORDER BY id DESC LIMIT 1; 36 | 37 | --- add column to table and update record 38 | ALTER TABLE foo ADD COLUMN d INTEGER; 39 | UPDATE foo SET d = 7 WHERE id = :record_id; 40 | SELECT row_data, changed_fields FROM audit.log ORDER BY id DESC LIMIT 1; 41 | 42 | --- remove column from table and update record 43 | ALTER TABLE foo DROP COLUMN d; 44 | UPDATE foo SET c = 99 WHERE id = :record_id; 45 | SELECT row_data, changed_fields FROM audit.log ORDER BY id DESC LIMIT 1; 46 | 47 | --- delete 48 | DELETE FROM foo WHERE id = :record_id; 49 | SELECT row_data, changed_fields FROM audit.log ORDER BY id DESC LIMIT 1; 50 | 51 | DROP TABLE foo; 52 | 53 | DROP EXTENSION "pg-audit-json"; 54 | -------------------------------------------------------------------------------- /test/sql/minus_test.sql: -------------------------------------------------------------------------------- 1 | CREATE EXTENSION "pg-audit-json"; 2 | 3 | -- Remove one key 4 | SELECT '{"a": 1, "b": 2, "c": 3}'::jsonb - '{a}'::text[]; 5 | 6 | -- Remove multiple keys 7 | SELECT '{"a": 1, "b": 2, "c": 3}'::jsonb - '{a,c}'::text[]; 8 | 9 | -- Test usage scenario where NEW - OLD 10 | 11 | -- Removed c 12 | SELECT '{"a": 1, "b": 2}'::jsonb 13 | - '{"a": 1, "b": 2, "c": 3}'::jsonb; 14 | 15 | -- Changed b 16 | SELECT '{"a": 1, "b": 99, "c": 3}'::jsonb 17 | - '{"a": 1, "b": 2, "c": 3}'::jsonb; 18 | 19 | -- Added d 20 | SELECT '{"a": 1, "b": 2, "c": 3, "d": 4}'::jsonb 21 | - '{"a": 1, "b": 2, "c": 3}'::jsonb; 22 | 23 | -- Recursive changed b->c 24 | SELECT '{"a":1, "b":{"c":321, "d":"test"}}'::jsonb 25 | - '{"a":1, "b":{"c":123, "d":"test"}}'::jsonb; 26 | 27 | DROP EXTENSION "pg-audit-json"; 28 | --------------------------------------------------------------------------------