发现一个查看postgresql锁比较好的sql语句,参考链接地址如下

链接地址

查看锁等待sql

witht_wait as(select a.mode,a.locktype,a.database,a.relation,a.page,a.tuple,a.classid,a.granted,a.objid,a.objsubid,a.pid,a.virtualtransaction,a.virtualxid,a.transactionid,a.fastpath,b.state,b.query,b.xact_start,b.query_start,b.usename,b.datname,b.client_addr,b.client_port,b.application_namefrom pg_locks a,pg_stat_activity b where a.pid=b.pid and not a.granted),t_run as(select a.mode,a.locktype,a.database,a.relation,a.page,a.tuple,a.classid,a.granted,a.objid,a.objsubid,a.pid,a.virtualtransaction,a.virtualxid,a.transactionid,a.fastpath,b.state,b.query,b.xact_start,b.query_start,b.usename,b.datname,b.client_addr,b.client_port,b.application_namefrom pg_locks a,pg_stat_activity b where a.pid=b.pid and a.granted),t_overlap as(select r.* from t_wait w join t_run r on(r.locktype is not distinct from w.locktype andr.database is not distinct from w.database andr.relation is not distinct from w.relation andr.page is not distinct from w.page andr.tuple is not distinct from w.tuple andr.virtualxid is not distinct from w.virtualxid andr.transactionid is not distinct from w.transactionid andr.classid is not distinct from w.classid andr.objid is not distinct from w.objid andr.objsubid is not distinct from w.objsubid andr.pid <> w.pid)),t_unionall as(select r.* from t_overlap runion allselect w.* from t_wait w)select locktype,datname,relation::regclass,page,tuple,virtualxid,transactionid::text,classid::regclass,objid,objsubid,string_agg('Pid: '||case when pid is null then 'NULL' else pid::text end||chr(10)||'Lock_Granted: '||case when granted is null then 'NULL' else granted::text end||' , Mode: '||case when mode is null then 'NULL' else mode::text end||' , FastPath: '||case when fastpath is null then 'NULL' else fastpath::text end||' , VirtualTransaction: '||case when virtualtransaction is null then 'NULL' else virtualtransaction::text end||' , Session_State: '||case when state is null then 'NULL' else state::text end||chr(10)||'Username: '||case when usename is null then 'NULL' else usename::text end||' , Database: '||case when datname is null then 'NULL' else datname::text end||' , Client_Addr: '||case when client_addr is null then 'NULL' else client_addr::text end||' , Client_Port: '||case when client_port is null then 'NULL' else client_port::text end||' , Application_Name: '||case when application_name is null then 'NULL' else application_name::text end||chr(10)||'Xact_Start: '||case when xact_start is null then 'NULL' else xact_start::text end||' , Query_Start: '||case when query_start is null then 'NULL' else query_start::text end||' , Xact_Elapse: '||case when (now()-xact_start) is null then 'NULL' else (now()-xact_start)::text end||' , Query_Elapse: '||case when (now()-query_start) is null then 'NULL' else (now()-query_start)::text end||chr(10)||'SQL (Current SQL in Transaction): '||chr(10)||case when query is null then 'NULL' else query::text end,chr(10)||'--------'||chr(10)order by( case modewhen 'INVALID' then 0when 'AccessShareLock' then 1when 'RowShareLock' then 2when 'RowExclusiveLock' then 3when 'ShareUpdateExclusiveLock' then 4when 'ShareLock' then 5when 'ShareRowExclusiveLock' then 6when 'ExclusiveLock' then 7when 'AccessExclusiveLock' then 8else 0end  ) desc,(case when granted then 0 else 1 end)) as lock_conflictfrom t_unionallgroup bylocktype,datname,relation,page,tuple,virtualxid,transactionid::text,classid,objid,objsubid ;

测试如下:

