mirror of https://github.com/postgres/postgres
This extension provides detailed logging classes, ability to control logging at a per-object level, and includes fully-qualified object names for logged statements (DML and DDL) in independent fields of the log output. Authors: Ian Barwick, Abhijit Menon-Sen, David Steele Reviews by: Robert Haas, Tatsuo Ishii, Sawada Masahiko, Fujii Masao, Simon Riggs Discussion with: Josh Berkus, Jaime Casanova, Peter Eisentraut, David Fetter, Yeb Havinga, Alvaro Herrera, Petr Jelinek, Tom Lane, MauMau, Bruce Momjian, Jim Nasby, Michael Paquier, Fabrízio de Royes Mello, Neil Tiffinpull/14/head
parent
9660710e2f
commit
ac52bb0442
@ -0,0 +1,5 @@ |
||||
log/ |
||||
results/ |
||||
tmp_check/ |
||||
regression.diffs |
||||
regression.out |
@ -0,0 +1,21 @@ |
||||
# pg_audit/Makefile
|
||||
|
||||
MODULE = pg_audit
|
||||
MODULE_big = pg_audit
|
||||
OBJS = pg_audit.o
|
||||
|
||||
EXTENSION = pg_audit
|
||||
REGRESS = pg_audit
|
||||
REGRESS_OPTS = --temp-config=$(top_srcdir)/contrib/pg_audit/pg_audit.conf
|
||||
DATA = pg_audit--1.0.0.sql
|
||||
|
||||
ifdef USE_PGXS |
||||
PG_CONFIG = pg_config
|
||||
PGXS := $(shell $(PG_CONFIG) --pgxs)
|
||||
include $(PGXS) |
||||
else |
||||
subdir = contrib/pg_audit
|
||||
top_builddir = ../..
|
||||
include $(top_builddir)/src/Makefile.global |
||||
include $(top_srcdir)/contrib/contrib-global.mk |
||||
endif |
@ -0,0 +1,964 @@ |
||||
-- Load pg_audit module |
||||
create extension pg_audit; |
||||
-- |
||||
-- Audit log fields are: |
||||
-- AUDIT_TYPE - SESSION or OBJECT |
||||
-- STATEMENT_ID - ID of the statement in the current backend |
||||
-- SUBSTATEMENT_ID - ID of the substatement in the current backend |
||||
-- CLASS - Class of statement being logged (e.g. ROLE, READ, WRITE) |
||||
-- COMMAND - e.g. SELECT, CREATE ROLE, UPDATE |
||||
-- OBJECT_TYPE - When available, type of object acted on (e.g. TABLE, VIEW) |
||||
-- OBJECT_NAME - When available, fully-qualified table of object |
||||
-- STATEMENT - The statement being logged |
||||
-- PARAMETER - If parameter logging is requested, they will follow the |
||||
-- statement |
||||
-- |
||||
-- Create a superuser role that we know the name of for testing |
||||
CREATE USER super SUPERUSER; |
||||
ALTER ROLE super SET pg_audit.log = 'Role'; |
||||
ALTER ROLE super SET pg_audit.log_level = 'notice'; |
||||
\connect contrib_regression super; |
||||
-- |
||||
-- Create auditor role |
||||
CREATE ROLE auditor; |
||||
NOTICE: AUDIT: SESSION,1,1,ROLE,CREATE ROLE,,,CREATE ROLE auditor;,<not logged> |
||||
-- |
||||
-- Create first test user |
||||
CREATE USER user1; |
||||
NOTICE: AUDIT: SESSION,2,1,ROLE,CREATE ROLE,,,CREATE USER user1;,<not logged> |
||||
ALTER ROLE user1 SET pg_audit.log = 'ddl, ROLE'; |
||||
NOTICE: AUDIT: SESSION,3,1,ROLE,ALTER ROLE,,,"ALTER ROLE user1 SET pg_audit.log = 'ddl, ROLE';",<not logged> |
||||
ALTER ROLE user1 SET pg_audit.log_level = 'notice'; |
||||
NOTICE: AUDIT: SESSION,4,1,ROLE,ALTER ROLE,,,ALTER ROLE user1 SET pg_audit.log_level = 'notice';,<not logged> |
||||
-- |
||||
-- Create, select, drop (select will not be audited) |
||||
\connect contrib_regression user1 |
||||
CREATE TABLE public.test (id INT); |
||||
NOTICE: AUDIT: SESSION,1,1,DDL,CREATE TABLE,TABLE,public.test,CREATE TABLE public.test (id INT);,<not logged> |
||||
SELECT * FROM test; |
||||
id |
||||
---- |
||||
(0 rows) |
||||
|
||||
DROP TABLE test; |
||||
NOTICE: AUDIT: SESSION,2,1,DDL,DROP TABLE,TABLE,public.test,DROP TABLE test;,<not logged> |
||||
-- |
||||
-- Create second test user |
||||
\connect contrib_regression super |
||||
CREATE USER user2; |
||||
NOTICE: AUDIT: SESSION,1,1,ROLE,CREATE ROLE,,,CREATE USER user2;,<not logged> |
||||
ALTER ROLE user2 SET pg_audit.log = 'Read, writE'; |
||||
NOTICE: AUDIT: SESSION,2,1,ROLE,ALTER ROLE,,,"ALTER ROLE user2 SET pg_audit.log = 'Read, writE';",<not logged> |
||||
ALTER ROLE user2 SET pg_audit.log_catalog = OFF; |
||||
NOTICE: AUDIT: SESSION,3,1,ROLE,ALTER ROLE,,,ALTER ROLE user2 SET pg_audit.log_catalog = OFF;,<not logged> |
||||
ALTER ROLE user2 SET pg_audit.log_level = 'warning'; |
||||
NOTICE: AUDIT: SESSION,4,1,ROLE,ALTER ROLE,,,ALTER ROLE user2 SET pg_audit.log_level = 'warning';,<not logged> |
||||
ALTER ROLE user2 SET pg_audit.role = auditor; |
||||
NOTICE: AUDIT: SESSION,5,1,ROLE,ALTER ROLE,,,ALTER ROLE user2 SET pg_audit.role = auditor;,<not logged> |
||||
ALTER ROLE user2 SET pg_audit.log_statement_once = ON; |
||||
NOTICE: AUDIT: SESSION,6,1,ROLE,ALTER ROLE,,,ALTER ROLE user2 SET pg_audit.log_statement_once = ON;,<not logged> |
||||
\connect contrib_regression user2 |
||||
CREATE TABLE test2 (id INT); |
||||
GRANT SELECT ON TABLE public.test2 TO auditor; |
||||
-- |
||||
-- Role-based tests |
||||
CREATE TABLE test3 |
||||
( |
||||
id INT |
||||
); |
||||
SELECT count(*) |
||||
FROM |
||||
( |
||||
SELECT relname |
||||
FROM pg_class |
||||
LIMIT 1 |
||||
) SUBQUERY; |
||||
count |
||||
------- |
||||
1 |
||||
(1 row) |
||||
|
||||
SELECT * |
||||
FROM test3, test2; |
||||
WARNING: AUDIT: SESSION,1,1,READ,SELECT,,,"SELECT * |
||||
FROM test3, test2;",<not logged> |
||||
WARNING: AUDIT: OBJECT,1,1,READ,SELECT,TABLE,public.test2,<previously logged>,<previously logged> |
||||
id | id |
||||
----+---- |
||||
(0 rows) |
||||
|
||||
GRANT INSERT |
||||
ON TABLE public.test3 |
||||
TO auditor; |
||||
-- |
||||
-- Create a view to test logging |
||||
CREATE VIEW vw_test3 AS |
||||
SELECT * |
||||
FROM test3; |
||||
GRANT SELECT |
||||
ON vw_test3 |
||||
TO auditor; |
||||
-- |
||||
-- Object logged because of: |
||||
-- select on vw_test3 |
||||
-- select on test2 |
||||
SELECT * |
||||
FROM vw_test3, test2; |
||||
WARNING: AUDIT: SESSION,2,1,READ,SELECT,,,"SELECT * |
||||
FROM vw_test3, test2;",<not logged> |
||||
WARNING: AUDIT: OBJECT,2,1,READ,SELECT,TABLE,public.test2,<previously logged>,<previously logged> |
||||
WARNING: AUDIT: OBJECT,2,1,READ,SELECT,VIEW,public.vw_test3,<previously logged>,<previously logged> |
||||
id | id |
||||
----+---- |
||||
(0 rows) |
||||
|
||||
-- |
||||
-- Object logged because of: |
||||
-- insert on test3 |
||||
-- select on test2 |
||||
WITH CTE AS |
||||
( |
||||
SELECT id |
||||
FROM test2 |
||||
) |
||||
INSERT INTO test3 |
||||
SELECT id |
||||
FROM cte; |
||||
WARNING: AUDIT: SESSION,3,1,WRITE,INSERT,,,"WITH CTE AS |
||||
( |
||||
SELECT id |
||||
FROM test2 |
||||
) |
||||
INSERT INTO test3 |
||||
SELECT id |
||||
FROM cte;",<not logged> |
||||
WARNING: AUDIT: OBJECT,3,1,WRITE,INSERT,TABLE,public.test3,<previously logged>,<previously logged> |
||||
WARNING: AUDIT: OBJECT,3,1,READ,SELECT,TABLE,public.test2,<previously logged>,<previously logged> |
||||
-- |
||||
-- Object logged because of: |
||||
-- insert on test3 |
||||
WITH CTE AS |
||||
( |
||||
INSERT INTO test3 VALUES (1) |
||||
RETURNING id |
||||
) |
||||
INSERT INTO test2 |
||||
SELECT id |
||||
FROM cte; |
||||
WARNING: AUDIT: SESSION,4,1,WRITE,INSERT,,,"WITH CTE AS |
||||
( |
||||
INSERT INTO test3 VALUES (1) |
||||
RETURNING id |
||||
) |
||||
INSERT INTO test2 |
||||
SELECT id |
||||
FROM cte;",<not logged> |
||||
WARNING: AUDIT: OBJECT,4,1,WRITE,INSERT,TABLE,public.test3,<previously logged>,<previously logged> |
||||
GRANT UPDATE ON TABLE public.test2 TO auditor; |
||||
-- |
||||
-- Object logged because of: |
||||
-- insert on test3 |
||||
-- update on test2 |
||||
WITH CTE AS |
||||
( |
||||
UPDATE test2 |
||||
SET id = 1 |
||||
RETURNING id |
||||
) |
||||
INSERT INTO test3 |
||||
SELECT id |
||||
FROM cte; |
||||
WARNING: AUDIT: SESSION,5,1,WRITE,INSERT,,,"WITH CTE AS |
||||
( |
||||
UPDATE test2 |
||||
SET id = 1 |
||||
RETURNING id |
||||
) |
||||
INSERT INTO test3 |
||||
SELECT id |
||||
FROM cte;",<not logged> |
||||
WARNING: AUDIT: OBJECT,5,1,WRITE,INSERT,TABLE,public.test3,<previously logged>,<previously logged> |
||||
WARNING: AUDIT: OBJECT,5,1,WRITE,UPDATE,TABLE,public.test2,<previously logged>,<previously logged> |
||||
-- |
||||
-- Object logged because of: |
||||
-- insert on test2 |
||||
WITH CTE AS |
||||
( |
||||
INSERT INTO test2 VALUES (1) |
||||
RETURNING id |
||||
) |
||||
UPDATE test3 |
||||
SET id = cte.id |
||||
FROM cte |
||||
WHERE test3.id <> cte.id; |
||||
WARNING: AUDIT: SESSION,6,1,WRITE,UPDATE,,,"WITH CTE AS |
||||
( |
||||
INSERT INTO test2 VALUES (1) |
||||
RETURNING id |
||||
) |
||||
UPDATE test3 |
||||
SET id = cte.id |
||||
FROM cte |
||||
WHERE test3.id <> cte.id;",<not logged> |
||||
WARNING: AUDIT: OBJECT,6,1,WRITE,INSERT,TABLE,public.test2,<previously logged>,<previously logged> |
||||
-- |
||||
-- Change permissions of user 2 so that only object logging will be done |
||||
\connect contrib_regression super |
||||
alter role user2 set pg_audit.log = 'NONE'; |
||||
NOTICE: AUDIT: SESSION,1,1,ROLE,ALTER ROLE,,,alter role user2 set pg_audit.log = 'NONE';,<not logged> |
||||
\connect contrib_regression user2 |
||||
-- |
||||
-- Create test4 and add permissions |
||||
CREATE TABLE test4 |
||||
( |
||||
id int, |
||||
name text |
||||
); |
||||
GRANT SELECT (name) |
||||
ON TABLE public.test4 |
||||
TO auditor; |
||||
GRANT UPDATE (id) |
||||
ON TABLE public.test4 |
||||
TO auditor; |
||||
GRANT insert (name) |
||||
ON TABLE public.test4 |
||||
TO auditor; |
||||
-- |
||||
-- Not object logged |
||||
SELECT id |
||||
FROM public.test4; |
||||
id |
||||
---- |
||||
(0 rows) |
||||
|
||||
-- |
||||
-- Object logged because of: |
||||
-- select (name) on test4 |
||||
SELECT name |
||||
FROM public.test4; |
||||
WARNING: AUDIT: OBJECT,1,1,READ,SELECT,TABLE,public.test4,"SELECT name |
||||
FROM public.test4;",<not logged> |
||||
name |
||||
------ |
||||
(0 rows) |
||||
|
||||
-- |
||||
-- Not object logged |
||||
INSERT INTO public.test4 (id) |
||||
VALUES (1); |
||||
-- |
||||
-- Object logged because of: |
||||
-- insert (name) on test4 |
||||
INSERT INTO public.test4 (name) |
||||
VALUES ('test'); |
||||
WARNING: AUDIT: OBJECT,2,1,WRITE,INSERT,TABLE,public.test4,"INSERT INTO public.test4 (name) |
||||
VALUES ('test');",<not logged> |
||||
-- |
||||
-- Not object logged |
||||
UPDATE public.test4 |
||||
SET name = 'foo'; |
||||
-- |
||||
-- Object logged because of: |
||||
-- update (id) on test4 |
||||
UPDATE public.test4 |
||||
SET id = 1; |
||||
WARNING: AUDIT: OBJECT,3,1,WRITE,UPDATE,TABLE,public.test4,"UPDATE public.test4 |
||||
SET id = 1;",<not logged> |
||||
-- |
||||
-- Object logged because of: |
||||
-- update (name) on test4 |
||||
-- update (name) takes precedence over select (name) due to ordering |
||||
update public.test4 set name = 'foo' where name = 'bar'; |
||||
WARNING: AUDIT: OBJECT,4,1,WRITE,UPDATE,TABLE,public.test4,update public.test4 set name = 'foo' where name = 'bar';,<not logged> |
||||
-- |
||||
-- Drop test tables |
||||
DROP TABLE test2; |
||||
DROP VIEW vw_test3; |
||||
DROP TABLE test3; |
||||
DROP TABLE test4; |
||||
-- |
||||
-- Change permissions of user 1 so that session logging will be done |
||||
\connect contrib_regression super |
||||
alter role user1 set pg_audit.log = 'DDL, READ'; |
||||
NOTICE: AUDIT: SESSION,1,1,ROLE,ALTER ROLE,,,"alter role user1 set pg_audit.log = 'DDL, READ';",<not logged> |
||||
\connect contrib_regression user1 |
||||
-- |
||||
-- Create table is session logged |
||||
CREATE TABLE public.account |
||||
( |
||||
id INT, |
||||
name TEXT, |
||||
password TEXT, |
||||
description TEXT |
||||
); |
||||
NOTICE: AUDIT: SESSION,1,1,DDL,CREATE TABLE,TABLE,public.account,"CREATE TABLE public.account |
||||
( |
||||
id INT, |
||||
name TEXT, |
||||
password TEXT, |
||||
description TEXT |
||||
);",<not logged> |
||||
-- |
||||
-- Select is session logged |
||||
SELECT * |
||||
FROM account; |
||||
NOTICE: AUDIT: SESSION,2,1,READ,SELECT,,,"SELECT * |
||||
FROM account;",<not logged> |
||||
id | name | password | description |
||||
----+------+----------+------------- |
||||
(0 rows) |
||||
|
||||
-- |
||||
-- Insert is not logged |
||||
INSERT INTO account (id, name, password, description) |
||||
VALUES (1, 'user1', 'HASH1', 'blah, blah'); |
||||
-- |
||||
-- Change permissions of user 1 so that only object logging will be done |
||||
\connect contrib_regression super |
||||
alter role user1 set pg_audit.log = 'none'; |
||||
NOTICE: AUDIT: SESSION,1,1,ROLE,ALTER ROLE,,,alter role user1 set pg_audit.log = 'none';,<not logged> |
||||
alter role user1 set pg_audit.role = 'auditor'; |
||||
NOTICE: AUDIT: SESSION,2,1,ROLE,ALTER ROLE,,,alter role user1 set pg_audit.role = 'auditor';,<not logged> |
||||
\connect contrib_regression user1 |
||||
-- |
||||
-- ROLE class not set, so auditor grants not logged |
||||
GRANT SELECT (password), |
||||
UPDATE (name, password) |
||||
ON TABLE public.account |
||||
TO auditor; |
||||
-- |
||||
-- Not object logged |
||||
SELECT id, |
||||
name |
||||
FROM account; |
||||
id | name |
||||
----+------- |
||||
1 | user1 |
||||
(1 row) |
||||
|
||||
-- |
||||
-- Object logged because of: |
||||
-- select (password) on account |
||||
SELECT password |
||||
FROM account; |
||||
NOTICE: AUDIT: OBJECT,1,1,READ,SELECT,TABLE,public.account,"SELECT password |
||||
FROM account;",<not logged> |
||||
password |
||||
---------- |
||||
HASH1 |
||||
(1 row) |
||||
|
||||
-- |
||||
-- Not object logged |
||||
UPDATE account |
||||
SET description = 'yada, yada'; |
||||
-- |
||||
-- Object logged because of: |
||||
-- update (password) on account |
||||
UPDATE account |
||||
SET password = 'HASH2'; |
||||
NOTICE: AUDIT: OBJECT,2,1,WRITE,UPDATE,TABLE,public.account,"UPDATE account |
||||
SET password = 'HASH2';",<not logged> |
||||
-- |
||||
-- Change permissions of user 1 so that session relation logging will be done |
||||
\connect contrib_regression super |
||||
alter role user1 set pg_audit.log_relation = on; |
||||
NOTICE: AUDIT: SESSION,1,1,ROLE,ALTER ROLE,,,alter role user1 set pg_audit.log_relation = on;,<not logged> |
||||
alter role user1 set pg_audit.log = 'read, WRITE'; |
||||
NOTICE: AUDIT: SESSION,2,1,ROLE,ALTER ROLE,,,"alter role user1 set pg_audit.log = 'read, WRITE';",<not logged> |
||||
\connect contrib_regression user1 |
||||
-- |
||||
-- Not logged |
||||
create table ACCOUNT_ROLE_MAP |
||||
( |
||||
account_id INT, |
||||
role_id INT |
||||
); |
||||
-- |
||||
-- ROLE class not set, so auditor grants not logged |
||||
GRANT SELECT |
||||
ON TABLE public.account_role_map |
||||
TO auditor; |
||||
-- |
||||
-- Object logged because of: |
||||
-- select (password) on account |
||||
-- select on account_role_map |
||||
-- Session logged on all tables because log = read and log_relation = on |
||||
SELECT account.password, |
||||
account_role_map.role_id |
||||
FROM account |
||||
INNER JOIN account_role_map |
||||
on account.id = account_role_map.account_id; |
||||
NOTICE: AUDIT: OBJECT,1,1,READ,SELECT,TABLE,public.account,"SELECT account.password, |
||||
account_role_map.role_id |
||||
FROM account |
||||
INNER JOIN account_role_map |
||||
on account.id = account_role_map.account_id;",<not logged> |
||||
NOTICE: AUDIT: SESSION,1,1,READ,SELECT,TABLE,public.account,"SELECT account.password, |
||||
account_role_map.role_id |
||||
FROM account |
||||
INNER JOIN account_role_map |
||||
on account.id = account_role_map.account_id;",<not logged> |
||||
NOTICE: AUDIT: OBJECT,1,1,READ,SELECT,TABLE,public.account_role_map,"SELECT account.password, |
||||
account_role_map.role_id |
||||
FROM account |
||||
INNER JOIN account_role_map |
||||
on account.id = account_role_map.account_id;",<not logged> |
||||
NOTICE: AUDIT: SESSION,1,1,READ,SELECT,TABLE,public.account_role_map,"SELECT account.password, |
||||
account_role_map.role_id |
||||
FROM account |
||||
INNER JOIN account_role_map |
||||
on account.id = account_role_map.account_id;",<not logged> |
||||
password | role_id |
||||
----------+--------- |
||||
(0 rows) |
||||
|
||||
-- |
||||
-- Object logged because of: |
||||
-- select (password) on account |
||||
-- Session logged on all tables because log = read and log_relation = on |
||||
SELECT password |
||||
FROM account; |
||||
NOTICE: AUDIT: OBJECT,2,1,READ,SELECT,TABLE,public.account,"SELECT password |
||||
FROM account;",<not logged> |
||||
NOTICE: AUDIT: SESSION,2,1,READ,SELECT,TABLE,public.account,"SELECT password |
||||
FROM account;",<not logged> |
||||
password |
||||
---------- |
||||
HASH2 |
||||
(1 row) |
||||
|
||||
-- |
||||
-- Not object logged |
||||
-- Session logged on all tables because log = read and log_relation = on |
||||
UPDATE account |
||||
SET description = 'yada, yada'; |
||||
NOTICE: AUDIT: SESSION,3,1,WRITE,UPDATE,TABLE,public.account,"UPDATE account |
||||
SET description = 'yada, yada';",<not logged> |
||||
-- |
||||
-- Object logged because of: |
||||
-- select (password) on account (in the where clause) |
||||
-- Session logged on all tables because log = read and log_relation = on |
||||
UPDATE account |
||||
SET description = 'yada, yada' |
||||
where password = 'HASH2'; |
||||
NOTICE: AUDIT: OBJECT,4,1,WRITE,UPDATE,TABLE,public.account,"UPDATE account |
||||
SET description = 'yada, yada' |
||||
where password = 'HASH2';",<not logged> |
||||
NOTICE: AUDIT: SESSION,4,1,WRITE,UPDATE,TABLE,public.account,"UPDATE account |
||||
SET description = 'yada, yada' |
||||
where password = 'HASH2';",<not logged> |
||||
-- |
||||
-- Object logged because of: |
||||
-- update (password) on account |
||||
-- Session logged on all tables because log = read and log_relation = on |
||||
UPDATE account |
||||
SET password = 'HASH2'; |
||||
NOTICE: AUDIT: OBJECT,5,1,WRITE,UPDATE,TABLE,public.account,"UPDATE account |
||||
SET password = 'HASH2';",<not logged> |
||||
NOTICE: AUDIT: SESSION,5,1,WRITE,UPDATE,TABLE,public.account,"UPDATE account |
||||
SET password = 'HASH2';",<not logged> |
||||
-- |
||||
-- Change back to superuser to do exhaustive tests |
||||
\connect contrib_regression super |
||||
SET pg_audit.log = 'ALL'; |
||||
NOTICE: AUDIT: SESSION,1,1,MISC,SET,,,SET pg_audit.log = 'ALL';,<not logged> |
||||
SET pg_audit.log_level = 'notice'; |
||||
NOTICE: AUDIT: SESSION,2,1,MISC,SET,,,SET pg_audit.log_level = 'notice';,<not logged> |
||||
SET pg_audit.log_relation = ON; |
||||
NOTICE: AUDIT: SESSION,3,1,MISC,SET,,,SET pg_audit.log_relation = ON;,<not logged> |
||||
SET pg_audit.log_parameter = ON; |
||||
NOTICE: AUDIT: SESSION,4,1,MISC,SET,,,SET pg_audit.log_parameter = ON;,<none> |
||||
-- |
||||
-- Simple DO block |
||||
DO $$ |
||||
BEGIN |
||||
raise notice 'test'; |
||||
END $$; |
||||
NOTICE: AUDIT: SESSION,5,1,FUNCTION,DO,,,"DO $$ |
||||
BEGIN |
||||
raise notice 'test'; |
||||
END $$;",<none> |
||||
NOTICE: test |
||||
-- |
||||
-- Create test schema |
||||
CREATE SCHEMA test; |
||||
NOTICE: AUDIT: SESSION,6,1,DDL,CREATE SCHEMA,SCHEMA,test,CREATE SCHEMA test;,<none> |
||||
-- |
||||
-- Copy account to stdout |
||||
COPY account TO stdout; |
||||
NOTICE: AUDIT: SESSION,7,1,READ,SELECT,TABLE,public.account,COPY account TO stdout;,<none> |
||||
1 user1 HASH2 yada, yada |
||||
-- |
||||
-- Create a table from a query |
||||
CREATE TABLE test.account_copy AS |
||||
SELECT * |
||||
FROM account; |
||||
NOTICE: AUDIT: SESSION,8,1,READ,SELECT,TABLE,public.account,"CREATE TABLE test.account_copy AS |
||||
SELECT * |
||||
FROM account;",<none> |
||||
NOTICE: AUDIT: SESSION,8,1,WRITE,INSERT,TABLE,test.account_copy,"CREATE TABLE test.account_copy AS |
||||
SELECT * |
||||
FROM account;",<none> |
||||
NOTICE: AUDIT: SESSION,8,2,DDL,CREATE TABLE AS,TABLE,test.account_copy,"CREATE TABLE test.account_copy AS |
||||
SELECT * |
||||
FROM account;",<none> |
||||
-- |
||||
-- Copy from stdin to account copy |
||||
COPY test.account_copy from stdin; |
||||
NOTICE: AUDIT: SESSION,9,1,WRITE,INSERT,TABLE,test.account_copy,COPY test.account_copy from stdin;,<none> |
||||
-- |
||||
-- Test prepared statement |
||||
PREPARE pgclassstmt (oid) AS |
||||
SELECT * |
||||
FROM account |
||||
WHERE id = $1; |
||||
NOTICE: AUDIT: SESSION,10,1,READ,PREPARE,,,"PREPARE pgclassstmt (oid) AS |
||||
SELECT * |
||||
FROM account |
||||
WHERE id = $1;",<none> |
||||
EXECUTE pgclassstmt (1); |
||||
NOTICE: AUDIT: SESSION,11,1,READ,SELECT,TABLE,public.account,"PREPARE pgclassstmt (oid) AS |
||||
SELECT * |
||||
FROM account |
||||
WHERE id = $1;",1 |
||||
NOTICE: AUDIT: SESSION,11,2,MISC,EXECUTE,,,EXECUTE pgclassstmt (1);,<none> |
||||
id | name | password | description |
||||
----+-------+----------+------------- |
||||
1 | user1 | HASH2 | yada, yada |
||||
(1 row) |
||||
|
||||
DEALLOCATE pgclassstmt; |
||||
NOTICE: AUDIT: SESSION,12,1,MISC,DEALLOCATE,,,DEALLOCATE pgclassstmt;,<none> |
||||
-- |
||||
-- Test cursor |
||||
BEGIN; |
||||
NOTICE: AUDIT: SESSION,13,1,MISC,BEGIN,,,BEGIN;,<none> |
||||
DECLARE ctest SCROLL CURSOR FOR |
||||
SELECT count(*) |
||||
FROM |
||||
( |
||||
SELECT relname |
||||
FROM pg_class |
||||
LIMIT 1 |
||||
) subquery; |
||||
NOTICE: AUDIT: SESSION,14,1,READ,SELECT,TABLE,pg_catalog.pg_class,"DECLARE ctest SCROLL CURSOR FOR |
||||
SELECT count(*) |
||||
FROM |
||||
( |
||||
SELECT relname |
||||
FROM pg_class |
||||
LIMIT 1 |
||||
) subquery;",<none> |
||||
NOTICE: AUDIT: SESSION,14,2,READ,DECLARE CURSOR,,,"DECLARE ctest SCROLL CURSOR FOR |
||||
SELECT count(*) |
||||
FROM |
||||
( |
||||
SELECT relname |
||||
FROM pg_class |
||||
LIMIT 1 |
||||
) subquery;",<none> |
||||
FETCH NEXT FROM ctest; |
||||
NOTICE: AUDIT: SESSION,15,1,MISC,FETCH,,,FETCH NEXT FROM ctest;,<none> |
||||
count |
||||
------- |
||||
1 |
||||
(1 row) |
||||
|
||||
CLOSE ctest; |
||||
NOTICE: AUDIT: SESSION,16,1,MISC,CLOSE CURSOR,,,CLOSE ctest;,<none> |
||||
COMMIT; |
||||
NOTICE: AUDIT: SESSION,17,1,MISC,COMMIT,,,COMMIT;,<none> |
||||
-- |
||||
-- Turn off log_catalog and pg_class will not be logged |
||||
SET pg_audit.log_catalog = OFF; |
||||
NOTICE: AUDIT: SESSION,18,1,MISC,SET,,,SET pg_audit.log_catalog = OFF;,<none> |
||||
SELECT count(*) |
||||
FROM |
||||
( |
||||
SELECT relname |
||||
FROM pg_class |
||||
LIMIT 1 |
||||
) subquery; |
||||
count |
||||
------- |
||||
1 |
||||
(1 row) |
||||
|
||||
-- |
||||
-- Test prepared insert |
||||
CREATE TABLE test.test_insert |
||||
( |
||||
id INT |
||||
); |
||||
NOTICE: AUDIT: SESSION,19,1,DDL,CREATE TABLE,TABLE,test.test_insert,"CREATE TABLE test.test_insert |
||||
( |
||||
id INT |
||||
);",<none> |
||||
PREPARE pgclassstmt (oid) AS |
||||
INSERT INTO test.test_insert (id) |
||||
VALUES ($1); |
||||
NOTICE: AUDIT: SESSION,20,1,WRITE,PREPARE,,,"PREPARE pgclassstmt (oid) AS |
||||
INSERT INTO test.test_insert (id) |
||||
VALUES ($1);",<none> |
||||
EXECUTE pgclassstmt (1); |
||||
NOTICE: AUDIT: SESSION,21,1,WRITE,INSERT,TABLE,test.test_insert,"PREPARE pgclassstmt (oid) AS |
||||
INSERT INTO test.test_insert (id) |
||||
VALUES ($1);",1 |
||||
NOTICE: AUDIT: SESSION,21,2,MISC,EXECUTE,,,EXECUTE pgclassstmt (1);,<none> |
||||
-- |
||||
-- Check that primary key creation is logged |
||||
CREATE TABLE public.test |
||||
( |
||||
id INT, |
||||
name TEXT, |
||||
description TEXT, |
||||
CONSTRAINT test_pkey PRIMARY KEY (id) |
||||
); |
||||
NOTICE: AUDIT: SESSION,22,1,DDL,CREATE TABLE,TABLE,public.test,"CREATE TABLE public.test |
||||
( |
||||
id INT, |
||||
name TEXT, |
||||
description TEXT, |
||||
CONSTRAINT test_pkey PRIMARY KEY (id) |
||||
);",<none> |
||||
NOTICE: AUDIT: SESSION,22,1,DDL,CREATE TABLE,INDEX,public.test_pkey,"CREATE TABLE public.test |
||||
( |
||||
id INT, |
||||
name TEXT, |
||||
description TEXT, |
||||
CONSTRAINT test_pkey PRIMARY KEY (id) |
||||
);",<none> |
||||
-- |
||||
-- Check that analyze is logged |
||||
ANALYZE test; |
||||
NOTICE: AUDIT: SESSION,23,1,MISC,ANALYZE,,,ANALYZE test;,<none> |
||||
-- |
||||
-- Grants to public should not cause object logging (session logging will |
||||
-- still happen) |
||||
GRANT SELECT |
||||
ON TABLE public.test |
||||
TO PUBLIC; |
||||
NOTICE: AUDIT: SESSION,24,1,ROLE,GRANT,TABLE,,"GRANT SELECT |
||||
ON TABLE public.test |
||||
TO PUBLIC;",<none> |
||||
SELECT * |
||||
FROM test; |
||||
NOTICE: AUDIT: SESSION,25,1,READ,SELECT,TABLE,public.test,"SELECT * |
||||
FROM test;",<none> |
||||
id | name | description |
||||
----+------+------------- |
||||
(0 rows) |
||||
|
||||
-- Check that statements without columns log |
||||
SELECT |
||||
FROM test; |
||||
NOTICE: AUDIT: SESSION,26,1,READ,SELECT,TABLE,public.test,"SELECT |
||||
FROM test;",<none> |
||||
-- |
||||
(0 rows) |
||||
|
||||
SELECT 1, |
||||
current_user; |
||||
NOTICE: AUDIT: SESSION,27,1,READ,SELECT,,,"SELECT 1, |
||||
current_user;",<none> |
||||
?column? | current_user |
||||
----------+-------------- |
||||
1 | super |
||||
(1 row) |
||||
|
||||
DO $$ |
||||
DECLARE |
||||
test INT; |
||||
BEGIN |
||||
SELECT 1 |
||||
INTO test; |
||||
END $$; |
||||
NOTICE: AUDIT: SESSION,28,1,FUNCTION,DO,,,"DO $$ |
||||
DECLARE |
||||
test INT; |
||||
BEGIN |
||||
SELECT 1 |
||||
INTO test; |
||||
END $$;",<none> |
||||
NOTICE: AUDIT: SESSION,28,2,READ,SELECT,,,SELECT 1,<none> |
||||
CONTEXT: SQL statement "SELECT 1" |
||||
PL/pgSQL function inline_code_block line 5 at SQL statement |
||||
explain select 1; |
||||
NOTICE: AUDIT: SESSION,29,1,READ,SELECT,,,explain select 1;,<none> |
||||
NOTICE: AUDIT: SESSION,29,2,MISC,EXPLAIN,,,explain select 1;,<none> |
||||
QUERY PLAN |
||||
------------------------------------------ |
||||
Result (cost=0.00..0.01 rows=1 width=0) |
||||
(1 row) |
||||
|
||||
-- |
||||
-- Test that looks inside of do blocks log |
||||
INSERT INTO TEST (id) |
||||
VALUES (1); |
||||
NOTICE: AUDIT: SESSION,30,1,WRITE,INSERT,TABLE,public.test,"INSERT INTO TEST (id) |
||||
VALUES (1);",<none> |
||||
INSERT INTO TEST (id) |
||||
VALUES (2); |
||||
NOTICE: AUDIT: SESSION,31,1,WRITE,INSERT,TABLE,public.test,"INSERT INTO TEST (id) |
||||
VALUES (2);",<none> |
||||
INSERT INTO TEST (id) |
||||
VALUES (3); |
||||
NOTICE: AUDIT: SESSION,32,1,WRITE,INSERT,TABLE,public.test,"INSERT INTO TEST (id) |
||||
VALUES (3);",<none> |
||||
DO $$ |
||||
DECLARE |
||||
result RECORD; |
||||
BEGIN |
||||
FOR result IN |
||||
SELECT id |
||||
FROM test |
||||
LOOP |
||||
INSERT INTO test (id) |
||||
VALUES (result.id + 100); |
||||
END LOOP; |
||||
END $$; |
||||
NOTICE: AUDIT: SESSION,33,1,FUNCTION,DO,,,"DO $$ |
||||
DECLARE |
||||
result RECORD; |
||||
BEGIN |
||||
FOR result IN |
||||
SELECT id |
||||
FROM test |
||||
LOOP |
||||
INSERT INTO test (id) |
||||
VALUES (result.id + 100); |
||||
END LOOP; |
||||
END $$;",<none> |
||||
NOTICE: AUDIT: SESSION,33,2,READ,SELECT,TABLE,public.test,"SELECT id |
||||
FROM test",<none> |
||||
CONTEXT: PL/pgSQL function inline_code_block line 5 at FOR over SELECT rows |
||||
NOTICE: AUDIT: SESSION,33,3,WRITE,INSERT,TABLE,public.test,"INSERT INTO test (id) |
||||
VALUES (result.id + 100)",",," |
||||
CONTEXT: SQL statement "INSERT INTO test (id) |
||||
VALUES (result.id + 100)" |
||||
PL/pgSQL function inline_code_block line 9 at SQL statement |
||||
NOTICE: AUDIT: SESSION,33,4,WRITE,INSERT,TABLE,public.test,"INSERT INTO test (id) |
||||
VALUES (result.id + 100)",",," |
||||
CONTEXT: SQL statement "INSERT INTO test (id) |
||||
VALUES (result.id + 100)" |
||||
PL/pgSQL function inline_code_block line 9 at SQL statement |
||||
NOTICE: AUDIT: SESSION,33,5,WRITE,INSERT,TABLE,public.test,"INSERT INTO test (id) |
||||
VALUES (result.id + 100)",",," |
||||
CONTEXT: SQL statement "INSERT INTO test (id) |
||||
VALUES (result.id + 100)" |
||||
PL/pgSQL function inline_code_block line 9 at SQL statement |
||||
-- |
||||
-- Test obfuscated dynamic sql for clean logging |
||||
DO $$ |
||||
DECLARE |
||||
table_name TEXT = 'do_table'; |
||||
BEGIN |
||||
EXECUTE 'CREATE TABLE ' || table_name || ' ("weird name" INT)'; |
||||
EXECUTE 'DROP table ' || table_name; |
||||
END $$; |
||||
NOTICE: AUDIT: SESSION,34,1,FUNCTION,DO,,,"DO $$ |
||||
DECLARE |
||||
table_name TEXT = 'do_table'; |
||||
BEGIN |
||||
EXECUTE 'CREATE TABLE ' || table_name || ' (""weird name"" INT)'; |
||||
EXECUTE 'DROP table ' || table_name; |
||||
END $$;",<none> |
||||
NOTICE: AUDIT: SESSION,34,2,DDL,CREATE TABLE,TABLE,public.do_table,"CREATE TABLE do_table (""weird name"" INT)",<none> |
||||
CONTEXT: SQL statement "CREATE TABLE do_table ("weird name" INT)" |
||||
PL/pgSQL function inline_code_block line 5 at EXECUTE statement |
||||
NOTICE: AUDIT: SESSION,34,3,DDL,DROP TABLE,TABLE,public.do_table,DROP table do_table,<none> |
||||
CONTEXT: SQL statement "DROP table do_table" |
||||
PL/pgSQL function inline_code_block line 6 at EXECUTE statement |
||||
-- |
||||
-- Generate an error and make sure the stack gets cleared |
||||
DO $$ |
||||
BEGIN |
||||
CREATE TABLE bogus.test_block |
||||
( |
||||
id INT |
||||
); |
||||
END $$; |
||||
NOTICE: AUDIT: SESSION,35,1,FUNCTION,DO,,,"DO $$ |
||||
BEGIN |
||||
CREATE TABLE bogus.test_block |
||||
( |
||||
id INT |
||||
); |
||||
END $$;",<none> |
||||
ERROR: schema "bogus" does not exist |
||||
LINE 1: CREATE TABLE bogus.test_block |
||||
^ |
||||
QUERY: CREATE TABLE bogus.test_block |
||||
( |
||||
id INT |
||||
) |
||||
CONTEXT: PL/pgSQL function inline_code_block line 3 at SQL statement |
||||
-- |
||||
-- Test alter table statements |
||||
ALTER TABLE public.test |
||||
DROP COLUMN description ; |
||||
NOTICE: AUDIT: SESSION,36,1,DDL,ALTER TABLE,TABLE COLUMN,public.test.description,"ALTER TABLE public.test |
||||
DROP COLUMN description ;",<none> |
||||
NOTICE: AUDIT: SESSION,36,1,DDL,ALTER TABLE,TABLE,public.test,"ALTER TABLE public.test |
||||
DROP COLUMN description ;",<none> |
||||
ALTER TABLE public.test |
||||
RENAME TO test2; |
||||
NOTICE: AUDIT: SESSION,37,1,DDL,ALTER TABLE,TABLE,public.test2,"ALTER TABLE public.test |
||||
RENAME TO test2;",<none> |
||||
ALTER TABLE public.test2 |
||||
SET SCHEMA test; |
||||
NOTICE: AUDIT: SESSION,38,1,DDL,ALTER TABLE,TABLE,test.test2,"ALTER TABLE public.test2 |
||||
SET SCHEMA test;",<none> |
||||
ALTER TABLE test.test2 |
||||
ADD COLUMN description TEXT; |
||||
NOTICE: AUDIT: SESSION,39,1,DDL,ALTER TABLE,TABLE,test.test2,"ALTER TABLE test.test2 |
||||
ADD COLUMN description TEXT;",<none> |
||||
ALTER TABLE test.test2 |
||||
DROP COLUMN description; |
||||
NOTICE: AUDIT: SESSION,40,1,DDL,ALTER TABLE,TABLE COLUMN,test.test2.description,"ALTER TABLE test.test2 |
||||
DROP COLUMN description;",<none> |
||||
NOTICE: AUDIT: SESSION,40,1,DDL,ALTER TABLE,TABLE,test.test2,"ALTER TABLE test.test2 |
||||
DROP COLUMN description;",<none> |
||||
DROP TABLE test.test2; |
||||
NOTICE: AUDIT: SESSION,41,1,DDL,DROP TABLE,TABLE,test.test2,DROP TABLE test.test2;,<none> |
||||
NOTICE: AUDIT: SESSION,41,1,DDL,DROP TABLE,TABLE CONSTRAINT,test_pkey on test.test2,DROP TABLE test.test2;,<none> |
||||
NOTICE: AUDIT: SESSION,41,1,DDL,DROP TABLE,INDEX,test.test_pkey,DROP TABLE test.test2;,<none> |
||||
-- |
||||
-- Test multiple statements with one semi-colon |
||||
CREATE SCHEMA foo |
||||
CREATE TABLE foo.bar (id int) |
||||
CREATE TABLE foo.baz (id int); |
||||
NOTICE: AUDIT: SESSION,42,1,DDL,CREATE SCHEMA,SCHEMA,foo,"CREATE SCHEMA foo |
||||
CREATE TABLE foo.bar (id int) |
||||
CREATE TABLE foo.baz (id int);",<none> |
||||
NOTICE: AUDIT: SESSION,42,1,DDL,CREATE SCHEMA,TABLE,foo.bar,"CREATE SCHEMA foo |
||||
CREATE TABLE foo.bar (id int) |
||||
CREATE TABLE foo.baz (id int);",<none> |
||||
NOTICE: AUDIT: SESSION,42,1,DDL,CREATE SCHEMA,TABLE,foo.baz,"CREATE SCHEMA foo |
||||
CREATE TABLE foo.bar (id int) |
||||
CREATE TABLE foo.baz (id int);",<none> |
||||
-- |
||||
-- Test aggregate |
||||
CREATE FUNCTION public.int_add |
||||
( |
||||
a INT, |
||||
b INT |
||||
) |
||||
RETURNS INT LANGUAGE plpgsql AS $$ |
||||
BEGIN |
||||
return a + b; |
||||
END $$; |
||||
NOTICE: AUDIT: SESSION,43,1,DDL,CREATE FUNCTION,FUNCTION,"public.int_add(integer,integer)","CREATE FUNCTION public.int_add |
||||
( |
||||
a INT, |
||||
b INT |
||||
) |
||||
RETURNS INT LANGUAGE plpgsql AS $$ |
||||
BEGIN |
||||
return a + b; |
||||
END $$;",<none> |
||||
SELECT int_add(1, 1); |
||||
NOTICE: AUDIT: SESSION,44,1,READ,SELECT,,,"SELECT int_add(1, 1);",<none> |
||||
NOTICE: AUDIT: SESSION,44,2,FUNCTION,EXECUTE,FUNCTION,public.int_add,"SELECT int_add(1, 1);",<none> |
||||
int_add |
||||
--------- |
||||
2 |
||||
(1 row) |
||||
|
||||
CREATE AGGREGATE public.sum_test(INT) (SFUNC=public.int_add, STYPE=INT, INITCOND='0'); |
||||
NOTICE: AUDIT: SESSION,45,1,DDL,CREATE AGGREGATE,AGGREGATE,public.sum_test(integer),"CREATE AGGREGATE public.sum_test(INT) (SFUNC=public.int_add, STYPE=INT, INITCOND='0');",<none> |
||||
ALTER AGGREGATE public.sum_test(integer) RENAME TO sum_test2; |
||||
NOTICE: AUDIT: SESSION,46,1,DDL,ALTER AGGREGATE,AGGREGATE,public.sum_test2(integer),ALTER AGGREGATE public.sum_test(integer) RENAME TO sum_test2;,<none> |
||||
-- |
||||
-- Test conversion |
||||
CREATE CONVERSION public.conversion_test FOR 'SQL_ASCII' TO 'MULE_INTERNAL' FROM pg_catalog.ascii_to_mic; |
||||
NOTICE: AUDIT: SESSION,47,1,DDL,CREATE CONVERSION,CONVERSION,public.conversion_test,CREATE CONVERSION public.conversion_test FOR 'SQL_ASCII' TO 'MULE_INTERNAL' FROM pg_catalog.ascii_to_mic;,<none> |
||||
ALTER CONVERSION public.conversion_test RENAME TO conversion_test2; |
||||
NOTICE: AUDIT: SESSION,48,1,DDL,ALTER CONVERSION,CONVERSION,public.conversion_test2,ALTER CONVERSION public.conversion_test RENAME TO conversion_test2;,<none> |
||||
-- |
||||
-- Test create/alter/drop database |
||||
CREATE DATABASE contrib_regression_pgaudit; |
||||
NOTICE: AUDIT: SESSION,49,1,DDL,CREATE DATABASE,,,CREATE DATABASE contrib_regression_pgaudit;,<none> |
||||
ALTER DATABASE contrib_regression_pgaudit RENAME TO contrib_regression_pgaudit2; |
||||
NOTICE: AUDIT: SESSION,50,1,DDL,ALTER DATABASE,,,ALTER DATABASE contrib_regression_pgaudit RENAME TO contrib_regression_pgaudit2;,<none> |
||||
DROP DATABASE contrib_regression_pgaudit2; |
||||
NOTICE: AUDIT: SESSION,51,1,DDL,DROP DATABASE,,,DROP DATABASE contrib_regression_pgaudit2;,<none> |
||||
-- |
||||
-- Test that frees a memory context earlier than expected |
||||
CREATE TABLE hoge |
||||
( |
||||
id int |
||||
); |
||||
NOTICE: AUDIT: SESSION,52,1,DDL,CREATE TABLE,TABLE,public.hoge,"CREATE TABLE hoge |
||||
( |
||||
id int |
||||
);",<none> |
||||
CREATE FUNCTION test() |
||||
RETURNS INT AS $$ |
||||
DECLARE |
||||
cur1 cursor for select * from hoge; |
||||
tmp int; |
||||
BEGIN |
||||
OPEN cur1; |
||||
FETCH cur1 into tmp; |
||||
RETURN tmp; |
||||
END $$ |
||||
LANGUAGE plpgsql ; |
||||
NOTICE: AUDIT: SESSION,53,1,DDL,CREATE FUNCTION,FUNCTION,public.test(),"CREATE FUNCTION test() |
||||
RETURNS INT AS $$ |
||||
DECLARE |
||||
cur1 cursor for select * from hoge; |
||||
tmp int; |
||||
BEGIN |
||||
OPEN cur1; |
||||
FETCH cur1 into tmp; |
||||
RETURN tmp; |
||||
END $$ |
||||
LANGUAGE plpgsql ;",<none> |
||||
SELECT test(); |
||||
NOTICE: AUDIT: SESSION,54,1,READ,SELECT,,,SELECT test();,<none> |
||||
NOTICE: AUDIT: SESSION,54,2,FUNCTION,EXECUTE,FUNCTION,public.test,SELECT test();,<none> |
||||
NOTICE: AUDIT: SESSION,54,3,READ,SELECT,TABLE,public.hoge,select * from hoge,<none> |
||||
CONTEXT: PL/pgSQL function test() line 6 at OPEN |
||||
test |
||||
------ |
||||
|
||||
(1 row) |
||||
|
||||
-- |
||||
-- Delete all rows then delete 1 row |
||||
SET pg_audit.log = 'write'; |
||||
SET pg_audit.role = 'auditor'; |
||||
create table bar |
||||
( |
||||
col int |
||||
); |
||||
grant delete |
||||
on bar |
||||
to auditor; |
||||
insert into bar (col) |
||||
values (1); |
||||
NOTICE: AUDIT: SESSION,55,1,WRITE,INSERT,TABLE,public.bar,"insert into bar (col) |
||||
values (1);",<none> |
||||
delete from bar; |
||||
NOTICE: AUDIT: OBJECT,56,1,WRITE,DELETE,TABLE,public.bar,delete from bar;,<none> |
||||
NOTICE: AUDIT: SESSION,56,1,WRITE,DELETE,TABLE,public.bar,delete from bar;,<none> |
||||
insert into bar (col) |
||||
values (1); |
||||
NOTICE: AUDIT: SESSION,57,1,WRITE,INSERT,TABLE,public.bar,"insert into bar (col) |
||||
values (1);",<none> |
||||
delete from bar |
||||
where col = 1; |
||||
NOTICE: AUDIT: OBJECT,58,1,WRITE,DELETE,TABLE,public.bar,"delete from bar |
||||
where col = 1;",<none> |
||||
NOTICE: AUDIT: SESSION,58,1,WRITE,DELETE,TABLE,public.bar,"delete from bar |
||||
where col = 1;",<none> |
||||
drop table bar; |
||||
-- |
||||
-- Grant roles to each other |
||||
SET pg_audit.log = 'role'; |
||||
GRANT user1 TO user2; |
||||
NOTICE: AUDIT: SESSION,59,1,ROLE,GRANT ROLE,,,GRANT user1 TO user2;,<none> |
||||
REVOKE user1 FROM user2; |
||||
NOTICE: AUDIT: SESSION,60,1,ROLE,REVOKE ROLE,,,REVOKE user1 FROM user2;,<none> |
@ -0,0 +1,22 @@ |
||||
/* pg_audit/pg_audit--1.0.0.sql */ |
||||
|
||||
-- complain if script is sourced in psql, rather than via CREATE EXTENSION |
||||
\echo Use "CREATE EXTENSION pg_audit" to load this file.\quit |
||||
|
||||
CREATE FUNCTION pg_audit_ddl_command_end() |
||||
RETURNS event_trigger |
||||
LANGUAGE C |
||||
AS 'MODULE_PATHNAME', 'pg_audit_ddl_command_end'; |
||||
|
||||
CREATE EVENT TRIGGER pg_audit_ddl_command_end |
||||
ON ddl_command_end |
||||
EXECUTE PROCEDURE pg_audit_ddl_command_end(); |
||||
|
||||
CREATE FUNCTION pg_audit_sql_drop() |
||||
RETURNS event_trigger |
||||
LANGUAGE C |
||||
AS 'MODULE_PATHNAME', 'pg_audit_sql_drop'; |
||||
|
||||
CREATE EVENT TRIGGER pg_audit_sql_drop |
||||
ON sql_drop |
||||
EXECUTE PROCEDURE pg_audit_sql_drop(); |
File diff suppressed because it is too large
Load Diff
@ -0,0 +1 @@ |
||||
shared_preload_libraries = pg_audit |
@ -0,0 +1,5 @@ |
||||
# pg_audit extension |
||||
comment = 'provides auditing functionality' |
||||
default_version = '1.0.0' |
||||
module_pathname = '$libdir/pg_audit' |
||||
relocatable = true |
@ -0,0 +1,617 @@ |
||||
-- Load pg_audit module |
||||
create extension pg_audit; |
||||
|
||||
-- |
||||
-- Audit log fields are: |
||||
-- AUDIT_TYPE - SESSION or OBJECT |
||||
-- STATEMENT_ID - ID of the statement in the current backend |
||||
-- SUBSTATEMENT_ID - ID of the substatement in the current backend |
||||
-- CLASS - Class of statement being logged (e.g. ROLE, READ, WRITE) |
||||
-- COMMAND - e.g. SELECT, CREATE ROLE, UPDATE |
||||
-- OBJECT_TYPE - When available, type of object acted on (e.g. TABLE, VIEW) |
||||
-- OBJECT_NAME - When available, fully-qualified table of object |
||||
-- STATEMENT - The statement being logged |
||||
-- PARAMETER - If parameter logging is requested, they will follow the |
||||
-- statement |
||||
|
||||
-- |
||||
-- Create a superuser role that we know the name of for testing |
||||
CREATE USER super SUPERUSER; |
||||
ALTER ROLE super SET pg_audit.log = 'Role'; |
||||
ALTER ROLE super SET pg_audit.log_level = 'notice'; |
||||
\connect contrib_regression super; |
||||
|
||||
-- |
||||
-- Create auditor role |
||||
CREATE ROLE auditor; |
||||
|
||||
-- |
||||
-- Create first test user |
||||
CREATE USER user1; |
||||
ALTER ROLE user1 SET pg_audit.log = 'ddl, ROLE'; |
||||
ALTER ROLE user1 SET pg_audit.log_level = 'notice'; |
||||
|
||||
-- |
||||
-- Create, select, drop (select will not be audited) |
||||
\connect contrib_regression user1 |
||||
CREATE TABLE public.test (id INT); |
||||
SELECT * FROM test; |
||||
DROP TABLE test; |
||||
|
||||
-- |
||||
-- Create second test user |
||||
\connect contrib_regression super |
||||
|
||||
CREATE USER user2; |
||||
ALTER ROLE user2 SET pg_audit.log = 'Read, writE'; |
||||
ALTER ROLE user2 SET pg_audit.log_catalog = OFF; |
||||
ALTER ROLE user2 SET pg_audit.log_level = 'warning'; |
||||
ALTER ROLE user2 SET pg_audit.role = auditor; |
||||
ALTER ROLE user2 SET pg_audit.log_statement_once = ON; |
||||
|
||||
\connect contrib_regression user2 |
||||
CREATE TABLE test2 (id INT); |
||||
GRANT SELECT ON TABLE public.test2 TO auditor; |
||||
|
||||
-- |
||||
-- Role-based tests |
||||
CREATE TABLE test3 |
||||
( |
||||
id INT |
||||
); |
||||
|
||||
SELECT count(*) |
||||
FROM |
||||
( |
||||
SELECT relname |
||||
FROM pg_class |
||||
LIMIT 1 |
||||
) SUBQUERY; |
||||
|
||||
SELECT * |
||||
FROM test3, test2; |
||||
|
||||
GRANT INSERT |
||||
ON TABLE public.test3 |
||||
TO auditor; |
||||
|
||||
-- |
||||
-- Create a view to test logging |
||||
CREATE VIEW vw_test3 AS |
||||
SELECT * |
||||
FROM test3; |
||||
|
||||
GRANT SELECT |
||||
ON vw_test3 |
||||
TO auditor; |
||||
|
||||
-- |
||||
-- Object logged because of: |
||||
-- select on vw_test3 |
||||
-- select on test2 |
||||
SELECT * |
||||
FROM vw_test3, test2; |
||||
|
||||
-- |
||||
-- Object logged because of: |
||||
-- insert on test3 |
||||
-- select on test2 |
||||
WITH CTE AS |
||||
( |
||||
SELECT id |
||||
FROM test2 |
||||
) |
||||
INSERT INTO test3 |
||||
SELECT id |
||||
FROM cte; |
||||
|
||||
-- |
||||
-- Object logged because of: |
||||
-- insert on test3 |
||||
WITH CTE AS |
||||
( |
||||
INSERT INTO test3 VALUES (1) |
||||
RETURNING id |
||||
) |
||||
INSERT INTO test2 |
||||
SELECT id |
||||
FROM cte; |
||||
|
||||
GRANT UPDATE ON TABLE public.test2 TO auditor; |
||||
|
||||
-- |
||||
-- Object logged because of: |
||||
-- insert on test3 |
||||
-- update on test2 |
||||
WITH CTE AS |
||||
( |
||||
UPDATE test2 |
||||
SET id = 1 |
||||
RETURNING id |
||||
) |
||||
INSERT INTO test3 |
||||
SELECT id |
||||
FROM cte; |
||||
|
||||
-- |
||||
-- Object logged because of: |
||||
-- insert on test2 |
||||
WITH CTE AS |
||||
( |
||||
INSERT INTO test2 VALUES (1) |
||||
RETURNING id |
||||
) |
||||
UPDATE test3 |
||||
SET id = cte.id |
||||
FROM cte |
||||
WHERE test3.id <> cte.id; |
||||
|
||||
-- |
||||
-- Change permissions of user 2 so that only object logging will be done |
||||
\connect contrib_regression super |
||||
alter role user2 set pg_audit.log = 'NONE'; |
||||
|
||||
\connect contrib_regression user2 |
||||
|
||||
-- |
||||
-- Create test4 and add permissions |
||||
CREATE TABLE test4 |
||||
( |
||||
id int, |
||||
name text |
||||
); |
||||
|
||||
GRANT SELECT (name) |
||||
ON TABLE public.test4 |
||||
TO auditor; |
||||
|
||||
GRANT UPDATE (id) |
||||
ON TABLE public.test4 |
||||
TO auditor; |
||||
|
||||
GRANT insert (name) |
||||
ON TABLE public.test4 |
||||
TO auditor; |
||||
|
||||
-- |
||||
-- Not object logged |
||||
SELECT id |
||||
FROM public.test4; |
||||
|
||||
-- |
||||
-- Object logged because of: |
||||
-- select (name) on test4 |
||||
SELECT name |
||||
FROM public.test4; |
||||
|
||||
-- |
||||
-- Not object logged |
||||
INSERT INTO public.test4 (id) |
||||
VALUES (1); |
||||
|
||||
-- |
||||
-- Object logged because of: |
||||
-- insert (name) on test4 |
||||
INSERT INTO public.test4 (name) |
||||
VALUES ('test'); |
||||
|
||||
-- |
||||
-- Not object logged |
||||
UPDATE public.test4 |
||||
SET name = 'foo'; |
||||
|
||||
-- |
||||
-- Object logged because of: |
||||
-- update (id) on test4 |
||||
UPDATE public.test4 |
||||
SET id = 1; |
||||
|
||||
-- |
||||
-- Object logged because of: |
||||
-- update (name) on test4 |
||||
-- update (name) takes precedence over select (name) due to ordering |
||||
update public.test4 set name = 'foo' where name = 'bar'; |
||||
|
||||
-- |
||||
-- Drop test tables |
||||
DROP TABLE test2; |
||||
DROP VIEW vw_test3; |
||||
DROP TABLE test3; |
||||
DROP TABLE test4; |
||||
|
||||
-- |
||||
-- Change permissions of user 1 so that session logging will be done |
||||
\connect contrib_regression super |
||||
alter role user1 set pg_audit.log = 'DDL, READ'; |
||||
\connect contrib_regression user1 |
||||
|
||||
-- |
||||
-- Create table is session logged |
||||
CREATE TABLE public.account |
||||
( |
||||
id INT, |
||||
name TEXT, |
||||
password TEXT, |
||||
description TEXT |
||||
); |
||||
|
||||
-- |
||||
-- Select is session logged |
||||
SELECT * |
||||
FROM account; |
||||
|
||||
-- |
||||
-- Insert is not logged |
||||
INSERT INTO account (id, name, password, description) |
||||
VALUES (1, 'user1', 'HASH1', 'blah, blah'); |
||||
|
||||
-- |
||||
-- Change permissions of user 1 so that only object logging will be done |
||||
\connect contrib_regression super |
||||
alter role user1 set pg_audit.log = 'none'; |
||||
alter role user1 set pg_audit.role = 'auditor'; |
||||
\connect contrib_regression user1 |
||||
|
||||
-- |
||||
-- ROLE class not set, so auditor grants not logged |
||||
GRANT SELECT (password), |
||||
UPDATE (name, password) |
||||
ON TABLE public.account |
||||
TO auditor; |
||||
|
||||
-- |
||||
-- Not object logged |
||||
SELECT id, |
||||
name |
||||
FROM account; |
||||
|
||||
-- |
||||
-- Object logged because of: |
||||
-- select (password) on account |
||||
SELECT password |
||||
FROM account; |
||||
|
||||
-- |
||||
-- Not object logged |
||||
UPDATE account |
||||
SET description = 'yada, yada'; |
||||
|
||||
-- |
||||
-- Object logged because of: |
||||
-- update (password) on account |
||||
UPDATE account |
||||
SET password = 'HASH2'; |
||||
|
||||
-- |
||||
-- Change permissions of user 1 so that session relation logging will be done |
||||
\connect contrib_regression super |
||||
alter role user1 set pg_audit.log_relation = on; |
||||
alter role user1 set pg_audit.log = 'read, WRITE'; |
||||
\connect contrib_regression user1 |
||||
|
||||
-- |
||||
-- Not logged |
||||
create table ACCOUNT_ROLE_MAP |
||||
( |
||||
account_id INT, |
||||
role_id INT |
||||
); |
||||
|
||||
-- |
||||
-- ROLE class not set, so auditor grants not logged |
||||
GRANT SELECT |
||||
ON TABLE public.account_role_map |
||||
TO auditor; |
||||
|
||||
-- |
||||
-- Object logged because of: |
||||
-- select (password) on account |
||||
-- select on account_role_map |
||||
-- Session logged on all tables because log = read and log_relation = on |
||||
SELECT account.password, |
||||
account_role_map.role_id |
||||
FROM account |
||||
INNER JOIN account_role_map |
||||
on account.id = account_role_map.account_id; |
||||
|
||||
-- |
||||
-- Object logged because of: |
||||
-- select (password) on account |
||||
-- Session logged on all tables because log = read and log_relation = on |
||||
SELECT password |
||||
FROM account; |
||||
|
||||
-- |
||||
-- Not object logged |
||||
-- Session logged on all tables because log = read and log_relation = on |
||||
UPDATE account |
||||
SET description = 'yada, yada'; |
||||
|
||||
-- |
||||
-- Object logged because of: |
||||
-- select (password) on account (in the where clause) |
||||
-- Session logged on all tables because log = read and log_relation = on |
||||
UPDATE account |
||||
SET description = 'yada, yada' |
||||
where password = 'HASH2'; |
||||
|
||||
-- |
||||
-- Object logged because of: |
||||
-- update (password) on account |
||||
-- Session logged on all tables because log = read and log_relation = on |
||||
UPDATE account |
||||
SET password = 'HASH2'; |
||||
|
||||
-- |
||||
-- Change back to superuser to do exhaustive tests |
||||
\connect contrib_regression super |
||||
SET pg_audit.log = 'ALL'; |
||||
SET pg_audit.log_level = 'notice'; |
||||
SET pg_audit.log_relation = ON; |
||||
SET pg_audit.log_parameter = ON; |
||||
|
||||
-- |
||||
-- Simple DO block |
||||
DO $$ |
||||
BEGIN |
||||
raise notice 'test'; |
||||
END $$; |
||||
|
||||
-- |
||||
-- Create test schema |
||||
CREATE SCHEMA test; |
||||
|
||||
-- |
||||
-- Copy account to stdout |
||||
COPY account TO stdout; |
||||
|
||||
-- |
||||
-- Create a table from a query |
||||
CREATE TABLE test.account_copy AS |
||||
SELECT * |
||||
FROM account; |
||||
|
||||
-- |
||||
-- Copy from stdin to account copy |
||||
COPY test.account_copy from stdin; |
||||
1 user1 HASH2 yada, yada |
||||
\. |
||||
|
||||
-- |
||||
-- Test prepared statement |
||||
PREPARE pgclassstmt (oid) AS |
||||
SELECT * |
||||
FROM account |
||||
WHERE id = $1; |
||||
|
||||
EXECUTE pgclassstmt (1); |
||||
DEALLOCATE pgclassstmt; |
||||
|
||||
-- |
||||
-- Test cursor |
||||
BEGIN; |
||||
|
||||
DECLARE ctest SCROLL CURSOR FOR |
||||
SELECT count(*) |
||||
FROM |
||||
( |
||||
SELECT relname |
||||
FROM pg_class |
||||
LIMIT 1 |
||||
) subquery; |
||||
|
||||
FETCH NEXT FROM ctest; |
||||
CLOSE ctest; |
||||
COMMIT; |
||||
|
||||
-- |
||||
-- Turn off log_catalog and pg_class will not be logged |
||||
SET pg_audit.log_catalog = OFF; |
||||
|
||||
SELECT count(*) |
||||
FROM |
||||
( |
||||
SELECT relname |
||||
FROM pg_class |
||||
LIMIT 1 |
||||
) subquery; |
||||
|
||||
-- |
||||
-- Test prepared insert |
||||
CREATE TABLE test.test_insert |
||||
( |
||||
id INT |
||||
); |
||||
|
||||
PREPARE pgclassstmt (oid) AS |
||||
INSERT INTO test.test_insert (id) |
||||
VALUES ($1); |
||||
EXECUTE pgclassstmt (1); |
||||
|
||||
-- |
||||
-- Check that primary key creation is logged |
||||
CREATE TABLE public.test |
||||
( |
||||
id INT, |
||||
name TEXT, |
||||
description TEXT, |
||||
CONSTRAINT test_pkey PRIMARY KEY (id) |
||||
); |
||||
|
||||
-- |
||||
-- Check that analyze is logged |
||||
ANALYZE test; |
||||
|
||||
-- |
||||
-- Grants to public should not cause object logging (session logging will |
||||
-- still happen) |
||||
GRANT SELECT |
||||
ON TABLE public.test |
||||
TO PUBLIC; |
||||
|
||||
SELECT * |
||||
FROM test; |
||||
|
||||
-- Check that statements without columns log |
||||
SELECT |
||||
FROM test; |
||||
|
||||
SELECT 1, |
||||
current_user; |
||||
|
||||
DO $$ |
||||
DECLARE |
||||
test INT; |
||||
BEGIN |
||||
SELECT 1 |
||||
INTO test; |
||||
END $$; |
||||
|
||||
explain select 1; |
||||
|
||||
-- |
||||
-- Test that looks inside of do blocks log |
||||
INSERT INTO TEST (id) |
||||
VALUES (1); |
||||
INSERT INTO TEST (id) |
||||
VALUES (2); |
||||
INSERT INTO TEST (id) |
||||
VALUES (3); |
||||
|
||||
DO $$ |
||||
DECLARE |
||||
result RECORD; |
||||
BEGIN |
||||
FOR result IN |
||||
SELECT id |
||||
FROM test |
||||
LOOP |
||||
INSERT INTO test (id) |
||||
VALUES (result.id + 100); |
||||
END LOOP; |
||||
END $$; |
||||
|
||||
-- |
||||
-- Test obfuscated dynamic sql for clean logging |
||||
DO $$ |
||||
DECLARE |
||||
table_name TEXT = 'do_table'; |
||||
BEGIN |
||||
EXECUTE 'CREATE TABLE ' || table_name || ' ("weird name" INT)'; |
||||
EXECUTE 'DROP table ' || table_name; |
||||
END $$; |
||||
|
||||
-- |
||||
-- Generate an error and make sure the stack gets cleared |
||||
DO $$ |
||||
BEGIN |
||||
CREATE TABLE bogus.test_block |
||||
( |
||||
id INT |
||||
); |
||||
END $$; |
||||
|
||||
-- |
||||
-- Test alter table statements |
||||
ALTER TABLE public.test |
||||
DROP COLUMN description ; |
||||
|
||||
ALTER TABLE public.test |
||||
RENAME TO test2; |
||||
|
||||
ALTER TABLE public.test2 |
||||
SET SCHEMA test; |
||||
|
||||
ALTER TABLE test.test2 |
||||
ADD COLUMN description TEXT; |
||||
|
||||
ALTER TABLE test.test2 |
||||
DROP COLUMN description; |
||||
|
||||
DROP TABLE test.test2; |
||||
|
||||
-- |
||||
-- Test multiple statements with one semi-colon |
||||
CREATE SCHEMA foo |
||||
CREATE TABLE foo.bar (id int) |
||||
CREATE TABLE foo.baz (id int); |
||||
|
||||
-- |
||||
-- Test aggregate |
||||
CREATE FUNCTION public.int_add |
||||
( |
||||
a INT, |
||||
b INT |
||||
) |
||||
RETURNS INT LANGUAGE plpgsql AS $$ |
||||
BEGIN |
||||
return a + b; |
||||
END $$; |
||||
|
||||
SELECT int_add(1, 1); |
||||
|
||||
CREATE AGGREGATE public.sum_test(INT) (SFUNC=public.int_add, STYPE=INT, INITCOND='0'); |
||||
ALTER AGGREGATE public.sum_test(integer) RENAME TO sum_test2; |
||||
|
||||
-- |
||||
-- Test conversion |
||||
CREATE CONVERSION public.conversion_test FOR 'SQL_ASCII' TO 'MULE_INTERNAL' FROM pg_catalog.ascii_to_mic; |
||||
ALTER CONVERSION public.conversion_test RENAME TO conversion_test2; |
||||
|
||||
-- |
||||
-- Test create/alter/drop database |
||||
CREATE DATABASE contrib_regression_pgaudit; |
||||
ALTER DATABASE contrib_regression_pgaudit RENAME TO contrib_regression_pgaudit2; |
||||
DROP DATABASE contrib_regression_pgaudit2; |
||||
|
||||
-- |
||||
-- Test that frees a memory context earlier than expected |
||||
CREATE TABLE hoge |
||||
( |
||||
id int |
||||
); |
||||
|
||||
CREATE FUNCTION test() |
||||
RETURNS INT AS $$ |
||||
DECLARE |
||||
cur1 cursor for select * from hoge; |
||||
tmp int; |
||||
BEGIN |
||||
OPEN cur1; |
||||
FETCH cur1 into tmp; |
||||
RETURN tmp; |
||||
END $$ |
||||
LANGUAGE plpgsql ; |
||||
|
||||
SELECT test(); |
||||
|
||||
-- |
||||
-- Delete all rows then delete 1 row |
||||
SET pg_audit.log = 'write'; |
||||
SET pg_audit.role = 'auditor'; |
||||
|
||||
create table bar |
||||
( |
||||
col int |
||||
); |
||||
|
||||
grant delete |
||||
on bar |
||||
to auditor; |
||||
|
||||
insert into bar (col) |
||||
values (1); |
||||
delete from bar; |
||||
|
||||
insert into bar (col) |
||||
values (1); |
||||
delete from bar |
||||
where col = 1; |
||||
|
||||
drop table bar; |
||||
|
||||
-- |
||||
-- Grant roles to each other |
||||
SET pg_audit.log = 'role'; |
||||
GRANT user1 TO user2; |
||||
REVOKE user1 FROM user2; |
@ -0,0 +1,678 @@ |
||||
<!-- doc/src/sgml/pgaudit.sgml --> |
||||
|
||||
<sect1 id="pgaudit" xreflabel="pgaudit"> |
||||
<title>pg_audit</title> |
||||
|
||||
<indexterm zone="pgaudit"> |
||||
<primary>pg_audit</primary> |
||||
</indexterm> |
||||
|
||||
<para> |
||||
The <filename>pg_audit</filename> extension provides detailed session |
||||
and/or object audit logging via the standard logging facility. The goal |
||||
is to provide the tools needed to produce audit logs required to pass any |
||||
government, financial, or ISO certification audit. |
||||
</para> |
||||
|
||||
<para> |
||||
An audit is an official inspection of an individual's or organization's |
||||
accounts, typically by an independent body. The information gathered by |
||||
<filename>pg_audit</filename> is properly called an audit trail or audit |
||||
log. The term audit log is used in this documentation. |
||||
</para> |
||||
|
||||
<sect2> |
||||
<title>Why <literal>pg_audit</>?</title> |
||||
|
||||
<para> |
||||
Basic statement logging can be provided by the standard logging facility |
||||
using <literal>log_statement = all</>. This is acceptable for monitoring |
||||
and other usages but does not provide the level of detail generally |
||||
required for an audit. It is not enough to have a list of all the |
||||
operations performed against the database. It must also be possible to |
||||
find particular statements that are of interest to an auditor. The |
||||
standard logging facility shows what the user requested, while |
||||
<literal>pg_audit</> focuses on the details of what happened while |
||||
the database was satisfying the request. |
||||
</para> |
||||
|
||||
<para> |
||||
For example, an auditor may want to verify that a particular table was |
||||
created inside a documented maintenance window. This might seem like a |
||||
simple job for grep, but what if you are presented with something like |
||||
this (intentionally obfuscated) example: |
||||
</para> |
||||
|
||||
<programlisting> |
||||
DO $$ |
||||
BEGIN |
||||
EXECUTE 'CREATE TABLE import' || 'ant_table (id INT)'; |
||||
END $$; |
||||
</programlisting> |
||||
|
||||
<para> |
||||
Standard logging will give you this: |
||||
</para> |
||||
|
||||
<programlisting> |
||||
LOG: statement: DO $$ |
||||
BEGIN |
||||
EXECUTE 'CREATE TABLE import' || 'ant_table (id INT)'; |
||||
END $$; |
||||
</programlisting> |
||||
|
||||
<para> |
||||
It appears that finding the table of interest may require some knowledge |
||||
of the code in cases where tables are created dynamically. This is not |
||||
ideal since it would be preferrable to just search on the table name. |
||||
This is where <literal>pg_audit</> comes in. For the same input, |
||||
it will produce this output in the log: |
||||
</para> |
||||
|
||||
<programlisting> |
||||
AUDIT: SESSION,33,1,FUNCTION,DO,,,"DO $$ |
||||
BEGIN |
||||
EXECUTE 'CREATE TABLE import' || 'ant_table (id INT)'; |
||||
END $$;" |
||||
AUDIT: SESSION,33,2,DDL,CREATE TABLE,TABLE,public.important_table,CREATE TABLE important_table (id INT) |
||||
</programlisting> |
||||
|
||||
<para> |
||||
Not only is the <literal>DO</> block logged, but substatement 2 contains |
||||
the full text of the <literal>CREATE TABLE</> with the statement type, |
||||
object type, and full-qualified name to make searches easy. |
||||
</para> |
||||
|
||||
<para> |
||||
When logging <literal>SELECT</> and <literal>DML</> statements, |
||||
<literal>pg_audit</> can be configured to log a separate entry for each |
||||
relation referenced in a statement. No parsing is required to find all |
||||
statements that touch a particular table. In fact, the goal is that the |
||||
statement text is provided primarily for deep forensics and should not be |
||||
the required for an audit. |
||||
</para> |
||||
</sect2> |
||||
|
||||
<sect2> |
||||
<title>Usage Considerations</title> |
||||
|
||||
<para> |
||||
Depending on settings, it is possible for <literal>pg_audit</literal> to |
||||
generate an enormous volume of logging. Be careful to determine |
||||
exactly what needs to be audit logged in your environment to avoid |
||||
logging too much. |
||||
</para> |
||||
|
||||
<para> |
||||
For example, when working in an OLAP environment it would probably not be |
||||
wise to audit log inserts into a large fact table. The size of the log |
||||
file will likely be many times the actual data size of the inserts because |
||||
the log file is expressed as text. Since logs are generally stored with |
||||
the OS this may lead to disk space being exhausted very |
||||
quickly. In cases where it is not possible to limit audit logging to |
||||
certain tables, be sure to assess the performance impact while testing |
||||
and allocate plenty of space on the log volume. This may also be true for |
||||
OLTP environments. Even if the insert volume is not as high, the |
||||
performance impact of audit logging may still noticeably affect latency. |
||||
</para> |
||||
|
||||
<para> |
||||
To limit the number of relations audit logged for <literal>SELECT</> |
||||
and <literal>DML</> statments, consider using object audit logging |
||||
(see <xref linkend="pgaudit-object-audit-logging">). Object audit logging |
||||
allows selection of the relations to be logged allowing for reduction |
||||
of the overall log volume. However, when new relations are added they |
||||
must be explicitly added to object audit logging. A programmatic |
||||
solution where specified tables are excluded from logging and all others |
||||
are included may be a good option in this case. |
||||
</para> |
||||
</sect2> |
||||
|
||||
<sect2> |
||||
<title>Settings</title> |
||||
|
||||
<para> |
||||
Settings may be modified only by a superuser. Allowing normal users to |
||||
change their settings would defeat the point of an audit log. |
||||
</para> |
||||
|
||||
<para> |
||||
Settings can be specified globally (in |
||||
<filename>postgresql.conf</filename> or using |
||||
<literal>ALTER SYSTEM ... SET</>), at the database level (using |
||||
<literal>ALTER DATABASE ... SET</literal>), or at the role level (using |
||||
<literal>ALTER ROLE ... SET</literal>). Note that settings are not |
||||
inherited through normal role inheritance and <literal>SET ROLE</> will |
||||
not alter a user's <literal>pg_audit</> settings. This is a limitation |
||||
of the roles system and not inherent to <literal>pg_audit</>. |
||||
</para> |
||||
|
||||
<para> |
||||
The <literal>pg_audit</> extension must be loaded in |
||||
<xref linkend="guc-shared-preload-libraries">. Otherwise, an error |
||||
will be raised at load time and no audit logging will occur. |
||||
</para> |
||||
|
||||
<variablelist> |
||||
<varlistentry id="guc-pgaudit-log" xreflabel="pg_audit.log"> |
||||
<term><varname>pg_audit.log</varname> (<type>string</type>) |
||||
<indexterm> |
||||
<primary><varname>pg_audit.log</> configuration parameter</primary> |
||||
</indexterm> |
||||
</term> |
||||
<listitem> |
||||
<para> |
||||
Specifies which classes of statements will be logged by session |
||||
audit logging. Possible values are: |
||||
</para> |
||||
|
||||
<itemizedlist> |
||||
<listitem> |
||||
<para> |
||||
<literal>READ</literal> - <literal>SELECT</literal> and |
||||
<literal>COPY</literal> when the source is a relation or a |
||||
query. |
||||
</para> |
||||
</listitem> |
||||
<listitem> |
||||
<para> |
||||
<literal>WRITE</literal> - <literal>INSERT</literal>, |
||||
<literal>UPDATE</literal>, <literal>DELETE</literal>, |
||||
<literal>TRUNCATE</literal>, and <literal>COPY</literal> when the |
||||
destination is a relation. |
||||
</para> |
||||
</listitem> |
||||
<listitem> |
||||
<para> |
||||
<literal>FUNCTION</literal> - Function calls and |
||||
<literal>DO</literal> blocks. |
||||
</para> |
||||
</listitem> |
||||
<listitem> |
||||
<para> |
||||
<literal>ROLE</literal> - Statements related to roles and |
||||
privileges: <literal>GRANT</literal>, |
||||
<literal>REVOKE</literal>, |
||||
<literal>CREATE/ALTER/DROP ROLE</literal>. |
||||
</para> |
||||
</listitem> |
||||
<listitem> |
||||
<para> |
||||
<literal>DDL</literal> - All <literal>DDL</> that is not included |
||||
in the <literal>ROLE</> class plus <literal>REINDEX</>. |
||||
</para> |
||||
</listitem> |
||||
<listitem> |
||||
<para> |
||||
<literal>MISC</literal> - Miscellaneous commands, e.g. |
||||
<literal>DISCARD</literal>, <literal>FETCH</literal>, |
||||
<literal>CHECKPOINT</literal>, <literal>VACUUM</literal>. |
||||
</para> |
||||
</listitem> |
||||
</itemizedlist> |
||||
|
||||
<para> |
||||
Multiple classes can be provided using a comma-separated list and |
||||
classes can be subtracted by prefacing the class with a |
||||
<literal>-</> sign (see <xref linkend="pgaudit-session-audit-logging">). |
||||
The default is <literal>none</>. |
||||
</para> |
||||
</listitem> |
||||
</varlistentry> |
||||
|
||||
<varlistentry id="guc-pgaudit-log-catalog" xreflabel="pg_audit.log_catalog"> |
||||
<term><varname>pg_audit.log_catalog</varname> (<type>boolean</type>) |
||||
<indexterm> |
||||
<primary><varname>pg_audit.log_catalog</> configuration parameter</primary> |
||||
</indexterm> |
||||
</term> |
||||
<listitem> |
||||
<para> |
||||
Specifies that session logging should be enabled in the case where all |
||||
relations in a statement are in pg_catalog. Disabling this setting |
||||
will reduce noise in the log from tools like psql and PgAdmin that query |
||||
the catalog heavily. The default is <literal>on</>. |
||||
</para> |
||||
</listitem> |
||||
</varlistentry> |
||||
|
||||
<varlistentry id="guc-pgaudit-log-level" xreflabel="pg_audit.log_level"> |
||||
<term><varname>pg_audit.log_level</varname> (<type>boolean</type>) |
||||
<indexterm> |
||||
<primary><varname>pg_audit.log_level</> configuration parameter</primary> |
||||
</indexterm> |
||||
</term> |
||||
<listitem> |
||||
<para> |
||||
Specifies the log level that will be used for log entries (see |
||||
<xref linkend="RUNTIME-CONFIG-SEVERITY-LEVELS"> for valid levels). |
||||
This setting is used for regression testing and may also be useful |
||||
to end users for testing or other purposes. It is not intended to |
||||
be used in a production environment as it may leak which statements |
||||
are being logged to the user. The default is <literal>log</>. |
||||
</para> |
||||
</listitem> |
||||
</varlistentry> |
||||
|
||||
<varlistentry id="guc-pgaudit-log-parameter" xreflabel="pg_audit.log_parameter"> |
||||
<term><varname>pg_audit.log_parameter</varname> (<type>boolean</type>) |
||||
<indexterm> |
||||
<primary><varname>pg_audit.log_parameter</> configuration parameter</primary> |
||||
</indexterm> |
||||
</term> |
||||
<listitem> |
||||
<para> |
||||
Specifies that audit logging should include the parameters that |
||||
were passed with the statement. When parameters are present they will |
||||
be included in CSV format after the statement text. The default is |
||||
<literal>off</>. |
||||
</para> |
||||
</listitem> |
||||
</varlistentry> |
||||
|
||||
<varlistentry id="guc-pgaudit-log-relation" xreflabel="pg_audit.log_relation"> |
||||
<term><varname>pg_audit.log_relation</varname> (<type>boolean</type>) |
||||
<indexterm> |
||||
<primary><varname>pg_audit.log_relation</> configuration parameter</primary> |
||||
</indexterm> |
||||
</term> |
||||
<listitem> |
||||
<para> |
||||
Specifies whether session audit logging should create a separate |
||||
log entry for each relation (<literal>TABLE</>, <literal>VIEW</>, |
||||
etc.) referenced in a <literal>SELECT</> or <literal>DML</> |
||||
statement. This is a useful shortcut for exhaustive logging |
||||
without using object audit logging. The default is |
||||
<literal>off</>. |
||||
</para> |
||||
</listitem> |
||||
</varlistentry> |
||||
|
||||
<varlistentry id="guc-pgaudit-log-statement-once" xreflabel="pg_audit.log_statement-once"> |
||||
<term><varname>pg_audit.log_statement_once</varname> (<type>boolean</type>) |
||||
<indexterm> |
||||
<primary><varname>pg_audit.log_statement_once</> configuration parameter</primary> |
||||
</indexterm> |
||||
</term> |
||||
<listitem> |
||||
<para> |
||||
Specifies whether logging will include the statement text and |
||||
parameters with the first log entry for a statement/substatement |
||||
combination or with every entry. Disabling this setting will |
||||
result in less verbose logging but may make it more difficult to |
||||
determine the statement that generated a log entry, though the |
||||
statement/substatement pair along with the process id should suffice |
||||
to identify the statement text logged with a previous entry. The |
||||
default is <literal>off</>. |
||||
</para> |
||||
</listitem> |
||||
</varlistentry> |
||||
|
||||
<varlistentry id="guc-pgaudit-role" xreflabel="pg_audit.role"> |
||||
<term><varname>pg_audit.role</varname> (<type>string</type>) |
||||
<indexterm> |
||||
<primary><varname>pg_audit.role</> configuration parameter</primary> |
||||
</indexterm> |
||||
</term> |
||||
<listitem> |
||||
<para> |
||||
Specifies the master role to use for object audit logging. Muliple |
||||
audit roles can be defined by granting them to the master role. |
||||
This allows multiple groups to be in charge of different aspects |
||||
of audit logging. There is no default. |
||||
</para> |
||||
</listitem> |
||||
</varlistentry> |
||||
</variablelist> |
||||
</sect2> |
||||
|
||||
<sect2 id="pgaudit-session-audit-logging"> |
||||
<title>Session Audit Logging</title> |
||||
|
||||
<para> |
||||
Session audit logging provides detailed logs of all statements executed |
||||
by a user in the backend. |
||||
</para> |
||||
|
||||
<sect3> |
||||
<title>Configuration</title> |
||||
|
||||
<para> |
||||
Session logging is enabled with the <xref linkend="guc-pgaudit-log"> |
||||
setting. |
||||
|
||||
Enable session logging for all <literal>DML</> and <literal>DDL</> and |
||||
log all relations in <literal>DML</> statements: |
||||
<programlisting> |
||||
set pg_audit.log = 'write, ddl'; |
||||
set pg_audit.log_relation = on; |
||||
</programlisting> |
||||
</para> |
||||
|
||||
<para> |
||||
Enable session logging for all commands except <literal>MISC</> and |
||||
raise audit log messages as <literal>NOTICE</>: |
||||
<programlisting> |
||||
set pg_audit.log = 'all, -misc'; |
||||
set pg_audit.log_notice = on; |
||||
</programlisting> |
||||
</para> |
||||
</sect3> |
||||
|
||||
<sect3> |
||||
<title>Example</title> |
||||
|
||||
<para> |
||||
In this example session audit logging is used for logging |
||||
<literal>DDL</> and <literal>SELECT</> statements. Note that the |
||||
insert statement is not logged since the <literal>WRITE</> class |
||||
is not enabled |
||||
</para> |
||||
|
||||
<para> |
||||
SQL: |
||||
</para> |
||||
<programlisting> |
||||
set pg_audit.log = 'read, ddl'; |
||||
|
||||
create table account |
||||
( |
||||
id int, |
||||
name text, |
||||
password text, |
||||
description text |
||||
); |
||||
|
||||
insert into account (id, name, password, description) |
||||
values (1, 'user1', 'HASH1', 'blah, blah'); |
||||
|
||||
select * |
||||
from account; |
||||
</programlisting> |
||||
|
||||
<para> |
||||
Log Output: |
||||
</para> |
||||
|
||||
<programlisting> |
||||
AUDIT: SESSION,1,1,DDL,CREATE TABLE,TABLE,public.account,create table account |
||||
( |
||||
id int, |
||||
name text, |
||||
password text, |
||||
description text |
||||
); |
||||
AUDIT: SESSION,2,1,READ,SELECT,,,select * |
||||
from account |
||||
</programlisting> |
||||
</sect3> |
||||
</sect2> |
||||
|
||||
<sect2 id="pgaudit-object-audit-logging"> |
||||
<title>Object Auditing</title> |
||||
|
||||
<para> |
||||
Object audit logging logs statements that affect a particular relation. |
||||
Only <literal>SELECT</>, <literal>INSERT</>, <literal>UPDATE</> and |
||||
<literal>DELETE</> commands are supported. <literal>TRUNCATE</> is not |
||||
included because there is no specific privilege for it. |
||||
</para> |
||||
|
||||
<para> |
||||
Object audit logging is intended to be a finer-grained replacement for |
||||
<literal>pg_audit.log = 'read, write'</literal>. As such, it may not |
||||
make sense to use them in conjunction but one possible scenario would |
||||
be to use session logging to capture each statement and then supplement |
||||
that with object logging to get more detail about specific relations. |
||||
</para> |
||||
|
||||
<sect3> |
||||
<title>Configuration</title> |
||||
|
||||
<para> |
||||
Object-level audit logging is implemented via the roles system. The |
||||
<xref linkend="guc-pgaudit-role"> setting defines the role that |
||||
will be used for audit logging. A relation (<literal>TABLE</>, |
||||
<literal>VIEW</>, etc.) will be audit logged when the audit role has |
||||
permissions for the command executed or inherits the permissions from |
||||
another role. This allows you to effectively have multiple audit roles |
||||
even though there is a single master role in any context. |
||||
</para> |
||||
|
||||
<para> |
||||
Set <xref linkend="guc-pgaudit-role"> to <literal>auditor</> and |
||||
grant <literal>SELECT</> and <literal>DELETE</> privileges on the |
||||
<literal>account</> table. Any <literal>SELECT</> or |
||||
<literal>DELETE</> statements on <literal>account</> will now be |
||||
logged: |
||||
</para> |
||||
|
||||
<programlisting> |
||||
set pg_audit.role = 'auditor'; |
||||
|
||||
grant select, delete |
||||
on public.account |
||||
to auditor; |
||||
</programlisting> |
||||
</sect3> |
||||
|
||||
<sect3> |
||||
<title>Example</title> |
||||
|
||||
<para> |
||||
In this example object audit logging is used to illustrate how a |
||||
granular approach may be taken towards logging of <literal>SELECT</> |
||||
and <literal>DML</> statements. Note that logging on the |
||||
<literal>account</> table is controlled by column-level permissions, |
||||
while logging on <literal>account_role_map</> is table-level. |
||||
</para> |
||||
|
||||
<para> |
||||
SQL: |
||||
</para> |
||||
|
||||
<programlisting> |
||||
set pg_audit.role = 'auditor'; |
||||
|
||||
create table account |
||||
( |
||||
id int, |
||||
name text, |
||||
password text, |
||||
description text |
||||
); |
||||
|
||||
grant select (password) |
||||
on public.account |
||||
to auditor; |
||||
|
||||
select id, name |
||||
from account; |
||||
|
||||
select password |
||||
from account; |
||||
|
||||
grant update (name, password) |
||||
on public.account |
||||
to auditor; |
||||
|
||||
update account |
||||
set description = 'yada, yada'; |
||||
|
||||
update account |
||||
set password = 'HASH2'; |
||||
|
||||
create table account_role_map |
||||
( |
||||
account_id int, |
||||
role_id int |
||||
); |
||||
|
||||
grant select |
||||
on public.account_role_map |
||||
to auditor; |
||||
|
||||
select account.password, |
||||
account_role_map.role_id |
||||
from account |
||||
inner join account_role_map |
||||
on account.id = account_role_map.account_id |
||||
</programlisting> |
||||
|
||||
<para> |
||||
Log Output: |
||||
</para> |
||||
|
||||
<programlisting> |
||||
AUDIT: OBJECT,1,1,READ,SELECT,TABLE,public.account,select password |
||||
from account |
||||
AUDIT: OBJECT,2,1,WRITE,UPDATE,TABLE,public.account,update account |
||||
set password = 'HASH2' |
||||
AUDIT: OBJECT,3,1,READ,SELECT,TABLE,public.account,select account.password, |
||||
account_role_map.role_id |
||||
from account |
||||
inner join account_role_map |
||||
on account.id = account_role_map.account_id |
||||
AUDIT: OBJECT,3,1,READ,SELECT,TABLE,public.account_role_map,select account.password, |
||||
account_role_map.role_id |
||||
from account |
||||
inner join account_role_map |
||||
on account.id = account_role_map.account_id |
||||
</programlisting> |
||||
</sect3> |
||||
</sect2> |
||||
|
||||
<sect2> |
||||
<title>Format</title> |
||||
|
||||
<para> |
||||
Audit entries are written to the standard logging facility and contain |
||||
the following columns in comma-separated format: |
||||
|
||||
<note> |
||||
<para> |
||||
Output is compliant CSV format only if the log line prefix portion |
||||
of each log entry is removed. |
||||
</para> |
||||
</note> |
||||
|
||||
<itemizedlist> |
||||
<listitem> |
||||
<para> |
||||
<literal>AUDIT_TYPE</> - <literal>SESSION</> or |
||||
<literal>OBJECT</>. |
||||
</para> |
||||
</listitem> |
||||
<listitem> |
||||
<para> |
||||
<literal>STATEMENT_ID</> - Unique statement ID for this session. |
||||
Each statement ID represents a backend call. Statement IDs are |
||||
sequential even if some statements are not logged. There may be |
||||
multiple entries for a statement ID when more than one relation |
||||
is logged. |
||||
</para> |
||||
</listitem> |
||||
<listitem> |
||||
<para> |
||||
<literal>SUBSTATEMENT_ID</> - Sequential ID for each |
||||
substatement within the main statement. For example, calling |
||||
a function from a query. Substatement IDs are continuous |
||||
even if some substatements are not logged. There may be multiple |
||||
entries for a substatement ID when more than one relation is logged. |
||||
</para> |
||||
</listitem> |
||||
<listitem> |
||||
<para> |
||||
<literal>CLASS</> - e.g. (<literal>READ</>, |
||||
<literal>ROLE</>) (see <xref linkend="guc-pgaudit-log">). |
||||
</para> |
||||
</listitem> |
||||
<listitem> |
||||
<para> |
||||
<literal>COMMAND</> - e.g. <literal>ALTER TABLE</>, |
||||
<literal>SELECT</>. |
||||
</para> |
||||
</listitem> |
||||
<listitem> |
||||
<para> |
||||
<literal>OBJECT_TYPE</> - <literal>TABLE</>, |
||||
<literal>INDEX</>, <literal>VIEW</>, etc. |
||||
Available for <literal>SELECT</>, <literal>DML</> and most |
||||
<literal>DDL</> statements. |
||||
</para> |
||||
</listitem> |
||||
<listitem> |
||||
<para> |
||||
<literal>OBJECT_NAME</> - The fully-qualified object name |
||||
(e.g. public.account). Available for <literal>SELECT</>, |
||||
<literal>DML</> and most <literal>DDL</> statements. |
||||
</para> |
||||
</listitem> |
||||
<listitem> |
||||
<para> |
||||
<literal>STATEMENT</> - Statement executed on the backend. |
||||
</para> |
||||
</listitem> |
||||
</itemizedlist> |
||||
</para> |
||||
|
||||
<para> |
||||
Use <xref linkend="guc-log-line-prefix"> to add any other fields that |
||||
are needed to satisfy your audit log requirements. A typical log line |
||||
prefix might be <literal>'%m %u %d: '</> which would provide the date/time, |
||||
user name, and database name for each audit log. |
||||
</para> |
||||
</sect2> |
||||
|
||||
<sect2> |
||||
<title>Caveats</title> |
||||
|
||||
<itemizedlist> |
||||
<listitem> |
||||
<para> |
||||
Object renames are logged under the name they were renamed to. |
||||
For example, renaming a table will produce the following result: |
||||
</para> |
||||
|
||||
<programlisting> |
||||
ALTER TABLE test RENAME TO test2; |
||||
|
||||
AUDIT: SESSION,36,1,DDL,ALTER TABLE,TABLE,public.test2,ALTER TABLE test RENAME TO test2 |
||||
</programlisting> |
||||
</listitem> |
||||
|
||||
<listitem> |
||||
<para> |
||||
It is possible to have a command logged more than once. For example, |
||||
when a table is created with a primary key specified at creation time |
||||
the index for the primary key will be logged independently and another |
||||
audit log will be made for the index under the create entry. The |
||||
multiple entries will however be contained within one statement ID. |
||||
</para> |
||||
</listitem> |
||||
|
||||
<listitem> |
||||
<para> |
||||
Autovacuum and Autoanalyze are not logged, nor are they intended to be. |
||||
</para> |
||||
</listitem> |
||||
|
||||
<listitem> |
||||
<para> |
||||
Statements that are executed after a transaction enters an aborted state |
||||
will not be audit logged. However, the statement that caused the error |
||||
and any subsequent statements executed in the aborted transaction will |
||||
be logged as ERRORs by the standard logging facility. |
||||
</para> |
||||
</listitem> |
||||
</itemizedlist> |
||||
</sect2> |
||||
|
||||
<sect2> |
||||
<title>Authors</title> |
||||
|
||||
<para> |
||||
Abhijit Menon-Sen <email>ams@2ndQuadrant.com</email>, Ian Barwick <email>ian@2ndQuadrant.com</email>, and David Steele <email>david@pgmasters.net</email>. |
||||
</para> |
||||
</sect2> |
||||
</sect1> |
Loading…
Reference in new issue