├── .gitignore ├── AUTHORS ├── CONTRIBUTORS ├── COPYING ├── ChangeLog ├── INSTALL ├── META.json ├── Makefile ├── README.md ├── expected ├── 00-init.out ├── 01-basic.out ├── 02-upt-del.out ├── 03-trig-fct.out ├── 04-partition.out └── 05-privileges.out ├── include ├── pel_errqueue.h ├── pel_worker.h └── pg_dbms_errlog.h ├── pel_errqueue.c ├── pel_worker.c ├── pg_dbms_errlog.c ├── pg_dbms_errlog.control ├── sql ├── pg_dbms_errlog--1.0.sql ├── pg_dbms_errlog--1.1.sql ├── pg_dbms_errlog--1.2.sql ├── pg_dbms_errlog--1.3.sql ├── pg_dbms_errlog--2.0.sql └── pg_dbms_errlog--2.1.sql ├── test ├── batch_script_example.pl └── sql │ ├── 00-init.sql │ ├── 01-basic.sql │ ├── 02-upt-del.sql │ ├── 03-trig-fct.sql │ ├── 04-partition.sql │ └── 05-privileges.sql └── updates ├── pg_dbms_errlog--1.0--1.1.sql ├── pg_dbms_errlog--1.1--1.2.sql ├── pg_dbms_errlog--1.2--1.3.sql ├── pg_dbms_errlog--1.3--2.0.sql └── pg_dbms_errlog--2.0--2.1.sql /.gitignore: -------------------------------------------------------------------------------- 1 | *.so 2 | *.bc 3 | *.o 4 | results/ 5 | -------------------------------------------------------------------------------- /AUTHORS: -------------------------------------------------------------------------------- 1 | pg_dbms_errlog extension is written by: 2 | 3 | * Julien Rouhaud 4 | * Gilles Darold 5 | 6 | -------------------------------------------------------------------------------- /CONTRIBUTORS: -------------------------------------------------------------------------------- 1 | List of contributors 2 | ==================== 3 | 4 | 5 | Thanks to all of them! 6 | -------------------------------------------------------------------------------- /COPYING: -------------------------------------------------------------------------------- 1 | Copyright (c) 2021 MigOps-Inc 2 | 3 | Permission to use, copy, modify, and distribute this software for any 4 | purpose with or without fee is hereby granted, provided that the above 5 | copyright notice and this permission notice appear in all copies. 6 | 7 | THE SOFTWARE IS PROVIDED "AS IS" AND THE AUTHOR DISCLAIMS ALL WARRANTIES 8 | WITH REGARD TO THIS SOFTWARE INCLUDING ALL IMPLIED WARRANTIES OF 9 | MERCHANTABILITY AND FITNESS. IN NO EVENT SHALL THE AUTHOR BE LIABLE FOR 10 | ANY SPECIAL, DIRECT, INDIRECT, OR CONSEQUENTIAL DAMAGES OR ANY DAMAGES 11 | WHATSOEVER RESULTING FROM LOSS OF USE, DATA OR PROFITS, WHETHER IN AN 12 | ACTION OF CONTRACT, NEGLIGENCE OR OTHER TORTIOUS ACTION, ARISING OUT OF 13 | OR IN CONNECTION WITH THE USE OR PERFORMANCE OF THIS SOFTWARE. 14 | -------------------------------------------------------------------------------- /ChangeLog: -------------------------------------------------------------------------------- 1 | Mon December 26 2022 - Version 2.1 2 | 3 | This maintenance release fix some issues reported by users since past 4 | six months. 5 | 6 | - Add missing PGDLLEXPORT markings. Thanks to Julien Rouhaud for the patch. 7 | Remove useless call to position. 8 | - Fix function create_error_log() to use the schema of the table to log 9 | instead of default schema (public or from search_path). The function 10 | now also check that the table to log exists and use quote_ident() in 11 | the errorlog table creation. 12 | - Fix compatibility with pg15 new shmem_request_hook. Thanks to Julien Rouhaud 13 | for the patch. 14 | - Fix regression tests for pg15 since PUBLIC doesn't have CREATE privilege on 15 | the public schema by default. Thanks to Julien Rouhaud for the patch. 16 | - Remove _PG_fini(). Thanks to Julien Rouhaud for the patch. 17 | - Fix compatibility with pg14 new process utility hook prototype. Thanks to 18 | Julien Rouhaud for the patch. 19 | - Fix regression test with new warning format. Thanks to Julien Rouhaud for 20 | the patch. 21 | 22 | Tue May 25 2021 - Version 2.0 23 | 24 | This major release replace pg_background with a custom infrastructure. 25 | It adds the following infrastructure: 26 | 27 | - queue in dynamic shared memory of error information that can be 28 | processed asynchronously 29 | 30 | - a dynamic background worker that can process the queued error and 31 | insert the data in the corresponding error table, launching dynamic 32 | background workers that can process the data in batch 33 | 34 | - a notification system so the backends can ask the background worker 35 | to start processing queue items they just processed immediately, 36 | and be notified when the work is done to reduce the waiting time as 37 | much as possible 38 | 39 | This fixes multiples issues with the pg_background approach: 40 | 41 | - we don't have to launch a dynamic bgworker per error anymore 42 | 43 | - if a dynamic bgworker can't be launched, the error data isn't lost 44 | and will be reprocessed until it's successful 45 | 46 | - we can (although it's not done yet) implement various "synchronous" 47 | mode, for instance [ off | query | transaction ], and options to 48 | start processing queued error in the background before the commit 49 | if the queue becomes too large 50 | 51 | - we can (although it's not done yet) implement a memory limit on the 52 | queue size 53 | 54 | Complete list of changes: 55 | 56 | - Fix batch script with synchronous setting. Gilles Darold 57 | - Fix detection when pg_dbms_errlog.reject_limit is reached for further 58 | error handling. Gilles Darold 59 | - Add extension upgrade file from 1.3 to 2.0. Gilles Darold 60 | - Remove extension downgrade SQL file for version 1.x. Gilles Darold 61 | - Add missing SQL extension file for version 1.x. Gilles Darold 62 | - Update documentation to new extension design. Gilles Darold 63 | - Change the default value of reject_limit to -1 (unlimited) and add 64 | support to unlimited logging. Gilles Darold 65 | - Update files headers. Gilles Darold 66 | - Fix portability to PG version prior 14. Gilles Darold 67 | - Fix SQL upgrade script for queue_size(). Julien Rouhaud 68 | - Don't throw errors in pel_log_error and always call the previous 69 | emit_log_hook. Julien Rouhaud 70 | - Handle the reject_limit GUC parameter and add a new queue_size() 71 | SQL function. Julien Rouhaud 72 | - Remove the unnecessary LOAD 'pg_dbms_errlog' calls in regression 73 | tests. Julien Rouhaud 74 | - Change synchronous GUC to [ off | query | transaction ] enum, 75 | default to xact. Julien Rouhaud 76 | - When pg_dbms_errlog.enabled is false prevent executing useless code. 77 | Gilles Darold 78 | - Add missing call to chained emit_log_hook in perl_errlog function. 79 | Gilles Darold 80 | - Remove obsolete function pel_unregister_errlog_table(), now the 81 | unregistration is handled at event triggger level. Gilles Darold 82 | - Fix case where subsequent error was not logged. Gilles Darold 83 | - Fix privilege issues on using pg_dbms_errlog as a basic user like 84 | Oracle DBMS_ERRLOG behavior. Gilles Darold 85 | - Add regression test for privilege on errorlog table. Gilles Darold 86 | - Add forgotten pg_dbms_errlog--1.1--2.0.sql script file. 87 | Julien Rouhaud 88 | - Fix compatibility with PostgreSQL version prior 12. Julien Rouhaud 89 | - bgworker: check if any work is queued before sleeping. Julien 90 | Rouhaud 91 | - If we just processed some queued entries, check if some more work 92 | has been queue since we last woke up and process it immediately, 93 | otherwise we might miss some request from backends and let them 94 | wait up to pel_frequency, as their SetLatch could be reset by 95 | the dynamic bgworker infrastructure. Restart the main bgworker 96 | immediately. Note that the main bgworker can hit an error and 97 | restart if the dynamic bgworker fails, for instance if it tries 98 | to process entries for a database than has been dropped since. 99 | This scenario should be tested and fixed but for now simply reduce 100 | the time needed for the main bgworker to restart in case of 101 | problem. Julien Rouhaud 102 | - Add a pg_dbms_errlog.debug GUC. Julien Rouhaud 103 | - Add compatibility with pg14. Julien Rouhaud 104 | - Fix COMMIT/ROLLBACK detection for PG prior 12. Julien Rouhaud 105 | - Similarly to pg13+ and the QueryCompletion field, the completionTag 106 | for a COMMIT/ROLLBACK only reports ROLLBACK in processUtility, and 107 | kept empty for a COMMIT. Julien Rouhaud 108 | - Some regression tests are still failing but let's fix the code 109 | compilation first. Julien Rouhaud 110 | - Fix some portability issues with PostgreSQL prior v13. Gilles Darold 111 | - Add some debug messages to bgworker and error queuing. Gilles Darold 112 | - Some cleanup & new infrastructure. Julien Rouhaud 113 | 114 | Tue May 25 2021 - Version 1.3 115 | 116 | - Register errors into error log tables as superuser to avoid granting 117 | priviledge to users. Gilles Darold 118 | - Make sure tests output are stable. Julien Rouhaud 119 | - Avoid too long lines and reindent the code. Julien Rouhaud 120 | - Remove forgotten useless declaration. Julien Rouhaud 121 | - Fix various dangling pointer issues. Julien Rouhaud 122 | - Update AUTHORS file. Gilles Darold 123 | - Add support to PostgreSQL v14. Gilles Darold 124 | - Fix support of PostgreSQL version prior 13. Gilles Darold 125 | 126 | Mon May 10 2021 - Version 1.2 127 | 128 | - Add bind parameters to error messages to be able to restore the failing 129 | statement. Gilles Darold 130 | - Add missing files for partition regression test. Gilles Darold 131 | - Add regression test for partionned table logging. Gilles Darold 132 | 133 | Mon May 10 2021 - Version 1.1 134 | 135 | - Replace internal handling of DropStmt when a DROP TABLE is issued by an 136 | event trigger on sql_drop to handle DROP SCHEMA CASCADE. Gilles Darold 137 | - Add verification that DML table to create is not null. Gilles Darold 138 | 139 | Sun May 9 2021 - Version 1.0 140 | 141 | Initial version 142 | -------------------------------------------------------------------------------- /INSTALL: -------------------------------------------------------------------------------- 1 | The installation steps are covered in the README file. 2 | -------------------------------------------------------------------------------- /META.json: -------------------------------------------------------------------------------- 1 | { 2 | "name": "pg_dbms_errlog", 3 | "abstract": "Extension to log DML errors to dedicated tables", 4 | "description": "pg_dbms_errlog is a PostgreSQL extension to add Oracle like DBMS_ERRLOG feature.", 5 | "version": "1.0", 6 | "maintainer": "Gilles Darold ", 7 | "license": { 8 | "PostgreSQL": "http://www.postgresql.org/about/licence" 9 | }, 10 | "release_status": "stable", 11 | "prereqs": { 12 | "runtime": { 13 | "requires": { 14 | "PostgreSQL": "10.0" 15 | } 16 | } 17 | }, 18 | "provides": { 19 | "pg_dbms_errlog": { 20 | "file": "sql/pg_dbms_errlog--2.1.sql", 21 | "docfile": "README.md", 22 | "version": "2.1", 23 | "abstract": "Extension to log DML errors to dedicated tables" 24 | } 25 | }, 26 | "meta-spec": { 27 | "version": "1.0", 28 | "url": "http://pgxn.org/meta/spec.txt" 29 | }, 30 | "tags": [ 31 | "error", 32 | "dml", 33 | "log" 34 | ], 35 | "resources": { 36 | "bugtracker": { 37 | "web": "https://github.com/MigOpsRepos/pg_dbms_errlog/issues" 38 | }, 39 | "repository": { 40 | "type": "git", 41 | "url": "git://github.com/MigOpsRepos/pg_dbms_errlog", 42 | "web": "https://github.com/MigOpsRepos/pg_dbms_errlog" 43 | } 44 | } 45 | } 46 | -------------------------------------------------------------------------------- /Makefile: -------------------------------------------------------------------------------- 1 | EXTENSION = pg_dbms_errlog 2 | EXTVERSION = $(shell grep default_version $(EXTENSION).control | \ 3 | sed -e "s/default_version[[:space:]]*=[[:space:]]*'\([^']*\)'/\1/") 4 | 5 | PGFILEDESC = "pg_dbms_errlog - Emulate Oracle DBMS_ERRLOG for PostgreSQL" 6 | 7 | PG_CONFIG = pg_config 8 | 9 | PG_CPPFLAGS = -Wno-uninitialized 10 | PG_LIBDIR := $(shell $(PG_CONFIG) --libdir) 11 | 12 | DOCS = $(wildcard README*) 13 | MODULE_big = pg_dbms_errlog 14 | 15 | OBJS = pg_dbms_errlog.o pel_errqueue.o pel_worker.o 16 | 17 | DATA = $(wildcard updates/*--*.sql) sql/$(EXTENSION)--$(EXTVERSION).sql 18 | 19 | TESTS = 00-init \ 20 | 01-basic \ 21 | 02-upt-del \ 22 | 03-trig-fct \ 23 | 04-partition \ 24 | 05-privileges 25 | 26 | REGRESS = $(patsubst test/sql/%.sql,%,$(TESTS)) 27 | REGRESS_OPTS = --inputdir=test 28 | 29 | PGXS := $(shell $(PG_CONFIG) --pgxs) 30 | include $(PGXS) 31 | 32 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | ## pg_dbms_errlog - DML error logging 2 | 3 | * [Description](#description) 4 | * [Installation](#installation) 5 | * [Configuration](#configuration) 6 | * [Use of the extension](#use-of-the-extension) 7 | * [Limitations](#limitation) 8 | * [Which errors are logged](#which-errors-are-logged)? 9 | * [Using a table with error logging](#using-a-table-with-error-logging) 10 | * [Error logging table](#error-logging-table) 11 | * [Batch script example](#batch-script-example) 12 | * [Authors](#authors) 13 | * [License](#license) 14 | 15 | ### [Description](#description) 16 | 17 | The pg_dbms_errlog extension provides the infrastructure that enables you to 18 | create an error logging table so that DML operations can continue after 19 | encountering errors rather than abort and roll back. It requires the use of 20 | the pg_statement_rollback extension or to fully manage the SAVEPOINT in the 21 | DML script. Logging in the corresponding error table is done using dynamic 22 | shared memory for error queuing and a background worker to write the errors 23 | queued into the corresponding error log tables. Note that configuration setting 24 | `max_worker_processes` must be high enough to support the extension, as it will 25 | launch up to `pg_dbms_errlog.max_workers` dynamic background workers, plus an 26 | additional fixed background worker. 27 | 28 | Error logging can be done synchronously by registering the error at query 29 | level or when the transaction ends using GUC `pg_dbms_errlog.synchronous`. 30 | Logging at transaction is the default and must be preferred to query, it is 31 | the mode that can guarantee that only errors on a committed transaction will 32 | be logged. When synchronous logging is disabled `off` error logging is done 33 | when the bg_worker wakes up or when function `dbms_errlog.publish_queue()` 34 | is called or that the synchronous level is changed. 35 | 36 | * [Installation](#installation) 37 | 38 | To install the pg_dbms_errlog extension you need at least a PostgreSQL 39 | version 10. Untar the pg_dbms_errlog tarball anywhere you want then you'll 40 | need to compile it with PGXS. The `pg_config` tool must be in your path. 41 | 42 | Depending on your installation, you may need to install some devel package. 43 | Once `pg_config` is in your path, do 44 | 45 | make 46 | sudo make install 47 | 48 | Configure the extension in `shared_preload_libraries`. For instance in a 49 | vanilla **postgresql.conf**:: 50 | 51 | shared_preload_libraries = 'pg_dbms_errlog' 52 | 53 | Restart the instance. 54 | 55 | To run test execute the following command as superuser: 56 | 57 | make installcheck 58 | 59 | ### [Configuration](#configuration) 60 | 61 | - *pg_dbms_errlog.enabled* 62 | 63 | Enable/disable log of failing queries. Default disabled. 64 | 65 | - *pg_dbms_errlog.query_tag* 66 | 67 | Tag (a numeric or string literal in parentheses) that gets added to the error 68 | log to help identify the statement that caused the errors. If the tag is 69 | omitted, a NULL value is used. 70 | 71 | - *pg_dbms_errlog.reject_limit* 72 | 73 | Maximum number of errors that can be encountered before the DML statement 74 | terminates and rolls back. A value of -1 mean unlimited, this is the default. 75 | When reject limit is zero no error is logged and the statement rolls back. 76 | Unlike Oracle which apply this limit per DML statement, the extension use 77 | this limit for the whole DML transaction. 78 | 79 | - *pg_dbms_errlog.synchronous* 80 | 81 | Wait for error processing completion when an error happens (`query`) or when the 82 | transaction ends (`transaction`). Default value is `transaction`. When synchronous 83 | logging is disabled (`off`) error logging is done when the bg_worker wakes up or 84 | when function `dbms_errlog.publish_queue()` is called or that the synchronous level 85 | is changed. 86 | 87 | - *pg_dbms_errlog.no_client_error* 88 | 89 | Enable/disable client error logging. Enable by default, the error messages 90 | logged will not be sent to the client but still logged on server side. This 91 | correspond to the Oracle behavior. 92 | 93 | - *pg_dbms_errlog.debug* 94 | 95 | Enable/disable debug traces. 96 | 97 | - *pg_dbms_errlog.frequency* 98 | 99 | Amount of time the background worker will sleep before checking for unprocessed 100 | errors, which only happens if `pg_dbms_errlog.synchronous` is disabled. Default 101 | is 60s. 102 | 103 | - *pg_dbms_errlog.max_workers* 104 | 105 | Number of dynamic background workers that can be launched simultaneously. Note 106 | that for now it can only happen on different databases. Default is 1. 107 | 108 | ### [Use of the extension](#use-of-the-extension) 109 | 110 | Enabling error logging for a table is done through the call of procedure 111 | `dbms_errlog.create_error_log()`. This procedure creates the error 112 | logging table that need to use the DML error logging capability. 113 | 114 | 115 | *dbms_errlog.create_error_log (dml_table_name varchar(132), err_log_table_name varchar(132) DEFAULT NULL, err_log_table_owner name DEFAULT NULL, err_log_table_space name DEFAULT NULL)* 116 | 117 | - *dml_table_name varchar(128)* 118 | 119 | Name of the DML table to base the error logging table on, can be fqdn. 120 | 121 | - *err_log_table_name name* 122 | 123 | Name of the error logging table to create. Can be NULL, default is to take 124 | the first 58 characters of the DML table name and to prefixed it with string 125 | `ERR$_`. The table is created in the current working schema it can be changed 126 | using `search_path` or using fqdn table name. 127 | 128 | - *err_log_table_owner name* 129 | 130 | Name of the owner of the error logging table. Can be NULL, default to 131 | current user. 132 | 133 | - *err_log_table_space name* 134 | 135 | Name of the tablespace where the error logging table will be created in. Can 136 | be NULL to not use any specific tablespace. 137 | 138 | This correspond to the [Oracle CREATE_ERROR_LOG Procedure](https://docs.oracle.com/database/121/ARPLS/d_errlog.htm#ARPLS66322) minus the use of 139 | parameter `skip_unsupported` because we don't have such limitation with the 140 | current design of the extension. The pg_dbms_errlog extension doesn't copy 141 | the DML data into a dedicated column but it logs the whole query and error 142 | details in two text columns. An other different behavior is the reject limit 143 | setting. With Oracle setting a limit to 0 means that the error is logged and 144 | the statement is rolled back. In this extension 0 mean, no log at all, the 145 | limit correspond to the number of error that will be logged in the full 146 | transaction, not just for the DML statement like in Oracle. 147 | 148 | - Example 1: 149 | ``` 150 | CREATE EXTENSION pg_dbms_errlog; 151 | LOAD 'pg_dbms_errlog'; 152 | BEGIN; 153 | CALL dbms_errlog.create_error_log('employees'); 154 | END; 155 | ``` 156 | will create the logging table; 157 | ``` 158 | gilles=# \d public."ERR$_employees" 159 | Table "public.ERR$_employees" 160 | Column | Type | Collation | Nullable | Default 161 | ----------------+--------------+-----------+----------+--------- 162 | pg_err_number$ | text | | | 163 | pg_err_mesg$ | text | | | 164 | pg_err_optyp$ | character(1) | | | 165 | pg_err_tag$ | text | | | 166 | pg_err_query$ | text | | | 167 | pg_err_detail$ | text | | | 168 | ``` 169 | - Example 2: 170 | ``` 171 | CREATE EXTENSION pg_dbms_errlog; 172 | LOAD 'pg_dbms_errlog'; 173 | BEGIN; 174 | CALL dbms_errlog.create_error_log('hr.employees','"ERRORS"."ERR$_EMPTABLE"); 175 | END; 176 | ``` 177 | will create the logging table; 178 | ``` 179 | gilles=# \d "ERRORS"."ERR$_EMPTABLE" 180 | Table « "ERRORS"."ERR$_EMPTABLE" » 181 | Column | Type | Collation | Nullable | Default 182 | ----------------+--------------+-----------------+-----------+------------ 183 | pg_err_number$ | text | | | 184 | pg_err_mesg$ | text | | | 185 | pg_err_optyp$ | character(1) | | | 186 | pg_err_tag$ | text | | | 187 | pg_err_query$ | text | | | 188 | pg_err_detail$ | text | | | 189 | ``` 190 | 191 | A user must be granted the DML privileges to the table and to the error log 192 | table to be able to use this feature. Insert to the registration table is done 193 | internally by superuser. To allow a user to create an error logging table he 194 | must be granted to execute the `create_error_log()` function and have read/write 195 | access to the registration table `dbms_errlog.register_errlog_tables`. 196 | 197 | When function `dbms_errlog.publish_queue()` is called or that the synchronous 198 | When synchronous logging is disabled errors can be logged at any moment calling 199 | function `dbms_errlog.publish_queue()`. Otherwise they will be logged according 200 | to the synchronous level or when the background worker will wake up following 201 | the frequency. 202 | 203 | 204 | ### [Limitations](#limitation) 205 | 206 | As explain above the pg_dbms_errlog extension copy the failing DML query into 207 | a text column and error details in an other text column, that means that the 208 | statement logged must have a length below 1GB. 209 | 210 | Expect changes on this part in further version, having a dedicated log column 211 | per column's data to give the exact same behavior as Oracle implementation. 212 | 213 | The form `INSERT INTO SELECT ...` will not have the same behavior 214 | than in Oracle. It will not stored the successful insert and logged the rows 215 | in error. This is not supported because it is a single transaction for PostgreSQL 216 | and everything is rolled back in case of error. 217 | 218 | 219 | ### [Which errors are logged](#which-errors-are-logged)? 220 | 221 | For the pg_dbms_errlog extension all errors are logged except errors at parse 222 | level, aka syntax error. 223 | 224 | About Oracle RDMBS_ERRLOG module DML operations logged see 225 | [Error Logging Restrictions and Caveats](https://docs.oracle.com/database/121/ADMIN/tables.htm#GUID-4E5F45D4-DA96-48AE-A3DD-7AC5C1C11076) for more details. 226 | 227 | 228 | ### [Using a table with error logging](#using-a-table-with-error-logging) 229 | 230 | The following statements create a raises table in the sample schema `HR`, 231 | create an error logging table using the pg_dbms_errlog extension, and 232 | populate the raises table with data from the employees table. One of the 233 | inserts violates the check constraint on raises, and that row can be seen 234 | in associated error log table. 235 | 236 | If more than ten errors had occurred, then the statement would have 237 | aborted, rolling back any insertions made. 238 | 239 | ``` 240 | CREATE EXTENSION pg_dbms_errlog; 241 | LOAD 'pg_dbms_errlog'; 242 | LOAD 'pg_statement_rollback'; 243 | 244 | CREATE SCHEMA "HR"; 245 | CREATE TABLE "HR".raises ( emp_id integer, sal integer CHECK(sal > 8000) ); 246 | 247 | BEGIN; 248 | CALL dbms_errlog.create_error_log('"HR".raises'); 249 | END; 250 | 251 | SET pg_dbms_errlog.query_tag TO 'daily_load'; 252 | SET pg_dbms_errlog.reject_limit TO 10; 253 | SET pg_dbms_errlog.enabled TO true; 254 | 255 | BEGIN; 256 | SET pg_statement_rollback.enabled TO on; 257 | INSERT INTO "HR".raises VALUES (145, 15400); -- Success 258 | INSERT INTO "HR".raises VALUES (161, 7700); -- Failure 259 | -- Back to the automatic savepoint generated by the extension 260 | -- pg_statement_rollback necessary to not break the transaction 261 | ROLLBACK TO SAVEPOINT "PgSLRAutoSvpt"; 262 | INSERT INTO "HR".raises VALUES (175, 9680); -- Success 263 | COMMIT; 264 | ``` 265 | 266 | This code have inserted 2 rows into the raise table and one log entry into 267 | the error log table: 268 | ``` 269 | gilles=# SELECT * FROM "HR".raises; 270 | emp_id | sal 271 | --------+------- 272 | 145 | 15400 273 | 175 | 9680 274 | (2 rows) 275 | 276 | gilles=# \x 277 | Expanded display is on. 278 | gilles=# SELECT * FROM "ERR$_raises"; 279 | -[ RECORD 1 ]--+------------------------------------------------------------------------------------------ 280 | pg_err_number$ | 23514 281 | pg_err_mesg$ | new row for relation "raises" violates check constraint "raises_sal_check" 282 | pg_err_optyp$ | I 283 | pg_err_tag$ | daily_load 284 | pg_err_query$ | INSERT INTO "HR".raises VALUES (161, 7700); 285 | pg_err_detail$ | ERROR: 23514: new row for relation "raises" violates check constraint "raises_sal_check"+ 286 | | DETAIL: Failing row contains (161, 7700). + 287 | | STATEMENT: INSERT INTO "HR".raises VALUES (161, 7700); + 288 | | 289 | ``` 290 | 291 | The following settings are equivalent to a Oracle DML clause 292 | `LOG ERRORS INTO ERR$_raises ('daily_log') REJECT LIMIT 10`. 293 | 294 | ``` 295 | SET pg_dbms_errlog.enabled TO on; 296 | SET pg_dbms_errlog.query_tag TO 'daily_log'; 297 | SET pg_dbms_errlog.reject_limit TO 10; 298 | ``` 299 | 300 | You don't need to precise the destination error log table (here `ERR$_raises`) 301 | it is found automatically by the extension regarding the table where the DML is 302 | acting. 303 | 304 | A more complex DML script to demonstrate the use based on the example above: 305 | ``` 306 | LOAD 'pg_dbms_errlog'; 307 | LOAD 'pg_statement_rollback'; 308 | 309 | SET pg_dbms_errlog.query_tag TO 'batch_load'; 310 | SET pg_dbms_errlog.reject_limit TO 0; 311 | SET pg_dbms_errlog.enabled TO true; 312 | 313 | BEGIN; 314 | DELETE FROM "HR".raises; 315 | DELETE FROM "ERR$_raises"; 316 | SET pg_statement_rollback.enabled TO on; 317 | DO 318 | $$ 319 | DECLARE 320 | emp RECORD; 321 | BEGIN 322 | FOR emp IN SELECT employee_id, salary FROM employees WHERE commission_pct > .2 323 | LOOP 324 | BEGIN 325 | INSERT INTO "HR".raises VALUES (emp.employee_id, emp.salary); 326 | EXCEPTION WHEN OTHERS THEN 327 | ROLLBACK TO "PgSLRAutoSvpt"; 328 | END; 329 | END LOOP; 330 | END; 331 | $$ LANGUAGE plpgsql; 332 | COMMIT; 333 | 334 | ``` 335 | 336 | ### [Error logging table](#error-logging-table) 337 | 338 | The table created to log DML errors executed on a table has the following 339 | structure: 340 | ``` 341 | CREATE TABLE ERR$_DML_TABLE ( 342 | PG_ERR_NUMBER$ integer, -- PostgreSQL error number 343 | PG_ERR_MESG$ text, -- PostgreSQL error message 344 | PG_ERR_OPTYP$ char(1), -- Type of operation: insert (I), update (U), delete (D) 345 | PG_ERR_TAG$ text, -- Label used to identify the DML batch 346 | PG_ERR_QUERY$ text -- Query at origin (insert,delete, update or the prepared DML statement) 347 | PG_ERR_DETAIL$ text -- Errors details 348 | ); 349 | ``` 350 | 351 | ### [Batch script example](#batch-script-example) 352 | 353 | Test file `test/batch_script_example.pl` is a Perl script to demonstrate the 354 | use of the extension in a batch script. This script will try to insert 10 rows 355 | in table `t1` where the half will generate an error and will be logged to the 356 | corresponding error table `ERR$_t1`. 357 | 358 | ``` 359 | #!/usr/bin/perl 360 | 361 | use DBI; 362 | 363 | print "Creating the regression database.\n"; 364 | my $dbh = DBI->connect("dbi:Pg:dbname=template1", '', '', {AutoCommit => 1}); 365 | die "ERROR: can't connect to database template1\n" if (not defined $dbh); 366 | $dbh->do("DROP DATABASE contrib_regression"); 367 | $dbh->do("CREATE DATABASE contrib_regression"); 368 | $dbh->do("ALTER DATABASE contrib_regression SET lc_messages = 'C'"); 369 | $dbh->disconnect; 370 | 371 | print "Connect to the regression database.\n"; 372 | $dbh = DBI->connect("dbi:Pg:dbname=contrib_regression", '', '', {AutoCommit => 1, PrintError => 0}); 373 | die "ERROR: can't connect to database ontrib_regression\n" if (not defined $dbh); 374 | print "---------------------------------------------\n"; 375 | print "Create the extension and initialize the test\n"; 376 | print "---------------------------------------------\n"; 377 | $dbh->do("CREATE EXTENSION pg_dbms_errlog"); 378 | $dbh->do("LOAD 'pg_dbms_errlog'"); 379 | $dbh->do("SET pg_dbms_errlog.synchronous TO 'transaction'"); 380 | $dbh->do("CREATE TABLE t1 (a bigint PRIMARY KEY, lbl text)"); 381 | $dbh->do("CALL dbms_errlog.create_error_log('t1')"); 382 | $dbh->do("SET pg_dbms_errlog.query_tag TO 'daily_load'"); 383 | $dbh->do("SET pg_dbms_errlog.reject_limit TO 25"); 384 | $dbh->do("SET pg_dbms_errlog.enabled TO true"); 385 | $dbh->do("BEGIN"); 386 | print "---------------------------------------------\n"; 387 | print "Start DML work\n"; 388 | print "---------------------------------------------\n"; 389 | for (my $i = 0; $i <= 10; $i++) 390 | { 391 | $dbh->do("SAVEPOINT aze"); 392 | my $sth = $dbh->prepare("INSERT INTO t1 VALUES (?, ?)"); 393 | if (not defined $sth) { 394 | #print STDERR "PREPARE ERROR: " . $dbh->errstr . "\n"; 395 | next; 396 | } 397 | # Generate a duplicate key each two row inserted 398 | my $val = $i; 399 | $val = $i-1 if ($i % 2 != 0); 400 | unless ($sth->execute($val, 'insert '.$i)) { 401 | #print STDERR "EXECUTE ERROR: " . $dbh->errstr . "\n"; 402 | $dbh->do("ROLLBACK TO aze"); 403 | } 404 | } 405 | 406 | print "---------------------------------------------\n"; 407 | print "Look at inserted values in DML table\n"; 408 | print "---------------------------------------------\n"; 409 | my $sth = $dbh->prepare("SELECT * FROM t1"); 410 | $sth->execute(); 411 | while (my $row = $sth->fetch) { 412 | print "INSERTED ID: $row->[0]\n"; 413 | } 414 | $dbh->do("COMMIT;"); 415 | 416 | print "---------------------------------------------\n"; 417 | print "Look at failing insert in error logging table\n"; 418 | print "---------------------------------------------\n"; 419 | $sth = $dbh->prepare('SELECT * FROM "ERR$_t1"'); 420 | $sth->execute(); 421 | while (my $row = $sth->fetch) { 422 | print "ERROR: LOGGED: ", join(' | ', @$row), "\n"; 423 | } 424 | 425 | $dbh->disconnect; 426 | 427 | exit 0; 428 | ``` 429 | 430 | ### [Authors](#authors) 431 | 432 | - Julien Rouhaud 433 | - Gilles Darold 434 | 435 | 436 | ### [License](#license) 437 | 438 | This extension is free software distributed under the PostgreSQL 439 | License. 440 | 441 | Copyright (c) 2021-2022 MigOps Inc. 442 | 443 | -------------------------------------------------------------------------------- /expected/00-init.out: -------------------------------------------------------------------------------- 1 | /* 2 | * Must be executed before all regression test. 3 | */ 4 | -- Create the PostgreSQL extension 5 | CREATE EXTENSION pg_dbms_errlog; 6 | -- Create the test table 7 | CREATE TABLE IF NOT EXISTS t1 (a bigint PRIMARY KEY); 8 | -------------------------------------------------------------------------------- /expected/01-basic.out: -------------------------------------------------------------------------------- 1 | SET pg_dbms_errlog.synchronous = query; 2 | -- Create the error log table for relation t1 3 | CALL dbms_errlog.create_error_log('t1'); 4 | SELECT count(*) FROM dbms_errlog.register_errlog_tables ; 5 | count 6 | ------- 7 | 1 8 | (1 row) 9 | 10 | -- Set error log behavior for this DML batch 11 | SET pg_dbms_errlog.query_tag TO 'daily_load'; 12 | SET pg_dbms_errlog.reject_limit TO 25; 13 | SET pg_dbms_errlog.enabled TO true; 14 | -- Start a transaction 15 | BEGIN; 16 | -- Insert will fail 17 | SAVEPOINT aze; 18 | INSERT INTO t1 VALUES ('10.4'); 19 | ROLLBACK TO aze; 20 | SELECT * FROM "ERR$_t1" 21 | ORDER BY "pg_err_number$" COLLATE "C", "pg_err_mesg$" COLLATE "C"; 22 | pg_err_number$ | pg_err_mesg$ | pg_err_optyp$ | pg_err_tag$ | pg_err_query$ | pg_err_detail$ 23 | ----------------+----------------------------------------------+---------------+-------------+---------------------------------+----------------------------------------------------------------------------- 24 | 22P02 | invalid input syntax for type bigint: "10.4" | I | daily_load | INSERT INTO t1 VALUES ('10.4'); | ERROR: 22P02: invalid input syntax for type bigint: "10.4" at character 24+ 25 | | | | | | STATEMENT: INSERT INTO t1 VALUES ('10.4'); + 26 | | | | | | 27 | (1 row) 28 | 29 | -- Insert successful 30 | INSERT INTO t1 VALUES (1); 31 | -- Insert will fail on duplicate key 32 | SAVEPOINT aze; 33 | INSERT INTO t1 VALUES (1); 34 | ROLLBACK TO aze; 35 | SELECT * FROM "ERR$_t1" 36 | ORDER BY "pg_err_number$" COLLATE "C", "pg_err_mesg$" COLLATE "C"; 37 | pg_err_number$ | pg_err_mesg$ | pg_err_optyp$ | pg_err_tag$ | pg_err_query$ | pg_err_detail$ 38 | ----------------+----------------------------------------------------------+---------------+-------------+---------------------------------+----------------------------------------------------------------------------- 39 | 22P02 | invalid input syntax for type bigint: "10.4" | I | daily_load | INSERT INTO t1 VALUES ('10.4'); | ERROR: 22P02: invalid input syntax for type bigint: "10.4" at character 24+ 40 | | | | | | STATEMENT: INSERT INTO t1 VALUES ('10.4'); + 41 | | | | | | 42 | 23505 | duplicate key value violates unique constraint "t1_pkey" | I | daily_load | INSERT INTO t1 VALUES (1); | ERROR: 23505: duplicate key value violates unique constraint "t1_pkey" + 43 | | | | | | DETAIL: Key (a)=(1) already exists. + 44 | | | | | | STATEMENT: INSERT INTO t1 VALUES (1); + 45 | | | | | | 46 | (2 rows) 47 | 48 | PREPARE prep_insert AS INSERT INTO t1 VALUES ($1); 49 | -- Insert successful 50 | SAVEPOINT aze; 51 | EXECUTE prep_insert(2); 52 | ROLLBACK TO aze; 53 | -- Insert will fail 54 | SAVEPOINT aze; 55 | EXECUTE prep_insert('10.5'); 56 | ROLLBACK TO aze; 57 | DEALLOCATE prep_insert; 58 | ROLLBACK; 59 | -- Looking at error logging table 60 | \x 61 | SELECT * FROM "ERR$_t1" 62 | ORDER BY "pg_err_number$" COLLATE "C", "pg_err_mesg$" COLLATE "C"; 63 | -[ RECORD 1 ]--+---------------------------------------------------------------------------- 64 | pg_err_number$ | 22P02 65 | pg_err_mesg$ | invalid input syntax for type bigint: "10.4" 66 | pg_err_optyp$ | I 67 | pg_err_tag$ | daily_load 68 | pg_err_query$ | INSERT INTO t1 VALUES ('10.4'); 69 | pg_err_detail$ | ERROR: 22P02: invalid input syntax for type bigint: "10.4" at character 24+ 70 | | STATEMENT: INSERT INTO t1 VALUES ('10.4'); + 71 | | 72 | -[ RECORD 2 ]--+---------------------------------------------------------------------------- 73 | pg_err_number$ | 22P02 74 | pg_err_mesg$ | invalid input syntax for type bigint: "10.5" 75 | pg_err_optyp$ | I 76 | pg_err_tag$ | daily_load 77 | pg_err_query$ | PREPARE prep_insert AS INSERT INTO t1 VALUES ($1); 78 | pg_err_detail$ | ERROR: 22P02: invalid input syntax for type bigint: "10.5" at character 21+ 79 | | STATEMENT: EXECUTE prep_insert('10.5'); + 80 | | 81 | -[ RECORD 3 ]--+---------------------------------------------------------------------------- 82 | pg_err_number$ | 23505 83 | pg_err_mesg$ | duplicate key value violates unique constraint "t1_pkey" 84 | pg_err_optyp$ | I 85 | pg_err_tag$ | daily_load 86 | pg_err_query$ | INSERT INTO t1 VALUES (1); 87 | pg_err_detail$ | ERROR: 23505: duplicate key value violates unique constraint "t1_pkey" + 88 | | DETAIL: Key (a)=(1) already exists. + 89 | | STATEMENT: INSERT INTO t1 VALUES (1); + 90 | | 91 | 92 | \x 93 | TRUNCATE "ERR$_t1"; 94 | -- test queue discard on rollback 95 | SET pg_dbms_errlog.synchronous = off; 96 | BEGIN; 97 | SAVEPOINT aze; 98 | INSERT INTO t1 VALUES ('queue 1'); 99 | ROLLBACK TO aze; 100 | -- commit should discard the queue 101 | ROLLBACK; 102 | SELECT dbms_errlog.publish_queue(true); 103 | publish_queue 104 | --------------- 105 | t 106 | (1 row) 107 | 108 | SELECT 0 AS exp, count(*) FROM "ERR$_t1"; 109 | exp | count 110 | -----+------- 111 | 0 | 0 112 | (1 row) 113 | 114 | BEGIN; 115 | INSERT INTO t1 VALUES ('queue 2'); 116 | -- unsuccessful commit should discard the queue 117 | COMMIT; 118 | SELECT dbms_errlog.publish_queue(true); 119 | publish_queue 120 | --------------- 121 | t 122 | (1 row) 123 | 124 | SELECT 0 AS exp, count(*) FROM "ERR$_t1"; 125 | exp | count 126 | -----+------- 127 | 0 | 0 128 | (1 row) 129 | 130 | BEGIN; 131 | SAVEPOINT aze; 132 | INSERT INTO t1 VALUES ('queue 3'); 133 | ROLLBACK TO aze; 134 | SET pg_dbms_errlog.synchronous = query; 135 | -- commit should publish the queue even in query level sync 136 | COMMIT; 137 | SELECT 1 AS exp, count(*) FROM "ERR$_t1"; 138 | exp | count 139 | -----+------- 140 | 1 | 1 141 | (1 row) 142 | 143 | SET pg_dbms_errlog.synchronous = off; 144 | BEGIN; 145 | SAVEPOINT aze; 146 | INSERT INTO t1 VALUES ('queue 4'); 147 | ROLLBACK TO aze; 148 | -- should publish the queue and wait for the result 149 | SELECT dbms_errlog.publish_queue(true); 150 | publish_queue 151 | --------------- 152 | t 153 | (1 row) 154 | 155 | SELECT 2 AS exp, count(*) FROM "ERR$_t1"; 156 | exp | count 157 | -----+------- 158 | 2 | 2 159 | (1 row) 160 | 161 | -- error should still be visible in the error table 162 | ROLLBACK; 163 | SELECT 2 AS exp, count(*) FROM "ERR$_t1"; 164 | exp | count 165 | -----+------- 166 | 2 | 2 167 | (1 row) 168 | 169 | TRUNCATE "ERR$_t1"; 170 | -- test queuing multiple batches 171 | SET pg_dbms_errlog.synchronous = off; 172 | SET pg_dbms_errlog.frequency TO '1h'; 173 | BEGIN; 174 | SAVEPOINT aze; 175 | INSERT INTO t1 VALUES ('queue 5'); 176 | ROLLBACK TO aze; 177 | COMMIT; 178 | SELECT 0 AS exp, count(*) FROM "ERR$_t1"; 179 | exp | count 180 | -----+------- 181 | 0 | 0 182 | (1 row) 183 | 184 | BEGIN; 185 | SAVEPOINT aze; 186 | INSERT INTO t1 VALUES ('queue 6'); 187 | ROLLBACK TO aze; 188 | SET pg_dbms_errlog.synchronous = query; 189 | COMMIT; 190 | SELECT 2 AS exp, count(*) FROM "ERR$_t1"; 191 | exp | count 192 | -----+------- 193 | 2 | 2 194 | (1 row) 195 | 196 | TRUNCATE "ERR$_t1"; 197 | -- test waiting for already published batches 198 | SET pg_dbms_errlog.synchronous = off; 199 | BEGIN; 200 | SAVEPOINT aze; 201 | INSERT INTO t1 VALUES ('queue 7'); 202 | ROLLBACK TO aze; 203 | COMMIT; 204 | BEGIN; 205 | SAVEPOINT aze; 206 | INSERT INTO t1 VALUES ('queue 8'); 207 | ROLLBACK TO aze; 208 | COMMIT; 209 | SELECT 0 AS exp, count(*) FROM "ERR$_t1"; 210 | exp | count 211 | -----+------- 212 | 0 | 0 213 | (1 row) 214 | 215 | SELECT dbms_errlog.publish_queue(true); 216 | publish_queue 217 | --------------- 218 | t 219 | (1 row) 220 | 221 | SELECT 2 AS exp, count(*) FROM "ERR$_t1"; 222 | exp | count 223 | -----+------- 224 | 2 | 2 225 | (1 row) 226 | 227 | TRUNCATE "ERR$_t1"; 228 | -- test transaction level sync 229 | SET pg_dbms_errlog.synchronous = transaction; 230 | BEGIN; 231 | SAVEPOINT aze; 232 | INSERT INTO t1 VALUES ('queue 9'); 233 | ROLLBACK TO aze; 234 | -- the error should not have been published or processed 235 | SELECT 0 AS exp, count(*) FROM "ERR$_t1"; 236 | exp | count 237 | -----+------- 238 | 0 | 0 239 | (1 row) 240 | 241 | -- commit should publish the error and wait for the result 242 | COMMIT; 243 | SELECT 1 AS exp, count(*) FROM "ERR$_t1"; 244 | exp | count 245 | -----+------- 246 | 1 | 1 247 | (1 row) 248 | 249 | RESET pg_dbms_errlog.frequency; 250 | TRUNCATE "ERR$_t1"; 251 | -- test reject_limit 252 | SET pg_dbms_errlog.reject_limit TO 0; 253 | -- there shouldn't be any queue created 254 | SELECT * FROM dbms_errlog.queue_size(); 255 | num_errors 256 | ------------ 257 | 258 | (1 row) 259 | 260 | BEGIN; 261 | SAVEPOINT aze; 262 | -- should fail complaining that nothing can be queue 263 | INSERT INTO t1 VALUES ('queue 10'); 264 | WARNING: pg_dbms_errlog.reject_limit is set to 0, no error is handled 265 | ERROR: invalid input syntax for type bigint: "queue 10" 266 | LINE 1: INSERT INTO t1 VALUES ('queue 10'); 267 | ^ 268 | ROLLBACK TO aze; 269 | -- the error should not have been published or processed 270 | SELECT 0 AS exp, count(*) FROM "ERR$_t1"; 271 | exp | count 272 | -----+------- 273 | 0 | 0 274 | (1 row) 275 | 276 | -- there shouldn't be any queue created 277 | SELECT * FROM dbms_errlog.queue_size(); 278 | num_errors 279 | ------------ 280 | 281 | (1 row) 282 | 283 | COMMIT; 284 | -- the error should not have been published or processed 285 | SELECT 0 AS exp, count(*) FROM "ERR$_t1"; 286 | exp | count 287 | -----+------- 288 | 0 | 0 289 | (1 row) 290 | 291 | SET pg_dbms_errlog.reject_limit TO 1; 292 | BEGIN; 293 | SAVEPOINT aze; 294 | INSERT INTO t1 VALUES ('queue 11a'); 295 | ROLLBACK TO aze; 296 | -- the error should not have been published or processed 297 | SELECT 0 AS exp, count(*) FROM "ERR$_t1"; 298 | exp | count 299 | -----+------- 300 | 0 | 0 301 | (1 row) 302 | 303 | -- there should be 1 queued item 304 | SELECT 1 AS exp, * FROM dbms_errlog.queue_size(); 305 | exp | num_errors 306 | -----+------------ 307 | 1 | 1 308 | (1 row) 309 | 310 | -- should fail complaining that reject_limit has been reached 311 | INSERT INTO t1 VALUES ('queue 11b'); 312 | WARNING: pg_dbms_errlog.reject_limit (1) is reached (queue_entries=1), no further error is handled 313 | ERROR: invalid input syntax for type bigint: "queue 11b" 314 | LINE 1: INSERT INTO t1 VALUES ('queue 11b'); 315 | ^ 316 | ROLLBACK TO aze; 317 | -- the queue should have been discarded 318 | SELECT * FROM dbms_errlog.queue_size(); 319 | num_errors 320 | ------------ 321 | 322 | (1 row) 323 | 324 | COMMIT; 325 | -- the error should not have been published or processed 326 | SELECT 0 AS exp, count(*) FROM "ERR$_t1"; 327 | exp | count 328 | -----+------- 329 | 0 | 0 330 | (1 row) 331 | 332 | -- Dropping one of the table 333 | BEGIN; 334 | DROP TABLE "ERR$_t1"; 335 | SELECT count(*) FROM dbms_errlog.register_errlog_tables ; 336 | count 337 | ------- 338 | 0 339 | (1 row) 340 | 341 | ROLLBACK; 342 | SELECT count(*) FROM dbms_errlog.register_errlog_tables ; 343 | count 344 | ------- 345 | 1 346 | (1 row) 347 | 348 | BEGIN; 349 | DROP TABLE t1; 350 | SELECT count(*) FROM dbms_errlog.register_errlog_tables ; 351 | count 352 | ------- 353 | 0 354 | (1 row) 355 | 356 | ROLLBACK; 357 | SELECT count(*) FROM dbms_errlog.register_errlog_tables ; 358 | count 359 | ------- 360 | 1 361 | (1 row) 362 | 363 | DROP TABLE "ERR$_t1"; 364 | -------------------------------------------------------------------------------- /expected/02-upt-del.out: -------------------------------------------------------------------------------- 1 | SET pg_dbms_errlog.synchronous = query; 2 | -- Create the error log table for relation t1 in a dedicated schema 3 | CREATE SCHEMA testerrlog; 4 | CALL dbms_errlog.create_error_log('public."t1"', 'testerrlog."errTable"'); 5 | SELECT count(*) FROM dbms_errlog.register_errlog_tables ; 6 | count 7 | ------- 8 | 1 9 | (1 row) 10 | 11 | -- Set error log behavior for this DML batch 12 | SET pg_dbms_errlog.query_tag TO 'daily_load'; 13 | SET pg_dbms_errlog.reject_limit TO -1; 14 | SET pg_dbms_errlog.enabled TO true; 15 | -- Start a transaction 16 | BEGIN; 17 | -- Insert successful 18 | INSERT INTO t1 VALUES (3); 19 | -- DELETE will fail 20 | SAVEPOINT aze; 21 | DELETE FROM t1 WHERE a = '10.6'; 22 | ROLLBACK TO aze; 23 | SELECT * FROM testerrlog."errTable" 24 | ORDER BY "pg_err_number$" COLLATE "C", "pg_err_mesg$" COLLATE "C"; 25 | pg_err_number$ | pg_err_mesg$ | pg_err_optyp$ | pg_err_tag$ | pg_err_query$ | pg_err_detail$ 26 | ----------------+----------------------------------------------+---------------+-------------+----------------------------------+----------------------------------------------------------------------------- 27 | 22P02 | invalid input syntax for type bigint: "10.6" | D | daily_load | DELETE FROM t1 WHERE a = '10.6'; | ERROR: 22P02: invalid input syntax for type bigint: "10.6" at character 26+ 28 | | | | | | STATEMENT: DELETE FROM t1 WHERE a = '10.6'; + 29 | | | | | | 30 | (1 row) 31 | 32 | -- Update will fail but at parser level, it must not be logged 33 | SAVEPOINT aze; 34 | UPDATE t1 SET a = '10.7'::varchar interval WHERE a = 1; 35 | ERROR: syntax error at or near "interval" 36 | LINE 1: UPDATE t1 SET a = '10.7'::varchar interval WHERE a = 1; 37 | ^ 38 | ROLLBACK TO aze; 39 | -- Test prepared statement 40 | PREPARE prep_delete (bigint) AS DELETE FROM t1 WHERE a IN ($1); 41 | -- Delete will fail 42 | SAVEPOINT aze; 43 | EXECUTE prep_delete ('10.8'); 44 | ROLLBACK TO aze; 45 | DEALLOCATE prep_delete; 46 | PREPARE prep_update (bigint) AS UPDATE t1 SET a = $1 WHERE a = 2; 47 | -- Update will fail 48 | SAVEPOINT aze; 49 | EXECUTE prep_update('10.9'); 50 | ROLLBACK TO aze; 51 | DEALLOCATE prep_update; 52 | ROLLBACK; 53 | -- Looking at error logging table 54 | \x 55 | SELECT * FROM testerrlog."errTable" 56 | ORDER BY "pg_err_number$" COLLATE "C", "pg_err_mesg$" COLLATE "C"; 57 | -[ RECORD 1 ]--+---------------------------------------------------------------------------- 58 | pg_err_number$ | 22P02 59 | pg_err_mesg$ | invalid input syntax for type bigint: "10.6" 60 | pg_err_optyp$ | D 61 | pg_err_tag$ | daily_load 62 | pg_err_query$ | DELETE FROM t1 WHERE a = '10.6'; 63 | pg_err_detail$ | ERROR: 22P02: invalid input syntax for type bigint: "10.6" at character 26+ 64 | | STATEMENT: DELETE FROM t1 WHERE a = '10.6'; + 65 | | 66 | -[ RECORD 2 ]--+---------------------------------------------------------------------------- 67 | pg_err_number$ | 22P02 68 | pg_err_mesg$ | invalid input syntax for type bigint: "10.8" 69 | pg_err_optyp$ | D 70 | pg_err_tag$ | daily_load 71 | pg_err_query$ | PREPARE prep_delete (bigint) AS DELETE FROM t1 WHERE a IN ($1); 72 | pg_err_detail$ | ERROR: 22P02: invalid input syntax for type bigint: "10.8" at character 22+ 73 | | STATEMENT: EXECUTE prep_delete ('10.8'); + 74 | | 75 | -[ RECORD 3 ]--+---------------------------------------------------------------------------- 76 | pg_err_number$ | 22P02 77 | pg_err_mesg$ | invalid input syntax for type bigint: "10.9" 78 | pg_err_optyp$ | U 79 | pg_err_tag$ | daily_load 80 | pg_err_query$ | PREPARE prep_update (bigint) AS UPDATE t1 SET a = $1 WHERE a = 2; 81 | pg_err_detail$ | ERROR: 22P02: invalid input syntax for type bigint: "10.9" at character 21+ 82 | | STATEMENT: EXECUTE prep_update('10.9'); + 83 | | 84 | 85 | \x 86 | -- Dropping one of the table 87 | BEGIN; 88 | DROP TABLE testerrlog."errTable"; 89 | SELECT count(*) FROM dbms_errlog.register_errlog_tables ; 90 | count 91 | ------- 92 | 0 93 | (1 row) 94 | 95 | ROLLBACK; 96 | SELECT count(*) FROM dbms_errlog.register_errlog_tables ; 97 | count 98 | ------- 99 | 1 100 | (1 row) 101 | 102 | BEGIN; 103 | DROP TABLE t1; 104 | SELECT count(*) FROM dbms_errlog.register_errlog_tables ; 105 | count 106 | ------- 107 | 0 108 | (1 row) 109 | 110 | ROLLBACK; 111 | SELECT count(*) FROM dbms_errlog.register_errlog_tables ; 112 | count 113 | ------- 114 | 1 115 | (1 row) 116 | 117 | DROP TABLE testerrlog."errTable"; 118 | -------------------------------------------------------------------------------- /expected/03-trig-fct.out: -------------------------------------------------------------------------------- 1 | SET pg_dbms_errlog.synchronous = query; 2 | -- Create the error log table for relation t1 in a dedicated schema 3 | CALL dbms_errlog.create_error_log('public."t1"', 'testerrlog."errTable"'); 4 | SELECT count(*) FROM dbms_errlog.register_errlog_tables ; 5 | count 6 | ------- 7 | 1 8 | (1 row) 9 | 10 | CREATE TABLE t2 (id varchar); 11 | -- Create the trigger that will generate an error, must be logged 12 | CREATE FUNCTION trig_fct() RETURNS TRIGGER AS 13 | $$ 14 | BEGIN 15 | INSERT INTO t2 VALUES (NEW.id); 16 | RETURN NEW; 17 | END; 18 | $$ LANGUAGE plpgsql; 19 | CREATE TRIGGER t1_insert BEFORE INSERT ON t1 FOR EACH ROW EXECUTE PROCEDURE trig_fct(); 20 | -- Set error log behavior for this DML batch 21 | SET pg_dbms_errlog.query_tag TO 'daily_load'; 22 | SET pg_dbms_errlog.reject_limit TO 25; 23 | SET pg_dbms_errlog.enabled TO true; 24 | -- Start a transaction 25 | BEGIN; 26 | -- Insert will fail inside trigger 27 | SAVEPOINT aze; 28 | INSERT INTO t1 VALUES (7); 29 | ROLLBACK TO aze; 30 | DROP TRIGGER t1_insert ON t1; 31 | -- Create a function that execute a failing insert, must not ne logged 32 | CREATE FUNCTION insert_fct() RETURNS integer AS 33 | $$ 34 | BEGIN 35 | INSERT INTO t1 VALUES (1234.45); 36 | RETURN 1; 37 | END; 38 | $$ LANGUAGE plpgsql; 39 | SAVEPOINT aze; 40 | SELECT insert_fct(); 41 | insert_fct 42 | ------------ 43 | 1 44 | (1 row) 45 | 46 | ROLLBACK TO aze; 47 | ROLLBACK; 48 | -- Looking at error logging table 49 | \x 50 | SELECT * FROM testerrlog."errTable" 51 | ORDER BY "pg_err_number$" COLLATE "C", "pg_err_mesg$" COLLATE "C"; 52 | -[ RECORD 1 ]--+------------------------------------------------------------- 53 | pg_err_number$ | 42703 54 | pg_err_mesg$ | record "new" has no field "id" 55 | pg_err_optyp$ | I 56 | pg_err_tag$ | daily_load 57 | pg_err_query$ | INSERT INTO t1 VALUES (7); 58 | pg_err_detail$ | ERROR: 42703: record "new" has no field "id" + 59 | | CONTEXT: SQL statement "INSERT INTO t2 VALUES (NEW.id)" + 60 | | PL/pgSQL function trig_fct() line 3 at SQL statement+ 61 | | STATEMENT: INSERT INTO t1 VALUES (7); + 62 | | 63 | 64 | \x 65 | -- Dropping one of the table 66 | BEGIN; 67 | DROP TABLE testerrlog."errTable"; 68 | SELECT count(*) FROM dbms_errlog.register_errlog_tables ; 69 | count 70 | ------- 71 | 0 72 | (1 row) 73 | 74 | ROLLBACK; 75 | SELECT count(*) FROM dbms_errlog.register_errlog_tables ; 76 | count 77 | ------- 78 | 1 79 | (1 row) 80 | 81 | BEGIN; 82 | DROP TABLE t1; 83 | SELECT count(*) FROM dbms_errlog.register_errlog_tables ; 84 | count 85 | ------- 86 | 0 87 | (1 row) 88 | 89 | ROLLBACK; 90 | SELECT count(*) FROM dbms_errlog.register_errlog_tables ; 91 | count 92 | ------- 93 | 1 94 | (1 row) 95 | 96 | DROP TABLE testerrlog."errTable"; 97 | DROP TRIGGER t1_insert ON t1; 98 | DROP FUNCTION trig_fct; 99 | DROP TABLE t2; 100 | DROP TABLE t1; 101 | -------------------------------------------------------------------------------- /expected/04-partition.out: -------------------------------------------------------------------------------- 1 | SET pg_dbms_errlog.synchronous = query; 2 | CREATE TABLE measurement ( 3 | city_id int not null, 4 | logdate date not null, 5 | peaktemp int, 6 | unitsales int 7 | ) PARTITION BY RANGE (logdate); 8 | CREATE TABLE measurement_y2006m02 PARTITION OF measurement 9 | FOR VALUES FROM ('2006-02-01') TO ('2006-03-01'); 10 | CREATE TABLE measurement_y2006m03 PARTITION OF measurement 11 | FOR VALUES FROM ('2006-03-01') TO ('2006-04-01'); 12 | -- Create the error log table for relation t1 in a dedicated schema 13 | CALL dbms_errlog.create_error_log('public.measurement'); 14 | SELECT count(*) FROM dbms_errlog.register_errlog_tables ; 15 | count 16 | ------- 17 | 1 18 | (1 row) 19 | 20 | -- Set error log behavior for this DML batch 21 | SET pg_dbms_errlog.query_tag TO 'daily_load'; 22 | SET pg_dbms_errlog.reject_limit TO 25; 23 | SET pg_dbms_errlog.enabled TO true; 24 | -- Start a transaction 25 | BEGIN; 26 | -- Insert will fail inside trigger 27 | SAVEPOINT aze; 28 | INSERT INTO measurement VALUES (1, '2006-04-01', 0, 2); 29 | ROLLBACK TO aze; 30 | ROLLBACK; 31 | -- Looking at error logging table 32 | \x 33 | SELECT * FROM "ERR$_measurement" 34 | ORDER BY "pg_err_number$" COLLATE "C", "pg_err_mesg$" COLLATE "C"; 35 | -[ RECORD 1 ]--+----------------------------------------------------------------------------- 36 | pg_err_number$ | 23514 37 | pg_err_mesg$ | no partition of relation "measurement" found for row 38 | pg_err_optyp$ | I 39 | pg_err_tag$ | daily_load 40 | pg_err_query$ | INSERT INTO measurement VALUES (1, '2006-04-01', 0, 2); 41 | pg_err_detail$ | ERROR: 23514: no partition of relation "measurement" found for row + 42 | | DETAIL: Partition key of the failing row contains (logdate) = (04-01-2006).+ 43 | | STATEMENT: INSERT INTO measurement VALUES (1, '2006-04-01', 0, 2); + 44 | | 45 | 46 | \x 47 | -- Dropping one of the table 48 | BEGIN; 49 | DROP TABLE "ERR$_measurement"; 50 | SELECT count(*) FROM dbms_errlog.register_errlog_tables ; 51 | count 52 | ------- 53 | 0 54 | (1 row) 55 | 56 | ROLLBACK; 57 | SELECT count(*) FROM dbms_errlog.register_errlog_tables ; 58 | count 59 | ------- 60 | 1 61 | (1 row) 62 | 63 | BEGIN; 64 | DROP TABLE measurement; 65 | SELECT count(*) FROM dbms_errlog.register_errlog_tables ; 66 | count 67 | ------- 68 | 0 69 | (1 row) 70 | 71 | ROLLBACK; 72 | SELECT count(*) FROM dbms_errlog.register_errlog_tables ; 73 | count 74 | ------- 75 | 1 76 | (1 row) 77 | 78 | DROP TABLE "ERR$_measurement"; 79 | DROP TABLE measurement; 80 | -------------------------------------------------------------------------------- /expected/05-privileges.out: -------------------------------------------------------------------------------- 1 | ------------------------------------------------------------------ 2 | -- Test privilege on errorlog table. A user need to be granted the 3 | -- DML privilege to the table and to the error log table to be able 4 | -- to use this feature. Insert to the registration table is done 5 | -- internally by superuser, to allow a user to create an error logging 6 | -- logging table he must be granted to execute the create_error_log() 7 | -- function and have read/write access to the registration table 8 | -- dbms_errlog.register_errlog_tables. 9 | ---------------------------------------------------------------- 10 | -- Set error log behavior for this DML batch 11 | SET pg_dbms_errlog.synchronous = query; 12 | SET pg_dbms_errlog.query_tag TO 'daily_load1'; 13 | SET pg_dbms_errlog.reject_limit TO 25; 14 | SET pg_dbms_errlog.enabled TO true; 15 | DROP ROLE IF EXISTS pel_u1; 16 | NOTICE: role "pel_u1" does not exist, skipping 17 | CREATE ROLE pel_u1 LOGIN; 18 | CREATE TABLE t2 ( 19 | id int NOT NULL 20 | ); 21 | GRANT ALL ON t2 TO pel_u1; 22 | -- Create the error log table for relation t2 23 | CALL dbms_errlog.create_error_log('t2'); 24 | -- Verify that it have been registered 25 | SELECT count(*) FROM dbms_errlog.register_errlog_tables ; 26 | count 27 | ------- 28 | 1 29 | (1 row) 30 | 31 | -- Start a transaction 32 | BEGIN; 33 | SAVEPOINT aze; 34 | -- Insert will fail with insuffisient privilege and be registered to ERR$_t2 35 | INSERT INTO t2 VALUES (NULL); 36 | ROLLBACK TO aze; 37 | COMMIT; 38 | -- Show content of the error log table with test user. 39 | \x 40 | SELECT * FROM "ERR$_t2" 41 | ORDER BY "pg_err_number$" COLLATE "C", "pg_err_mesg$" COLLATE "C"; 42 | -[ RECORD 1 ]--+--------------------------------------------------------------------------------------- 43 | pg_err_number$ | 23502 44 | pg_err_mesg$ | null value in column "id" of relation "t2" violates not-null constraint 45 | pg_err_optyp$ | I 46 | pg_err_tag$ | daily_load1 47 | pg_err_query$ | INSERT INTO t2 VALUES (NULL); 48 | pg_err_detail$ | ERROR: 23502: null value in column "id" of relation "t2" violates not-null constraint+ 49 | | DETAIL: Failing row contains (null). + 50 | | STATEMENT: INSERT INTO t2 VALUES (NULL); + 51 | | 52 | 53 | \x 54 | -- Cleanup 55 | DELETE FROM "ERR$_t2"; 56 | -- connect as basic user to test privileges 57 | SET SESSION AUTHORIZATION 'pel_u1'; 58 | -- Set error log behavior for this DML batch 59 | SET pg_dbms_errlog.synchronous = query; 60 | SET pg_dbms_errlog.query_tag TO 'daily_load2'; 61 | SET pg_dbms_errlog.reject_limit TO 25; 62 | SET pg_dbms_errlog.enabled TO true; 63 | -- Start a transaction 64 | BEGIN; 65 | SAVEPOINT aze; 66 | -- Insert will fail with insuffisient privilege 67 | -- and nothing is registered on ERR$_t2, not granted 68 | INSERT INTO t2 VALUES (NULL); 69 | ERROR: permission denied for table ERR$_t2 70 | ROLLBACK TO aze; 71 | COMMIT; 72 | -- Not enough privilege 73 | SELECT * FROM "ERR$_t2" 74 | ORDER BY "pg_err_number$" COLLATE "C", "pg_err_mesg$" COLLATE "C"; 75 | ERROR: permission denied for table ERR$_t2 76 | -- Back to origin connection 77 | SET SESSION AUTHORIZATION DEFAULT; 78 | -- Allow user pel_u1 to write to ERR$_t2 79 | GRANT ALL ON "ERR$_t2" TO pel_u1; 80 | -- switch back to test privilege user 81 | SET SESSION AUTHORIZATION 'pel_u1'; 82 | SET pg_dbms_errlog.synchronous = query; 83 | SET pg_dbms_errlog.query_tag TO 'daily_load3'; 84 | SET pg_dbms_errlog.reject_limit TO 25; 85 | SET pg_dbms_errlog.enabled TO true; 86 | -- Show content of the error log table with test user. 0 87 | \x 88 | SELECT * FROM "ERR$_t2" 89 | ORDER BY "pg_err_number$" COLLATE "C", "pg_err_mesg$" COLLATE "C"; 90 | (0 rows) 91 | 92 | \x 93 | -- Start a transaction 94 | BEGIN; 95 | SAVEPOINT aze; 96 | -- Insert will fail and the error will be registered this time 97 | INSERT INTO t2 VALUES (NULL); 98 | ROLLBACK TO aze; 99 | COMMIT; 100 | -- Show content of the error log table with test user. 1 101 | \x 102 | SELECT * FROM "ERR$_t2" 103 | ORDER BY "pg_err_number$" COLLATE "C", "pg_err_mesg$" COLLATE "C"; 104 | -[ RECORD 1 ]--+--------------------------------------------------------------------------------------- 105 | pg_err_number$ | 23502 106 | pg_err_mesg$ | null value in column "id" of relation "t2" violates not-null constraint 107 | pg_err_optyp$ | I 108 | pg_err_tag$ | daily_load3 109 | pg_err_query$ | INSERT INTO t2 VALUES (NULL); 110 | pg_err_detail$ | ERROR: 23502: null value in column "id" of relation "t2" violates not-null constraint+ 111 | | DETAIL: Failing row contains (null). + 112 | | STATEMENT: INSERT INTO t2 VALUES (NULL); + 113 | | 114 | 115 | \x 116 | -- Dropping table is not allowed, it must not be unregistered 117 | DROP TABLE t2; 118 | ERROR: must be owner of table t2 119 | SELECT count(*) FROM dbms_errlog.register_errlog_tables ; -- returns 1 120 | ERROR: permission denied for table register_errlog_tables 121 | -- Back to original connection 122 | SET SESSION AUTHORIZATION DEFAULT; 123 | -- cleanup 124 | DROP TABLE t2; 125 | DROP TABLE "ERR$_t2"; 126 | SELECT count(*) FROM dbms_errlog.register_errlog_tables ; 127 | count 128 | ------- 129 | 0 130 | (1 row) 131 | 132 | ---- 133 | -- Try error logging creation by non superuser role 134 | ---- 135 | CREATE SCHEMA pel_u1; 136 | GRANT ALL ON SCHEMA pel_u1 TO pel_u1; 137 | CREATE TABLE pel_u1.t3 ( 138 | id int NOT NULL 139 | ); 140 | GRANT ALL ON pel_u1.t3 TO pel_u1; 141 | GRANT ALL ON dbms_errlog.register_errlog_tables TO pel_u1; 142 | SET SESSION AUTHORIZATION 'pel_u1'; 143 | SET pg_dbms_errlog.synchronous = query; 144 | SET pg_dbms_errlog.query_tag TO 'daily_load4'; 145 | SET pg_dbms_errlog.reject_limit TO 25; 146 | SET pg_dbms_errlog.enabled TO true; 147 | -- Create the error log table for relation pel_u1.t3 as non superuser role 148 | CALL dbms_errlog.create_error_log('pel_u1.t3', 'pel_u1."ERR$_t3"'); 149 | -- Verify that it have been registered 150 | SELECT count(*) FROM dbms_errlog.register_errlog_tables ; 151 | count 152 | ------- 153 | 1 154 | (1 row) 155 | 156 | -- Start a transaction 157 | BEGIN; 158 | SAVEPOINT aze; 159 | -- Insert will fail for NULL value and will be registered in pel_u1.ERR$_t3 160 | INSERT INTO pel_u1.t3 VALUES (NULL); 161 | ROLLBACK TO aze; 162 | COMMIT; 163 | -- Show content of the error log table with test user. 164 | \x 165 | SELECT * FROM pel_u1."ERR$_t3" 166 | ORDER BY "pg_err_number$" COLLATE "C", "pg_err_mesg$" COLLATE "C"; 167 | -[ RECORD 1 ]--+--------------------------------------------------------------------------------------- 168 | pg_err_number$ | 23502 169 | pg_err_mesg$ | null value in column "id" of relation "t3" violates not-null constraint 170 | pg_err_optyp$ | I 171 | pg_err_tag$ | daily_load4 172 | pg_err_query$ | INSERT INTO pel_u1.t3 VALUES (NULL); 173 | pg_err_detail$ | ERROR: 23502: null value in column "id" of relation "t3" violates not-null constraint+ 174 | | DETAIL: Failing row contains (null). + 175 | | STATEMENT: INSERT INTO pel_u1.t3 VALUES (NULL); + 176 | | 177 | 178 | \x 179 | -- cleanup 180 | DROP TABLE pel_u1.t3; -- will fail 181 | ERROR: must be owner of table t3 182 | DROP TABLE pel_u1."ERR$_t3"; -- will be dropped 183 | SELECT count(*) FROM dbms_errlog.register_errlog_tables ; 184 | count 185 | ------- 186 | 0 187 | (1 row) 188 | 189 | SET SESSION AUTHORIZATION DEFAULT; 190 | DROP TABLE pel_u1.t3; 191 | DROP SCHEMA pel_u1; 192 | SELECT count(*) FROM dbms_errlog.register_errlog_tables ; 193 | count 194 | ------- 195 | 0 196 | (1 row) 197 | 198 | REVOKE ALL ON dbms_errlog.register_errlog_tables FROM pel_u1; 199 | DROP ROLE pel_u1; 200 | -------------------------------------------------------------------------------- /include/pel_errqueue.h: -------------------------------------------------------------------------------- 1 | /*------------------------------------------------------------------------- 2 | * 3 | * pel_errrqueue.h: 4 | * Implementation of error logging queue in dynshm. 5 | * 6 | * This program is open source, licensed under the PostgreSQL license. 7 | * For license terms, see the LICENSE file. 8 | * 9 | * Copyright (C) 2021: MigOps Inc 10 | * 11 | *------------------------------------------------------------------------- 12 | */ 13 | 14 | #ifndef _PEL_ERRORQUEUE_H 15 | #define _PEL_ERRORQUEUE_H 16 | 17 | #include "postgres.h" 18 | 19 | #include "nodes/nodes.h" 20 | 21 | #define PEL_PUBLISH_ERROR -1 22 | #define PEL_PUBLISH_EMPTY -2 23 | 24 | typedef struct pelWorkerError 25 | { 26 | Oid err_relid; 27 | int sqlstate; 28 | char *errmessage; 29 | char cmdtype; 30 | char *query_tag; 31 | char *sql; 32 | char *detail; 33 | } pelWorkerError; 34 | 35 | typedef struct pelWorkerEntry 36 | { 37 | Oid dbid; 38 | int pgprocno; 39 | int num_errors; 40 | pelWorkerError *errors; 41 | } pelWorkerEntry; 42 | 43 | Oid pel_get_queue_item_dbid(int pos); 44 | pelWorkerEntry *pel_get_worker_entry(int pos); 45 | void pel_worker_entry_complete(void); 46 | void pel_init_dsm(bool isMainBgworker); 47 | bool pel_queue_error(Oid err_relid, int sqlstate, char *errmessage, 48 | char cmdtype, const char *query_tag, const char *sql, 49 | const char *detail, bool sync); 50 | void pel_discard_queue(void); 51 | int pel_publish_queue(bool async); 52 | int pel_queue_size(void); 53 | 54 | #endif 55 | -------------------------------------------------------------------------------- /include/pel_worker.h: -------------------------------------------------------------------------------- 1 | /*------------------------------------------------------------------------- 2 | * 3 | * pel_worker.h: 4 | * Implementation of bgworker for error queue processing. 5 | * 6 | * This program is open source, licensed under the PostgreSQL license. 7 | * For license terms, see the LICENSE file. 8 | * 9 | * Copyright (C) 2021: MigOps Inc 10 | * 11 | *------------------------------------------------------------------------- 12 | */ 13 | 14 | #ifndef _PEL_WORKER_H 15 | #define _PEL_WORKER_H 16 | 17 | #include "postgres.h" 18 | 19 | #if PG_VERSION_NUM >= 100000 20 | PGDLLEXPORT void pel_worker_main(Datum main_arg) pg_attribute_noreturn(); 21 | PGDLLEXPORT void pel_dynworker_main(Datum main_arg); 22 | #endif /* pg10 */ 23 | #endif /* _PEL_WORKER_H */ 24 | -------------------------------------------------------------------------------- /include/pg_dbms_errlog.h: -------------------------------------------------------------------------------- 1 | /*------------------------------------------------------------------------- 2 | * 3 | * pg_dbms_errlog.h: 4 | * pg_dbms_errlog is a PostgreSQL extension that logs each failing DML 5 | * query. It emulates the DBMS_ERRLOG Oracle module. 6 | * 7 | * This program is open source, licensed under the PostgreSQL license. 8 | * For license terms, see the LICENSE file. 9 | * 10 | * Copyright (C) 2021: MigOps Inc 11 | * 12 | *------------------------------------------------------------------------- 13 | */ 14 | 15 | #ifndef _PEL_H 16 | #define _PEL_H 17 | 18 | #include "postgres.h" 19 | 20 | #include "storage/lwlock.h" 21 | #include "utils/dsa.h" 22 | 23 | #if PG_VERSION_NUM < 120000 24 | #define table_open(r,l) heap_open(r,l) 25 | #define table_openrv(r,l) heap_openrv(r,l) 26 | #define table_close(r,l) heap_close(r,l) 27 | #endif 28 | 29 | #define PEL_NAMESPACE_NAME "dbms_errlog" 30 | 31 | #if PG_VERSION_NUM >= 100000 32 | 33 | #define PEL_POS_PREV(pos) ( ((pos) == 0) ? pel->max_errs : (pos) - 1) 34 | #define PEL_POS_NEXT(pos) ( ((pos) >= pel->max_errs) ? 0 : (pos) + 1) 35 | 36 | #define PEL_DEBUG (pel_debug ? WARNING : DEBUG1) 37 | 38 | /* Global shared state */ 39 | typedef struct pelSharedState { 40 | int bgw_saved_cur; /* upper limit for dynbgworker, only written in 41 | the main bgworker.*/ 42 | pg_atomic_uint32 bgw_procno; 43 | int max_errs; 44 | LWLock *lock; /* protects the following fields only */ 45 | int LWTRANCHE_PEL; 46 | dsa_handle pel_dsa_handle; 47 | dsa_pointer pqueue; /* pointer to pelGlobalQueue */ 48 | int cur_err; 49 | int bgw_err; 50 | } pelSharedState; 51 | 52 | /* Links to shared memory state */ 53 | extern pelSharedState *pel; 54 | extern dsa_area *pel_area; 55 | #endif 56 | 57 | /* GUC variables */ 58 | extern bool pel_debug; 59 | extern int pel_frequency; 60 | extern int pel_max_workers; 61 | extern int pel_reject_limit; 62 | 63 | #endif 64 | -------------------------------------------------------------------------------- /pel_errqueue.c: -------------------------------------------------------------------------------- 1 | /*------------------------------------------------------------------------- 2 | * 3 | * pel_errrqueue.c: 4 | * Implementation of error logging queue in dynshm. 5 | * 6 | * This program is open source, licensed under the PostgreSQL license. 7 | * For license terms, see the LICENSE file. 8 | * 9 | * Copyright (C) 2021-2022: MigOps Inc 10 | * 11 | *------------------------------------------------------------------------- 12 | */ 13 | 14 | #include "postgres.h" 15 | 16 | #if PG_VERSION_NUM >= 100000 17 | 18 | #include "miscadmin.h" 19 | #include "storage/lwlock.h" 20 | #include "storage/proc.h" 21 | #include "tcop/tcopprot.h" 22 | #include "utils/dsa.h" 23 | #include "utils/lsyscache.h" 24 | #include "utils/memutils.h" 25 | #if PG_VERSION_NUM >= 140000 26 | #include "utils/wait_event.h" 27 | #else 28 | #include "pgstat.h" 29 | #endif 30 | #include "include/pg_dbms_errlog.h" 31 | #include "include/pel_errqueue.h" 32 | 33 | #define PEL_QUEUE_SIZE 1000 /* XXX alow queue size to grow? */ 34 | #define PEL_ENTRY_INIT_SIZE 50 35 | 36 | typedef struct pelError 37 | { 38 | Oid err_relid; 39 | int sqlstate; 40 | dsa_pointer perrmessage; 41 | char cmdtype; 42 | dsa_pointer pquery_tag; 43 | dsa_pointer psql; 44 | dsa_pointer pdetail; 45 | } pelError; 46 | 47 | typedef struct pelQueueEntry 48 | { 49 | int num_entries; 50 | int max_entries; 51 | dsa_pointer perrors; /* array of pelError */ 52 | } pelQueueEntry; 53 | 54 | typedef struct pelGlobalEntry 55 | { 56 | Oid dbid; 57 | int pgprocno; 58 | dsa_handle handle; 59 | dsa_pointer pentry; /* store a pelQueueEntry */ 60 | bool notify; 61 | bool processed; 62 | } pelGlobalEntry; 63 | 64 | typedef struct pelGlobalQueue 65 | { 66 | pelGlobalEntry *entries; /* used as token ring */ 67 | } pelGlobalQueue; 68 | 69 | /* 70 | * Struct containing reference to the current local entry, used in a global 71 | * variable 72 | */ 73 | typedef struct pelLocalData 74 | { 75 | dsa_area *area; 76 | dsa_pointer pentry; 77 | pelQueueEntry *entry; 78 | pelError *errors; 79 | int pos; /* offset of the entry in queue.entries, -1 if no local 80 | entry */ 81 | int last_pos; /* offset of the last queued and not processed entry, -1 if 82 | none */ 83 | } pelLocalData; 84 | 85 | /* Local variables */ 86 | static pelGlobalQueue queue = { 0 }; 87 | 88 | static pelLocalData local_data = { NULL, InvalidDsaPointer, NULL, NULL, -1, -1 }; 89 | 90 | /* Functions declaration */ 91 | static void pel_attach_dsa(bool globalOnly); 92 | static void pel_setup_local_area(dsm_handle handle); 93 | static void pel_attach_entry(dsa_pointer pentry); 94 | static bool pel_prepare_entry(void); 95 | static void pel_cleanup_local(void); 96 | 97 | /* Create or attach to dsa and allocate the global queue if needed. 98 | * 99 | * can throw an error if the global queue can't be allocated 100 | */ 101 | static void 102 | pel_attach_dsa(bool globalOnly) 103 | { 104 | MemoryContext oldcontext; 105 | 106 | Assert(!LWLockHeldByMe(pel->lock)); 107 | 108 | /* Nothing to do if we're already attached to the dsa. */ 109 | if (pel_area != NULL && (globalOnly || local_data.area != NULL)) 110 | return; 111 | 112 | oldcontext = MemoryContextSwitchTo(TopMemoryContext); 113 | 114 | LWLockAcquire(pel->lock, LW_EXCLUSIVE); 115 | if (pel->pel_dsa_handle == DSM_HANDLE_INVALID) 116 | { 117 | pel_area = dsa_create(pel->LWTRANCHE_PEL); 118 | dsa_pin(pel_area); 119 | dsa_pin_mapping(pel_area); 120 | pel->pel_dsa_handle = dsa_get_handle(pel_area); 121 | } 122 | else if (pel_area == NULL) 123 | { 124 | pel_area = dsa_attach(pel->pel_dsa_handle); 125 | dsa_pin_mapping(pel_area); 126 | } 127 | 128 | MemoryContextSwitchTo(oldcontext); 129 | 130 | if (pel->pqueue == InvalidDsaPointer) 131 | { 132 | Assert(queue.entries == NULL); 133 | pel->pqueue = dsa_allocate_extended(pel_area, 134 | sizeof(pelGlobalEntry) * PEL_QUEUE_SIZE, DSA_ALLOC_ZERO); 135 | pel->max_errs = PEL_QUEUE_SIZE; 136 | queue.entries = dsa_get_address(pel_area, pel->pqueue); 137 | } 138 | else if (queue.entries == NULL) 139 | { 140 | Assert(pel->pqueue != InvalidDsaPointer); 141 | 142 | queue.entries = dsa_get_address(pel_area, pel->pqueue); 143 | } 144 | 145 | Assert(pel->pqueue != InvalidDsaPointer && queue.entries != NULL); 146 | 147 | LWLockRelease(pel->lock); 148 | 149 | if (globalOnly) 150 | return; 151 | 152 | if (local_data.area == NULL) 153 | pel_setup_local_area(InvalidDsaPointer); 154 | } 155 | 156 | /* 157 | * Only create or attach to the local area, the rest of the data will be setup 158 | * in pel_prepare_entry() or pel_attach_entry(). 159 | */ 160 | static void 161 | pel_setup_local_area(dsm_handle handle) 162 | { 163 | MemoryContext oldcontext; 164 | 165 | Assert(local_data.area == NULL); 166 | Assert(local_data.entry == NULL); 167 | Assert(local_data.pentry == InvalidDsaPointer); 168 | Assert(local_data.errors == NULL); 169 | 170 | if (handle == DSM_HANDLE_INVALID) 171 | { 172 | /* This area will only be pinned when published */ 173 | /* FIXME: use a dedicated context under TopTransactionContext */ 174 | oldcontext = MemoryContextSwitchTo(TopMemoryContext); 175 | local_data.area = dsa_create(pel->LWTRANCHE_PEL); 176 | MemoryContextSwitchTo(oldcontext); 177 | } 178 | else 179 | { 180 | oldcontext = MemoryContextSwitchTo(TopMemoryContext); 181 | local_data.area = dsa_attach(handle); 182 | MemoryContextSwitchTo(oldcontext); 183 | } 184 | dsa_pin_mapping(local_data.area); 185 | } 186 | 187 | static void 188 | pel_attach_entry(dsa_pointer pentry) 189 | { 190 | Assert(local_data.area != NULL); 191 | Assert(local_data.pentry == InvalidDsaPointer); 192 | Assert(local_data.entry == NULL); 193 | Assert(local_data.errors == NULL); 194 | 195 | local_data.pentry = pentry; 196 | local_data.entry = dsa_get_address(local_data.area, local_data.pentry); 197 | local_data.errors = dsa_get_address(local_data.area, 198 | local_data.entry->perrors); 199 | } 200 | 201 | /* Create a pelQueueEntry or make room for a new error */ 202 | static bool 203 | pel_prepare_entry(void) 204 | { 205 | Assert(!LWLockHeldByMe(pel->lock)); 206 | pel_attach_dsa(false); 207 | 208 | if (local_data.pentry == InvalidDsaPointer) 209 | { 210 | if (pel_reject_limit == 0) 211 | { 212 | elog(WARNING, "pg_dbms_errlog.reject_limit is set to 0, no error" 213 | " is handled"); 214 | return false; 215 | } 216 | 217 | local_data.pentry = dsa_allocate_extended(local_data.area, sizeof(pelQueueEntry), 218 | DSA_ALLOC_ZERO | DSA_ALLOC_NO_OOM); 219 | 220 | if (!local_data.pentry) 221 | { 222 | pel_cleanup_local(); 223 | return false; 224 | } 225 | 226 | local_data.pos = -1; 227 | } 228 | 229 | local_data.entry = dsa_get_address(local_data.area, local_data.pentry); 230 | 231 | if (pel_reject_limit > -1 && 232 | local_data.entry->num_entries >= pel_reject_limit ) 233 | { 234 | elog(WARNING, "pg_dbms_errlog.reject_limit (%d) is reached (queue_entries=%d), no further" 235 | " error is handled", pel_reject_limit, local_data.entry->num_entries); 236 | pel_cleanup_local(); 237 | return false; 238 | } 239 | 240 | /* init or grow the entry if needed */ 241 | if (local_data.entry->max_entries == 0 || 242 | local_data.entry->num_entries >= local_data.entry->max_entries) 243 | { 244 | bool do_init = (local_data.entry->max_entries == 0); 245 | 246 | Assert( 247 | (local_data.entry->num_entries == 0 && 248 | local_data.entry->perrors == InvalidDsaPointer 249 | ) || 250 | (local_data.entry->num_entries != 0 && 251 | local_data.entry->perrors != InvalidDsaPointer) 252 | ); 253 | 254 | /* FIXME implement the memory size limit */ 255 | if (local_data.entry->max_entries == 0) 256 | local_data.entry->max_entries = PEL_ENTRY_INIT_SIZE; 257 | else 258 | local_data.entry->max_entries *= 2; 259 | 260 | if (do_init) 261 | { 262 | Assert(local_data.errors == NULL); 263 | Assert(local_data.entry->perrors == InvalidDsaPointer); 264 | 265 | local_data.entry->perrors = dsa_allocate_extended(local_data.area, 266 | sizeof(pelError) * local_data.entry->max_entries, 267 | DSA_ALLOC_NO_OOM); 268 | 269 | if (local_data.entry->perrors == InvalidDsaPointer) 270 | { 271 | pel_cleanup_local(); 272 | return false; 273 | } 274 | 275 | local_data.errors = dsa_get_address(local_data.area, 276 | local_data.entry->perrors); 277 | } 278 | else 279 | { 280 | dsa_pointer new_perrors = InvalidDsaPointer; 281 | pelError *new_errors; 282 | 283 | Assert(local_data.entry != NULL); 284 | 285 | new_perrors = dsa_allocate_extended(local_data.area, 286 | sizeof(pelError) * local_data.entry->max_entries, DSA_ALLOC_NO_OOM); 287 | 288 | if (new_perrors == InvalidDsaPointer) 289 | { 290 | pel_cleanup_local(); 291 | return false; 292 | } 293 | 294 | new_errors = dsa_get_address(local_data.area, new_perrors); 295 | 296 | memcpy(new_errors, local_data.entry, sizeof(pelError) * local_data.entry->num_entries); 297 | 298 | local_data.entry = NULL; 299 | dsa_free(local_data.area, local_data.entry->perrors); 300 | local_data.entry->perrors = new_perrors; 301 | local_data.errors = new_errors; 302 | } 303 | } 304 | 305 | Assert(local_data.entry != NULL); 306 | Assert(local_data.errors != NULL); 307 | return true; 308 | } 309 | 310 | /* 311 | * Cleanup local variables and detach from the local area. 312 | */ 313 | static void 314 | pel_cleanup_local() 315 | { 316 | Assert(local_data.area != NULL); 317 | 318 | local_data.pentry = InvalidDsaPointer; 319 | local_data.entry = NULL; 320 | local_data.errors = NULL; 321 | local_data.pos = -1; 322 | 323 | /* 324 | * dsa_detach will free the local memory allocated in dsa_create() if the 325 | * area isn't pinned. 326 | */ 327 | dsa_detach(local_data.area); 328 | 329 | local_data.area = NULL; 330 | } 331 | 332 | /* Discard errors cached in dyn shm not yet published, if any */ 333 | void pel_discard_queue(void) 334 | { 335 | pel_attach_dsa(false); 336 | 337 | pel_cleanup_local(); 338 | } 339 | 340 | /* Publish the pelError in the global queue. 341 | * 342 | * If sync is true, it wakes up the bgworker and wait for it to process all 343 | * queued entries until the one we just published. 344 | */ 345 | int 346 | pel_publish_queue(bool sync) 347 | { 348 | int pos; 349 | 350 | pel_attach_dsa(false); 351 | Assert(queue.entries != NULL); 352 | 353 | /* No work queued */ 354 | if(local_data.pentry == InvalidDsaPointer) 355 | { 356 | pel_cleanup_local(); 357 | 358 | /* 359 | * If there wasn't any previously queued work or if it's async mode, 360 | * return immediately. 361 | */ 362 | if (local_data.last_pos < 0 || !sync) 363 | { 364 | elog(PEL_DEBUG, "pel_publish_queue(): no queued work or async mode (%d)", sync); 365 | return PEL_PUBLISH_EMPTY; 366 | } 367 | 368 | /* Restore the last known queue entry position */ 369 | pos = local_data.last_pos; 370 | elog(PEL_DEBUG, "pel_publish_queue(): restore the last known queue entry position %d", pos); 371 | LWLockAcquire(pel->lock, LW_EXCLUSIVE); 372 | /* 373 | * Check if the entry in that position is still ours. If yes, ask to 374 | * be notify, otherwise we know it was already processed so we can 375 | * inform caller. 376 | */ 377 | if (queue.entries[pos].pgprocno == MyProc->pgprocno) 378 | queue.entries[pos].notify = true; 379 | else 380 | local_data.last_pos = -1; 381 | LWLockRelease(pel->lock); 382 | 383 | if (local_data.last_pos == -1) 384 | return PEL_PUBLISH_EMPTY; 385 | 386 | goto wait_for_bgworker; 387 | } 388 | 389 | Assert(!LWLockHeldByMe(pel->lock)); 390 | LWLockAcquire(pel->lock, LW_EXCLUSIVE); 391 | 392 | /* bail out if nothing is queued */ 393 | if (local_data.entry->num_entries == 0) 394 | { 395 | LWLockRelease(pel->lock); 396 | pel_cleanup_local(); 397 | goto error; 398 | } 399 | 400 | /* check if there's enough room to store the entry */ 401 | if (pel->cur_err != pel->bgw_err) 402 | { 403 | if (PEL_POS_NEXT(pel->cur_err) == pel->bgw_err) 404 | { 405 | /* no more room, too bad */ 406 | LWLockRelease(pel->lock); 407 | pel_cleanup_local(); 408 | goto error; 409 | } 410 | } 411 | 412 | pos = PEL_POS_NEXT(pel->cur_err); 413 | 414 | local_data.last_pos = pos; 415 | 416 | queue.entries[pos].dbid = MyDatabaseId; 417 | queue.entries[pos].pgprocno = MyProc->pgprocno; 418 | queue.entries[pos].handle = dsa_get_handle(local_data.area); 419 | queue.entries[pos].pentry = local_data.pentry; 420 | queue.entries[pos].notify = sync; 421 | queue.entries[pos].processed = false; 422 | 423 | /* We transfer the area to the queue, so make it long lived */ 424 | dsa_pin(local_data.area); 425 | 426 | /* 427 | * XXX is an error happens here we'll leak the memory forever. Should we 428 | * first make the entry visible and handle a possibly freed area? 429 | */ 430 | 431 | /* And make it visible in the global queue */ 432 | pel->cur_err = pos; 433 | 434 | LWLockRelease(pel->lock); 435 | 436 | /* And reset local variables */ 437 | pel_cleanup_local(); 438 | 439 | wait_for_bgworker: 440 | elog(PEL_DEBUG, "pel_publish_queue(): wait_for_bgworker, sync: %d", sync); 441 | Assert(!LWLockHeldByMe(pel->lock)); 442 | 443 | if (sync == true) 444 | { 445 | uint32 bgw_procno = pg_atomic_read_u32(&pel->bgw_procno); 446 | int sleep_time = 1; 447 | bool processed; 448 | 449 | while (bgw_procno == INVALID_PGPROCNO) 450 | { 451 | /* 452 | * If we're in the middle of an error interruption, interrupts will 453 | * be held, so we'll have to detect a cancel or terminate pending 454 | * and act accordingly. 455 | */ 456 | if (InterruptHoldoffCount > 0) 457 | { 458 | if (QueryCancelPending || ProcDiePending) 459 | goto error; 460 | } 461 | else 462 | CHECK_FOR_INTERRUPTS(); 463 | 464 | elog(PEL_DEBUG, "pel_publish_queue(): WaitLatch for %d", sleep_time); 465 | WaitLatch(&MyProc->procLatch, 466 | WL_LATCH_SET | WL_TIMEOUT | WL_POSTMASTER_DEATH, 467 | sleep_time, 468 | PG_WAIT_EXTENSION); 469 | ResetLatch(&MyProc->procLatch); 470 | 471 | sleep_time = Max(sleep_time * 2, 100); 472 | 473 | bgw_procno = pg_atomic_read_u32(&pel->bgw_procno); 474 | } 475 | 476 | /* Wake up the bgworker to force queue processing */ 477 | elog(PEL_DEBUG, "pel_publish_queue(): set bgworker latch (procno: %d)", 478 | bgw_procno); 479 | SetLatch(&ProcGlobal->allProcs[bgw_procno].procLatch); 480 | 481 | /* 482 | * And sleep until the launched dynamic bgworker wakes us. 483 | */ 484 | elog(PEL_DEBUG, "pel_publish_queue(): sleep until the launched dynamic" 485 | " bgworker wakes us, procno: %d", MyProc->pgprocno); 486 | processed = false; 487 | while (!processed) 488 | { 489 | int rc; 490 | 491 | rc = WaitLatch(&MyProc->procLatch, 492 | WL_TIMEOUT | WL_LATCH_SET | WL_POSTMASTER_DEATH, 493 | 1000, 494 | PG_WAIT_EXTENSION); 495 | ResetLatch(&MyProc->procLatch); 496 | elog(PEL_DEBUG, "pel_publish_queue() woke up, rc: %d" 497 | " (procno: %d)", rc, MyProc->pgprocno); 498 | 499 | /* 500 | * If we're in the middle of an error interruption, interrupts will 501 | * be held, so we'll have to detect a cancel or terminate pending 502 | * and act accordingly. 503 | */ 504 | if (InterruptHoldoffCount > 0) 505 | { 506 | if (QueryCancelPending || ProcDiePending) 507 | goto error; 508 | } 509 | else 510 | CHECK_FOR_INTERRUPTS(); 511 | 512 | if (rc == WL_POSTMASTER_DEATH) 513 | goto error; 514 | 515 | /* bgworker restarted */ 516 | if (pg_atomic_read_u32(&pel->bgw_procno) != bgw_procno) 517 | { 518 | bgw_procno = pg_atomic_read_u32(&pel->bgw_procno); 519 | elog(PEL_DEBUG, "pel_publish_queue(): bgworker restarted" 520 | " (procno: %d)", bgw_procno); 521 | continue; 522 | } 523 | 524 | LWLockAcquire(pel->lock, LW_SHARED); 525 | /* 526 | * Check if the item is processed. Note that while unlikely it's 527 | * possible the system consumed the whole queue entries and the 528 | * entry at the given position now belongs to another backend. 529 | */ 530 | elog(PEL_DEBUG, "pel_publish_queue(): Checking if item at pos %d is processed %d (queue.pgprocno: %d / MyProc->pgprocno: %d.", pos, queue.entries[pos].processed, queue.entries[pos].pgprocno, MyProc->pgprocno); 531 | processed = (queue.entries[pos].processed || 532 | queue.entries[pos].pgprocno != MyProc->pgprocno); 533 | LWLockRelease(pel->lock); 534 | 535 | /* There won't be any need to check for that entry anymore */ 536 | if (processed) 537 | local_data.last_pos = -1; 538 | 539 | elog(PEL_DEBUG, "pel_publish_queue(): queue entry %d processed last_pos = %d", pos, local_data.last_pos); 540 | } 541 | } 542 | 543 | return pos; 544 | 545 | error: 546 | elog(PEL_DEBUG, "pel_publish_queue(): error, returning invalid pos %d", PEL_PUBLISH_ERROR); 547 | local_data.last_pos = -1; 548 | return PEL_PUBLISH_ERROR; 549 | } 550 | 551 | int pel_queue_size(void) 552 | { 553 | if(local_data.pentry == InvalidDsaPointer) 554 | return -1; 555 | 556 | return local_data.entry->num_entries; 557 | } 558 | 559 | Oid 560 | pel_get_queue_item_dbid(int pos) 561 | { 562 | Assert(LWLockHeldByMe(pel->lock)); 563 | Assert(pos < PEL_QUEUE_SIZE); 564 | 565 | Assert(pel->pqueue != InvalidDsaPointer && queue.entries != NULL); 566 | 567 | return queue.entries[pos].dbid; 568 | } 569 | 570 | /* 571 | * Clean the pelLocalData corresponding to a previous call of 572 | * pel_get_worker_entry(). 573 | */ 574 | void 575 | pel_worker_entry_complete(void) 576 | { 577 | int pgprocno; 578 | 579 | Assert(!LWLockHeldByMe(pel->lock)); 580 | Assert(local_data.pos >= 0); 581 | 582 | elog(PEL_DEBUG, "pel_worker_entry_complete(): Mark the entry as processed"); 583 | LWLockAcquire(pel->lock, LW_EXCLUSIVE); 584 | 585 | /* Mark the entry as processed */ 586 | queue.entries[local_data.pos].processed = true; 587 | if (queue.entries[local_data.pos].notify) 588 | pgprocno = queue.entries[local_data.pos].pgprocno; 589 | else 590 | pgprocno = INVALID_PGPROCNO; 591 | LWLockRelease(pel->lock); 592 | 593 | elog(PEL_DEBUG, "pel_worker_entry_complete(): notify caller %d if it was required after releasing pel->lock", pgprocno); 594 | /* Notify caller if it was required after releasing pel->lock */ 595 | if (pgprocno != INVALID_PGPROCNO) 596 | SetLatch(&ProcGlobal->allProcs[pgprocno].procLatch); 597 | 598 | /* Finally clean all local data structures */ 599 | pel_cleanup_local(); 600 | } 601 | 602 | /* 603 | * Return a pelWorkerEntry for the given position. 604 | * 605 | * This is done setting up pelLocalData with the entry at the given position. 606 | * 607 | * This should be called by dynamic background worker only, and 608 | * pel_clear_worker_entry() should be called once work is finished with the 609 | * given entry. 610 | */ 611 | pelWorkerEntry * 612 | pel_get_worker_entry(int pos) 613 | { 614 | pelWorkerEntry *result = (pelWorkerEntry *) palloc(sizeof(pelWorkerEntry)); 615 | pelGlobalEntry global; 616 | int num_entries, i; 617 | 618 | Assert(!LWLockHeldByMe(pel->lock)); 619 | Assert(pos < PEL_QUEUE_SIZE); 620 | 621 | /* We'll reattach on a specific local_data.area */ 622 | pel_attach_dsa(true); 623 | Assert(pel->pqueue != InvalidDsaPointer && queue.entries != NULL); 624 | 625 | LWLockAcquire(pel->lock, LW_SHARED); 626 | 627 | global = queue.entries[pos]; 628 | Assert(OidIsValid(global.dbid)); 629 | 630 | Assert(global.handle != DSM_HANDLE_INVALID); 631 | Assert(global.pentry != InvalidDsaPointer); 632 | 633 | pel_setup_local_area(global.handle); 634 | pel_attach_entry(global.pentry); 635 | 636 | /* Remember the position for pel_worker_entry_complete() */ 637 | local_data.pos = pos; 638 | 639 | Assert(local_data.entry->num_entries > 0); 640 | num_entries = local_data.entry->num_entries; 641 | 642 | local_data.errors = dsa_get_address(local_data.area, local_data.entry->perrors); 643 | 644 | /* 645 | * None of the underlying dynshm should be changed until caller process the 646 | * data and the bgworker release it. 647 | */ 648 | LWLockRelease(pel->lock); 649 | 650 | result->dbid = global.dbid; 651 | result->pgprocno = global.pgprocno; 652 | result->num_errors = num_entries; 653 | result->errors = (pelWorkerError *) palloc(sizeof(pelWorkerError) * num_entries); 654 | for (i = 0; i < num_entries; i++) 655 | { 656 | pelError *error = &local_data.errors[i]; 657 | char *msg = dsa_get_address(local_data.area, error->perrmessage); 658 | char *sql = dsa_get_address(local_data.area, error->psql); 659 | char *query_tag; 660 | char *detail; 661 | int lenmsg; 662 | int lensql; 663 | int lenquery_tag; 664 | int lendetail; 665 | 666 | if (error->pquery_tag != InvalidDsaPointer) 667 | { 668 | query_tag = dsa_get_address(local_data.area, error->pquery_tag); 669 | lenquery_tag = strlen(query_tag); 670 | } 671 | else 672 | lenquery_tag = 0; 673 | 674 | if (error->pdetail != InvalidDsaPointer) 675 | { 676 | detail = dsa_get_address(local_data.area, error->pdetail); 677 | lendetail = strlen(detail); 678 | } 679 | else 680 | lendetail = 0; 681 | 682 | Assert(msg != NULL && sql != NULL); 683 | lenmsg = strlen(msg); 684 | lensql = strlen(sql); 685 | 686 | Assert(lenmsg > 0 && lensql > 0); 687 | 688 | result->errors[i].err_relid = error->err_relid; 689 | result->errors[i].sqlstate = error->sqlstate; 690 | 691 | result->errors[i].errmessage = (char *) palloc(lenmsg + 1); 692 | strncpy(result->errors[i].errmessage, msg, lenmsg); 693 | result->errors[i].errmessage[lenmsg] = '\0'; 694 | 695 | result->errors[i].cmdtype = error->cmdtype; 696 | 697 | if (lenquery_tag > 0) 698 | { 699 | result->errors[i].query_tag = (char *) palloc(lenquery_tag + 1); 700 | strncpy(result->errors[i].query_tag, query_tag, lenquery_tag); 701 | result->errors[i].query_tag[lenquery_tag] = '\0'; 702 | } 703 | else 704 | result->errors[i].query_tag = NULL; 705 | 706 | result->errors[i].sql = (char *) palloc(lensql + 1); 707 | strncpy(result->errors[i].sql, sql, lensql); 708 | result->errors[i].sql[lensql] = '\0'; 709 | 710 | if (lendetail > 0) 711 | { 712 | result->errors[i].detail = (char *) palloc(lendetail + 1); 713 | strncpy(result->errors[i].detail, detail, lendetail); 714 | result->errors[i].detail[lendetail] = '\0'; 715 | } 716 | else 717 | result->errors[i].detail = NULL; 718 | } 719 | 720 | return result; 721 | } 722 | 723 | void 724 | pel_init_dsm(bool isMainBgworker) 725 | { 726 | pel_attach_dsa(isMainBgworker); 727 | } 728 | 729 | bool 730 | pel_queue_error(Oid err_relid, int sqlstate, char *errmessage, char cmdtype, 731 | const char *query_tag, const char *sql, const char *detail, bool sync) 732 | { 733 | pelError *error; 734 | char *tmp; 735 | Size len; 736 | 737 | Assert(errmessage != NULL); 738 | Assert(sql != NULL); 739 | 740 | if (!pel_prepare_entry()) 741 | return false; 742 | 743 | Assert(local_data.area != NULL); 744 | 745 | Assert(local_data.entry->num_entries < local_data.entry->max_entries); 746 | 747 | error = &local_data.errors[local_data.entry->num_entries]; 748 | 749 | error->err_relid = err_relid; 750 | error->sqlstate = sqlstate; 751 | 752 | len = strlen(errmessage); 753 | error->perrmessage = dsa_allocate_extended(local_data.area, len + 1, 754 | DSA_ALLOC_NO_OOM); 755 | if (error->perrmessage == InvalidDsaPointer) 756 | { 757 | elog(WARNING, "pel_queue_error(): can not extend queue for %ld bytes, errmsg: %s", 758 | len+1, errmessage); 759 | pel_cleanup_local(); 760 | return false; 761 | } 762 | tmp = dsa_get_address(local_data.area, error->perrmessage); 763 | memcpy(tmp, errmessage, len); 764 | tmp[len] = '\0'; 765 | 766 | error->cmdtype = cmdtype; 767 | 768 | if (query_tag) 769 | { 770 | len = strlen(query_tag); 771 | error->pquery_tag = dsa_allocate_extended(local_data.area, len + 1, 772 | DSA_ALLOC_NO_OOM); 773 | if (error->pquery_tag == InvalidDsaPointer) 774 | { 775 | elog(WARNING, "pel_queue_error(): can not extend queue for %ld bytes, query_tag: %s", 776 | len+1, errmessage); 777 | pel_cleanup_local(); 778 | return false; 779 | } 780 | tmp = dsa_get_address(local_data.area, error->pquery_tag); 781 | memcpy(tmp, query_tag, len); 782 | tmp[len] = '\0'; 783 | } 784 | else 785 | error->pquery_tag = InvalidDsaPointer; 786 | 787 | len = strlen(sql); 788 | error->psql = dsa_allocate_extended(local_data.area, len + 1, 789 | DSA_ALLOC_NO_OOM); 790 | if (error->psql == InvalidDsaPointer) 791 | { 792 | elog(WARNING, "pel_queue_error(): can not extend queue for %ld bytes, query: %s", 793 | len+1, errmessage); 794 | pel_cleanup_local(); 795 | return false; 796 | } 797 | tmp = dsa_get_address(local_data.area, error->psql); 798 | memcpy(tmp, sql, len); 799 | tmp[len] = '\0'; 800 | 801 | if (detail) 802 | { 803 | len = strlen(detail); 804 | error->pdetail = dsa_allocate_extended(local_data.area, len + 1, 805 | DSA_ALLOC_NO_OOM); 806 | if (error->pdetail == InvalidDsaPointer) 807 | { 808 | elog(WARNING, "pel_queue_error(): can not extend queue for %ld bytes, detail: %s", 809 | len+1, errmessage); 810 | pel_cleanup_local(); 811 | return false; 812 | } 813 | tmp = dsa_get_address(local_data.area, error->pdetail); 814 | memcpy(tmp, detail, len); 815 | tmp[len] = '\0'; 816 | } 817 | else 818 | error->pdetail = InvalidDsaPointer; 819 | 820 | /* no error, make the error visible */ 821 | local_data.entry->num_entries++; 822 | 823 | if (sync) 824 | { 825 | int pos = pel_publish_queue(true); 826 | elog(PEL_DEBUG, "pel_queue_error(): queue position returned by pel_publish_queue(): %d", pos); 827 | 828 | if (pos == PEL_PUBLISH_ERROR) 829 | { 830 | Assert(local_data.area == NULL); 831 | return false; 832 | } 833 | } 834 | 835 | return true; 836 | } 837 | 838 | #endif 839 | -------------------------------------------------------------------------------- /pel_worker.c: -------------------------------------------------------------------------------- 1 | /*------------------------------------------------------------------------- 2 | * 3 | * pel_worker.c: 4 | * Implementation of bgworker for error queue processing. 5 | * 6 | * This program is open source, licensed under the PostgreSQL license. 7 | * For license terms, see the LICENSE file. 8 | * 9 | * Copyright (C) 2021-2022: MigOps Inc 10 | * 11 | *------------------------------------------------------------------------- 12 | */ 13 | 14 | #include "postgres.h" 15 | 16 | #if PG_VERSION_NUM >= 100000 17 | 18 | #include "access/xact.h" 19 | #include "commands/dbcommands.h" 20 | #include "executor/spi.h" 21 | #include "fmgr.h" 22 | #include "miscadmin.h" 23 | #if PG_VERSION_NUM < 140000 24 | #include "pgstat.h" 25 | #else 26 | #include "utils/wait_event.h" 27 | #endif 28 | #include "postmaster/bgworker.h" 29 | #include "storage/latch.h" 30 | #include "storage/proc.h" 31 | #include "storage/procsignal.h" 32 | #if PG_VERSION_NUM >= 140000 33 | #include "utils/backend_status.h" 34 | #endif 35 | #include "utils/builtins.h" 36 | #include "utils/guc.h" 37 | #include "utils/lsyscache.h" 38 | #include "utils/ps_status.h" 39 | #include "utils/snapmgr.h" 40 | 41 | #include "include/pg_dbms_errlog.h" 42 | #include "include/pel_worker.h" 43 | #include "include/pel_errqueue.h" 44 | 45 | #if PG_VERSION_NUM < 130000 46 | #define PS_DISPLAY(m) set_ps_display(m, false) 47 | #else 48 | #define PS_DISPLAY(m) set_ps_display(m) 49 | #endif 50 | 51 | #define PEL_WORKER_MAX_DB 10 52 | 53 | #define PEL_WORKER_INSERT "INSERT INTO %s.%s VALUES ('%s', %s, '%c', %s, %s, %s)" 54 | 55 | typedef struct pelWorkerQueueItems 56 | { 57 | int nb_db; 58 | pid_t *pid; 59 | Oid *dbs; 60 | int *starting_pos; 61 | int *stopping_pos; 62 | BackgroundWorkerHandle **handles; 63 | } pelWorkerQueueItems; 64 | 65 | /* flags set by signal handlers */ 66 | static volatile sig_atomic_t got_sighup = false; 67 | 68 | static void pel_sighup(SIGNAL_ARGS); 69 | static void pel_process_sighup(void); 70 | 71 | static void pel_get_queue_items(pelWorkerQueueItems *items); 72 | 73 | static void 74 | pel_sighup(SIGNAL_ARGS) 75 | { 76 | int save_errno = errno; 77 | 78 | got_sighup = true; 79 | 80 | if (MyProc) 81 | SetLatch(&MyProc->procLatch); 82 | 83 | errno = save_errno; 84 | } 85 | 86 | static void 87 | pel_process_sighup(void) 88 | { 89 | if (got_sighup) 90 | { 91 | got_sighup = false; 92 | 93 | ProcessConfigFile(PGC_SIGHUP); 94 | } 95 | } 96 | 97 | /* 98 | * Fillup the given pelWorkerQueueItems with work to be processed. 99 | * 100 | * We want to avoid spawning too many dynamic bgworkers, so we try to batch 101 | * queue items from the same database together. However, we can't rely on the 102 | * launch of a dynamic bgworkers to always be successful, so we only batch them 103 | * if they're contiguous, otherwise we would risk to skip processing some queue 104 | * entries or process them multiple times. We don't currently try to batch the 105 | * same database in multiple batch to avoid launching multiple dynamic 106 | * bgworkers on the same database, but this could be allowed in a later version 107 | * as the bgworker only performs INSERTs on tables without PK. 108 | * 109 | * We also save the current position in the global queue, so dynamic bgworker 110 | * will know where to stop even if other backend queue more errors. 111 | */ 112 | static void 113 | pel_get_queue_items(pelWorkerQueueItems *items) 114 | { 115 | Oid lastdbid = InvalidOid; 116 | int pos; 117 | 118 | items->nb_db = 0; 119 | 120 | Assert(!LWLockHeldByMe(pel->lock)); 121 | Assert(items && items->pid && items->dbs && items->starting_pos && 122 | items->stopping_pos); 123 | 124 | LWLockAcquire(pel->lock, LW_SHARED); 125 | 126 | /* Remember the position of the current error */ 127 | pel->bgw_saved_cur = pel->cur_err; 128 | 129 | if (pel->bgw_err == pel->cur_err) 130 | { 131 | LWLockRelease(pel->lock); 132 | return; 133 | } 134 | 135 | pos = pel->bgw_err; 136 | while (true) 137 | { 138 | Oid dbid; 139 | int i, arrid; 140 | 141 | pos = PEL_POS_NEXT(pos); 142 | 143 | dbid = pel_get_queue_item_dbid(pos); 144 | Assert(OidIsValid(dbid)); 145 | if (!OidIsValid(lastdbid)) 146 | lastdbid = dbid; 147 | 148 | arrid = -1; 149 | for(i = 0; i < items->nb_db; i++) 150 | { 151 | if (items->dbs[i] == dbid) 152 | { 153 | arrid = i; 154 | break; 155 | } 156 | } 157 | 158 | /* No more room for another worker */ 159 | if (arrid == -1 && items->nb_db >= PEL_WORKER_MAX_DB) 160 | break; 161 | 162 | /* 163 | * Found an already saved db that's non contiguous with the other one, 164 | * we have to stop here. 165 | */ 166 | if (arrid >= 0 && dbid != lastdbid) 167 | break; 168 | 169 | if (arrid == -1) 170 | { 171 | /* New db (and worker), save the first position for it */ 172 | items->pid[items->nb_db] = 0; 173 | items->dbs[items->nb_db] = dbid; 174 | items->starting_pos[items->nb_db] = pos; 175 | items->stopping_pos[items->nb_db] = pos; 176 | items->nb_db++; 177 | } 178 | else 179 | { 180 | /* Remember the last position seen for that db */ 181 | items->stopping_pos[arrid] = pos; 182 | } 183 | 184 | /* Reached current queue item, no more work to do. */ 185 | if (pos == pel->cur_err) 186 | break; 187 | } 188 | LWLockRelease(pel->lock); 189 | } 190 | 191 | void 192 | pel_worker_main(Datum main_arg) 193 | { 194 | pelWorkerQueueItems items; 195 | 196 | pqsignal(SIGHUP, pel_sighup); 197 | /* We get notified of dynamic bgworker termination through SIGUSR1 */ 198 | pqsignal(SIGUSR1, procsignal_sigusr1_handler); 199 | BackgroundWorkerUnblockSignals(); 200 | 201 | elog(LOG, "pg_dbms_errlog main worker started"); 202 | PS_DISPLAY("init"); 203 | 204 | 205 | items.pid = (pid_t *) palloc(sizeof(pid_t) * pel_max_workers); 206 | items.dbs = (Oid *) palloc(sizeof(Oid) * pel_max_workers); 207 | items.starting_pos = (int *) palloc(sizeof(int) * pel_max_workers); 208 | items.stopping_pos = (int *) palloc(sizeof(int) * pel_max_workers); 209 | items.handles = (BackgroundWorkerHandle **) 210 | palloc(sizeof(BackgroundWorkerHandle *) * pel_max_workers); 211 | 212 | elog(PEL_DEBUG, "pel_worker_main(): set bgworker procno: %d", 213 | MyProc->pgprocno); 214 | pg_atomic_write_u32(&pel->bgw_procno, MyProc->pgprocno); 215 | pel_init_dsm(true); 216 | 217 | while (true) 218 | { 219 | int i, last, rc; 220 | 221 | pel_process_sighup(); 222 | 223 | PS_DISPLAY("checking for queue items to process"); 224 | elog(PEL_DEBUG, "pel_worker_main() checking for queue items to process"); 225 | pel->bgw_saved_cur = -1; 226 | pel_get_queue_items(&items); 227 | Assert(pel->bgw_saved_cur != -1); 228 | 229 | if (items.nb_db > 0) 230 | { 231 | PS_DISPLAY("launching dynamic bgworkers"); 232 | elog(PEL_DEBUG, "pel_worker_main() will launch %d workers", 233 | items.nb_db); 234 | } 235 | else 236 | elog(PEL_DEBUG, "pel_worker_main() no worker will be launched"); 237 | 238 | last = -1; 239 | for (i = 0; i < items.nb_db; i++) 240 | { 241 | BackgroundWorker worker; 242 | 243 | worker.bgw_flags = BGWORKER_SHMEM_ACCESS | 244 | BGWORKER_BACKEND_DATABASE_CONNECTION; 245 | worker.bgw_start_time = BgWorkerStart_ConsistentState; 246 | worker.bgw_restart_time = BGW_NEVER_RESTART; 247 | sprintf(worker.bgw_library_name, "pg_dbms_errlog"); 248 | sprintf(worker.bgw_function_name, "pel_dynworker_main"); 249 | snprintf(worker.bgw_name, BGW_MAXLEN, "pel dyn worker for db %u", 250 | items.dbs[i]); 251 | #if PG_VERSION_NUM >= 110000 252 | sprintf(worker.bgw_type, "pg_dbms_errlog"); 253 | #endif 254 | worker.bgw_main_arg = Int32GetDatum(items.starting_pos[i]); 255 | worker.bgw_notify_pid = MyProcPid; 256 | 257 | if (!RegisterDynamicBackgroundWorker(&worker, &items.handles[i])) 258 | { 259 | elog(WARNING, "could not register dynamic bgworker for db %u", 260 | items.starting_pos[i]); 261 | break; 262 | } 263 | else 264 | elog(PEL_DEBUG, "pel_worker_main() registered a bgworker for" 265 | " db %u", items.starting_pos[i]); 266 | last = i; 267 | } 268 | 269 | PS_DISPLAY("waiting for dynamic bgworker to finish"); 270 | elog(PEL_DEBUG, "pel_worker_main() waiting for dynamic bgworker to finish"); 271 | /* And now wait for the completion of all the workers */ 272 | for (i = 0; i <= last; i++) 273 | { 274 | BgwHandleStatus status; 275 | 276 | status = WaitForBackgroundWorkerShutdown(items.handles[i]); 277 | switch (status) 278 | { 279 | case BGWH_STOPPED: 280 | /* done, we can wait for the next one */ 281 | elog(PEL_DEBUG, "pel_worker_main() dynamic bgworker %d/%d" 282 | " terminated", i + 1, last + 1); 283 | break; 284 | case BGWH_POSTMASTER_DIED: 285 | /* postmaster died, simply exit */ 286 | elog(PEL_DEBUG, "pel_worker_main(): set bgworker procno: %d", 287 | INVALID_PGPROCNO); 288 | pg_atomic_write_u32(&pel->bgw_procno, INVALID_PGPROCNO); 289 | exit(1); 290 | break; 291 | default: 292 | /* should not happen */ 293 | elog(PEL_DEBUG, "pel_worker_main(): set bgworker procno: %d", 294 | INVALID_PGPROCNO); 295 | pg_atomic_write_u32(&pel->bgw_procno, INVALID_PGPROCNO); 296 | elog(WARNING, "unexpected worker status %d", status); 297 | exit(1); 298 | break; 299 | } 300 | LWLockAcquire(pel->lock, LW_EXCLUSIVE); 301 | pel->bgw_err = items.stopping_pos[i]; 302 | LWLockRelease(pel->lock); 303 | pfree(items.handles[i]); 304 | } 305 | 306 | /* 307 | * If we just processed some queued entries, check if some more work 308 | * has been queue since we last woke up and process it immediately, 309 | * otherwise we might miss some request from backends and let them wait 310 | * up to pel_frequency, as their SetLatch could be reset by the dynamic 311 | * bgworker infrastructure. 312 | */ 313 | if (last >= 0) 314 | continue; 315 | 316 | PS_DISPLAY("sleeping"); 317 | elog(PEL_DEBUG, "pel_worker_main(): sleeping (procno: %d)", 318 | MyProc->pgprocno); 319 | rc = WaitLatch(&MyProc->procLatch, 320 | WL_LATCH_SET | WL_TIMEOUT | WL_POSTMASTER_DEATH, 321 | pel_frequency * 1000, 322 | PG_WAIT_EXTENSION); 323 | ResetLatch(&MyProc->procLatch); 324 | elog(PEL_DEBUG, "pel_worker_main() woke up, rc: %d", rc); 325 | } 326 | } 327 | 328 | void 329 | pel_dynworker_main(Datum main_arg) 330 | { 331 | int pos = DatumGetInt32(main_arg); 332 | pelWorkerEntry *entry; 333 | pelWorkerError *error; 334 | StringInfoData sql; 335 | int i, limit;; 336 | 337 | pqsignal(SIGHUP, pel_sighup); 338 | BackgroundWorkerUnblockSignals(); 339 | 340 | PS_DISPLAY("init"); 341 | 342 | /* 343 | * No need for lock as the main bgworker won't update it's saved position 344 | * while dynamic bgworker are running. 345 | */ 346 | limit = pel->bgw_saved_cur; 347 | 348 | entry = pel_get_worker_entry(pos); 349 | 350 | elog(LOG, "pg_dbms_errlog dynamic worker for db %u started", entry->dbid); 351 | 352 | /* XXX should we use a non privileged user here? */ 353 | BackgroundWorkerInitializeConnectionByOid(entry->dbid, InvalidOid 354 | #if PG_VERSION_NUM >= 110000 355 | ,0 356 | #endif 357 | ); 358 | 359 | set_config_option("pg_dbms_errlog.enabled", "off", 360 | PGC_SUSET, PGC_S_SESSION, GUC_ACTION_SET, true, 0, false); 361 | 362 | while(true) 363 | { 364 | Oid new_dbid; 365 | int rc; 366 | 367 | rc = SPI_connect(); 368 | if (rc != SPI_OK_CONNECT) 369 | ereport(WARNING, (errmsg("Can not connect to SPI manager."))); 370 | 371 | StartTransactionCommand(); 372 | SetCurrentStatementStartTimestamp(); 373 | PushActiveSnapshot(GetTransactionSnapshot()); 374 | 375 | for(i = 0; i < entry->num_errors; i++) 376 | { 377 | char *relnamespace, *relname; 378 | 379 | error = &entry->errors[i]; 380 | 381 | relnamespace = get_namespace_name(get_rel_namespace(error->err_relid)); 382 | Assert(relnamespace); 383 | 384 | relname = get_rel_name(error->err_relid); 385 | Assert(relname); 386 | 387 | initStringInfo(&sql); 388 | appendStringInfo(&sql, PEL_WORKER_INSERT, 389 | quote_identifier(relnamespace), 390 | quote_identifier(relname), 391 | unpack_sql_state(error->sqlstate), 392 | quote_literal_cstr(error->errmessage), 393 | error->cmdtype, 394 | error->query_tag ? quote_literal_cstr(error->query_tag) : "NULL", 395 | quote_literal_cstr(error->sql), 396 | error->detail ? quote_literal_cstr(error->detail) : "NULL" 397 | ); 398 | pgstat_report_activity(STATE_RUNNING, sql.data); 399 | SPI_execute(sql.data, false, 0); 400 | if (rc != SPI_OK_INSERT) 401 | if (SPI_processed != 1) 402 | ereport(WARNING, 403 | (errmsg("SPI execution failure (rc=%d) on query: %s", 404 | rc, sql.data))); 405 | elog(PEL_DEBUG, "pel_dynworker_main(): inserted %ld rows", SPI_processed); 406 | pgstat_report_activity(STATE_IDLE, NULL); 407 | 408 | pfree(sql.data); 409 | } 410 | 411 | rc = SPI_finish(); 412 | if (rc != SPI_OK_FINISH) 413 | elog(WARNING, "could not disconnect from SPI manager"); 414 | PopActiveSnapshot(); 415 | CommitTransactionCommand(); 416 | 417 | /* 418 | * Cleanup data structure that was set in pel_get_worker_entry() and 419 | * notify caller if it was required 420 | */ 421 | pel_worker_entry_complete(); 422 | 423 | /* Move to the next item in the batch if any */ 424 | pos = PEL_POS_NEXT(pos); 425 | elog(PEL_DEBUG, "pel_dynworker_main(): new pos after processing %d", pos); 426 | 427 | if (pos > limit) 428 | break; 429 | 430 | LWLockAcquire(pel->lock, LW_SHARED); 431 | new_dbid = pel_get_queue_item_dbid(pos); 432 | LWLockRelease(pel->lock); 433 | 434 | if (new_dbid != entry->dbid) 435 | break; 436 | 437 | entry = pel_get_worker_entry(pos); 438 | } 439 | 440 | pgstat_report_activity(STATE_IDLE, NULL); 441 | elog(LOG, "pg_dbms_errlog dynamic worker for db %u finished", entry->dbid); 442 | } 443 | #endif /* pg10 */ 444 | -------------------------------------------------------------------------------- /pg_dbms_errlog.c: -------------------------------------------------------------------------------- 1 | /*------------------------------------------------------------------------- 2 | * 3 | * pg_dbms_errlog.c: 4 | * pg_dbms_errlog is a PostgreSQL extension that logs each failing DML 5 | * query. It emulates the DBMS_ERRLOG Oracle module. 6 | * 7 | * This program is open source, licensed under the PostgreSQL license. 8 | * For license terms, see the LICENSE file. 9 | * 10 | * Copyright (C) 2021-2022: MigOps Inc 11 | * 12 | *------------------------------------------------------------------------- 13 | */ 14 | 15 | #include "postgres.h" 16 | 17 | #include "access/genam.h" 18 | #include "access/heapam.h" 19 | #if PG_VERSION_NUM >= 130000 20 | #include "access/table.h" 21 | #else 22 | /* for imported functions */ 23 | #include "mb/pg_wchar.h" 24 | #endif 25 | #include "access/xact.h" 26 | #include "catalog/dependency.h" 27 | #include "catalog/namespace.h" 28 | #include "catalog/pg_authid.h" 29 | #include "catalog/pg_namespace.h" 30 | #include "executor/executor.h" 31 | #include "executor/spi.h" 32 | #include "funcapi.h" 33 | #include "miscadmin.h" 34 | #include "miscadmin.h" 35 | #include "nodes/makefuncs.h" 36 | #include "parser/analyze.h" 37 | #include "parser/parser.h" 38 | #include "postmaster/bgworker.h" 39 | #include "storage/ipc.h" 40 | #include "storage/proc.h" 41 | #include "tcop/tcopprot.h" 42 | #include "tcop/utility.h" 43 | #include "utils/builtins.h" 44 | #include "utils/elog.h" 45 | #include "utils/fmgroids.h" 46 | #include "utils/guc.h" 47 | #include "utils/lsyscache.h" 48 | #if PG_VERSION_NUM < 110000 49 | #include "utils/memutils.h" 50 | #endif 51 | #include "utils/rel.h" 52 | #include "utils/syscache.h" 53 | #include "utils/varlena.h" 54 | #if PG_VERSION_NUM >= 140000 55 | #include "utils/wait_event.h" 56 | #else 57 | #include "pgstat.h" 58 | #endif 59 | 60 | #include "include/pg_dbms_errlog.h" 61 | #include "include/pel_errqueue.h" 62 | 63 | #if PG_VERSION_NUM < 100000 64 | #error Minimum version of PostgreSQL required is 10 65 | #endif 66 | 67 | /* Define ProcessUtility hook proto/parameters following the PostgreSQL version */ 68 | #if PG_VERSION_NUM >= 140000 69 | #define PEL_PROCESSUTILITY_PROTO PlannedStmt *pstmt, const char *queryString, \ 70 | bool readOnlyTree, \ 71 | ProcessUtilityContext context, ParamListInfo params, \ 72 | QueryEnvironment *queryEnv, DestReceiver *dest, \ 73 | QueryCompletion *qc 74 | #define PEL_PROCESSUTILITY_ARGS pstmt, queryString, readOnlyTree, context, params, queryEnv, dest, qc 75 | #elif PG_VERSION_NUM >= 130000 76 | #define PEL_PROCESSUTILITY_PROTO PlannedStmt *pstmt, const char *queryString, \ 77 | ProcessUtilityContext context, ParamListInfo params, \ 78 | QueryEnvironment *queryEnv, DestReceiver *dest, \ 79 | QueryCompletion *qc 80 | #define PEL_PROCESSUTILITY_ARGS pstmt, queryString, context, params, queryEnv, dest, qc 81 | #else 82 | #define PEL_PROCESSUTILITY_PROTO PlannedStmt *pstmt, const char *queryString, \ 83 | ProcessUtilityContext context, ParamListInfo params, \ 84 | QueryEnvironment *queryEnv, DestReceiver *dest, \ 85 | char *completionTag 86 | #define PEL_PROCESSUTILITY_ARGS pstmt, queryString, context, params, queryEnv, dest, completionTag 87 | #endif 88 | 89 | #define PEL_REGISTRATION_TABLE "register_errlog_tables" 90 | #define Anum_pel_relid 1 91 | #define Anum_pel_errlogid 2 92 | 93 | #define MAX_PREPARED_STMT_SIZE 1048576 94 | 95 | 96 | PG_MODULE_MAGIC; 97 | 98 | #define PEL_TRANCHE_NAME "pg_dbms_errlog" 99 | 100 | /* Saved hook values in case of unload */ 101 | #if PG_VERSION_NUM >= 150000 102 | static shmem_request_hook_type prev_shmem_request_hook = NULL; 103 | #endif 104 | static shmem_startup_hook_type prev_shmem_startup_hook = NULL; 105 | static ProcessUtility_hook_type prev_ProcessUtility = NULL; 106 | static ExecutorStart_hook_type prev_ExecutorStart = NULL; 107 | static ExecutorRun_hook_type prev_ExecutorRun = NULL; 108 | static ExecutorFinish_hook_type prev_ExecutorFinish = NULL; 109 | static ExecutorEnd_hook_type prev_ExecutorEnd = NULL; 110 | static emit_log_hook_type prev_emit_log_hook = NULL; 111 | static post_parse_analyze_hook_type prev_post_parse_analyze_hook = NULL; 112 | 113 | /* Links to shared memory state */ 114 | pelSharedState *pel = NULL; 115 | dsa_area *pel_area = NULL; 116 | 117 | /* GUC variables */ 118 | 119 | typedef enum 120 | { 121 | PEL_SYNC_OFF, /* never wait for queued errors processing */ 122 | PEL_SYNC_QUERY, /* wait for every error */ 123 | PEL_SYNC_XACT /* wait at the end of the xact (implicit or not) */ 124 | } pelSyncLevel; 125 | 126 | static const struct config_enum_entry pel_sync_options[] = 127 | { 128 | {"off", PEL_SYNC_OFF, false}, 129 | {"query", PEL_SYNC_QUERY, false}, 130 | {"transaction", PEL_SYNC_XACT, false}, 131 | {NULL, 0, false} 132 | }; 133 | 134 | #define PEL_SYNC_ON_QUERY() (pel_synchronous == PEL_SYNC_QUERY || \ 135 | (pel_synchronous == PEL_SYNC_XACT && !IsTransactionBlock())) 136 | /* 137 | * We also have to wait for completion if level is PEL_SYNC_QUERY and we're in 138 | * a transaction block, as it could have be raised from PEL_SYNC_OFF just 139 | * before a COMMIT, which should force a sync 140 | */ 141 | #define PEL_SYNC_ON_XACT() (pel_synchronous == PEL_SYNC_XACT || \ 142 | (pel_synchronous == PEL_SYNC_QUERY && IsTransactionBlock())) 143 | bool pel_debug = false; 144 | bool pel_done = false; 145 | bool pel_enabled = false; 146 | int pel_frequency = 60; 147 | int pel_max_workers = 1; 148 | int pel_reject_limit = -1; 149 | char *query_tag = NULL; 150 | int pel_synchronous = PEL_SYNC_XACT; 151 | bool pel_no_client_error = true; 152 | 153 | /* global variable used to store DML table name */ 154 | char *current_dml_table = NULL; 155 | char current_dml_kind = '\0'; 156 | char *current_bind_parameters = NULL; 157 | 158 | /* Current nesting depth of ExecutorRun calls */ 159 | static int exec_nested_level = 0; 160 | 161 | /* cache to store query of prepared stamement */ 162 | struct HTAB *PreparedCache = NULL; 163 | 164 | /* Functions declaration */ 165 | void _PG_init(void); 166 | 167 | extern PGDLLEXPORT Datum pg_dbms_errlog_publish_queue(PG_FUNCTION_ARGS); 168 | PG_FUNCTION_INFO_V1(pg_dbms_errlog_publish_queue); 169 | extern PGDLLEXPORT Datum pg_dbms_errlog_queue_size(PG_FUNCTION_ARGS); 170 | PG_FUNCTION_INFO_V1(pg_dbms_errlog_queue_size); 171 | 172 | #if PG_VERSION_NUM >= 150000 173 | static void pel_shmem_request(void); 174 | #endif 175 | static void pel_shmem_startup(void); 176 | static void pel_ProcessUtility(PEL_PROCESSUTILITY_PROTO); 177 | static void pel_ExecutorStart(QueryDesc *queryDesc, int eflags); 178 | static void pel_ExecutorRun(QueryDesc *queryDesc, 179 | ScanDirection direction, 180 | uint64 count, bool execute_once); 181 | static void pel_ExecutorFinish(QueryDesc *queryDesc); 182 | static void pel_ExecutorEnd(QueryDesc *queryDesc); 183 | static void pel_log_error(ErrorData *edata); 184 | static Size pel_memsize(void); 185 | char *lookupCachedPrepared(const char *preparedName); 186 | void removeCachedPrepared(const char *localPreparedName); 187 | static void pel_setupCachedPreparedHash(void); 188 | void putCachedPrepared(const char *preparedName, const char *preparedStmt); 189 | char *get_relation_name(Oid relid); 190 | void generate_error_message (ErrorData *edata, StringInfoData *buf); 191 | void append_with_tabs(StringInfo buf, const char *str); 192 | #if PG_VERSION_NUM < 130000 193 | /* Copied from src/backend/nodes/params.c for older versions */ 194 | char *BuildParamLogString(ParamListInfo params, char **knownTextValues, int maxlen); 195 | /* Copied from src/backend/utils/mb/stringinfo_mb.c */ 196 | void appendStringInfoStringQuoted(StringInfo str, const char *s, int maxlen); 197 | /* Copied from src/backend/access/transam/xact.c */ 198 | /* Adapted from src/backend/nodes/list.c */ 199 | static List *list_copy_deep(const List *oldlist); 200 | #endif 201 | #if PG_VERSION_NUM < 110000 202 | static void appendBinaryStringInfoNT(StringInfo str, const char *data, int datalen); 203 | #endif 204 | 205 | typedef struct PreparedCacheKey 206 | { 207 | char preparedName[NAMEDATALEN]; 208 | } PreparedCacheKey; 209 | 210 | typedef struct PreparedCacheEntry 211 | { 212 | PreparedCacheKey key; 213 | char preparedStmt[MAX_PREPARED_STMT_SIZE]; 214 | } PreparedCacheEntry; 215 | 216 | static void 217 | pel_setupCachedPreparedHash(void) 218 | { 219 | /* Initialize cache */ 220 | if (PreparedCache == NULL) 221 | { 222 | HASHCTL ctl; 223 | MemSet(&ctl, 0, sizeof(ctl)); 224 | ctl.keysize = sizeof(PreparedCacheKey); 225 | ctl.entrysize = sizeof(PreparedCacheEntry); 226 | /* allocate PrepareHash in the cache context */ 227 | ctl.hcxt = CacheMemoryContext; 228 | PreparedCache = hash_create("pg_dbms_errlog_prepares", 8, &ctl, 229 | HASH_ELEM | HASH_CONTEXT | HASH_BLOBS); 230 | } 231 | } 232 | 233 | void 234 | putCachedPrepared(const char *preparedName, const char *preparedStmt) 235 | { 236 | PreparedCacheKey key = { { 0 } }; 237 | PreparedCacheEntry *entry; 238 | bool found; 239 | 240 | pel_setupCachedPreparedHash(); 241 | 242 | strncpy(key.preparedName, preparedName, sizeof(PreparedCacheKey)); 243 | 244 | entry = hash_search(PreparedCache, &key, HASH_ENTER, &found); 245 | if (found) 246 | { 247 | elog(ERROR, "PREPAREDCACHE: Prepared statement '%s' already exist in cache with query: %s", 248 | preparedName, entry->preparedStmt); 249 | } 250 | else 251 | { 252 | elog(DEBUG1, "PREPAREDCACHE: Add prepared statement '%s' with query '%s'", 253 | preparedName, preparedStmt); 254 | strncpy(entry->preparedStmt, preparedStmt, sizeof(entry->preparedStmt)); 255 | } 256 | } 257 | 258 | void 259 | removeCachedPrepared(const char *preparedName) 260 | { 261 | PreparedCacheKey key = { { 0 } }; // zero out the key, no trailing garbage 262 | PreparedCacheEntry *entry; 263 | bool found; 264 | 265 | pel_setupCachedPreparedHash(); 266 | 267 | strncpy(key.preparedName, preparedName, sizeof(PreparedCacheKey)); 268 | 269 | entry = hash_search(PreparedCache, &key, HASH_REMOVE, &found); 270 | if (found) 271 | elog(DEBUG1, "PREPAREDCACHE: Prepared statement '%s' exist in cache with query '%s'", 272 | preparedName, entry->preparedStmt); 273 | else 274 | elog(DEBUG1, "PREPAREDCACHE: Prepared statement '%s' to remove not in cache", 275 | preparedName); 276 | } 277 | 278 | char * 279 | lookupCachedPrepared(const char *preparedName) 280 | { 281 | PreparedCacheKey key = { { 0 } }; 282 | PreparedCacheEntry *entry; 283 | bool found; 284 | 285 | pel_setupCachedPreparedHash(); 286 | 287 | strncpy(key.preparedName, preparedName, sizeof(PreparedCacheKey)); 288 | 289 | entry = hash_search(PreparedCache, &key, HASH_FIND, &found); 290 | 291 | if (!found) 292 | elog(ERROR, "Prepared statement '%s' is not found in cache", preparedName); 293 | 294 | elog(DEBUG1, "PREPAREDCACHE: prepared statement '%s' found in cache with query: %s", 295 | key.preparedName, entry->preparedStmt); 296 | return entry->preparedStmt; 297 | } 298 | 299 | /* 300 | * Module load callback 301 | */ 302 | void 303 | _PG_init(void) 304 | { 305 | BackgroundWorker worker; 306 | 307 | if (!process_shared_preload_libraries_in_progress) 308 | { 309 | elog(ERROR, "This module can only be loaded via shared_preload_libraries"); 310 | return; 311 | } 312 | 313 | /* Define custom GUC variables */ 314 | DefineCustomBoolVariable( "pg_dbms_errlog.debug", 315 | "Enable/disable debug traces.", 316 | NULL, 317 | &pel_debug, 318 | false, 319 | PGC_USERSET, /* Any user can set it */ 320 | 0, 321 | NULL, 322 | NULL, 323 | NULL); 324 | 325 | DefineCustomBoolVariable( "pg_dbms_errlog.enabled", 326 | "Enable/disable log of failing queries.", 327 | NULL, 328 | &pel_enabled, 329 | false, 330 | PGC_USERSET, /* Any user can set it */ 331 | 0, 332 | NULL, 333 | NULL, 334 | NULL); 335 | 336 | DefineCustomIntVariable("pg_dbms_errlog.frequency", 337 | "Defines the frequency for checking for data to process", 338 | NULL, 339 | &pel_frequency, 340 | 60, 341 | 10, 342 | 3600, 343 | PGC_SUSET, 344 | GUC_UNIT_S, 345 | NULL, 346 | NULL, 347 | NULL); 348 | 349 | DefineCustomIntVariable("pg_dbms_errlog.max_workers", 350 | "Defines the maximum number of bgworker to launch to process data", 351 | NULL, 352 | &pel_max_workers, 353 | 1, 354 | 1, 355 | max_worker_processes, 356 | PGC_POSTMASTER, 357 | 0, 358 | NULL, 359 | NULL, 360 | NULL); 361 | 362 | DefineCustomIntVariable("pg_dbms_errlog.reject_limit", 363 | "Maximum number of errors that can be encountered before the DML" 364 | " statement terminates and rolls back. A value of -1 mean unlimited," 365 | " this is the default. When reject limit is zero no error is logged" 366 | " and the statement rolls back.", 367 | NULL, 368 | &pel_reject_limit, 369 | -1, 370 | -1, 371 | INT_MAX, 372 | PGC_USERSET, /* Any user can set it */ 373 | 0, 374 | NULL, 375 | NULL, 376 | NULL); 377 | 378 | DefineCustomStringVariable( "pg_dbms_errlog.query_tag", 379 | "Tag (a numeric or string literal in parentheses) that gets added" 380 | " to the error log to help identify the statement that caused the" 381 | " errors. If the tag is omitted, a NULL value is used.", 382 | NULL, 383 | &query_tag, 384 | NULL, 385 | PGC_USERSET, /* Any user can set it */ 386 | 0, 387 | NULL, 388 | NULL, 389 | NULL ); 390 | 391 | DefineCustomEnumVariable("pg_dbms_errlog.synchronous", 392 | "Wait for error queue completion when an error happens", 393 | NULL, 394 | &pel_synchronous, 395 | PEL_SYNC_XACT, 396 | pel_sync_options, 397 | PGC_USERSET, 398 | 0, 399 | NULL, 400 | NULL, 401 | NULL); 402 | 403 | DefineCustomBoolVariable("pg_dbms_errlog.no_client_error", 404 | "Enable/disable client error logging", 405 | NULL, 406 | &pel_no_client_error, 407 | true, 408 | PGC_USERSET, 409 | 0, 410 | NULL, 411 | NULL, 412 | NULL); 413 | 414 | EmitWarningsOnPlaceholders("pg_dbms_errlog"); 415 | 416 | #if PG_VERSION_NUM < 150000 417 | /* 418 | * Request additional shared resources. (These are no-ops if we're not in 419 | * the postmaster process.) We'll allocate or attach to the shared 420 | * resources in pel_shmem_startup(). 421 | * 422 | * If you change code here, don't forget to also report the modifications 423 | * in pel_shmem_request() for pg15 and later. 424 | */ 425 | RequestAddinShmemSpace(pel_memsize()); 426 | RequestNamedLWLockTranche(PEL_TRANCHE_NAME, 1); 427 | #endif 428 | 429 | 430 | /* Install hooks */ 431 | #if PG_VERSION_NUM >= 150000 432 | prev_shmem_request_hook = shmem_request_hook; 433 | shmem_request_hook = pel_shmem_request; 434 | #endif 435 | prev_shmem_startup_hook = shmem_startup_hook; 436 | shmem_startup_hook = pel_shmem_startup; 437 | prev_ProcessUtility = ProcessUtility_hook; 438 | ProcessUtility_hook = pel_ProcessUtility; 439 | prev_ExecutorStart = ExecutorStart_hook; 440 | ExecutorStart_hook = pel_ExecutorStart; 441 | prev_ExecutorRun = ExecutorRun_hook; 442 | ExecutorRun_hook = pel_ExecutorRun; 443 | prev_ExecutorFinish = ExecutorFinish_hook; 444 | ExecutorFinish_hook = pel_ExecutorFinish; 445 | prev_ExecutorEnd = ExecutorEnd_hook; 446 | ExecutorEnd_hook = pel_ExecutorEnd; 447 | prev_emit_log_hook = emit_log_hook; 448 | emit_log_hook = pel_log_error; 449 | prev_post_parse_analyze_hook = post_parse_analyze_hook; 450 | 451 | memset(&worker, 0, sizeof(BackgroundWorker)); 452 | worker.bgw_flags = BGWORKER_SHMEM_ACCESS; 453 | worker.bgw_start_time = BgWorkerStart_RecoveryFinished; 454 | snprintf(worker.bgw_library_name, BGW_MAXLEN, "pg_dbms_errlog"); 455 | snprintf(worker.bgw_function_name, BGW_MAXLEN, "pel_worker_main"); 456 | snprintf(worker.bgw_name, BGW_MAXLEN, "pg_dbms_errlog main worker"); 457 | worker.bgw_restart_time = 0; 458 | worker.bgw_main_arg = (Datum) 0; 459 | worker.bgw_notify_pid = 0; 460 | RegisterBackgroundWorker(&worker); 461 | } 462 | 463 | PGDLLEXPORT Datum 464 | pg_dbms_errlog_publish_queue(PG_FUNCTION_ARGS) 465 | { 466 | bool sync; 467 | int pos; 468 | 469 | if (PG_ARGISNULL(0)) 470 | sync = false; 471 | else 472 | sync = PG_GETARG_BOOL(0); 473 | 474 | pos = pel_publish_queue(sync); 475 | 476 | PG_RETURN_BOOL(pos != PEL_PUBLISH_ERROR); 477 | } 478 | 479 | PGDLLEXPORT Datum 480 | pg_dbms_errlog_queue_size(PG_FUNCTION_ARGS) 481 | { 482 | int num = pel_queue_size(); 483 | 484 | if (num == -1) 485 | PG_RETURN_NULL(); 486 | else 487 | PG_RETURN_INT32(num); 488 | } 489 | 490 | #if PG_VERSION_NUM >= 150000 491 | static void 492 | pel_shmem_request(void) 493 | { 494 | if (prev_shmem_request_hook) 495 | prev_shmem_request_hook(); 496 | 497 | /* 498 | * If you change code here, don't forget to also report the modifications in 499 | * _PG_init() for pg14 and below. 500 | */ 501 | RequestAddinShmemSpace(pel_memsize()); 502 | RequestNamedLWLockTranche(PEL_TRANCHE_NAME, 1); 503 | } 504 | #endif 505 | 506 | static void 507 | pel_shmem_startup(void) 508 | { 509 | bool found; 510 | 511 | if (prev_shmem_startup_hook) 512 | prev_shmem_startup_hook(); 513 | 514 | /* reset in case this is a restart within the postmaster */ 515 | pel = NULL; 516 | 517 | /* Create or attach to the shared memory state */ 518 | LWLockAcquire(AddinShmemInitLock, LW_EXCLUSIVE); 519 | 520 | pel = ShmemInitStruct("pg_dbms_errlog", 521 | pel_memsize(), 522 | &found); 523 | 524 | if (!found) 525 | { 526 | int trancheid; 527 | 528 | /* First time through ... */ 529 | pel->bgw_saved_cur = 0; 530 | pg_atomic_init_u32(&pel->bgw_procno, INVALID_PGPROCNO); 531 | StaticAssertStmt(sizeof(INVALID_PGPROCNO <= sizeof(pel->bgw_procno)), 532 | "INVALID_PGPROCNO is bigger for uint32"); 533 | pel->lock = &(GetNamedLWLockTranche(PEL_TRANCHE_NAME))->lock; 534 | pel->pel_dsa_handle = DSM_HANDLE_INVALID; 535 | pel->pqueue = InvalidDsaPointer; 536 | pel->max_errs = 0; 537 | pel->cur_err = 0; 538 | pel->bgw_err = 0; 539 | 540 | /* try to guess our trancheid */ 541 | for (trancheid = LWTRANCHE_FIRST_USER_DEFINED; ; trancheid++) 542 | { 543 | if (strcmp(GetLWLockIdentifier(PG_WAIT_LWLOCK, trancheid), 544 | PEL_TRANCHE_NAME) == 0) 545 | { 546 | /* Found it! */ 547 | break; 548 | } 549 | if ((trancheid - LWTRANCHE_FIRST_USER_DEFINED) > 50) 550 | { 551 | /* No point trying so hard, just give up. */ 552 | trancheid = LWTRANCHE_FIRST_USER_DEFINED; 553 | break; 554 | } 555 | } 556 | Assert(trancheid >= LWTRANCHE_FIRST_USER_DEFINED); 557 | pel->LWTRANCHE_PEL = trancheid; 558 | } 559 | 560 | LWLockRelease(AddinShmemInitLock); 561 | } 562 | 563 | static void 564 | pel_ProcessUtility(PEL_PROCESSUTILITY_PROTO) 565 | { 566 | Node *parsetree = pstmt->utilityStmt; 567 | 568 | pel_done = false; 569 | 570 | if (IsA(parsetree, PrepareStmt)) 571 | { 572 | PrepareStmt *stmt = (PrepareStmt *) parsetree; 573 | putCachedPrepared(stmt->name, debug_query_string); 574 | } 575 | else if (IsA(parsetree, DeallocateStmt)) 576 | { 577 | DeallocateStmt *stmt = (DeallocateStmt *) parsetree; 578 | removeCachedPrepared(stmt->name); 579 | } 580 | 581 | /* Excecute the utility command, we are not concerned */ 582 | if (prev_ProcessUtility) 583 | prev_ProcessUtility(PEL_PROCESSUTILITY_ARGS); 584 | else 585 | standard_ProcessUtility(PEL_PROCESSUTILITY_ARGS); 586 | 587 | /* Publish or discard queue on COMMIT/ROLLBACK */ 588 | if (IsA(parsetree, TransactionStmt)) 589 | { 590 | TransactionStmt *stmt = (TransactionStmt *) parsetree; 591 | 592 | /* Check if the commit really performed a commit */ 593 | if (stmt->kind == TRANS_STMT_COMMIT) 594 | { 595 | bool is_commit = false; 596 | 597 | #if PG_VERSION_NUM >= 130000 598 | if (!qc) 599 | { 600 | /* no way to tell, assume commit did happen */ 601 | is_commit = true; 602 | } 603 | else if (qc->commandTag != CMDTAG_ROLLBACK) 604 | is_commit = true; 605 | #else 606 | if (strcmp(completionTag, "ROLLBACK") != 0) 607 | is_commit = true; 608 | #endif 609 | 610 | if (is_commit) 611 | { 612 | if (pel_publish_queue(PEL_SYNC_ON_XACT()) == PEL_PUBLISH_ERROR) 613 | elog(WARNING, "could not publish the queue"); 614 | } 615 | else 616 | pel_discard_queue(); 617 | } 618 | else if (stmt->kind == TRANS_STMT_ROLLBACK) 619 | pel_discard_queue(); 620 | } 621 | } 622 | 623 | static void 624 | pel_ExecutorStart(QueryDesc *queryDesc, int eflags) 625 | { 626 | if (pel_enabled) 627 | { 628 | if (queryDesc->dest->mydest != DestSPI) 629 | { 630 | if (queryDesc->operation == CMD_INSERT) 631 | current_dml_kind = 'I'; 632 | else if (queryDesc->operation == CMD_UPDATE) 633 | current_dml_kind = 'U'; 634 | else if (queryDesc->operation == CMD_DELETE) 635 | current_dml_kind = 'D'; 636 | else 637 | current_dml_kind = '?'; 638 | } 639 | 640 | if (exec_nested_level == 0) 641 | { 642 | pel_done = false; 643 | if (current_bind_parameters != NULL) 644 | { 645 | pfree(current_bind_parameters); 646 | current_bind_parameters = NULL; 647 | } 648 | } 649 | 650 | if (!pel_done) 651 | { 652 | if (queryDesc->params && queryDesc->params->numParams > 0) 653 | current_bind_parameters = BuildParamLogString(queryDesc->params, NULL, -1); 654 | else 655 | current_bind_parameters = NULL; 656 | } 657 | } 658 | 659 | if (prev_ExecutorStart) 660 | prev_ExecutorStart(queryDesc, eflags); 661 | else 662 | standard_ExecutorStart(queryDesc, eflags); 663 | } 664 | 665 | /* 666 | * ExecutorRun hook: all we need do is track nesting depth 667 | */ 668 | static void 669 | pel_ExecutorRun(QueryDesc *queryDesc, ScanDirection direction, uint64 count, 670 | bool execute_once) 671 | { 672 | exec_nested_level++; 673 | PG_TRY(); 674 | { 675 | if (prev_ExecutorRun) 676 | prev_ExecutorRun(queryDesc, direction, count, execute_once); 677 | else 678 | standard_ExecutorRun(queryDesc, direction, count, execute_once); 679 | exec_nested_level--; 680 | } 681 | PG_CATCH(); 682 | { 683 | exec_nested_level--; 684 | PG_RE_THROW(); 685 | } 686 | PG_END_TRY(); 687 | } 688 | 689 | /* 690 | * ExecutorFinish hook: all we need do is track nesting depth 691 | */ 692 | static void 693 | pel_ExecutorFinish(QueryDesc *queryDesc) 694 | { 695 | exec_nested_level++; 696 | PG_TRY(); 697 | { 698 | if (prev_ExecutorFinish) 699 | prev_ExecutorFinish(queryDesc); 700 | else 701 | standard_ExecutorFinish(queryDesc); 702 | exec_nested_level--; 703 | } 704 | PG_CATCH(); 705 | { 706 | exec_nested_level--; 707 | PG_RE_THROW(); 708 | } 709 | PG_END_TRY(); 710 | } 711 | 712 | /* 713 | * ExecutorEnd hook: done required cleanup 714 | */ 715 | static void 716 | pel_ExecutorEnd(QueryDesc *queryDesc) 717 | { 718 | if (pel_enabled && exec_nested_level == 0) 719 | { 720 | if (current_bind_parameters != NULL) 721 | { 722 | pfree(current_bind_parameters); 723 | current_bind_parameters = NULL; 724 | } 725 | } 726 | 727 | if (prev_ExecutorEnd) 728 | prev_ExecutorEnd(queryDesc); 729 | else 730 | standard_ExecutorEnd(queryDesc); 731 | } 732 | 733 | /* 734 | * Log statement according to the user that launched the statement. 735 | */ 736 | static void 737 | pel_log_error(ErrorData *edata) 738 | { 739 | if (!pel_enabled 740 | || !edata || edata->elevel != ERROR /* Only process errors */ 741 | || !debug_query_string /* Ignore errors raised from non-backend processes */ 742 | || edata->sqlerrcode == ERRCODE_SUCCESSFUL_COMPLETION 743 | ) 744 | { 745 | goto prev_hook; 746 | } 747 | 748 | if (!pel_done) 749 | { 750 | MemoryContext pelcontext, oldcontext; 751 | List *stmts; 752 | RawStmt *raw; 753 | Node *stmt; 754 | const char *sql = debug_query_string; 755 | CmdType cmdType = CMD_UNKNOWN; 756 | char *operation = NULL; 757 | RangeVar *rv = NULL; 758 | Oid relid; 759 | 760 | pel_done = true; /* prevent recursive call */ 761 | 762 | pelcontext = AllocSetContextCreate(CurTransactionContext, 763 | "PEL temporary context", 764 | ALLOCSET_DEFAULT_SIZES); 765 | oldcontext = MemoryContextSwitchTo(pelcontext); 766 | #if PG_VERSION_NUM >= 140000 767 | stmts = raw_parser(sql, RAW_PARSE_DEFAULT); 768 | #else 769 | stmts = raw_parser(sql); 770 | #endif 771 | MemoryContextSwitchTo(oldcontext); 772 | stmts = list_copy_deep(stmts); 773 | MemoryContextDelete(pelcontext); 774 | 775 | if (list_length(stmts) != 1) 776 | { 777 | elog(WARNING, "pel_log_error(): not supported"); 778 | goto prev_hook; 779 | } 780 | raw = (RawStmt *) linitial(stmts); 781 | stmt = raw->stmt; 782 | 783 | if (IsA(stmt, ExecuteStmt)) 784 | { 785 | ExecuteStmt *s = (ExecuteStmt *) stmt; 786 | sql = lookupCachedPrepared(s->name); 787 | #if PG_VERSION_NUM >= 140000 788 | stmts = raw_parser(sql, RAW_PARSE_DEFAULT); 789 | #else 790 | stmts = raw_parser(sql); 791 | #endif 792 | 793 | if (list_length(stmts) != 1) 794 | { 795 | elog(WARNING, "not supported"); 796 | goto prev_hook; 797 | } 798 | 799 | raw = (RawStmt *) linitial(stmts); 800 | Assert(IsA(raw->stmt, PrepareStmt)); 801 | 802 | stmt = ((PrepareStmt *) raw->stmt)->query; 803 | } 804 | 805 | if(IsA(stmt, InsertStmt)) 806 | { 807 | rv = ((InsertStmt *) stmt)->relation; 808 | cmdType = CMD_INSERT; 809 | operation = "INSERT"; 810 | current_dml_kind = 'I'; 811 | } 812 | else if (IsA(stmt, UpdateStmt)) 813 | { 814 | rv = ((UpdateStmt *) stmt)->relation; 815 | cmdType = CMD_UPDATE; 816 | operation = "UPDATE"; 817 | current_dml_kind = 'U'; 818 | } 819 | else if (IsA(stmt, DeleteStmt)) 820 | { 821 | rv = ((DeleteStmt *) stmt)->relation; 822 | cmdType = CMD_DELETE; 823 | operation = "DELETE"; 824 | current_dml_kind = 'D'; 825 | } 826 | 827 | if (cmdType == CMD_UNKNOWN) 828 | { 829 | /* Unhandled DML, bail out */ 830 | goto prev_hook; 831 | } 832 | else 833 | { 834 | Assert(rv != NULL); 835 | Assert(operation != NULL); 836 | } 837 | 838 | relid = RangeVarGetRelid(rv, AccessShareLock, true); 839 | 840 | if (!OidIsValid(relid)) 841 | { 842 | if (rv->schemaname) 843 | elog(WARNING, "could not find an oid for relation \"%s\".\"%s\"", 844 | rv->schemaname, rv->relname); 845 | else 846 | elog(WARNING, "could not find an oid for relation \"%s\"", 847 | rv->relname); 848 | goto prev_hook; 849 | } 850 | 851 | elog(DEBUG1, "pel_log_error(): OPERATION: %s, KIND: %c, RELID: %u", operation, current_dml_kind, relid); 852 | 853 | /* Get the associated error logging table if any */ 854 | if (OidIsValid(relid)) 855 | { 856 | StringInfoData relstmt; 857 | StringInfoData msg; 858 | int rc = 0; 859 | Oid logtable; 860 | bool isnull, ok; 861 | bool need_priv_escalation = !superuser(); /* we might be a SU */ 862 | Oid save_userid; 863 | int save_sec_context; 864 | Relation rel; 865 | AclResult aclresult; 866 | 867 | initStringInfo(&relstmt); 868 | 869 | /* Inserting error to log table must be created as SU */ 870 | if (need_priv_escalation) 871 | { 872 | /* Get current user's Oid and security context */ 873 | GetUserIdAndSecContext(&save_userid, &save_sec_context); 874 | /* Become superuser */ 875 | SetUserIdAndSecContext(BOOTSTRAP_SUPERUSERID, save_sec_context 876 | | SECURITY_LOCAL_USERID_CHANGE 877 | | SECURITY_RESTRICTED_OPERATION); 878 | } 879 | 880 | rc = SPI_connect(); 881 | if (rc != SPI_OK_CONNECT) 882 | { 883 | elog(WARNING, "Can not connect to SPI manager to retrieve" 884 | " error log table for \"%s\", rc=%d. ", 885 | rv->relname, rc); 886 | goto prev_hook; 887 | } 888 | 889 | appendStringInfo(&relstmt, "SELECT e.relerrlog" 890 | " FROM %s.%s e" 891 | " WHERE e.reldml = %u", 892 | quote_identifier(PEL_NAMESPACE_NAME), 893 | quote_identifier(PEL_REGISTRATION_TABLE), 894 | relid); 895 | 896 | rc = SPI_exec(relstmt.data, 0); 897 | if (rc != SPI_OK_SELECT || SPI_processed != 1) 898 | { 899 | elog(WARNING, "SPI execution failure (rc=%d) on query: %s", 900 | rc, relstmt.data); 901 | goto prev_hook; 902 | } 903 | 904 | logtable = DatumGetObjectId(SPI_getbinval(SPI_tuptable->vals[0], 905 | SPI_tuptable->tupdesc, 906 | 1, 907 | &isnull)); 908 | if (isnull) 909 | { 910 | elog(WARNING, "can not get error logging table for table %s", 911 | relstmt.data); 912 | goto prev_hook; 913 | } 914 | 915 | rc = SPI_finish(); 916 | if (rc != SPI_OK_FINISH) 917 | { 918 | elog(WARNING, "could not disconnect from SPI manager"); 919 | goto prev_hook; 920 | } 921 | 922 | /* Restore user's privileges */ 923 | if (need_priv_escalation) 924 | SetUserIdAndSecContext(save_userid, save_sec_context); 925 | 926 | /* 927 | * Try to open the error log relation to catch priviledge issues 928 | * as the bg_worker will have the full priviledge on the table. 929 | */ 930 | rel = table_open(logtable, AccessShareLock); 931 | aclresult = pg_class_aclcheck(RelationGetRelid(rel), GetUserId(), 932 | ACL_INSERT); 933 | if (aclresult != ACLCHECK_OK) 934 | aclcheck_error(aclresult, get_relkind_objtype(rel->rd_rel->relkind), 935 | RelationGetRelationName(rel)); 936 | table_close(rel, AccessShareLock); 937 | 938 | /* generate the full error message to log */ 939 | initStringInfo(&msg); 940 | generate_error_message(edata, &msg); 941 | if (current_bind_parameters && current_bind_parameters[0] != '\0') 942 | { 943 | appendStringInfo(&msg, "PARAMETERS: %s", 944 | current_bind_parameters); 945 | } 946 | 947 | /* Queue the error information. */ 948 | ok = pel_queue_error(logtable, 949 | edata->sqlerrcode, 950 | edata->message, 951 | current_dml_kind, 952 | query_tag, 953 | sql, 954 | msg.data, 955 | PEL_SYNC_ON_QUERY()); 956 | if (!ok) 957 | goto prev_hook; 958 | 959 | elog(DEBUG1, "pel_log_error(): ERRCODE: %s;KIND: %c,TAG: %s;MESSAGE: %s;QUERY: %s;TABLE: %s; INFO: %s", 960 | unpack_sql_state(edata->sqlerrcode), 961 | current_dml_kind, 962 | (query_tag) ? query_tag : "null", 963 | (edata->message) ? edata->message : "null", 964 | quote_literal_cstr(sql), 965 | rv->relname, 966 | msg.data 967 | ); 968 | } 969 | if (pel_no_client_error) 970 | edata->output_to_client = false; 971 | } 972 | pel_done = false; 973 | 974 | prev_hook: 975 | if (current_bind_parameters != NULL) 976 | { 977 | pfree(current_bind_parameters); 978 | current_bind_parameters = NULL; 979 | } 980 | 981 | /* Continue chain to previous hook */ 982 | if (prev_emit_log_hook) 983 | (*prev_emit_log_hook) (edata); 984 | } 985 | 986 | static Size 987 | pel_memsize(void) 988 | { 989 | Size size; 990 | 991 | size = CACHELINEALIGN(sizeof(pelSharedState)); 992 | 993 | return size; 994 | } 995 | 996 | /* 997 | * append_with_tabs 998 | * 999 | * Append the string to the StringInfo buffer, inserting a tab after any 1000 | * newline. 1001 | */ 1002 | void 1003 | append_with_tabs(StringInfo buf, const char *str) 1004 | { 1005 | char ch; 1006 | 1007 | while ((ch = *str++) != '\0') 1008 | { 1009 | appendStringInfoCharMacro(buf, ch); 1010 | if (ch == '\n') 1011 | appendStringInfoCharMacro(buf, '\t'); 1012 | } 1013 | } 1014 | 1015 | void 1016 | generate_error_message (ErrorData *edata, StringInfoData *buf) 1017 | { 1018 | appendStringInfo(buf, "%s: ", "ERROR"); 1019 | appendStringInfo(buf, "%s: ", unpack_sql_state(edata->sqlerrcode)); 1020 | 1021 | if (edata->message) 1022 | append_with_tabs(buf, edata->message); 1023 | else 1024 | append_with_tabs(buf, _("missing error text")); 1025 | 1026 | if (edata->cursorpos > 0) 1027 | appendStringInfo(buf, _(" at character %d"), 1028 | edata->cursorpos); 1029 | else if (edata->internalpos > 0) 1030 | appendStringInfo(buf, _(" at character %d"), 1031 | edata->internalpos); 1032 | 1033 | appendStringInfoChar(buf, '\n'); 1034 | 1035 | if (edata->detail_log) 1036 | { 1037 | appendStringInfoString(buf, _("DETAIL: ")); 1038 | append_with_tabs(buf, edata->detail_log); 1039 | appendStringInfoChar(buf, '\n'); 1040 | } 1041 | else if (edata->detail) 1042 | { 1043 | appendStringInfoString(buf, _("DETAIL: ")); 1044 | append_with_tabs(buf, edata->detail); 1045 | appendStringInfoChar(buf, '\n'); 1046 | } 1047 | if (edata->hint) 1048 | { 1049 | appendStringInfoString(buf, _("HINT: ")); 1050 | append_with_tabs(buf, edata->hint); 1051 | appendStringInfoChar(buf, '\n'); 1052 | } 1053 | if (edata->internalquery) 1054 | { 1055 | appendStringInfoString(buf, _("QUERY: ")); 1056 | append_with_tabs(buf, edata->internalquery); 1057 | appendStringInfoChar(buf, '\n'); 1058 | } 1059 | if (edata->context) 1060 | { 1061 | appendStringInfoString(buf, _("CONTEXT: ")); 1062 | append_with_tabs(buf, edata->context); 1063 | appendStringInfoChar(buf, '\n'); 1064 | } 1065 | if (debug_query_string != NULL) 1066 | { 1067 | appendStringInfoString(buf, _("STATEMENT: ")); 1068 | append_with_tabs(buf, debug_query_string); 1069 | appendStringInfoChar(buf, '\n'); 1070 | } 1071 | } 1072 | 1073 | #if PG_VERSION_NUM < 130000 1074 | /* 1075 | * BuildParamLogString 1076 | * Return a string that represents the parameter list, for logging. 1077 | * 1078 | * If caller already knows textual representations for some parameters, it can 1079 | * pass an array of exactly params->numParams values as knownTextValues, which 1080 | * can contain NULLs for any unknown individual values. NULL can be given if 1081 | * no parameters are known. 1082 | * 1083 | * If maxlen is >= 0, that's the maximum number of bytes of any one 1084 | * parameter value to be printed; an ellipsis is added if the string is 1085 | * longer. (Added quotes are not considered in this calculation.) 1086 | */ 1087 | char * 1088 | BuildParamLogString(ParamListInfo params, char **knownTextValues, int maxlen) 1089 | { 1090 | MemoryContext tmpCxt, 1091 | oldCxt; 1092 | StringInfoData buf; 1093 | 1094 | /* 1095 | * NB: think not of returning params->paramValuesStr! It may have been 1096 | * generated with a different maxlen, and so be unsuitable. Besides that, 1097 | * this is the function used to create that string. 1098 | */ 1099 | 1100 | /* 1101 | * No work if the param fetch hook is in use. Also, it's not possible to 1102 | * do this in an aborted transaction. (It might be possible to improve on 1103 | * this last point when some knownTextValues exist, but it seems tricky.) 1104 | */ 1105 | if (params->paramFetch != NULL || 1106 | IsAbortedTransactionBlockState()) 1107 | return NULL; 1108 | 1109 | /* Initialize the output stringinfo, in caller's memory context */ 1110 | initStringInfo(&buf); 1111 | 1112 | /* Use a temporary context to call output functions, just in case */ 1113 | tmpCxt = AllocSetContextCreate(CurrentMemoryContext, 1114 | "BuildParamLogString", 1115 | ALLOCSET_DEFAULT_SIZES); 1116 | oldCxt = MemoryContextSwitchTo(tmpCxt); 1117 | 1118 | for (int paramno = 0; paramno < params->numParams; paramno++) 1119 | { 1120 | ParamExternData *param = ¶ms->params[paramno]; 1121 | 1122 | appendStringInfo(&buf, 1123 | "%s$%d = ", 1124 | paramno > 0 ? ", " : "", 1125 | paramno + 1); 1126 | 1127 | if (param->isnull || !OidIsValid(param->ptype)) 1128 | appendStringInfoString(&buf, "NULL"); 1129 | else 1130 | { 1131 | if (knownTextValues != NULL && knownTextValues[paramno] != NULL) 1132 | appendStringInfoStringQuoted(&buf, knownTextValues[paramno], 1133 | maxlen); 1134 | else 1135 | { 1136 | Oid typoutput; 1137 | bool typisvarlena; 1138 | char *pstring; 1139 | 1140 | getTypeOutputInfo(param->ptype, &typoutput, &typisvarlena); 1141 | pstring = OidOutputFunctionCall(typoutput, param->value); 1142 | appendStringInfoStringQuoted(&buf, pstring, maxlen); 1143 | } 1144 | } 1145 | } 1146 | 1147 | MemoryContextSwitchTo(oldCxt); 1148 | MemoryContextDelete(tmpCxt); 1149 | 1150 | return buf.data; 1151 | } 1152 | 1153 | /* 1154 | * appendStringInfoStringQuoted 1155 | * 1156 | * Append up to maxlen bytes from s to str, or the whole input string if 1157 | * maxlen < 0, adding single quotes around it and doubling all single quotes. 1158 | * Add an ellipsis if the copy is incomplete. 1159 | */ 1160 | void 1161 | appendStringInfoStringQuoted(StringInfo str, const char *s, int maxlen) 1162 | { 1163 | char *copy = NULL; 1164 | const char *chunk_search_start, 1165 | *chunk_copy_start, 1166 | *chunk_end; 1167 | int slen; 1168 | bool ellipsis; 1169 | 1170 | Assert(str != NULL); 1171 | 1172 | 1173 | slen = strlen(s); 1174 | if (maxlen >= 0 && maxlen < slen) 1175 | { 1176 | int finallen = pg_mbcliplen(s, slen, maxlen); 1177 | 1178 | copy = pnstrdup(s, finallen); 1179 | chunk_search_start = copy; 1180 | chunk_copy_start = copy; 1181 | 1182 | ellipsis = true; 1183 | } 1184 | else 1185 | { 1186 | chunk_search_start = s; 1187 | chunk_copy_start = s; 1188 | 1189 | ellipsis = false; 1190 | } 1191 | 1192 | appendStringInfoCharMacro(str, '\''); 1193 | 1194 | while ((chunk_end = strchr(chunk_search_start, '\'')) != NULL) 1195 | { 1196 | /* copy including the found delimiting ' */ 1197 | appendBinaryStringInfoNT(str, 1198 | chunk_copy_start, 1199 | chunk_end - chunk_copy_start + 1); 1200 | 1201 | /* in order to double it, include this ' into the next chunk as well */ 1202 | chunk_copy_start = chunk_end; 1203 | chunk_search_start = chunk_end + 1; 1204 | } 1205 | 1206 | /* copy the last chunk and terminate */ 1207 | if (ellipsis) 1208 | appendStringInfo(str, "%s...'", chunk_copy_start); 1209 | else 1210 | appendStringInfo(str, "%s'", chunk_copy_start); 1211 | 1212 | if (copy) 1213 | pfree(copy); 1214 | } 1215 | 1216 | #ifdef USE_ASSERT_CHECKING 1217 | /* 1218 | * Check that the specified List is valid (so far as we can tell). 1219 | */ 1220 | static void 1221 | check_list_invariants(const List *list) 1222 | { 1223 | if (list == NIL) 1224 | return; 1225 | 1226 | Assert(list->length > 0); 1227 | Assert(list->head != NULL); 1228 | Assert(list->tail != NULL); 1229 | 1230 | Assert(list->type == T_List || 1231 | list->type == T_IntList || 1232 | list->type == T_OidList); 1233 | 1234 | if (list->length == 1) 1235 | Assert(list->head == list->tail); 1236 | if (list->length == 2) 1237 | Assert(list->head->next == list->tail); 1238 | Assert(list->tail->next == NULL); 1239 | } 1240 | #else 1241 | #define check_list_invariants(l) 1242 | #endif /* USE_ASSERT_CHECKING */ 1243 | 1244 | /* 1245 | * Return a deep copy of the specified list. 1246 | * 1247 | * The list elements are copied via copyObject(), so that this function's 1248 | * idea of a "deep" copy is considerably deeper than what list_free_deep() 1249 | * means by the same word. 1250 | */ 1251 | static List * 1252 | list_copy_deep(const List *oldlist) 1253 | { 1254 | List *newlist = NIL; 1255 | ListCell *lc; 1256 | 1257 | if (oldlist == NIL) 1258 | return NIL; 1259 | 1260 | if (oldlist->type != T_List) 1261 | { 1262 | /* Should not be reached in our code */ 1263 | elog(ERROR, "list type unsupported"); 1264 | } 1265 | 1266 | /* This is only sensible for pointer Lists */ 1267 | Assert(IsA(oldlist, List)); 1268 | 1269 | foreach(lc, oldlist) 1270 | newlist = lappend(newlist, copyObjectImpl(lfirst(lc))); 1271 | 1272 | check_list_invariants(newlist); 1273 | return newlist; 1274 | } 1275 | #endif 1276 | 1277 | #if PG_VERSION_NUM < 110000 1278 | /* 1279 | * appendBinaryStringInfoNT 1280 | * 1281 | * Append arbitrary binary data to a StringInfo, allocating more space 1282 | * if necessary. Does not ensure a trailing null-byte exists. 1283 | */ 1284 | static void 1285 | appendBinaryStringInfoNT(StringInfo str, const char *data, int datalen) 1286 | { 1287 | Assert(str != NULL); 1288 | 1289 | /* Make more room if needed */ 1290 | enlargeStringInfo(str, datalen); 1291 | 1292 | /* OK, append the data */ 1293 | memcpy(str->data + str->len, data, datalen); 1294 | str->len += datalen; 1295 | } 1296 | #endif 1297 | -------------------------------------------------------------------------------- /pg_dbms_errlog.control: -------------------------------------------------------------------------------- 1 | # pg_error extension, requires pg_statement_rollback 2 | comment = 'Emulate DBMS_ERRLOG Oracle module to log DML errors in a dedicated table.' 3 | default_version = '2.1' 4 | module_pathname = '$libdir/pg_dbms_errlog' 5 | relocatable = false 6 | schema = 'dbms_errlog' 7 | -------------------------------------------------------------------------------- /sql/pg_dbms_errlog--1.0.sql: -------------------------------------------------------------------------------- 1 | --------------------------------------------------------------------------------- 2 | -- pg_dbms_errlog extension for PostgreSQL 3 | -- Emulate DBMS_ERRLOG Oracle module but in a simplistic way. 4 | --------------------------------------------------------------------------------- 5 | 6 | -- complain if script is sourced in psql, rather than via CREATE EXTENSION 7 | \echo Use "CREATE EXTENSION pg_dbms_errlog" to load this file. \quit 8 | 9 | -- check the functions bodies as creation time, enabled by default 10 | SET LOCAL check_function_bodies = on ; 11 | -- make sure of client encofing 12 | SET LOCAL client_encoding = 'UTF8'; 13 | 14 | 15 | -- Create the extension schema 16 | CREATE SCHEMA IF NOT EXISTS @extschema@; 17 | REVOKE ALL ON SCHEMA @extschema@ FROM PUBLIC; 18 | GRANT USAGE ON SCHEMA @extschema@ TO PUBLIC; 19 | 20 | 21 | -- Create registration table for error loging tables association 22 | CREATE TABLE @extschema@.register_errlog_tables 23 | ( 24 | reldml oid, -- oid of the table where DML are done 25 | relerrlog oid -- oid of the table for error logging 26 | ); 27 | CREATE UNIQUE INDEX ON @extschema@.register_errlog_tables(reldml); 28 | CREATE UNIQUE INDEX ON @extschema@.register_errlog_tables(relerrlog); 29 | 30 | -- Include tables into pg_dump 31 | SELECT pg_catalog.pg_extension_config_dump('register_errlog_tables', ''); 32 | 33 | CREATE OR REPLACE PROCEDURE @extschema@.create_error_log ( 34 | dml_table_name varchar(132), -- name of the DML table to base the error logging table on, can use fqdn. 35 | err_log_table_name varchar(132) DEFAULT NULL, -- name of the error logging table to create, default is the first 58 characters in the name of the DML table prefixed with 'ERR$_', can use fqdn. 36 | err_log_table_owner name DEFAULT NULL, -- name of the owner of the error logging table. Default current user. 37 | err_log_table_space name DEFAULT NULL -- tablespace the error logging table will be created in. 38 | ) AS 39 | $$ 40 | DECLARE 41 | sql_create_table text; 42 | sql_register_table text; 43 | fqdn_pos int := 0; 44 | err_log_tbname name := $2; 45 | BEGIN 46 | IF dml_table_name IS NULL THEN 47 | RAISE EXCEPTION 'You must specify a DML table name.'; 48 | END IF; 49 | IF err_log_table_name IS NULL THEN 50 | fqdn_pos := position('.' IN dml_table_name) + 1; 51 | err_log_tbname := '"ERR$_'||substring(dml_table_name FROM fqdn_pos FOR 58)||'"'; 52 | END IF; 53 | sql_create_table := 'CREATE TABLE '||err_log_tbname||' ( 54 | PG_ERR_NUMBER$ text, -- PostgreSQL error number 55 | PG_ERR_MESG$ text, -- PostgreSQL error message 56 | PG_ERR_OPTYP$ char(1), -- Type of operation: insert (I), update (U), delete (D) 57 | PG_ERR_TAG$ text, -- Label used to identify the DML batch 58 | PG_ERR_QUERY$ text, -- Query at origin 59 | PG_ERR_DETAIL$ text -- Detail of the query origin 60 | )'; 61 | 62 | EXECUTE sql_create_table; 63 | IF err_log_table_owner IS NOT NULL THEN 64 | EXECUTE 'ALTER TABLE '||err_log_tbname||' OWNER TO '||err_log_table_owner; 65 | END IF; 66 | IF err_log_table_space IS NOT NULL THEN 67 | EXECUTE 'ALTER TABLE '||err_log_tbname||' SET TABLESPACE '||err_log_table_space||' NOWAIT'; 68 | END IF; 69 | sql_register_table := 'INSERT INTO @extschema@.register_errlog_tables VALUES ('''||dml_table_name||'''::regclass::oid, '''||err_log_tbname||'''::regclass::oid)'; 70 | EXECUTE sql_register_table; 71 | END; 72 | $$ 73 | LANGUAGE plpgsql SECURITY INVOKER; 74 | 75 | -------------------------------------------------------------------------------- /sql/pg_dbms_errlog--1.1.sql: -------------------------------------------------------------------------------- 1 | --------------------------------------------------------------------------------- 2 | -- pg_dbms_errlog extension for PostgreSQL 3 | -- Emulate DBMS_ERRLOG Oracle module but in a simplistic way. 4 | --------------------------------------------------------------------------------- 5 | 6 | -- complain if script is sourced in psql, rather than via CREATE EXTENSION 7 | \echo Use "CREATE EXTENSION pg_dbms_errlog" to load this file. \quit 8 | 9 | -- check the functions bodies as creation time, enabled by default 10 | SET LOCAL check_function_bodies = on ; 11 | -- make sure of client encofing 12 | SET LOCAL client_encoding = 'UTF8'; 13 | 14 | 15 | -- Create the extension schema 16 | CREATE SCHEMA IF NOT EXISTS @extschema@; 17 | REVOKE ALL ON SCHEMA @extschema@ FROM PUBLIC; 18 | GRANT USAGE ON SCHEMA @extschema@ TO PUBLIC; 19 | 20 | 21 | -- Create registration table for error loging tables association 22 | CREATE TABLE @extschema@.register_errlog_tables 23 | ( 24 | reldml oid, -- oid of the table where DML are done 25 | relerrlog oid -- oid of the table for error logging 26 | ); 27 | CREATE UNIQUE INDEX ON @extschema@.register_errlog_tables(reldml); 28 | CREATE UNIQUE INDEX ON @extschema@.register_errlog_tables(relerrlog); 29 | 30 | -- Include tables into pg_dump 31 | SELECT pg_catalog.pg_extension_config_dump('register_errlog_tables', ''); 32 | 33 | CREATE OR REPLACE PROCEDURE @extschema@.create_error_log ( 34 | dml_table_name varchar(132), -- name of the DML table to base the error logging table on, can use fqdn. 35 | err_log_table_name varchar(132) DEFAULT NULL, -- name of the error logging table to create, default is the first 58 characters in the name of the DML table prefixed with 'ERR$_', can use fqdn. 36 | err_log_table_owner name DEFAULT NULL, -- name of the owner of the error logging table. Default current user. 37 | err_log_table_space name DEFAULT NULL -- tablespace the error logging table will be created in. 38 | ) AS 39 | $$ 40 | DECLARE 41 | sql_create_table text; 42 | sql_register_table text; 43 | fqdn_pos int := 0; 44 | err_log_tbname name := $2; 45 | BEGIN 46 | IF dml_table_name IS NULL THEN 47 | RAISE EXCEPTION 'You must specify a DML table name.'; 48 | END IF; 49 | IF err_log_table_name IS NULL THEN 50 | fqdn_pos := position('.' IN dml_table_name) + 1; 51 | err_log_tbname := '"ERR$_'||substring(dml_table_name FROM fqdn_pos FOR 58)||'"'; 52 | END IF; 53 | sql_create_table := 'CREATE TABLE '||err_log_tbname||' ( 54 | PG_ERR_NUMBER$ text, -- PostgreSQL error number 55 | PG_ERR_MESG$ text, -- PostgreSQL error message 56 | PG_ERR_OPTYP$ char(1), -- Type of operation: insert (I), update (U), delete (D) 57 | PG_ERR_TAG$ text, -- Label used to identify the DML batch 58 | PG_ERR_QUERY$ text, -- Query at origin 59 | PG_ERR_DETAIL$ text -- Detail of the query origin 60 | )'; 61 | 62 | EXECUTE sql_create_table; 63 | IF err_log_table_owner IS NOT NULL THEN 64 | EXECUTE 'ALTER TABLE '||err_log_tbname||' OWNER TO '||err_log_table_owner; 65 | END IF; 66 | IF err_log_table_space IS NOT NULL THEN 67 | EXECUTE 'ALTER TABLE '||err_log_tbname||' SET TABLESPACE '||err_log_table_space||' NOWAIT'; 68 | END IF; 69 | sql_register_table := 'INSERT INTO @extschema@.register_errlog_tables VALUES ('''||dml_table_name||'''::regclass::oid, '''||err_log_tbname||'''::regclass::oid)'; 70 | EXECUTE sql_register_table; 71 | END; 72 | $$ 73 | LANGUAGE plpgsql SECURITY INVOKER; 74 | 75 | CREATE OR REPLACE FUNCTION @extschema@.unregister_errlog_table() 76 | RETURNS event_trigger 77 | AS $$ 78 | DECLARE 79 | sql_unregister_table text; 80 | relinfo RECORD; 81 | BEGIN 82 | IF tg_tag = 'DROP TABLE' OR tg_tag = 'DROP SCHEMA' THEN 83 | FOR relinfo IN SELECT * FROM pg_catalog.pg_event_trigger_dropped_objects() WHERE object_type IN ('table', 'view') 84 | LOOP 85 | sql_unregister_table := 'DELETE FROM @extschema@.register_errlog_tables WHERE reldml ='||relinfo.objid||' OR relerrlog = '||relinfo.objid; 86 | EXECUTE sql_unregister_table; 87 | END LOOP; 88 | END IF; 89 | END; 90 | $$ LANGUAGE plpgsql; 91 | 92 | CREATE EVENT TRIGGER ddl_drop_errlog_table ON sql_drop EXECUTE PROCEDURE @extschema@.unregister_errlog_table(); 93 | 94 | -------------------------------------------------------------------------------- /sql/pg_dbms_errlog--1.2.sql: -------------------------------------------------------------------------------- 1 | --------------------------------------------------------------------------------- 2 | -- pg_dbms_errlog extension for PostgreSQL 3 | -- Emulate DBMS_ERRLOG Oracle module but in a simplistic way. 4 | --------------------------------------------------------------------------------- 5 | 6 | -- complain if script is sourced in psql, rather than via CREATE EXTENSION 7 | \echo Use "CREATE EXTENSION pg_dbms_errlog" to load this file. \quit 8 | 9 | -- check the functions bodies as creation time, enabled by default 10 | SET LOCAL check_function_bodies = on ; 11 | -- make sure of client encofing 12 | SET LOCAL client_encoding = 'UTF8'; 13 | 14 | 15 | -- Create the extension schema 16 | CREATE SCHEMA IF NOT EXISTS @extschema@; 17 | REVOKE ALL ON SCHEMA @extschema@ FROM PUBLIC; 18 | GRANT USAGE ON SCHEMA @extschema@ TO PUBLIC; 19 | 20 | 21 | -- Create registration table for error loging tables association 22 | CREATE TABLE @extschema@.register_errlog_tables 23 | ( 24 | reldml oid, -- oid of the table where DML are done 25 | relerrlog oid -- oid of the table for error logging 26 | ); 27 | CREATE UNIQUE INDEX ON @extschema@.register_errlog_tables(reldml); 28 | CREATE UNIQUE INDEX ON @extschema@.register_errlog_tables(relerrlog); 29 | 30 | -- Include tables into pg_dump 31 | SELECT pg_catalog.pg_extension_config_dump('register_errlog_tables', ''); 32 | 33 | CREATE OR REPLACE PROCEDURE @extschema@.create_error_log ( 34 | dml_table_name varchar(132), -- name of the DML table to base the error logging table on, can use fqdn. 35 | err_log_table_name varchar(132) DEFAULT NULL, -- name of the error logging table to create, default is the first 58 characters in the name of the DML table prefixed with 'ERR$_', can use fqdn. 36 | err_log_table_owner name DEFAULT NULL, -- name of the owner of the error logging table. Default current user. 37 | err_log_table_space name DEFAULT NULL -- tablespace the error logging table will be created in. 38 | ) AS 39 | $$ 40 | DECLARE 41 | sql_create_table text; 42 | sql_register_table text; 43 | fqdn_pos int := 0; 44 | err_log_tbname name := $2; 45 | BEGIN 46 | IF dml_table_name IS NULL THEN 47 | RAISE EXCEPTION 'You must specify a DML table name.'; 48 | END IF; 49 | IF err_log_table_name IS NULL THEN 50 | fqdn_pos := position('.' IN dml_table_name) + 1; 51 | err_log_tbname := '"ERR$_'||substring(dml_table_name FROM fqdn_pos FOR 58)||'"'; 52 | END IF; 53 | sql_create_table := 'CREATE TABLE '||err_log_tbname||' ( 54 | PG_ERR_NUMBER$ text, -- PostgreSQL error number 55 | PG_ERR_MESG$ text, -- PostgreSQL error message 56 | PG_ERR_OPTYP$ char(1), -- Type of operation: insert (I), update (U), delete (D) 57 | PG_ERR_TAG$ text, -- Label used to identify the DML batch 58 | PG_ERR_QUERY$ text, -- Query at origin 59 | PG_ERR_DETAIL$ text -- Detail of the query origin 60 | )'; 61 | 62 | EXECUTE sql_create_table; 63 | IF err_log_table_owner IS NOT NULL THEN 64 | EXECUTE 'ALTER TABLE '||err_log_tbname||' OWNER TO '||err_log_table_owner; 65 | END IF; 66 | IF err_log_table_space IS NOT NULL THEN 67 | EXECUTE 'ALTER TABLE '||err_log_tbname||' SET TABLESPACE '||err_log_table_space||' NOWAIT'; 68 | END IF; 69 | sql_register_table := 'INSERT INTO @extschema@.register_errlog_tables VALUES ('''||dml_table_name||'''::regclass::oid, '''||err_log_tbname||'''::regclass::oid)'; 70 | EXECUTE sql_register_table; 71 | END; 72 | $$ 73 | LANGUAGE plpgsql SECURITY INVOKER; 74 | 75 | CREATE OR REPLACE FUNCTION @extschema@.unregister_errlog_table() 76 | RETURNS event_trigger 77 | AS $$ 78 | DECLARE 79 | sql_unregister_table text; 80 | relinfo RECORD; 81 | BEGIN 82 | IF tg_tag = 'DROP TABLE' OR tg_tag = 'DROP SCHEMA' THEN 83 | FOR relinfo IN SELECT * FROM pg_catalog.pg_event_trigger_dropped_objects() WHERE object_type IN ('table', 'view') 84 | LOOP 85 | sql_unregister_table := 'DELETE FROM @extschema@.register_errlog_tables WHERE reldml ='||relinfo.objid||' OR relerrlog = '||relinfo.objid; 86 | EXECUTE sql_unregister_table; 87 | END LOOP; 88 | END IF; 89 | END; 90 | $$ LANGUAGE plpgsql; 91 | 92 | CREATE EVENT TRIGGER ddl_drop_errlog_table ON sql_drop EXECUTE PROCEDURE @extschema@.unregister_errlog_table(); 93 | 94 | -------------------------------------------------------------------------------- /sql/pg_dbms_errlog--1.3.sql: -------------------------------------------------------------------------------- 1 | --------------------------------------------------------------------------------- 2 | -- pg_dbms_errlog extension for PostgreSQL 3 | -- Emulate DBMS_ERRLOG Oracle module but in a simplistic way. 4 | --------------------------------------------------------------------------------- 5 | 6 | -- complain if script is sourced in psql, rather than via CREATE EXTENSION 7 | \echo Use "CREATE EXTENSION pg_dbms_errlog" to load this file. \quit 8 | 9 | -- check the functions bodies as creation time, enabled by default 10 | SET LOCAL check_function_bodies = on ; 11 | -- make sure of client encofing 12 | SET LOCAL client_encoding = 'UTF8'; 13 | 14 | 15 | -- Create the extension schema 16 | CREATE SCHEMA IF NOT EXISTS @extschema@; 17 | REVOKE ALL ON SCHEMA @extschema@ FROM PUBLIC; 18 | GRANT USAGE ON SCHEMA @extschema@ TO PUBLIC; 19 | 20 | 21 | -- Create registration table for error loging tables association 22 | CREATE TABLE @extschema@.register_errlog_tables 23 | ( 24 | reldml oid, -- oid of the table where DML are done 25 | relerrlog oid -- oid of the table for error logging 26 | ); 27 | CREATE UNIQUE INDEX ON @extschema@.register_errlog_tables(reldml); 28 | CREATE UNIQUE INDEX ON @extschema@.register_errlog_tables(relerrlog); 29 | 30 | -- Include tables into pg_dump 31 | SELECT pg_catalog.pg_extension_config_dump('register_errlog_tables', ''); 32 | 33 | CREATE OR REPLACE PROCEDURE @extschema@.create_error_log ( 34 | dml_table_name varchar(132), -- name of the DML table to base the error logging table on, can use fqdn. 35 | err_log_table_name varchar(132) DEFAULT NULL, -- name of the error logging table to create, default is the first 58 characters in the name of the DML table prefixed with 'ERR$_', can use fqdn. 36 | err_log_table_owner name DEFAULT NULL, -- name of the owner of the error logging table. Default current user. 37 | err_log_table_space name DEFAULT NULL -- tablespace the error logging table will be created in. 38 | ) AS 39 | $$ 40 | DECLARE 41 | sql_create_table text; 42 | sql_register_table text; 43 | fqdn_pos int := 0; 44 | err_log_tbname name := $2; 45 | BEGIN 46 | IF dml_table_name IS NULL THEN 47 | RAISE EXCEPTION 'You must specify a DML table name.'; 48 | END IF; 49 | IF err_log_table_name IS NULL THEN 50 | fqdn_pos := position('.' IN dml_table_name) + 1; 51 | err_log_tbname := '"ERR$_'||substring(dml_table_name FROM fqdn_pos FOR 58)||'"'; 52 | END IF; 53 | sql_create_table := 'CREATE TABLE '||err_log_tbname||' ( 54 | PG_ERR_NUMBER$ text, -- PostgreSQL error number 55 | PG_ERR_MESG$ text, -- PostgreSQL error message 56 | PG_ERR_OPTYP$ char(1), -- Type of operation: insert (I), update (U), delete (D) 57 | PG_ERR_TAG$ text, -- Label used to identify the DML batch 58 | PG_ERR_QUERY$ text, -- Query at origin 59 | PG_ERR_DETAIL$ text -- Detail of the query origin 60 | )'; 61 | 62 | EXECUTE sql_create_table; 63 | IF err_log_table_owner IS NOT NULL THEN 64 | EXECUTE 'ALTER TABLE '||err_log_tbname||' OWNER TO '||err_log_table_owner; 65 | END IF; 66 | IF err_log_table_space IS NOT NULL THEN 67 | EXECUTE 'ALTER TABLE '||err_log_tbname||' SET TABLESPACE '||err_log_table_space||' NOWAIT'; 68 | END IF; 69 | sql_register_table := 'INSERT INTO @extschema@.register_errlog_tables VALUES ('''||dml_table_name||'''::regclass::oid, '''||err_log_tbname||'''::regclass::oid)'; 70 | EXECUTE sql_register_table; 71 | END; 72 | $$ 73 | LANGUAGE plpgsql SECURITY INVOKER; 74 | 75 | CREATE OR REPLACE FUNCTION @extschema@.unregister_errlog_table() 76 | RETURNS event_trigger 77 | AS $$ 78 | DECLARE 79 | sql_unregister_table text; 80 | relinfo RECORD; 81 | BEGIN 82 | IF tg_tag = 'DROP TABLE' OR tg_tag = 'DROP SCHEMA' THEN 83 | FOR relinfo IN SELECT * FROM pg_catalog.pg_event_trigger_dropped_objects() WHERE object_type IN ('table', 'view') 84 | LOOP 85 | sql_unregister_table := 'DELETE FROM @extschema@.register_errlog_tables WHERE reldml ='||relinfo.objid||' OR relerrlog = '||relinfo.objid; 86 | EXECUTE sql_unregister_table; 87 | END LOOP; 88 | END IF; 89 | END; 90 | $$ LANGUAGE plpgsql; 91 | 92 | CREATE EVENT TRIGGER ddl_drop_errlog_table ON sql_drop EXECUTE PROCEDURE @extschema@.unregister_errlog_table(); 93 | 94 | -------------------------------------------------------------------------------- /sql/pg_dbms_errlog--2.0.sql: -------------------------------------------------------------------------------- 1 | --------------------------------------------------------------------------------- 2 | -- pg_dbms_errlog extension for PostgreSQL 3 | -- Emulate DBMS_ERRLOG Oracle module but in a simplistic way. 4 | --------------------------------------------------------------------------------- 5 | 6 | -- complain if script is sourced in psql, rather than via CREATE EXTENSION 7 | \echo Use "CREATE EXTENSION pg_dbms_errlog" to load this file. \quit 8 | 9 | -- check the functions bodies as creation time, enabled by default 10 | SET LOCAL check_function_bodies = on ; 11 | -- make sure of client encofing 12 | SET LOCAL client_encoding = 'UTF8'; 13 | 14 | 15 | -- Create the extension schema 16 | CREATE SCHEMA IF NOT EXISTS @extschema@; 17 | REVOKE ALL ON SCHEMA @extschema@ FROM PUBLIC; 18 | GRANT USAGE ON SCHEMA @extschema@ TO PUBLIC; 19 | 20 | 21 | -- Create registration table for error loging tables association 22 | CREATE TABLE @extschema@.register_errlog_tables 23 | ( 24 | reldml oid, -- oid of the table where DML are done 25 | relerrlog oid -- oid of the table for error logging 26 | ); 27 | CREATE UNIQUE INDEX ON @extschema@.register_errlog_tables(reldml); 28 | CREATE UNIQUE INDEX ON @extschema@.register_errlog_tables(relerrlog); 29 | 30 | -- Include tables into pg_dump 31 | SELECT pg_catalog.pg_extension_config_dump('register_errlog_tables', ''); 32 | 33 | CREATE OR REPLACE PROCEDURE @extschema@.create_error_log ( 34 | dml_table_name varchar(132), -- name of the DML table to base the error logging table on, can use fqdn. 35 | err_log_table_name varchar(132) DEFAULT NULL, -- name of the error logging table to create, default is the first 58 characters in the name of the DML table prefixed with 'ERR$_', can use fqdn. 36 | err_log_table_owner name DEFAULT NULL, -- name of the owner of the error logging table. Default current user. 37 | err_log_table_space name DEFAULT NULL -- tablespace the error logging table will be created in. 38 | ) AS 39 | $$ 40 | DECLARE 41 | sql_create_table text; 42 | sql_register_table text; 43 | fqdn_pos int := 0; 44 | err_log_tbname name := $2; 45 | BEGIN 46 | IF dml_table_name IS NULL THEN 47 | RAISE EXCEPTION 'You must specify a DML table name.'; 48 | END IF; 49 | IF err_log_table_name IS NULL THEN 50 | fqdn_pos := position('.' IN dml_table_name) + 1; 51 | err_log_tbname := '"ERR$_'||substring(dml_table_name FROM fqdn_pos FOR 58)||'"'; 52 | END IF; 53 | sql_create_table := 'CREATE TABLE '||err_log_tbname||' ( 54 | PG_ERR_NUMBER$ text, -- PostgreSQL error number 55 | PG_ERR_MESG$ text, -- PostgreSQL error message 56 | PG_ERR_OPTYP$ char(1), -- Type of operation: insert (I), update (U), delete (D) 57 | PG_ERR_TAG$ text, -- Label used to identify the DML batch 58 | PG_ERR_QUERY$ text, -- Query at origin 59 | PG_ERR_DETAIL$ text -- Detail of the query origin 60 | )'; 61 | 62 | EXECUTE sql_create_table; 63 | IF err_log_table_owner IS NOT NULL THEN 64 | EXECUTE 'ALTER TABLE '||err_log_tbname||' OWNER TO '||err_log_table_owner; 65 | END IF; 66 | IF err_log_table_space IS NOT NULL THEN 67 | EXECUTE 'ALTER TABLE '||err_log_tbname||' SET TABLESPACE '||err_log_table_space||' NOWAIT'; 68 | END IF; 69 | sql_register_table := 'INSERT INTO @extschema@.register_errlog_tables VALUES ('''||dml_table_name||'''::regclass::oid, '''||err_log_tbname||'''::regclass::oid)'; 70 | EXECUTE sql_register_table; 71 | END; 72 | $$ 73 | LANGUAGE plpgsql SECURITY INVOKER; 74 | 75 | CREATE OR REPLACE FUNCTION @extschema@.unregister_errlog_table() 76 | RETURNS event_trigger 77 | AS $$ 78 | DECLARE 79 | sql_unregister_table text; 80 | relinfo RECORD; 81 | BEGIN 82 | IF tg_tag = 'DROP TABLE' OR tg_tag = 'DROP SCHEMA' THEN 83 | FOR relinfo IN SELECT * FROM pg_catalog.pg_event_trigger_dropped_objects() WHERE object_type IN ('table', 'view') 84 | LOOP 85 | sql_unregister_table := 'DELETE FROM @extschema@.register_errlog_tables WHERE reldml ='||relinfo.objid||' OR relerrlog = '||relinfo.objid; 86 | EXECUTE sql_unregister_table; 87 | END LOOP; 88 | END IF; 89 | END; 90 | $$ LANGUAGE plpgsql; 91 | 92 | CREATE OR REPLACE FUNCTION @extschema@.publish_queue( 93 | wait_for_completion bool DEFAULT false 94 | ) RETURNS bool 95 | LANGUAGE C COST 1000 96 | AS '$libdir/pg_dbms_errlog', 'pg_dbms_errlog_publish_queue'; 97 | REVOKE ALL ON FUNCTION @extschema@.publish_queue FROM public; 98 | 99 | CREATE OR REPLACE FUNCTION @extschema@.queue_size( 100 | OUT num_errors integer 101 | ) RETURNS integer 102 | LANGUAGE C COST 1000 103 | AS '$libdir/pg_dbms_errlog', 'pg_dbms_errlog_queue_size'; 104 | GRANT ALL ON FUNCTION @extschema@.queue_size TO public; 105 | 106 | CREATE EVENT TRIGGER ddl_drop_errlog_table ON sql_drop EXECUTE PROCEDURE @extschema@.unregister_errlog_table(); 107 | -------------------------------------------------------------------------------- /sql/pg_dbms_errlog--2.1.sql: -------------------------------------------------------------------------------- 1 | --------------------------------------------------------------------------------- 2 | -- pg_dbms_errlog extension for PostgreSQL 3 | -- Emulate DBMS_ERRLOG Oracle module but in a simplistic way. 4 | --------------------------------------------------------------------------------- 5 | 6 | -- complain if script is sourced in psql, rather than via CREATE EXTENSION 7 | \echo Use "CREATE EXTENSION pg_dbms_errlog" to load this file. \quit 8 | 9 | -- check the functions bodies as creation time, enabled by default 10 | SET LOCAL check_function_bodies = on ; 11 | -- make sure of client encofing 12 | SET LOCAL client_encoding = 'UTF8'; 13 | 14 | 15 | -- Create the extension schema 16 | CREATE SCHEMA IF NOT EXISTS @extschema@; 17 | REVOKE ALL ON SCHEMA @extschema@ FROM PUBLIC; 18 | GRANT USAGE ON SCHEMA @extschema@ TO PUBLIC; 19 | 20 | 21 | -- Create registration table for error loging tables association 22 | CREATE TABLE @extschema@.register_errlog_tables 23 | ( 24 | reldml oid, -- oid of the table where DML are done 25 | relerrlog oid -- oid of the table for error logging 26 | ); 27 | CREATE UNIQUE INDEX ON @extschema@.register_errlog_tables(reldml); 28 | CREATE UNIQUE INDEX ON @extschema@.register_errlog_tables(relerrlog); 29 | 30 | -- Include tables into pg_dump 31 | SELECT pg_catalog.pg_extension_config_dump('register_errlog_tables', ''); 32 | 33 | CREATE OR REPLACE PROCEDURE @extschema@.create_error_log ( 34 | dml_table_name varchar(132), -- name of the DML table to base the error logging table on, can use fqdn. 35 | err_log_table_name varchar(132) DEFAULT NULL, -- name of the error logging table to create, default is the first 58 characters in the name of the DML table prefixed with 'ERR$_', can use fqdn. 36 | err_log_table_owner name DEFAULT NULL, -- name of the owner of the error logging table. Default current user. 37 | err_log_table_space name DEFAULT NULL -- tablespace the error logging table will be created in. 38 | ) AS 39 | $$ 40 | DECLARE 41 | sql_create_table text; 42 | sql_register_table text; 43 | fqdn_pos int := 0; 44 | err_log_tbname name := $2; 45 | err_log_namespace text; 46 | BEGIN 47 | IF dml_table_name IS NULL THEN 48 | RAISE EXCEPTION 'You must specify a DML table name.'; 49 | END IF; 50 | 51 | -- Verify that the DML table exists and get the 52 | -- schema and name of the table from the catalog 53 | SELECT n.nspname, c.relname INTO STRICT err_log_namespace, dml_table_name FROM pg_catalog.pg_namespace n JOIN pg_catalog.pg_class c ON (c.relnamespace = n.oid) WHERE c.oid = dml_table_name::regclass::oid; 54 | -- Set the name of the error table if it is not provided 55 | IF err_log_table_name IS NOT NULL THEN 56 | err_log_tbname := 'ERR$_'||substring(dml_table_name FROM 1 FOR 58); 57 | ELSE 58 | -- Remove quoting from table name if any 59 | err_log_table_name := replace(err_log_table_name, '"', ''); 60 | fqdn_pos := position('.' IN err_log_table_name) + 1; 61 | err_log_tbname := substring(err_log_table_name FROM fqdn_pos FOR 58); 62 | IF fqdn_pos > 1 THEN 63 | err_log_namespace := substring(err_log_table_name FROM 1 FOR fqdn_pos - 2); 64 | END IF; 65 | END IF; 66 | err_log_tbname := quote_ident(err_log_namespace) || '.' || quote_ident(err_log_tbname); 67 | 68 | -- Create the error log table 69 | sql_create_table := 'CREATE TABLE '||err_log_tbname||' ( 70 | PG_ERR_NUMBER$ text, -- PostgreSQL error number 71 | PG_ERR_MESG$ text, -- PostgreSQL error message 72 | PG_ERR_OPTYP$ char(1), -- Type of operation: insert (I), update (U), delete (D) 73 | PG_ERR_TAG$ text, -- Label used to identify the DML batch 74 | PG_ERR_QUERY$ text, -- Query at origin 75 | PG_ERR_DETAIL$ text -- Detail of the query origin 76 | )'; 77 | 78 | EXECUTE sql_create_table; 79 | IF err_log_table_owner IS NOT NULL THEN 80 | EXECUTE 'ALTER TABLE '||err_log_tbname||' OWNER TO '||err_log_table_owner; 81 | END IF; 82 | IF err_log_table_space IS NOT NULL THEN 83 | EXECUTE 'ALTER TABLE '||err_log_tbname||' SET TABLESPACE '||err_log_table_space||' NOWAIT'; 84 | END IF; 85 | sql_register_table := 'INSERT INTO @extschema@.register_errlog_tables VALUES ('''||dml_table_name||'''::regclass::oid, '''||err_log_tbname||'''::regclass::oid)'; 86 | EXECUTE sql_register_table; 87 | END; 88 | $$ 89 | LANGUAGE plpgsql SECURITY INVOKER; 90 | 91 | CREATE OR REPLACE FUNCTION @extschema@.unregister_errlog_table() 92 | RETURNS event_trigger 93 | AS $$ 94 | DECLARE 95 | sql_unregister_table text; 96 | relinfo RECORD; 97 | BEGIN 98 | IF tg_tag = 'DROP TABLE' OR tg_tag = 'DROP SCHEMA' THEN 99 | FOR relinfo IN SELECT * FROM pg_catalog.pg_event_trigger_dropped_objects() WHERE object_type IN ('table', 'view') 100 | LOOP 101 | sql_unregister_table := 'DELETE FROM @extschema@.register_errlog_tables WHERE reldml ='||relinfo.objid||' OR relerrlog = '||relinfo.objid; 102 | EXECUTE sql_unregister_table; 103 | END LOOP; 104 | END IF; 105 | END; 106 | $$ LANGUAGE plpgsql; 107 | 108 | CREATE OR REPLACE FUNCTION @extschema@.publish_queue( 109 | wait_for_completion bool DEFAULT false 110 | ) RETURNS bool 111 | LANGUAGE C COST 1000 112 | AS '$libdir/pg_dbms_errlog', 'pg_dbms_errlog_publish_queue'; 113 | REVOKE ALL ON FUNCTION @extschema@.publish_queue FROM public; 114 | 115 | CREATE OR REPLACE FUNCTION @extschema@.queue_size( 116 | OUT num_errors integer 117 | ) RETURNS integer 118 | LANGUAGE C COST 1000 119 | AS '$libdir/pg_dbms_errlog', 'pg_dbms_errlog_queue_size'; 120 | GRANT ALL ON FUNCTION @extschema@.queue_size TO public; 121 | 122 | CREATE EVENT TRIGGER ddl_drop_errlog_table ON sql_drop EXECUTE PROCEDURE @extschema@.unregister_errlog_table(); 123 | -------------------------------------------------------------------------------- /test/batch_script_example.pl: -------------------------------------------------------------------------------- 1 | #!/usr/bin/perl 2 | 3 | use DBI; 4 | 5 | print "Creating the regression database.\n"; 6 | my $dbh = DBI->connect("dbi:Pg:dbname=template1", '', '', {AutoCommit => 1}); 7 | die "ERROR: can't connect to database template1\n" if (not defined $dbh); 8 | $dbh->do("DROP DATABASE contrib_regression"); 9 | $dbh->do("CREATE DATABASE contrib_regression"); 10 | $dbh->do("ALTER DATABASE contrib_regression SET lc_messages = 'C'"); 11 | $dbh->disconnect; 12 | 13 | print "Connect to the regression database.\n"; 14 | $dbh = DBI->connect("dbi:Pg:dbname=contrib_regression", '', '', {AutoCommit => 1, PrintError => 0}); 15 | die "ERROR: can't connect to database ontrib_regression\n" if (not defined $dbh); 16 | print "---------------------------------------------\n"; 17 | print "Create the extension and initialize the test\n"; 18 | print "---------------------------------------------\n"; 19 | $dbh->do("CREATE EXTENSION pg_dbms_errlog"); 20 | $dbh->do("CREATE TABLE t1 (a bigint PRIMARY KEY, lbl text)"); 21 | $dbh->do("CALL dbms_errlog.create_error_log('t1')"); 22 | $dbh->do("SET pg_dbms_errlog.synchronous TO 'transaction'"); 23 | $dbh->do("SET pg_dbms_errlog.query_tag TO 'daily_load'"); 24 | $dbh->do("SET pg_dbms_errlog.reject_limit TO 25"); 25 | $dbh->do("SET pg_dbms_errlog.enabled TO true"); 26 | $dbh->do("BEGIN"); 27 | print "---------------------------------------------\n"; 28 | print "Start DML work\n"; 29 | print "---------------------------------------------\n"; 30 | for (my $i = 0; $i <= 10; $i++) 31 | { 32 | $dbh->do("SAVEPOINT aze"); 33 | my $sth = $dbh->prepare("INSERT INTO t1 VALUES (?, ?)"); 34 | if (not defined $sth) { 35 | #print STDERR "PREPARE ERROR: " . $dbh->errstr . "\n"; 36 | next; 37 | } 38 | # Generate a duplicate key each two row inserted 39 | my $val = $i; 40 | $val = $i-1 if ($i % 2 != 0); 41 | unless ($sth->execute($val, 'insert '.$i)) { 42 | #print STDERR "EXECUTE ERROR: " . $dbh->errstr . "\n"; 43 | $dbh->do("ROLLBACK TO aze"); 44 | } 45 | } 46 | 47 | print "---------------------------------------------\n"; 48 | print "Look at inserted values in DML table\n"; 49 | print "---------------------------------------------\n"; 50 | my $sth = $dbh->prepare("SELECT * FROM t1"); 51 | $sth->execute(); 52 | while (my $row = $sth->fetch) { 53 | print "INSERTED ID: $row->[0]\n"; 54 | } 55 | $dbh->do("COMMIT;"); 56 | 57 | print "---------------------------------------------\n"; 58 | print "Look at failing insert in error logging table\n"; 59 | print "---------------------------------------------\n"; 60 | $sth = $dbh->prepare('SELECT * FROM "ERR$_t1"'); 61 | $sth->execute(); 62 | while (my $row = $sth->fetch) { 63 | print "ERROR: LOGGED: ", join(' | ', @$row), "\n"; 64 | } 65 | 66 | $dbh->disconnect; 67 | 68 | exit 0; 69 | -------------------------------------------------------------------------------- /test/sql/00-init.sql: -------------------------------------------------------------------------------- 1 | /* 2 | * Must be executed before all regression test. 3 | */ 4 | 5 | -- Create the PostgreSQL extension 6 | CREATE EXTENSION pg_dbms_errlog; 7 | 8 | -- Create the test table 9 | CREATE TABLE IF NOT EXISTS t1 (a bigint PRIMARY KEY); 10 | 11 | -------------------------------------------------------------------------------- /test/sql/01-basic.sql: -------------------------------------------------------------------------------- 1 | SET pg_dbms_errlog.synchronous = query; 2 | 3 | -- Create the error log table for relation t1 4 | CALL dbms_errlog.create_error_log('t1'); 5 | SELECT count(*) FROM dbms_errlog.register_errlog_tables ; 6 | 7 | -- Set error log behavior for this DML batch 8 | SET pg_dbms_errlog.query_tag TO 'daily_load'; 9 | SET pg_dbms_errlog.reject_limit TO 25; 10 | SET pg_dbms_errlog.enabled TO true; 11 | 12 | -- Start a transaction 13 | BEGIN; 14 | -- Insert will fail 15 | SAVEPOINT aze; 16 | INSERT INTO t1 VALUES ('10.4'); 17 | ROLLBACK TO aze; 18 | SELECT * FROM "ERR$_t1" 19 | ORDER BY "pg_err_number$" COLLATE "C", "pg_err_mesg$" COLLATE "C"; 20 | -- Insert successful 21 | INSERT INTO t1 VALUES (1); 22 | -- Insert will fail on duplicate key 23 | SAVEPOINT aze; 24 | INSERT INTO t1 VALUES (1); 25 | ROLLBACK TO aze; 26 | SELECT * FROM "ERR$_t1" 27 | ORDER BY "pg_err_number$" COLLATE "C", "pg_err_mesg$" COLLATE "C"; 28 | PREPARE prep_insert AS INSERT INTO t1 VALUES ($1); 29 | -- Insert successful 30 | SAVEPOINT aze; 31 | EXECUTE prep_insert(2); 32 | ROLLBACK TO aze; 33 | -- Insert will fail 34 | SAVEPOINT aze; 35 | EXECUTE prep_insert('10.5'); 36 | ROLLBACK TO aze; 37 | DEALLOCATE prep_insert; 38 | ROLLBACK; 39 | 40 | -- Looking at error logging table 41 | \x 42 | SELECT * FROM "ERR$_t1" 43 | ORDER BY "pg_err_number$" COLLATE "C", "pg_err_mesg$" COLLATE "C"; 44 | \x 45 | 46 | TRUNCATE "ERR$_t1"; 47 | 48 | -- test queue discard on rollback 49 | SET pg_dbms_errlog.synchronous = off; 50 | BEGIN; 51 | SAVEPOINT aze; 52 | INSERT INTO t1 VALUES ('queue 1'); 53 | ROLLBACK TO aze; 54 | -- commit should discard the queue 55 | ROLLBACK; 56 | SELECT dbms_errlog.publish_queue(true); 57 | SELECT 0 AS exp, count(*) FROM "ERR$_t1"; 58 | 59 | BEGIN; 60 | INSERT INTO t1 VALUES ('queue 2'); 61 | -- unsuccessful commit should discard the queue 62 | COMMIT; 63 | SELECT dbms_errlog.publish_queue(true); 64 | SELECT 0 AS exp, count(*) FROM "ERR$_t1"; 65 | 66 | BEGIN; 67 | SAVEPOINT aze; 68 | INSERT INTO t1 VALUES ('queue 3'); 69 | ROLLBACK TO aze; 70 | SET pg_dbms_errlog.synchronous = query; 71 | -- commit should publish the queue even in query level sync 72 | COMMIT; 73 | SELECT 1 AS exp, count(*) FROM "ERR$_t1"; 74 | 75 | SET pg_dbms_errlog.synchronous = off; 76 | BEGIN; 77 | SAVEPOINT aze; 78 | INSERT INTO t1 VALUES ('queue 4'); 79 | ROLLBACK TO aze; 80 | -- should publish the queue and wait for the result 81 | SELECT dbms_errlog.publish_queue(true); 82 | SELECT 2 AS exp, count(*) FROM "ERR$_t1"; 83 | -- error should still be visible in the error table 84 | ROLLBACK; 85 | SELECT 2 AS exp, count(*) FROM "ERR$_t1"; 86 | 87 | TRUNCATE "ERR$_t1"; 88 | 89 | -- test queuing multiple batches 90 | SET pg_dbms_errlog.synchronous = off; 91 | SET pg_dbms_errlog.frequency TO '1h'; 92 | 93 | BEGIN; 94 | SAVEPOINT aze; 95 | INSERT INTO t1 VALUES ('queue 5'); 96 | ROLLBACK TO aze; 97 | COMMIT; 98 | SELECT 0 AS exp, count(*) FROM "ERR$_t1"; 99 | 100 | BEGIN; 101 | SAVEPOINT aze; 102 | INSERT INTO t1 VALUES ('queue 6'); 103 | ROLLBACK TO aze; 104 | SET pg_dbms_errlog.synchronous = query; 105 | COMMIT; 106 | SELECT 2 AS exp, count(*) FROM "ERR$_t1"; 107 | 108 | TRUNCATE "ERR$_t1"; 109 | 110 | -- test waiting for already published batches 111 | SET pg_dbms_errlog.synchronous = off; 112 | 113 | BEGIN; 114 | SAVEPOINT aze; 115 | INSERT INTO t1 VALUES ('queue 7'); 116 | ROLLBACK TO aze; 117 | COMMIT; 118 | 119 | BEGIN; 120 | SAVEPOINT aze; 121 | INSERT INTO t1 VALUES ('queue 8'); 122 | ROLLBACK TO aze; 123 | COMMIT; 124 | 125 | SELECT 0 AS exp, count(*) FROM "ERR$_t1"; 126 | SELECT dbms_errlog.publish_queue(true); 127 | SELECT 2 AS exp, count(*) FROM "ERR$_t1"; 128 | 129 | TRUNCATE "ERR$_t1"; 130 | 131 | -- test transaction level sync 132 | SET pg_dbms_errlog.synchronous = transaction; 133 | BEGIN; 134 | SAVEPOINT aze; 135 | INSERT INTO t1 VALUES ('queue 9'); 136 | ROLLBACK TO aze; 137 | -- the error should not have been published or processed 138 | SELECT 0 AS exp, count(*) FROM "ERR$_t1"; 139 | -- commit should publish the error and wait for the result 140 | COMMIT; 141 | SELECT 1 AS exp, count(*) FROM "ERR$_t1"; 142 | 143 | RESET pg_dbms_errlog.frequency; 144 | 145 | TRUNCATE "ERR$_t1"; 146 | 147 | -- test reject_limit 148 | SET pg_dbms_errlog.reject_limit TO 0; 149 | -- there shouldn't be any queue created 150 | SELECT * FROM dbms_errlog.queue_size(); 151 | BEGIN; 152 | SAVEPOINT aze; 153 | -- should fail complaining that nothing can be queue 154 | INSERT INTO t1 VALUES ('queue 10'); 155 | ROLLBACK TO aze; 156 | -- the error should not have been published or processed 157 | SELECT 0 AS exp, count(*) FROM "ERR$_t1"; 158 | -- there shouldn't be any queue created 159 | SELECT * FROM dbms_errlog.queue_size(); 160 | COMMIT; 161 | -- the error should not have been published or processed 162 | SELECT 0 AS exp, count(*) FROM "ERR$_t1"; 163 | 164 | SET pg_dbms_errlog.reject_limit TO 1; 165 | BEGIN; 166 | SAVEPOINT aze; 167 | INSERT INTO t1 VALUES ('queue 11a'); 168 | ROLLBACK TO aze; 169 | -- the error should not have been published or processed 170 | SELECT 0 AS exp, count(*) FROM "ERR$_t1"; 171 | -- there should be 1 queued item 172 | SELECT 1 AS exp, * FROM dbms_errlog.queue_size(); 173 | -- should fail complaining that reject_limit has been reached 174 | INSERT INTO t1 VALUES ('queue 11b'); 175 | ROLLBACK TO aze; 176 | -- the queue should have been discarded 177 | SELECT * FROM dbms_errlog.queue_size(); 178 | COMMIT; 179 | -- the error should not have been published or processed 180 | SELECT 0 AS exp, count(*) FROM "ERR$_t1"; 181 | 182 | -- Dropping one of the table 183 | BEGIN; 184 | DROP TABLE "ERR$_t1"; 185 | SELECT count(*) FROM dbms_errlog.register_errlog_tables ; 186 | ROLLBACK; 187 | SELECT count(*) FROM dbms_errlog.register_errlog_tables ; 188 | BEGIN; 189 | DROP TABLE t1; 190 | SELECT count(*) FROM dbms_errlog.register_errlog_tables ; 191 | ROLLBACK; 192 | SELECT count(*) FROM dbms_errlog.register_errlog_tables ; 193 | DROP TABLE "ERR$_t1"; 194 | -------------------------------------------------------------------------------- /test/sql/02-upt-del.sql: -------------------------------------------------------------------------------- 1 | SET pg_dbms_errlog.synchronous = query; 2 | 3 | -- Create the error log table for relation t1 in a dedicated schema 4 | CREATE SCHEMA testerrlog; 5 | CALL dbms_errlog.create_error_log('public."t1"', 'testerrlog."errTable"'); 6 | SELECT count(*) FROM dbms_errlog.register_errlog_tables ; 7 | 8 | -- Set error log behavior for this DML batch 9 | SET pg_dbms_errlog.query_tag TO 'daily_load'; 10 | SET pg_dbms_errlog.reject_limit TO -1; 11 | SET pg_dbms_errlog.enabled TO true; 12 | 13 | -- Start a transaction 14 | BEGIN; 15 | -- Insert successful 16 | INSERT INTO t1 VALUES (3); 17 | -- DELETE will fail 18 | SAVEPOINT aze; 19 | DELETE FROM t1 WHERE a = '10.6'; 20 | ROLLBACK TO aze; 21 | SELECT * FROM testerrlog."errTable" 22 | ORDER BY "pg_err_number$" COLLATE "C", "pg_err_mesg$" COLLATE "C"; 23 | -- Update will fail but at parser level, it must not be logged 24 | SAVEPOINT aze; 25 | UPDATE t1 SET a = '10.7'::varchar interval WHERE a = 1; 26 | ROLLBACK TO aze; 27 | -- Test prepared statement 28 | PREPARE prep_delete (bigint) AS DELETE FROM t1 WHERE a IN ($1); 29 | -- Delete will fail 30 | SAVEPOINT aze; 31 | EXECUTE prep_delete ('10.8'); 32 | ROLLBACK TO aze; 33 | DEALLOCATE prep_delete; 34 | PREPARE prep_update (bigint) AS UPDATE t1 SET a = $1 WHERE a = 2; 35 | -- Update will fail 36 | SAVEPOINT aze; 37 | EXECUTE prep_update('10.9'); 38 | ROLLBACK TO aze; 39 | DEALLOCATE prep_update; 40 | ROLLBACK; 41 | 42 | -- Looking at error logging table 43 | \x 44 | SELECT * FROM testerrlog."errTable" 45 | ORDER BY "pg_err_number$" COLLATE "C", "pg_err_mesg$" COLLATE "C"; 46 | \x 47 | 48 | -- Dropping one of the table 49 | BEGIN; 50 | DROP TABLE testerrlog."errTable"; 51 | SELECT count(*) FROM dbms_errlog.register_errlog_tables ; 52 | ROLLBACK; 53 | SELECT count(*) FROM dbms_errlog.register_errlog_tables ; 54 | BEGIN; 55 | DROP TABLE t1; 56 | SELECT count(*) FROM dbms_errlog.register_errlog_tables ; 57 | ROLLBACK; 58 | SELECT count(*) FROM dbms_errlog.register_errlog_tables ; 59 | DROP TABLE testerrlog."errTable"; 60 | -------------------------------------------------------------------------------- /test/sql/03-trig-fct.sql: -------------------------------------------------------------------------------- 1 | SET pg_dbms_errlog.synchronous = query; 2 | 3 | -- Create the error log table for relation t1 in a dedicated schema 4 | CALL dbms_errlog.create_error_log('public."t1"', 'testerrlog."errTable"'); 5 | SELECT count(*) FROM dbms_errlog.register_errlog_tables ; 6 | 7 | CREATE TABLE t2 (id varchar); 8 | 9 | -- Create the trigger that will generate an error, must be logged 10 | CREATE FUNCTION trig_fct() RETURNS TRIGGER AS 11 | $$ 12 | BEGIN 13 | INSERT INTO t2 VALUES (NEW.id); 14 | RETURN NEW; 15 | END; 16 | $$ LANGUAGE plpgsql; 17 | 18 | CREATE TRIGGER t1_insert BEFORE INSERT ON t1 FOR EACH ROW EXECUTE PROCEDURE trig_fct(); 19 | 20 | -- Set error log behavior for this DML batch 21 | SET pg_dbms_errlog.query_tag TO 'daily_load'; 22 | SET pg_dbms_errlog.reject_limit TO 25; 23 | SET pg_dbms_errlog.enabled TO true; 24 | 25 | -- Start a transaction 26 | BEGIN; 27 | -- Insert will fail inside trigger 28 | SAVEPOINT aze; 29 | INSERT INTO t1 VALUES (7); 30 | ROLLBACK TO aze; 31 | DROP TRIGGER t1_insert ON t1; 32 | -- Create a function that execute a failing insert, must not ne logged 33 | CREATE FUNCTION insert_fct() RETURNS integer AS 34 | $$ 35 | BEGIN 36 | INSERT INTO t1 VALUES (1234.45); 37 | RETURN 1; 38 | END; 39 | $$ LANGUAGE plpgsql; 40 | SAVEPOINT aze; 41 | SELECT insert_fct(); 42 | ROLLBACK TO aze; 43 | ROLLBACK; 44 | 45 | -- Looking at error logging table 46 | \x 47 | SELECT * FROM testerrlog."errTable" 48 | ORDER BY "pg_err_number$" COLLATE "C", "pg_err_mesg$" COLLATE "C"; 49 | \x 50 | 51 | -- Dropping one of the table 52 | BEGIN; 53 | DROP TABLE testerrlog."errTable"; 54 | SELECT count(*) FROM dbms_errlog.register_errlog_tables ; 55 | ROLLBACK; 56 | SELECT count(*) FROM dbms_errlog.register_errlog_tables ; 57 | BEGIN; 58 | DROP TABLE t1; 59 | SELECT count(*) FROM dbms_errlog.register_errlog_tables ; 60 | ROLLBACK; 61 | SELECT count(*) FROM dbms_errlog.register_errlog_tables ; 62 | DROP TABLE testerrlog."errTable"; 63 | 64 | DROP TRIGGER t1_insert ON t1; 65 | DROP FUNCTION trig_fct; 66 | DROP TABLE t2; 67 | DROP TABLE t1; 68 | -------------------------------------------------------------------------------- /test/sql/04-partition.sql: -------------------------------------------------------------------------------- 1 | SET pg_dbms_errlog.synchronous = query; 2 | 3 | CREATE TABLE measurement ( 4 | city_id int not null, 5 | logdate date not null, 6 | peaktemp int, 7 | unitsales int 8 | ) PARTITION BY RANGE (logdate); 9 | 10 | CREATE TABLE measurement_y2006m02 PARTITION OF measurement 11 | FOR VALUES FROM ('2006-02-01') TO ('2006-03-01'); 12 | 13 | CREATE TABLE measurement_y2006m03 PARTITION OF measurement 14 | FOR VALUES FROM ('2006-03-01') TO ('2006-04-01'); 15 | 16 | -- Create the error log table for relation t1 in a dedicated schema 17 | CALL dbms_errlog.create_error_log('public.measurement'); 18 | SELECT count(*) FROM dbms_errlog.register_errlog_tables ; 19 | 20 | -- Set error log behavior for this DML batch 21 | SET pg_dbms_errlog.query_tag TO 'daily_load'; 22 | SET pg_dbms_errlog.reject_limit TO 25; 23 | SET pg_dbms_errlog.enabled TO true; 24 | 25 | -- Start a transaction 26 | BEGIN; 27 | -- Insert will fail inside trigger 28 | SAVEPOINT aze; 29 | INSERT INTO measurement VALUES (1, '2006-04-01', 0, 2); 30 | ROLLBACK TO aze; 31 | ROLLBACK; 32 | 33 | -- Looking at error logging table 34 | \x 35 | SELECT * FROM "ERR$_measurement" 36 | ORDER BY "pg_err_number$" COLLATE "C", "pg_err_mesg$" COLLATE "C"; 37 | \x 38 | 39 | -- Dropping one of the table 40 | BEGIN; 41 | DROP TABLE "ERR$_measurement"; 42 | SELECT count(*) FROM dbms_errlog.register_errlog_tables ; 43 | ROLLBACK; 44 | SELECT count(*) FROM dbms_errlog.register_errlog_tables ; 45 | BEGIN; 46 | DROP TABLE measurement; 47 | SELECT count(*) FROM dbms_errlog.register_errlog_tables ; 48 | ROLLBACK; 49 | SELECT count(*) FROM dbms_errlog.register_errlog_tables ; 50 | DROP TABLE "ERR$_measurement"; 51 | DROP TABLE measurement; 52 | 53 | -------------------------------------------------------------------------------- /test/sql/05-privileges.sql: -------------------------------------------------------------------------------- 1 | ------------------------------------------------------------------ 2 | -- Test privilege on errorlog table. A user need to be granted the 3 | -- DML privilege to the table and to the error log table to be able 4 | -- to use this feature. Insert to the registration table is done 5 | -- internally by superuser, to allow a user to create an error logging 6 | -- logging table he must be granted to execute the create_error_log() 7 | -- function and have read/write access to the registration table 8 | -- dbms_errlog.register_errlog_tables. 9 | ---------------------------------------------------------------- 10 | 11 | -- Set error log behavior for this DML batch 12 | SET pg_dbms_errlog.synchronous = query; 13 | SET pg_dbms_errlog.query_tag TO 'daily_load1'; 14 | SET pg_dbms_errlog.reject_limit TO 25; 15 | SET pg_dbms_errlog.enabled TO true; 16 | 17 | DROP ROLE IF EXISTS pel_u1; 18 | CREATE ROLE pel_u1 LOGIN; 19 | 20 | CREATE TABLE t2 ( 21 | id int NOT NULL 22 | ); 23 | GRANT ALL ON t2 TO pel_u1; 24 | 25 | -- Create the error log table for relation t2 26 | CALL dbms_errlog.create_error_log('t2'); 27 | -- Verify that it have been registered 28 | SELECT count(*) FROM dbms_errlog.register_errlog_tables ; 29 | 30 | -- Start a transaction 31 | BEGIN; 32 | SAVEPOINT aze; 33 | -- Insert will fail with insuffisient privilege and be registered to ERR$_t2 34 | INSERT INTO t2 VALUES (NULL); 35 | ROLLBACK TO aze; 36 | COMMIT; 37 | 38 | -- Show content of the error log table with test user. 39 | \x 40 | SELECT * FROM "ERR$_t2" 41 | ORDER BY "pg_err_number$" COLLATE "C", "pg_err_mesg$" COLLATE "C"; 42 | \x 43 | 44 | -- Cleanup 45 | DELETE FROM "ERR$_t2"; 46 | 47 | -- connect as basic user to test privileges 48 | SET SESSION AUTHORIZATION 'pel_u1'; 49 | 50 | -- Set error log behavior for this DML batch 51 | SET pg_dbms_errlog.synchronous = query; 52 | SET pg_dbms_errlog.query_tag TO 'daily_load2'; 53 | SET pg_dbms_errlog.reject_limit TO 25; 54 | SET pg_dbms_errlog.enabled TO true; 55 | 56 | -- Start a transaction 57 | BEGIN; 58 | SAVEPOINT aze; 59 | -- Insert will fail with insuffisient privilege 60 | -- and nothing is registered on ERR$_t2, not granted 61 | INSERT INTO t2 VALUES (NULL); 62 | ROLLBACK TO aze; 63 | COMMIT; 64 | 65 | -- Not enough privilege 66 | SELECT * FROM "ERR$_t2" 67 | ORDER BY "pg_err_number$" COLLATE "C", "pg_err_mesg$" COLLATE "C"; 68 | 69 | -- Back to origin connection 70 | SET SESSION AUTHORIZATION DEFAULT; 71 | 72 | -- Allow user pel_u1 to write to ERR$_t2 73 | GRANT ALL ON "ERR$_t2" TO pel_u1; 74 | 75 | -- switch back to test privilege user 76 | SET SESSION AUTHORIZATION 'pel_u1'; 77 | 78 | SET pg_dbms_errlog.synchronous = query; 79 | SET pg_dbms_errlog.query_tag TO 'daily_load3'; 80 | SET pg_dbms_errlog.reject_limit TO 25; 81 | SET pg_dbms_errlog.enabled TO true; 82 | 83 | -- Show content of the error log table with test user. 0 84 | \x 85 | SELECT * FROM "ERR$_t2" 86 | ORDER BY "pg_err_number$" COLLATE "C", "pg_err_mesg$" COLLATE "C"; 87 | \x 88 | 89 | -- Start a transaction 90 | BEGIN; 91 | SAVEPOINT aze; 92 | -- Insert will fail and the error will be registered this time 93 | INSERT INTO t2 VALUES (NULL); 94 | ROLLBACK TO aze; 95 | COMMIT; 96 | 97 | -- Show content of the error log table with test user. 1 98 | \x 99 | SELECT * FROM "ERR$_t2" 100 | ORDER BY "pg_err_number$" COLLATE "C", "pg_err_mesg$" COLLATE "C"; 101 | \x 102 | 103 | -- Dropping table is not allowed, it must not be unregistered 104 | DROP TABLE t2; 105 | SELECT count(*) FROM dbms_errlog.register_errlog_tables ; -- returns 1 106 | 107 | -- Back to original connection 108 | SET SESSION AUTHORIZATION DEFAULT; 109 | 110 | -- cleanup 111 | DROP TABLE t2; 112 | DROP TABLE "ERR$_t2"; 113 | SELECT count(*) FROM dbms_errlog.register_errlog_tables ; 114 | 115 | ---- 116 | -- Try error logging creation by non superuser role 117 | ---- 118 | CREATE SCHEMA pel_u1; 119 | GRANT ALL ON SCHEMA pel_u1 TO pel_u1; 120 | CREATE TABLE pel_u1.t3 ( 121 | id int NOT NULL 122 | ); 123 | GRANT ALL ON pel_u1.t3 TO pel_u1; 124 | GRANT ALL ON dbms_errlog.register_errlog_tables TO pel_u1; 125 | 126 | SET SESSION AUTHORIZATION 'pel_u1'; 127 | 128 | SET pg_dbms_errlog.synchronous = query; 129 | SET pg_dbms_errlog.query_tag TO 'daily_load4'; 130 | SET pg_dbms_errlog.reject_limit TO 25; 131 | SET pg_dbms_errlog.enabled TO true; 132 | 133 | -- Create the error log table for relation pel_u1.t3 as non superuser role 134 | CALL dbms_errlog.create_error_log('pel_u1.t3', 'pel_u1."ERR$_t3"'); 135 | -- Verify that it have been registered 136 | SELECT count(*) FROM dbms_errlog.register_errlog_tables ; 137 | 138 | -- Start a transaction 139 | BEGIN; 140 | SAVEPOINT aze; 141 | -- Insert will fail for NULL value and will be registered in pel_u1.ERR$_t3 142 | INSERT INTO pel_u1.t3 VALUES (NULL); 143 | ROLLBACK TO aze; 144 | COMMIT; 145 | 146 | -- Show content of the error log table with test user. 147 | \x 148 | SELECT * FROM pel_u1."ERR$_t3" 149 | ORDER BY "pg_err_number$" COLLATE "C", "pg_err_mesg$" COLLATE "C"; 150 | \x 151 | 152 | -- cleanup 153 | DROP TABLE pel_u1.t3; -- will fail 154 | DROP TABLE pel_u1."ERR$_t3"; -- will be dropped 155 | SELECT count(*) FROM dbms_errlog.register_errlog_tables ; 156 | 157 | SET SESSION AUTHORIZATION DEFAULT; 158 | 159 | DROP TABLE pel_u1.t3; 160 | DROP SCHEMA pel_u1; 161 | SELECT count(*) FROM dbms_errlog.register_errlog_tables ; 162 | REVOKE ALL ON dbms_errlog.register_errlog_tables FROM pel_u1; 163 | DROP ROLE pel_u1; 164 | -------------------------------------------------------------------------------- /updates/pg_dbms_errlog--1.0--1.1.sql: -------------------------------------------------------------------------------- 1 | --------------------------------------------------------------------------------- 2 | -- pg_dbms_errlog extension for PostgreSQL 3 | -- Emulate DBMS_ERRLOG Oracle module but in a simplistic way. 4 | --------------------------------------------------------------------------------- 5 | 6 | -- complain if script is sourced in psql, rather than via CREATE EXTENSION 7 | \echo Use "CREATE EXTENSION pg_dbms_errlog" to load this file. \quit 8 | 9 | -- check the functions bodies as creation time, enabled by default 10 | SET LOCAL check_function_bodies = on ; 11 | -- make sure of client encofing 12 | SET LOCAL client_encoding = 'UTF8'; 13 | 14 | 15 | CREATE OR REPLACE FUNCTION @extschema@.unregister_errlog_table() 16 | RETURNS event_trigger 17 | AS $$ 18 | DECLARE 19 | sql_unregister_table text; 20 | relinfo RECORD; 21 | BEGIN 22 | IF tg_tag = 'DROP TABLE' OR tg_tag = 'DROP SCHEMA' THEN 23 | FOR relinfo IN SELECT * FROM pg_catalog.pg_event_trigger_dropped_objects() WHERE object_type IN ('table', 'view') 24 | LOOP 25 | sql_unregister_table := 'DELETE FROM @extschema@.register_errlog_tables WHERE reldml ='||relinfo.objid||' OR relerrlog = '||relinfo.objid; 26 | EXECUTE sql_unregister_table; 27 | END LOOP; 28 | END IF; 29 | END; 30 | $$ LANGUAGE plpgsql; 31 | 32 | CREATE EVENT TRIGGER ddl_drop_errlog_table ON sql_drop EXECUTE PROCEDURE @extschema@.unregister_errlog_table(); 33 | -------------------------------------------------------------------------------- /updates/pg_dbms_errlog--1.1--1.2.sql: -------------------------------------------------------------------------------- 1 | --------------------------------------------------------------------------------- 2 | -- pg_dbms_errlog extension for PostgreSQL 3 | -- Emulate DBMS_ERRLOG Oracle module but in a simplistic way. 4 | --------------------------------------------------------------------------------- 5 | 6 | -- complain if script is sourced in psql, rather than via CREATE EXTENSION 7 | \echo Use "CREATE EXTENSION pg_dbms_errlog" to load this file. \quit 8 | 9 | -- check the functions bodies as creation time, enabled by default 10 | SET LOCAL check_function_bodies = on ; 11 | -- make sure of client encofing 12 | SET LOCAL client_encoding = 'UTF8'; 13 | 14 | -- Nothing to do, only change in C code 15 | -------------------------------------------------------------------------------- /updates/pg_dbms_errlog--1.2--1.3.sql: -------------------------------------------------------------------------------- 1 | --------------------------------------------------------------------------------- 2 | -- pg_dbms_errlog extension for PostgreSQL 3 | -- Emulate DBMS_ERRLOG Oracle module but in a simplistic way. 4 | --------------------------------------------------------------------------------- 5 | 6 | -- complain if script is sourced in psql, rather than via CREATE EXTENSION 7 | \echo Use "CREATE EXTENSION pg_dbms_errlog" to load this file. \quit 8 | 9 | -- check the functions bodies as creation time, enabled by default 10 | SET LOCAL check_function_bodies = on ; 11 | -- make sure of client encofing 12 | SET LOCAL client_encoding = 'UTF8'; 13 | 14 | -- Nothing to do, only change in C code 15 | -------------------------------------------------------------------------------- /updates/pg_dbms_errlog--1.3--2.0.sql: -------------------------------------------------------------------------------- 1 | --------------------------------------------------------------------------------- 2 | -- pg_dbms_errlog extension for PostgreSQL 3 | -- Emulate DBMS_ERRLOG Oracle module but in a simplistic way. 4 | --------------------------------------------------------------------------------- 5 | 6 | -- complain if script is sourced in psql, rather than via CREATE EXTENSION 7 | \echo Use "ALTER EXTENSION pg_dbms_errlog UPDATE" to load this file. \quit 8 | 9 | -- check the functions bodies as creation time, enabled by default 10 | SET LOCAL check_function_bodies = on ; 11 | -- make sure of client encofing 12 | SET LOCAL client_encoding = 'UTF8'; 13 | 14 | CREATE OR REPLACE FUNCTION @extschema@.publish_queue( 15 | wait_for_completion bool DEFAULT false 16 | ) RETURNS bool 17 | LANGUAGE C COST 1000 18 | AS '$libdir/pg_dbms_errlog', 'pg_dbms_errlog_publish_queue'; 19 | REVOKE ALL ON FUNCTION @extschema@.publish_queue FROM public; 20 | 21 | CREATE OR REPLACE FUNCTION @extschema@.queue_size( 22 | OUT num_errors integer 23 | ) RETURNS integer 24 | LANGUAGE C COST 1000 25 | AS '$libdir/pg_dbms_errlog', 'pg_dbms_errlog_queue_size'; 26 | GRANT ALL ON FUNCTION @extschema@.queue_size TO public; 27 | -------------------------------------------------------------------------------- /updates/pg_dbms_errlog--2.0--2.1.sql: -------------------------------------------------------------------------------- 1 | --------------------------------------------------------------------------------- 2 | -- pg_dbms_errlog extension for PostgreSQL 3 | -- Emulate DBMS_ERRLOG Oracle module but in a simplistic way. 4 | --------------------------------------------------------------------------------- 5 | 6 | -- complain if script is sourced in psql, rather than via CREATE EXTENSION 7 | \echo Use "ALTER EXTENSION pg_dbms_errlog UPDATE" to load this file. \quit 8 | 9 | -- check the functions bodies as creation time, enabled by default 10 | SET LOCAL check_function_bodies = on ; 11 | -- make sure of client encofing 12 | SET LOCAL client_encoding = 'UTF8'; 13 | 14 | CREATE OR REPLACE PROCEDURE @extschema@.create_error_log ( 15 | dml_table_name varchar(132), -- name of the DML table to base the error logging table on, can use fqdn. 16 | err_log_table_name varchar(132) DEFAULT NULL, -- name of the error logging table to create, default is the first 58 characters in the name of the DML table prefixed with 'ERR$_', can use fqdn. 17 | err_log_table_owner name DEFAULT NULL, -- name of the owner of the error logging table. Default current user. 18 | err_log_table_space name DEFAULT NULL -- tablespace the error logging table will be created in. 19 | ) AS 20 | $$ 21 | DECLARE 22 | sql_create_table text; 23 | sql_register_table text; 24 | fqdn_pos int := 0; 25 | err_log_tbname name := $2; 26 | err_log_namespace text; 27 | BEGIN 28 | IF dml_table_name IS NULL THEN 29 | RAISE EXCEPTION 'You must specify a DML table name.'; 30 | END IF; 31 | 32 | -- Verify that the DML table exists and get the 33 | -- schema and name of the table from the catalog 34 | SELECT n.nspname, c.relname INTO STRICT err_log_namespace, dml_table_name FROM pg_catalog.pg_namespace n JOIN pg_catalog.pg_class c ON (c.relnamespace = n.oid) WHERE c.oid = dml_table_name::regclass::oid; 35 | -- Set the name of the error table if it is not provided 36 | IF err_log_table_name IS NULL THEN 37 | err_log_tbname := 'ERR$_'||substring(dml_table_name FROM 1 FOR 58); 38 | ELSE 39 | -- Remove quoting from table name if any 40 | err_log_table_name := replace(err_log_table_name, '"', ''); 41 | fqdn_pos := position('.' IN err_log_table_name) + 1; 42 | err_log_tbname := substring(err_log_table_name FROM fqdn_pos FOR 58); 43 | IF fqdn_pos > 1 THEN 44 | err_log_namespace := substring(err_log_table_name FROM 1 FOR fqdn_pos - 2); 45 | END IF; 46 | END IF; 47 | err_log_tbname := quote_ident(err_log_namespace) || '.' || quote_ident(err_log_tbname); 48 | 49 | -- Create the error log table 50 | sql_create_table := 'CREATE TABLE '||err_log_tbname||' ( 51 | PG_ERR_NUMBER$ text, -- PostgreSQL error number 52 | PG_ERR_MESG$ text, -- PostgreSQL error message 53 | PG_ERR_OPTYP$ char(1), -- Type of operation: insert (I), update (U), delete (D) 54 | PG_ERR_TAG$ text, -- Label used to identify the DML batch 55 | PG_ERR_QUERY$ text, -- Query at origin 56 | PG_ERR_DETAIL$ text -- Detail of the query origin 57 | )'; 58 | 59 | EXECUTE sql_create_table; 60 | IF err_log_table_owner IS NOT NULL THEN 61 | EXECUTE 'ALTER TABLE '||err_log_tbname||' OWNER TO '||err_log_table_owner; 62 | END IF; 63 | IF err_log_table_space IS NOT NULL THEN 64 | EXECUTE 'ALTER TABLE '||err_log_tbname||' SET TABLESPACE '||err_log_table_space||' NOWAIT'; 65 | END IF; 66 | sql_register_table := 'INSERT INTO @extschema@.register_errlog_tables VALUES ('''||dml_table_name||'''::regclass::oid, '''||err_log_tbname||'''::regclass::oid)'; 67 | EXECUTE sql_register_table; 68 | END; 69 | $$ 70 | LANGUAGE plpgsql SECURITY INVOKER; 71 | --------------------------------------------------------------------------------