//session 1
test=# select * from test123;id |               info
----+----------------------------------1 | 101dc9e8c1d68234176830154b085ac72 | a43bf589b17bba8f38f117fda7a52b0d3 | daf21791ed3a9a45cca9ff1523d9090f4 | 92d9d4badb391f7e75d0c65bb720002e5 | f6a528c82a337412dbeff0a037bbb41b6 | 95e830bfd6789ff3b460f293ab1943e57 | a48251f4dc31eaaa8d9d14310fe7a66c8 | 0abd9628ccdeabe85f63de244019591a9 | 42a01ab80a13b64619d8b6371caf670b10 | 0048a0b3a4da91c05b7997b2f9a48156
(10 行记录)test=#
test=#
test=#
test=#
test=#
test=# begin;
BEGIN
test=*# delete from test123 where id=1
DELETE 1//session 2,被hang住了test=# begin;
BEGIN
test=*# truncate table test123;

检测结果:

locktype      | relation
datname       | test
relation      | test123
page          |
tuple         |
virtualxid    |
transactionid |
classid       |
objid         |
objsubid      |
lock_conflict | Pid: 8209                                                                                                                                            +| Lock_Granted: false , Mode: AccessExclusiveLock , FastPath: false , VirtualTransaction: 8/1931 , Session_State: active                               +| Username: sde , Database: test , Client_Addr: 192.168.100.182/32 , Client_Port: 6503 , Application_Name: psql                                        +| Xact_Start: 2025-06-30 10:35:22.978384+08 , Query_Start: 2025-06-30 10:35:32.866765+08 , Xact_Elapse: 00:09:33.288584 , Query_Elapse: 00:09:23.400203+| SQL (Current SQL in Transaction):                                                                                                                    +| truncate table test123;                                                                                                                              +| --------                                                                                                                                             +| Pid: 31733                                                                                                                                           +| Lock_Granted: true , Mode: RowExclusiveLock , FastPath: false , VirtualTransaction: 6/7257 , Session_State: idle in transaction                      +| Username: sde , Database: test , Client_Addr: 192.168.100.182/32 , Client_Port: 13683 , Application_Name: psql                                       +| Xact_Start: 2025-06-30 10:33:56.666653+08 , Query_Start: 2025-06-30 10:34:00.961553+08 , Xact_Elapse: 00:10:59.600315 , Query_Elapse: 00:10:55.305415+| SQL (Current SQL in Transaction):                                                                                                                    +| delete from test123 where id=1;

查看阻塞会话,并生成kill sql

with recursive 
tmp_lock as (select distinct--w.mode w_mode,w.page w_page,--w.tuple w_tuple,w.xact_start w_xact_start,w.query_start w_query_start,--now()-w.query_start w_locktime,w.query w_queryw.pid as id,--w_pid,r.pid as parentid--r_pid,--r.locktype,r.mode r_mode,r.usename r_user,r.datname r_db,--r.relation::regclass,--r.page r_page,r.tuple r_tuple,r.xact_start r_xact_start,--r.query_start r_query_start,--now()-r.query_start r_locktime,r.query r_query,from (select a.mode,a.locktype,a.database,a.relation,a.page,a.tuple,a.classid,a.objid,a.objsubid,a.pid,a.virtualtransaction,a.virtualxid,a.transactionid,b.query as query,b.xact_start,b.query_start,b.usename,b.datnamefrom pg_locks a,pg_stat_activity bwhere a.pid=b.pidand not a.granted) w,(select a.mode,a.locktype,a.database,a.relation,a.page,a.tuple,a.classid,a.objid,a.objsubid,a.pid,a.virtualtransaction,a.virtualxid,a.transactionid,b.query as query,b.xact_start,b.query_start,b.usename,b.datnamefrom pg_locks a,pg_stat_activity b -- select pg_typeof(pid) from pg_stat_activitywhere a.pid=b.pidand a.granted) rwhere 1=1and r.locktype is not distinct from w.locktypeand r.database is not distinct from w.databaseand r.relation is not distinct from w.relationand r.page is not distinct from w.pageand r.tuple is not distinct from w.tupleand r.classid is not distinct from w.classidand r.objid is not distinct from w.objidand r.objsubid is not distinct from w.objsubidand r.transactionid is not distinct from w.transactionidand r.pid <> w.pid),
tmp0 as (select *from tmp_lock tlunion allselect t1.parentid,0::int4from tmp_lock t1where 1=1and t1.parentid not in (select id from tmp_lock)),
tmp3 (pathid,depth,id,parentid) as (SELECT array[id]::text[] as pathid,1 as depth,id,parentidFROM tmp0where 1=1 and parentid=0unionSELECT t0.pathid||array[t1.id]::text[] as pathid,t0.depth+1 as depth,t1.id,t1.parentidFROM tmp0 t1, tmp3 t0where 1=1 and t1.parentid=t0.id
)
select distinct'/'||array_to_string(a0.pathid,'/') as pathid,a0.depth,a0.id,a0.parentid,lpad(a0.id::text, 2*a0.depth-1+length(a0.id::text),' ') as tree_id,--'select pg_cancel_backend('||a0.id|| ');' as cancel_pid,--'select pg_terminate_backend('||a0.id|| ');' as term_pid,case when a0.depth =1 then 'select pg_terminate_backend('|| a0.id || ');' else null end  as term_pid,case when a0.depth =1 then 'select cancel_backend('|| a0.id || ');' else null end  as cancel_pid,a2.datname,a2.usename,a2.application_name,a2.client_addr,a2.wait_event_type,a2.wait_event,a2.state--,a2.backend_start,a2.xact_start,a2.query_start
from tmp3 a0
left outer join (select distinct '/'||id||'/' as prefix_id,idfrom tmp0where 1=1 ) a1
on position( a1.prefix_id in '/'||array_to_string(a0.pathid,'/')||'/' ) >0
left outer join pg_stat_activity a2 -- select * from pg_stat_activity
on a0.id = a2.pid
order by '/'||array_to_string(a0.pathid,'/'),a0.depth;

