原 PG中记录慢SQL语句的方法
 
Tags: 原创PGPostgreSQL慢SQLlog_min_duration_statement
👉 本文共约355个字,系统预计阅读时间或需2分钟。
简介
在PostgreSQL中,可以通过启用慢查询日志来记录执行时间较长的SQL语句,然后通过外部表来查询告警日志即可。
步骤一
log_min_duration_statement:设置记录SQL执行时间的阈值(以毫秒为单位)。只有执行时间超过此阈值的SQL语句才会记录在日志中。设置为0
将记录所有语句的执行时间,设置为较高的值(如5000)将只记录执行时间超过5秒的语句。
编辑postgresql.conf
并设置如下:
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 | alter system set log_destination='csvlog'; alter system set logging_collector = on; alter system set log_directory = 'pg_log'; alter system set log_filename = 'postgresql-%a.log'; alter system set log_truncate_on_rotation = on; alter system set log_statement = 'ddl'; alter system set log_connections = 'off'; alter system set log_disconnections = 'off'; alter system set log_min_duration_statement = 5000; show logging_collector; show log_directory; show log_filename; show log_truncate_on_rotation; show log_statement; show log_connections; show log_disconnections; show log_min_duration_statement; SELECT pg_reload_conf(); sudo systemctl restart postgresql select * from pg_settings where name in ('logging_collector','log_directory','log_filename','log_truncate_on_rotation'); |
本人提供Oracle(OCP、OCM)、MySQL(OCP)、PostgreSQL(PGCA、PGCE、PGCM)等数据库的培训和考证业务,私聊QQ646634621或微信dbaup66,谢谢!
步骤二
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232 233 234 235 236 237 238 239 240 241 242 243 244 245 246 247 248 249 250 251 252 253 254 255 256 257 258 259 260 261 262 263 264 265 266 267 268 269 270 271 272 273 274 275 276 277 278 279 280 281 282 283 284 285 286 287 288 289 290 291 292 293 294 295 296 297 298 299 300 301 302 303 304 305 306 307 308 309 310 311 312 313 314 315 316 317 318 319 320 321 322 323 324 325 326 327 328 329 330 331 332 333 334 335 336 337 338 339 340 341 342 343 344 345 346 347 348 349 350 351 352 353 354 355 356 357 358 359 360 361 362 363 364 365 366 367 368 369 370 371 372 373 374 375 376 377 378 379 380 381 382 383 384 385 386 387 388 389 390 391 392 393 394 395 396 397 398 399 400 401 402 403 404 405 406 407 408 409 410 411 412 413 414 415 416 417 418 419 420 421 422 423 424 425 426 427 428 429 430 431 432 433 434 435 436 437 | create extension if not EXISTS file_fdw; CREATE SERVER if not EXISTS pg_file_server FOREIGN DATA WRAPPER file_fdw; drop view if EXISTS pg_log; drop foreign table if exists pg_log_mon; create foreign table pg_log_mon( log_time timestamp ,user_name text ,database_name text ,process_id integer ,connection_from text ,session_id text ,session_line_num bigint ,command_tag text ,session_start_time timestamp ,virtual_transaction_id text ,transaction_id bigint ,error_severity text ,sql_state_code text ,message text ,detail text ,hint text ,internal_query text ,internal_query_pos integer ,context text ,query text ,query_pos integer ,location text ,application_name text ,backend_type text ,additional_column2 text ,queryid text ) server pg_file_server options( filename '/data/pg_log/postgresql-Mon.csv' ,format 'csv' ,header 'false' ,delimiter ',' ,quote '"' ,escape '"' ); comment on foreign table pg_log_mon is '每周一当天审计日志'; comment on column pg_log_mon.log_time is '日志时间'; comment on column pg_log_mon.user_name is '用户名'; comment on column pg_log_mon.database_name is '数据库名'; comment on column pg_log_mon.process_id is '进程id'; comment on column pg_log_mon.connection_from is '客户端ip:端口'; comment on column pg_log_mon.session_id is '会话id'; comment on column pg_log_mon.session_line_num is '当前会话的第几次查询'; comment on column pg_log_mon.command_tag is '命令类型'; comment on column pg_log_mon.session_start_time is '会话开始时间'; comment on column pg_log_mon.virtual_transaction_id is '虚拟事务id'; comment on column pg_log_mon.transaction_id is '事务id'; comment on column pg_log_mon.error_severity is '错误级别'; comment on column pg_log_mon.sql_state_code is 'sql状态代码'; comment on column pg_log_mon.message is '信息'; comment on column pg_log_mon.detail is '详细信息'; comment on column pg_log_mon.hint is '提示信息'; comment on column pg_log_mon.query is '查询的sql'; comment on column pg_log_mon.application_name is '应用名(客户端名)'; drop foreign table if exists pg_log_tue; create foreign table pg_log_tue( log_time timestamp ,user_name text ,database_name text ,process_id integer ,connection_from text ,session_id text ,session_line_num bigint ,command_tag text ,session_start_time timestamp ,virtual_transaction_id text ,transaction_id bigint ,error_severity text ,sql_state_code text ,message text ,detail text ,hint text ,internal_query text ,internal_query_pos integer ,context text ,query text ,query_pos integer ,location text ,application_name text ,backend_type text ,additional_column2 text ,queryid text ) server pg_file_server options( filename '/data/pg_log/postgresql-Tue.csv' ,format 'csv' ,header 'false' ,delimiter ',' ,quote '"' ,escape '"' ); comment on foreign table pg_log_tue is '每周二当天审计日志'; comment on column pg_log_tue.log_time is '日志时间'; comment on column pg_log_tue.user_name is '用户名'; comment on column pg_log_tue.database_name is '数据库名'; comment on column pg_log_tue.process_id is '进程id'; comment on column pg_log_tue.connection_from is '客户端ip:端口'; comment on column pg_log_tue.session_id is '会话id'; comment on column pg_log_tue.session_line_num is '当前会话的第几次查询'; comment on column pg_log_tue.command_tag is '命令类型'; comment on column pg_log_tue.session_start_time is '会话开始时间'; comment on column pg_log_tue.virtual_transaction_id is '虚拟事务id'; comment on column pg_log_tue.transaction_id is '事务id'; comment on column pg_log_tue.error_severity is '错误级别'; comment on column pg_log_tue.sql_state_code is 'sql状态代码'; comment on column pg_log_tue.message is '信息'; comment on column pg_log_tue.detail is '详细信息'; comment on column pg_log_tue.hint is '提示信息'; comment on column pg_log_tue.query is '查询的sql'; comment on column pg_log_tue.application_name is '应用名(客户端名)'; drop foreign table if exists pg_log_wed; create foreign table pg_log_wed( log_time timestamp ,user_name text ,database_name text ,process_id integer ,connection_from text ,session_id text ,session_line_num bigint ,command_tag text ,session_start_time timestamp ,virtual_transaction_id text ,transaction_id bigint ,error_severity text ,sql_state_code text ,message text ,detail text ,hint text ,internal_query text ,internal_query_pos integer ,context text ,query text ,query_pos integer ,location text ,application_name text ,backend_type text ,additional_column2 text ,queryid text ) server pg_file_server options( filename '/data/pg_log//postgresql-Wed.csv' ,format 'csv' ,header 'false' ,delimiter ',' ,quote '"' ,escape '"' ); comment on foreign table pg_log_wed is '每周三当天审计日志'; comment on column pg_log_wed.log_time is '日志时间'; comment on column pg_log_wed.user_name is '用户名'; comment on column pg_log_wed.database_name is '数据库名'; comment on column pg_log_wed.process_id is '进程id'; comment on column pg_log_wed.connection_from is '客户端ip:端口'; comment on column pg_log_wed.session_id is '会话id'; comment on column pg_log_wed.session_line_num is '当前会话的第几次查询'; comment on column pg_log_wed.command_tag is '命令类型'; comment on column pg_log_wed.session_start_time is '会话开始时间'; comment on column pg_log_wed.virtual_transaction_id is '虚拟事务id'; comment on column pg_log_wed.transaction_id is '事务id'; comment on column pg_log_wed.error_severity is '错误级别'; comment on column pg_log_wed.sql_state_code is 'sql状态代码'; comment on column pg_log_wed.message is '信息'; comment on column pg_log_wed.detail is '详细信息'; comment on column pg_log_wed.hint is '提示信息'; comment on column pg_log_wed.query is '查询的sql'; comment on column pg_log_wed.application_name is '应用名(客户端名)'; drop foreign table if exists pg_log_thu; create foreign table pg_log_thu( log_time timestamp ,user_name text ,database_name text ,process_id integer ,connection_from text ,session_id text ,session_line_num bigint ,command_tag text ,session_start_time timestamp ,virtual_transaction_id text ,transaction_id bigint ,error_severity text ,sql_state_code text ,message text ,detail text ,hint text ,internal_query text ,internal_query_pos integer ,context text ,query text ,query_pos integer ,location text ,application_name text ,backend_type text ,additional_column2 text ,queryid text ) server pg_file_server options( filename '/data/pg_log/postgresql-Thu.csv' ,format 'csv' ,header 'false' ,delimiter ',' ,quote '"' ,escape '"' ); comment on foreign table pg_log_thu is '每周四当天审计日志'; comment on column pg_log_thu.log_time is '日志时间'; comment on column pg_log_thu.user_name is '用户名'; comment on column pg_log_thu.database_name is '数据库名'; comment on column pg_log_thu.process_id is '进程id'; comment on column pg_log_thu.connection_from is '客户端ip:端口'; comment on column pg_log_thu.session_id is '会话id'; comment on column pg_log_thu.session_line_num is '当前会话的第几次查询'; comment on column pg_log_thu.command_tag is '命令类型'; comment on column pg_log_thu.session_start_time is '会话开始时间'; comment on column pg_log_thu.virtual_transaction_id is '虚拟事务id'; comment on column pg_log_thu.transaction_id is '事务id'; comment on column pg_log_thu.error_severity is '错误级别'; comment on column pg_log_thu.sql_state_code is 'sql状态代码'; comment on column pg_log_thu.message is '信息'; comment on column pg_log_thu.detail is '详细信息'; comment on column pg_log_thu.hint is '提示信息'; comment on column pg_log_thu.query is '查询的sql'; comment on column pg_log_thu.application_name is '应用名(客户端名)'; drop foreign table if exists pg_log_fri; create foreign table pg_log_fri( log_time timestamp ,user_name text ,database_name text ,process_id integer ,connection_from text ,session_id text ,session_line_num bigint ,command_tag text ,session_start_time timestamp ,virtual_transaction_id text ,transaction_id bigint ,error_severity text ,sql_state_code text ,message text ,detail text ,hint text ,internal_query text ,internal_query_pos integer ,context text ,query text ,query_pos integer ,location text ,application_name text ,backend_type text ,additional_column2 text ,queryid text ) server pg_file_server options( filename '/data/pg_log/postgresql-Fri.csv' ,format 'csv' ,header 'false' ,delimiter ',' ,quote '"' ,escape '"' ); comment on foreign table pg_log_fri is '每周五当天审计日志'; comment on column pg_log_fri.log_time is '日志时间'; comment on column pg_log_fri.user_name is '用户名'; comment on column pg_log_fri.database_name is '数据库名'; comment on column pg_log_fri.process_id is '进程id'; comment on column pg_log_fri.connection_from is '客户端ip:端口'; comment on column pg_log_fri.session_id is '会话id'; comment on column pg_log_fri.session_line_num is '当前会话的第几次查询'; comment on column pg_log_fri.command_tag is '命令类型'; comment on column pg_log_fri.session_start_time is '会话开始时间'; comment on column pg_log_fri.virtual_transaction_id is '虚拟事务id'; comment on column pg_log_fri.transaction_id is '事务id'; comment on column pg_log_fri.error_severity is '错误级别'; comment on column pg_log_fri.sql_state_code is 'sql状态代码'; comment on column pg_log_fri.message is '信息'; comment on column pg_log_fri.detail is '详细信息'; comment on column pg_log_fri.hint is '提示信息'; comment on column pg_log_fri.query is '查询的sql'; comment on column pg_log_fri.application_name is '应用名(客户端名)'; drop foreign table if exists pg_log_sat; create foreign table pg_log_sat( log_time timestamp ,user_name text ,database_name text ,process_id integer ,connection_from text ,session_id text ,session_line_num bigint ,command_tag text ,session_start_time timestamp ,virtual_transaction_id text ,transaction_id bigint ,error_severity text ,sql_state_code text ,message text ,detail text ,hint text ,internal_query text ,internal_query_pos integer ,context text ,query text ,query_pos integer ,location text ,application_name text ,backend_type text ,additional_column2 text ,queryid text ) server pg_file_server options( filename '/data/pg_log/postgresql-Sat.csv' ,format 'csv' ,header 'false' ,delimiter ',' ,quote '"' ,escape '"' ); comment on foreign table pg_log_sat is '每周六当天审计日志'; comment on column pg_log_sat.log_time is '日志时间'; comment on column pg_log_sat.user_name is '用户名'; comment on column pg_log_sat.database_name is '数据库名'; comment on column pg_log_sat.process_id is '进程id'; comment on column pg_log_sat.connection_from is '客户端ip:端口'; comment on column pg_log_sat.session_id is '会话id'; comment on column pg_log_sat.session_line_num is '当前会话的第几次查询'; comment on column pg_log_sat.command_tag is '命令类型'; comment on column pg_log_sat.session_start_time is '会话开始时间'; comment on column pg_log_sat.virtual_transaction_id is '虚拟事务id'; comment on column pg_log_sat.transaction_id is '事务id'; comment on column pg_log_sat.error_severity is '错误级别'; comment on column pg_log_sat.sql_state_code is 'sql状态代码'; comment on column pg_log_sat.message is '信息'; comment on column pg_log_sat.detail is '详细信息'; comment on column pg_log_sat.hint is '提示信息'; comment on column pg_log_sat.query is '查询的sql'; comment on column pg_log_sat.application_name is '应用名(客户端名)'; drop foreign table if exists pg_log_sun; create foreign table pg_log_sun( log_time timestamp ,user_name text ,database_name text ,process_id integer ,connection_from text ,session_id text ,session_line_num bigint ,command_tag text ,session_start_time timestamp ,virtual_transaction_id text ,transaction_id bigint ,error_severity text ,sql_state_code text ,message text ,detail text ,hint text ,internal_query text ,internal_query_pos integer ,context text ,query text ,query_pos integer ,location text ,application_name text ,backend_type text ,additional_column2 text ,queryid text ) server pg_file_server options( filename '/data/pg_log/postgresql-Sun.csv' ,format 'csv' ,header 'false' ,delimiter ',' ,quote '"' ,escape '"' ); comment on foreign table pg_log_sun is '每周日当天审计日志'; comment on column pg_log_sun.log_time is '日志时间'; comment on column pg_log_sun.user_name is '用户名'; comment on column pg_log_sun.database_name is '数据库名'; comment on column pg_log_sun.process_id is '进程id'; comment on column pg_log_sun.connection_from is '客户端ip:端口'; comment on column pg_log_sun.session_id is '会话id'; comment on column pg_log_sun.session_line_num is '当前会话的第几次查询'; comment on column pg_log_sun.command_tag is '命令类型'; comment on column pg_log_sun.session_start_time is '会话开始时间'; comment on column pg_log_sun.virtual_transaction_id is '虚拟事务id'; comment on column pg_log_sun.transaction_id is '事务id'; comment on column pg_log_sun.error_severity is '错误级别'; comment on column pg_log_sun.sql_state_code is 'sql状态代码'; comment on column pg_log_sun.message is '信息'; comment on column pg_log_sun.detail is '详细信息'; comment on column pg_log_sun.hint is '提示信息'; comment on column pg_log_sun.query is '查询的sql'; comment on column pg_log_sun.application_name is '应用名(客户端名)'; create or replace view pg_log as select * from pg_log_mon union all select * from pg_log_tue union all select * from pg_log_wed union all select * from pg_log_thu union all select * from pg_log_fri union all select * from pg_log_sat union all select * from pg_log_sun; SELECT d.log_time, d.user_name, d.connection_from, d.command_tag, d.session_start_time, -- d.virtual_transaction_id, -- d.transaction_id, d.context, d.message, d.query, d.queryid from pg_log d where 1=1 -- and d.database_name = 'HOSPITAL_CUBEDB_PROD' -- and (d.query is not null or d.message is not null ) -- and d.message like '%duration: %' -- and d.query like '%select 0 %' and d.message like '%select replace(t.yf,%' ; select * from pg_log_fri d where d.log_time='2024-11-01 11:24:24.809' |
总结
1、可以结合pg_stat_statements插件来监控慢SQL,该插件记录的SQL语句可能不是原始SQL,而是带参数的SQL语句。常用SQL
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 | cat >> postgresql.conf <<"EOF" shared_preload_libraries='pg_stat_statements' track_io_timing = on track_activity_query_size = 102400 pg_stat_statements.max = 100000 pg_stat_statements.track = all pg_stat_statements.track_utility = on pg_stat_statements.save = on EOF alter system set shared_preload_libraries = 'pg_stat_statements'; alter system set track_io_timing = on; alter system set track_activity_query_size = 102400 ; alter system set pg_stat_statements.max = 100000 ; alter system set pg_stat_statements.track = 'all'; alter system set pg_stat_statements.track_utility = on; alter system set pg_stat_statements.save = on ; alter system set log_min_duration_statement = 5000; CREATE EXTENSION pg_stat_statements; SELECT pg_reload_conf(); SELECT b.rolname, C.datname, query, queryid, calls, round((total_exec_time/1000)::numeric, 2) AS total_time, round((mean_exec_time::numeric/1000), 2) AS mean_time, round((100 * total_exec_time / sum(total_exec_time) OVER ())::numeric, 2) AS percentage, round((a.min_exec_time/1000)::numeric, 2) AS min_exec_time, round((a.max_exec_time/1000)::numeric, 2) AS max_exec_time, a.rows, a.shared_blks_hit FROM pg_stat_statements a left join pg_authid b on a.userid=b.oid left join pg_database c on a.dbid=c.oid WHERE mean_exec_time > 2000 and calls > 1 ORDER BY total_exec_time DESC LIMIT 100; |
2、pg_stat_statements也可以用于PG 9.2
相关文章
- PG查询表的属性Options的内容(例如并行度、fillfactor、autovacuum_enabled等)
- 所有数据库查询表和列的注释SQL汇总(Oracle、MySQL、PostgreSQL、GreenPlum、SQL Server)
- 【异地备份】pgbackrest如何将PostgreSQL数据库备份到S3中?
- 【异地备份】如何让pg_rman支持异地备份?
- 【异地备份】pgbackrest如何将PostgreSQL数据库备份到sshfs中?
- 在PG高可用中,异构平台是否可以? 主库为Windows,备库为Linux?
- PG或GP增加id列
- PG的copy命令如何导出单个斜杠到文件中?
- PG备份管理工具之PG Back Web
- PG通过tds_fdw访问SQL Server数据库
- PG系数据库(PG、人大金仓KES)如何配置只允许某个用户u1只能访问某单个数据库db1,而不能访问其它库
- PG中的LOCALE介绍
- PG中的告警日志配置介绍
- 在Windows系统中定时pg_dump逻辑导出备份PG或GreenPlum数据库(异机备份、动态生成导出命令)
- PG在SQL语句中使用nolock提示??
- PostgreSQL之PGCA培训认证
- PostgreSQL之PGCM培训认证
- PostgreSQL之PGCA+PGCE培训认证
- PG和GreenPlum中的依赖查询
- PG做任意DML操作均卡住,等待事件为SyncRep,类型为IPC