diff --git a/contrib/pgaudit/README.md b/contrib/pgaudit/README.md new file mode 100644 index 0000000..3d14d7d --- /dev/null +++ b/contrib/pgaudit/README.md @@ -0,0 +1,331 @@ +# PostgreSQL Audit Extension + +The PostgreSQL Audit extension (`pgaudit`) provides detailed session and/or object audit logging via the standard PostgreSQL logging facility. + +The goal of the PostgreSQL Audit extension (`pgaudit`) is to provide PostgreSQL users with capability to produce audit logs often required to comply with government, financial, or ISO certifications. + +An audit is an official inspection of an individual's or organization's accounts, typically by an independent body. The information gathered by the PostgreSQL Audit extension (`pgaudit`) is properly called an audit trail or audit log. The term audit log is used in this documentation. + +## Why PostgreSQL Audit Extension? + +Basic statement logging can be provided by the standard logging facility +`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 `pgaudit` focuses on the details of what happened while the database was satisfying the request. + +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: +``` +BEGIN + EXECUTE 'CREATE TABLE import' || 'ant_table (id INT)'; +END $$; +``` +Standard logging will give you this: +``` +LOG: statement: DO $$ +BEGIN + EXECUTE 'CREATE TABLE import' || 'ant_table (id INT)'; +END $$; +``` +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 preferable to just search on the table name. This is where `pgaudit` comes in. For the same input, it will produce this output in the log: +``` +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) +``` +Not only is the `DO` block logged, but substatement 2 contains the full text of the `CREATE TABLE` with the statement type, object type, and full-qualified name to make searches easy. + +When logging `SELECT` and `DML` statements, `pgaudit` 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 required for an audit. + +## Usage Considerations + +Depending on settings, it is possible for `pgaudit` 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. + +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. + +To limit the number of relations audit logged for `SELECT` and `DML` statments, consider using object audit logging (see [Object Auditing](#object-auditing)). 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. + +## Compile and Install + +Clone the PostgreSQL repository: +``` +git clone https://github.com/postgres/postgres.git +``` +Checkout REL9_5_STABLE branch: +``` +git checkout REL9_5_STABLE +``` +Make PostgreSQL: +``` +./configure +make install -s +``` +Change to the contrib directory: +``` +cd contrib +``` +Clone the `pgaudit` extension: +``` +git clone https://github.com/pgaudit/pgaudit.git +``` +Change to `pgaudit` directory: +``` +cd pgaudit +``` +Build ``pgaudit`` and run regression tests: +``` +make -s check +``` +Install `pgaudit`: +``` +make install +``` + +## Settings + +Settings may be modified only by a superuser. Allowing normal users to change their settings would defeat the point of an audit log. + +Settings can be specified globally (in `postgresql.conf` or using `ALTER SYSTEM ... SET`), at the database level (using `ALTER DATABASE ... SET`), or at the role level (using `ALTER ROLE ... SET`). Note that settings are not inherited through normal role inheritance and `SET ROLE` will not alter a user's `pgaudit` settings. This is a limitation of the roles system and not inherent to `pgaudit`. + +The `pgaudit` extension must be loaded in [shared_preload_libraries](http://www.postgresql.org/docs/9.5/static/runtime-config-client.html#GUC-SHARED-PRELOAD-LIBRARIES). Otherwise, an error will be raised at load time and no audit logging will occur. + +### pgaudit.log + +Specifies which classes of statements will be logged by session audit logging. Possible values are: + +* __READ__: `SELECT` and `COPY` when the source is a relation or a query. + +* __WRITE__: `INSERT`, `UPDATE`, `DELETE`, `TRUNCATE`, and `COPY` when the destination is a relation. + +* __FUNCTION__: Function calls and `DO` blocks. + +* __ROLE__: Statements related to roles and privileges: `GRANT`, `REVOKE`, `CREATE/ALTER/DROP ROLE`. + +* __DDL__: All `DDL` that is not included in the `ROLE` class. + +* __MISC__: Miscellaneous commands, e.g. `DISCARD`, `FETCH`, `CHECKPOINT`, `VACUUM`. + +Multiple classes can be provided using a comma-separated list and classes can be subtracted by prefacing the class with a `-` sign (see [Session Audit Logging](#session-audit-logging)). + +The default is `none`. + +### pgaudit.log_catalog + +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 `on`. + +### pgaudit.log_level + +Specifies the log level that will be used for log entries (see [Message Severity Levels] (http://www.postgresql.org/docs/9.1/static/runtime-config-logging.html#RUNTIME-CONFIG-SEVERITY-LEVELS) for valid levels but note that `ERROR`, `FATAL`, and `PANIC` are not allowed). This setting is used for regression testing and may also be useful to end users for testing or other purposes. + +The default is `log`. + +### pgaudit.log_parameter + +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 `off`. + +### pgaudit.log_relation + +Specifies whether session audit logging should create a separate log entry for each relation (`TABLE`, `VIEW`, etc.) referenced in a `SELECT` or `DML` statement. This is a useful shortcut for exhaustive logging without using object audit logging. + +The default is `off`. + +### pgaudit.log_statement_once + +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 `off`. + +### pgaudit.role + +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. + +## Session Audit Logging + +Session audit logging provides detailed logs of all statements executed by a user in the backend. + +### Configuration + +Session logging is enabled with the [pgaudit.log](#pgauditlog) setting. + +Enable session logging for all `DML` and `DDL` and log all relations in `DML` statements: +``` +set pgaudit.log = 'write, ddl'; +set pgaudit.log_relation = on; +``` +Enable session logging for all commands except `MISC` and raise audit log messages as `NOTICE`: +``` +set pgaudit.log = 'all, -misc'; +set pgaudit.log_level = notice; +``` + +### Example + +In this example session audit logging is used for logging `DDL` and `SELECT` statements. Note that the insert statement is not logged since the `WRITE` class is not enabled + +SQL: +``` +set pgaudit.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; +``` +Log Output: +``` +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 +``` + +## Object Auditing + +Object audit logging logs statements that affect a particular relation. Only `SELECT`, `INSERT`, `UPDATE` and `DELETE` commands are supported. `TRUNCATE` is not included in object audit logging. + +Object audit logging is intended to be a finer-grained replacement for `pgaudit.log = 'read, write'`. 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. + +### Configuration + +Object-level audit logging is implemented via the roles system. The [pgaudit.role](#pgauditrole) setting defines the role that will be used for audit logging. A relation (`TABLE`, `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. + +Set [pgaudit.role](#pgauditrole) to `auditor` and grant `SELECT` and `DELETE` privileges on the `account` table. Any `SELECT` or `DELETE` statements on `account` will now be logged: +``` +set pgaudit.role = 'auditor'; + +grant select, delete + on public.account + to auditor; +``` + +### Example + +In this example object audit logging is used to illustrate how a granular approach may be taken towards logging of `SELECT` and `DML` statements. Note that logging on the `account` table is controlled by column-level permissions, while logging on `account_role_map` is table-level. + +SQL: +``` +set pgaudit.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 +``` +Log Output: +``` +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 +``` + +## Format + +Audit entries are written to the standard logging facility and contain the following columns in comma-separated format: + +Output is compliant CSV format only if the log line prefix portion of each log entry is removed. + +* __AUDIT_TYPE__ - `SESSION` or `OBJECT`. +* __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. + +* __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. + +* __CLASS__ - e.g. (`READ`, `ROLE`) (see [pgaudit.log](#pgauditlog)). +* __COMMAND__ - e.g. `ALTER TABLE`, `SELECT`. + +* __OBJECT_TYPE__ - `TABLE`, `INDEX`, `VIEW`, etc. Available for `SELECT`, `DML` and most `DDL` statements. + +* __OBJECT_NAME__ - The fully-qualified object name (e.g. public.account). Available for `SELECT`, `DML` and most `DDL` statements. + +* __STATEMENT__ - Statement executed on the backend. + +* __PARAMETER__ - If `pgaudit.log_parameter` is set then this field will contain the statement parameters as quoted CSV. + +Use [log_line_prefix](http://www.postgresql.org/docs/9.5/static/runtime-config-logging.html#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 `'%m %u %d: '` which would provide the date/time, user name, and database name for each audit log. + +## Caveats + +* Object renames are logged under the name they were renamed to. For example, renaming a table will produce the following result: + +``` +ALTER TABLE test RENAME TO test2; + +AUDIT: SESSION,36,1,DDL,ALTER TABLE,TABLE,public.test2,ALTER TABLE test RENAME TO test2 +``` +* 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. + +* Autovacuum and Autoanalyze are not logged. + +* 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. + +## Authors + +The PostgreSQL Audit Extension is based on the pgaudit project at https://github.com/2ndQuadrant authored by Abhijit Menon-Sen and Ian Barwick. Further development has been done by David Steele. diff --git a/contrib/pgaudit/expected/pgaudit.out b/contrib/pgaudit/expected/pgaudit.out new file mode 100644 index 0000000..e7ee93b --- /dev/null +++ b/contrib/pgaudit/expected/pgaudit.out @@ -0,0 +1,1123 @@ +\set VERBOSITY terse +-- Create pgaudit extension +CREATE EXTENSION IF NOT EXISTS pgaudit; +-- +-- 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 +SELECT current_user \gset +-- +-- Set pgaudit parameters for the current (super)user. +ALTER ROLE :current_user SET pgaudit.log = 'Role'; +ALTER ROLE :current_user SET pgaudit.log_level = 'notice'; +ALTER ROLE :current_user SET pgaudit.log_client = ON; +-- After each connect, we need to load pgaudit, as if it was +-- being loaded from shared_preload_libraries. Otherwise, the hooks +-- won't be set up and called correctly, leading to lots of ugly +-- errors. +\connect - :current_user; +-- +-- Create auditor role +CREATE ROLE auditor; +NOTICE: AUDIT: SESSION,1,1,ROLE,CREATE ROLE,,,CREATE ROLE auditor;, +-- +-- Create first test user +CREATE USER user1; +NOTICE: AUDIT: SESSION,2,1,ROLE,CREATE ROLE,,,CREATE USER user1;, +ALTER ROLE user1 SET pgaudit.log = 'ddl, ROLE'; +NOTICE: AUDIT: SESSION,3,1,ROLE,ALTER ROLE,,,"ALTER ROLE user1 SET pgaudit.log = 'ddl, ROLE';", +ALTER ROLE user1 SET pgaudit.log_level = 'notice'; +NOTICE: AUDIT: SESSION,4,1,ROLE,ALTER ROLE,,,ALTER ROLE user1 SET pgaudit.log_level = 'notice';, +ALTER ROLE user1 SET pgaudit.log_client = ON; +NOTICE: AUDIT: SESSION,5,1,ROLE,ALTER ROLE,,,ALTER ROLE user1 SET pgaudit.log_client = ON;, +-- +-- Create, select, drop (select will not be audited) +\connect - user1 +CREATE TABLE public.test +( + id INT +); +NOTICE: AUDIT: SESSION,1,1,DDL,CREATE TABLE,TABLE,public.test,"CREATE TABLE public.test +( + id INT +);", +SELECT * + FROM test; + id +---- +(0 rows) + +DROP TABLE test; +NOTICE: AUDIT: SESSION,2,1,DDL,DROP TABLE,TABLE,public.test,DROP TABLE test;, +-- +-- Create second test user +\connect - :current_user +CREATE USER user2; +NOTICE: AUDIT: SESSION,1,1,ROLE,CREATE ROLE,,,CREATE USER user2;, +ALTER ROLE user2 SET pgaudit.log = 'Read, writE'; +NOTICE: AUDIT: SESSION,2,1,ROLE,ALTER ROLE,,,"ALTER ROLE user2 SET pgaudit.log = 'Read, writE';", +ALTER ROLE user2 SET pgaudit.log_catalog = OFF; +NOTICE: AUDIT: SESSION,3,1,ROLE,ALTER ROLE,,,ALTER ROLE user2 SET pgaudit.log_catalog = OFF;, +ALTER ROLE user2 SET pgaudit.log_level = 'warning'; +NOTICE: AUDIT: SESSION,4,1,ROLE,ALTER ROLE,,,ALTER ROLE user2 SET pgaudit.log_level = 'warning';, +ALTER ROLE user2 SET pgaudit.log_client = ON; +NOTICE: AUDIT: SESSION,5,1,ROLE,ALTER ROLE,,,ALTER ROLE user2 SET pgaudit.log_client = ON;, +ALTER ROLE user2 SET pgaudit.role = auditor; +NOTICE: AUDIT: SESSION,6,1,ROLE,ALTER ROLE,,,ALTER ROLE user2 SET pgaudit.role = auditor;, +ALTER ROLE user2 SET pgaudit.log_statement_once = ON; +NOTICE: AUDIT: SESSION,7,1,ROLE,ALTER ROLE,,,ALTER ROLE user2 SET pgaudit.log_statement_once = ON;, +-- +-- Setup role-based tests +CREATE TABLE test2 +( + id INT +); +GRANT SELECT, INSERT, UPDATE, DELETE + ON test2 + TO user2, user1; +NOTICE: AUDIT: SESSION,8,1,ROLE,GRANT,TABLE,,"GRANT SELECT, INSERT, UPDATE, DELETE + ON test2 + TO user2, user1;", +GRANT SELECT, UPDATE + ON TABLE public.test2 + TO auditor; +NOTICE: AUDIT: SESSION,9,1,ROLE,GRANT,TABLE,,"GRANT SELECT, UPDATE + ON TABLE public.test2 + TO auditor;", +CREATE TABLE test3 +( + id INT +); +GRANT SELECT, INSERT, UPDATE, DELETE + ON test3 + TO user2; +NOTICE: AUDIT: SESSION,10,1,ROLE,GRANT,TABLE,,"GRANT SELECT, INSERT, UPDATE, DELETE + ON test3 + TO user2;", +GRANT INSERT + ON TABLE public.test3 + TO auditor; +NOTICE: AUDIT: SESSION,11,1,ROLE,GRANT,TABLE,,"GRANT INSERT + ON TABLE public.test3 + TO auditor;", +CREATE FUNCTION test2_insert() RETURNS TRIGGER AS $$ +BEGIN + UPDATE test2 + SET id = id + 90 + WHERE id = new.id; + + RETURN new; +END $$ LANGUAGE plpgsql security definer; +ALTER FUNCTION test2_insert() OWNER TO user1; +CREATE TRIGGER test2_insert_trg + AFTER INSERT ON test2 + FOR EACH ROW EXECUTE PROCEDURE test2_insert(); +CREATE FUNCTION test2_change(change_id int) RETURNS void AS $$ +BEGIN + UPDATE test2 + SET id = id + 1 + WHERE id = change_id; +END $$ LANGUAGE plpgsql security definer; +ALTER FUNCTION test2_change(int) OWNER TO user2; +CREATE VIEW vw_test3 AS +SELECT * + FROM test3; +GRANT SELECT + ON vw_test3 + TO user2; +NOTICE: AUDIT: SESSION,12,1,ROLE,GRANT,TABLE,,"GRANT SELECT + ON vw_test3 + TO user2;", +GRANT SELECT + ON vw_test3 + TO auditor; +NOTICE: AUDIT: SESSION,13,1,ROLE,GRANT,TABLE,,"GRANT SELECT + ON vw_test3 + TO auditor;", +\connect - user2 +-- +-- Role-based tests +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;", +WARNING: AUDIT: OBJECT,1,1,READ,SELECT,TABLE,public.test2,, + id | id +----+---- +(0 rows) + +-- +-- 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;", +WARNING: AUDIT: OBJECT,2,1,READ,SELECT,TABLE,public.test2,, +WARNING: AUDIT: OBJECT,2,1,READ,SELECT,VIEW,public.vw_test3,, + 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;", +WARNING: AUDIT: OBJECT,3,1,WRITE,INSERT,TABLE,public.test3,, +WARNING: AUDIT: OBJECT,3,1,READ,SELECT,TABLE,public.test2,, +-- +-- 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;", +WARNING: AUDIT: OBJECT,4,1,WRITE,INSERT,TABLE,public.test3,, +DO $$ BEGIN PERFORM test2_change(91); END $$; +WARNING: AUDIT: SESSION,5,1,READ,SELECT,,,SELECT test2_change(91), +WARNING: AUDIT: SESSION,5,2,WRITE,UPDATE,,,"UPDATE test2 + SET id = id + 1 + WHERE id = change_id", +WARNING: AUDIT: OBJECT,5,2,WRITE,UPDATE,TABLE,public.test2,, +-- +-- Object logged because of: +-- insert on test3 +-- update on test2 +WITH CTE AS +( + UPDATE test2 + SET id = 45 + WHERE id = 92 + RETURNING id +) +INSERT INTO test3 +SELECT id + FROM cte; +WARNING: AUDIT: SESSION,6,1,WRITE,INSERT,,,"WITH CTE AS +( + UPDATE test2 + SET id = 45 + WHERE id = 92 + RETURNING id +) +INSERT INTO test3 +SELECT id + FROM cte;", +WARNING: AUDIT: OBJECT,6,1,WRITE,INSERT,TABLE,public.test3,, +WARNING: AUDIT: OBJECT,6,1,WRITE,UPDATE,TABLE,public.test2,, +-- +-- Object logged because of: +-- insert on test2 +WITH CTE AS +( + INSERT INTO test2 VALUES (37) + RETURNING id +) +UPDATE test3 + SET id = cte.id + FROM cte + WHERE test3.id <> cte.id; +WARNING: AUDIT: SESSION,7,1,WRITE,UPDATE,,,"WITH CTE AS +( + INSERT INTO test2 VALUES (37) + RETURNING id +) +UPDATE test3 + SET id = cte.id + FROM cte + WHERE test3.id <> cte.id;", +WARNING: AUDIT: OBJECT,7,1,WRITE,INSERT,TABLE,public.test2,, +-- +-- Be sure that test has correct contents +SELECT * + FROM test2 + ORDER BY ID; +WARNING: AUDIT: SESSION,8,1,READ,SELECT,,,"SELECT * + FROM test2 + ORDER BY ID;", +WARNING: AUDIT: OBJECT,8,1,READ,SELECT,TABLE,public.test2,, + id +----- + 45 + 127 +(2 rows) + +-- +-- Change permissions of user 2 so that only object logging will be done +\connect - :current_user +ALTER ROLE user2 SET pgaudit.log = 'NONE'; +NOTICE: AUDIT: SESSION,1,1,ROLE,ALTER ROLE,,,ALTER ROLE user2 SET pgaudit.log = 'NONE';, +\connect - 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;", + 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 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;", +-- +-- 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';, +-- +-- Change permissions of user 1 so that session logging will be done +\connect - :current_user +-- +-- Drop test tables +DROP TABLE test2; +DROP VIEW vw_test3; +DROP TABLE test3; +DROP TABLE test4; +DROP FUNCTION test2_insert(); +DROP FUNCTION test2_change(int); +ALTER ROLE user1 SET pgaudit.log = 'DDL, READ'; +NOTICE: AUDIT: SESSION,1,1,ROLE,ALTER ROLE,,,"ALTER ROLE user1 SET pgaudit.log = 'DDL, READ';", +\connect - 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 +);", +-- +-- Select is session logged +SELECT * + FROM account; +NOTICE: AUDIT: SESSION,2,1,READ,SELECT,,,"SELECT * + FROM account;", + 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 - :current_user +ALTER ROLE user1 SET pgaudit.log = 'none'; +NOTICE: AUDIT: SESSION,1,1,ROLE,ALTER ROLE,,,ALTER ROLE user1 SET pgaudit.log = 'none';, +ALTER ROLE user1 SET pgaudit.role = 'auditor'; +NOTICE: AUDIT: SESSION,2,1,ROLE,ALTER ROLE,,,ALTER ROLE user1 SET pgaudit.role = 'auditor';, +\connect - 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;", + 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';", +-- +-- Change permissions of user 1 so that session relation logging will be done +\connect - :current_user +ALTER ROLE user1 SET pgaudit.log_relation = on; +NOTICE: AUDIT: SESSION,1,1,ROLE,ALTER ROLE,,,ALTER ROLE user1 SET pgaudit.log_relation = on;, +ALTER ROLE user1 SET pgaudit.log = 'read, WRITE'; +NOTICE: AUDIT: SESSION,2,1,ROLE,ALTER ROLE,,,"ALTER ROLE user1 SET pgaudit.log = 'read, WRITE';", +\connect - 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;", +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;", +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;", +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;", + 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;", +NOTICE: AUDIT: SESSION,2,1,READ,SELECT,TABLE,public.account,"SELECT password + FROM account;", + 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';", +-- +-- 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';", +NOTICE: AUDIT: SESSION,4,1,WRITE,UPDATE,TABLE,public.account,"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'; +NOTICE: AUDIT: OBJECT,5,1,WRITE,UPDATE,TABLE,public.account,"UPDATE account + SET password = 'HASH2';", +NOTICE: AUDIT: SESSION,5,1,WRITE,UPDATE,TABLE,public.account,"UPDATE account + SET password = 'HASH2';", +-- +-- Change back to superuser to do exhaustive tests +\connect - :current_user +SET pgaudit.log = 'ALL'; +NOTICE: AUDIT: SESSION,1,1,MISC,SET,,,SET pgaudit.log = 'ALL';, +SET pgaudit.log_level = 'notice'; +NOTICE: AUDIT: SESSION,2,1,MISC,SET,,,SET pgaudit.log_level = 'notice';, +SET pgaudit.log_client = ON; +NOTICE: AUDIT: SESSION,3,1,MISC,SET,,,SET pgaudit.log_client = ON;, +SET pgaudit.log_relation = ON; +NOTICE: AUDIT: SESSION,4,1,MISC,SET,,,SET pgaudit.log_relation = ON;, +SET pgaudit.log_parameter = ON; +NOTICE: AUDIT: SESSION,5,1,MISC,SET,,,SET pgaudit.log_parameter = ON;, +-- +-- Simple DO block +DO $$ +BEGIN + raise notice 'test'; +END $$; +NOTICE: AUDIT: SESSION,6,1,FUNCTION,DO,,,"DO $$ +BEGIN + raise notice 'test'; +END $$;", +NOTICE: test +-- +-- Create test schema +CREATE SCHEMA test; +NOTICE: AUDIT: SESSION,7,1,DDL,CREATE SCHEMA,SCHEMA,test,CREATE SCHEMA test;, +-- +-- Copy account to stdout +COPY account TO stdout; +NOTICE: AUDIT: SESSION,8,1,READ,SELECT,TABLE,public.account,COPY account TO stdout;, +1 user1 HASH2 yada, yada +-- +-- Create a table from a query +CREATE TABLE test.account_copy AS +SELECT * + FROM account; +NOTICE: AUDIT: SESSION,9,1,READ,SELECT,TABLE,public.account,"CREATE TABLE test.account_copy AS +SELECT * + FROM account;", +NOTICE: AUDIT: SESSION,9,1,WRITE,INSERT,TABLE,test.account_copy,"CREATE TABLE test.account_copy AS +SELECT * + FROM account;", +NOTICE: AUDIT: SESSION,9,2,DDL,CREATE TABLE AS,TABLE,test.account_copy,"CREATE TABLE test.account_copy AS +SELECT * + FROM account;", +-- +-- Copy from stdin to account copy +COPY test.account_copy from stdin; +NOTICE: AUDIT: SESSION,10,1,WRITE,INSERT,TABLE,test.account_copy,COPY test.account_copy from stdin;, +-- +-- Test prepared statement +PREPARE pgclassstmt (oid) AS +SELECT * + FROM account + WHERE id = $1; +NOTICE: AUDIT: SESSION,11,1,READ,PREPARE,,,"PREPARE pgclassstmt (oid) AS +SELECT * + FROM account + WHERE id = $1;", +EXECUTE pgclassstmt (1); +NOTICE: AUDIT: SESSION,12,1,READ,SELECT,TABLE,public.account,"PREPARE pgclassstmt (oid) AS +SELECT * + FROM account + WHERE id = $1;",1 +NOTICE: AUDIT: SESSION,12,2,MISC,EXECUTE,,,EXECUTE pgclassstmt (1);, + id | name | password | description +----+-------+----------+------------- + 1 | user1 | HASH2 | yada, yada +(1 row) + +DEALLOCATE pgclassstmt; +NOTICE: AUDIT: SESSION,13,1,MISC,DEALLOCATE,,,DEALLOCATE pgclassstmt;, +-- +-- Test cursor +BEGIN; +NOTICE: AUDIT: SESSION,14,1,MISC,BEGIN,,,BEGIN;, +DECLARE ctest SCROLL CURSOR FOR +SELECT count(*) + FROM +( + SELECT relname + FROM pg_class + LIMIT 1 + ) subquery; +NOTICE: AUDIT: SESSION,15,1,READ,SELECT,TABLE,pg_catalog.pg_class,"DECLARE ctest SCROLL CURSOR FOR +SELECT count(*) + FROM +( + SELECT relname + FROM pg_class + LIMIT 1 + ) subquery;", +NOTICE: AUDIT: SESSION,15,2,READ,DECLARE CURSOR,,,"DECLARE ctest SCROLL CURSOR FOR +SELECT count(*) + FROM +( + SELECT relname + FROM pg_class + LIMIT 1 + ) subquery;", +FETCH NEXT FROM ctest; +NOTICE: AUDIT: SESSION,16,1,MISC,FETCH,,,FETCH NEXT FROM ctest;, + count +------- + 1 +(1 row) + +CLOSE ctest; +NOTICE: AUDIT: SESSION,17,1,MISC,CLOSE CURSOR,,,CLOSE ctest;, +COMMIT; +NOTICE: AUDIT: SESSION,18,1,MISC,COMMIT,,,COMMIT;, +-- +-- Turn off log_catalog and pg_class will not be logged +SET pgaudit.log_catalog = OFF; +NOTICE: AUDIT: SESSION,19,1,MISC,SET,,,SET pgaudit.log_catalog = OFF;, +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,20,1,DDL,CREATE TABLE,TABLE,test.test_insert,"CREATE TABLE test.test_insert +( + id INT +);", +PREPARE pgclassstmt (oid) AS +INSERT INTO test.test_insert (id) + VALUES ($1); +NOTICE: AUDIT: SESSION,21,1,WRITE,PREPARE,,,"PREPARE pgclassstmt (oid) AS +INSERT INTO test.test_insert (id) + VALUES ($1);", +EXECUTE pgclassstmt (1); +NOTICE: AUDIT: SESSION,22,1,WRITE,INSERT,TABLE,test.test_insert,"PREPARE pgclassstmt (oid) AS +INSERT INTO test.test_insert (id) + VALUES ($1);",1 +NOTICE: AUDIT: SESSION,22,2,MISC,EXECUTE,,,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) +); +NOTICE: AUDIT: SESSION,23,1,DDL,CREATE TABLE,TABLE,public.test,"CREATE TABLE public.test +( + id INT, + name TEXT, + description TEXT, + CONSTRAINT test_pkey PRIMARY KEY (id) +);", +NOTICE: AUDIT: SESSION,23,1,DDL,CREATE INDEX,INDEX,public.test_pkey,"CREATE TABLE public.test +( + id INT, + name TEXT, + description TEXT, + CONSTRAINT test_pkey PRIMARY KEY (id) +);", +-- +-- Check that analyze is logged +ANALYZE test; +NOTICE: AUDIT: SESSION,24,1,MISC,ANALYZE,,,ANALYZE test;, +-- +-- Grants to public should not cause object logging (session logging will +-- still happen) +GRANT SELECT + ON TABLE public.test + TO PUBLIC; +NOTICE: AUDIT: SESSION,25,1,ROLE,GRANT,TABLE,,"GRANT SELECT + ON TABLE public.test + TO PUBLIC;", +SELECT * + FROM test; +NOTICE: AUDIT: SESSION,26,1,READ,SELECT,TABLE,public.test,"SELECT * + FROM test;", + id | name | description +----+------+------------- +(0 rows) + +-- Check that statements without columns log +SELECT + FROM test; +NOTICE: AUDIT: SESSION,27,1,READ,SELECT,TABLE,public.test,"SELECT + FROM test;", +-- +(0 rows) + +SELECT 1, + substring('Thomas' from 2 for 3); +NOTICE: AUDIT: SESSION,28,1,READ,SELECT,,,"SELECT 1, + substring('Thomas' from 2 for 3);", + ?column? | substring +----------+----------- + 1 | hom +(1 row) + +DO $$ +DECLARE + test INT; +BEGIN + SELECT 1 + INTO test; +END $$; +NOTICE: AUDIT: SESSION,29,1,FUNCTION,DO,,,"DO $$ +DECLARE + test INT; +BEGIN + SELECT 1 + INTO test; +END $$;", +NOTICE: AUDIT: SESSION,29,2,READ,SELECT,,,SELECT 1, +explain select 1; +NOTICE: AUDIT: SESSION,30,1,READ,SELECT,,,explain select 1;, +NOTICE: AUDIT: SESSION,30,2,MISC,EXPLAIN,,,explain select 1;, + 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,31,1,WRITE,INSERT,TABLE,public.test,"INSERT INTO TEST (id) + VALUES (1);", +INSERT INTO TEST (id) + VALUES (2); +NOTICE: AUDIT: SESSION,32,1,WRITE,INSERT,TABLE,public.test,"INSERT INTO TEST (id) + VALUES (2);", +INSERT INTO TEST (id) + VALUES (3); +NOTICE: AUDIT: SESSION,33,1,WRITE,INSERT,TABLE,public.test,"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 $$; +NOTICE: AUDIT: SESSION,34,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 $$;", +NOTICE: AUDIT: SESSION,34,2,READ,SELECT,TABLE,public.test,"SELECT id + FROM test", +NOTICE: AUDIT: SESSION,34,3,WRITE,INSERT,TABLE,public.test,"INSERT INTO test (id) + VALUES (result.id + 100)","f,," +NOTICE: AUDIT: SESSION,34,4,WRITE,INSERT,TABLE,public.test,"INSERT INTO test (id) + VALUES (result.id + 100)","t,," +NOTICE: AUDIT: SESSION,34,5,WRITE,INSERT,TABLE,public.test,"INSERT INTO test (id) + VALUES (result.id + 100)","t,," +-- +-- 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,35,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 $$;", +NOTICE: AUDIT: SESSION,35,2,DDL,CREATE TABLE,TABLE,public.do_table,"CREATE TABLE do_table (""weird name"" INT)", +NOTICE: AUDIT: SESSION,35,3,DDL,DROP TABLE,TABLE,public.do_table,DROP table do_table, +-- +-- Generate an error and make sure the stack gets cleared +DO $$ +BEGIN + CREATE TABLE bogus.test_block + ( + id INT + ); +END $$; +NOTICE: AUDIT: SESSION,36,1,FUNCTION,DO,,,"DO $$ +BEGIN + CREATE TABLE bogus.test_block + ( + id INT + ); +END $$;", +ERROR: schema "bogus" does not exist at character 14 +-- +-- Test alter table statements +ALTER TABLE public.test + DROP COLUMN description ; +NOTICE: AUDIT: SESSION,37,1,DDL,ALTER TABLE,TABLE COLUMN,public.test.description,"ALTER TABLE public.test + DROP COLUMN description ;", +NOTICE: AUDIT: SESSION,37,1,DDL,ALTER TABLE,TABLE,public.test,"ALTER TABLE public.test + DROP COLUMN description ;", +ALTER TABLE public.test + RENAME TO test2; +NOTICE: AUDIT: SESSION,38,1,DDL,ALTER TABLE,TABLE,public.test2,"ALTER TABLE public.test + RENAME TO test2;", +ALTER TABLE public.test2 + SET SCHEMA test; +NOTICE: AUDIT: SESSION,39,1,DDL,ALTER TABLE,TABLE,test.test2,"ALTER TABLE public.test2 + SET SCHEMA test;", +ALTER TABLE test.test2 + ADD COLUMN description TEXT; +NOTICE: AUDIT: SESSION,40,1,DDL,ALTER TABLE,TABLE,test.test2,"ALTER TABLE test.test2 + ADD COLUMN description TEXT;", +ALTER TABLE test.test2 + DROP COLUMN description; +NOTICE: AUDIT: SESSION,41,1,DDL,ALTER TABLE,TABLE COLUMN,test.test2.description,"ALTER TABLE test.test2 + DROP COLUMN description;", +NOTICE: AUDIT: SESSION,41,1,DDL,ALTER TABLE,TABLE,test.test2,"ALTER TABLE test.test2 + DROP COLUMN description;", +DROP TABLE test.test2; +NOTICE: AUDIT: SESSION,42,1,DDL,DROP TABLE,TABLE,test.test2,DROP TABLE test.test2;, +NOTICE: AUDIT: SESSION,42,1,DDL,DROP TABLE,TABLE CONSTRAINT,test_pkey on test.test2,DROP TABLE test.test2;, +NOTICE: AUDIT: SESSION,42,1,DDL,DROP TABLE,INDEX,test.test_pkey,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); +NOTICE: AUDIT: SESSION,43,1,DDL,CREATE SCHEMA,SCHEMA,foo,"CREATE SCHEMA foo + CREATE TABLE foo.bar (id int) + CREATE TABLE foo.baz (id int);", +NOTICE: AUDIT: SESSION,43,1,DDL,CREATE TABLE,TABLE,foo.bar,"CREATE SCHEMA foo + CREATE TABLE foo.bar (id int) + CREATE TABLE foo.baz (id int);", +NOTICE: AUDIT: SESSION,43,1,DDL,CREATE TABLE,TABLE,foo.baz,"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 $$; +NOTICE: AUDIT: SESSION,44,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 $$;", +SELECT int_add(1, 1); +NOTICE: AUDIT: SESSION,45,1,READ,SELECT,,,"SELECT int_add(1, 1);", +NOTICE: AUDIT: SESSION,45,2,FUNCTION,EXECUTE,FUNCTION,public.int_add,"SELECT int_add(1, 1);", + int_add +--------- + 2 +(1 row) + +CREATE AGGREGATE public.sum_test(INT) (SFUNC=public.int_add, STYPE=INT, INITCOND='0'); +NOTICE: AUDIT: SESSION,46,1,DDL,CREATE AGGREGATE,AGGREGATE,public.sum_test(integer),"CREATE AGGREGATE public.sum_test(INT) (SFUNC=public.int_add, STYPE=INT, INITCOND='0');", +ALTER AGGREGATE public.sum_test(integer) RENAME TO sum_test2; +NOTICE: AUDIT: SESSION,47,1,DDL,ALTER AGGREGATE,AGGREGATE,public.sum_test2(integer),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; +NOTICE: AUDIT: SESSION,48,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;, +ALTER CONVERSION public.conversion_test RENAME TO conversion_test2; +NOTICE: AUDIT: SESSION,49,1,DDL,ALTER CONVERSION,CONVERSION,public.conversion_test2,ALTER CONVERSION public.conversion_test RENAME TO conversion_test2;, +-- +-- Test create/alter/drop database +CREATE DATABASE contrib_regression_pgaudit; +NOTICE: AUDIT: SESSION,50,1,DDL,CREATE DATABASE,,,CREATE DATABASE contrib_regression_pgaudit;, +ALTER DATABASE contrib_regression_pgaudit RENAME TO contrib_regression_pgaudit2; +NOTICE: AUDIT: SESSION,51,1,DDL,ALTER DATABASE,,,ALTER DATABASE contrib_regression_pgaudit RENAME TO contrib_regression_pgaudit2;, +DROP DATABASE contrib_regression_pgaudit2; +NOTICE: AUDIT: SESSION,52,1,DDL,DROP DATABASE,,,DROP DATABASE contrib_regression_pgaudit2;, +-- Test role as a substmt +SET pgaudit.log = 'ROLE'; +CREATE TABLE t (); +CREATE ROLE alice; +NOTICE: AUDIT: SESSION,53,1,ROLE,CREATE ROLE,,,CREATE ROLE alice;, +CREATE SCHEMA foo2 + GRANT SELECT + ON public.t + TO alice; +NOTICE: AUDIT: SESSION,54,1,ROLE,GRANT,TABLE,,"CREATE SCHEMA foo2 + GRANT SELECT + ON public.t + TO alice;", +drop table public.t; +drop role alice; +NOTICE: AUDIT: SESSION,55,1,ROLE,DROP ROLE,,,drop role alice;, +-- +-- Test that frees a memory context earlier than expected +SET pgaudit.log = 'ALL'; +NOTICE: AUDIT: SESSION,56,1,MISC,SET,,,SET pgaudit.log = 'ALL';, +CREATE TABLE hoge +( + id int +); +NOTICE: AUDIT: SESSION,57,1,DDL,CREATE TABLE,TABLE,public.hoge,"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 ; +NOTICE: AUDIT: SESSION,58,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 ;", +SELECT test(); +NOTICE: AUDIT: SESSION,59,1,READ,SELECT,,,SELECT test();, +NOTICE: AUDIT: SESSION,59,2,FUNCTION,EXECUTE,FUNCTION,public.test,SELECT test();, +NOTICE: AUDIT: SESSION,59,3,READ,SELECT,TABLE,public.hoge,select * from hoge, + test +------ + +(1 row) + +-- +-- Delete all rows then delete 1 row +SET pgaudit.log = 'write'; +SET pgaudit.role = 'auditor'; +create table bar +( + col int +); +grant delete + on bar + to auditor; +insert into bar (col) + values (1); +NOTICE: AUDIT: SESSION,60,1,WRITE,INSERT,TABLE,public.bar,"insert into bar (col) + values (1);", +delete from bar; +NOTICE: AUDIT: OBJECT,61,1,WRITE,DELETE,TABLE,public.bar,delete from bar;, +NOTICE: AUDIT: SESSION,61,1,WRITE,DELETE,TABLE,public.bar,delete from bar;, +insert into bar (col) + values (1); +NOTICE: AUDIT: SESSION,62,1,WRITE,INSERT,TABLE,public.bar,"insert into bar (col) + values (1);", +delete from bar + where col = 1; +NOTICE: AUDIT: OBJECT,63,1,WRITE,DELETE,TABLE,public.bar,"delete from bar + where col = 1;", +NOTICE: AUDIT: SESSION,63,1,WRITE,DELETE,TABLE,public.bar,"delete from bar + where col = 1;", +drop table bar; +-- +-- Grant roles to each other +SET pgaudit.log = 'role'; +GRANT user1 TO user2; +NOTICE: AUDIT: SESSION,64,1,ROLE,GRANT ROLE,,,GRANT user1 TO user2;, +REVOKE user1 FROM user2; +NOTICE: AUDIT: SESSION,65,1,ROLE,REVOKE ROLE,,,REVOKE user1 FROM user2;, +-- +-- Test that FK references do not log but triggers still do +SET pgaudit.log = 'READ,WRITE'; +SET pgaudit.role TO 'auditor'; +SET pgaudit.log_parameter TO OFF; +CREATE TABLE aaa +( + ID int primary key +); +CREATE TABLE bbb +( + id int + references aaa(id) +); +CREATE FUNCTION bbb_insert() RETURNS TRIGGER AS $$ +BEGIN + UPDATE bbb set id = new.id + 1; + + RETURN new; +END $$ LANGUAGE plpgsql; +CREATE TRIGGER bbb_insert_trg + AFTER INSERT ON bbb + FOR EACH ROW EXECUTE PROCEDURE bbb_insert(); +GRANT SELECT + ON aaa + TO auditor; +GRANT UPDATE + ON bbb + TO auditor; +INSERT INTO aaa VALUES (generate_series(1,100)); +NOTICE: AUDIT: SESSION,66,1,WRITE,INSERT,TABLE,public.aaa,"INSERT INTO aaa VALUES (generate_series(1,100));", +INSERT INTO bbb VALUES (1); +NOTICE: AUDIT: SESSION,67,1,WRITE,INSERT,TABLE,public.bbb,INSERT INTO bbb VALUES (1);, +NOTICE: AUDIT: OBJECT,67,2,WRITE,UPDATE,TABLE,public.aaa,"SELECT 1 FROM ONLY ""public"".""aaa"" x WHERE ""id"" OPERATOR(pg_catalog.=) $1 FOR KEY SHARE OF x", +NOTICE: AUDIT: SESSION,67,2,WRITE,UPDATE,TABLE,public.aaa,"SELECT 1 FROM ONLY ""public"".""aaa"" x WHERE ""id"" OPERATOR(pg_catalog.=) $1 FOR KEY SHARE OF x", +NOTICE: AUDIT: OBJECT,67,3,WRITE,UPDATE,TABLE,public.bbb,UPDATE bbb set id = new.id + 1, +NOTICE: AUDIT: SESSION,67,3,WRITE,UPDATE,TABLE,public.bbb,UPDATE bbb set id = new.id + 1, +NOTICE: AUDIT: OBJECT,67,4,WRITE,UPDATE,TABLE,public.aaa,"SELECT 1 FROM ONLY ""public"".""aaa"" x WHERE ""id"" OPERATOR(pg_catalog.=) $1 FOR KEY SHARE OF x", +NOTICE: AUDIT: SESSION,67,4,WRITE,UPDATE,TABLE,public.aaa,"SELECT 1 FROM ONLY ""public"".""aaa"" x WHERE ""id"" OPERATOR(pg_catalog.=) $1 FOR KEY SHARE OF x", +DROP TABLE bbb; +DROP TABLE aaa; +-- Cleanup +-- Set client_min_messages up to warning to avoid noise +SET client_min_messages = 'warning'; +ALTER ROLE :current_user RESET pgaudit.log; +ALTER ROLE :current_user RESET pgaudit.log_catalog; +ALTER ROLE :current_user RESET pgaudit.log_level; +ALTER ROLE :current_user RESET pgaudit.log_parameter; +ALTER ROLE :current_user RESET pgaudit.log_relation; +ALTER ROLE :current_user RESET pgaudit.log_statement_once; +ALTER ROLE :current_user RESET pgaudit.role; +RESET pgaudit.log; +RESET pgaudit.log_catalog; +RESET pgaudit.log_level; +RESET pgaudit.log_parameter; +RESET pgaudit.log_relation; +RESET pgaudit.log_statement_once; +RESET pgaudit.role; +DROP TABLE test.account_copy; +DROP TABLE test.test_insert; +DROP SCHEMA test; +DROP TABLE foo.bar; +DROP TABLE foo.baz; +DROP SCHEMA foo; +DROP TABLE hoge; +DROP TABLE account; +DROP TABLE account_role_map; +DROP USER user2; +DROP USER user1; +DROP ROLE auditor; +RESET client_min_messages; diff --git a/contrib/pgaudit/sql/pgaudit.sql b/contrib/pgaudit/sql/pgaudit.sql new file mode 100644 index 0000000..1c81d70 --- /dev/null +++ b/contrib/pgaudit/sql/pgaudit.sql @@ -0,0 +1,780 @@ +\set VERBOSITY terse + +-- Create pgaudit extension +CREATE EXTENSION IF NOT EXISTS pgaudit; + +-- +-- 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 + +SELECT current_user \gset + +-- +-- Set pgaudit parameters for the current (super)user. +ALTER ROLE :current_user SET pgaudit.log = 'Role'; +ALTER ROLE :current_user SET pgaudit.log_level = 'notice'; +ALTER ROLE :current_user SET pgaudit.log_client = ON; + +-- After each connect, we need to load pgaudit, as if it was +-- being loaded from shared_preload_libraries. Otherwise, the hooks +-- won't be set up and called correctly, leading to lots of ugly +-- errors. +\connect - :current_user; + +-- +-- Create auditor role +CREATE ROLE auditor; + +-- +-- Create first test user +CREATE USER user1; +ALTER ROLE user1 SET pgaudit.log = 'ddl, ROLE'; +ALTER ROLE user1 SET pgaudit.log_level = 'notice'; +ALTER ROLE user1 SET pgaudit.log_client = ON; + +-- +-- Create, select, drop (select will not be audited) +\connect - user1 + +CREATE TABLE public.test +( + id INT +); + +SELECT * + FROM test; + +DROP TABLE test; + +-- +-- Create second test user +\connect - :current_user + +CREATE USER user2; +ALTER ROLE user2 SET pgaudit.log = 'Read, writE'; +ALTER ROLE user2 SET pgaudit.log_catalog = OFF; +ALTER ROLE user2 SET pgaudit.log_level = 'warning'; +ALTER ROLE user2 SET pgaudit.log_client = ON; +ALTER ROLE user2 SET pgaudit.role = auditor; +ALTER ROLE user2 SET pgaudit.log_statement_once = ON; + +-- +-- Setup role-based tests +CREATE TABLE test2 +( + id INT +); + +GRANT SELECT, INSERT, UPDATE, DELETE + ON test2 + TO user2, user1; + +GRANT SELECT, UPDATE + ON TABLE public.test2 + TO auditor; + +CREATE TABLE test3 +( + id INT +); + +GRANT SELECT, INSERT, UPDATE, DELETE + ON test3 + TO user2; + +GRANT INSERT + ON TABLE public.test3 + TO auditor; + +CREATE FUNCTION test2_insert() RETURNS TRIGGER AS $$ +BEGIN + UPDATE test2 + SET id = id + 90 + WHERE id = new.id; + + RETURN new; +END $$ LANGUAGE plpgsql security definer; +ALTER FUNCTION test2_insert() OWNER TO user1; + +CREATE TRIGGER test2_insert_trg + AFTER INSERT ON test2 + FOR EACH ROW EXECUTE PROCEDURE test2_insert(); + +CREATE FUNCTION test2_change(change_id int) RETURNS void AS $$ +BEGIN + UPDATE test2 + SET id = id + 1 + WHERE id = change_id; +END $$ LANGUAGE plpgsql security definer; +ALTER FUNCTION test2_change(int) OWNER TO user2; + +CREATE VIEW vw_test3 AS +SELECT * + FROM test3; + +GRANT SELECT + ON vw_test3 + TO user2; + +GRANT SELECT + ON vw_test3 + TO auditor; + +\connect - user2 + +-- +-- Role-based tests +SELECT count(*) + FROM +( + SELECT relname + FROM pg_class + LIMIT 1 +) SUBQUERY; + +SELECT * + FROM test3, test2; + +-- +-- 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; + +DO $$ BEGIN PERFORM test2_change(91); END $$; + +-- +-- Object logged because of: +-- insert on test3 +-- update on test2 +WITH CTE AS +( + UPDATE test2 + SET id = 45 + WHERE id = 92 + RETURNING id +) +INSERT INTO test3 +SELECT id + FROM cte; + +-- +-- Object logged because of: +-- insert on test2 +WITH CTE AS +( + INSERT INTO test2 VALUES (37) + RETURNING id +) +UPDATE test3 + SET id = cte.id + FROM cte + WHERE test3.id <> cte.id; + +-- +-- Be sure that test has correct contents +SELECT * + FROM test2 + ORDER BY ID; + +-- +-- Change permissions of user 2 so that only object logging will be done +\connect - :current_user +ALTER ROLE user2 SET pgaudit.log = 'NONE'; + +\connect - 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'; + +-- +-- Change permissions of user 1 so that session logging will be done +\connect - :current_user + +-- +-- Drop test tables +DROP TABLE test2; +DROP VIEW vw_test3; +DROP TABLE test3; +DROP TABLE test4; +DROP FUNCTION test2_insert(); +DROP FUNCTION test2_change(int); + +ALTER ROLE user1 SET pgaudit.log = 'DDL, READ'; +\connect - 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 - :current_user +ALTER ROLE user1 SET pgaudit.log = 'none'; +ALTER ROLE user1 SET pgaudit.role = 'auditor'; +\connect - 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 - :current_user +ALTER ROLE user1 SET pgaudit.log_relation = on; +ALTER ROLE user1 SET pgaudit.log = 'read, WRITE'; +\connect - 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 - :current_user +SET pgaudit.log = 'ALL'; +SET pgaudit.log_level = 'notice'; +SET pgaudit.log_client = ON; +SET pgaudit.log_relation = ON; +SET pgaudit.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 pgaudit.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, + substring('Thomas' from 2 for 3); + +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 role as a substmt +SET pgaudit.log = 'ROLE'; + +CREATE TABLE t (); +CREATE ROLE alice; + +CREATE SCHEMA foo2 + GRANT SELECT + ON public.t + TO alice; + +drop table public.t; +drop role alice; + +-- +-- Test that frees a memory context earlier than expected +SET pgaudit.log = 'ALL'; + +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 pgaudit.log = 'write'; +SET pgaudit.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 pgaudit.log = 'role'; +GRANT user1 TO user2; +REVOKE user1 FROM user2; + +-- +-- Test that FK references do not log but triggers still do +SET pgaudit.log = 'READ,WRITE'; +SET pgaudit.role TO 'auditor'; +SET pgaudit.log_parameter TO OFF; + +CREATE TABLE aaa +( + ID int primary key +); + +CREATE TABLE bbb +( + id int + references aaa(id) +); + +CREATE FUNCTION bbb_insert() RETURNS TRIGGER AS $$ +BEGIN + UPDATE bbb set id = new.id + 1; + + RETURN new; +END $$ LANGUAGE plpgsql; + +CREATE TRIGGER bbb_insert_trg + AFTER INSERT ON bbb + FOR EACH ROW EXECUTE PROCEDURE bbb_insert(); + +GRANT SELECT + ON aaa + TO auditor; + +GRANT UPDATE + ON bbb + TO auditor; + +INSERT INTO aaa VALUES (generate_series(1,100)); +INSERT INTO bbb VALUES (1); + +DROP TABLE bbb; +DROP TABLE aaa; + +-- Cleanup +-- Set client_min_messages up to warning to avoid noise +SET client_min_messages = 'warning'; + +ALTER ROLE :current_user RESET pgaudit.log; +ALTER ROLE :current_user RESET pgaudit.log_catalog; +ALTER ROLE :current_user RESET pgaudit.log_level; +ALTER ROLE :current_user RESET pgaudit.log_parameter; +ALTER ROLE :current_user RESET pgaudit.log_relation; +ALTER ROLE :current_user RESET pgaudit.log_statement_once; +ALTER ROLE :current_user RESET pgaudit.role; + +RESET pgaudit.log; +RESET pgaudit.log_catalog; +RESET pgaudit.log_level; +RESET pgaudit.log_parameter; +RESET pgaudit.log_relation; +RESET pgaudit.log_statement_once; +RESET pgaudit.role; + +DROP TABLE test.account_copy; +DROP TABLE test.test_insert; +DROP SCHEMA test; +DROP TABLE foo.bar; +DROP TABLE foo.baz; +DROP SCHEMA foo; +DROP TABLE hoge; +DROP TABLE account; +DROP TABLE account_role_map; +DROP USER user2; +DROP USER user1; +DROP ROLE auditor; + +RESET client_min_messages;