查询结果如下:

-[ RECORD 1 ]----+------------------------------------
pathid           | /31733
depth            | 1
id               | 31733
parentid         | 0
tree_id          |  31733
term_pid         | select pg_terminate_backend(31733);
cancel_pid       | select cancel_backend(31733);
datname          | test
usename          | sde
application_name | psql
client_addr      | 192.168.100.182
wait_event_type  | Client
wait_event       | ClientRead
state            | idle in transaction
-[ RECORD 2 ]----+------------------------------------
pathid           | /31733/8209
depth            | 2
id               | 8209
parentid         | 31733
tree_id          |    8209
term_pid         |
cancel_pid       |
datname          | test
usename          | sde
application_name | psql
client_addr      | 192.168.100.182
wait_event_type  | Lock
wait_event       | relation
state            | active

查询超过60s的sql

selectpg_stat_activity.datname,pg_stat_activity.pid,pg_stat_activity.query,pg_stat_activity.client_addr,clock_timestamp() - pg_stat_activity.query_start
frompg_stat_activity pg_stat_activity
where(pg_stat_activity.state = any (array['active'::text,'idle in transaction'::text]))and (clock_timestamp() - pg_stat_activity.query_start) > '00:00:60'::interval
order by(clock_timestamp() - pg_stat_activity.query_start) desc;

结果如下:

-[ RECORD 1 ]--------------------------------
datname     | test
pid         | 31733
query       | delete from test123 where id=1;
client_addr | 192.168.100.182
?column?    | 00:21:25.624592
-[ RECORD 2 ]--------------------------------
datname     | test
pid         | 8209
query       | truncate table test123;
client_addr | 192.168.100.182
?column?    | 00:19:53.719401

本文来自互联网用户投稿,该文观点仅代表作者本人,不代表本站立场。本站仅提供信息存储空间服务,不拥有所有权,不承担相关法律责任。
如若转载,请注明出处:http://www.pswp.cn/web/86937.shtml
繁体地址,请注明出处:http://hk.pswp.cn/web/86937.shtml
英文地址,请注明出处:http://en.pswp.cn/web/86937.shtml

如若内容造成侵权/违法违规/事实不符,请联系英文站点网进行投诉反馈email:809451989@qq.com,一经查实,立即删除!

相关文章

