分析作业是否被阻塞
数据库系统运行时,在某些业务场景下查询语句会被阻塞,导致语句运行时间过长,可以强制结束有问题的会话。
操作步骤
- 参考连接数据库,连接数据库。
- 查看阻塞的查询语句及阻塞查询的表、模式信息。
1 2 3 4 5 6 7 8 9 10 11
SELECT w.query as waiting_query, w.pid as w_pid, w.usename as w_user, l.query as locking_query, l.pid as l_pid, l.usename as l_user, t.schemaname || '.' || t.relname as tablename from pg_stat_activity w join pg_locks l1 on w.pid = l1.pid and not l1.granted join pg_locks l2 on l1.relation = l2.relation and l2.granted join pg_stat_activity l on l2.pid = l.pid join pg_stat_user_tables t on l1.relation = t.relid where w.waiting;
该查询返回线程ID、用户信息、查询状态,以及导致阻塞的表、模式信息。
- 使用如下命令结束相应的会话。其中,139834762094352为线程ID。
1
SELECT PG_TERMINATE_BACKEND(139834762094352);
显示类似如下信息,表示结束会话成功。
PG_TERMINATE_BACKEND ---------------------- t (1 row)
显示类似如下信息,表示用户正在尝试结束当前会话,此时仅会重连会话,而不是结束会话。
FATAL: terminating connection due to administrator command FATAL: terminating connection due to administrator command The connection to the server was lost. Attempting reset: Succeeded.
gsql客户端使用PG_TERMINATE_BACKEND函数终止本会话后台线程时,客户端不会退出而是自动重连。