Skip to content

Commit 7d71f36

Browse files
committed
fix
1 parent d40a3aa commit 7d71f36

File tree

1 file changed

+129
-0
lines changed

1 file changed

+129
-0
lines changed

201705/20170521_01.md

Lines changed: 129 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -368,6 +368,135 @@ postgres=# select * from v_locks_monitor ;
368368
(0 rows)
369369
```
370370

371+
## Greenplum
372+
如果是Greenplum,由于版本问题,SQL语句略微不一样,如下:
373+
374+
```
375+
with
376+
t_wait as
377+
(
378+
select a.mode,a.locktype,a.database,a.relation,a.page,a.tuple,a.classid,a.granted,
379+
a.objid,a.objsubid,a.pid,a.transactionid,a.mppsessionid,a.mppiswriter,a.gp_segment_id,
380+
b.procpid,b.sess_id,b.waiting_reason,b.current_query,b.xact_start,b.query_start,b.usename,b.datname,b.client_addr,b.client_port,b.application_name
381+
from pg_locks a,pg_stat_activity b where a.mppsessionid=b.sess_id and not a.granted
382+
),
383+
t_run as
384+
(
385+
select a.mode,a.locktype,a.database,a.relation,a.page,a.tuple,a.classid,a.granted,
386+
a.objid,a.objsubid,a.pid,a.transactionid,a.mppsessionid,a.mppiswriter,a.gp_segment_id,
387+
b.procpid,b.sess_id,b.waiting_reason,b.current_query,b.xact_start,b.query_start,b.usename,b.datname,b.client_addr,b.client_port,b.application_name
388+
from pg_locks a,pg_stat_activity b where a.mppsessionid=b.sess_id and a.granted
389+
),
390+
t_overlap as
391+
(
392+
select r.* from t_wait w join t_run r on
393+
(
394+
r.locktype is not distinct from w.locktype and
395+
r.database is not distinct from w.database and
396+
r.relation is not distinct from w.relation and
397+
r.page is not distinct from w.page and
398+
r.tuple is not distinct from w.tuple and
399+
r.transactionid is not distinct from w.transactionid and
400+
r.classid is not distinct from w.classid and
401+
r.objid is not distinct from w.objid and
402+
r.objsubid is not distinct from w.objsubid and
403+
r.mppsessionid <> w.mppsessionid
404+
)
405+
),
406+
t_unionall as
407+
(
408+
select r.* from t_overlap r
409+
union all
410+
select w.* from t_wait w
411+
)
412+
select locktype,datname,relation::regclass,page,tuple,textin(xidout(transactionid)),classid::regclass,objid,objsubid,
413+
string_agg(
414+
'Gp_Segment_Id: '||case when gp_segment_id is null then 'NULL' else gp_segment_id::text end||chr(10)||
415+
'MppIsWriter: '||case when mppiswriter is null then 'NULL' when mppiswriter is true then 'TRUE' else 'FALSE' end||chr(10)||
416+
'MppSessionId: '||case when mppsessionid is null then 'NULL' else mppsessionid::text end||chr(10)||
417+
'ProcPid: '||case when procpid is null then 'NULL' else procpid::text end||chr(10)||
418+
'Pid: '||case when pid is null then 'NULL' else pid::text end||chr(10)||
419+
'Lock_Granted: '||case when granted is null then 'NULL' when granted is true then 'TRUE' else 'FALSE' end||' , Mode: '||case when mode is null then 'NULL' else mode::text end||' , Waiting_Reason: '||case when waiting_reason is null then 'NULL' else waiting_reason::text end||chr(10)||
420+
'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)||
421+
'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)||
422+
'SQL (Current SQL in Transaction): '||chr(10)||
423+
case when current_query is null then 'NULL' else current_query::text end,
424+
chr(10)||'--------'||chr(10)
425+
order by
426+
( case mode
427+
when 'INVALID' then 0
428+
when 'AccessShareLock' then 1
429+
when 'RowShareLock' then 2
430+
when 'RowExclusiveLock' then 3
431+
when 'ShareUpdateExclusiveLock' then 4
432+
when 'ShareLock' then 5
433+
when 'ShareRowExclusiveLock' then 6
434+
when 'ExclusiveLock' then 7
435+
when 'AccessExclusiveLock' then 8
436+
else 0
437+
end ) desc,
438+
(case when granted then 0 else 1 end)
439+
) as lock_conflict
440+
from t_unionall
441+
group by
442+
locktype,datname,relation::regclass,page,tuple,textin(xidout(transactionid)),classid::regclass,objid,objsubid ;
443+
```
444+
445+
测试
446+
447+
```
448+
-[ RECORD 1 ]-+------------------------------------------------------------------------------------------------------------------------------------------------------
449+
locktype | relation
450+
datname | postgres
451+
relation | locktest
452+
page |
453+
tuple |
454+
textin |
455+
classid |
456+
objid |
457+
objsubid |
458+
lock_conflict | Gp_Segment_Id: -1
459+
| MppIsWriter: TRUE
460+
| MppSessionId: 46
461+
| ProcPid: 100310
462+
| Pid: 100310
463+
| Lock_Granted: TRUE , Mode: ExclusiveLock , Waiting_Reason: NULL
464+
| Username: dege.zzz , Database: postgres , Client_Addr: 127.0.0.1/32 , Client_Port: 51220 , Application_Name: psql
465+
| Xact_Start: 2017-05-22 14:59:50.067908+08 , Query_Start: 2017-05-22 15:00:01.568904+08 , Xact_Elapse: 00:00:37.858031 , Query_Elapse: 00:00:26.357035
466+
| SQL (Current SQL in Transaction):
467+
| <IDLE> in transaction
468+
| --------
469+
| Gp_Segment_Id: -1
470+
| MppIsWriter: TRUE
471+
| MppSessionId: 47
472+
| ProcPid: 112053
473+
| Pid: 112053
474+
| Lock_Granted: FALSE , Mode: ExclusiveLock , Waiting_Reason: lock
475+
| Username: dege.zzz , Database: postgres , Client_Addr: 127.0.0.1/32 , Client_Port: 51518 , Application_Name: psql
476+
| Xact_Start: 2017-05-22 15:00:06.994012+08 , Query_Start: 2017-05-22 15:00:19.6+08 , Xact_Elapse: 00:00:20.931927 , Query_Elapse: 00:00:08.325939
477+
| SQL (Current SQL in Transaction):
478+
| update locktest set info='b' where id=2;
479+
| --------
480+
| Gp_Segment_Id: 0
481+
| MppIsWriter: TRUE
482+
| MppSessionId: 46
483+
| ProcPid: 100310, master的pid
484+
| Pid: 111641, segment的pid
485+
| Lock_Granted: TRUE , Mode: RowExclusiveLock , Waiting_Reason: NULL
486+
| Username: dege.zzz , Database: postgres , Client_Addr: 127.0.0.1/32 , Client_Port: 51220 , Application_Name: psql
487+
| Xact_Start: 2017-05-22 14:59:50.067908+08 , Query_Start: 2017-05-22 15:00:01.568904+08 , Xact_Elapse: 00:00:37.858031 , Query_Elapse: 00:00:26.357035
488+
| SQL (Current SQL in Transaction):
489+
| <IDLE> in transaction
490+
```
491+
492+
关注gp_segment_id=-1的,长时间等待,杀掉procpid即可。
493+
494+
```
495+
postgres=# select pg_terminate_backend(100310);
496+
-[ RECORD 1 ]--------+--
497+
pg_terminate_backend | t
498+
```
499+
371500
## 参考
372501
https://www.postgresql.org/docs/9.6/static/view-pg-locks.html
373502

0 commit comments

Comments
 (0)