JSON 格式详解

JSON 格式详解 随着互联网的发展和各种 Web 应用程序的普及&#xff0c;数据交换已经成为了我们日常开发中的重要环节。而在各种数据交换格式中&#xff0c;JSON&#xff08;JavaScript Object Notation&#xff09;作为一种轻量级的数据交换格式&#xff0c;以其简洁、易于阅…

原型设计Axure RP网盘资源下载与安装教程共享

对于初学者来说&#xff0c;我们熟悉一下其定义&#xff1a;‌Axure RP是一款常用的快速原型设计工具‌&#xff0c;主要用于创建应用软件或Web网站的线框图、流程图、原型和规格说明文档&#xff0c;广泛应用于产品经理、UI/UX设计师等专业领域。‌‌ 主要用户群体&#xff1…

iframe嵌套 redirect中转页面 route跳转

需求是项目A要使用iframe内嵌项目B的页面&#xff0c; 由于需要嵌套的页面很多&#xff0c;每个页面路径和参数又各不相同&#xff0c; 所以我们在项目B里做了一个中转页面&#xff0c;这样就能自己掌控项目A传递过来的东西了&#xff1b; routes.js 增加一个菜单&#xff1a;…

IP数据报 封装成 MAC帧 ( 目的MAC地址6B 源MAC地址6B 类型2B 数据部分 FCS校验和4B )

将 IP 数据报&#xff08;Internet Protocol Datagram&#xff09;封装成 MAC 帧 需要在数据链路层添加适当的头部信息&#xff0c;以便在局域网内进行传输。这个过程涉及将网络层&#xff08;IP 层&#xff09;的数据通过数据链路层&#xff08;MAC 层&#xff09;封装成适合物…

Note2.4 机器学习:Batch Normalization Introduction

Batch Normalization&#xff08;批标准化&#xff0c;BN&#xff09;通过标准化数据的操作&#xff0c;使得损失函数的优化地形&#xff08;optimization landscape&#xff09;更加平滑&#xff0c;从而达到更好地训练效果。BN常用于卷积神经网络&#xff08;CNN&#xff09;…

IDEA在AI时代的智能编程实践:从工蜂到通义灵码的效能跃迁‌‌

引言‌ 在腾讯云工作期间&#xff0c;我曾使用‌工蜂的AI代码补全功能&#xff0c;结合IntelliJ IDEA&#xff08;以下简称IDEA&#xff09;极大提升了开发效率。如今离开腾讯云&#xff0c;面对外部开发环境&#xff0c;如何继续利用AI提升编码效率&#xff1f;本文将系统梳理…

MySQL 慢查询日志详解

慢查询日志&#xff08;Slow Query Log&#xff09;是 MySQL 提供的一种核心性能优化工具&#xff0c;用于记录执行时间超过指定阈值的 SQL 语句。通过分析这些日志&#xff0c;可以定位数据库性能瓶颈&#xff0c;优化低效查询&#xff0c;提升系统整体效率。 一、慢查询日志的…

UV安装Python指南总结

UV安装Python指南总结 UV是一个Python包管理工具,它可以帮助我们安装和管理Python版本。以下是关于UV安装Python的主要功能和用法总结。 基本使用 安装最新版Python uv python install注意&#xff1a;UV使用Astral的python-build-standalone项目提供的Python发行版,而不是…

运维基础-MYSQL数据库-笔记

序 欠10年前自己的一份笔记&#xff0c;献给今后的自己。 数据库介绍 数据的时代 涉及的数据量大数据不随程序的结束而消失数据被多个应用程序共享大数据 数据库的发展史 萌芽阶段&#xff1a;文件系统 使用磁盘文件来存储数据初级阶段&#xff1a;第一代数据库 出现了网状…

从GPTs到Real智能体:目前常见的几种创建智能体方式

文章目录 智能体的三个发展阶段低阶智能体(面向过程) VS 高阶智能体(面向目标)主流智能体创建平台实践基础型平台cherry-studio豆包讯飞星火腾讯元器 高阶智能体开发体系cline开发套件Coze平台Dify开源框架Manus突破性方案 技术演进趋势总结 智能体的三个发展阶段 当前智能体技…

