更新时间:2024-10-14 GMT+08:00

分析作业是否被阻塞

数据库系统运行时,在某些业务场景下查询语句会被阻塞,导致语句运行时间过长,可以强制结束有问题的会话。

操作步骤

  1. 参考连接数据库,连接数据库。
  2. 查看阻塞的查询语句及阻塞查询的语句及其查询状态、会话ID(如下SQL在线程池开启的模式下适用)。

    SELECT w.query AS waiting_query,
    w.state as w_state,
    w.datname as w_datname,
    w.usename as w_user,
    w.client_addr as w_client_addr,
    l.query AS locking_query,
    l.state as l_state,
    l.pid AS l_pid,
    l.sessionid as l_sessionid
    FROM pgxc_stat_activity AS w
    JOIN (
        SELECT query_id,block_sessionid,global_sessionid,node_name
        FROM pgxc_thread_wait_status
    ) AS a ON a.query_id = w.query_id
     JOIN (
        SELECT sessionid,node_name,global_sessionid  FROM pgxc_thread_wait_status
    ) AS b ON b.sessionid = a.block_sessionid and b.node_name=a.node_name
    JOIN (select query,pid,sessionid,global_sessionid,state from pgxc_stat_activity ) l
    on substring(l.global_sessionid,0,instr(l.global_sessionid,'#')) ilike substring(b.global_sessionid,0,instr(b.global_sessionid,'#'))
    WHERE a.block_sessionid !=0;

    该查询返回会话ID、用户信息、查询状态,以及导致阻塞的语句及其查询状态、会话ID。

  3. 使用如下命令结束相应的会话。其中,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

    1. gsql客户端使用PG_TERMINATE_BACKEND函数结束当前正在执行会话的后台线程时,如果当前的用户是初始用户,客户端不会退出而是自动重连,即还会返回“The connection to the server was lost. Attempting reset: Succeeded.”;否则客户端会重连失败,即返回“The connection to the server was lost. Attempting reset: Failed.”。这是因为只有初始用户可以免密登录,普遍用户不能免密登录,从而重连失败。

    2. 对于使用PG_TERMINATE_BACKEND函数结束非活跃的后台线程时。如果打开了线程池,此时空闲的会话没有线程ID,无法结束会话。非线程池模式下,结束的会话不会自动重连。