diff --git a/contrib/Makefile b/contrib/Makefile index bd251f6..0046610 100644 --- a/contrib/Makefile +++ b/contrib/Makefile @@ -34,6 +34,7 @@ SUBDIRS = \ pg_standby \ pg_stat_statements \ pg_trgm \ + pgaudit \ pgcrypto \ pgrowlocks \ pgstattuple \ diff --git a/contrib/pgaudit/.gitignore b/contrib/pgaudit/.gitignore new file mode 100644 index 0000000..e8d2612 --- /dev/null +++ b/contrib/pgaudit/.gitignore @@ -0,0 +1,8 @@ +log/ +results/ +tmp_check/ +regression.diffs +regression.out +*.o +*.so +.vagrant diff --git a/contrib/pgaudit/LICENSE b/contrib/pgaudit/LICENSE new file mode 100644 index 0000000..998f814 --- /dev/null +++ b/contrib/pgaudit/LICENSE @@ -0,0 +1,4 @@ +This code is released under the PostgreSQL licence, as given at +http://www.postgresql.org/about/licence/ + +Copyright is novated to the PostgreSQL Global Development Group. diff --git a/contrib/pgaudit/Makefile b/contrib/pgaudit/Makefile new file mode 100644 index 0000000..b3a488b --- /dev/null +++ b/contrib/pgaudit/Makefile @@ -0,0 +1,22 @@ +# contrib/pg_audit/Makefile + +MODULE_big = pgaudit +OBJS = pgaudit.o $(WIN32RES) + +EXTENSION = pgaudit +DATA = pgaudit--1.0.sql +PGFILEDESC = "pgAudit - An audit logging extension for PostgreSQL" + +REGRESS = pgaudit +REGRESS_OPTS = --temp-config=$(top_srcdir)/contrib/pgaudit/pgaudit.conf + +ifdef USE_PGXS +PG_CONFIG = pg_config +PGXS := $(shell $(PG_CONFIG) --pgxs) +include $(PGXS) +else +subdir = contrib/pgaudit +top_builddir = ../.. +include $(top_builddir)/src/Makefile.global +include $(top_srcdir)/contrib/contrib-global.mk +endif 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/pgaudit--1.0.sql b/contrib/pgaudit/pgaudit--1.0.sql new file mode 100644 index 0000000..e0a12b7 --- /dev/null +++ b/contrib/pgaudit/pgaudit--1.0.sql @@ -0,0 +1,22 @@ +/* pgaudit/pgaudit--1.0.sql */ + +-- complain if script is sourced in psql, rather than via CREATE EXTENSION +\echo Use "CREATE EXTENSION pgaudit" to load this file.\quit + +CREATE FUNCTION pgaudit_ddl_command_end() + RETURNS event_trigger + LANGUAGE C + AS 'MODULE_PATHNAME', 'pgaudit_ddl_command_end'; + +CREATE EVENT TRIGGER pgaudit_ddl_command_end + ON ddl_command_end + EXECUTE PROCEDURE pgaudit_ddl_command_end(); + +CREATE FUNCTION pgaudit_sql_drop() + RETURNS event_trigger + LANGUAGE C + AS 'MODULE_PATHNAME', 'pgaudit_sql_drop'; + +CREATE EVENT TRIGGER pgaudit_sql_drop + ON sql_drop + EXECUTE PROCEDURE pgaudit_sql_drop(); diff --git a/contrib/pgaudit/pgaudit.c b/contrib/pgaudit/pgaudit.c new file mode 100644 index 0000000..00be0c2 --- /dev/null +++ b/contrib/pgaudit/pgaudit.c @@ -0,0 +1,1922 @@ +/*------------------------------------------------------------------------------ + * pgaudit.c + * + * An audit logging extension for PostgreSQL. Provides detailed logging classes, + * object level logging, and fully-qualified object names for all DML and DDL + * statements where possible (See pgaudit.sgml for details). + * + * Copyright (c) 2014-2015, PostgreSQL Global Development Group + * + * IDENTIFICATION + * contrib/pgaudit/pgaudit.c + *------------------------------------------------------------------------------ + */ +#include "postgres.h" + +#include "access/htup_details.h" +#include "access/sysattr.h" +#include "access/xact.h" +#include "catalog/catalog.h" +#include "catalog/objectaccess.h" +#include "catalog/pg_class.h" +#include "catalog/namespace.h" +#include "commands/dbcommands.h" +#include "catalog/pg_proc.h" +#include "commands/event_trigger.h" +#include "executor/executor.h" +#include "executor/spi.h" +#include "miscadmin.h" +#include "libpq/auth.h" +#include "nodes/nodes.h" +#include "tcop/utility.h" +#include "tcop/deparse_utility.h" +#include "utils/acl.h" +#include "utils/builtins.h" +#include "utils/guc.h" +#include "utils/lsyscache.h" +#include "utils/memutils.h" +#include "utils/rel.h" +#include "utils/syscache.h" +#include "utils/timestamp.h" + +PG_MODULE_MAGIC; + +void _PG_init(void); + +PG_FUNCTION_INFO_V1(pgaudit_ddl_command_end); +PG_FUNCTION_INFO_V1(pgaudit_sql_drop); + +/* + * Log Classes + * + * pgAudit categorizes actions into classes (eg: DDL, FUNCTION calls, READ + * queries, WRITE queries). A GUC is provided for the administrator to + * configure which class (or classes) of actions to include in the + * audit log. We track the currently active set of classes using + * auditLogBitmap. + */ + +/* Bits within auditLogBitmap, defines the classes we understand */ +#define LOG_DDL (1 << 0) /* CREATE/DROP/ALTER objects */ +#define LOG_FUNCTION (1 << 1) /* Functions and DO blocks */ +#define LOG_MISC (1 << 2) /* Statements not covered */ +#define LOG_READ (1 << 3) /* SELECTs */ +#define LOG_ROLE (1 << 4) /* GRANT/REVOKE, CREATE/ALTER/DROP ROLE */ +#define LOG_WRITE (1 << 5) /* INSERT, UPDATE, DELETE, TRUNCATE */ + +#define LOG_NONE 0 /* nothing */ +#define LOG_ALL (0xFFFFFFFF) /* All */ + +/* GUC variable for pgaudit.log, which defines the classes to log. */ +char *auditLog = NULL; + +/* Bitmap of classes selected */ +static int auditLogBitmap = LOG_NONE; + +/* + * String constants for log classes - used when processing tokens in the + * pgaudit.log GUC. + */ +#define CLASS_DDL "DDL" +#define CLASS_FUNCTION "FUNCTION" +#define CLASS_MISC "MISC" +#define CLASS_READ "READ" +#define CLASS_ROLE "ROLE" +#define CLASS_WRITE "WRITE" + +#define CLASS_NONE "NONE" +#define CLASS_ALL "ALL" + +/* + * GUC variable for pgaudit.log_catalog + * + * Administrators can choose to NOT log queries when all relations used in + * the query are in pg_catalog. Interactive sessions (eg: psql) can cause + * a lot of noise in the logs which might be uninteresting. + */ +bool auditLogCatalog = true; + +/* + * GUC variable for pgaudit.log_client + * + * Specifies whether audit messages should be visible to the client. This + * setting should generally be left disabled but may be useful for debugging or + * other purposes. + */ +bool auditLogClient = false; + +/* + * GUC variable for pgaudit.log_level + * + * Administrators can choose which log level the audit log is to be logged + * at. The default level is LOG, which goes into the server log but does + * not go to the client. Set to NOTICE in the regression tests. + */ +char *auditLogLevelString = NULL; +int auditLogLevel = LOG; + +/* + * GUC variable for pgaudit.log_parameter + * + * Administrators can choose if parameters passed into a statement are + * included in the audit log. + */ +bool auditLogParameter = false; + +/* + * GUC variable for pgaudit.log_relation + * + * Administrators can choose, in SESSION logging, to log each relation involved + * in READ/WRITE class queries. By default, SESSION logs include the query but + * do not have a log entry for each relation. + */ +bool auditLogRelation = false; + +/* + * GUC variable for pgaudit.log_statement_once + * + * Administrators can choose to have the statement run logged only once instead + * of on every line. By default, the statement is repeated on every line of + * the audit log to facilitate searching, but this can cause the log to be + * unnecessairly bloated in some environments. + */ +bool auditLogStatementOnce = false; + +/* + * GUC variable for pgaudit.role + * + * Administrators can choose which role to base OBJECT auditing off of. + * Object-level auditing uses the privileges which are granted to this role to + * determine if a statement should be logged. + */ +char *auditRole = NULL; + +/* + * String constants for the audit log fields. + */ + +/* + * Audit type, which is responsbile for the log message + */ +#define AUDIT_TYPE_OBJECT "OBJECT" +#define AUDIT_TYPE_SESSION "SESSION" + +/* + * Command, used for SELECT/DML and function calls. + * + * We hook into the executor, but we do not have access to the parsetree there. + * Therefore we can't simply call CreateCommandTag() to get the command and have + * to build it ourselves based on what information we do have. + * + * These should be updated if new commands are added to what the exectuor + * currently handles. Note that most of the interesting commands do not go + * through the executor but rather ProcessUtility, where we have the parsetree. + */ +#define COMMAND_SELECT "SELECT" +#define COMMAND_INSERT "INSERT" +#define COMMAND_UPDATE "UPDATE" +#define COMMAND_DELETE "DELETE" +#define COMMAND_EXECUTE "EXECUTE" +#define COMMAND_UNKNOWN "UNKNOWN" + +/* + * Object type, used for SELECT/DML statements and function calls. + * + * For relation objects, this is essentially relkind (though we do not have + * access to a function which will just return a string given a relkind; + * getRelationTypeDescription() comes close but is not public currently). + * + * We also handle functions, so it isn't quite as simple as just relkind. + * + * This should be kept consistent with what is returned from + * pg_event_trigger_ddl_commands(), as that's what we use for DDL. + */ +#define OBJECT_TYPE_TABLE "TABLE" +#define OBJECT_TYPE_INDEX "INDEX" +#define OBJECT_TYPE_SEQUENCE "SEQUENCE" +#define OBJECT_TYPE_TOASTVALUE "TOAST TABLE" +#define OBJECT_TYPE_VIEW "VIEW" +#define OBJECT_TYPE_MATVIEW "MATERIALIZED VIEW" +#define OBJECT_TYPE_COMPOSITE_TYPE "COMPOSITE TYPE" +#define OBJECT_TYPE_FOREIGN_TABLE "FOREIGN TABLE" +#define OBJECT_TYPE_FUNCTION "FUNCTION" + +#define OBJECT_TYPE_UNKNOWN "UNKNOWN" + +/* + * String constants for testing role commands. Rename and drop role statements + * are assigned the nodeTag T_RenameStmt and T_DropStmt respectively. This is + * not very useful for classification, so we resort to comparing strings + * against the result of CreateCommandTag(parsetree). + */ +#define COMMAND_ALTER_ROLE "ALTER ROLE" +#define COMMAND_DROP_ROLE "DROP ROLE" +#define COMMAND_GRANT "GRANT" +#define COMMAND_REVOKE "REVOKE" + +/* + * An AuditEvent represents an operation that potentially affects a single + * object. If a statement affects multiple objects then multiple AuditEvents + * are created to represent them. + */ +typedef struct +{ + int64 statementId; /* Simple counter */ + int64 substatementId; /* Simple counter */ + + LogStmtLevel logStmtLevel; /* From GetCommandLogLevel when possible, + generated when not. */ + NodeTag commandTag; /* same here */ + const char *command; /* same here */ + const char *objectType; /* From event trigger when possible, + generated when not. */ + char *objectName; /* Fully qualified object identification */ + const char *commandText; /* sourceText / queryString */ + ParamListInfo paramList; /* QueryDesc/ProcessUtility parameters */ + + bool granted; /* Audit role has object permissions? */ + bool logged; /* Track if we have logged this event, used + post-ProcessUtility to make sure we log */ + bool statementLogged; /* Track if we have logged the statement */ +} AuditEvent; + +/* + * A simple FIFO queue to keep track of the current stack of audit events. + */ +typedef struct AuditEventStackItem +{ + struct AuditEventStackItem *next; + + AuditEvent auditEvent; + + int64 stackId; + + MemoryContext contextAudit; + MemoryContextCallback contextCallback; +} AuditEventStackItem; + +AuditEventStackItem *auditEventStack = NULL; + +/* + * pgAudit runs queries of its own when using the event trigger system. + * + * Track when we are running a query and don't log it. + */ +static bool internalStatement = false; + +/* + * Track running total for statements and substatements and whether or not + * anything has been logged since the current statement began. + */ +static int64 statementTotal = 0; +static int64 substatementTotal = 0; +static int64 stackTotal = 0; + +static bool statementLogged = false; + +/* + * Stack functions + * + * Audit events can go down to multiple levels so a stack is maintained to keep + * track of them. + */ + +/* + * Respond to callbacks registered with MemoryContextRegisterResetCallback(). + * Removes the event(s) off the stack that have become obsolete once the + * MemoryContext has been freed. The callback should always be freeing the top + * of the stack, but the code is tolerant of out-of-order callbacks. + */ +static void +stack_free(void *stackFree) +{ + AuditEventStackItem *nextItem = auditEventStack; + + /* Only process if the stack contains items */ + while (nextItem != NULL) + { + /* Check if this item matches the item to be freed */ + if (nextItem == (AuditEventStackItem *) stackFree) + { + /* Move top of stack to the item after the freed item */ + auditEventStack = nextItem->next; + + /* If the stack is not empty */ + if (auditEventStack == NULL) + { + /* + * Reset internal statement to false. Normally this will be + * reset but in case of an error it might be left set. + */ + internalStatement = false; + + /* + * Reset sub statement total so the next statement will start + * from 1. + */ + substatementTotal = 0; + + /* + * Reset statement logged so that next statement will be + * logged. + */ + statementLogged = false; + } + + return; + } + + nextItem = nextItem->next; + } +} + +/* + * Push a new audit event onto the stack and create a new memory context to + * store it. + */ +static AuditEventStackItem * +stack_push() +{ + MemoryContext contextAudit; + MemoryContext contextOld; + AuditEventStackItem *stackItem; + + /* + * Create a new memory context to contain the stack item. This will be + * free'd on stack_pop, or by our callback when the parent context is + * destroyed. + */ + contextAudit = AllocSetContextCreate(CurrentMemoryContext, + "pgaudit stack context", + ALLOCSET_DEFAULT_MINSIZE, + ALLOCSET_DEFAULT_INITSIZE, + ALLOCSET_DEFAULT_MAXSIZE); + + /* Save the old context to switch back to at the end */ + contextOld = MemoryContextSwitchTo(contextAudit); + + /* Create our new stack item in our context */ + stackItem = palloc0(sizeof(AuditEventStackItem)); + stackItem->contextAudit = contextAudit; + stackItem->stackId = ++stackTotal; + + /* + * Setup a callback in case an error happens. stack_free() will truncate + * the stack at this item. + */ + stackItem->contextCallback.func = stack_free; + stackItem->contextCallback.arg = (void *) stackItem; + MemoryContextRegisterResetCallback(contextAudit, + &stackItem->contextCallback); + + /* Push new item onto the stack */ + if (auditEventStack != NULL) + stackItem->next = auditEventStack; + else + stackItem->next = NULL; + + auditEventStack = stackItem; + + MemoryContextSwitchTo(contextOld); + + return stackItem; +} + +/* + * Pop an audit event from the stack by deleting the memory context that + * contains it. The callback to stack_free() does the actual pop. + */ +static void +stack_pop(int64 stackId) +{ + /* Make sure what we want to delete is at the top of the stack */ + if (auditEventStack != NULL && auditEventStack->stackId == stackId) + MemoryContextDelete(auditEventStack->contextAudit); + else + elog(ERROR, "pgaudit stack item " INT64_FORMAT + " not found on top - cannot pop", + stackId); +} + +/* + * Check that an item is on the stack. If not, an error will be raised since + * this is a bad state to be in and it might mean audit records are being lost. + */ +static void +stack_valid(int64 stackId) +{ + AuditEventStackItem *nextItem = auditEventStack; + + /* Look through the stack for the stack entry */ + while (nextItem != NULL && nextItem->stackId != stackId) + nextItem = nextItem->next; + + /* If we didn't find it, something went wrong. */ + if (nextItem == NULL) + elog(ERROR, "pgaudit stack item " INT64_FORMAT + " not found - top of stack is " INT64_FORMAT "", + stackId, + auditEventStack == NULL ? (int64) -1 : auditEventStack->stackId); +} + +/* + * Appends a properly quoted CSV field to StringInfo. + */ +static void +append_valid_csv(StringInfoData *buffer, const char *appendStr) +{ + const char *pChar; + + /* + * If the append string is null then do nothing. NULL fields are not + * quoted in CSV. + */ + if (appendStr == NULL) + return; + + /* Only format for CSV if appendStr contains: ", comma, \n, \r */ + if (strstr(appendStr, ",") || strstr(appendStr, "\"") || + strstr(appendStr, "\n") || strstr(appendStr, "\r")) + { + appendStringInfoCharMacro(buffer, '"'); + + for (pChar = appendStr; *pChar; pChar++) + { + if (*pChar == '"') /* double single quotes */ + appendStringInfoCharMacro(buffer, *pChar); + + appendStringInfoCharMacro(buffer, *pChar); + } + + appendStringInfoCharMacro(buffer, '"'); + } + /* Else just append */ + else + appendStringInfoString(buffer, appendStr); +} + +/* + * Takes an AuditEvent, classifies it, then logs it if appropriate. + * + * Logging is decided based on if the statement is in one of the classes being + * logged or if an object used has been marked for auditing. + * + * Objects are marked for auditing by the auditor role being granted access + * to the object. The kind of access (INSERT, UPDATE, etc) is also considered + * and logging is only performed when the kind of access matches the granted + * right on the object. + * + * This will need to be updated if new kinds of GRANTs are added. + */ +static void +log_audit_event(AuditEventStackItem *stackItem) +{ + /* By default, put everything in the MISC class. */ + int class = LOG_MISC; + const char *className = CLASS_MISC; + MemoryContext contextOld; + StringInfoData auditStr; + + /* Classify the statement using log stmt level and the command tag */ + switch (stackItem->auditEvent.logStmtLevel) + { + /* All mods go in WRITE class, except EXECUTE */ + case LOGSTMT_MOD: + className = CLASS_WRITE; + class = LOG_WRITE; + + switch (stackItem->auditEvent.commandTag) + { + /* Currently, only EXECUTE is different */ + case T_ExecuteStmt: + className = CLASS_MISC; + class = LOG_MISC; + break; + default: + break; + } + break; + + /* These are DDL, unless they are ROLE */ + case LOGSTMT_DDL: + className = CLASS_DDL; + class = LOG_DDL; + + /* Identify role statements */ + switch (stackItem->auditEvent.commandTag) + { + /* We know these are all role statements */ + case T_GrantStmt: + case T_GrantRoleStmt: + case T_CreateRoleStmt: + case T_DropRoleStmt: + case T_AlterRoleStmt: + case T_AlterRoleSetStmt: + case T_AlterDefaultPrivilegesStmt: + className = CLASS_ROLE; + class = LOG_ROLE; + break; + + /* + * Rename and Drop are general and therefore we have to do + * an additional check against the command string to see + * if they are role or regular DDL. + */ + case T_RenameStmt: + case T_DropStmt: + if (pg_strcasecmp(stackItem->auditEvent.command, + COMMAND_ALTER_ROLE) == 0 || + pg_strcasecmp(stackItem->auditEvent.command, + COMMAND_DROP_ROLE) == 0) + { + className = CLASS_ROLE; + class = LOG_ROLE; + } + break; + + default: + break; + } + break; + + /* Classify the rest */ + case LOGSTMT_ALL: + switch (stackItem->auditEvent.commandTag) + { + /* READ statements */ + case T_CopyStmt: + case T_SelectStmt: + case T_PrepareStmt: + case T_PlannedStmt: + className = CLASS_READ; + class = LOG_READ; + break; + + /* FUNCTION statements */ + case T_DoStmt: + className = CLASS_FUNCTION; + class = LOG_FUNCTION; + break; + + default: + break; + } + break; + + case LOGSTMT_NONE: + break; + } + + /* + * Only log the statement if: + * + * 1. If object was selected for audit logging (granted), or + * 2. The statement belongs to a class that is being logged + * + * If neither of these is true, return. + */ + if (!stackItem->auditEvent.granted && !(auditLogBitmap & class)) + return; + + /* + * Use audit memory context in case something is not free'd while + * appending strings and parameters. + */ + contextOld = MemoryContextSwitchTo(stackItem->contextAudit); + + /* Set statement and substatement IDs */ + if (stackItem->auditEvent.statementId == 0) + { + /* If nothing has been logged yet then create a new statement Id */ + if (!statementLogged) + { + statementTotal++; + statementLogged = true; + } + + stackItem->auditEvent.statementId = statementTotal; + stackItem->auditEvent.substatementId = ++substatementTotal; + } + + /* + * Create the audit substring + * + * The type-of-audit-log and statement/substatement ID are handled below, + * this string is everything else. + */ + initStringInfo(&auditStr); + append_valid_csv(&auditStr, stackItem->auditEvent.command); + + appendStringInfoCharMacro(&auditStr, ','); + append_valid_csv(&auditStr, stackItem->auditEvent.objectType); + + appendStringInfoCharMacro(&auditStr, ','); + append_valid_csv(&auditStr, stackItem->auditEvent.objectName); + + /* + * If auditLogStatmentOnce is true, then only log the statement and + * parameters if they have not already been logged for this substatement. + */ + appendStringInfoCharMacro(&auditStr, ','); + if (!stackItem->auditEvent.statementLogged || !auditLogStatementOnce) + { + append_valid_csv(&auditStr, stackItem->auditEvent.commandText); + + appendStringInfoCharMacro(&auditStr, ','); + + /* Handle parameter logging, if enabled. */ + if (auditLogParameter) + { + int paramIdx; + int numParams; + StringInfoData paramStrResult; + ParamListInfo paramList = stackItem->auditEvent.paramList; + + numParams = paramList == NULL ? 0 : paramList->numParams; + + /* Create the param substring */ + initStringInfo(¶mStrResult); + + /* Iterate through all params */ + for (paramIdx = 0; paramList != NULL && paramIdx < numParams; + paramIdx++) + { + ParamExternData *prm = ¶mList->params[paramIdx]; + Oid typeOutput; + bool typeIsVarLena; + char *paramStr; + + /* Add a comma for each param */ + if (paramIdx != 0) + appendStringInfoCharMacro(¶mStrResult, ','); + + /* Skip if null or if oid is invalid */ + if (prm->isnull || !OidIsValid(prm->ptype)) + continue; + + /* Output the string */ + getTypeOutputInfo(prm->ptype, &typeOutput, &typeIsVarLena); + paramStr = OidOutputFunctionCall(typeOutput, prm->value); + + append_valid_csv(¶mStrResult, paramStr); + pfree(paramStr); + } + + if (numParams == 0) + appendStringInfoString(&auditStr, ""); + else + append_valid_csv(&auditStr, paramStrResult.data); + } + else + appendStringInfoString(&auditStr, ""); + + stackItem->auditEvent.statementLogged = true; + } + else + /* we were asked to not log it */ + appendStringInfoString(&auditStr, + ","); + + /* + * Log the audit entry. Note: use of INT64_FORMAT here is bad for + * translatability, but we currently haven't got translation support in + * pgaudit anyway. + */ + if (!auditLogClient) + LimitClientLogOutput(true); + + ereport(auditLogLevel, + (errmsg("AUDIT: %s," INT64_FORMAT "," INT64_FORMAT ",%s,%s", + stackItem->auditEvent.granted ? + AUDIT_TYPE_OBJECT : AUDIT_TYPE_SESSION, + stackItem->auditEvent.statementId, + stackItem->auditEvent.substatementId, + className, + auditStr.data), + errhidestmt(true), + errhidecontext(true))); + + if (!auditLogClient) + LimitClientLogOutput(false); + + stackItem->auditEvent.logged = true; + + MemoryContextSwitchTo(contextOld); +} + +/* + * Check if the role or any inherited role has any permission in the mask. The + * public role is excluded from this check and superuser permissions are not + * considered. + */ +static bool +audit_on_acl(Datum aclDatum, + Oid auditOid, + AclMode mask) +{ + bool result = false; + Acl *acl; + AclItem *aclItemData; + int aclIndex; + int aclTotal; + + /* Detoast column's ACL if necessary */ + acl = DatumGetAclP(aclDatum); + + /* Get the acl list and total number of items */ + aclTotal = ACL_NUM(acl); + aclItemData = ACL_DAT(acl); + + /* Check privileges granted directly to auditOid */ + for (aclIndex = 0; aclIndex < aclTotal; aclIndex++) + { + AclItem *aclItem = &aclItemData[aclIndex]; + + if (aclItem->ai_grantee == auditOid && + aclItem->ai_privs & mask) + { + result = true; + break; + } + } + + /* + * Check privileges granted indirectly via role memberships. We do this in + * a separate pass to minimize expensive indirect membership tests. In + * particular, it's worth testing whether a given ACL entry grants any + * privileges still of interest before we perform the has_privs_of_role + * test. + */ + if (!result) + { + for (aclIndex = 0; aclIndex < aclTotal; aclIndex++) + { + AclItem *aclItem = &aclItemData[aclIndex]; + + /* Don't test public or auditOid (it has been tested already) */ + if (aclItem->ai_grantee == ACL_ID_PUBLIC || + aclItem->ai_grantee == auditOid) + continue; + + /* + * Check that the role has the required privileges and that it is + * inherited by auditOid. + */ + if (aclItem->ai_privs & mask && + has_privs_of_role(auditOid, aclItem->ai_grantee)) + { + result = true; + break; + } + } + } + + /* if we have a detoasted copy, free it */ + if (acl && (Pointer) acl != DatumGetPointer(aclDatum)) + pfree(acl); + + return result; +} + +/* + * Check if a role has any of the permissions in the mask on a relation. + */ +static bool +audit_on_relation(Oid relOid, + Oid auditOid, + AclMode mask) +{ + bool result = false; + HeapTuple tuple; + Datum aclDatum; + bool isNull; + + /* Get relation tuple from pg_class */ + tuple = SearchSysCache1(RELOID, ObjectIdGetDatum(relOid)); + if (!HeapTupleIsValid(tuple)) + return false; + + /* Get the relation's ACL */ + aclDatum = SysCacheGetAttr(RELOID, tuple, Anum_pg_class_relacl, + &isNull); + + /* Only check if non-NULL, since NULL means no permissions */ + if (!isNull) + result = audit_on_acl(aclDatum, auditOid, mask); + + /* Free the relation tuple */ + ReleaseSysCache(tuple); + + return result; +} + +/* + * Check if a role has any of the permissions in the mask on a column. + */ +static bool +audit_on_attribute(Oid relOid, + AttrNumber attNum, + Oid auditOid, + AclMode mask) +{ + bool result = false; + HeapTuple attTuple; + Datum aclDatum; + bool isNull; + + /* Get the attribute's ACL */ + attTuple = SearchSysCache2(ATTNUM, + ObjectIdGetDatum(relOid), + Int16GetDatum(attNum)); + if (!HeapTupleIsValid(attTuple)) + return false; + + /* Only consider attributes that have not been dropped */ + if (!((Form_pg_attribute) GETSTRUCT(attTuple))->attisdropped) + { + aclDatum = SysCacheGetAttr(ATTNUM, attTuple, Anum_pg_attribute_attacl, + &isNull); + + if (!isNull) + result = audit_on_acl(aclDatum, auditOid, mask); + } + + /* Free attribute */ + ReleaseSysCache(attTuple); + + return result; +} + +/* + * Check if a role has any of the permissions in the mask on a column in + * the provided set. If the set is empty, then all valid columns in the + * relation will be tested. + */ +static bool +audit_on_any_attribute(Oid relOid, + Oid auditOid, + Bitmapset *attributeSet, + AclMode mode) +{ + bool result = false; + AttrNumber col; + Bitmapset *tmpSet; + + /* If bms is empty then check for any column match */ + if (bms_is_empty(attributeSet)) + { + HeapTuple classTuple; + AttrNumber nattrs; + AttrNumber curr_att; + + /* Get relation to determine total columns */ + classTuple = SearchSysCache1(RELOID, ObjectIdGetDatum(relOid)); + + if (!HeapTupleIsValid(classTuple)) + return false; + + nattrs = ((Form_pg_class) GETSTRUCT(classTuple))->relnatts; + ReleaseSysCache(classTuple); + + /* Check each column */ + for (curr_att = 1; curr_att <= nattrs; curr_att++) + if (audit_on_attribute(relOid, curr_att, auditOid, mode)) + return true; + } + + /* bms_first_member is destructive, so make a copy before using it. */ + tmpSet = bms_copy(attributeSet); + + /* Check each column */ + while ((col = bms_first_member(tmpSet)) >= 0) + { + col += FirstLowInvalidHeapAttributeNumber; + + if (col != InvalidAttrNumber && + audit_on_attribute(relOid, col, auditOid, mode)) + { + result = true; + break; + } + } + + bms_free(tmpSet); + + return result; +} + +/* + * Create AuditEvents for SELECT/DML operations via executor permissions checks. + */ +static void +log_select_dml(Oid auditOid, List *rangeTabls) +{ + ListCell *lr; + bool first = true; + bool found = false; + + /* Do not log if this is an internal statement */ + if (internalStatement) + return; + + foreach(lr, rangeTabls) + { + Oid relOid; + Relation rel; + RangeTblEntry *rte = lfirst(lr); + + /* We only care about tables, and can ignore subqueries etc. */ + if (rte->rtekind != RTE_RELATION) + continue; + + found = true; + + /* + * Don't log if the session user is not a member of the current + * role. This prevents contents of security definer functions + * from being logged and supresses foreign key queries unless the + * session user is the owner of the referenced table. + */ + if (!is_member_of_role_nosuper(GetSessionUserId(), GetUserId())) + return; + + /* + * If we are not logging all-catalog queries (auditLogCatalog is + * false) then filter out any system relations here. + */ + relOid = rte->relid; + rel = relation_open(relOid, NoLock); + + if (!auditLogCatalog && IsSystemNamespace(RelationGetNamespace(rel))) + { + relation_close(rel, NoLock); + continue; + } + + /* + * Default is that this was not through a grant, to support session + * logging. Will be updated below if a grant is found. + */ + auditEventStack->auditEvent.granted = false; + + /* + * If this is the first RTE then session log unless auditLogRelation + * is set. + */ + if (first && !auditLogRelation) + { + log_audit_event(auditEventStack); + + first = false; + } + + /* + * We don't have access to the parsetree here, so we have to generate + * the node type, object type, and command tag by decoding + * rte->requiredPerms and rte->relkind. + */ + if (rte->requiredPerms & ACL_INSERT) + { + auditEventStack->auditEvent.logStmtLevel = LOGSTMT_MOD; + auditEventStack->auditEvent.commandTag = T_InsertStmt; + auditEventStack->auditEvent.command = COMMAND_INSERT; + } + else if (rte->requiredPerms & ACL_UPDATE) + { + auditEventStack->auditEvent.logStmtLevel = LOGSTMT_MOD; + auditEventStack->auditEvent.commandTag = T_UpdateStmt; + auditEventStack->auditEvent.command = COMMAND_UPDATE; + } + else if (rte->requiredPerms & ACL_DELETE) + { + auditEventStack->auditEvent.logStmtLevel = LOGSTMT_MOD; + auditEventStack->auditEvent.commandTag = T_DeleteStmt; + auditEventStack->auditEvent.command = COMMAND_DELETE; + } + else if (rte->requiredPerms & ACL_SELECT) + { + auditEventStack->auditEvent.logStmtLevel = LOGSTMT_ALL; + auditEventStack->auditEvent.commandTag = T_SelectStmt; + auditEventStack->auditEvent.command = COMMAND_SELECT; + } + else + { + auditEventStack->auditEvent.logStmtLevel = LOGSTMT_ALL; + auditEventStack->auditEvent.commandTag = T_Invalid; + auditEventStack->auditEvent.command = COMMAND_UNKNOWN; + } + + /* Use the relation type to assign object type */ + switch (rte->relkind) + { + case RELKIND_RELATION: + auditEventStack->auditEvent.objectType = OBJECT_TYPE_TABLE; + break; + + case RELKIND_INDEX: + auditEventStack->auditEvent.objectType = OBJECT_TYPE_INDEX; + break; + + case RELKIND_SEQUENCE: + auditEventStack->auditEvent.objectType = OBJECT_TYPE_SEQUENCE; + break; + + case RELKIND_TOASTVALUE: + auditEventStack->auditEvent.objectType = OBJECT_TYPE_TOASTVALUE; + break; + + case RELKIND_VIEW: + auditEventStack->auditEvent.objectType = OBJECT_TYPE_VIEW; + break; + + case RELKIND_COMPOSITE_TYPE: + auditEventStack->auditEvent.objectType = OBJECT_TYPE_COMPOSITE_TYPE; + break; + + case RELKIND_FOREIGN_TABLE: + auditEventStack->auditEvent.objectType = OBJECT_TYPE_FOREIGN_TABLE; + break; + + case RELKIND_MATVIEW: + auditEventStack->auditEvent.objectType = OBJECT_TYPE_MATVIEW; + break; + + default: + auditEventStack->auditEvent.objectType = OBJECT_TYPE_UNKNOWN; + break; + } + + /* Get a copy of the relation name and assign it to object name */ + auditEventStack->auditEvent.objectName = + quote_qualified_identifier(get_namespace_name( + RelationGetNamespace(rel)), + RelationGetRelationName(rel)); + relation_close(rel, NoLock); + + /* Perform object auditing only if the audit role is valid */ + if (auditOid != InvalidOid) + { + AclMode auditPerms = + (ACL_SELECT | ACL_UPDATE | ACL_INSERT | ACL_DELETE) & + rte->requiredPerms; + + /* + * If any of the required permissions for the relation are granted + * to the audit role then audit the relation + */ + if (audit_on_relation(relOid, auditOid, auditPerms)) + auditEventStack->auditEvent.granted = true; + + /* + * Else check if the audit role has column-level permissions for + * select, insert, or update. + */ + else if (auditPerms != 0) + { + /* + * Check the select columns + */ + if (auditPerms & ACL_SELECT) + auditEventStack->auditEvent.granted = + audit_on_any_attribute(relOid, auditOid, + rte->selectedCols, + ACL_SELECT); + + /* + * Check the insert columns + */ + if (!auditEventStack->auditEvent.granted && + auditPerms & ACL_INSERT) + auditEventStack->auditEvent.granted = + audit_on_any_attribute(relOid, auditOid, + rte->insertedCols, + auditPerms); + + /* + * Check the update columns + */ + if (!auditEventStack->auditEvent.granted && + auditPerms & ACL_UPDATE) + auditEventStack->auditEvent.granted = + audit_on_any_attribute(relOid, auditOid, + rte->updatedCols, + auditPerms); + } + } + + /* Do relation level logging if a grant was found */ + if (auditEventStack->auditEvent.granted) + { + auditEventStack->auditEvent.logged = false; + log_audit_event(auditEventStack); + } + + /* Do relation level logging if auditLogRelation is set */ + if (auditLogRelation) + { + auditEventStack->auditEvent.logged = false; + auditEventStack->auditEvent.granted = false; + log_audit_event(auditEventStack); + } + + pfree(auditEventStack->auditEvent.objectName); + } + + /* + * If no tables were found that means that RangeTbls was empty or all + * relations were in the system schema. In that case still log a session + * record. + */ + if (!found) + { + auditEventStack->auditEvent.granted = false; + auditEventStack->auditEvent.logged = false; + + log_audit_event(auditEventStack); + } +} + +/* + * Create AuditEvents for non-catalog function execution, as detected by + * log_object_access() below. + */ +static void +log_function_execute(Oid objectId) +{ + HeapTuple proctup; + Form_pg_proc proc; + AuditEventStackItem *stackItem; + + /* Get info about the function. */ + proctup = SearchSysCache1(PROCOID, ObjectIdGetDatum(objectId)); + + if (!proctup) + elog(ERROR, "cache lookup failed for function %u", objectId); + + proc = (Form_pg_proc) GETSTRUCT(proctup); + + /* + * Logging execution of all pg_catalog functions would make the log + * unusably noisy. + */ + if (IsSystemNamespace(proc->pronamespace)) + { + ReleaseSysCache(proctup); + return; + } + + /* Push audit event onto the stack */ + stackItem = stack_push(); + + /* Generate the fully-qualified function name. */ + stackItem->auditEvent.objectName = + quote_qualified_identifier(get_namespace_name(proc->pronamespace), + NameStr(proc->proname)); + ReleaseSysCache(proctup); + + /* Log the function call */ + stackItem->auditEvent.logStmtLevel = LOGSTMT_ALL; + stackItem->auditEvent.commandTag = T_DoStmt; + stackItem->auditEvent.command = COMMAND_EXECUTE; + stackItem->auditEvent.objectType = OBJECT_TYPE_FUNCTION; + stackItem->auditEvent.commandText = stackItem->next->auditEvent.commandText; + + log_audit_event(stackItem); + + /* Pop audit event from the stack */ + stack_pop(stackItem->stackId); +} + +/* + * Hook functions + */ +static ExecutorCheckPerms_hook_type next_ExecutorCheckPerms_hook = NULL; +static ProcessUtility_hook_type next_ProcessUtility_hook = NULL; +static object_access_hook_type next_object_access_hook = NULL; +static ExecutorStart_hook_type next_ExecutorStart_hook = NULL; + +/* + * Hook ExecutorStart to get the query text and basic command type for queries + * that do not contain a table and so can't be idenitified accurately in + * ExecutorCheckPerms. + */ +static void +pgaudit_ExecutorStart_hook(QueryDesc *queryDesc, int eflags) +{ + AuditEventStackItem *stackItem = NULL; + + if (!internalStatement) + { + /* Push the audit even onto the stack */ + stackItem = stack_push(); + + /* Initialize command using queryDesc->operation */ + switch (queryDesc->operation) + { + case CMD_SELECT: + stackItem->auditEvent.logStmtLevel = LOGSTMT_ALL; + stackItem->auditEvent.commandTag = T_SelectStmt; + stackItem->auditEvent.command = COMMAND_SELECT; + break; + + case CMD_INSERT: + stackItem->auditEvent.logStmtLevel = LOGSTMT_MOD; + stackItem->auditEvent.commandTag = T_InsertStmt; + stackItem->auditEvent.command = COMMAND_INSERT; + break; + + case CMD_UPDATE: + stackItem->auditEvent.logStmtLevel = LOGSTMT_MOD; + stackItem->auditEvent.commandTag = T_UpdateStmt; + stackItem->auditEvent.command = COMMAND_UPDATE; + break; + + case CMD_DELETE: + stackItem->auditEvent.logStmtLevel = LOGSTMT_MOD; + stackItem->auditEvent.commandTag = T_DeleteStmt; + stackItem->auditEvent.command = COMMAND_DELETE; + break; + + default: + stackItem->auditEvent.logStmtLevel = LOGSTMT_ALL; + stackItem->auditEvent.commandTag = T_Invalid; + stackItem->auditEvent.command = COMMAND_UNKNOWN; + break; + } + + /* Initialize the audit event */ + stackItem->auditEvent.commandText = queryDesc->sourceText; + stackItem->auditEvent.paramList = queryDesc->params; + } + + /* Call the previous hook or standard function */ + if (next_ExecutorStart_hook) + next_ExecutorStart_hook(queryDesc, eflags); + else + standard_ExecutorStart(queryDesc, eflags); + + /* + * Move the stack memory context to the query memory context. This needs + * to be done here because the query context does not exist before the + * call to standard_ExecutorStart() but the stack item is required by + * pgaudit_ExecutorCheckPerms_hook() which is called during + * standard_ExecutorStart(). + */ + if (stackItem) + MemoryContextSetParent(stackItem->contextAudit, + queryDesc->estate->es_query_cxt); +} + +/* + * Hook ExecutorCheckPerms to do session and object auditing for DML. + */ +static bool +pgaudit_ExecutorCheckPerms_hook(List *rangeTabls, bool abort) +{ + Oid auditOid; + + /* Get the audit oid if the role exists */ + auditOid = get_role_oid(auditRole, true); + + /* Log DML if the audit role is valid or session logging is enabled */ + if ((auditOid != InvalidOid || auditLogBitmap != 0) && + !IsAbortedTransactionBlockState()) + log_select_dml(auditOid, rangeTabls); + + /* Call the next hook function */ + if (next_ExecutorCheckPerms_hook && + !(*next_ExecutorCheckPerms_hook) (rangeTabls, abort)) + return false; + + return true; +} + +/* + * Hook ProcessUtility to do session auditing for DDL and utility commands. + */ +static void +pgaudit_ProcessUtility_hook(Node *parsetree, + const char *queryString, + ProcessUtilityContext context, + ParamListInfo params, + DestReceiver *dest, + char *completionTag) +{ + AuditEventStackItem *stackItem = NULL; + int64 stackId = 0; + + /* + * Don't audit substatements. All the substatements we care about should + * be covered by the event triggers. + */ + if (context <= PROCESS_UTILITY_QUERY && !IsAbortedTransactionBlockState()) + { + /* Process top level utility statement */ + if (context == PROCESS_UTILITY_TOPLEVEL) + { + if (auditEventStack != NULL) + elog(ERROR, "pgaudit stack is not empty"); + + stackItem = stack_push(); + stackItem->auditEvent.paramList = params; + } + else + stackItem = stack_push(); + + stackId = stackItem->stackId; + stackItem->auditEvent.logStmtLevel = GetCommandLogLevel(parsetree); + stackItem->auditEvent.commandTag = nodeTag(parsetree); + stackItem->auditEvent.command = CreateCommandTag(parsetree); + stackItem->auditEvent.commandText = queryString; + + /* + * If this is a DO block log it before calling the next ProcessUtility + * hook. + */ + if (auditLogBitmap & LOG_FUNCTION && + stackItem->auditEvent.commandTag == T_DoStmt && + !IsAbortedTransactionBlockState()) + log_audit_event(stackItem); + } + + /* Call the standard process utility chain. */ + if (next_ProcessUtility_hook) + (*next_ProcessUtility_hook) (parsetree, queryString, context, + params, dest, completionTag); + else + standard_ProcessUtility(parsetree, queryString, context, + params, dest, completionTag); + + /* + * Process the audit event if there is one. Also check that this event + * was not popped off the stack by a memory context being free'd + * elsewhere. + */ + if (stackItem && !IsAbortedTransactionBlockState()) + { + /* + * Make sure the item we want to log is still on the stack - if not + * then something has gone wrong and an error will be raised. + */ + stack_valid(stackId); + + /* + * Log the utility command if logging is on, the command has not + * already been logged by another hook, and the transaction is not + * aborted. + */ + if (auditLogBitmap != 0 && !stackItem->auditEvent.logged) + log_audit_event(stackItem); + } +} + +/* + * Hook object_access_hook to provide fully-qualified object names for function + * calls. + */ +static void +pgaudit_object_access_hook(ObjectAccessType access, + Oid classId, + Oid objectId, + int subId, + void *arg) +{ + if (auditLogBitmap & LOG_FUNCTION && access == OAT_FUNCTION_EXECUTE && + auditEventStack && !IsAbortedTransactionBlockState()) + log_function_execute(objectId); + + if (next_object_access_hook) + (*next_object_access_hook) (access, classId, objectId, subId, arg); +} + +/* + * Event trigger functions + */ + +/* + * Supply additional data for (non drop) statements that have event trigger + * support and can be deparsed. + * + * Drop statements are handled below through the older sql_drop event trigger. + */ +Datum +pgaudit_ddl_command_end(PG_FUNCTION_ARGS) +{ + EventTriggerData *eventData; + int result, + row; + TupleDesc spiTupDesc; + const char *query; + MemoryContext contextQuery; + MemoryContext contextOld; + + /* Continue only if session DDL logging is enabled */ + if (~auditLogBitmap & LOG_DDL && ~auditLogBitmap & LOG_ROLE) + PG_RETURN_NULL(); + + /* Be sure the module was loaded */ + if (!auditEventStack) + elog(ERROR, "pgaudit not loaded before call to " + "pgaudit_ddl_command_end()"); + + /* This is an internal statement - do not log it */ + internalStatement = true; + + /* Make sure the fuction was fired as a trigger */ + if (!CALLED_AS_EVENT_TRIGGER(fcinfo)) + elog(ERROR, "not fired by event trigger manager"); + + /* Switch memory context for query */ + contextQuery = AllocSetContextCreate( + CurrentMemoryContext, + "pgaudit_func_ddl_command_end temporary context", + ALLOCSET_DEFAULT_MINSIZE, + ALLOCSET_DEFAULT_INITSIZE, + ALLOCSET_DEFAULT_MAXSIZE); + contextOld = MemoryContextSwitchTo(contextQuery); + + /* Get information about triggered events */ + eventData = (EventTriggerData *) fcinfo->context; + + auditEventStack->auditEvent.logStmtLevel = + GetCommandLogLevel(eventData->parsetree); + auditEventStack->auditEvent.commandTag = + nodeTag(eventData->parsetree); + auditEventStack->auditEvent.command = + CreateCommandTag(eventData->parsetree); + + /* Return objects affected by the (non drop) DDL statement */ + query = "SELECT UPPER(object_type), object_identity, UPPER(command_tag)\n" + " FROM pg_catalog.pg_event_trigger_ddl_commands()"; + + /* Attempt to connect */ + result = SPI_connect(); + if (result < 0) + elog(ERROR, "pgaudit_ddl_command_end: SPI_connect returned %d", + result); + + /* Execute the query */ + result = SPI_execute(query, true, 0); + if (result != SPI_OK_SELECT) + elog(ERROR, "pgaudit_ddl_command_end: SPI_execute returned %d", + result); + + /* Iterate returned rows */ + spiTupDesc = SPI_tuptable->tupdesc; + for (row = 0; row < SPI_processed; row++) + { + HeapTuple spiTuple; + + spiTuple = SPI_tuptable->vals[row]; + + /* Supply object name and type for audit event */ + auditEventStack->auditEvent.objectType = + SPI_getvalue(spiTuple, spiTupDesc, 1); + auditEventStack->auditEvent.objectName = + SPI_getvalue(spiTuple, spiTupDesc, 2); + auditEventStack->auditEvent.command = + SPI_getvalue(spiTuple, spiTupDesc, 3); + + /* + * Identify grant/revoke commands - these are the only non-DDL class + * commands that should be coming through the event triggers. + */ + if (pg_strcasecmp(auditEventStack->auditEvent.command, + COMMAND_GRANT) == 0 || + pg_strcasecmp(auditEventStack->auditEvent.command, + COMMAND_REVOKE) == 0) + { + NodeTag currentCommandTag = auditEventStack->auditEvent.commandTag; + + auditEventStack->auditEvent.commandTag = T_GrantStmt; + log_audit_event(auditEventStack); + + auditEventStack->auditEvent.commandTag = currentCommandTag; + } + else + log_audit_event(auditEventStack); + } + + /* Complete the query */ + SPI_finish(); + + MemoryContextSwitchTo(contextOld); + MemoryContextDelete(contextQuery); + + /* No longer in an internal statement */ + internalStatement = false; + + PG_RETURN_NULL(); +} + +/* + * Supply additional data for drop statements that have event trigger support. + */ +Datum +pgaudit_sql_drop(PG_FUNCTION_ARGS) +{ + int result, + row; + TupleDesc spiTupDesc; + const char *query; + MemoryContext contextQuery; + MemoryContext contextOld; + + if (~auditLogBitmap & LOG_DDL) + PG_RETURN_NULL(); + + /* Be sure the module was loaded */ + if (!auditEventStack) + elog(ERROR, "pgaudit not loaded before call to " + "pgaudit_sql_drop()"); + + /* This is an internal statement - do not log it */ + internalStatement = true; + + /* Make sure the fuction was fired as a trigger */ + if (!CALLED_AS_EVENT_TRIGGER(fcinfo)) + elog(ERROR, "not fired by event trigger manager"); + + /* Switch memory context for the query */ + contextQuery = AllocSetContextCreate( + CurrentMemoryContext, + "pgaudit_func_ddl_command_end temporary context", + ALLOCSET_DEFAULT_MINSIZE, + ALLOCSET_DEFAULT_INITSIZE, + ALLOCSET_DEFAULT_MAXSIZE); + contextOld = MemoryContextSwitchTo(contextQuery); + + /* Return objects affected by the drop statement */ + query = "SELECT UPPER(object_type),\n" + " object_identity\n" + " FROM pg_catalog.pg_event_trigger_dropped_objects()\n" + " WHERE lower(object_type) <> 'type'\n" + " AND schema_name <> 'pg_toast'"; + + /* Attempt to connect */ + result = SPI_connect(); + if (result < 0) + elog(ERROR, "pgaudit_ddl_drop: SPI_connect returned %d", + result); + + /* Execute the query */ + result = SPI_execute(query, true, 0); + if (result != SPI_OK_SELECT) + elog(ERROR, "pgaudit_ddl_drop: SPI_execute returned %d", + result); + + /* Iterate returned rows */ + spiTupDesc = SPI_tuptable->tupdesc; + for (row = 0; row < SPI_processed; row++) + { + HeapTuple spiTuple; + + spiTuple = SPI_tuptable->vals[row]; + + auditEventStack->auditEvent.objectType = + SPI_getvalue(spiTuple, spiTupDesc, 1); + auditEventStack->auditEvent.objectName = + SPI_getvalue(spiTuple, spiTupDesc, 2); + + log_audit_event(auditEventStack); + } + + /* Complete the query */ + SPI_finish(); + + MemoryContextSwitchTo(contextOld); + MemoryContextDelete(contextQuery); + + /* No longer in an internal statement */ + internalStatement = false; + + PG_RETURN_NULL(); +} + +/* + * GUC check and assign functions + */ + +/* + * Take a pgaudit.log value such as "read, write, dml", verify that each of the + * comma-separated tokens corresponds to a LogClass value, and convert them into + * a bitmap that log_audit_event can check. + */ +static bool +check_pgaudit_log(char **newVal, void **extra, GucSource source) +{ + List *flagRawList; + char *rawVal; + ListCell *lt; + int *flags; + + /* Make sure newval is a comma-separated list of tokens. */ + rawVal = pstrdup(*newVal); + if (!SplitIdentifierString(rawVal, ',', &flagRawList)) + { + GUC_check_errdetail("List syntax is invalid"); + list_free(flagRawList); + pfree(rawVal); + return false; + } + + /* + * Check that we recognise each token, and add it to the bitmap we're + * building up in a newly-allocated int *f. + */ + if (!(flags = (int *) malloc(sizeof(int)))) + return false; + + *flags = 0; + + foreach(lt, flagRawList) + { + char *token = (char *) lfirst(lt); + bool subtract = false; + int class; + + /* If token is preceded by -, then the token is subtractive */ + if (token[0] == '-') + { + token++; + subtract = true; + } + + /* Test each token */ + if (pg_strcasecmp(token, CLASS_NONE) == 0) + class = LOG_NONE; + else if (pg_strcasecmp(token, CLASS_ALL) == 0) + class = LOG_ALL; + else if (pg_strcasecmp(token, CLASS_DDL) == 0) + class = LOG_DDL; + else if (pg_strcasecmp(token, CLASS_FUNCTION) == 0) + class = LOG_FUNCTION; + else if (pg_strcasecmp(token, CLASS_MISC) == 0) + class = LOG_MISC; + else if (pg_strcasecmp(token, CLASS_READ) == 0) + class = LOG_READ; + else if (pg_strcasecmp(token, CLASS_ROLE) == 0) + class = LOG_ROLE; + else if (pg_strcasecmp(token, CLASS_WRITE) == 0) + class = LOG_WRITE; + else + { + free(flags); + pfree(rawVal); + list_free(flagRawList); + return false; + } + + /* Add or subtract class bits from the log bitmap */ + if (subtract) + *flags &= ~class; + else + *flags |= class; + } + + pfree(rawVal); + list_free(flagRawList); + + /* Store the bitmap for assign_pgaudit_log */ + *extra = flags; + + return true; +} + +/* + * Set pgaudit_log from extra (ignoring newVal, which has already been + * converted to a bitmap above). Note that extra may not be set if the + * assignment is to be suppressed. + */ +static void +assign_pgaudit_log(const char *newVal, void *extra) +{ + if (extra) + auditLogBitmap = *(int *) extra; +} + +/* + * Take a pgaudit.log_level value such as "debug" and check that is is valid. + * Return the enum value so it does not have to be checked again in the assign + * function. + */ +static bool +check_pgaudit_log_level(char **newVal, void **extra, GucSource source) +{ + int *logLevel; + + /* Allocate memory to store the log level */ + if (!(logLevel = (int *) malloc(sizeof(int)))) + return false; + + /* Find the log level enum */ + if (pg_strcasecmp(*newVal, "debug") == 0) + *logLevel = DEBUG2; + else if (pg_strcasecmp(*newVal, "debug5") == 0) + *logLevel = DEBUG5; + else if (pg_strcasecmp(*newVal, "debug4") == 0) + *logLevel = DEBUG4; + else if (pg_strcasecmp(*newVal, "debug3") == 0) + *logLevel = DEBUG3; + else if (pg_strcasecmp(*newVal, "debug2") == 0) + *logLevel = DEBUG2; + else if (pg_strcasecmp(*newVal, "debug1") == 0) + *logLevel = DEBUG1; + else if (pg_strcasecmp(*newVal, "info") == 0) + *logLevel = INFO; + else if (pg_strcasecmp(*newVal, "notice") == 0) + *logLevel = NOTICE; + else if (pg_strcasecmp(*newVal, "warning") == 0) + *logLevel = WARNING; + else if (pg_strcasecmp(*newVal, "log") == 0) + *logLevel = LOG; + + /* Error if the log level enum is not found */ + else + { + free(logLevel); + return false; + } + + /* Return the log level enum */ + *extra = logLevel; + + return true; +} + +/* + * Set pgaudit_log from extra (ignoring newVal, which has already been + * converted to an enum above). Note that extra may not be set if the + * assignment is to be suppressed. + */ +static void +assign_pgaudit_log_level(const char *newVal, void *extra) +{ + if (extra) + auditLogLevel = *(int *) extra; +} + +/* + * Define GUC variables and install hooks upon module load. + */ +void +_PG_init(void) +{ + /* Must be loaded with shared_preload_libaries */ + if (IsUnderPostmaster) + ereport(ERROR, (errcode(ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE), + errmsg("pgaudit must be loaded via shared_preload_libraries"))); + + /* Define pgaudit.log */ + DefineCustomStringVariable( + "pgaudit.log", + + "Specifies which classes of statements will be logged by session audit " + "logging. Multiple classes can be provided using a comma-separated " + "list and classes can be subtracted by prefacing the class with a " + "- sign.", + + NULL, + &auditLog, + "none", + PGC_SUSET, + GUC_LIST_INPUT | GUC_NOT_IN_SAMPLE, + check_pgaudit_log, + assign_pgaudit_log, + NULL); + + /* Define pgaudit.log_catalog */ + DefineCustomBoolVariable( + "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.", + + NULL, + &auditLogCatalog, + true, + PGC_SUSET, + GUC_NOT_IN_SAMPLE, + NULL, NULL, NULL); + + /* Define pgaudit.log_client */ + DefineCustomBoolVariable( + "pgaudit.log_client", + + "Specifies whether audit messages should be visible to the client. " + "This setting should generally be left disabled but may be useful for " + "debugging or other purposes.", + + NULL, + &auditLogClient, + false, + PGC_SUSET, + GUC_NOT_IN_SAMPLE, + NULL, NULL, NULL); + + /* Define pgaudit.log_level */ + DefineCustomStringVariable( + "pgaudit.log_level", + + "Specifies the log level that will be used for log entries. 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.", + + NULL, + &auditLogLevelString, + "log", + PGC_SUSET, + GUC_LIST_INPUT | GUC_NOT_IN_SAMPLE, + check_pgaudit_log_level, + assign_pgaudit_log_level, + NULL); + + /* Define pgaudit.log_parameter */ + DefineCustomBoolVariable( + "pgaudit.log_parameter", + + "Specifies that audit logging should include the parameters that were " + "passed with the statement. When parameters are present they will be " + "be included in CSV format after the statement text.", + + NULL, + &auditLogParameter, + false, + PGC_SUSET, + GUC_NOT_IN_SAMPLE, + NULL, NULL, NULL); + + /* Define pgaudit.log_relation */ + DefineCustomBoolVariable( + "pgaudit.log_relation", + + "Specifies whether session audit logging should create a separate log " + "entry for each relation referenced in a SELECT or DML statement. " + "This is a useful shortcut for exhaustive logging without using object " + "audit logging.", + + NULL, + &auditLogRelation, + false, + PGC_SUSET, + GUC_NOT_IN_SAMPLE, + NULL, NULL, NULL); + + /* Define pgaudit.log_statement_once */ + DefineCustomBoolVariable( + "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.", + + NULL, + &auditLogStatementOnce, + false, + PGC_SUSET, + GUC_NOT_IN_SAMPLE, + NULL, NULL, NULL); + + /* Define pgaudit.role */ + DefineCustomStringVariable( + "pgaudit.role", + + "Specifies the master role to use for object audit logging. Multiple " + "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.", + + NULL, + &auditRole, + "", + PGC_SUSET, + GUC_NOT_IN_SAMPLE, + NULL, NULL, NULL); + + /* + * Install our hook functions after saving the existing pointers to + * preserve the chains. + */ + next_ExecutorStart_hook = ExecutorStart_hook; + ExecutorStart_hook = pgaudit_ExecutorStart_hook; + + next_ExecutorCheckPerms_hook = ExecutorCheckPerms_hook; + ExecutorCheckPerms_hook = pgaudit_ExecutorCheckPerms_hook; + + next_ProcessUtility_hook = ProcessUtility_hook; + ProcessUtility_hook = pgaudit_ProcessUtility_hook; + + next_object_access_hook = object_access_hook; + object_access_hook = pgaudit_object_access_hook; + + /* Log that the extension has completed initialization */ + ereport(LOG, (errmsg("pgaudit extension initialized"))); +} diff --git a/contrib/pgaudit/pgaudit.conf b/contrib/pgaudit/pgaudit.conf new file mode 100644 index 0000000..cc6f09c --- /dev/null +++ b/contrib/pgaudit/pgaudit.conf @@ -0,0 +1 @@ +shared_preload_libraries = pgaudit diff --git a/contrib/pgaudit/pgaudit.control b/contrib/pgaudit/pgaudit.control new file mode 100644 index 0000000..16612b2 --- /dev/null +++ b/contrib/pgaudit/pgaudit.control @@ -0,0 +1,5 @@ +# pgaudit extension +comment = 'provides auditing functionality' +default_version = '1.0' +module_pathname = '$libdir/pgaudit' +relocatable = true 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;