WPF 实现自定义数字输入弹窗

1.前端代码实现 <Grid><Grid.RowDefinitions><RowDefinition Height"100" /><RowDefinition Height"*" /></Grid.RowDefinitions><BorderGrid.Row"0"BorderBrush"WhiteSmoke"BorderThickness"0…

基于yolo海洋垃圾物品识别系统flask

查看完整项目包点击文末名片 项目简介 本项目 基于YOLO的海洋垃圾物品识别系统 旨在利用深度学习中的YOLO&#xff08;You Only Look Once&#xff09;模型&#xff0c;实现对海洋垃圾的自动识别与分类。通过构建一个基于Flask的Web应用&#xff0c;用户可以方便地上传图片&…

从数据到决策:UI前端如何利用数字孪生技术提升管理效率?

hello宝子们...我们是艾斯视觉擅长ui设计、前端开发、数字孪生、大数据、三维建模、三维动画10年经验!希望我的分享能帮助到您!如需帮助可以评论关注私信我们一起探讨!致敬感谢感恩! 在数字化转型的深水区&#xff0c;企业管理者正面临数据过载与决策滞后的双重挑战 ——IDC 研…

Spring Boot高并发 锁的使用方法

Spring Boot高并发 锁的使用方法 在高并发场景中&#xff08;比如电商秒杀、抢票系统、转账交易&#xff09;&#xff0c;多个线程/用户会同时操作同一共享资源&#xff08;如库存、账户余额、订单号&#xff09;。如果不做控制&#xff0c;会导致数据错误&#xff08;如库存超…

二十九:Dynamic Prompts插件动态提示词讲解

引言:可变化提示词,随机抽取不固定 使用方式一:{提示词1|提示词2|。。。。}------从提示词种随机抽取生成 方式二:{25::提示词1|75::提示词2}------数字为每个提示词的占比,相当于权重 方式三:{2$$提示词1|提示词2|提示词3|提示词4|。。。}从中选区2个搭配生成(可以换 比…

vscode 改注释的颜色,默认是灰色的,想改成红色

修改VScode编辑器默认注释的颜色_databricks代码中怎么设置让注释是灰色的-CSDN博客 //改变注释颜色"editor.tokenColorCustomizations": {"comments": "#009933" // 注释}, //如果后面还加内容&#xff0c;记得块末用逗号隔开我自己用的vscdoe.…

chili3d笔记22 正交投影3d重建笔记3 面构建

双视图重建3d solid import { FaceNode } from "chili"; import {IDocument,IEdge,Logger,ShapeNode,XYZ } from "chili-core"; import { Graph } from "graphlib"; function pointToString(point: XYZ): string {return ${point.x.toFixed(0)}-…

Kotlin 协程使用与通信

一、协程基础使用 1. 协程的三种创建方式 (1) launch - 启动后台作业 val job CoroutineScope(Dispatchers.IO).launch {// 后台操作delay(1000)println("任务完成 ${Thread.currentThread().name}")// 输出&#xff1a;任务完成 DefaultDispatcher-worker-1 } j…

Ubuntu服务器(公网)- Ubuntu客户端(内网)的FRP内网穿透配置教程

以下是为Ubuntu服务器&#xff08;公网&#xff09;- Ubuntu客户端&#xff08;内网&#xff09;的FRP内网穿透配置教程&#xff0c;基于最新版本&#xff08;2025年6月&#xff0c;使用frp_0.61.1_linux_amd64&#xff09;整理&#xff1a; 一、服务端配置&#xff08;公网Ubu…

什么是哈希函数(SHA-256)

SHA-256 是区块链系统中最核心的加密基础之一&#xff0c;尤其是在比特币、以太坊、文件存证等场景中扮演“指纹识别器”的角色。下面是对它的详细讲解&#xff0c;包括原理、特点、用途和代码示例。 &#x1f4cc; 一、什么是 SHA-256&#xff1f; SHA-256 是一种密码学哈希函…