├── .gitignore
├── LICENSE
├── Makefile
├── README.md
├── expected
└── pgaudit.out
├── pgaudit--1.5.50.1.sql
├── pgaudit.c
├── pgaudit.conf
├── pgaudit.control
├── sql
└── pgaudit.sql
└── test
└── Vagrantfile
/.gitignore:
--------------------------------------------------------------------------------
1 | log/
2 | results/
3 | tmp_check/
4 | regression.diffs
5 | regression.out
6 | *.bc
7 | *.o
8 | *.so
9 | .vagrant
10 |
--------------------------------------------------------------------------------
/LICENSE:
--------------------------------------------------------------------------------
1 | This code is released under the PostgreSQL licence, as given at
2 | http://www.postgresql.org/about/licence/
3 |
4 | Copyright is novated to the PostgreSQL Global Development Group.
5 |
--------------------------------------------------------------------------------
/Makefile:
--------------------------------------------------------------------------------
1 | # contrib/pg_audit/Makefile
2 |
3 | MODULE_big = pgaudit
4 | OBJS = pgaudit.o $(WIN32RES)
5 |
6 | EXTENSION = pgaudit
7 | DATA = pgaudit--1.5.50.1.sql
8 | PGFILEDESC = "pgAudit - An audit logging extension for PostgreSQL"
9 |
10 | REGRESS = pgaudit
11 | REGRESS_OPTS = --temp-config=$(top_srcdir)/contrib/pgaudit/pgaudit.conf
12 |
13 | ifdef USE_PGXS
14 | PG_CONFIG = pg_config
15 | PGXS := $(shell $(PG_CONFIG) --pgxs)
16 | include $(PGXS)
17 | else
18 | subdir = contrib/pgaudit
19 | top_builddir = ../..
20 | include $(top_builddir)/src/Makefile.global
21 | include $(top_srcdir)/contrib/contrib-global.mk
22 | endif
23 |
--------------------------------------------------------------------------------
/README.md:
--------------------------------------------------------------------------------
1 | # pgAudit
Open Source PostgreSQL Audit Logging
2 |
3 | ## Introduction
4 |
5 | The PostgreSQL Audit Extension (pgAudit) provides detailed session and/or object audit logging via the standard PostgreSQL logging facility.
6 |
7 | The goal of the pgAudit is to provide PostgreSQL users with capability to produce audit logs often required to comply with government, financial, or ISO certifications.
8 |
9 | An audit is an official inspection of an individual's or organization's accounts, typically by an independent body. The information gathered by pgAudit is properly called an audit trail or audit log. The term audit log is used in this documentation.
10 |
11 | ## Why pgAudit?
12 |
13 | Basic statement logging can be provided by the standard logging facility with `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.
14 |
15 | 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:
16 | ```
17 | DO $$
18 | BEGIN
19 | EXECUTE 'CREATE TABLE import' || 'ant_table (id INT)';
20 | END $$;
21 | ```
22 | Standard logging will give you this:
23 | ```
24 | LOG: statement: DO $$
25 | BEGIN
26 | EXECUTE 'CREATE TABLE import' || 'ant_table (id INT)';
27 | END $$;
28 | ```
29 | 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:
30 | ```
31 | AUDIT: SESSION,33,1,FUNCTION,DO,,,"DO $$
32 | BEGIN
33 | EXECUTE 'CREATE TABLE import' || 'ant_table (id INT)';
34 | END $$;"
35 | AUDIT: SESSION,33,2,DDL,CREATE TABLE,TABLE,public.important_table,CREATE TABLE important_table (id INT)
36 | ```
37 | 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.
38 |
39 | 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.
40 |
41 | ## Usage Considerations
42 |
43 | 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.
44 |
45 | 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.
46 |
47 | To limit the number of relations audit logged for `SELECT` and `DML` statements, consider using object audit logging (see [Object Auditing](#object-audit-logging)). Object audit logging allows selection of the relations to be logged allowing for reduction of the overall log volume. However, when new relations are added they must be explicitly added to object audit logging. A programmatic solution where specified tables are excluded from logging and all others are included may be a good option in this case.
48 |
49 | ## PostgreSQL Version Compatibility
50 |
51 | pgAudit was developed to support PostgreSQL 9.5 or greater.
52 |
53 | In order to support new functionality introduced in each PostgreSQL release, pgAudit maintains a separate branch for each PostgreSQL major version (currently PostgreSQL 9.5 - 11) which will be maintained in a manner similar to the PostgreSQL project.
54 |
55 | Aside from bug fixes, no further development is planned for stable branches. New development, if any, will be strictly for next unreleased major version of PostgreSQL.
56 |
57 | pgAudit versions relate to PostgreSQL major versions as follows:
58 |
59 | - **pgAudit v1.5.X** is intended to support PostgreSQL 13.
60 |
61 | - **pgAudit v1.4.X** is intended to support PostgreSQL 12.
62 |
63 | - **pgAudit v1.3.X** is intended to support PostgreSQL 11.
64 |
65 | - **pgAudit v1.2.X** is intended to support PostgreSQL 10.
66 |
67 | - **pgAudit v1.1.X** is intended to support PostgreSQL 9.6.
68 |
69 | - **pgAudit v1.0.X** is intended to support PostgreSQL 9.5.
70 |
71 | ## Compile and Install
72 |
73 | pgAudit can be compiled against an installed copy of PostgreSQL with development packages using `PGXS`.
74 |
75 | The following instructions are for RHEL 7.
76 |
77 | Clone the pgAudit extension:
78 | ```
79 | git clone https://github.com/pgaudit/pgaudit.git
80 | ```
81 | Change to pgAudit directory:
82 | ```
83 | cd pgaudit
84 | ```
85 | Checkout `REL_13_STABLE` branch (note that the stable branch may not exist for unreleased versions of PostgreSQL):
86 | ```
87 | git checkout REL_13_STABLE
88 | ```
89 | Build and install pgAudit:
90 | ```
91 | make install USE_PGXS=1 PG_CONFIG=/usr/pgsql-13/bin/pg_config
92 | ```
93 | Detailed instructions for testing and development may be found in `test/Vagrantfile`.
94 |
95 | ## Settings
96 |
97 | Settings may be modified only by a superuser. Allowing normal users to change their settings would defeat the point of an audit log.
98 |
99 | 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.
100 |
101 | The pgAudit extension must be loaded in [shared_preload_libraries](http://www.postgresql.org/docs/13/runtime-config-client.html#GUC-SHARED-PRELOAD-LIBRARIES). Otherwise, an error will be raised at load time and no audit logging will occur. In addition, `CREATE EXTENSION pgaudit` must be called before `pgaudit.log` is set. If the `pgaudit` extension is dropped and needs to be recreated then `pgaudit.log` must be unset first otherwise an error will be raised.
102 |
103 | ### pgaudit.log
104 |
105 | Specifies which classes of statements will be logged by session audit logging. Possible values are:
106 |
107 | - **READ**: `SELECT` and `COPY` when the source is a relation or a query.
108 |
109 | - **WRITE**: `INSERT`, `UPDATE`, `DELETE`, `TRUNCATE`, and `COPY` when the destination is a relation.
110 |
111 | - **FUNCTION**: Function calls and `DO` blocks.
112 |
113 | - **ROLE**: Statements related to roles and privileges: `GRANT`, `REVOKE`, `CREATE/ALTER/DROP ROLE`.
114 |
115 | - **DDL**: All `DDL` that is not included in the `ROLE` class.
116 |
117 | - **MISC**: Miscellaneous commands, e.g. `DISCARD`, `FETCH`, `CHECKPOINT`, `VACUUM`, `SET`.
118 |
119 | - **MISC_SET**: Miscellaneous `SET` commands, e.g. `SET ROLE`.
120 |
121 | - **ALL**: Include all of the above.
122 |
123 | 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)).
124 |
125 | The default is `none`.
126 |
127 | ### pgaudit.log_catalog
128 |
129 | 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.
130 |
131 | The default is `on`.
132 |
133 | ### pgaudit.log_client
134 |
135 | Specifies whether log messages will be visible to a client process such as psql. This setting should generally be left disabled but may be useful for debugging or other purposes.
136 |
137 | Note that `pgaudit.log_level` is only enabled when `pgaudit.log_client` is `on`.
138 |
139 | The default is `off`.
140 |
141 | ### pgaudit.log_level
142 |
143 | Specifies the log level that will be used for log entries (see [Message Severity Levels](http://www.postgresql.org/docs/13/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.
144 |
145 | Note that `pgaudit.log_level` is only enabled when `pgaudit.log_client` is `on`; otherwise the default will be used.
146 |
147 | The default is `log`.
148 |
149 | ### pgaudit.log_parameter
150 |
151 | 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.
152 |
153 | The default is `off`.
154 |
155 | ### pgaudit.log_relation
156 |
157 | 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.
158 |
159 | The default is `off`.
160 |
161 | ### pgaudit.log_statement
162 |
163 | Specifies whether logging will include the statement text and parameters (if enabled). Depending on requirements, an audit log might not require this and it will make the logs less verbose.
164 |
165 | The default is `on`.
166 |
167 | ### pgaudit.log_statement_once
168 |
169 | 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.
170 |
171 | The default is `off`.
172 |
173 | ### pgaudit.role
174 |
175 | 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.
176 |
177 | There is no default.
178 |
179 | ## Session Audit Logging
180 |
181 | Session audit logging provides detailed logs of all statements executed by a user in the backend.
182 |
183 | ### Configuration
184 |
185 | Session logging is enabled with the [pgaudit.log](#pgauditlog) setting.
186 |
187 | Enable session logging for all `DML` and `DDL` and log all relations in `DML` statements:
188 | ```
189 | set pgaudit.log = 'write, ddl';
190 | set pgaudit.log_relation = on;
191 | ```
192 | Enable session logging for all commands except `MISC` and raise audit log messages as `NOTICE`:
193 | ```
194 | set pgaudit.log = 'all, -misc';
195 | set pgaudit.log_level = notice;
196 | ```
197 |
198 | ### Example
199 |
200 | 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
201 |
202 | _SQL_:
203 | ```
204 | set pgaudit.log = 'read, ddl';
205 |
206 | create table account
207 | (
208 | id int,
209 | name text,
210 | password text,
211 | description text
212 | );
213 |
214 | insert into account (id, name, password, description)
215 | values (1, 'user1', 'HASH1', 'blah, blah');
216 |
217 | select *
218 | from account;
219 | ```
220 | _Log Output_:
221 | ```
222 | AUDIT: SESSION,1,1,DDL,CREATE TABLE,TABLE,public.account,create table account
223 | (
224 | id int,
225 | name text,
226 | password text,
227 | description text
228 | );,
229 | AUDIT: SESSION,2,1,READ,SELECT,,,select *
230 | from account,,
231 | ```
232 |
233 | ## Object Audit Logging
234 |
235 | 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.
236 |
237 | 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.
238 |
239 | ### Configuration
240 |
241 | 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.
242 |
243 | Set [pgaudit.role](#pgauditrole) to `auditor` and grant `SELECT` and `DELETE` privileges on the `account` table. Any `SELECT` or `DELETE` statements on the `account` table will now be logged:
244 | ```
245 | set pgaudit.role = 'auditor';
246 |
247 | grant select, delete
248 | on public.account
249 | to auditor;
250 | ```
251 |
252 | ### Example
253 |
254 | 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 the `account_role_map` table is table-level.
255 |
256 | _SQL_:
257 | ```
258 | set pgaudit.role = 'auditor';
259 |
260 | create table account
261 | (
262 | id int,
263 | name text,
264 | password text,
265 | description text
266 | );
267 |
268 | grant select (password)
269 | on public.account
270 | to auditor;
271 |
272 | select id, name
273 | from account;
274 |
275 | select password
276 | from account;
277 |
278 | grant update (name, password)
279 | on public.account
280 | to auditor;
281 |
282 | update account
283 | set description = 'yada, yada';
284 |
285 | update account
286 | set password = 'HASH2';
287 |
288 | create table account_role_map
289 | (
290 | account_id int,
291 | role_id int
292 | );
293 |
294 | grant select
295 | on public.account_role_map
296 | to auditor;
297 |
298 | select account.password,
299 | account_role_map.role_id
300 | from account
301 | inner join account_role_map
302 | on account.id = account_role_map.account_id
303 | ```
304 | _Log Output_:
305 | ```
306 | AUDIT: OBJECT,1,1,READ,SELECT,TABLE,public.account,select password
307 | from account,
308 | AUDIT: OBJECT,2,1,WRITE,UPDATE,TABLE,public.account,update account
309 | set password = 'HASH2',
310 | AUDIT: OBJECT,3,1,READ,SELECT,TABLE,public.account,select account.password,
311 | account_role_map.role_id
312 | from account
313 | inner join account_role_map
314 | on account.id = account_role_map.account_id,
315 | AUDIT: OBJECT,3,1,READ,SELECT,TABLE,public.account_role_map,select account.password,
316 | account_role_map.role_id
317 | from account
318 | inner join account_role_map
319 | on account.id = account_role_map.account_id,
320 | ```
321 |
322 | ## Format
323 |
324 | 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.
325 |
326 | - **AUDIT_TYPE** - `SESSION` or `OBJECT`.
327 |
328 | - **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.
329 |
330 | - **SUBSTATEMENT_ID** - Sequential ID for each sub-statement within the main statement. For example, calling a function from a query. Sub-statement IDs are continuous even if some sub-statements are not logged. There may be multiple entries for a sub-statement ID when more than one relation is logged.
331 |
332 | - **CLASS** - e.g. `READ`, `ROLE` (see [pgaudit.log](#pgauditlog)).
333 |
334 | - **COMMAND** - e.g. `ALTER TABLE`, `SELECT`.
335 |
336 | - **OBJECT_TYPE** - `TABLE`, `INDEX`, `VIEW`, etc. Available for `SELECT`, `DML` and most `DDL` statements.
337 |
338 | - **OBJECT_NAME** - The fully-qualified object name (e.g. public.account). Available for `SELECT`, `DML` and most `DDL` statements.
339 |
340 | - **STATEMENT** - Statement executed on the backend.
341 |
342 | - **PARAMETER** - If `pgaudit.log_parameter` is set then this field will contain the statement parameters as quoted CSV or `` if there are no parameters. Otherwise, the field is ``.
343 |
344 | Use [log_line_prefix](http://www.postgresql.org/docs/13/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 [%p]: '` which would provide the date/time, user name, database name, and process id for each audit log.
345 |
346 | ## Caveats
347 |
348 | Object renames are logged under the name they were renamed to. For example, renaming a table will produce the following result:
349 | ```
350 | ALTER TABLE test RENAME TO test2;
351 |
352 | AUDIT: SESSION,36,1,DDL,ALTER TABLE,TABLE,public.test2,ALTER TABLE test RENAME TO test2,
353 | ```
354 | 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.
355 |
356 | Autovacuum and Autoanalyze are not logged.
357 |
358 | 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.
359 |
360 | ## Authors
361 |
362 | The PostgreSQL Audit Extension is based on the [2ndQuadrant](http://www.2ndquadrant.com) [pgaudit project](https://github.com/2ndQuadrant/pgaudit) authored by Simon Riggs, Abhijit Menon-Sen, and Ian Barwick and submitted as an extension to PostgreSQL core. Additional development has been done by David Steele of [Crunchy Data](http://www.crunchydata.com).
363 |
--------------------------------------------------------------------------------
/expected/pgaudit.out:
--------------------------------------------------------------------------------
1 | \set VERBOSITY terse
2 | -- Create pgaudit extension
3 | CREATE EXTENSION IF NOT EXISTS pgaudit;
4 | -- Make sure events don't get logged twice when session logging
5 | SET pgaudit.log = 'all';
6 | SET pgaudit.log_client = ON;
7 | SET pgaudit.log_level = 'notice';
8 | NOTICE: AUDIT: SESSION,3,1,MISC,SET,,,SET pgaudit.log_level = 'notice';,
9 | CREATE TABLE tmp (id int, data text);
10 | NOTICE: AUDIT: SESSION,4,1,DDL,CREATE TABLE,TABLE,public.tmp,"CREATE TABLE tmp (id int, data text);",
11 | CREATE TABLE tmp2 AS (SELECT * FROM tmp);
12 | NOTICE: AUDIT: SESSION,5,1,READ,SELECT,,,CREATE TABLE tmp2 AS (SELECT * FROM tmp);,
13 | NOTICE: AUDIT: SESSION,5,2,DDL,CREATE TABLE AS,TABLE,public.tmp2,CREATE TABLE tmp2 AS (SELECT * FROM tmp);,
14 | -- Reset log_client first to show that audits logs are not set to client
15 | RESET pgaudit.log_client;
16 | DROP TABLE tmp;
17 | DROP TABLE tmp2;
18 | RESET pgaudit.log;
19 | RESET pgaudit.log_level;
20 | --
21 | -- Audit log fields are:
22 | -- AUDIT_TYPE - SESSION or OBJECT
23 | -- STATEMENT_ID - ID of the statement in the current backend
24 | -- SUBSTATEMENT_ID - ID of the substatement in the current backend
25 | -- CLASS - Class of statement being logged (e.g. ROLE, READ, WRITE)
26 | -- COMMAND - e.g. SELECT, CREATE ROLE, UPDATE
27 | -- OBJECT_TYPE - When available, type of object acted on (e.g. TABLE, VIEW)
28 | -- OBJECT_NAME - When available, fully-qualified table of object
29 | -- STATEMENT - The statement being logged
30 | -- PARAMETER - If parameter logging is requested, they will follow the
31 | -- statement
32 | SELECT current_user \gset
33 | --
34 | -- Set pgaudit parameters for the current (super)user.
35 | ALTER ROLE :current_user SET pgaudit.log = 'Role';
36 | ALTER ROLE :current_user SET pgaudit.log_level = 'notice';
37 | ALTER ROLE :current_user SET pgaudit.log_client = ON;
38 | \connect - :current_user;
39 | --
40 | -- Create auditor role
41 | CREATE ROLE auditor;
42 | NOTICE: AUDIT: SESSION,1,1,ROLE,CREATE ROLE,,,CREATE ROLE auditor;,
43 | --
44 | -- Create first test user
45 | CREATE USER user1 password 'password';
46 | NOTICE: AUDIT: SESSION,2,1,ROLE,CREATE ROLE,,,CREATE USER user1 password ,
47 | ALTER ROLE user1 SET pgaudit.log = 'ddl, ROLE';
48 | NOTICE: AUDIT: SESSION,3,1,ROLE,ALTER ROLE,,,"ALTER ROLE user1 SET pgaudit.log = 'ddl, ROLE';",
49 | ALTER ROLE user1 SET pgaudit.log_level = 'notice';
50 | NOTICE: AUDIT: SESSION,4,1,ROLE,ALTER ROLE,,,ALTER ROLE user1 SET pgaudit.log_level = 'notice';,
51 | ALTER ROLE user1 PassWord 'password2' NOLOGIN;
52 | NOTICE: AUDIT: SESSION,5,1,ROLE,ALTER ROLE,,,ALTER ROLE user1 PassWord ,
53 | ALTER USER user1 encrypted /* random comment */PASSWORD
54 | /* random comment */
55 | 'md565cb1da342495ea6bb0418a6e5718c38' LOGIN;
56 | NOTICE: AUDIT: SESSION,6,1,ROLE,ALTER ROLE,,,ALTER USER user1 encrypted /* random comment */PASSWORD ,
57 | ALTER ROLE user1 SET pgaudit.log_client = ON;
58 | NOTICE: AUDIT: SESSION,7,1,ROLE,ALTER ROLE,,,ALTER ROLE user1 SET pgaudit.log_client = ON;,
59 | --
60 | -- Create, select, drop (select will not be audited)
61 | \connect - user1
62 | CREATE TABLE public.test
63 | (
64 | id INT
65 | );
66 | NOTICE: AUDIT: SESSION,1,1,DDL,CREATE TABLE,TABLE,public.test,"CREATE TABLE public.test
67 | (
68 | id INT
69 | );",
70 | SELECT *
71 | FROM test;
72 | id
73 | ----
74 | (0 rows)
75 |
76 | DROP TABLE test;
77 | NOTICE: AUDIT: SESSION,2,1,DDL,DROP TABLE,TABLE,public.test,DROP TABLE test;,
78 | --
79 | -- Create second test user
80 | \connect - :current_user
81 | CREATE ROLE user2 LOGIN password 'password';
82 | NOTICE: AUDIT: SESSION,1,1,ROLE,CREATE ROLE,,,CREATE ROLE user2 LOGIN password ,
83 | ALTER ROLE user2 SET pgaudit.log = 'Read, writE';
84 | NOTICE: AUDIT: SESSION,2,1,ROLE,ALTER ROLE,,,"ALTER ROLE user2 SET pgaudit.log = 'Read, writE';",
85 | ALTER ROLE user2 SET pgaudit.log_catalog = OFF;
86 | NOTICE: AUDIT: SESSION,3,1,ROLE,ALTER ROLE,,,ALTER ROLE user2 SET pgaudit.log_catalog = OFF;,
87 | ALTER ROLE user2 SET pgaudit.log_client = ON;
88 | NOTICE: AUDIT: SESSION,4,1,ROLE,ALTER ROLE,,,ALTER ROLE user2 SET pgaudit.log_client = ON;,
89 | ALTER ROLE user2 SET pgaudit.log_level = 'warning';
90 | NOTICE: AUDIT: SESSION,5,1,ROLE,ALTER ROLE,,,ALTER ROLE user2 SET pgaudit.log_level = 'warning';,
91 | ALTER ROLE user2 SET pgaudit.role = auditor;
92 | NOTICE: AUDIT: SESSION,6,1,ROLE,ALTER ROLE,,,ALTER ROLE user2 SET pgaudit.role = auditor;,
93 | ALTER ROLE user2 SET pgaudit.log_statement_once = ON;
94 | NOTICE: AUDIT: SESSION,7,1,ROLE,ALTER ROLE,,,ALTER ROLE user2 SET pgaudit.log_statement_once = ON;,
95 | --
96 | -- Setup role-based tests
97 | CREATE TABLE test2
98 | (
99 | id INT
100 | );
101 | GRANT SELECT, INSERT, UPDATE, DELETE
102 | ON test2
103 | TO user2, user1;
104 | NOTICE: AUDIT: SESSION,8,1,ROLE,GRANT,TABLE,,"GRANT SELECT, INSERT, UPDATE, DELETE
105 | ON test2
106 | TO user2, user1;",
107 | GRANT SELECT, UPDATE
108 | ON TABLE public.test2
109 | TO auditor;
110 | NOTICE: AUDIT: SESSION,9,1,ROLE,GRANT,TABLE,,"GRANT SELECT, UPDATE
111 | ON TABLE public.test2
112 | TO auditor;",
113 | CREATE TABLE test3
114 | (
115 | id INT
116 | );
117 | GRANT SELECT, INSERT, UPDATE, DELETE
118 | ON test3
119 | TO user2;
120 | NOTICE: AUDIT: SESSION,10,1,ROLE,GRANT,TABLE,,"GRANT SELECT, INSERT, UPDATE, DELETE
121 | ON test3
122 | TO user2;",
123 | GRANT INSERT
124 | ON TABLE public.test3
125 | TO auditor;
126 | NOTICE: AUDIT: SESSION,11,1,ROLE,GRANT,TABLE,,"GRANT INSERT
127 | ON TABLE public.test3
128 | TO auditor;",
129 | CREATE FUNCTION test2_insert() RETURNS TRIGGER AS $$
130 | BEGIN
131 | UPDATE test2
132 | SET id = id + 90
133 | WHERE id = new.id;
134 |
135 | RETURN new;
136 | END $$ LANGUAGE plpgsql security definer;
137 | ALTER FUNCTION test2_insert() OWNER TO user1;
138 | CREATE TRIGGER test2_insert_trg
139 | AFTER INSERT ON test2
140 | FOR EACH ROW EXECUTE PROCEDURE test2_insert();
141 | CREATE FUNCTION test2_change(change_id int) RETURNS void AS $$
142 | BEGIN
143 | UPDATE test2
144 | SET id = id + 1
145 | WHERE id = change_id;
146 | END $$ LANGUAGE plpgsql security definer;
147 | ALTER FUNCTION test2_change(int) OWNER TO user2;
148 | CREATE VIEW vw_test3 AS
149 | SELECT *
150 | FROM test3;
151 | GRANT SELECT
152 | ON vw_test3
153 | TO user2;
154 | NOTICE: AUDIT: SESSION,12,1,ROLE,GRANT,TABLE,,"GRANT SELECT
155 | ON vw_test3
156 | TO user2;",
157 | GRANT SELECT
158 | ON vw_test3
159 | TO auditor;
160 | NOTICE: AUDIT: SESSION,13,1,ROLE,GRANT,TABLE,,"GRANT SELECT
161 | ON vw_test3
162 | TO auditor;",
163 | \connect - user2
164 | --
165 | -- Role-based tests
166 | SELECT count(*)
167 | FROM
168 | (
169 | SELECT relname
170 | FROM pg_class
171 | LIMIT 1
172 | ) SUBQUERY;
173 | count
174 | -------
175 | 1
176 | (1 row)
177 |
178 | SELECT *
179 | FROM test3, test2;
180 | WARNING: AUDIT: SESSION,1,1,READ,SELECT,,,"SELECT *
181 | FROM test3, test2;",
182 | WARNING: AUDIT: OBJECT,1,1,READ,SELECT,TABLE,public.test2,,
183 | id | id
184 | ----+----
185 | (0 rows)
186 |
187 | --
188 | -- Object logged because of:
189 | -- select on vw_test3
190 | -- select on test2
191 | SELECT *
192 | FROM vw_test3, test2;
193 | WARNING: AUDIT: SESSION,2,1,READ,SELECT,,,"SELECT *
194 | FROM vw_test3, test2;",
195 | WARNING: AUDIT: OBJECT,2,1,READ,SELECT,TABLE,public.test2,,
196 | WARNING: AUDIT: OBJECT,2,1,READ,SELECT,VIEW,public.vw_test3,,
197 | id | id
198 | ----+----
199 | (0 rows)
200 |
201 | --
202 | -- Object logged because of:
203 | -- insert on test3
204 | -- select on test2
205 | WITH CTE AS
206 | (
207 | SELECT id
208 | FROM test2
209 | )
210 | INSERT INTO test3
211 | SELECT id
212 | FROM cte;
213 | WARNING: AUDIT: SESSION,3,1,WRITE,INSERT,,,"WITH CTE AS
214 | (
215 | SELECT id
216 | FROM test2
217 | )
218 | INSERT INTO test3
219 | SELECT id
220 | FROM cte;",
221 | WARNING: AUDIT: OBJECT,3,1,WRITE,INSERT,TABLE,public.test3,,
222 | WARNING: AUDIT: OBJECT,3,1,READ,SELECT,TABLE,public.test2,,
223 | --
224 | -- Object logged because of:
225 | -- insert on test3
226 | WITH CTE AS
227 | (
228 | INSERT INTO test3 VALUES (1)
229 | RETURNING id
230 | )
231 | INSERT INTO test2
232 | SELECT id
233 | FROM cte;
234 | WARNING: AUDIT: SESSION,4,1,WRITE,INSERT,,,"WITH CTE AS
235 | (
236 | INSERT INTO test3 VALUES (1)
237 | RETURNING id
238 | )
239 | INSERT INTO test2
240 | SELECT id
241 | FROM cte;",
242 | WARNING: AUDIT: OBJECT,4,1,WRITE,INSERT,TABLE,public.test3,,
243 | DO $$ BEGIN PERFORM test2_change(91); END $$;
244 | WARNING: AUDIT: SESSION,5,1,READ,SELECT,,,SELECT test2_change(91),
245 | WARNING: AUDIT: SESSION,5,2,WRITE,UPDATE,,,"UPDATE test2
246 | SET id = id + 1
247 | WHERE id = change_id",
248 | WARNING: AUDIT: OBJECT,5,2,WRITE,UPDATE,TABLE,public.test2,,
249 | --
250 | -- Object logged because of:
251 | -- insert on test3
252 | -- update on test2
253 | WITH CTE AS
254 | (
255 | UPDATE test2
256 | SET id = 45
257 | WHERE id = 92
258 | RETURNING id
259 | )
260 | INSERT INTO test3
261 | SELECT id
262 | FROM cte;
263 | WARNING: AUDIT: SESSION,6,1,WRITE,INSERT,,,"WITH CTE AS
264 | (
265 | UPDATE test2
266 | SET id = 45
267 | WHERE id = 92
268 | RETURNING id
269 | )
270 | INSERT INTO test3
271 | SELECT id
272 | FROM cte;",
273 | WARNING: AUDIT: OBJECT,6,1,WRITE,INSERT,TABLE,public.test3,,
274 | WARNING: AUDIT: OBJECT,6,1,WRITE,UPDATE,TABLE,public.test2,,
275 | --
276 | -- Object logged because of:
277 | -- insert on test2
278 | WITH CTE AS
279 | (
280 | INSERT INTO test2 VALUES (37)
281 | RETURNING id
282 | )
283 | UPDATE test3
284 | SET id = cte.id
285 | FROM cte
286 | WHERE test3.id <> cte.id;
287 | WARNING: AUDIT: SESSION,7,1,WRITE,UPDATE,,,"WITH CTE AS
288 | (
289 | INSERT INTO test2 VALUES (37)
290 | RETURNING id
291 | )
292 | UPDATE test3
293 | SET id = cte.id
294 | FROM cte
295 | WHERE test3.id <> cte.id;",
296 | WARNING: AUDIT: OBJECT,7,1,WRITE,INSERT,TABLE,public.test2,,
297 | --
298 | -- Be sure that test has correct contents
299 | SELECT *
300 | FROM test2
301 | ORDER BY ID;
302 | WARNING: AUDIT: SESSION,8,1,READ,SELECT,,,"SELECT *
303 | FROM test2
304 | ORDER BY ID;",
305 | WARNING: AUDIT: OBJECT,8,1,READ,SELECT,TABLE,public.test2,,
306 | id
307 | -----
308 | 45
309 | 127
310 | (2 rows)
311 |
312 | --
313 | -- Change permissions of user 2 so that only object logging will be done
314 | \connect - :current_user
315 | ALTER ROLE user2 SET pgaudit.log = 'NONE';
316 | NOTICE: AUDIT: SESSION,1,1,ROLE,ALTER ROLE,,,ALTER ROLE user2 SET pgaudit.log = 'NONE';,
317 | \connect - user2
318 | --
319 | -- Create test4 and add permissions
320 | CREATE TABLE test4
321 | (
322 | id int,
323 | name text
324 | );
325 | GRANT SELECT (name)
326 | ON TABLE public.test4
327 | TO auditor;
328 | GRANT UPDATE (id)
329 | ON TABLE public.test4
330 | TO auditor;
331 | GRANT insert (name)
332 | ON TABLE public.test4
333 | TO auditor;
334 | --
335 | -- Not object logged
336 | SELECT id
337 | FROM public.test4;
338 | id
339 | ----
340 | (0 rows)
341 |
342 | --
343 | -- Object logged because of:
344 | -- select (name) on test4
345 | SELECT name
346 | FROM public.test4;
347 | WARNING: AUDIT: OBJECT,1,1,READ,SELECT,TABLE,public.test4,"SELECT name
348 | FROM public.test4;",
349 | name
350 | ------
351 | (0 rows)
352 |
353 | --
354 | -- Not object logged
355 | INSERT INTO public.test4 (id)
356 | VALUES (1);
357 | --
358 | -- Object logged because of:
359 | -- insert (name) on test4
360 | INSERT INTO public.test4 (name)
361 | VALUES ('test');
362 | WARNING: AUDIT: OBJECT,2,1,WRITE,INSERT,TABLE,public.test4,"INSERT INTO public.test4 (name)
363 | VALUES ('test');",
364 | --
365 | -- Not object logged
366 | UPDATE public.test4
367 | SET name = 'foo';
368 | --
369 | -- Object logged because of:
370 | -- update (id) on test4
371 | UPDATE public.test4
372 | SET id = 1;
373 | WARNING: AUDIT: OBJECT,3,1,WRITE,UPDATE,TABLE,public.test4,"UPDATE public.test4
374 | SET id = 1;",
375 | --
376 | -- Object logged because of:
377 | -- update (name) on test4
378 | -- update (name) takes precedence over select (name) due to ordering
379 | update public.test4 set name = 'foo' where name = 'bar';
380 | WARNING: AUDIT: OBJECT,4,1,WRITE,UPDATE,TABLE,public.test4,update public.test4 set name = 'foo' where name = 'bar';,
381 | --
382 | -- Change permissions of user 1 so that session logging will be done
383 | \connect - :current_user
384 | --
385 | -- Drop test tables
386 | DROP TABLE test2;
387 | DROP VIEW vw_test3;
388 | DROP TABLE test3;
389 | DROP TABLE test4;
390 | DROP FUNCTION test2_insert();
391 | DROP FUNCTION test2_change(int);
392 | ALTER ROLE user1 SET pgaudit.log = 'DDL, READ';
393 | NOTICE: AUDIT: SESSION,1,1,ROLE,ALTER ROLE,,,"ALTER ROLE user1 SET pgaudit.log = 'DDL, READ';",
394 | \connect - user1
395 | --
396 | -- Create table is session logged
397 | CREATE TABLE public.account
398 | (
399 | id INT,
400 | name TEXT,
401 | password TEXT,
402 | description TEXT
403 | );
404 | NOTICE: AUDIT: SESSION,1,1,DDL,CREATE TABLE,TABLE,public.account,"CREATE TABLE public.account
405 | (
406 | id INT,
407 | name TEXT,
408 | password TEXT,
409 | description TEXT
410 | );",
411 | --
412 | -- Select is session logged
413 | SELECT *
414 | FROM account;
415 | NOTICE: AUDIT: SESSION,2,1,READ,SELECT,,,"SELECT *
416 | FROM account;",
417 | id | name | password | description
418 | ----+------+----------+-------------
419 | (0 rows)
420 |
421 | --
422 | -- Insert is not logged
423 | INSERT INTO account (id, name, password, description)
424 | VALUES (1, 'user1', 'HASH1', 'blah, blah');
425 | --
426 | -- Change permissions of user 1 so that only object logging will be done
427 | \connect - :current_user
428 | ALTER ROLE user1 SET pgaudit.log = 'none';
429 | NOTICE: AUDIT: SESSION,1,1,ROLE,ALTER ROLE,,,ALTER ROLE user1 SET pgaudit.log = 'none';,
430 | ALTER ROLE user1 SET pgaudit.role = 'auditor';
431 | NOTICE: AUDIT: SESSION,2,1,ROLE,ALTER ROLE,,,ALTER ROLE user1 SET pgaudit.role = 'auditor';,
432 | \connect - user1
433 | --
434 | -- ROLE class not set, so auditor grants not logged
435 | GRANT SELECT (password),
436 | UPDATE (name, password)
437 | ON TABLE public.account
438 | TO auditor;
439 | --
440 | -- Not object logged
441 | SELECT id,
442 | name
443 | FROM account;
444 | id | name
445 | ----+-------
446 | 1 | user1
447 | (1 row)
448 |
449 | --
450 | -- Object logged because of:
451 | -- select (password) on account
452 | SELECT password
453 | FROM account;
454 | NOTICE: AUDIT: OBJECT,1,1,READ,SELECT,TABLE,public.account,"SELECT password
455 | FROM account;",
456 | password
457 | ----------
458 | HASH1
459 | (1 row)
460 |
461 | --
462 | -- Not object logged
463 | UPDATE account
464 | SET description = 'yada, yada';
465 | --
466 | -- Object logged because of:
467 | -- update (password) on account
468 | UPDATE account
469 | SET password = 'HASH2';
470 | NOTICE: AUDIT: OBJECT,2,1,WRITE,UPDATE,TABLE,public.account,"UPDATE account
471 | SET password = 'HASH2';",
472 | --
473 | -- Change permissions of user 1 so that session relation logging will be done
474 | \connect - :current_user
475 | ALTER ROLE user1 SET pgaudit.log_relation = on;
476 | NOTICE: AUDIT: SESSION,1,1,ROLE,ALTER ROLE,,,ALTER ROLE user1 SET pgaudit.log_relation = on;,
477 | ALTER ROLE user1 SET pgaudit.log = 'read, WRITE';
478 | NOTICE: AUDIT: SESSION,2,1,ROLE,ALTER ROLE,,,"ALTER ROLE user1 SET pgaudit.log = 'read, WRITE';",
479 | \connect - user1
480 | --
481 | -- Not logged
482 | CREATE TABLE ACCOUNT_ROLE_MAP
483 | (
484 | account_id INT,
485 | role_id INT
486 | );
487 | --
488 | -- ROLE class not set, so auditor grants not logged
489 | GRANT SELECT
490 | ON TABLE public.account_role_map
491 | TO auditor;
492 | --
493 | -- Object logged because of:
494 | -- select (password) on account
495 | -- select on account_role_map
496 | -- Session logged on all tables because log = read and log_relation = on
497 | SELECT account.password,
498 | account_role_map.role_id
499 | FROM account
500 | INNER JOIN account_role_map
501 | on account.id = account_role_map.account_id;
502 | NOTICE: AUDIT: OBJECT,1,1,READ,SELECT,TABLE,public.account,"SELECT account.password,
503 | account_role_map.role_id
504 | FROM account
505 | INNER JOIN account_role_map
506 | on account.id = account_role_map.account_id;",
507 | NOTICE: AUDIT: SESSION,1,1,READ,SELECT,TABLE,public.account,"SELECT account.password,
508 | account_role_map.role_id
509 | FROM account
510 | INNER JOIN account_role_map
511 | on account.id = account_role_map.account_id;",
512 | NOTICE: AUDIT: OBJECT,1,1,READ,SELECT,TABLE,public.account_role_map,"SELECT account.password,
513 | account_role_map.role_id
514 | FROM account
515 | INNER JOIN account_role_map
516 | on account.id = account_role_map.account_id;",
517 | NOTICE: AUDIT: SESSION,1,1,READ,SELECT,TABLE,public.account_role_map,"SELECT account.password,
518 | account_role_map.role_id
519 | FROM account
520 | INNER JOIN account_role_map
521 | on account.id = account_role_map.account_id;",
522 | password | role_id
523 | ----------+---------
524 | (0 rows)
525 |
526 | --
527 | -- Object logged because of:
528 | -- select (password) on account
529 | -- Session logged on all tables because log = read and log_relation = on
530 | SELECT password
531 | FROM account;
532 | NOTICE: AUDIT: OBJECT,2,1,READ,SELECT,TABLE,public.account,"SELECT password
533 | FROM account;",
534 | NOTICE: AUDIT: SESSION,2,1,READ,SELECT,TABLE,public.account,"SELECT password
535 | FROM account;",
536 | password
537 | ----------
538 | HASH2
539 | (1 row)
540 |
541 | --
542 | -- Not object logged
543 | -- Session logged on all tables because log = read and log_relation = on
544 | UPDATE account
545 | SET description = 'yada, yada';
546 | NOTICE: AUDIT: SESSION,3,1,WRITE,UPDATE,TABLE,public.account,"UPDATE account
547 | SET description = 'yada, yada';",
548 | --
549 | -- Object logged because of:
550 | -- select (password) on account (in the where clause)
551 | -- Session logged on all tables because log = read and log_relation = on
552 | UPDATE account
553 | SET description = 'yada, yada'
554 | where password = 'HASH2';
555 | NOTICE: AUDIT: OBJECT,4,1,WRITE,UPDATE,TABLE,public.account,"UPDATE account
556 | SET description = 'yada, yada'
557 | where password = 'HASH2';",
558 | NOTICE: AUDIT: SESSION,4,1,WRITE,UPDATE,TABLE,public.account,"UPDATE account
559 | SET description = 'yada, yada'
560 | where password = 'HASH2';",
561 | --
562 | -- Object logged because of:
563 | -- update (password) on account
564 | -- Session logged on all tables because log = read and log_relation = on
565 | UPDATE account
566 | SET password = 'HASH2';
567 | NOTICE: AUDIT: OBJECT,5,1,WRITE,UPDATE,TABLE,public.account,"UPDATE account
568 | SET password = 'HASH2';",
569 | NOTICE: AUDIT: SESSION,5,1,WRITE,UPDATE,TABLE,public.account,"UPDATE account
570 | SET password = 'HASH2';",
571 | --
572 | -- Change configuration of user 1 so that full statements are not logged
573 | \connect - :current_user
574 | ALTER ROLE user1 RESET pgaudit.log_relation;
575 | NOTICE: AUDIT: SESSION,1,1,ROLE,ALTER ROLE,,,ALTER ROLE user1 RESET pgaudit.log_relation;,
576 | ALTER ROLE user1 RESET pgaudit.log;
577 | NOTICE: AUDIT: SESSION,2,1,ROLE,ALTER ROLE,,,ALTER ROLE user1 RESET pgaudit.log;,
578 | ALTER ROLE user1 SET pgaudit.log_statement = OFF;
579 | NOTICE: AUDIT: SESSION,3,1,ROLE,ALTER ROLE,,,ALTER ROLE user1 SET pgaudit.log_statement = OFF;,
580 | \connect - user1
581 | --
582 | -- Logged but without full statement
583 | SELECT * FROM account;
584 | NOTICE: AUDIT: OBJECT,1,1,READ,SELECT,TABLE,public.account,,
585 | id | name | password | description
586 | ----+-------+----------+-------------
587 | 1 | user1 | HASH2 | yada, yada
588 | (1 row)
589 |
590 | --
591 | -- Change back to superuser to do exhaustive tests
592 | \connect - :current_user
593 | SET pgaudit.log = 'ALL';
594 | NOTICE: AUDIT: SESSION,1,1,MISC,SET,,,SET pgaudit.log = 'ALL';,
595 | SET pgaudit.log_level = 'notice';
596 | NOTICE: AUDIT: SESSION,2,1,MISC,SET,,,SET pgaudit.log_level = 'notice';,
597 | SET pgaudit.log_client = ON;
598 | NOTICE: AUDIT: SESSION,3,1,MISC,SET,,,SET pgaudit.log_client = ON;,
599 | SET pgaudit.log_relation = ON;
600 | NOTICE: AUDIT: SESSION,4,1,MISC,SET,,,SET pgaudit.log_relation = ON;,
601 | SET pgaudit.log_parameter = ON;
602 | NOTICE: AUDIT: SESSION,5,1,MISC,SET,,,SET pgaudit.log_parameter = ON;,
603 | --
604 | -- Simple DO block
605 | DO $$
606 | BEGIN
607 | raise notice 'test';
608 | END $$;
609 | NOTICE: AUDIT: SESSION,6,1,FUNCTION,DO,,,"DO $$
610 | BEGIN
611 | raise notice 'test';
612 | END $$;",
613 | NOTICE: test
614 | --
615 | -- Create test schema
616 | CREATE SCHEMA test;
617 | NOTICE: AUDIT: SESSION,7,1,DDL,CREATE SCHEMA,SCHEMA,test,CREATE SCHEMA test;,
618 | --
619 | -- Copy account to stdout
620 | COPY account TO stdout;
621 | NOTICE: AUDIT: SESSION,8,1,READ,SELECT,TABLE,public.account,COPY account TO stdout;,
622 | 1 user1 HASH2 yada, yada
623 | --
624 | -- Create a table from a query
625 | CREATE TABLE test.account_copy AS
626 | SELECT *
627 | FROM account;
628 | NOTICE: AUDIT: SESSION,9,1,READ,SELECT,TABLE,public.account,"CREATE TABLE test.account_copy AS
629 | SELECT *
630 | FROM account;",
631 | NOTICE: AUDIT: SESSION,9,1,WRITE,INSERT,TABLE,test.account_copy,"CREATE TABLE test.account_copy AS
632 | SELECT *
633 | FROM account;",
634 | NOTICE: AUDIT: SESSION,9,2,DDL,CREATE TABLE AS,TABLE,test.account_copy,"CREATE TABLE test.account_copy AS
635 | SELECT *
636 | FROM account;",
637 | --
638 | -- Copy from stdin to account copy
639 | COPY test.account_copy from stdin;
640 | NOTICE: AUDIT: SESSION,10,1,WRITE,INSERT,TABLE,test.account_copy,COPY test.account_copy from stdin;,
641 | --
642 | -- Test prepared statement
643 | PREPARE pgclassstmt (oid) AS
644 | SELECT *
645 | FROM account
646 | WHERE id = $1;
647 | NOTICE: AUDIT: SESSION,11,1,READ,PREPARE,,,"PREPARE pgclassstmt (oid) AS
648 | SELECT *
649 | FROM account
650 | WHERE id = $1;",
651 | EXECUTE pgclassstmt (1);
652 | NOTICE: AUDIT: SESSION,12,1,READ,SELECT,TABLE,public.account,"PREPARE pgclassstmt (oid) AS
653 | SELECT *
654 | FROM account
655 | WHERE id = $1;",1
656 | NOTICE: AUDIT: SESSION,12,2,MISC,EXECUTE,,,EXECUTE pgclassstmt (1);,
657 | id | name | password | description
658 | ----+-------+----------+-------------
659 | 1 | user1 | HASH2 | yada, yada
660 | (1 row)
661 |
662 | DEALLOCATE pgclassstmt;
663 | NOTICE: AUDIT: SESSION,13,1,MISC,DEALLOCATE,,,DEALLOCATE pgclassstmt;,
664 | --
665 | -- Test cursor
666 | BEGIN;
667 | NOTICE: AUDIT: SESSION,14,1,MISC,BEGIN,,,BEGIN;,
668 | DECLARE ctest SCROLL CURSOR FOR
669 | SELECT count(*)
670 | FROM
671 | (
672 | SELECT relname
673 | FROM pg_class
674 | LIMIT 1
675 | ) subquery;
676 | NOTICE: AUDIT: SESSION,15,1,READ,SELECT,TABLE,pg_catalog.pg_class,"DECLARE ctest SCROLL CURSOR FOR
677 | SELECT count(*)
678 | FROM
679 | (
680 | SELECT relname
681 | FROM pg_class
682 | LIMIT 1
683 | ) subquery;",
684 | NOTICE: AUDIT: SESSION,15,2,READ,DECLARE CURSOR,,,"DECLARE ctest SCROLL CURSOR FOR
685 | SELECT count(*)
686 | FROM
687 | (
688 | SELECT relname
689 | FROM pg_class
690 | LIMIT 1
691 | ) subquery;",
692 | FETCH NEXT FROM ctest;
693 | NOTICE: AUDIT: SESSION,16,1,MISC,FETCH,,,FETCH NEXT FROM ctest;,
694 | count
695 | -------
696 | 1
697 | (1 row)
698 |
699 | CLOSE ctest;
700 | NOTICE: AUDIT: SESSION,17,1,MISC,CLOSE CURSOR,,,CLOSE ctest;,
701 | COMMIT;
702 | NOTICE: AUDIT: SESSION,18,1,MISC,COMMIT,,,COMMIT;,
703 | --
704 | -- Turn off log_catalog and pg_class will not be logged
705 | SET pgaudit.log_catalog = OFF;
706 | NOTICE: AUDIT: SESSION,19,1,MISC,SET,,,SET pgaudit.log_catalog = OFF;,
707 | SELECT count(*)
708 | FROM
709 | (
710 | SELECT relname
711 | FROM pg_class
712 | LIMIT 1
713 | ) subquery;
714 | count
715 | -------
716 | 1
717 | (1 row)
718 |
719 | --
720 | -- Test prepared insert
721 | CREATE TABLE test.test_insert
722 | (
723 | id INT
724 | );
725 | NOTICE: AUDIT: SESSION,20,1,DDL,CREATE TABLE,TABLE,test.test_insert,"CREATE TABLE test.test_insert
726 | (
727 | id INT
728 | );",
729 | PREPARE pgclassstmt (oid) AS
730 | INSERT INTO test.test_insert (id)
731 | VALUES ($1);
732 | NOTICE: AUDIT: SESSION,21,1,WRITE,PREPARE,,,"PREPARE pgclassstmt (oid) AS
733 | INSERT INTO test.test_insert (id)
734 | VALUES ($1);",
735 | EXECUTE pgclassstmt (1);
736 | NOTICE: AUDIT: SESSION,22,1,WRITE,INSERT,TABLE,test.test_insert,"PREPARE pgclassstmt (oid) AS
737 | INSERT INTO test.test_insert (id)
738 | VALUES ($1);",1
739 | NOTICE: AUDIT: SESSION,22,2,MISC,EXECUTE,,,EXECUTE pgclassstmt (1);,
740 | --
741 | -- Check that primary key creation is logged
742 | CREATE TABLE public.test
743 | (
744 | id INT,
745 | name TEXT,
746 | description TEXT,
747 | CONSTRAINT test_pkey PRIMARY KEY (id)
748 | );
749 | NOTICE: AUDIT: SESSION,23,1,DDL,CREATE TABLE,TABLE,public.test,"CREATE TABLE public.test
750 | (
751 | id INT,
752 | name TEXT,
753 | description TEXT,
754 | CONSTRAINT test_pkey PRIMARY KEY (id)
755 | );",
756 | NOTICE: AUDIT: SESSION,23,1,DDL,CREATE INDEX,INDEX,public.test_pkey,"CREATE TABLE public.test
757 | (
758 | id INT,
759 | name TEXT,
760 | description TEXT,
761 | CONSTRAINT test_pkey PRIMARY KEY (id)
762 | );",
763 | --
764 | -- Check that analyze is logged
765 | ANALYZE test;
766 | NOTICE: AUDIT: SESSION,24,1,MISC,ANALYZE,,,ANALYZE test;,
767 | --
768 | -- Grants to public should not cause object logging (session logging will
769 | -- still happen)
770 | GRANT SELECT
771 | ON TABLE public.test
772 | TO PUBLIC;
773 | NOTICE: AUDIT: SESSION,25,1,ROLE,GRANT,TABLE,,"GRANT SELECT
774 | ON TABLE public.test
775 | TO PUBLIC;",
776 | SELECT *
777 | FROM test;
778 | NOTICE: AUDIT: SESSION,26,1,READ,SELECT,TABLE,public.test,"SELECT *
779 | FROM test;",
780 | id | name | description
781 | ----+------+-------------
782 | (0 rows)
783 |
784 | -- Check that statements without columns log
785 | SELECT
786 | FROM test;
787 | NOTICE: AUDIT: SESSION,27,1,READ,SELECT,TABLE,public.test,"SELECT
788 | FROM test;",
789 | --
790 | (0 rows)
791 |
792 | SELECT 1,
793 | substring('Thomas' from 2 for 3);
794 | NOTICE: AUDIT: SESSION,28,1,READ,SELECT,,,"SELECT 1,
795 | substring('Thomas' from 2 for 3);",
796 | ?column? | substring
797 | ----------+-----------
798 | 1 | hom
799 | (1 row)
800 |
801 | DO $$
802 | DECLARE
803 | test INT;
804 | BEGIN
805 | SELECT 1
806 | INTO test;
807 | END $$;
808 | NOTICE: AUDIT: SESSION,29,1,FUNCTION,DO,,,"DO $$
809 | DECLARE
810 | test INT;
811 | BEGIN
812 | SELECT 1
813 | INTO test;
814 | END $$;",
815 | NOTICE: AUDIT: SESSION,29,2,READ,SELECT,,,SELECT 1,
816 | explain select 1;
817 | NOTICE: AUDIT: SESSION,30,1,READ,SELECT,,,explain select 1;,
818 | NOTICE: AUDIT: SESSION,30,2,MISC,EXPLAIN,,,explain select 1;,
819 | QUERY PLAN
820 | ------------------------------------------
821 | Result (cost=0.00..0.01 rows=1 width=4)
822 | (1 row)
823 |
824 | --
825 | -- Test that looks inside of do blocks log
826 | INSERT INTO TEST (id)
827 | VALUES (1);
828 | NOTICE: AUDIT: SESSION,31,1,WRITE,INSERT,TABLE,public.test,"INSERT INTO TEST (id)
829 | VALUES (1);",
830 | INSERT INTO TEST (id)
831 | VALUES (2);
832 | NOTICE: AUDIT: SESSION,32,1,WRITE,INSERT,TABLE,public.test,"INSERT INTO TEST (id)
833 | VALUES (2);",
834 | INSERT INTO TEST (id)
835 | VALUES (3);
836 | NOTICE: AUDIT: SESSION,33,1,WRITE,INSERT,TABLE,public.test,"INSERT INTO TEST (id)
837 | VALUES (3);",
838 | DO $$
839 | DECLARE
840 | result RECORD;
841 | BEGIN
842 | FOR result IN
843 | SELECT id
844 | FROM test
845 | LOOP
846 | INSERT INTO test (id)
847 | VALUES (result.id + 100);
848 | END LOOP;
849 | END $$;
850 | NOTICE: AUDIT: SESSION,34,1,FUNCTION,DO,,,"DO $$
851 | DECLARE
852 | result RECORD;
853 | BEGIN
854 | FOR result IN
855 | SELECT id
856 | FROM test
857 | LOOP
858 | INSERT INTO test (id)
859 | VALUES (result.id + 100);
860 | END LOOP;
861 | END $$;",
862 | NOTICE: AUDIT: SESSION,34,2,READ,SELECT,TABLE,public.test,"SELECT id
863 | FROM test",
864 | NOTICE: AUDIT: SESSION,34,3,WRITE,INSERT,TABLE,public.test,"INSERT INTO test (id)
865 | VALUES (result.id + 100)",",,1"
866 | NOTICE: AUDIT: SESSION,34,4,WRITE,INSERT,TABLE,public.test,"INSERT INTO test (id)
867 | VALUES (result.id + 100)",",,2"
868 | NOTICE: AUDIT: SESSION,34,5,WRITE,INSERT,TABLE,public.test,"INSERT INTO test (id)
869 | VALUES (result.id + 100)",",,3"
870 | --
871 | -- Test obfuscated dynamic sql for clean logging
872 | DO $$
873 | DECLARE
874 | table_name TEXT = 'do_table';
875 | BEGIN
876 | EXECUTE 'CREATE TABLE ' || table_name || ' ("weird name" INT)';
877 | EXECUTE 'DROP table ' || table_name;
878 | END $$;
879 | NOTICE: AUDIT: SESSION,35,1,FUNCTION,DO,,,"DO $$
880 | DECLARE
881 | table_name TEXT = 'do_table';
882 | BEGIN
883 | EXECUTE 'CREATE TABLE ' || table_name || ' (""weird name"" INT)';
884 | EXECUTE 'DROP table ' || table_name;
885 | END $$;",
886 | NOTICE: AUDIT: SESSION,35,2,DDL,CREATE TABLE,TABLE,public.do_table,"CREATE TABLE do_table (""weird name"" INT)",
887 | NOTICE: AUDIT: SESSION,35,3,DDL,DROP TABLE,TABLE,public.do_table,DROP table do_table,
888 | --
889 | -- Generate an error and make sure the stack gets cleared
890 | DO $$
891 | BEGIN
892 | CREATE TABLE bogus.test_block
893 | (
894 | id INT
895 | );
896 | END $$;
897 | NOTICE: AUDIT: SESSION,36,1,FUNCTION,DO,,,"DO $$
898 | BEGIN
899 | CREATE TABLE bogus.test_block
900 | (
901 | id INT
902 | );
903 | END $$;",
904 | ERROR: schema "bogus" does not exist at character 14
905 | --
906 | -- Test alter table statements
907 | ALTER TABLE public.test
908 | DROP COLUMN description ;
909 | NOTICE: AUDIT: SESSION,37,1,DDL,ALTER TABLE,TABLE COLUMN,public.test.description,"ALTER TABLE public.test
910 | DROP COLUMN description ;",
911 | NOTICE: AUDIT: SESSION,37,1,DDL,ALTER TABLE,TABLE,public.test,"ALTER TABLE public.test
912 | DROP COLUMN description ;",
913 | ALTER TABLE public.test
914 | RENAME TO test2;
915 | NOTICE: AUDIT: SESSION,38,1,DDL,ALTER TABLE,TABLE,public.test2,"ALTER TABLE public.test
916 | RENAME TO test2;",
917 | ALTER TABLE public.test2
918 | SET SCHEMA test;
919 | NOTICE: AUDIT: SESSION,39,1,DDL,ALTER TABLE,TABLE,test.test2,"ALTER TABLE public.test2
920 | SET SCHEMA test;",
921 | ALTER TABLE test.test2
922 | ADD COLUMN description TEXT;
923 | NOTICE: AUDIT: SESSION,40,1,DDL,ALTER TABLE,TABLE,test.test2,"ALTER TABLE test.test2
924 | ADD COLUMN description TEXT;",
925 | ALTER TABLE test.test2
926 | DROP COLUMN description;
927 | NOTICE: AUDIT: SESSION,41,1,DDL,ALTER TABLE,TABLE COLUMN,test.test2.description,"ALTER TABLE test.test2
928 | DROP COLUMN description;",
929 | NOTICE: AUDIT: SESSION,41,1,DDL,ALTER TABLE,TABLE,test.test2,"ALTER TABLE test.test2
930 | DROP COLUMN description;",
931 | DROP TABLE test.test2;
932 | NOTICE: AUDIT: SESSION,42,1,DDL,DROP TABLE,TABLE,test.test2,DROP TABLE test.test2;,
933 | NOTICE: AUDIT: SESSION,42,1,DDL,DROP TABLE,TABLE CONSTRAINT,test_pkey on test.test2,DROP TABLE test.test2;,
934 | NOTICE: AUDIT: SESSION,42,1,DDL,DROP TABLE,INDEX,test.test_pkey,DROP TABLE test.test2;,
935 | --
936 | -- Test multiple statements with one semi-colon
937 | CREATE SCHEMA foo
938 | CREATE TABLE foo.bar (id int)
939 | CREATE TABLE foo.baz (id int);
940 | NOTICE: AUDIT: SESSION,43,1,DDL,CREATE SCHEMA,SCHEMA,foo,"CREATE SCHEMA foo
941 | CREATE TABLE foo.bar (id int)
942 | CREATE TABLE foo.baz (id int);",
943 | NOTICE: AUDIT: SESSION,43,1,DDL,CREATE TABLE,TABLE,foo.bar,"CREATE SCHEMA foo
944 | CREATE TABLE foo.bar (id int)
945 | CREATE TABLE foo.baz (id int);",
946 | NOTICE: AUDIT: SESSION,43,1,DDL,CREATE TABLE,TABLE,foo.baz,"CREATE SCHEMA foo
947 | CREATE TABLE foo.bar (id int)
948 | CREATE TABLE foo.baz (id int);",
949 | --
950 | -- Test aggregate
951 | CREATE FUNCTION public.int_add
952 | (
953 | a INT,
954 | b INT
955 | )
956 | RETURNS INT LANGUAGE plpgsql AS $$
957 | BEGIN
958 | return a + b;
959 | END $$;
960 | NOTICE: AUDIT: SESSION,44,1,DDL,CREATE FUNCTION,FUNCTION,"public.int_add(integer,integer)","CREATE FUNCTION public.int_add
961 | (
962 | a INT,
963 | b INT
964 | )
965 | RETURNS INT LANGUAGE plpgsql AS $$
966 | BEGIN
967 | return a + b;
968 | END $$;",
969 | SELECT int_add(1, 1);
970 | NOTICE: AUDIT: SESSION,45,1,READ,SELECT,,,"SELECT int_add(1, 1);",
971 | NOTICE: AUDIT: SESSION,45,2,FUNCTION,EXECUTE,FUNCTION,public.int_add,"SELECT int_add(1, 1);",
972 | int_add
973 | ---------
974 | 2
975 | (1 row)
976 |
977 | CREATE AGGREGATE public.sum_test(INT) (SFUNC=public.int_add, STYPE=INT, INITCOND='0');
978 | 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');",
979 | ALTER AGGREGATE public.sum_test(integer) RENAME TO sum_test2;
980 | NOTICE: AUDIT: SESSION,47,1,DDL,ALTER AGGREGATE,AGGREGATE,public.sum_test2(integer),ALTER AGGREGATE public.sum_test(integer) RENAME TO sum_test2;,
981 | --
982 | -- Test conversion
983 | CREATE CONVERSION public.conversion_test FOR 'latin1' TO 'utf8' FROM pg_catalog.iso8859_1_to_utf8;
984 | NOTICE: AUDIT: SESSION,48,1,DDL,CREATE CONVERSION,CONVERSION,public.conversion_test,CREATE CONVERSION public.conversion_test FOR 'latin1' TO 'utf8' FROM pg_catalog.iso8859_1_to_utf8;,
985 | ALTER CONVERSION public.conversion_test RENAME TO conversion_test2;
986 | NOTICE: AUDIT: SESSION,49,1,DDL,ALTER CONVERSION,CONVERSION,public.conversion_test2,ALTER CONVERSION public.conversion_test RENAME TO conversion_test2;,
987 | --
988 | -- Test create/alter/drop database
989 | CREATE DATABASE contrib_regression_pgaudit;
990 | NOTICE: AUDIT: SESSION,50,1,DDL,CREATE DATABASE,,,CREATE DATABASE contrib_regression_pgaudit;,
991 | ALTER DATABASE contrib_regression_pgaudit RENAME TO contrib_regression_pgaudit2;
992 | NOTICE: AUDIT: SESSION,51,1,DDL,ALTER DATABASE,,,ALTER DATABASE contrib_regression_pgaudit RENAME TO contrib_regression_pgaudit2;,
993 | DROP DATABASE contrib_regression_pgaudit2;
994 | NOTICE: AUDIT: SESSION,52,1,DDL,DROP DATABASE,,,DROP DATABASE contrib_regression_pgaudit2;,
995 | -- Test role as a substmt
996 | SET pgaudit.log = 'ROLE';
997 | CREATE TABLE t ();
998 | CREATE ROLE alice;
999 | NOTICE: AUDIT: SESSION,53,1,ROLE,CREATE ROLE,,,CREATE ROLE alice;,
1000 | CREATE SCHEMA foo2
1001 | GRANT SELECT
1002 | ON public.t
1003 | TO alice;
1004 | NOTICE: AUDIT: SESSION,54,1,ROLE,GRANT,TABLE,,"CREATE SCHEMA foo2
1005 | GRANT SELECT
1006 | ON public.t
1007 | TO alice;",
1008 | drop table public.t;
1009 | drop role alice;
1010 | NOTICE: AUDIT: SESSION,55,1,ROLE,DROP ROLE,,,drop role alice;,
1011 | --
1012 | -- Test for non-empty stack error
1013 | CREATE OR REPLACE FUNCTION get_test_id(_ret REFCURSOR) RETURNS REFCURSOR
1014 | LANGUAGE plpgsql IMMUTABLE AS $$
1015 | BEGIN
1016 | OPEN _ret FOR SELECT 200;
1017 | RETURN _ret;
1018 | END $$;
1019 | BEGIN;
1020 | SELECT get_test_id('_ret');
1021 | get_test_id
1022 | -------------
1023 | _ret
1024 | (1 row)
1025 |
1026 | SELECT get_test_id('_ret2');
1027 | get_test_id
1028 | -------------
1029 | _ret2
1030 | (1 row)
1031 |
1032 | FETCH ALL FROM _ret;
1033 | ?column?
1034 | ----------
1035 | 200
1036 | (1 row)
1037 |
1038 | FETCH ALL FROM _ret2;
1039 | ?column?
1040 | ----------
1041 | 200
1042 | (1 row)
1043 |
1044 | CLOSE _ret;
1045 | CLOSE _ret2;
1046 | END;
1047 | --
1048 | -- Test that frees a memory context earlier than expected
1049 | SET pgaudit.log = 'ALL';
1050 | NOTICE: AUDIT: SESSION,56,1,MISC,SET,,,SET pgaudit.log = 'ALL';,
1051 | CREATE TABLE hoge
1052 | (
1053 | id int
1054 | );
1055 | NOTICE: AUDIT: SESSION,57,1,DDL,CREATE TABLE,TABLE,public.hoge,"CREATE TABLE hoge
1056 | (
1057 | id int
1058 | );",
1059 | CREATE FUNCTION test()
1060 | RETURNS INT AS $$
1061 | DECLARE
1062 | cur1 cursor for select * from hoge;
1063 | tmp int;
1064 | BEGIN
1065 | OPEN cur1;
1066 | FETCH cur1 into tmp;
1067 | RETURN tmp;
1068 | END $$
1069 | LANGUAGE plpgsql ;
1070 | NOTICE: AUDIT: SESSION,58,1,DDL,CREATE FUNCTION,FUNCTION,public.test(),"CREATE FUNCTION test()
1071 | RETURNS INT AS $$
1072 | DECLARE
1073 | cur1 cursor for select * from hoge;
1074 | tmp int;
1075 | BEGIN
1076 | OPEN cur1;
1077 | FETCH cur1 into tmp;
1078 | RETURN tmp;
1079 | END $$
1080 | LANGUAGE plpgsql ;",
1081 | SELECT test();
1082 | NOTICE: AUDIT: SESSION,59,1,READ,SELECT,,,SELECT test();,
1083 | NOTICE: AUDIT: SESSION,59,2,FUNCTION,EXECUTE,FUNCTION,public.test,SELECT test();,
1084 | NOTICE: AUDIT: SESSION,59,3,READ,SELECT,TABLE,public.hoge,select * from hoge,
1085 | test
1086 | ------
1087 |
1088 | (1 row)
1089 |
1090 | --
1091 | -- Delete all rows then delete 1 row
1092 | SET pgaudit.log = 'write';
1093 | SET pgaudit.role = 'auditor';
1094 | create table bar
1095 | (
1096 | col int
1097 | );
1098 | grant delete
1099 | on bar
1100 | to auditor;
1101 | insert into bar (col)
1102 | values (1);
1103 | NOTICE: AUDIT: SESSION,60,1,WRITE,INSERT,TABLE,public.bar,"insert into bar (col)
1104 | values (1);",
1105 | delete from bar;
1106 | NOTICE: AUDIT: OBJECT,61,1,WRITE,DELETE,TABLE,public.bar,delete from bar;,
1107 | NOTICE: AUDIT: SESSION,61,1,WRITE,DELETE,TABLE,public.bar,delete from bar;,
1108 | insert into bar (col)
1109 | values (1);
1110 | NOTICE: AUDIT: SESSION,62,1,WRITE,INSERT,TABLE,public.bar,"insert into bar (col)
1111 | values (1);",
1112 | delete from bar
1113 | where col = 1;
1114 | NOTICE: AUDIT: OBJECT,63,1,WRITE,DELETE,TABLE,public.bar,"delete from bar
1115 | where col = 1;",
1116 | NOTICE: AUDIT: SESSION,63,1,WRITE,DELETE,TABLE,public.bar,"delete from bar
1117 | where col = 1;",
1118 | drop table bar;
1119 | --
1120 | -- Grant roles to each other
1121 | SET pgaudit.log = 'role';
1122 | GRANT user1 TO user2;
1123 | NOTICE: AUDIT: SESSION,64,1,ROLE,GRANT ROLE,,,GRANT user1 TO user2;,
1124 | REVOKE user1 FROM user2;
1125 | NOTICE: AUDIT: SESSION,65,1,ROLE,REVOKE ROLE,,,REVOKE user1 FROM user2;,
1126 | --
1127 | -- Test that FK references do not log but triggers still do
1128 | SET pgaudit.log = 'READ,WRITE';
1129 | SET pgaudit.role TO 'auditor';
1130 | CREATE TABLE aaa
1131 | (
1132 | ID int primary key
1133 | );
1134 | CREATE TABLE bbb
1135 | (
1136 | id int
1137 | references aaa(id)
1138 | );
1139 | CREATE FUNCTION bbb_insert() RETURNS TRIGGER AS $$
1140 | BEGIN
1141 | UPDATE bbb set id = new.id + 1;
1142 |
1143 | RETURN new;
1144 | END $$ LANGUAGE plpgsql;
1145 | CREATE TRIGGER bbb_insert_trg
1146 | AFTER INSERT ON bbb
1147 | FOR EACH ROW EXECUTE PROCEDURE bbb_insert();
1148 | GRANT SELECT, UPDATE
1149 | ON aaa
1150 | TO auditor;
1151 | GRANT UPDATE
1152 | ON bbb
1153 | TO auditor;
1154 | INSERT INTO aaa VALUES (generate_series(1,100));
1155 | NOTICE: AUDIT: SESSION,66,1,WRITE,INSERT,TABLE,public.aaa,"INSERT INTO aaa VALUES (generate_series(1,100));",
1156 | SET pgaudit.log_parameter TO OFF;
1157 | INSERT INTO bbb VALUES (1);
1158 | NOTICE: AUDIT: SESSION,67,1,WRITE,INSERT,TABLE,public.bbb,INSERT INTO bbb VALUES (1);,
1159 | NOTICE: AUDIT: OBJECT,67,2,WRITE,UPDATE,TABLE,public.bbb,UPDATE bbb set id = new.id + 1,
1160 | NOTICE: AUDIT: SESSION,67,2,WRITE,UPDATE,TABLE,public.bbb,UPDATE bbb set id = new.id + 1,
1161 | SET pgaudit.log_parameter TO ON;
1162 | DROP TABLE bbb;
1163 | DROP TABLE aaa;
1164 | -- Test create table as after extension as been dropped
1165 | DROP EXTENSION pgaudit;
1166 | CREATE TABLE tmp (id int, data text);
1167 | CREATE TABLE tmp2 AS (SELECT * FROM tmp);
1168 | NOTICE: AUDIT: SESSION,68,1,READ,SELECT,TABLE,public.tmp,CREATE TABLE tmp2 AS (SELECT * FROM tmp);,
1169 | NOTICE: AUDIT: SESSION,68,1,WRITE,INSERT,TABLE,public.tmp2,CREATE TABLE tmp2 AS (SELECT * FROM tmp);,
1170 | DROP TABLE tmp;
1171 | DROP TABLE tmp2;
1172 | --
1173 | -- Test MISC
1174 | SET pgaudit.log = 'MISC';
1175 | NOTICE: AUDIT: SESSION,69,1,MISC,SET,,,SET pgaudit.log = 'MISC';,
1176 | SET pgaudit.log_level = 'notice';
1177 | NOTICE: AUDIT: SESSION,70,1,MISC,SET,,,SET pgaudit.log_level = 'notice';,
1178 | SET pgaudit.log_client = ON;
1179 | NOTICE: AUDIT: SESSION,71,1,MISC,SET,,,SET pgaudit.log_client = ON;,
1180 | SET pgaudit.log_relation = ON;
1181 | NOTICE: AUDIT: SESSION,72,1,MISC,SET,,,SET pgaudit.log_relation = ON;,
1182 | SET pgaudit.log_parameter = ON;
1183 | NOTICE: AUDIT: SESSION,73,1,MISC,SET,,,SET pgaudit.log_parameter = ON;,
1184 | CREATE ROLE alice;
1185 | SET ROLE alice;
1186 | NOTICE: AUDIT: SESSION,74,1,MISC,SET,,,SET ROLE alice;,
1187 | CREATE TABLE t (a int, b text);
1188 | SET search_path TO test, public;
1189 | NOTICE: AUDIT: SESSION,75,1,MISC,SET,,,"SET search_path TO test, public;",
1190 | INSERT INTO t VALUES (1, 'misc');
1191 | VACUUM t;
1192 | NOTICE: AUDIT: SESSION,76,1,MISC,VACUUM,,,VACUUM t;,
1193 | RESET ROLE;
1194 | NOTICE: AUDIT: SESSION,77,1,MISC,RESET,,,RESET ROLE;,
1195 | --
1196 | -- Test MISC_SET
1197 | SET pgaudit.log = 'MISC_SET';
1198 | NOTICE: AUDIT: SESSION,78,1,MISC,SET,,,SET pgaudit.log = 'MISC_SET';,
1199 | SET ROLE alice;
1200 | NOTICE: AUDIT: SESSION,79,1,MISC,SET,,,SET ROLE alice;,
1201 | SET search_path TO public;
1202 | NOTICE: AUDIT: SESSION,80,1,MISC,SET,,,SET search_path TO public;,
1203 | INSERT INTO t VALUES (2, 'misc_set');
1204 | VACUUM t;
1205 | RESET ROLE;
1206 | NOTICE: AUDIT: SESSION,81,1,MISC,RESET,,,RESET ROLE;,
1207 | --
1208 | -- Test ALL, -MISC, MISC_SET
1209 | SET pgaudit.log = 'ALL, -MISC, MISC_SET';
1210 | NOTICE: AUDIT: SESSION,82,1,MISC,SET,,,"SET pgaudit.log = 'ALL, -MISC, MISC_SET';",
1211 | SET search_path TO public;
1212 | NOTICE: AUDIT: SESSION,83,1,MISC,SET,,,SET search_path TO public;,
1213 | INSERT INTO t VALUES (3, 'all, -misc, misc_set');
1214 | NOTICE: AUDIT: SESSION,84,1,WRITE,INSERT,TABLE,public.t,"INSERT INTO t VALUES (3, 'all, -misc, misc_set');",
1215 | VACUUM t;
1216 | RESET ROLE;
1217 | NOTICE: AUDIT: SESSION,85,1,MISC,RESET,,,RESET ROLE;,
1218 | DROP TABLE public.t;
1219 | NOTICE: AUDIT: SESSION,86,1,DDL,DROP TABLE,,,DROP TABLE public.t;,
1220 | DROP ROLE alice;
1221 | NOTICE: AUDIT: SESSION,87,1,ROLE,DROP ROLE,,,DROP ROLE alice;,
1222 | --
1223 | -- Test PARTITIONED table
1224 | CREATE TABLE h(x int ,y int) PARTITION BY HASH(x);
1225 | NOTICE: AUDIT: SESSION,88,1,DDL,CREATE TABLE,,,"CREATE TABLE h(x int ,y int) PARTITION BY HASH(x);",
1226 | CREATE TABLE h_0 partition OF h FOR VALUES WITH ( MODULUS 2, REMAINDER 0);
1227 | NOTICE: AUDIT: SESSION,89,1,DDL,CREATE TABLE,,,"CREATE TABLE h_0 partition OF h FOR VALUES WITH ( MODULUS 2, REMAINDER 0);",
1228 | CREATE TABLE h_1 partition OF h FOR VALUES WITH ( MODULUS 2, REMAINDER 1);
1229 | NOTICE: AUDIT: SESSION,90,1,DDL,CREATE TABLE,,,"CREATE TABLE h_1 partition OF h FOR VALUES WITH ( MODULUS 2, REMAINDER 1);",
1230 | INSERT INTO h VALUES(1,1);
1231 | NOTICE: AUDIT: SESSION,91,1,WRITE,INSERT,TABLE,public.h,"INSERT INTO h VALUES(1,1);",
1232 | SELECT * FROM h;
1233 | NOTICE: AUDIT: SESSION,92,1,READ,SELECT,TABLE,public.h,SELECT * FROM h;,
1234 | x | y
1235 | ---+---
1236 | 1 | 1
1237 | (1 row)
1238 |
1239 | SELECT * FROM h_0;
1240 | NOTICE: AUDIT: SESSION,93,1,READ,SELECT,TABLE,public.h_0,SELECT * FROM h_0;,
1241 | x | y
1242 | ---+---
1243 | 1 | 1
1244 | (1 row)
1245 |
1246 | CREATE INDEX h_idx ON h (x);
1247 | NOTICE: AUDIT: SESSION,94,1,DDL,CREATE INDEX,,,CREATE INDEX h_idx ON h (x);,
1248 | DROP INDEX h_idx;
1249 | NOTICE: AUDIT: SESSION,95,1,DDL,DROP INDEX,,,DROP INDEX h_idx;,
1250 | DROP TABLE h;
1251 | NOTICE: AUDIT: SESSION,96,1,DDL,DROP TABLE,,,DROP TABLE h;,
1252 | -- Cleanup
1253 | -- Set client_min_messages up to warning to avoid noise
1254 | SET client_min_messages = 'warning';
1255 | ALTER ROLE :current_user RESET pgaudit.log;
1256 | ALTER ROLE :current_user RESET pgaudit.log_catalog;
1257 | ALTER ROLE :current_user RESET pgaudit.log_client;
1258 | ALTER ROLE :current_user RESET pgaudit.log_level;
1259 | ALTER ROLE :current_user RESET pgaudit.log_parameter;
1260 | ALTER ROLE :current_user RESET pgaudit.log_relation;
1261 | ALTER ROLE :current_user RESET pgaudit.log_statement;
1262 | ALTER ROLE :current_user RESET pgaudit.log_statement_once;
1263 | ALTER ROLE :current_user RESET pgaudit.role;
1264 | RESET pgaudit.log;
1265 | RESET pgaudit.log_catalog;
1266 | RESET pgaudit.log_level;
1267 | RESET pgaudit.log_parameter;
1268 | RESET pgaudit.log_relation;
1269 | RESET pgaudit.log_statement;
1270 | RESET pgaudit.log_statement_once;
1271 | RESET pgaudit.role;
1272 | DROP TABLE test.account_copy;
1273 | DROP TABLE test.test_insert;
1274 | DROP SCHEMA test;
1275 | DROP TABLE foo.bar;
1276 | DROP TABLE foo.baz;
1277 | DROP SCHEMA foo;
1278 | DROP TABLE hoge;
1279 | DROP TABLE account;
1280 | DROP TABLE account_role_map;
1281 | DROP USER user2;
1282 | DROP USER user1;
1283 | DROP ROLE auditor;
1284 | RESET client_min_messages;
1285 |
--------------------------------------------------------------------------------
/pgaudit--1.5.50.1.sql:
--------------------------------------------------------------------------------
1 | -- complain if script is sourced in psql, rather than via CREATE EXTENSION
2 | \echo Use "CREATE EXTENSION pgaudit" to load this file.\quit
3 |
4 | CREATE FUNCTION pgaudit_ddl_command_end()
5 | RETURNS event_trigger
6 | LANGUAGE C
7 | AS 'MODULE_PATHNAME', 'pgaudit_ddl_command_end';
8 |
9 | CREATE EVENT TRIGGER pgaudit_ddl_command_end
10 | ON ddl_command_end
11 | EXECUTE PROCEDURE pgaudit_ddl_command_end();
12 |
13 | CREATE FUNCTION pgaudit_sql_drop()
14 | RETURNS event_trigger
15 | LANGUAGE C
16 | AS 'MODULE_PATHNAME', 'pgaudit_sql_drop';
17 |
18 | CREATE EVENT TRIGGER pgaudit_sql_drop
19 | ON sql_drop
20 | EXECUTE PROCEDURE pgaudit_sql_drop();
21 |
--------------------------------------------------------------------------------
/pgaudit.c:
--------------------------------------------------------------------------------
1 | /*------------------------------------------------------------------------------
2 | * pgaudit.c
3 | *
4 | * An audit logging extension for PostgreSQL. Provides detailed logging classes,
5 | * object level logging, and fully-qualified object names for all DML and DDL
6 | * statements where possible (See README.md for details).
7 | *
8 | * Copyright (c) 2014-2021, PostgreSQL Global Development Group
9 | *------------------------------------------------------------------------------
10 | */
11 | #include "postgres.h"
12 |
13 | #include "access/htup_details.h"
14 | #include "access/sysattr.h"
15 | #include "access/xact.h"
16 | #include "catalog/catalog.h"
17 | #include "catalog/objectaccess.h"
18 | #include "catalog/pg_class.h"
19 | #include "catalog/namespace.h"
20 | #include "commands/dbcommands.h"
21 | #include "catalog/pg_proc.h"
22 | #include "commands/event_trigger.h"
23 | #include "executor/executor.h"
24 | #include "executor/spi.h"
25 | #include "miscadmin.h"
26 | #include "libpq/auth.h"
27 | #include "nodes/nodes.h"
28 | #include "nodes/params.h"
29 | #include "tcop/utility.h"
30 | #include "tcop/deparse_utility.h"
31 | #include "utils/acl.h"
32 | #include "utils/builtins.h"
33 | #include "utils/guc.h"
34 | #include "utils/lsyscache.h"
35 | #include "utils/memutils.h"
36 | #include "utils/rel.h"
37 | #include "utils/syscache.h"
38 | #include "utils/timestamp.h"
39 | #include "utils/varlena.h"
40 |
41 | PG_MODULE_MAGIC;
42 |
43 | void _PG_init(void);
44 |
45 | PG_FUNCTION_INFO_V1(pgaudit_ddl_command_end);
46 | PG_FUNCTION_INFO_V1(pgaudit_sql_drop);
47 |
48 | /*
49 | * Log Classes
50 | *
51 | * pgAudit categorizes actions into classes (eg: DDL, FUNCTION calls, READ
52 | * queries, WRITE queries). A GUC is provided for the administrator to
53 | * configure which class (or classes) of actions to include in the
54 | * audit log. We track the currently active set of classes using
55 | * auditLogBitmap.
56 | */
57 |
58 | /* Bits within auditLogBitmap, defines the classes we understand */
59 | #define LOG_DDL (1 << 0) /* CREATE/DROP/ALTER objects */
60 | #define LOG_FUNCTION (1 << 1) /* Functions and DO blocks */
61 | #define LOG_MISC (1 << 2) /* Statements not covered */
62 | #define LOG_READ (1 << 3) /* SELECTs */
63 | #define LOG_ROLE (1 << 4) /* GRANT/REVOKE, CREATE/ALTER/DROP ROLE */
64 | #define LOG_WRITE (1 << 5) /* INSERT, UPDATE, DELETE, TRUNCATE */
65 | #define LOG_MISC_SET (1 << 6) /* SET ... */
66 |
67 | #define LOG_NONE 0 /* nothing */
68 | #define LOG_ALL (0xFFFFFFFF) /* All */
69 |
70 | /* GUC variable for pgaudit.log, which defines the classes to log. */
71 | char *auditLog = NULL;
72 |
73 | /* Bitmap of classes selected */
74 | static int auditLogBitmap = LOG_NONE;
75 |
76 | /*
77 | * String constants for log classes - used when processing tokens in the
78 | * pgaudit.log GUC.
79 | */
80 | #define CLASS_DDL "DDL"
81 | #define CLASS_FUNCTION "FUNCTION"
82 | #define CLASS_MISC "MISC"
83 | #define CLASS_MISC_SET "MISC_SET"
84 | #define CLASS_READ "READ"
85 | #define CLASS_ROLE "ROLE"
86 | #define CLASS_WRITE "WRITE"
87 |
88 | #define CLASS_NONE "NONE"
89 | #define CLASS_ALL "ALL"
90 |
91 | /*
92 | * GUC variable for pgaudit.log_catalog
93 | *
94 | * Administrators can choose to NOT log queries when all relations used in
95 | * the query are in pg_catalog. Interactive sessions (eg: psql) can cause
96 | * a lot of noise in the logs which might be uninteresting.
97 | */
98 | bool auditLogCatalog = true;
99 |
100 | /*
101 | * GUC variable for pgaudit.log_client
102 | *
103 | * Specifies whether audit messages should be visible to the client. This
104 | * setting should generally be left disabled but may be useful for debugging or
105 | * other purposes.
106 | */
107 | bool auditLogClient = false;
108 |
109 | /*
110 | * GUC variable for pgaudit.log_level
111 | *
112 | * Administrators can choose which log level the audit log is to be logged
113 | * at. The default level is LOG, which goes into the server log but does
114 | * not go to the client. Set to NOTICE in the regression tests.
115 | */
116 | char *auditLogLevelString = NULL;
117 | int auditLogLevel = LOG;
118 |
119 | /*
120 | * GUC variable for pgaudit.log_parameter
121 | *
122 | * Administrators can choose if parameters passed into a statement are
123 | * included in the audit log.
124 | */
125 | bool auditLogParameter = false;
126 |
127 | /*
128 | * GUC variable for pgaudit.log_relation
129 | *
130 | * Administrators can choose, in SESSION logging, to log each relation involved
131 | * in READ/WRITE class queries. By default, SESSION logs include the query but
132 | * do not have a log entry for each relation.
133 | */
134 | bool auditLogRelation = false;
135 |
136 | /*
137 | * GUC variable for pgaudit.log_statement
138 | *
139 | * Administrators can choose to not have the full statement text logged.
140 | */
141 | bool auditLogStatement = true;
142 |
143 | /*
144 | * GUC variable for pgaudit.log_statement_once
145 | *
146 | * Administrators can choose to have the statement run logged only once instead
147 | * of on every line. By default, the statement is repeated on every line of
148 | * the audit log to facilitate searching, but this can cause the log to be
149 | * unnecessairly bloated in some environments.
150 | */
151 | bool auditLogStatementOnce = false;
152 |
153 | /*
154 | * GUC variable for pgaudit.role
155 | *
156 | * Administrators can choose which role to base OBJECT auditing off of.
157 | * Object-level auditing uses the privileges which are granted to this role to
158 | * determine if a statement should be logged.
159 | */
160 | char *auditRole = NULL;
161 |
162 | /*
163 | * String constants for the audit log fields.
164 | */
165 |
166 | /*
167 | * Audit type, which is responsbile for the log message
168 | */
169 | #define AUDIT_TYPE_OBJECT "OBJECT"
170 | #define AUDIT_TYPE_SESSION "SESSION"
171 |
172 | /*
173 | * Object type, used for SELECT/DML statements and function calls.
174 | *
175 | * For relation objects, this is essentially relkind (though we do not have
176 | * access to a function which will just return a string given a relkind;
177 | * getRelationTypeDescription() comes close but is not public currently).
178 | *
179 | * We also handle functions, so it isn't quite as simple as just relkind.
180 | *
181 | * This should be kept consistent with what is returned from
182 | * pg_event_trigger_ddl_commands(), as that's what we use for DDL.
183 | */
184 | #define OBJECT_TYPE_TABLE "TABLE"
185 | #define OBJECT_TYPE_INDEX "INDEX"
186 | #define OBJECT_TYPE_SEQUENCE "SEQUENCE"
187 | #define OBJECT_TYPE_TOASTVALUE "TOAST TABLE"
188 | #define OBJECT_TYPE_VIEW "VIEW"
189 | #define OBJECT_TYPE_MATVIEW "MATERIALIZED VIEW"
190 | #define OBJECT_TYPE_COMPOSITE_TYPE "COMPOSITE TYPE"
191 | #define OBJECT_TYPE_FOREIGN_TABLE "FOREIGN TABLE"
192 | #define OBJECT_TYPE_FUNCTION "FUNCTION"
193 |
194 | #define OBJECT_TYPE_UNKNOWN "UNKNOWN"
195 |
196 | /*
197 | * String constants used for redacting text after the password token in
198 | * CREATE/ALTER ROLE commands.
199 | */
200 | #define TOKEN_PASSWORD "password"
201 | #define TOKEN_REDACTED ""
202 |
203 | #if PG_VERSION_NUM < 130000
204 |
205 | #define CommandTag const char *
206 | #define QueryCompletion char
207 |
208 | #define GetCommandTagName(commandTag) (commandTag)
209 | #define GetCommandTagEnum(commandname) (commandname)
210 |
211 | #define CMDTAG_ALTER_ROLE "ALTER ROLE"
212 | #define CMDTAG_DELETE "DELETE"
213 | #define CMDTAG_DROP_ROLE "DROP ROLE"
214 | #define CMDTAG_EXECUTE "EXECUTE"
215 | #define CMDTAG_GRANT "GRANT"
216 | #define CMDTAG_INSERT "INSERT"
217 | #define CMDTAG_REVOKE "REVOKE"
218 | #define CMDTAG_SELECT "SELECT"
219 | #define CMDTAG_UPDATE "UPDATE"
220 | #define CMDTAG_UNKNOWN "???"
221 |
222 | #endif
223 |
224 | #if PG_VERSION_NUM < 120000
225 | #define IsCatalogNamespace(namespaceId) IsSystemNamespace(namespaceId)
226 | #endif
227 |
228 | /*
229 | * An AuditEvent represents an operation that potentially affects a single
230 | * object. If a statement affects multiple objects then multiple AuditEvents
231 | * are created to represent them.
232 | */
233 | typedef struct
234 | {
235 | int64 statementId; /* Simple counter */
236 | int64 substatementId; /* Simple counter */
237 |
238 | LogStmtLevel logStmtLevel; /* From GetCommandLogLevel when possible,
239 | generated when not. */
240 | NodeTag commandTag; /* same here */
241 | CommandTag command; /* same here */
242 | const char *objectType; /* From event trigger when possible,
243 | generated when not. */
244 | char *objectName; /* Fully qualified object identification */
245 | const char *commandText; /* sourceText / queryString */
246 | ParamListInfo paramList; /* QueryDesc/ProcessUtility parameters */
247 |
248 | bool granted; /* Audit role has object permissions? */
249 | bool logged; /* Track if we have logged this event, used
250 | post-ProcessUtility to make sure we log */
251 | bool statementLogged; /* Track if we have logged the statement */
252 | } AuditEvent;
253 |
254 | /*
255 | * A simple FIFO queue to keep track of the current stack of audit events.
256 | */
257 | typedef struct AuditEventStackItem
258 | {
259 | struct AuditEventStackItem *next;
260 |
261 | AuditEvent auditEvent;
262 |
263 | int64 stackId;
264 |
265 | MemoryContext contextAudit;
266 | MemoryContextCallback contextCallback;
267 | } AuditEventStackItem;
268 |
269 | AuditEventStackItem *auditEventStack = NULL;
270 |
271 | /*
272 | * pgAudit runs queries of its own when using the event trigger system.
273 | *
274 | * Track when we are running a query and don't log it.
275 | */
276 | static bool internalStatement = false;
277 |
278 | /*
279 | * Track running total for statements and substatements and whether or not
280 | * anything has been logged since the current statement began.
281 | */
282 | static int64 statementTotal = 0;
283 | static int64 substatementTotal = 0;
284 | static int64 stackTotal = 0;
285 |
286 | static bool statementLogged = false;
287 |
288 | /*
289 | * Stack functions
290 | *
291 | * Audit events can go down to multiple levels so a stack is maintained to keep
292 | * track of them.
293 | */
294 |
295 | /*
296 | * Respond to callbacks registered with MemoryContextRegisterResetCallback().
297 | * Removes the event(s) off the stack that have become obsolete once the
298 | * MemoryContext has been freed. The callback should always be freeing the top
299 | * of the stack, but the code is tolerant of out-of-order callbacks.
300 | */
301 | static void
302 | stack_free(void *stackFree)
303 | {
304 | AuditEventStackItem *nextItem = auditEventStack;
305 |
306 | /* Only process if the stack contains items */
307 | while (nextItem != NULL)
308 | {
309 | /* Check if this item matches the item to be freed */
310 | if (nextItem == (AuditEventStackItem *) stackFree)
311 | {
312 | /* Move top of stack to the item after the freed item */
313 | auditEventStack = nextItem->next;
314 |
315 | /* If the stack is not empty */
316 | if (auditEventStack == NULL)
317 | {
318 | /*
319 | * Reset internal statement to false. Normally this will be
320 | * reset but in case of an error it might be left set.
321 | */
322 | internalStatement = false;
323 |
324 | /*
325 | * Reset sub statement total so the next statement will start
326 | * from 1.
327 | */
328 | substatementTotal = 0;
329 |
330 | /*
331 | * Reset statement logged so that next statement will be
332 | * logged.
333 | */
334 | statementLogged = false;
335 | }
336 |
337 | return;
338 | }
339 |
340 | nextItem = nextItem->next;
341 | }
342 | }
343 |
344 | /*
345 | * Push a new audit event onto the stack and create a new memory context to
346 | * store it.
347 | */
348 | static AuditEventStackItem *
349 | stack_push()
350 | {
351 | MemoryContext contextAudit;
352 | MemoryContext contextOld;
353 | AuditEventStackItem *stackItem;
354 |
355 | /*
356 | * Create a new memory context to contain the stack item. This will be
357 | * free'd on stack_pop, or by our callback when the parent context is
358 | * destroyed.
359 | */
360 | contextAudit = AllocSetContextCreate(CurrentMemoryContext,
361 | "pgaudit stack context",
362 | ALLOCSET_DEFAULT_SIZES);
363 |
364 | /* Save the old context to switch back to at the end */
365 | contextOld = MemoryContextSwitchTo(contextAudit);
366 |
367 | /* Create our new stack item in our context */
368 | stackItem = palloc0(sizeof(AuditEventStackItem));
369 | stackItem->contextAudit = contextAudit;
370 | stackItem->stackId = ++stackTotal;
371 |
372 | /*
373 | * Setup a callback in case an error happens. stack_free() will truncate
374 | * the stack at this item.
375 | */
376 | stackItem->contextCallback.func = stack_free;
377 | stackItem->contextCallback.arg = (void *) stackItem;
378 | MemoryContextRegisterResetCallback(contextAudit,
379 | &stackItem->contextCallback);
380 |
381 | /* Push new item onto the stack */
382 | if (auditEventStack != NULL)
383 | stackItem->next = auditEventStack;
384 | else
385 | stackItem->next = NULL;
386 |
387 | auditEventStack = stackItem;
388 |
389 | MemoryContextSwitchTo(contextOld);
390 |
391 | return stackItem;
392 | }
393 |
394 | /*
395 | * Pop an audit event from the stack by deleting the memory context that
396 | * contains it. The callback to stack_free() does the actual pop.
397 | */
398 | static void
399 | stack_pop(int64 stackId)
400 | {
401 | /* Make sure what we want to delete is at the top of the stack */
402 | if (auditEventStack != NULL && auditEventStack->stackId == stackId)
403 | MemoryContextDelete(auditEventStack->contextAudit);
404 | else
405 | elog(ERROR, "pgaudit stack item " INT64_FORMAT " not found on top - cannot pop",
406 | stackId);
407 | }
408 |
409 | /*
410 | * Check that an item is on the stack. If not, an error will be raised since
411 | * this is a bad state to be in and it might mean audit records are being lost.
412 | */
413 | static void
414 | stack_valid(int64 stackId)
415 | {
416 | AuditEventStackItem *nextItem = auditEventStack;
417 |
418 | /* Look through the stack for the stack entry */
419 | while (nextItem != NULL && nextItem->stackId != stackId)
420 | nextItem = nextItem->next;
421 |
422 | /* If we didn't find it, something went wrong. */
423 | if (nextItem == NULL)
424 | elog(ERROR, "pgaudit stack item " INT64_FORMAT
425 | " not found - top of stack is " INT64_FORMAT "",
426 | stackId,
427 | auditEventStack == NULL ? (int64) -1 : auditEventStack->stackId);
428 | }
429 |
430 | /*
431 | * Appends a properly quoted CSV field to StringInfo.
432 | */
433 | static void
434 | append_valid_csv(StringInfoData *buffer, const char *appendStr)
435 | {
436 | const char *pChar;
437 |
438 | /*
439 | * If the append string is null then do nothing. NULL fields are not
440 | * quoted in CSV.
441 | */
442 | if (appendStr == NULL)
443 | return;
444 |
445 | /* Only format for CSV if appendStr contains: ", comma, \n, \r */
446 | if (strstr(appendStr, ",") || strstr(appendStr, "\"") ||
447 | strstr(appendStr, "\n") || strstr(appendStr, "\r"))
448 | {
449 | appendStringInfoCharMacro(buffer, '"');
450 |
451 | for (pChar = appendStr; *pChar; pChar++)
452 | {
453 | if (*pChar == '"') /* double single quotes */
454 | appendStringInfoCharMacro(buffer, *pChar);
455 |
456 | appendStringInfoCharMacro(buffer, *pChar);
457 | }
458 |
459 | appendStringInfoCharMacro(buffer, '"');
460 | }
461 | /* Else just append */
462 | else
463 | appendStringInfoString(buffer, appendStr);
464 | }
465 |
466 | /*
467 | * Takes an AuditEvent, classifies it, then logs it if appropriate.
468 | *
469 | * Logging is decided based on if the statement is in one of the classes being
470 | * logged or if an object used has been marked for auditing.
471 | *
472 | * Objects are marked for auditing by the auditor role being granted access
473 | * to the object. The kind of access (INSERT, UPDATE, etc) is also considered
474 | * and logging is only performed when the kind of access matches the granted
475 | * right on the object.
476 | *
477 | * This will need to be updated if new kinds of GRANTs are added.
478 | */
479 | static void
480 | log_audit_event(AuditEventStackItem *stackItem)
481 | {
482 | /* By default, put everything in the MISC class. */
483 | int class = LOG_MISC;
484 | const char *className = CLASS_MISC;
485 | MemoryContext contextOld;
486 | StringInfoData auditStr;
487 |
488 | /* If this event has already been logged don't log it again */
489 | if (stackItem->auditEvent.logged)
490 | return;
491 |
492 | /* Classify the statement using log stmt level and the command tag */
493 | switch (stackItem->auditEvent.logStmtLevel)
494 | {
495 | /* All mods go in WRITE class, except EXECUTE */
496 | case LOGSTMT_MOD:
497 | className = CLASS_WRITE;
498 | class = LOG_WRITE;
499 |
500 | switch (stackItem->auditEvent.commandTag)
501 | {
502 | /* Currently, only EXECUTE is different */
503 | case T_ExecuteStmt:
504 | className = CLASS_MISC;
505 | class = LOG_MISC;
506 | break;
507 | default:
508 | break;
509 | }
510 | break;
511 |
512 | /* These are DDL, unless they are ROLE */
513 | case LOGSTMT_DDL:
514 | className = CLASS_DDL;
515 | class = LOG_DDL;
516 |
517 | /* Identify role statements */
518 | switch (stackItem->auditEvent.commandTag)
519 | {
520 | /* In the case of create and alter role redact all text in the
521 | * command after the password token for security. This doesn't
522 | * cover all possible cases where passwords can be leaked but
523 | * should take care of the most common usage.
524 | */
525 | case T_CreateRoleStmt:
526 | case T_AlterRoleStmt:
527 |
528 | if (stackItem->auditEvent.commandText != NULL)
529 | {
530 | char *commandStr;
531 | char *passwordToken;
532 | int i;
533 | int passwordPos;
534 |
535 | /* Copy the command string and convert to lower case */
536 | commandStr = pstrdup(stackItem->auditEvent.commandText);
537 |
538 | for (i = 0; commandStr[i]; i++)
539 | commandStr[i] =
540 | (char)pg_tolower((unsigned char)commandStr[i]);
541 |
542 | /* Find index of password token */
543 | passwordToken = strstr(commandStr, TOKEN_PASSWORD);
544 |
545 | if (passwordToken != NULL)
546 | {
547 | /* Copy command string up to password token */
548 | passwordPos = (passwordToken - commandStr) +
549 | strlen(TOKEN_PASSWORD);
550 |
551 | commandStr = palloc(passwordPos + 1 +
552 | strlen(TOKEN_REDACTED) + 1);
553 |
554 | strncpy(commandStr,
555 | stackItem->auditEvent.commandText,
556 | passwordPos);
557 |
558 | /* And append redacted token */
559 | commandStr[passwordPos] = ' ';
560 |
561 | strcpy(commandStr + passwordPos + 1, TOKEN_REDACTED);
562 |
563 | /* Assign new command string */
564 | stackItem->auditEvent.commandText = commandStr;
565 | }
566 | }
567 |
568 | /* Fall through */
569 |
570 | /* Classify role statements */
571 | case T_GrantStmt:
572 | case T_GrantRoleStmt:
573 | case T_DropRoleStmt:
574 | case T_AlterRoleSetStmt:
575 | case T_AlterDefaultPrivilegesStmt:
576 | className = CLASS_ROLE;
577 | class = LOG_ROLE;
578 | break;
579 |
580 | /*
581 | * Rename and Drop are general and therefore we have to do
582 | * an additional check against the command string to see
583 | * if they are role or regular DDL.
584 | */
585 | case T_RenameStmt:
586 | case T_DropStmt:
587 | #if PG_VERSION_NUM >= 130000
588 | if (stackItem->auditEvent.command == CMDTAG_ALTER_ROLE ||
589 | stackItem->auditEvent.command == CMDTAG_DROP_ROLE)
590 | #else
591 | if (pg_strcasecmp(stackItem->auditEvent.command,
592 | CMDTAG_ALTER_ROLE) == 0 ||
593 | pg_strcasecmp(stackItem->auditEvent.command,
594 | CMDTAG_DROP_ROLE) == 0)
595 | #endif
596 | {
597 | className = CLASS_ROLE;
598 | class = LOG_ROLE;
599 | }
600 | break;
601 |
602 | default:
603 | break;
604 | }
605 | break;
606 |
607 | /* Classify the rest */
608 | case LOGSTMT_ALL:
609 | switch (stackItem->auditEvent.commandTag)
610 | {
611 | /* READ statements */
612 | case T_CopyStmt:
613 | case T_DeclareCursorStmt:
614 | case T_SelectStmt:
615 | case T_PrepareStmt:
616 | case T_PlannedStmt:
617 | className = CLASS_READ;
618 | class = LOG_READ;
619 | break;
620 |
621 | /* FUNCTION statements */
622 | case T_DoStmt:
623 | className = CLASS_FUNCTION;
624 | class = LOG_FUNCTION;
625 | break;
626 |
627 | /*
628 | * SET statements reported as MISC but filtered by MISC_SET
629 | * flags to maintain existing functionality.
630 | */
631 | case T_VariableSetStmt:
632 | className = CLASS_MISC;
633 | class = LOG_MISC_SET;
634 | break;
635 |
636 | default:
637 | break;
638 | }
639 | break;
640 |
641 | case LOGSTMT_NONE:
642 | break;
643 | }
644 |
645 | /*
646 | * Only log the statement if:
647 | *
648 | * 1. The object was selected for audit logging (granted), or
649 | * 2. The statement belongs to a class that is being logged
650 | *
651 | * If neither of these is true, return.
652 | */
653 | if (!stackItem->auditEvent.granted && !(auditLogBitmap & class))
654 | return;
655 |
656 | /*
657 | * Use audit memory context in case something is not free'd while
658 | * appending strings and parameters.
659 | */
660 | contextOld = MemoryContextSwitchTo(stackItem->contextAudit);
661 |
662 | /* Set statement and substatement IDs */
663 | if (stackItem->auditEvent.statementId == 0)
664 | {
665 | /* If nothing has been logged yet then create a new statement Id */
666 | if (!statementLogged)
667 | {
668 | statementTotal++;
669 | statementLogged = true;
670 | }
671 |
672 | stackItem->auditEvent.statementId = statementTotal;
673 | stackItem->auditEvent.substatementId = ++substatementTotal;
674 | }
675 |
676 | /*
677 | * Create the audit substring
678 | *
679 | * The type-of-audit-log and statement/substatement ID are handled below,
680 | * this string is everything else.
681 | */
682 | initStringInfo(&auditStr);
683 | append_valid_csv(&auditStr, GetCommandTagName(stackItem->auditEvent.command));
684 |
685 | appendStringInfoCharMacro(&auditStr, ',');
686 | append_valid_csv(&auditStr, stackItem->auditEvent.objectType);
687 |
688 | appendStringInfoCharMacro(&auditStr, ',');
689 | append_valid_csv(&auditStr, stackItem->auditEvent.objectName);
690 |
691 | /*
692 | * If auditLogStatmentOnce is true, then only log the statement and
693 | * parameters if they have not already been logged for this substatement.
694 | */
695 | appendStringInfoCharMacro(&auditStr, ',');
696 | if (auditLogStatement && !(stackItem->auditEvent.statementLogged && auditLogStatementOnce))
697 | {
698 | append_valid_csv(&auditStr, stackItem->auditEvent.commandText);
699 |
700 | appendStringInfoCharMacro(&auditStr, ',');
701 |
702 | /* Handle parameter logging, if enabled. */
703 | if (auditLogParameter)
704 | {
705 | int paramIdx;
706 | int numParams;
707 | StringInfoData paramStrResult;
708 | ParamListInfo paramList = stackItem->auditEvent.paramList;
709 |
710 | numParams = paramList == NULL ? 0 : paramList->numParams;
711 |
712 | /* Create the param substring */
713 | initStringInfo(¶mStrResult);
714 |
715 | /* Iterate through all params */
716 | for (paramIdx = 0; paramList != NULL && paramIdx < numParams;
717 | paramIdx++)
718 | {
719 | ParamExternData *prm = ¶mList->params[paramIdx];
720 | Oid typeOutput;
721 | bool typeIsVarLena;
722 | char *paramStr;
723 |
724 | /* Add a comma for each param */
725 | if (paramIdx != 0)
726 | appendStringInfoCharMacro(¶mStrResult, ',');
727 |
728 | /* Skip if null or if oid is invalid */
729 | if (prm->isnull || !OidIsValid(prm->ptype))
730 | continue;
731 |
732 | /* Output the string */
733 | getTypeOutputInfo(prm->ptype, &typeOutput, &typeIsVarLena);
734 | paramStr = OidOutputFunctionCall(typeOutput, prm->value);
735 |
736 | append_valid_csv(¶mStrResult, paramStr);
737 | pfree(paramStr);
738 | }
739 |
740 | if (numParams == 0)
741 | appendStringInfoString(&auditStr, "");
742 | else
743 | append_valid_csv(&auditStr, paramStrResult.data);
744 | }
745 | else
746 | appendStringInfoString(&auditStr, "");
747 |
748 | stackItem->auditEvent.statementLogged = true;
749 | }
750 | /* we were asked to not log it */
751 | else if (!auditLogStatement)
752 | appendStringInfoString(&auditStr,
753 | ",");
754 | else
755 | appendStringInfoString(&auditStr,
756 | ",");
757 |
758 | /*
759 | * Log the audit entry. Note: use of INT64_FORMAT here is bad for
760 | * translatability, but we currently haven't got translation support in
761 | * pgaudit anyway.
762 | */
763 | ereport(auditLogClient ? auditLogLevel : LOG_SERVER_ONLY,
764 | (errmsg("AUDIT: %s," INT64_FORMAT "," INT64_FORMAT ",%s,%s",
765 | stackItem->auditEvent.granted ?
766 | AUDIT_TYPE_OBJECT : AUDIT_TYPE_SESSION,
767 | stackItem->auditEvent.statementId,
768 | stackItem->auditEvent.substatementId,
769 | className,
770 | auditStr.data),
771 | errhidestmt(true),
772 | errhidecontext(true)));
773 |
774 | stackItem->auditEvent.logged = true;
775 |
776 | MemoryContextSwitchTo(contextOld);
777 | }
778 |
779 | /*
780 | * Check if the role or any inherited role has any permission in the mask. The
781 | * public role is excluded from this check and superuser permissions are not
782 | * considered.
783 | */
784 | static bool
785 | audit_on_acl(Datum aclDatum,
786 | Oid auditOid,
787 | AclMode mask)
788 | {
789 | bool result = false;
790 | Acl *acl;
791 | AclItem *aclItemData;
792 | int aclIndex;
793 | int aclTotal;
794 |
795 | /* Detoast column's ACL if necessary */
796 | acl = DatumGetAclP(aclDatum);
797 |
798 | /* Get the acl list and total number of items */
799 | aclTotal = ACL_NUM(acl);
800 | aclItemData = ACL_DAT(acl);
801 |
802 | /* Check privileges granted directly to auditOid */
803 | for (aclIndex = 0; aclIndex < aclTotal; aclIndex++)
804 | {
805 | AclItem *aclItem = &aclItemData[aclIndex];
806 |
807 | if (aclItem->ai_grantee == auditOid &&
808 | aclItem->ai_privs & mask)
809 | {
810 | result = true;
811 | break;
812 | }
813 | }
814 |
815 | /*
816 | * Check privileges granted indirectly via role memberships. We do this in
817 | * a separate pass to minimize expensive indirect membership tests. In
818 | * particular, it's worth testing whether a given ACL entry grants any
819 | * privileges still of interest before we perform the has_privs_of_role
820 | * test.
821 | */
822 | if (!result)
823 | {
824 | for (aclIndex = 0; aclIndex < aclTotal; aclIndex++)
825 | {
826 | AclItem *aclItem = &aclItemData[aclIndex];
827 |
828 | /* Don't test public or auditOid (it has been tested already) */
829 | if (aclItem->ai_grantee == ACL_ID_PUBLIC ||
830 | aclItem->ai_grantee == auditOid)
831 | continue;
832 |
833 | /*
834 | * Check that the role has the required privileges and that it is
835 | * inherited by auditOid.
836 | */
837 | if (aclItem->ai_privs & mask &&
838 | has_privs_of_role(auditOid, aclItem->ai_grantee))
839 | {
840 | result = true;
841 | break;
842 | }
843 | }
844 | }
845 |
846 | /* If we have a detoasted copy, free it */
847 | if (acl && (Pointer) acl != DatumGetPointer(aclDatum))
848 | pfree(acl);
849 |
850 | return result;
851 | }
852 |
853 | /*
854 | * Check if a role has any of the permissions in the mask on a relation.
855 | */
856 | static bool
857 | audit_on_relation(Oid relOid,
858 | Oid auditOid,
859 | AclMode mask)
860 | {
861 | bool result = false;
862 | HeapTuple tuple;
863 | Datum aclDatum;
864 | bool isNull;
865 |
866 | /* Get relation tuple from pg_class */
867 | tuple = SearchSysCache1(RELOID, ObjectIdGetDatum(relOid));
868 | if (!HeapTupleIsValid(tuple))
869 | return false;
870 |
871 | /* Get the relation's ACL */
872 | aclDatum = SysCacheGetAttr(RELOID, tuple, Anum_pg_class_relacl,
873 | &isNull);
874 |
875 | /* Only check if non-NULL, since NULL means no permissions */
876 | if (!isNull)
877 | result = audit_on_acl(aclDatum, auditOid, mask);
878 |
879 | /* Free the relation tuple */
880 | ReleaseSysCache(tuple);
881 |
882 | return result;
883 | }
884 |
885 | /*
886 | * Check if a role has any of the permissions in the mask on a column.
887 | */
888 | static bool
889 | audit_on_attribute(Oid relOid,
890 | AttrNumber attNum,
891 | Oid auditOid,
892 | AclMode mask)
893 | {
894 | bool result = false;
895 | HeapTuple attTuple;
896 | Datum aclDatum;
897 | bool isNull;
898 |
899 | /* Get the attribute's ACL */
900 | attTuple = SearchSysCache2(ATTNUM,
901 | ObjectIdGetDatum(relOid),
902 | Int16GetDatum(attNum));
903 | if (!HeapTupleIsValid(attTuple))
904 | return false;
905 |
906 | /* Only consider attributes that have not been dropped */
907 | if (!((Form_pg_attribute) GETSTRUCT(attTuple))->attisdropped)
908 | {
909 | aclDatum = SysCacheGetAttr(ATTNUM, attTuple, Anum_pg_attribute_attacl,
910 | &isNull);
911 |
912 | if (!isNull)
913 | result = audit_on_acl(aclDatum, auditOid, mask);
914 | }
915 |
916 | /* Free attribute */
917 | ReleaseSysCache(attTuple);
918 |
919 | return result;
920 | }
921 |
922 | /*
923 | * Check if a role has any of the permissions in the mask on a column in
924 | * the provided set. If the set is empty, then all valid columns in the
925 | * relation will be tested.
926 | */
927 | static bool
928 | audit_on_any_attribute(Oid relOid,
929 | Oid auditOid,
930 | Bitmapset *attributeSet,
931 | AclMode mode)
932 | {
933 | bool result = false;
934 | AttrNumber col;
935 | Bitmapset *tmpSet;
936 |
937 | /* If bms is empty then check for any column match */
938 | if (bms_is_empty(attributeSet))
939 | {
940 | HeapTuple classTuple;
941 | AttrNumber nattrs;
942 | AttrNumber curr_att;
943 |
944 | /* Get relation to determine total columns */
945 | classTuple = SearchSysCache1(RELOID, ObjectIdGetDatum(relOid));
946 |
947 | if (!HeapTupleIsValid(classTuple))
948 | return false;
949 |
950 | nattrs = ((Form_pg_class) GETSTRUCT(classTuple))->relnatts;
951 | ReleaseSysCache(classTuple);
952 |
953 | /* Check each column */
954 | for (curr_att = 1; curr_att <= nattrs; curr_att++)
955 | if (audit_on_attribute(relOid, curr_att, auditOid, mode))
956 | return true;
957 | }
958 |
959 | /* bms_first_member is destructive, so make a copy before using it. */
960 | tmpSet = bms_copy(attributeSet);
961 |
962 | /* Check each column */
963 | while ((col = bms_first_member(tmpSet)) >= 0)
964 | {
965 | col += FirstLowInvalidHeapAttributeNumber;
966 |
967 | if (col != InvalidAttrNumber &&
968 | audit_on_attribute(relOid, col, auditOid, mode))
969 | {
970 | result = true;
971 | break;
972 | }
973 | }
974 |
975 | bms_free(tmpSet);
976 |
977 | return result;
978 | }
979 |
980 | /*
981 | * Create AuditEvents for SELECT/DML operations via executor permissions checks.
982 | */
983 | static void
984 | log_select_dml(Oid auditOid, List *rangeTabls)
985 | {
986 | ListCell *lr;
987 | bool first = true;
988 | bool found = false;
989 |
990 | /* Do not log if this is an internal statement */
991 | if (internalStatement)
992 | return;
993 |
994 | foreach(lr, rangeTabls)
995 | {
996 | Oid relOid;
997 | Oid relNamespaceOid;
998 | RangeTblEntry *rte = lfirst(lr);
999 |
1000 | /* We only care about tables, and can ignore subqueries etc. */
1001 | if (rte->rtekind != RTE_RELATION)
1002 | continue;
1003 |
1004 | found = true;
1005 |
1006 | /*
1007 | * Don't log if the session user is not a member of the current
1008 | * role. This prevents contents of security definer functions
1009 | * from being logged.
1010 | */
1011 | if (!is_member_of_role(GetSessionUserId(), GetUserId()))
1012 | return;
1013 |
1014 | #if PG_VERSION_NUM >= 120000
1015 | /*
1016 | * Don't log if this is not a true update UPDATE command, e.g. a
1017 | * SELECT FOR UPDATE used for foreign key lookups.
1018 | */
1019 | if (rte->requiredPerms & ACL_UPDATE &&
1020 | rte->rellockmode < RowExclusiveLock)
1021 | continue;
1022 | #endif
1023 |
1024 | /*
1025 | * If we are not logging all-catalog queries (auditLogCatalog is
1026 | * false) then filter out any system relations here.
1027 | */
1028 | relOid = rte->relid;
1029 | relNamespaceOid = get_rel_namespace(relOid);
1030 |
1031 | if (!auditLogCatalog && IsCatalogNamespace(relNamespaceOid))
1032 | continue;
1033 |
1034 | /*
1035 | * Default is that this was not through a grant, to support session
1036 | * logging. Will be updated below if a grant is found.
1037 | */
1038 | auditEventStack->auditEvent.granted = false;
1039 |
1040 | /*
1041 | * If this is the first RTE then session log unless auditLogRelation
1042 | * is set.
1043 | */
1044 | if (first && !auditLogRelation)
1045 | {
1046 | log_audit_event(auditEventStack);
1047 |
1048 | first = false;
1049 | }
1050 |
1051 | /*
1052 | * We don't have access to the parsetree here, so we have to generate
1053 | * the node type, object type, and command tag by decoding
1054 | * rte->requiredPerms and rte->relkind.
1055 | */
1056 | if (rte->requiredPerms & ACL_INSERT)
1057 | {
1058 | auditEventStack->auditEvent.logStmtLevel = LOGSTMT_MOD;
1059 | auditEventStack->auditEvent.commandTag = T_InsertStmt;
1060 | auditEventStack->auditEvent.command = CMDTAG_INSERT;
1061 | }
1062 | else if (rte->requiredPerms & ACL_UPDATE)
1063 | {
1064 | auditEventStack->auditEvent.logStmtLevel = LOGSTMT_MOD;
1065 | auditEventStack->auditEvent.commandTag = T_UpdateStmt;
1066 | auditEventStack->auditEvent.command = CMDTAG_UPDATE;
1067 | }
1068 | else if (rte->requiredPerms & ACL_DELETE)
1069 | {
1070 | auditEventStack->auditEvent.logStmtLevel = LOGSTMT_MOD;
1071 | auditEventStack->auditEvent.commandTag = T_DeleteStmt;
1072 | auditEventStack->auditEvent.command = CMDTAG_DELETE;
1073 | }
1074 | else if (rte->requiredPerms & ACL_SELECT)
1075 | {
1076 | auditEventStack->auditEvent.logStmtLevel = LOGSTMT_ALL;
1077 | auditEventStack->auditEvent.commandTag = T_SelectStmt;
1078 | auditEventStack->auditEvent.command = CMDTAG_SELECT;
1079 | }
1080 | else
1081 | {
1082 | auditEventStack->auditEvent.logStmtLevel = LOGSTMT_ALL;
1083 | auditEventStack->auditEvent.commandTag = T_Invalid;
1084 | auditEventStack->auditEvent.command = CMDTAG_UNKNOWN;
1085 | }
1086 |
1087 | /* Use the relation type to assign object type */
1088 | switch (rte->relkind)
1089 | {
1090 | case RELKIND_RELATION:
1091 | case RELKIND_PARTITIONED_TABLE:
1092 | auditEventStack->auditEvent.objectType = OBJECT_TYPE_TABLE;
1093 | break;
1094 |
1095 | case RELKIND_INDEX:
1096 | #if PG_VERSION_NUM >= 110000
1097 | case RELKIND_PARTITIONED_INDEX:
1098 | #endif
1099 | auditEventStack->auditEvent.objectType = OBJECT_TYPE_INDEX;
1100 | break;
1101 |
1102 | case RELKIND_SEQUENCE:
1103 | auditEventStack->auditEvent.objectType = OBJECT_TYPE_SEQUENCE;
1104 | break;
1105 |
1106 | case RELKIND_TOASTVALUE:
1107 | auditEventStack->auditEvent.objectType = OBJECT_TYPE_TOASTVALUE;
1108 | break;
1109 |
1110 | case RELKIND_VIEW:
1111 | auditEventStack->auditEvent.objectType = OBJECT_TYPE_VIEW;
1112 | break;
1113 |
1114 | case RELKIND_COMPOSITE_TYPE:
1115 | auditEventStack->auditEvent.objectType = OBJECT_TYPE_COMPOSITE_TYPE;
1116 | break;
1117 |
1118 | case RELKIND_FOREIGN_TABLE:
1119 | auditEventStack->auditEvent.objectType = OBJECT_TYPE_FOREIGN_TABLE;
1120 | break;
1121 |
1122 | case RELKIND_MATVIEW:
1123 | auditEventStack->auditEvent.objectType = OBJECT_TYPE_MATVIEW;
1124 | break;
1125 |
1126 | default:
1127 | auditEventStack->auditEvent.objectType = OBJECT_TYPE_UNKNOWN;
1128 | break;
1129 | }
1130 |
1131 | /* Get a copy of the relation name and assign it to object name */
1132 | auditEventStack->auditEvent.objectName =
1133 | quote_qualified_identifier(
1134 | get_namespace_name(relNamespaceOid), get_rel_name(relOid));
1135 |
1136 | /* Perform object auditing only if the audit role is valid */
1137 | if (auditOid != InvalidOid)
1138 | {
1139 | AclMode auditPerms =
1140 | (ACL_SELECT | ACL_UPDATE | ACL_INSERT | ACL_DELETE) &
1141 | rte->requiredPerms;
1142 |
1143 | /*
1144 | * If any of the required permissions for the relation are granted
1145 | * to the audit role then audit the relation
1146 | */
1147 | if (audit_on_relation(relOid, auditOid, auditPerms))
1148 | auditEventStack->auditEvent.granted = true;
1149 |
1150 | /*
1151 | * Else check if the audit role has column-level permissions for
1152 | * select, insert, or update.
1153 | */
1154 | else if (auditPerms != 0)
1155 | {
1156 | /*
1157 | * Check the select columns
1158 | */
1159 | if (auditPerms & ACL_SELECT)
1160 | auditEventStack->auditEvent.granted =
1161 | audit_on_any_attribute(relOid, auditOid,
1162 | rte->selectedCols,
1163 | ACL_SELECT);
1164 |
1165 | /*
1166 | * Check the insert columns
1167 | */
1168 | if (!auditEventStack->auditEvent.granted &&
1169 | auditPerms & ACL_INSERT)
1170 | auditEventStack->auditEvent.granted =
1171 | audit_on_any_attribute(relOid, auditOid,
1172 | rte->insertedCols,
1173 | auditPerms);
1174 |
1175 | /*
1176 | * Check the update columns
1177 | */
1178 | if (!auditEventStack->auditEvent.granted &&
1179 | auditPerms & ACL_UPDATE)
1180 | auditEventStack->auditEvent.granted =
1181 | audit_on_any_attribute(relOid, auditOid,
1182 | rte->updatedCols,
1183 | auditPerms);
1184 | }
1185 | }
1186 |
1187 | /* Do relation level logging if a grant was found */
1188 | if (auditEventStack->auditEvent.granted)
1189 | {
1190 | auditEventStack->auditEvent.logged = false;
1191 | log_audit_event(auditEventStack);
1192 | }
1193 |
1194 | /* Do relation level logging if auditLogRelation is set */
1195 | if (auditLogRelation)
1196 | {
1197 | auditEventStack->auditEvent.logged = false;
1198 | auditEventStack->auditEvent.granted = false;
1199 | log_audit_event(auditEventStack);
1200 | }
1201 |
1202 | pfree(auditEventStack->auditEvent.objectName);
1203 | }
1204 |
1205 | /*
1206 | * If no tables were found that means that RangeTbls was empty or all
1207 | * relations were in the system schema. In that case still log a session
1208 | * record.
1209 | */
1210 | if (!found)
1211 | {
1212 | auditEventStack->auditEvent.granted = false;
1213 | auditEventStack->auditEvent.logged = false;
1214 |
1215 | log_audit_event(auditEventStack);
1216 | }
1217 | }
1218 |
1219 | /*
1220 | * Create AuditEvents for non-catalog function execution, as detected by
1221 | * log_object_access() below.
1222 | */
1223 | static void
1224 | log_function_execute(Oid objectId)
1225 | {
1226 | HeapTuple proctup;
1227 | Form_pg_proc proc;
1228 | AuditEventStackItem *stackItem;
1229 |
1230 | /* Get info about the function. */
1231 | proctup = SearchSysCache1(PROCOID, ObjectIdGetDatum(objectId));
1232 |
1233 | if (!proctup)
1234 | elog(ERROR, "cache lookup failed for function %u", objectId);
1235 |
1236 | proc = (Form_pg_proc) GETSTRUCT(proctup);
1237 |
1238 | /*
1239 | * Logging execution of all pg_catalog functions would make the log
1240 | * unusably noisy.
1241 | */
1242 | if (IsCatalogNamespace(proc->pronamespace))
1243 | {
1244 | ReleaseSysCache(proctup);
1245 | return;
1246 | }
1247 |
1248 | /* Push audit event onto the stack */
1249 | stackItem = stack_push();
1250 |
1251 | /* Generate the fully-qualified function name. */
1252 | stackItem->auditEvent.objectName =
1253 | quote_qualified_identifier(get_namespace_name(proc->pronamespace),
1254 | NameStr(proc->proname));
1255 | ReleaseSysCache(proctup);
1256 |
1257 | /* Log the function call */
1258 | stackItem->auditEvent.logStmtLevel = LOGSTMT_ALL;
1259 | stackItem->auditEvent.commandTag = T_DoStmt;
1260 | stackItem->auditEvent.command = CMDTAG_EXECUTE;
1261 | stackItem->auditEvent.objectType = OBJECT_TYPE_FUNCTION;
1262 | stackItem->auditEvent.commandText = stackItem->next->auditEvent.commandText;
1263 |
1264 | log_audit_event(stackItem);
1265 |
1266 | /* Pop audit event from the stack */
1267 | stack_pop(stackItem->stackId);
1268 | }
1269 |
1270 | /*
1271 | * Hook functions
1272 | */
1273 | static ExecutorCheckPerms_hook_type next_ExecutorCheckPerms_hook = NULL;
1274 | static ProcessUtility_hook_type next_ProcessUtility_hook = NULL;
1275 | static object_access_hook_type next_object_access_hook = NULL;
1276 | static ExecutorStart_hook_type next_ExecutorStart_hook = NULL;
1277 |
1278 | /*
1279 | * Hook ExecutorStart to get the query text and basic command type for queries
1280 | * that do not contain a table and so can't be idenitified accurately in
1281 | * ExecutorCheckPerms.
1282 | */
1283 | static void
1284 | pgaudit_ExecutorStart_hook(QueryDesc *queryDesc, int eflags)
1285 | {
1286 | AuditEventStackItem *stackItem = NULL;
1287 |
1288 | if (!internalStatement)
1289 | {
1290 | /* Push the audit even onto the stack */
1291 | stackItem = stack_push();
1292 |
1293 | /* Initialize command using queryDesc->operation */
1294 | switch (queryDesc->operation)
1295 | {
1296 | case CMD_SELECT:
1297 | stackItem->auditEvent.logStmtLevel = LOGSTMT_ALL;
1298 | stackItem->auditEvent.commandTag = T_SelectStmt;
1299 | stackItem->auditEvent.command = CMDTAG_SELECT;
1300 | break;
1301 |
1302 | case CMD_INSERT:
1303 | stackItem->auditEvent.logStmtLevel = LOGSTMT_MOD;
1304 | stackItem->auditEvent.commandTag = T_InsertStmt;
1305 | stackItem->auditEvent.command = CMDTAG_INSERT;
1306 | break;
1307 |
1308 | case CMD_UPDATE:
1309 | stackItem->auditEvent.logStmtLevel = LOGSTMT_MOD;
1310 | stackItem->auditEvent.commandTag = T_UpdateStmt;
1311 | stackItem->auditEvent.command = CMDTAG_UPDATE;
1312 | break;
1313 |
1314 | case CMD_DELETE:
1315 | stackItem->auditEvent.logStmtLevel = LOGSTMT_MOD;
1316 | stackItem->auditEvent.commandTag = T_DeleteStmt;
1317 | stackItem->auditEvent.command = CMDTAG_DELETE;
1318 | break;
1319 |
1320 | default:
1321 | stackItem->auditEvent.logStmtLevel = LOGSTMT_ALL;
1322 | stackItem->auditEvent.commandTag = T_Invalid;
1323 | stackItem->auditEvent.command = CMDTAG_UNKNOWN;
1324 | break;
1325 | }
1326 |
1327 | /* Initialize the audit event */
1328 | stackItem->auditEvent.commandText = queryDesc->sourceText;
1329 | stackItem->auditEvent.paramList = copyParamList(queryDesc->params);
1330 | }
1331 |
1332 | /* Call the previous hook or standard function */
1333 | if (next_ExecutorStart_hook)
1334 | next_ExecutorStart_hook(queryDesc, eflags);
1335 | else
1336 | standard_ExecutorStart(queryDesc, eflags);
1337 |
1338 | /*
1339 | * Move the stack memory context to the query memory context. This needs
1340 | * to be done here because the query context does not exist before the
1341 | * call to standard_ExecutorStart() but the stack item is required by
1342 | * pgaudit_ExecutorCheckPerms_hook() which is called during
1343 | * standard_ExecutorStart().
1344 | */
1345 | if (stackItem)
1346 | MemoryContextSetParent(stackItem->contextAudit,
1347 | queryDesc->estate->es_query_cxt);
1348 | }
1349 |
1350 | /*
1351 | * Hook ExecutorCheckPerms to do session and object auditing for DML.
1352 | */
1353 | static bool
1354 | pgaudit_ExecutorCheckPerms_hook(List *rangeTabls, bool abort)
1355 | {
1356 | Oid auditOid;
1357 |
1358 | /* Get the audit oid if the role exists */
1359 | auditOid = get_role_oid(auditRole, true);
1360 |
1361 | /* Log DML if the audit role is valid or session logging is enabled */
1362 | if ((auditOid != InvalidOid || auditLogBitmap != 0) &&
1363 | !IsAbortedTransactionBlockState())
1364 | log_select_dml(auditOid, rangeTabls);
1365 |
1366 | /* Call the next hook function */
1367 | if (next_ExecutorCheckPerms_hook &&
1368 | !(*next_ExecutorCheckPerms_hook) (rangeTabls, abort))
1369 | return false;
1370 |
1371 | return true;
1372 | }
1373 |
1374 | /*
1375 | * Hook ProcessUtility to do session auditing for DDL and utility commands.
1376 | */
1377 | static void
1378 | pgaudit_ProcessUtility_hook(PlannedStmt *pstmt,
1379 | const char *queryString,
1380 | ProcessUtilityContext context,
1381 | ParamListInfo params,
1382 | QueryEnvironment *queryEnv,
1383 | DestReceiver *dest,
1384 | QueryCompletion *qc)
1385 | {
1386 | AuditEventStackItem *stackItem = NULL;
1387 | int64 stackId = 0;
1388 |
1389 | /*
1390 | * Don't audit substatements. All the substatements we care about should
1391 | * be covered by the event triggers.
1392 | */
1393 | if (context <= PROCESS_UTILITY_QUERY && !IsAbortedTransactionBlockState())
1394 | {
1395 | /* Process top level utility statement */
1396 | if (context == PROCESS_UTILITY_TOPLEVEL)
1397 | {
1398 | /*
1399 | * If the stack is not empty then the only allowed entries are open
1400 | * select, show, and explain cursors
1401 | */
1402 | if (auditEventStack != NULL)
1403 | {
1404 | AuditEventStackItem *nextItem = auditEventStack;
1405 |
1406 | do
1407 | {
1408 | if (nextItem->auditEvent.commandTag != T_SelectStmt &&
1409 | nextItem->auditEvent.commandTag != T_VariableShowStmt &&
1410 | nextItem->auditEvent.commandTag != T_ExplainStmt)
1411 | {
1412 | elog(ERROR, "pgaudit stack is not empty");
1413 | }
1414 |
1415 | nextItem = nextItem->next;
1416 | }
1417 | while (nextItem != NULL);
1418 | }
1419 |
1420 | stackItem = stack_push();
1421 | stackItem->auditEvent.paramList = copyParamList(params);
1422 | }
1423 | else
1424 | stackItem = stack_push();
1425 |
1426 | stackId = stackItem->stackId;
1427 | stackItem->auditEvent.logStmtLevel = GetCommandLogLevel(pstmt->utilityStmt);
1428 | stackItem->auditEvent.commandTag = nodeTag(pstmt->utilityStmt);
1429 | stackItem->auditEvent.command = CreateCommandTag(pstmt->utilityStmt);
1430 | stackItem->auditEvent.commandText = queryString;
1431 |
1432 | /*
1433 | * If this is a DO block log it before calling the next ProcessUtility
1434 | * hook.
1435 | */
1436 | if (auditLogBitmap & LOG_FUNCTION &&
1437 | stackItem->auditEvent.commandTag == T_DoStmt &&
1438 | !IsAbortedTransactionBlockState())
1439 | log_audit_event(stackItem);
1440 |
1441 | /*
1442 | * A close will free the open cursor which will also free the close
1443 | * audit entry. Immediately log the close and set stackItem to NULL so
1444 | * it won't be logged later.
1445 | */
1446 | if (stackItem->auditEvent.commandTag == T_ClosePortalStmt)
1447 | {
1448 | if (auditLogBitmap & LOG_MISC && !IsAbortedTransactionBlockState())
1449 | log_audit_event(stackItem);
1450 |
1451 | stackItem = NULL;
1452 | }
1453 | }
1454 |
1455 | /* Call the standard process utility chain. */
1456 | if (next_ProcessUtility_hook)
1457 | (*next_ProcessUtility_hook) (pstmt, queryString, context, params,
1458 | queryEnv, dest, qc);
1459 | else
1460 | standard_ProcessUtility(pstmt, queryString, context, params,
1461 | queryEnv, dest, qc);
1462 |
1463 | /*
1464 | * Process the audit event if there is one. Also check that this event
1465 | * was not popped off the stack by a memory context being free'd
1466 | * elsewhere.
1467 | */
1468 | if (stackItem && !IsAbortedTransactionBlockState())
1469 | {
1470 | /*
1471 | * Make sure the item we want to log is still on the stack - if not
1472 | * then something has gone wrong and an error will be raised.
1473 | */
1474 | stack_valid(stackId);
1475 |
1476 | /*
1477 | * Log the utility command if logging is on, the command has not
1478 | * already been logged by another hook, and the transaction is not
1479 | * aborted.
1480 | */
1481 | if (auditLogBitmap != 0 && !stackItem->auditEvent.logged)
1482 | log_audit_event(stackItem);
1483 | }
1484 | }
1485 |
1486 | /*
1487 | * Hook object_access_hook to provide fully-qualified object names for function
1488 | * calls.
1489 | */
1490 | static void
1491 | pgaudit_object_access_hook(ObjectAccessType access,
1492 | Oid classId,
1493 | Oid objectId,
1494 | int subId,
1495 | void *arg)
1496 | {
1497 | if (auditLogBitmap & LOG_FUNCTION && access == OAT_FUNCTION_EXECUTE &&
1498 | auditEventStack && !IsAbortedTransactionBlockState())
1499 | log_function_execute(objectId);
1500 |
1501 | if (next_object_access_hook)
1502 | (*next_object_access_hook) (access, classId, objectId, subId, arg);
1503 | }
1504 |
1505 | /*
1506 | * Event trigger functions
1507 | */
1508 |
1509 | /*
1510 | * Supply additional data for (non drop) statements that have event trigger
1511 | * support and can be deparsed.
1512 | *
1513 | * Drop statements are handled below through the older sql_drop event trigger.
1514 | */
1515 | Datum
1516 | pgaudit_ddl_command_end(PG_FUNCTION_ARGS)
1517 | {
1518 | EventTriggerData *eventData;
1519 | int result,
1520 | row;
1521 | TupleDesc spiTupDesc;
1522 | const char *query;
1523 | MemoryContext contextQuery;
1524 | MemoryContext contextOld;
1525 |
1526 | /* Continue only if session DDL logging is enabled */
1527 | if (~auditLogBitmap & LOG_DDL && ~auditLogBitmap & LOG_ROLE)
1528 | PG_RETURN_NULL();
1529 |
1530 | /* Be sure the module was loaded */
1531 | if (!auditEventStack)
1532 | elog(ERROR, "pgaudit not loaded before call to "
1533 | "pgaudit_ddl_command_end()");
1534 |
1535 | /* This is an internal statement - do not log it */
1536 | internalStatement = true;
1537 |
1538 | /* Make sure the fuction was fired as a trigger */
1539 | if (!CALLED_AS_EVENT_TRIGGER(fcinfo))
1540 | elog(ERROR, "not fired by event trigger manager");
1541 |
1542 | /* Switch memory context for query */
1543 | contextQuery = AllocSetContextCreate(
1544 | CurrentMemoryContext,
1545 | "pgaudit_func_ddl_command_end temporary context",
1546 | ALLOCSET_DEFAULT_SIZES);
1547 | contextOld = MemoryContextSwitchTo(contextQuery);
1548 |
1549 | /* Get information about triggered events */
1550 | eventData = (EventTriggerData *) fcinfo->context;
1551 |
1552 | auditEventStack->auditEvent.logStmtLevel =
1553 | GetCommandLogLevel(eventData->parsetree);
1554 | auditEventStack->auditEvent.commandTag =
1555 | nodeTag(eventData->parsetree);
1556 | auditEventStack->auditEvent.command =
1557 | CreateCommandTag(eventData->parsetree);
1558 |
1559 | /* Return objects affected by the (non drop) DDL statement */
1560 | query = "SELECT UPPER(object_type), object_identity, UPPER(command_tag)\n"
1561 | " FROM pg_catalog.pg_event_trigger_ddl_commands()";
1562 |
1563 | /* Attempt to connect */
1564 | result = SPI_connect();
1565 | if (result < 0)
1566 | elog(ERROR, "pgaudit_ddl_command_end: SPI_connect returned %d",
1567 | result);
1568 |
1569 | /* Execute the query */
1570 | result = SPI_execute(query, true, 0);
1571 | if (result != SPI_OK_SELECT)
1572 | elog(ERROR, "pgaudit_ddl_command_end: SPI_execute returned %d",
1573 | result);
1574 |
1575 | /* Iterate returned rows */
1576 | spiTupDesc = SPI_tuptable->tupdesc;
1577 | for (row = 0; row < SPI_processed; row++)
1578 | {
1579 | HeapTuple spiTuple;
1580 |
1581 | spiTuple = SPI_tuptable->vals[row];
1582 |
1583 | /* Supply object name and type for audit event */
1584 | auditEventStack->auditEvent.objectType =
1585 | SPI_getvalue(spiTuple, spiTupDesc, 1);
1586 | auditEventStack->auditEvent.objectName =
1587 | SPI_getvalue(spiTuple, spiTupDesc, 2);
1588 | auditEventStack->auditEvent.command =
1589 | GetCommandTagEnum(SPI_getvalue(spiTuple, spiTupDesc, 3));
1590 |
1591 | auditEventStack->auditEvent.logged = false;
1592 |
1593 | /*
1594 | * Identify grant/revoke commands - these are the only non-DDL class
1595 | * commands that should be coming through the event triggers.
1596 | */
1597 | #if PG_VERSION_NUM >= 130000
1598 | if (auditEventStack->auditEvent.command == CMDTAG_GRANT ||
1599 | auditEventStack->auditEvent.command == CMDTAG_REVOKE)
1600 | #else
1601 | if (pg_strcasecmp(auditEventStack->auditEvent.command, CMDTAG_GRANT) == 0 ||
1602 | pg_strcasecmp(auditEventStack->auditEvent.command, CMDTAG_REVOKE) == 0)
1603 | #endif
1604 | {
1605 | NodeTag currentCommandTag = auditEventStack->auditEvent.commandTag;
1606 |
1607 | auditEventStack->auditEvent.commandTag = T_GrantStmt;
1608 | log_audit_event(auditEventStack);
1609 |
1610 | auditEventStack->auditEvent.commandTag = currentCommandTag;
1611 | }
1612 | else
1613 | log_audit_event(auditEventStack);
1614 | }
1615 |
1616 | /* Complete the query */
1617 | SPI_finish();
1618 |
1619 | MemoryContextSwitchTo(contextOld);
1620 | MemoryContextDelete(contextQuery);
1621 |
1622 | /* No longer in an internal statement */
1623 | internalStatement = false;
1624 |
1625 | PG_RETURN_NULL();
1626 | }
1627 |
1628 | /*
1629 | * Supply additional data for drop statements that have event trigger support.
1630 | */
1631 | Datum
1632 | pgaudit_sql_drop(PG_FUNCTION_ARGS)
1633 | {
1634 | int result,
1635 | row;
1636 | TupleDesc spiTupDesc;
1637 | const char *query;
1638 | MemoryContext contextQuery;
1639 | MemoryContext contextOld;
1640 |
1641 | if (~auditLogBitmap & LOG_DDL)
1642 | PG_RETURN_NULL();
1643 |
1644 | /* Be sure the module was loaded */
1645 | if (!auditEventStack)
1646 | elog(ERROR, "pgaudit not loaded before call to "
1647 | "pgaudit_sql_drop()");
1648 |
1649 | /* This is an internal statement - do not log it */
1650 | internalStatement = true;
1651 |
1652 | /* Make sure the fuction was fired as a trigger */
1653 | if (!CALLED_AS_EVENT_TRIGGER(fcinfo))
1654 | elog(ERROR, "not fired by event trigger manager");
1655 |
1656 | /* Switch memory context for the query */
1657 | contextQuery = AllocSetContextCreate(
1658 | CurrentMemoryContext,
1659 | "pgaudit_func_ddl_command_end temporary context",
1660 | ALLOCSET_DEFAULT_SIZES);
1661 | contextOld = MemoryContextSwitchTo(contextQuery);
1662 |
1663 | /* Return objects affected by the drop statement */
1664 | query = "SELECT UPPER(object_type),\n"
1665 | " object_identity\n"
1666 | " FROM pg_catalog.pg_event_trigger_dropped_objects()\n"
1667 | " WHERE lower(object_type) <> 'type'\n"
1668 | " AND schema_name <> 'pg_toast'";
1669 |
1670 | /* Attempt to connect */
1671 | result = SPI_connect();
1672 | if (result < 0)
1673 | elog(ERROR, "pgaudit_ddl_drop: SPI_connect returned %d",
1674 | result);
1675 |
1676 | /* Execute the query */
1677 | result = SPI_execute(query, true, 0);
1678 | if (result != SPI_OK_SELECT)
1679 | elog(ERROR, "pgaudit_ddl_drop: SPI_execute returned %d",
1680 | result);
1681 |
1682 | /* Iterate returned rows */
1683 | spiTupDesc = SPI_tuptable->tupdesc;
1684 | for (row = 0; row < SPI_processed; row++)
1685 | {
1686 | HeapTuple spiTuple;
1687 |
1688 | spiTuple = SPI_tuptable->vals[row];
1689 |
1690 | auditEventStack->auditEvent.objectType =
1691 | SPI_getvalue(spiTuple, spiTupDesc, 1);
1692 | auditEventStack->auditEvent.objectName =
1693 | SPI_getvalue(spiTuple, spiTupDesc, 2);
1694 |
1695 | auditEventStack->auditEvent.logged = false;
1696 | log_audit_event(auditEventStack);
1697 | }
1698 |
1699 | /* Complete the query */
1700 | SPI_finish();
1701 |
1702 | MemoryContextSwitchTo(contextOld);
1703 | MemoryContextDelete(contextQuery);
1704 |
1705 | /* No longer in an internal statement */
1706 | internalStatement = false;
1707 |
1708 | PG_RETURN_NULL();
1709 | }
1710 |
1711 | /*
1712 | * GUC check and assign functions
1713 | */
1714 |
1715 | /*
1716 | * Take a pgaudit.log value such as "read, write, dml", verify that each of the
1717 | * comma-separated tokens corresponds to a LogClass value, and convert them into
1718 | * a bitmap that log_audit_event can check.
1719 | */
1720 | static bool
1721 | check_pgaudit_log(char **newVal, void **extra, GucSource source)
1722 | {
1723 | List *flagRawList;
1724 | char *rawVal;
1725 | ListCell *lt;
1726 | int *flags;
1727 |
1728 | /* Make sure newval is a comma-separated list of tokens. */
1729 | rawVal = pstrdup(*newVal);
1730 | if (!SplitIdentifierString(rawVal, ',', &flagRawList))
1731 | {
1732 | GUC_check_errdetail("List syntax is invalid");
1733 | list_free(flagRawList);
1734 | pfree(rawVal);
1735 | return false;
1736 | }
1737 |
1738 | /*
1739 | * Check that we recognise each token, and add it to the bitmap we're
1740 | * building up in a newly-allocated int *f.
1741 | */
1742 | if (!(flags = (int *) malloc(sizeof(int))))
1743 | return false;
1744 |
1745 | *flags = 0;
1746 |
1747 | foreach(lt, flagRawList)
1748 | {
1749 | char *token = (char *) lfirst(lt);
1750 | bool subtract = false;
1751 | int class;
1752 |
1753 | /* If token is preceded by -, then the token is subtractive */
1754 | if (token[0] == '-')
1755 | {
1756 | token++;
1757 | subtract = true;
1758 | }
1759 |
1760 | /* Test each token */
1761 | if (pg_strcasecmp(token, CLASS_NONE) == 0)
1762 | class = LOG_NONE;
1763 | else if (pg_strcasecmp(token, CLASS_ALL) == 0)
1764 | class = LOG_ALL;
1765 | else if (pg_strcasecmp(token, CLASS_DDL) == 0)
1766 | class = LOG_DDL;
1767 | else if (pg_strcasecmp(token, CLASS_FUNCTION) == 0)
1768 | class = LOG_FUNCTION;
1769 | else if (pg_strcasecmp(token, CLASS_MISC) == 0)
1770 | class = LOG_MISC | LOG_MISC_SET;
1771 | else if (pg_strcasecmp(token, CLASS_MISC_SET) == 0)
1772 | class = LOG_MISC_SET;
1773 | else if (pg_strcasecmp(token, CLASS_READ) == 0)
1774 | class = LOG_READ;
1775 | else if (pg_strcasecmp(token, CLASS_ROLE) == 0)
1776 | class = LOG_ROLE;
1777 | else if (pg_strcasecmp(token, CLASS_WRITE) == 0)
1778 | class = LOG_WRITE;
1779 | else
1780 | {
1781 | free(flags);
1782 | pfree(rawVal);
1783 | list_free(flagRawList);
1784 | return false;
1785 | }
1786 |
1787 | /* Add or subtract class bits from the log bitmap */
1788 | if (subtract)
1789 | *flags &= ~class;
1790 | else
1791 | *flags |= class;
1792 | }
1793 |
1794 | pfree(rawVal);
1795 | list_free(flagRawList);
1796 |
1797 | /* Store the bitmap for assign_pgaudit_log */
1798 | *extra = flags;
1799 |
1800 | return true;
1801 | }
1802 |
1803 | /*
1804 | * Set pgaudit_log from extra (ignoring newVal, which has already been
1805 | * converted to a bitmap above). Note that extra may not be set if the
1806 | * assignment is to be suppressed.
1807 | */
1808 | static void
1809 | assign_pgaudit_log(const char *newVal, void *extra)
1810 | {
1811 | if (extra)
1812 | auditLogBitmap = *(int *) extra;
1813 | }
1814 |
1815 | /*
1816 | * Take a pgaudit.log_level value such as "debug" and check that is is valid.
1817 | * Return the enum value so it does not have to be checked again in the assign
1818 | * function.
1819 | */
1820 | static bool
1821 | check_pgaudit_log_level(char **newVal, void **extra, GucSource source)
1822 | {
1823 | int *logLevel;
1824 |
1825 | /* Allocate memory to store the log level */
1826 | if (!(logLevel = (int *) malloc(sizeof(int))))
1827 | return false;
1828 |
1829 | /* Find the log level enum */
1830 | if (pg_strcasecmp(*newVal, "debug") == 0)
1831 | *logLevel = DEBUG2;
1832 | else if (pg_strcasecmp(*newVal, "debug5") == 0)
1833 | *logLevel = DEBUG5;
1834 | else if (pg_strcasecmp(*newVal, "debug4") == 0)
1835 | *logLevel = DEBUG4;
1836 | else if (pg_strcasecmp(*newVal, "debug3") == 0)
1837 | *logLevel = DEBUG3;
1838 | else if (pg_strcasecmp(*newVal, "debug2") == 0)
1839 | *logLevel = DEBUG2;
1840 | else if (pg_strcasecmp(*newVal, "debug1") == 0)
1841 | *logLevel = DEBUG1;
1842 | else if (pg_strcasecmp(*newVal, "info") == 0)
1843 | *logLevel = INFO;
1844 | else if (pg_strcasecmp(*newVal, "notice") == 0)
1845 | *logLevel = NOTICE;
1846 | else if (pg_strcasecmp(*newVal, "warning") == 0)
1847 | *logLevel = WARNING;
1848 | else if (pg_strcasecmp(*newVal, "log") == 0)
1849 | *logLevel = LOG;
1850 |
1851 | /* Error if the log level enum is not found */
1852 | else
1853 | {
1854 | free(logLevel);
1855 | return false;
1856 | }
1857 |
1858 | /* Return the log level enum */
1859 | *extra = logLevel;
1860 |
1861 | return true;
1862 | }
1863 |
1864 | /*
1865 | * Set pgaudit_log from extra (ignoring newVal, which has already been
1866 | * converted to an enum above). Note that extra may not be set if the
1867 | * assignment is to be suppressed.
1868 | */
1869 | static void
1870 | assign_pgaudit_log_level(const char *newVal, void *extra)
1871 | {
1872 | if (extra)
1873 | auditLogLevel = *(int *) extra;
1874 | }
1875 |
1876 | /*
1877 | * Define GUC variables and install hooks upon module load.
1878 | */
1879 | void
1880 | _PG_init(void)
1881 | {
1882 | /* Be sure we do initialization only once */
1883 | static bool inited = false;
1884 |
1885 | if (inited)
1886 | return;
1887 |
1888 | /* Must be loaded with shared_preload_libraries */
1889 | if (!process_shared_preload_libraries_in_progress)
1890 | ereport(ERROR, (errcode(ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE),
1891 | errmsg("pgaudit must be loaded via shared_preload_libraries")));
1892 |
1893 | /* Define pgaudit.log */
1894 | DefineCustomStringVariable(
1895 | "pgaudit.log",
1896 |
1897 | "Specifies which classes of statements will be logged by session audit "
1898 | "logging. Multiple classes can be provided using a comma-separated "
1899 | "list and classes can be subtracted by prefacing the class with a "
1900 | "- sign.",
1901 |
1902 | NULL,
1903 | &auditLog,
1904 | "none",
1905 | PGC_SUSET,
1906 | GUC_LIST_INPUT | GUC_NOT_IN_SAMPLE,
1907 | check_pgaudit_log,
1908 | assign_pgaudit_log,
1909 | NULL);
1910 |
1911 | /* Define pgaudit.log_catalog */
1912 | DefineCustomBoolVariable(
1913 | "pgaudit.log_catalog",
1914 |
1915 | "Specifies that session logging should be enabled in the case where "
1916 | "all relations in a statement are in pg_catalog. Disabling this "
1917 | "setting will reduce noise in the log from tools like psql and PgAdmin "
1918 | "that query the catalog heavily.",
1919 |
1920 | NULL,
1921 | &auditLogCatalog,
1922 | true,
1923 | PGC_SUSET,
1924 | GUC_NOT_IN_SAMPLE,
1925 | NULL, NULL, NULL);
1926 |
1927 | /* Define pgaudit.log_client */
1928 | DefineCustomBoolVariable(
1929 | "pgaudit.log_client",
1930 |
1931 | "Specifies whether audit messages should be visible to the client. "
1932 | "This setting should generally be left disabled but may be useful for "
1933 | "debugging or other purposes.",
1934 |
1935 | NULL,
1936 | &auditLogClient,
1937 | false,
1938 | PGC_SUSET,
1939 | GUC_NOT_IN_SAMPLE,
1940 | NULL, NULL, NULL);
1941 |
1942 | /* Define pgaudit.log_level */
1943 | DefineCustomStringVariable(
1944 | "pgaudit.log_level",
1945 |
1946 | "Specifies the log level that will be used for log entries. This "
1947 | "setting is used for regression testing and may also be useful to end "
1948 | "users for testing or other purposes. It is not intended to be used "
1949 | "in a production environment as it may leak which statements are being "
1950 | "logged to the user.",
1951 |
1952 | NULL,
1953 | &auditLogLevelString,
1954 | "log",
1955 | PGC_SUSET,
1956 | GUC_LIST_INPUT | GUC_NOT_IN_SAMPLE,
1957 | check_pgaudit_log_level,
1958 | assign_pgaudit_log_level,
1959 | NULL);
1960 |
1961 | /* Define pgaudit.log_parameter */
1962 | DefineCustomBoolVariable(
1963 | "pgaudit.log_parameter",
1964 |
1965 | "Specifies that audit logging should include the parameters that were "
1966 | "passed with the statement. When parameters are present they will be "
1967 | "be included in CSV format after the statement text.",
1968 |
1969 | NULL,
1970 | &auditLogParameter,
1971 | false,
1972 | PGC_SUSET,
1973 | GUC_NOT_IN_SAMPLE,
1974 | NULL, NULL, NULL);
1975 |
1976 | /* Define pgaudit.log_relation */
1977 | DefineCustomBoolVariable(
1978 | "pgaudit.log_relation",
1979 |
1980 | "Specifies whether session audit logging should create a separate log "
1981 | "entry for each relation referenced in a SELECT or DML statement. "
1982 | "This is a useful shortcut for exhaustive logging without using object "
1983 | "audit logging.",
1984 |
1985 | NULL,
1986 | &auditLogRelation,
1987 | false,
1988 | PGC_SUSET,
1989 | GUC_NOT_IN_SAMPLE,
1990 | NULL, NULL, NULL);
1991 |
1992 | /* Define pgaudit.log_statement */
1993 | DefineCustomBoolVariable(
1994 | "pgaudit.log_statement",
1995 |
1996 | "Specifies whether logging will include the statement text and "
1997 | "parameters. Depending on requirements, the full statement text might "
1998 | "not be required in the audit log.",
1999 |
2000 | NULL,
2001 | &auditLogStatement,
2002 | true,
2003 | PGC_SUSET,
2004 | GUC_NOT_IN_SAMPLE,
2005 | NULL, NULL, NULL);
2006 |
2007 | /* Define pgaudit.log_statement_once */
2008 | DefineCustomBoolVariable(
2009 | "pgaudit.log_statement_once",
2010 |
2011 | "Specifies whether logging will include the statement text and "
2012 | "parameters with the first log entry for a statement/substatement "
2013 | "combination or with every entry. Disabling this setting will result "
2014 | "in less verbose logging but may make it more difficult to determine "
2015 | "the statement that generated a log entry, though the "
2016 | "statement/substatement pair along with the process id should suffice "
2017 | "to identify the statement text logged with a previous entry.",
2018 |
2019 | NULL,
2020 | &auditLogStatementOnce,
2021 | false,
2022 | PGC_SUSET,
2023 | GUC_NOT_IN_SAMPLE,
2024 | NULL, NULL, NULL);
2025 |
2026 | /* Define pgaudit.role */
2027 | DefineCustomStringVariable(
2028 | "pgaudit.role",
2029 |
2030 | "Specifies the master role to use for object audit logging. Muliple "
2031 | "audit roles can be defined by granting them to the master role. This "
2032 | "allows multiple groups to be in charge of different aspects of audit "
2033 | "logging.",
2034 |
2035 | NULL,
2036 | &auditRole,
2037 | "",
2038 | PGC_SUSET,
2039 | GUC_NOT_IN_SAMPLE,
2040 | NULL, NULL, NULL);
2041 |
2042 | /*
2043 | * Install our hook functions after saving the existing pointers to
2044 | * preserve the chains.
2045 | */
2046 | next_ExecutorStart_hook = ExecutorStart_hook;
2047 | ExecutorStart_hook = pgaudit_ExecutorStart_hook;
2048 |
2049 | next_ExecutorCheckPerms_hook = ExecutorCheckPerms_hook;
2050 | ExecutorCheckPerms_hook = pgaudit_ExecutorCheckPerms_hook;
2051 |
2052 | next_ProcessUtility_hook = ProcessUtility_hook;
2053 | ProcessUtility_hook = pgaudit_ProcessUtility_hook;
2054 |
2055 | next_object_access_hook = object_access_hook;
2056 | object_access_hook = pgaudit_object_access_hook;
2057 |
2058 | /* Log that the extension has completed initialization */
2059 | #ifndef EXEC_BACKEND
2060 | ereport(LOG, (errmsg("pgaudit extension initialized")));
2061 | #else
2062 | ereport(DEBUG1, (errmsg("pgaudit extension initialized")));
2063 | #endif /* EXEC_BACKEND */
2064 |
2065 | inited = true;
2066 | }
2067 |
--------------------------------------------------------------------------------
/pgaudit.conf:
--------------------------------------------------------------------------------
1 | shared_preload_libraries = pgaudit
2 |
--------------------------------------------------------------------------------
/pgaudit.control:
--------------------------------------------------------------------------------
1 | # pgaudit extension
2 | comment = 'provides auditing functionality'
3 | default_version = '1.5.50.1'
4 | module_pathname = '$libdir/pgaudit'
5 | relocatable = true
6 |
--------------------------------------------------------------------------------
/sql/pgaudit.sql:
--------------------------------------------------------------------------------
1 | \set VERBOSITY terse
2 |
3 | -- Create pgaudit extension
4 | CREATE EXTENSION IF NOT EXISTS pgaudit;
5 |
6 | -- Make sure events don't get logged twice when session logging
7 | SET pgaudit.log = 'all';
8 | SET pgaudit.log_client = ON;
9 | SET pgaudit.log_level = 'notice';
10 |
11 | CREATE TABLE tmp (id int, data text);
12 | CREATE TABLE tmp2 AS (SELECT * FROM tmp);
13 |
14 | -- Reset log_client first to show that audits logs are not set to client
15 | RESET pgaudit.log_client;
16 |
17 | DROP TABLE tmp;
18 | DROP TABLE tmp2;
19 |
20 | RESET pgaudit.log;
21 | RESET pgaudit.log_level;
22 |
23 | --
24 | -- Audit log fields are:
25 | -- AUDIT_TYPE - SESSION or OBJECT
26 | -- STATEMENT_ID - ID of the statement in the current backend
27 | -- SUBSTATEMENT_ID - ID of the substatement in the current backend
28 | -- CLASS - Class of statement being logged (e.g. ROLE, READ, WRITE)
29 | -- COMMAND - e.g. SELECT, CREATE ROLE, UPDATE
30 | -- OBJECT_TYPE - When available, type of object acted on (e.g. TABLE, VIEW)
31 | -- OBJECT_NAME - When available, fully-qualified table of object
32 | -- STATEMENT - The statement being logged
33 | -- PARAMETER - If parameter logging is requested, they will follow the
34 | -- statement
35 |
36 | SELECT current_user \gset
37 |
38 | --
39 | -- Set pgaudit parameters for the current (super)user.
40 | ALTER ROLE :current_user SET pgaudit.log = 'Role';
41 | ALTER ROLE :current_user SET pgaudit.log_level = 'notice';
42 | ALTER ROLE :current_user SET pgaudit.log_client = ON;
43 |
44 | \connect - :current_user;
45 |
46 | --
47 | -- Create auditor role
48 | CREATE ROLE auditor;
49 |
50 | --
51 | -- Create first test user
52 | CREATE USER user1 password 'password';
53 | ALTER ROLE user1 SET pgaudit.log = 'ddl, ROLE';
54 | ALTER ROLE user1 SET pgaudit.log_level = 'notice';
55 |
56 | ALTER ROLE user1 PassWord 'password2' NOLOGIN;
57 | ALTER USER user1 encrypted /* random comment */PASSWORD
58 | /* random comment */
59 | 'md565cb1da342495ea6bb0418a6e5718c38' LOGIN;
60 | ALTER ROLE user1 SET pgaudit.log_client = ON;
61 |
62 | --
63 | -- Create, select, drop (select will not be audited)
64 | \connect - user1
65 |
66 | CREATE TABLE public.test
67 | (
68 | id INT
69 | );
70 |
71 | SELECT *
72 | FROM test;
73 |
74 | DROP TABLE test;
75 |
76 | --
77 | -- Create second test user
78 | \connect - :current_user
79 |
80 | CREATE ROLE user2 LOGIN password 'password';
81 | ALTER ROLE user2 SET pgaudit.log = 'Read, writE';
82 | ALTER ROLE user2 SET pgaudit.log_catalog = OFF;
83 | ALTER ROLE user2 SET pgaudit.log_client = ON;
84 | ALTER ROLE user2 SET pgaudit.log_level = 'warning';
85 | ALTER ROLE user2 SET pgaudit.role = auditor;
86 | ALTER ROLE user2 SET pgaudit.log_statement_once = ON;
87 |
88 | --
89 | -- Setup role-based tests
90 | CREATE TABLE test2
91 | (
92 | id INT
93 | );
94 |
95 | GRANT SELECT, INSERT, UPDATE, DELETE
96 | ON test2
97 | TO user2, user1;
98 |
99 | GRANT SELECT, UPDATE
100 | ON TABLE public.test2
101 | TO auditor;
102 |
103 | CREATE TABLE test3
104 | (
105 | id INT
106 | );
107 |
108 | GRANT SELECT, INSERT, UPDATE, DELETE
109 | ON test3
110 | TO user2;
111 |
112 | GRANT INSERT
113 | ON TABLE public.test3
114 | TO auditor;
115 |
116 | CREATE FUNCTION test2_insert() RETURNS TRIGGER AS $$
117 | BEGIN
118 | UPDATE test2
119 | SET id = id + 90
120 | WHERE id = new.id;
121 |
122 | RETURN new;
123 | END $$ LANGUAGE plpgsql security definer;
124 | ALTER FUNCTION test2_insert() OWNER TO user1;
125 |
126 | CREATE TRIGGER test2_insert_trg
127 | AFTER INSERT ON test2
128 | FOR EACH ROW EXECUTE PROCEDURE test2_insert();
129 |
130 | CREATE FUNCTION test2_change(change_id int) RETURNS void AS $$
131 | BEGIN
132 | UPDATE test2
133 | SET id = id + 1
134 | WHERE id = change_id;
135 | END $$ LANGUAGE plpgsql security definer;
136 | ALTER FUNCTION test2_change(int) OWNER TO user2;
137 |
138 | CREATE VIEW vw_test3 AS
139 | SELECT *
140 | FROM test3;
141 |
142 | GRANT SELECT
143 | ON vw_test3
144 | TO user2;
145 |
146 | GRANT SELECT
147 | ON vw_test3
148 | TO auditor;
149 |
150 | \connect - user2
151 |
152 | --
153 | -- Role-based tests
154 | SELECT count(*)
155 | FROM
156 | (
157 | SELECT relname
158 | FROM pg_class
159 | LIMIT 1
160 | ) SUBQUERY;
161 |
162 | SELECT *
163 | FROM test3, test2;
164 |
165 | --
166 | -- Object logged because of:
167 | -- select on vw_test3
168 | -- select on test2
169 | SELECT *
170 | FROM vw_test3, test2;
171 |
172 | --
173 | -- Object logged because of:
174 | -- insert on test3
175 | -- select on test2
176 | WITH CTE AS
177 | (
178 | SELECT id
179 | FROM test2
180 | )
181 | INSERT INTO test3
182 | SELECT id
183 | FROM cte;
184 |
185 | --
186 | -- Object logged because of:
187 | -- insert on test3
188 | WITH CTE AS
189 | (
190 | INSERT INTO test3 VALUES (1)
191 | RETURNING id
192 | )
193 | INSERT INTO test2
194 | SELECT id
195 | FROM cte;
196 |
197 | DO $$ BEGIN PERFORM test2_change(91); END $$;
198 |
199 | --
200 | -- Object logged because of:
201 | -- insert on test3
202 | -- update on test2
203 | WITH CTE AS
204 | (
205 | UPDATE test2
206 | SET id = 45
207 | WHERE id = 92
208 | RETURNING id
209 | )
210 | INSERT INTO test3
211 | SELECT id
212 | FROM cte;
213 |
214 | --
215 | -- Object logged because of:
216 | -- insert on test2
217 | WITH CTE AS
218 | (
219 | INSERT INTO test2 VALUES (37)
220 | RETURNING id
221 | )
222 | UPDATE test3
223 | SET id = cte.id
224 | FROM cte
225 | WHERE test3.id <> cte.id;
226 |
227 | --
228 | -- Be sure that test has correct contents
229 | SELECT *
230 | FROM test2
231 | ORDER BY ID;
232 |
233 | --
234 | -- Change permissions of user 2 so that only object logging will be done
235 | \connect - :current_user
236 | ALTER ROLE user2 SET pgaudit.log = 'NONE';
237 |
238 | \connect - user2
239 |
240 | --
241 | -- Create test4 and add permissions
242 | CREATE TABLE test4
243 | (
244 | id int,
245 | name text
246 | );
247 |
248 | GRANT SELECT (name)
249 | ON TABLE public.test4
250 | TO auditor;
251 |
252 | GRANT UPDATE (id)
253 | ON TABLE public.test4
254 | TO auditor;
255 |
256 | GRANT insert (name)
257 | ON TABLE public.test4
258 | TO auditor;
259 |
260 | --
261 | -- Not object logged
262 | SELECT id
263 | FROM public.test4;
264 |
265 | --
266 | -- Object logged because of:
267 | -- select (name) on test4
268 | SELECT name
269 | FROM public.test4;
270 |
271 | --
272 | -- Not object logged
273 | INSERT INTO public.test4 (id)
274 | VALUES (1);
275 |
276 | --
277 | -- Object logged because of:
278 | -- insert (name) on test4
279 | INSERT INTO public.test4 (name)
280 | VALUES ('test');
281 |
282 | --
283 | -- Not object logged
284 | UPDATE public.test4
285 | SET name = 'foo';
286 |
287 | --
288 | -- Object logged because of:
289 | -- update (id) on test4
290 | UPDATE public.test4
291 | SET id = 1;
292 |
293 | --
294 | -- Object logged because of:
295 | -- update (name) on test4
296 | -- update (name) takes precedence over select (name) due to ordering
297 | update public.test4 set name = 'foo' where name = 'bar';
298 |
299 | --
300 | -- Change permissions of user 1 so that session logging will be done
301 | \connect - :current_user
302 |
303 | --
304 | -- Drop test tables
305 | DROP TABLE test2;
306 | DROP VIEW vw_test3;
307 | DROP TABLE test3;
308 | DROP TABLE test4;
309 | DROP FUNCTION test2_insert();
310 | DROP FUNCTION test2_change(int);
311 |
312 | ALTER ROLE user1 SET pgaudit.log = 'DDL, READ';
313 | \connect - user1
314 |
315 | --
316 | -- Create table is session logged
317 | CREATE TABLE public.account
318 | (
319 | id INT,
320 | name TEXT,
321 | password TEXT,
322 | description TEXT
323 | );
324 |
325 | --
326 | -- Select is session logged
327 | SELECT *
328 | FROM account;
329 |
330 | --
331 | -- Insert is not logged
332 | INSERT INTO account (id, name, password, description)
333 | VALUES (1, 'user1', 'HASH1', 'blah, blah');
334 |
335 | --
336 | -- Change permissions of user 1 so that only object logging will be done
337 | \connect - :current_user
338 | ALTER ROLE user1 SET pgaudit.log = 'none';
339 | ALTER ROLE user1 SET pgaudit.role = 'auditor';
340 | \connect - user1
341 |
342 | --
343 | -- ROLE class not set, so auditor grants not logged
344 | GRANT SELECT (password),
345 | UPDATE (name, password)
346 | ON TABLE public.account
347 | TO auditor;
348 |
349 | --
350 | -- Not object logged
351 | SELECT id,
352 | name
353 | FROM account;
354 |
355 | --
356 | -- Object logged because of:
357 | -- select (password) on account
358 | SELECT password
359 | FROM account;
360 |
361 | --
362 | -- Not object logged
363 | UPDATE account
364 | SET description = 'yada, yada';
365 |
366 | --
367 | -- Object logged because of:
368 | -- update (password) on account
369 | UPDATE account
370 | SET password = 'HASH2';
371 |
372 | --
373 | -- Change permissions of user 1 so that session relation logging will be done
374 | \connect - :current_user
375 | ALTER ROLE user1 SET pgaudit.log_relation = on;
376 | ALTER ROLE user1 SET pgaudit.log = 'read, WRITE';
377 | \connect - user1
378 |
379 | --
380 | -- Not logged
381 | CREATE TABLE ACCOUNT_ROLE_MAP
382 | (
383 | account_id INT,
384 | role_id INT
385 | );
386 |
387 | --
388 | -- ROLE class not set, so auditor grants not logged
389 | GRANT SELECT
390 | ON TABLE public.account_role_map
391 | TO auditor;
392 |
393 | --
394 | -- Object logged because of:
395 | -- select (password) on account
396 | -- select on account_role_map
397 | -- Session logged on all tables because log = read and log_relation = on
398 | SELECT account.password,
399 | account_role_map.role_id
400 | FROM account
401 | INNER JOIN account_role_map
402 | on account.id = account_role_map.account_id;
403 |
404 | --
405 | -- Object logged because of:
406 | -- select (password) on account
407 | -- Session logged on all tables because log = read and log_relation = on
408 | SELECT password
409 | FROM account;
410 |
411 | --
412 | -- Not object logged
413 | -- Session logged on all tables because log = read and log_relation = on
414 | UPDATE account
415 | SET description = 'yada, yada';
416 |
417 | --
418 | -- Object logged because of:
419 | -- select (password) on account (in the where clause)
420 | -- Session logged on all tables because log = read and log_relation = on
421 | UPDATE account
422 | SET description = 'yada, yada'
423 | where password = 'HASH2';
424 |
425 | --
426 | -- Object logged because of:
427 | -- update (password) on account
428 | -- Session logged on all tables because log = read and log_relation = on
429 | UPDATE account
430 | SET password = 'HASH2';
431 |
432 | --
433 | -- Change configuration of user 1 so that full statements are not logged
434 | \connect - :current_user
435 | ALTER ROLE user1 RESET pgaudit.log_relation;
436 | ALTER ROLE user1 RESET pgaudit.log;
437 | ALTER ROLE user1 SET pgaudit.log_statement = OFF;
438 | \connect - user1
439 |
440 | --
441 | -- Logged but without full statement
442 | SELECT * FROM account;
443 |
444 | --
445 | -- Change back to superuser to do exhaustive tests
446 | \connect - :current_user
447 | SET pgaudit.log = 'ALL';
448 | SET pgaudit.log_level = 'notice';
449 | SET pgaudit.log_client = ON;
450 | SET pgaudit.log_relation = ON;
451 | SET pgaudit.log_parameter = ON;
452 |
453 | --
454 | -- Simple DO block
455 | DO $$
456 | BEGIN
457 | raise notice 'test';
458 | END $$;
459 |
460 | --
461 | -- Create test schema
462 | CREATE SCHEMA test;
463 |
464 | --
465 | -- Copy account to stdout
466 | COPY account TO stdout;
467 |
468 | --
469 | -- Create a table from a query
470 | CREATE TABLE test.account_copy AS
471 | SELECT *
472 | FROM account;
473 |
474 | --
475 | -- Copy from stdin to account copy
476 | COPY test.account_copy from stdin;
477 | 1 user1 HASH2 yada, yada
478 | \.
479 |
480 | --
481 | -- Test prepared statement
482 | PREPARE pgclassstmt (oid) AS
483 | SELECT *
484 | FROM account
485 | WHERE id = $1;
486 |
487 | EXECUTE pgclassstmt (1);
488 | DEALLOCATE pgclassstmt;
489 |
490 | --
491 | -- Test cursor
492 | BEGIN;
493 |
494 | DECLARE ctest SCROLL CURSOR FOR
495 | SELECT count(*)
496 | FROM
497 | (
498 | SELECT relname
499 | FROM pg_class
500 | LIMIT 1
501 | ) subquery;
502 |
503 | FETCH NEXT FROM ctest;
504 | CLOSE ctest;
505 | COMMIT;
506 |
507 | --
508 | -- Turn off log_catalog and pg_class will not be logged
509 | SET pgaudit.log_catalog = OFF;
510 |
511 | SELECT count(*)
512 | FROM
513 | (
514 | SELECT relname
515 | FROM pg_class
516 | LIMIT 1
517 | ) subquery;
518 |
519 | --
520 | -- Test prepared insert
521 | CREATE TABLE test.test_insert
522 | (
523 | id INT
524 | );
525 |
526 | PREPARE pgclassstmt (oid) AS
527 | INSERT INTO test.test_insert (id)
528 | VALUES ($1);
529 | EXECUTE pgclassstmt (1);
530 |
531 | --
532 | -- Check that primary key creation is logged
533 | CREATE TABLE public.test
534 | (
535 | id INT,
536 | name TEXT,
537 | description TEXT,
538 | CONSTRAINT test_pkey PRIMARY KEY (id)
539 | );
540 |
541 | --
542 | -- Check that analyze is logged
543 | ANALYZE test;
544 |
545 | --
546 | -- Grants to public should not cause object logging (session logging will
547 | -- still happen)
548 | GRANT SELECT
549 | ON TABLE public.test
550 | TO PUBLIC;
551 |
552 | SELECT *
553 | FROM test;
554 |
555 | -- Check that statements without columns log
556 | SELECT
557 | FROM test;
558 |
559 | SELECT 1,
560 | substring('Thomas' from 2 for 3);
561 |
562 | DO $$
563 | DECLARE
564 | test INT;
565 | BEGIN
566 | SELECT 1
567 | INTO test;
568 | END $$;
569 |
570 | explain select 1;
571 |
572 | --
573 | -- Test that looks inside of do blocks log
574 | INSERT INTO TEST (id)
575 | VALUES (1);
576 | INSERT INTO TEST (id)
577 | VALUES (2);
578 | INSERT INTO TEST (id)
579 | VALUES (3);
580 |
581 | DO $$
582 | DECLARE
583 | result RECORD;
584 | BEGIN
585 | FOR result IN
586 | SELECT id
587 | FROM test
588 | LOOP
589 | INSERT INTO test (id)
590 | VALUES (result.id + 100);
591 | END LOOP;
592 | END $$;
593 |
594 | --
595 | -- Test obfuscated dynamic sql for clean logging
596 | DO $$
597 | DECLARE
598 | table_name TEXT = 'do_table';
599 | BEGIN
600 | EXECUTE 'CREATE TABLE ' || table_name || ' ("weird name" INT)';
601 | EXECUTE 'DROP table ' || table_name;
602 | END $$;
603 |
604 | --
605 | -- Generate an error and make sure the stack gets cleared
606 | DO $$
607 | BEGIN
608 | CREATE TABLE bogus.test_block
609 | (
610 | id INT
611 | );
612 | END $$;
613 |
614 | --
615 | -- Test alter table statements
616 | ALTER TABLE public.test
617 | DROP COLUMN description ;
618 |
619 | ALTER TABLE public.test
620 | RENAME TO test2;
621 |
622 | ALTER TABLE public.test2
623 | SET SCHEMA test;
624 |
625 | ALTER TABLE test.test2
626 | ADD COLUMN description TEXT;
627 |
628 | ALTER TABLE test.test2
629 | DROP COLUMN description;
630 |
631 | DROP TABLE test.test2;
632 |
633 | --
634 | -- Test multiple statements with one semi-colon
635 | CREATE SCHEMA foo
636 | CREATE TABLE foo.bar (id int)
637 | CREATE TABLE foo.baz (id int);
638 |
639 | --
640 | -- Test aggregate
641 | CREATE FUNCTION public.int_add
642 | (
643 | a INT,
644 | b INT
645 | )
646 | RETURNS INT LANGUAGE plpgsql AS $$
647 | BEGIN
648 | return a + b;
649 | END $$;
650 |
651 | SELECT int_add(1, 1);
652 |
653 | CREATE AGGREGATE public.sum_test(INT) (SFUNC=public.int_add, STYPE=INT, INITCOND='0');
654 | ALTER AGGREGATE public.sum_test(integer) RENAME TO sum_test2;
655 |
656 | --
657 | -- Test conversion
658 | CREATE CONVERSION public.conversion_test FOR 'latin1' TO 'utf8' FROM pg_catalog.iso8859_1_to_utf8;
659 | ALTER CONVERSION public.conversion_test RENAME TO conversion_test2;
660 |
661 | --
662 | -- Test create/alter/drop database
663 | CREATE DATABASE contrib_regression_pgaudit;
664 | ALTER DATABASE contrib_regression_pgaudit RENAME TO contrib_regression_pgaudit2;
665 | DROP DATABASE contrib_regression_pgaudit2;
666 |
667 | -- Test role as a substmt
668 | SET pgaudit.log = 'ROLE';
669 |
670 | CREATE TABLE t ();
671 | CREATE ROLE alice;
672 |
673 | CREATE SCHEMA foo2
674 | GRANT SELECT
675 | ON public.t
676 | TO alice;
677 |
678 | drop table public.t;
679 | drop role alice;
680 |
681 | --
682 | -- Test for non-empty stack error
683 | CREATE OR REPLACE FUNCTION get_test_id(_ret REFCURSOR) RETURNS REFCURSOR
684 | LANGUAGE plpgsql IMMUTABLE AS $$
685 | BEGIN
686 | OPEN _ret FOR SELECT 200;
687 | RETURN _ret;
688 | END $$;
689 |
690 | BEGIN;
691 | SELECT get_test_id('_ret');
692 | SELECT get_test_id('_ret2');
693 | FETCH ALL FROM _ret;
694 | FETCH ALL FROM _ret2;
695 | CLOSE _ret;
696 | CLOSE _ret2;
697 | END;
698 |
699 | --
700 | -- Test that frees a memory context earlier than expected
701 | SET pgaudit.log = 'ALL';
702 |
703 | CREATE TABLE hoge
704 | (
705 | id int
706 | );
707 |
708 | CREATE FUNCTION test()
709 | RETURNS INT AS $$
710 | DECLARE
711 | cur1 cursor for select * from hoge;
712 | tmp int;
713 | BEGIN
714 | OPEN cur1;
715 | FETCH cur1 into tmp;
716 | RETURN tmp;
717 | END $$
718 | LANGUAGE plpgsql ;
719 |
720 | SELECT test();
721 |
722 | --
723 | -- Delete all rows then delete 1 row
724 | SET pgaudit.log = 'write';
725 | SET pgaudit.role = 'auditor';
726 |
727 | create table bar
728 | (
729 | col int
730 | );
731 |
732 | grant delete
733 | on bar
734 | to auditor;
735 |
736 | insert into bar (col)
737 | values (1);
738 | delete from bar;
739 |
740 | insert into bar (col)
741 | values (1);
742 | delete from bar
743 | where col = 1;
744 |
745 | drop table bar;
746 |
747 | --
748 | -- Grant roles to each other
749 | SET pgaudit.log = 'role';
750 | GRANT user1 TO user2;
751 | REVOKE user1 FROM user2;
752 |
753 | --
754 | -- Test that FK references do not log but triggers still do
755 | SET pgaudit.log = 'READ,WRITE';
756 | SET pgaudit.role TO 'auditor';
757 |
758 | CREATE TABLE aaa
759 | (
760 | ID int primary key
761 | );
762 |
763 | CREATE TABLE bbb
764 | (
765 | id int
766 | references aaa(id)
767 | );
768 |
769 | CREATE FUNCTION bbb_insert() RETURNS TRIGGER AS $$
770 | BEGIN
771 | UPDATE bbb set id = new.id + 1;
772 |
773 | RETURN new;
774 | END $$ LANGUAGE plpgsql;
775 |
776 | CREATE TRIGGER bbb_insert_trg
777 | AFTER INSERT ON bbb
778 | FOR EACH ROW EXECUTE PROCEDURE bbb_insert();
779 |
780 | GRANT SELECT, UPDATE
781 | ON aaa
782 | TO auditor;
783 |
784 | GRANT UPDATE
785 | ON bbb
786 | TO auditor;
787 |
788 | INSERT INTO aaa VALUES (generate_series(1,100));
789 |
790 | SET pgaudit.log_parameter TO OFF;
791 | INSERT INTO bbb VALUES (1);
792 | SET pgaudit.log_parameter TO ON;
793 |
794 | DROP TABLE bbb;
795 | DROP TABLE aaa;
796 |
797 | -- Test create table as after extension as been dropped
798 | DROP EXTENSION pgaudit;
799 |
800 | CREATE TABLE tmp (id int, data text);
801 | CREATE TABLE tmp2 AS (SELECT * FROM tmp);
802 |
803 | DROP TABLE tmp;
804 | DROP TABLE tmp2;
805 |
806 | --
807 | -- Test MISC
808 | SET pgaudit.log = 'MISC';
809 | SET pgaudit.log_level = 'notice';
810 | SET pgaudit.log_client = ON;
811 | SET pgaudit.log_relation = ON;
812 | SET pgaudit.log_parameter = ON;
813 |
814 | CREATE ROLE alice;
815 |
816 | SET ROLE alice;
817 | CREATE TABLE t (a int, b text);
818 | SET search_path TO test, public;
819 |
820 | INSERT INTO t VALUES (1, 'misc');
821 |
822 | VACUUM t;
823 | RESET ROLE;
824 |
825 | --
826 | -- Test MISC_SET
827 | SET pgaudit.log = 'MISC_SET';
828 |
829 | SET ROLE alice;
830 | SET search_path TO public;
831 |
832 | INSERT INTO t VALUES (2, 'misc_set');
833 |
834 | VACUUM t;
835 | RESET ROLE;
836 |
837 | --
838 | -- Test ALL, -MISC, MISC_SET
839 | SET pgaudit.log = 'ALL, -MISC, MISC_SET';
840 |
841 | SET search_path TO public;
842 |
843 | INSERT INTO t VALUES (3, 'all, -misc, misc_set');
844 |
845 | VACUUM t;
846 |
847 | RESET ROLE;
848 | DROP TABLE public.t;
849 | DROP ROLE alice;
850 |
851 | --
852 | -- Test PARTITIONED table
853 | CREATE TABLE h(x int ,y int) PARTITION BY HASH(x);
854 | CREATE TABLE h_0 partition OF h FOR VALUES WITH ( MODULUS 2, REMAINDER 0);
855 | CREATE TABLE h_1 partition OF h FOR VALUES WITH ( MODULUS 2, REMAINDER 1);
856 | INSERT INTO h VALUES(1,1);
857 | SELECT * FROM h;
858 | SELECT * FROM h_0;
859 | CREATE INDEX h_idx ON h (x);
860 | DROP INDEX h_idx;
861 | DROP TABLE h;
862 |
863 | -- Cleanup
864 | -- Set client_min_messages up to warning to avoid noise
865 | SET client_min_messages = 'warning';
866 |
867 | ALTER ROLE :current_user RESET pgaudit.log;
868 | ALTER ROLE :current_user RESET pgaudit.log_catalog;
869 | ALTER ROLE :current_user RESET pgaudit.log_client;
870 | ALTER ROLE :current_user RESET pgaudit.log_level;
871 | ALTER ROLE :current_user RESET pgaudit.log_parameter;
872 | ALTER ROLE :current_user RESET pgaudit.log_relation;
873 | ALTER ROLE :current_user RESET pgaudit.log_statement;
874 | ALTER ROLE :current_user RESET pgaudit.log_statement_once;
875 | ALTER ROLE :current_user RESET pgaudit.role;
876 |
877 | RESET pgaudit.log;
878 | RESET pgaudit.log_catalog;
879 | RESET pgaudit.log_level;
880 | RESET pgaudit.log_parameter;
881 | RESET pgaudit.log_relation;
882 | RESET pgaudit.log_statement;
883 | RESET pgaudit.log_statement_once;
884 | RESET pgaudit.role;
885 |
886 | DROP TABLE test.account_copy;
887 | DROP TABLE test.test_insert;
888 | DROP SCHEMA test;
889 | DROP TABLE foo.bar;
890 | DROP TABLE foo.baz;
891 | DROP SCHEMA foo;
892 | DROP TABLE hoge;
893 | DROP TABLE account;
894 | DROP TABLE account_role_map;
895 | DROP USER user2;
896 | DROP USER user1;
897 | DROP ROLE auditor;
898 |
899 | RESET client_min_messages;
900 |
--------------------------------------------------------------------------------
/test/Vagrantfile:
--------------------------------------------------------------------------------
1 | Vagrant.configure(2) do |config|
2 | config.vm.box = "bento/centos-7.6"
3 |
4 | config.vm.provider :virtualbox do |vb|
5 | vb.name = "pgaudit-centos7-test"
6 | end
7 |
8 | # Provision the VM
9 | config.vm.provision "shell", inline: <<-SHELL
10 | # Setup environment
11 | echo 'export PG_VERSION=13' >> /etc/bashrc
12 | echo 'export PATH=$PATH:/usr/pgsql-${PG_VERSION?}/bin' >> /etc/bashrc
13 | source /etc/bashrc
14 |
15 | # Install PostgreSQL
16 | rpm -ivh https://download.postgresql.org/pub/repos/yum/reporpms/EL-7-x86_64/pgdg-redhat-repo-latest.noarch.rpm
17 | yum install -y postgresql${PG_VERSION?}-server
18 |
19 | # Compile & install pgaudit
20 | yum install -y centos-release-scl-rh epel-release
21 | yum install -y postgresql${PG_VERSION?}-devel gcc openssl-devel llvm-toolset-7-clang llvm5.0
22 | make -C /pgaudit install USE_PGXS=1
23 |
24 | # Create PostgreSQL cluster
25 | sudo -u postgres /usr/pgsql-${PG_VERSION?}/bin/initdb -A trust -k /var/lib/pgsql/${PG_VERSION?}/data
26 | echo "shared_preload_libraries = 'pgaudit'" >> /var/lib/pgsql/${PG_VERSION?}/data/postgresql.conf
27 | systemctl start postgresql-${PG_VERSION?}
28 | sudo -u postgres psql -Xc 'create user vagrant superuser' postgres
29 |
30 | # Test pgaudit
31 | sudo -u vagrant bash -cl 'make -C /pgaudit installcheck USE_PGXS=1'
32 | SHELL
33 |
34 | # Don't share the default vagrant folder
35 | config.vm.synced_folder ".", "/vagrant", disabled: true
36 |
37 | # Mount project path for testing
38 | config.vm.synced_folder "..", "/pgaudit"
39 | end
40 |
--------------------------------------------------------------------------------