Site icon IT Tutorial

Find Blocking Sessions and Kill Locked Session Scripts & Locked Objects | Oracle DBA Scripts All in One -3

I will share Find Blocking Sessions and Kill Locked Session Scripts & Locked Objects scripts and other Oracle DBA Scripts ( Oracle RAC, Dataguard, Performance Tuning, Monitoring and etc.. ) in this tutorial series.

 

Find Blocking Sessions and Kill Locked Session Scripts & Locked Objects in Oracle

 

 

Oracle DBA ( Database Administrator ) needs useful scripts to monitor, analyze and check Oracle database for routine database operations and monitoring.

 

 

Before Oracle DBA Scripts, If you don’t know Oracle database and want to learn, click following link to start learning Oracle database with this tutorial.

Oracle Tutorial | Oracle Database Tutorials for Beginners ( Junior Oracle DBA )

 

 

 

 

Find Blocking Sessions in Oracle

You can find historical blocking session and lock with below scripts. Change date time column which is specified with bold character.

select v.sql_text,v.sql_fulltext,sub.* from v$sql v,
(select sample_time,s.sql_id sql_id, session_state, blocking_session,
owner||'.'||object_name||':'||nvl(subobject_name,'-') obj_name,s.program,s.module,s.machine
from dba_hist_active_sess_history s, dba_objects o
where sample_time between
to_date('27/02/2019 07:30:02','DD/MM/YYYY HH24:MI:SS')
and
to_date('28/02/2019 15:10:02','DD/MM/YYYY HH24:MI:SS')
and event = 'enq: TX - row lock contention'
and o.data_object_id = s.current_obj#
order by 1 desc) sub where sub.sql_id=v.sql_id;




You can find momentarily blocking session and lock with below scripts.

select s1.username || '@' || s1.machine
|| ' ( THIS SID=' || s1.sid || ' )  is blocking '
|| s2.username || '@' || s2.machine || ' ( SID=' || s2.sid || ' ) ' AS blocking_status
from gv$lock l1, gv$session s1, gv$lock l2, gv$session s2
where s1.sid=l1.sid and s2.sid=l2.sid
and l1.BLOCK=1 and l2.request > 0
and l1.id1 = l2.id1
and l2.id2 = l2.id2 ;

 

You can generate Kill script of Blocking sessions like below.

SELECT 
'alter system kill session ''' || SID || ',' || s.serial# || ',@'||inst_id||''';',sid,username,serial#,process,NVL (sql_id, 0),
sql_address,blocking_session,wait_class,event,p1,p2,p3,seconds_in_wait
FROM gv$session s WHERE blocking_session_status = 'VALID'
OR sid IN (SELECT blocking_session
FROM gv$session WHERE blocking_session_status = 'VALID');

 

 

Alter system kill session

query result will be like below if you have blocking session in your database.

alter system kill session '1,39390,@1';
alter system kill session '2,2536,@1';
alter system kill session '3,26324,@1';






Kill Locked Session

Sometimes application developers or client offers you to kill any session or sessions group like SQL Net Client, or JDBC Client sessions or RMAN sessions.

You need to find session SID and SERIAL# with below script.

select s.SID,s.SERIAL#,S.USERNAME from v$session s where s.sid=63;

 

You can kill any session with its SID and SERIAL# number like below.

alter system kill session '63,1963';

 

Customer offers you to kill sessions group like SQL Net Client, or JDBC Client sessions or RMAN sessions. You can generate kill session script like below. You can change event to kill any other event group sessions.

SELECT 'kill -9 ' || p.spid, s.username,
'alter system kill session ''' || SID || ',' || s.serial# || ''';'
FROM v$session s, v$process p
WHERE s.paddr = p.addr(+)
AND s.SID IN (SELECT SID
FROM v$session_wait
WHERE event LIKE 'SQL*Net message from client%')
and s.username ='DEVECI'
and s.saddr not in ( select SES_ADDR from v$transaction );


