├── .gitignore ├── uninstall_pg_grab_statement.sql ├── pg_grab_statement.control ├── Makefile ├── pg_grab_statement--1.0.sql ├── README.md └── pg_grab_statement.c /.gitignore: -------------------------------------------------------------------------------- 1 | *.so 2 | *.o 3 | *.swp 4 | -------------------------------------------------------------------------------- /uninstall_pg_grab_statement.sql: -------------------------------------------------------------------------------- 1 | DROP SCHEMA grab CASCADE; 2 | -------------------------------------------------------------------------------- /pg_grab_statement.control: -------------------------------------------------------------------------------- 1 | # pg_statement_grab extension 2 | comment = 'Grab SQL statements' 3 | default_version = '1.0' 4 | module_pathname = '$libdir/pg_grab_statement' 5 | relocatable = false 6 | schema = 'grab' 7 | -------------------------------------------------------------------------------- /Makefile: -------------------------------------------------------------------------------- 1 | # contrib/pg_grab_statement/Makefile 2 | 3 | EXTENSION = pg_grab_statement 4 | EXTVERSION = 1.0 5 | 6 | MODULE_big = $(EXTENSION) 7 | OBJS = $(EXTENSION).o $(WIN32RES) 8 | 9 | DATA = $(EXTENSION)--$(EXTVERSION).sql 10 | PGFILEDESC = "$(EXTENSION) - dump SQL statements" 11 | 12 | ifdef USE_PGXS 13 | PG_CONFIG = pg_config 14 | PGXS := $(shell $(PG_CONFIG) --pgxs) 15 | include $(PGXS) 16 | else 17 | subdir = contrib/$(EXTENSION) 18 | top_builddir = ../.. 19 | include $(top_builddir)/src/Makefile.global 20 | include $(top_srcdir)/contrib/contrib-global.mk 21 | endif 22 | -------------------------------------------------------------------------------- /pg_grab_statement--1.0.sql: -------------------------------------------------------------------------------- 1 | /* contrib/pg_grab_statement/pg_grab_statement--1.0.sql */ 2 | 3 | \echo Use "CREATE EXTENSION pg_grab_statement" to load this file. \quit 4 | 5 | CREATE UNLOGGED TABLE grab.statement_log( 6 | transaction_id int, 7 | query_id int, 8 | process_id int, 9 | user_id int, 10 | query_start timestamptz, 11 | total_execution float8, 12 | query_type_id int, 13 | query_source text, 14 | query_param_values text[], 15 | query_param_types regtype[] 16 | ); 17 | 18 | COMMENT ON COLUMN grab.statement_log.transaction_id IS 'Number of transaction'; 19 | COMMENT ON COLUMN grab.statement_log.query_id IS 'Number of query of the specific transaction'; 20 | COMMENT ON COLUMN grab.statement_log.process_id IS 'Backend PID'; 21 | COMMENT ON COLUMN grab.statement_log.user_id IS 'User ID'; 22 | COMMENT ON COLUMN grab.statement_log.query_start IS 'Timestamp of query execution'; 23 | COMMENT ON COLUMN grab.statement_log.total_execution IS 'Total time execution (in seconds)'; 24 | COMMENT ON COLUMN grab.statement_log.query_type_id IS 'Type of query operation id'; 25 | COMMENT ON COLUMN grab.statement_log.query_source IS 'Source of the query'; 26 | COMMENT ON COLUMN grab.statement_log.query_param_values IS 'Parameter values of query'; 27 | COMMENT ON COLUMN grab.statement_log.query_param_types IS 'Parameter types of query'; 28 | 29 | CREATE FUNCTION grab.query_types( 30 | OUT id int, 31 | OUT modify boolean, 32 | OUT name text 33 | ) 34 | RETURNS SETOF record 35 | AS 'MODULE_PATHNAME' 36 | LANGUAGE C VOLATILE; 37 | 38 | CREATE VIEW grab.statements AS 39 | SELECT 40 | l.transaction_id AS transaction, 41 | l.query_id AS query_number, 42 | l.process_id AS backend_pid, 43 | u.usename AS username, 44 | l.query_start, 45 | l.total_execution, 46 | t.name AS query_type, 47 | t.modify AS query_modify_data, 48 | l.query_source, 49 | l.query_param_values, 50 | l.query_param_types 51 | FROM grab.statement_log AS l 52 | LEFT JOIN pg_catalog.pg_user AS u ON u.usesysid = l.user_id 53 | LEFT JOIN grab.query_types() AS t ON t.id = l.query_type_id; 54 | 55 | COMMENT ON COLUMN grab.statements.transaction IS 'Number of transaction'; 56 | COMMENT ON COLUMN grab.statements.query_number IS 'Number of query of the specific transaction'; 57 | COMMENT ON COLUMN grab.statements.backend_pid IS 'Backend PID'; 58 | COMMENT ON COLUMN grab.statements.username IS 'User name'; 59 | COMMENT ON COLUMN grab.statements.query_start IS 'Timestamp of query execution'; 60 | COMMENT ON COLUMN grab.statements.total_execution IS 'Total time execution (in seconds)'; 61 | COMMENT ON COLUMN grab.statements.query_type IS 'Type of query operation'; 62 | COMMENT ON COLUMN grab.statements.query_modify_data IS 'Is query modify data'; 63 | COMMENT ON COLUMN grab.statements.query_source IS 'Source of the query'; 64 | COMMENT ON COLUMN grab.statements.query_param_values IS 'Parameter values of query'; 65 | COMMENT ON COLUMN grab.statements.query_param_types IS 'Parameter types of query'; 66 | -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | pg_grab_statement - PostgreSQL extension for recoding workload of specific database 2 | ======================================================================== 3 | 4 | pg_grab_statement is a PostgreSQL extension for recording detailed information of successfully committed transactions. 5 | 6 | This extension overrides Executor{Start,End} PostgreSQL hooks and writes detailed information in an unlogged table without using the SQL level. 7 | 8 | 9 | Authors 10 | ------- 11 | 12 | * Dmitry Vasilyev , Postgres Professional, Moscow, Russia 13 | 14 | 15 | License 16 | ------- 17 | 18 | Development version, available on github, released under the 19 | GNU General Public License, version 2 (June 1991). 20 | 21 | Downloads 22 | --------- 23 | Stable version of pg_grab_statement is available at https://github.com/postgrespro/pg_grab_statement 24 | 25 | Installation 26 | ------------ 27 | 28 | pg_grab_statement is a regular PostgreSQL extension. 29 | To build and install it you should ensure the following: 30 | 31 | * The development package of PostgreSQL is installed or 32 | PostgreSQL is built from source. 33 | * Your PATH variable is configured so that pg_config command is available. 34 | 35 | Typical installation procedure may look like this: 36 | 37 | $ git clone https://github.com/postgrespro/pg_grab_statement.git 38 | $ cd pg_grab_statement 39 | $ make USE_PGXS=1 40 | $ sudo make USE_PGXS=1 install 41 | $ psql YourDatabaseName -c "CREATE EXTENSION pg_grab_statement;" 42 | 43 | 44 | PostgreSQL 9.0 installation notes 45 | ---------------------- 46 | You need to create the logging table by hand: 47 | 48 | CREATE SCHEMA grab; 49 | CREATE TABLE grab.statement( 50 | transaction_id int, 51 | query_id int, 52 | process_id int, 53 | user_id int, 54 | query_start timestamptz, 55 | total_execution float8, 56 | query_type_id int, 57 | query_source text, 58 | query_param_values text[], 59 | query_param_types regtype[] 60 | ); 61 | 62 | 63 | 64 | Choose your right way to enable the library 65 | --------------------------------------- 66 | 67 | Load library in current session: 68 | 69 | LOAD 'pg_grab_statement'; 70 | 71 | Or set shared_preload_libraries in postgresql.conf (works for version >= 9.0) to record all transactions on all databases: 72 | 73 | shared_preload_libraries = 'pg_grab_statement' 74 | 75 | Or enable recording for all new sessions with a specific role (works for version >= 9.4, without restart): 76 | 77 | ALTER ROLE rolename SET session_preload_libraries = 'pg_grab_statement'; 78 | 79 | Or record all new sessions of all users in a specific database (works for version >= 9.4, without restart): 80 | 81 | ALTER DATABASE dbname SET session_preload_libraries = 'pg_grab_statement'; 82 | 83 | 84 | Overhead 85 | -------- 86 | 87 | * No overhead if library is not loaded 88 | * 10-15% with SELECT-only benchmark 89 | 90 | 91 | Recorded data 92 | -------------- 93 | ``` 94 | =# \d+ grab.statement_log 95 | Unlogged table "grab.statement_log" 96 | Column | Type | Modifiers | Storage | Stats target | Description 97 | --------------------+--------------------------+-----------+----------+--------------+--------------------------------------------- 98 | transaction_id | integer | | plain | | Number of transaction 99 | query_id | integer | | plain | | Number of query of the specific transaction 100 | process_id | integer | | plain | | Backend PID 101 | user_id | integer | | plain | | User ID 102 | query_start | timestamp with time zone | | plain | | Timestamp of query execution 103 | total_execution | double precision | | plain | | Total time execution (in seconds) 104 | query_type_id | integer | | plain | | Type of query operation id 105 | query_source | text | | extended | | Source of the query 106 | query_param_values | text[] | | extended | | Parameter values of query 107 | query_param_types | regtype[] | | extended | | Parameter types of query 108 | ``` 109 | 110 | Defenition of query operation types 111 | ----------------------------------- 112 | ``` 113 | =# select * from grab.query_types(); 114 | id | modify | name 115 | ----+--------+--------- 116 | 0 | t | UNKNOWN 117 | 1 | f | SELECT 118 | 2 | t | UPDATE 119 | 3 | t | INSERT 120 | 4 | t | DELETE 121 | 5 | t | UTILITY 122 | 6 | t | NOTHING 123 | (7 rows) 124 | ``` 125 | 126 | User view 127 | --------- 128 | ``` 129 | =# \d+ grab.statements 130 | View "grab.statements" 131 | Column | Type | Modifiers | Storage | Description 132 | --------------------+--------------------------+-----------+----------+--------------------------------------------- 133 | transaction | integer | | plain | Number of transaction 134 | query_number | integer | | plain | Number of query of the specific transaction 135 | backend_pid | integer | | plain | Backend PID 136 | username | name | | plain | User name 137 | query_start | timestamp with time zone | | plain | Timestamp of query execution 138 | total_execution | double precision | | plain | Total time execution (in seconds) 139 | query_type | text | | extended | Type of query operation 140 | query_modify_data | boolean | | plain | Is query modify data 141 | query_source | text | | extended | Source of the query 142 | query_param_values | text[] | | extended | Parameter values of query 143 | query_param_types | regtype[] | | extended | Parameter types of query 144 | View definition: 145 | SELECT l.transaction_id AS transaction, 146 | l.query_id AS query_number, 147 | l.process_id AS backend_pid, 148 | u.usename AS username, 149 | l.query_start, 150 | l.total_execution, 151 | t.name AS query_type, 152 | t.modify AS query_modify_data, 153 | l.query_source, 154 | l.query_param_values, 155 | l.query_param_types 156 | FROM grab.statement_log l 157 | LEFT JOIN pg_user u ON u.usesysid = l.user_id::oid 158 | LEFT JOIN grab.query_types() t(id, modify, name) ON t.id = l.query_type_id; 159 | ``` 160 | -------------------------------------------------------------------------------- /pg_grab_statement.c: -------------------------------------------------------------------------------- 1 | #include "postgres.h" 2 | #include "funcapi.h" 3 | #include "miscadmin.h" 4 | #include "access/xact.h" 5 | #include "nodes/makefuncs.h" 6 | #include "catalog/pg_type.h" 7 | #include "utils/rel.h" 8 | #include "utils/array.h" 9 | #include "utils/builtins.h" 10 | #include "utils/timestamp.h" 11 | #include "utils/syscache.h" 12 | #include "utils/lsyscache.h" 13 | #include "lib/stringinfo.h" 14 | #include "executor/instrument.h" 15 | 16 | #if (PG_VERSION_NUM >= 90400) 17 | #include "access/htup_details.h" 18 | #endif 19 | 20 | #define EXTENSION_SCHEMA "grab" 21 | #define EXTENSION_LOG_TABLE "statement_log" 22 | 23 | PG_MODULE_MAGIC; 24 | 25 | void _PG_init(void); 26 | void _PG_fini(void); 27 | 28 | static ExecutorStart_hook_type prev_ExecutorStart = NULL; 29 | static ExecutorEnd_hook_type prev_ExecutorEnd = NULL; 30 | 31 | static void grab_ExecutorStart(QueryDesc * queryDesc, int eflags); 32 | static void grab_ExecutorEnd(QueryDesc * queryDesc); 33 | 34 | void 35 | _PG_init(void) 36 | { 37 | prev_ExecutorStart = ExecutorStart_hook; 38 | ExecutorStart_hook = grab_ExecutorStart; 39 | prev_ExecutorEnd = ExecutorEnd_hook; 40 | ExecutorEnd_hook = grab_ExecutorEnd; 41 | } 42 | 43 | void 44 | _PG_fini(void) 45 | { 46 | ExecutorStart_hook = prev_ExecutorStart; 47 | ExecutorEnd_hook = prev_ExecutorEnd; 48 | } 49 | 50 | static void 51 | grab_ExecutorStart(QueryDesc * queryDesc, int eflags) 52 | { 53 | if (prev_ExecutorStart) 54 | prev_ExecutorStart(queryDesc, eflags); 55 | else 56 | standard_ExecutorStart(queryDesc, eflags); 57 | 58 | if (queryDesc->totaltime == NULL) { 59 | MemoryContext oldcxt; 60 | 61 | oldcxt = MemoryContextSwitchTo(queryDesc->estate->es_query_cxt); 62 | queryDesc->totaltime = InstrAlloc(1, INSTRUMENT_ALL); 63 | MemoryContextSwitchTo(oldcxt); 64 | } 65 | } 66 | 67 | PG_FUNCTION_INFO_V1(query_types); 68 | Datum 69 | query_types(PG_FUNCTION_ARGS) 70 | { 71 | FuncCallContext *funcctx; 72 | CmdType MaxCmdElement = CMD_NOTHING; 73 | 74 | if (SRF_IS_FIRSTCALL()) { 75 | MemoryContext oldcontext; 76 | TupleDesc tupdesc; 77 | 78 | funcctx = SRF_FIRSTCALL_INIT(); 79 | 80 | oldcontext = MemoryContextSwitchTo(funcctx->multi_call_memory_ctx); 81 | 82 | tupdesc = CreateTemplateTupleDesc(3, false); 83 | TupleDescInitEntry(tupdesc, (AttrNumber) 1, "id", 84 | INT4OID, -1, 0); 85 | TupleDescInitEntry(tupdesc, (AttrNumber) 2, "modify", 86 | BOOLOID, -1, 0); 87 | TupleDescInitEntry(tupdesc, (AttrNumber) 3, "name", 88 | TEXTOID, -1, 0); 89 | funcctx->tuple_desc = BlessTupleDesc(tupdesc); 90 | 91 | MemoryContextSwitchTo(oldcontext); 92 | } 93 | funcctx = SRF_PERCALL_SETUP(); 94 | 95 | if (funcctx->call_cntr < MaxCmdElement + 1) { 96 | Datum values[3]; 97 | bool nulls[3]; 98 | HeapTuple tuple; 99 | CmdType current; 100 | 101 | MemSet(values, 0, sizeof(values)); 102 | MemSet(nulls, false, sizeof(nulls)); 103 | 104 | current = (CmdType) funcctx->call_cntr; 105 | values[0] = Int32GetDatum(funcctx->call_cntr); 106 | if (CMD_SELECT == current) { 107 | values[1] = BoolGetDatum(false); 108 | } else { 109 | values[1] = BoolGetDatum(true); 110 | } 111 | 112 | switch (current) { 113 | case CMD_UNKNOWN: 114 | values[2] = CStringGetDatum(cstring_to_text("UNKNOWN")); 115 | break; 116 | case CMD_SELECT: 117 | values[2] = CStringGetDatum(cstring_to_text("SELECT")); 118 | break; 119 | case CMD_UPDATE: 120 | values[2] = CStringGetDatum(cstring_to_text("UPDATE")); 121 | break; 122 | case CMD_INSERT: 123 | values[2] = CStringGetDatum(cstring_to_text("INSERT")); 124 | break; 125 | case CMD_DELETE: 126 | values[2] = CStringGetDatum(cstring_to_text("DELETE")); 127 | break; 128 | case CMD_UTILITY: 129 | values[2] = CStringGetDatum(cstring_to_text("UTILITY")); 130 | break; 131 | case CMD_NOTHING: 132 | values[2] = CStringGetDatum(cstring_to_text("NOTHING")); 133 | break; 134 | default: 135 | values[2] = CStringGetDatum(cstring_to_text("UNKNOWN")); 136 | break; 137 | } 138 | 139 | tuple = heap_form_tuple(funcctx->tuple_desc, values, nulls); 140 | SRF_RETURN_NEXT(funcctx, HeapTupleGetDatum(tuple)); 141 | funcctx->call_cntr++; 142 | } else { 143 | SRF_RETURN_DONE(funcctx); 144 | } 145 | } 146 | 147 | static void 148 | grab_ExecutorEnd(QueryDesc * queryDesc) 149 | { 150 | Datum values[10]; 151 | bool nulls[10] = {false, false, false, false, false, false, false, false, false, false}; 152 | Relation dump_heap; 153 | RangeVar *dump_table_rv; 154 | HeapTuple tuple; 155 | Oid namespaceId; 156 | 157 | /* lookup schema */ 158 | namespaceId = GetSysCacheOid1(NAMESPACENAME, CStringGetDatum(EXTENSION_SCHEMA)); 159 | if (OidIsValid(namespaceId)) { 160 | /* lookup table */ 161 | if (OidIsValid(get_relname_relid(EXTENSION_LOG_TABLE, namespaceId))) { 162 | 163 | /* get table heap */ 164 | dump_table_rv = makeRangeVar(EXTENSION_SCHEMA, EXTENSION_LOG_TABLE, -1); 165 | dump_heap = heap_openrv(dump_table_rv, RowExclusiveLock); 166 | 167 | /* transaction info */ 168 | values[0] = Int32GetDatum(GetCurrentTransactionId()); 169 | values[1] = Int32GetDatum(GetCurrentCommandId(false)); 170 | values[2] = Int32GetDatum(MyProcPid); 171 | values[3] = Int32GetDatum(GetUserId()); 172 | 173 | /* query timing */ 174 | if (queryDesc->totaltime != NULL) { 175 | InstrEndLoop(queryDesc->totaltime); 176 | values[4] = TimestampGetDatum( 177 | TimestampTzPlusMilliseconds(GetCurrentTimestamp(), 178 | (queryDesc->totaltime->total * -1000.0))); 179 | values[5] = Float8GetDatum(queryDesc->totaltime->total); 180 | } else { 181 | nulls[4] = true; 182 | nulls[5] = true; 183 | } 184 | 185 | /* query command type */ 186 | values[6] = Int32GetDatum(queryDesc->operation); 187 | 188 | /* query text */ 189 | values[7] = CStringGetDatum( 190 | cstring_to_text(queryDesc->sourceText)); 191 | 192 | /* query params */ 193 | if (queryDesc->params != NULL) { 194 | int numParams = queryDesc->params->numParams; 195 | Oid out_func_oid, ptype; 196 | Datum pvalue; 197 | bool isvarlena; 198 | FmgrInfo *out_functions; 199 | 200 | bool arr_nulls[numParams]; 201 | size_t arr_nelems = (size_t) numParams; 202 | Datum *arr_val_elems = palloc(sizeof(Datum) * arr_nelems); 203 | Datum *arr_typ_elems = palloc(sizeof(Datum) * arr_nelems); 204 | char elem_val_byval, elem_val_align, elem_typ_byval, 205 | elem_typ_align; 206 | int16 elem_val_len, elem_typ_len; 207 | int elem_dims[1], elem_lbs[1]; 208 | 209 | int paramno; 210 | 211 | /* init */ 212 | out_functions = (FmgrInfo *) palloc( 213 | (numParams) * sizeof(FmgrInfo)); 214 | get_typlenbyvalalign(TEXTOID, &elem_val_len, &elem_val_byval, &elem_val_align); 215 | get_typlenbyvalalign(REGTYPEOID, &elem_typ_len, &elem_typ_byval, &elem_typ_align); 216 | elem_dims[0] = arr_nelems; 217 | elem_lbs[0] = 1; 218 | 219 | for (paramno = 0; paramno < numParams; paramno++) { 220 | pvalue = queryDesc->params->params[paramno].value; 221 | ptype = queryDesc->params->params[paramno].ptype; 222 | getTypeOutputInfo(ptype, &out_func_oid, &isvarlena); 223 | fmgr_info(out_func_oid, &out_functions[paramno]); 224 | 225 | arr_typ_elems[paramno] = ptype; 226 | 227 | arr_nulls[paramno] = true; 228 | if (!queryDesc->params->params[paramno].isnull) { 229 | arr_nulls[paramno] = false; 230 | arr_val_elems[paramno] = PointerGetDatum( 231 | cstring_to_text( 232 | OutputFunctionCall(&out_functions[paramno], pvalue))); 233 | } 234 | } 235 | values[8] = PointerGetDatum( 236 | construct_md_array( 237 | arr_val_elems, 238 | arr_nulls, 239 | 1, 240 | elem_dims, 241 | elem_lbs, 242 | TEXTOID, 243 | elem_val_len, 244 | elem_val_byval, 245 | elem_val_align)); 246 | values[9] = PointerGetDatum( 247 | construct_array( 248 | arr_typ_elems, 249 | arr_nelems, 250 | REGTYPEOID, 251 | elem_typ_len, 252 | elem_typ_byval, 253 | elem_typ_align)); 254 | 255 | pfree(out_functions); 256 | pfree(arr_val_elems); 257 | 258 | } else { 259 | nulls[8] = true; 260 | nulls[9] = true; 261 | } 262 | 263 | /* insert */ 264 | tuple = heap_form_tuple(dump_heap->rd_att, values, nulls); 265 | simple_heap_insert(dump_heap, tuple); 266 | heap_close(dump_heap, RowExclusiveLock); 267 | } 268 | } 269 | if (prev_ExecutorEnd) 270 | prev_ExecutorEnd(queryDesc); 271 | else 272 | standard_ExecutorEnd(queryDesc); 273 | } 274 | --------------------------------------------------------------------------------