Sometimes you have just SQL_ID and you need to find sessions related with this SQL_ID, then you can find like below and you can generate kill script like below.

SELECT 'kill -9 ' || p.spid, s.username,
'alter system kill session ''' || SID || ',' || s.serial# ||',@'||p.inst_id|| ''';'
FROM gv$session s, gv$process p
where s.SQL_ID like '4p5w3j8b3yhcw'
and s.PADDR = p.ADDR (+)
and s.STATUS='ACTIVE'
order by 1;


You can kill RMAN sessions which gives extra efor to the database like below.

SELECT 'kill -9 ' || p.spid, s.username,
       'alter system kill session ''' || SID || ',' || s.serial# ||',@'||p.inst_id|| ''';'
  FROM gv$session s, gv$process p
 WHERE s.paddr = p.addr(+)
and s.TYPE ='USER'
and s.program like 'rman%';


Sometimes you want to kill all users sessions except Application user. You can use following query to do this task.

SELECT 'kill -9 ' || p.spid, s.username,
       'alter system kill session ''' || SID || ',' || s.serial# ||',@'||p.inst_id|| ''';'
  FROM gv$session s, gv$process p
 WHERE s.paddr = p.addr(+)
and s.TYPE ='USER'
AND s.USERNAME <>'MSDEVECI';



 

 

Kill Session Script

You may want to kill some users sessions which is still executing more than 300 seconds, then you can use following useful Oracle DBA script.

 

SELECT 'kill -9 ' || p.spid, s.username,
       'alter system kill session ''' || SID || ',' || s.serial# || ''';'
  FROM v$session s, v$process p
 WHERE s.paddr = p.addr(+)
       AND s.SID IN (
   select sid
  from v$sql_monitor where status ='EXECUTING'  and elapsed_time/1000000> 300 
  and username in ('MEHMET','SALIH'))



You may want to kill some users sessions which are still executing more than 720 seconds and without SYS user and User type ( not background sessions ), then you can use following useful Oracle DBA script.

 

SELECT 
'alter system kill session ''' || SID || ',' || s.serial# ||',@'||p.inst_id|| ''';'
FROM gv$session s, gv$process p
WHERE s.paddr = p.addr(+)
and s.TYPE ='USER' and s.username!='SYS' and status='ACTIVE' and last_call_et > 720;





Find and Kill locked Objects

You can find the all locked objects and users for any Schema User with the following script. This scripts generate the kill session scripts also. You can use it to kill these sessions after review the sessions.

 

SELECT c.owner,
c.object_name,
c.object_type,
b.sid,
b.serial#,
b.inst_id,
b.status,
b.osuser,
b.machine,'alter system kill session ''' || b.sid || ',' || b.serial# || ',@'|| b.inst_id ||''';'
FROM gv$locked_object a, gv$session b, dba_objects c
WHERE b.sid = a.session_id AND a.object_id = c.object_id and c.owner= 'SCHEMA_NAME';

 

 

You can find the all locked objects and users for any Schema User with the following script. This scripts generate the kill session scripts also. You can use it to kill these sessions after review the sessions.

SELECT c.owner,
c.object_name,
c.object_type,
b.sid,
b.serial#,
b.inst_id,
b.status,
b.osuser,
b.machine,'alter system kill session ''' || b.sid || ',' || b.serial# || ',@'|| b.inst_id ||''';'
FROM gv$locked_object a, gv$session b, dba_objects c
WHERE b.sid = a.session_id AND a.object_id = c.object_id and c.object_name='TABLE_NAME';

 

 

 

You can access the second Oracle DBA scripts related to Dataguard with following link.

https://ittutorial.org/dataguard-status-standby-monitoring-command-and-scripts-oracle-dba-scripts-all-in-one-2/

 

 

 

Do you want to learn Oracle Database Performance Tuning detailed, then Click this link.
Exit mobile version