Oracle用户会话管理

(0 comments)

通过V$SESSION视图,可以查询Oracle所有会话信息:

select sid,logon_time,username,machine from v$session; 

通过分组,统计每个不同的用户或主机打开的会话总数:

select username,machine,count(*) from v$session group by username,machine;

根据SID和SERIAL#可以终止用户会话:

ALTER SYSTEM KILL SESSION 'v_sid,v_serial#' immediate;

用户会话的SID和SERIAL#可以通过V$SESSION视图查到:

SQL> select sid,serial#,username, machine,status from v$session where username like 'PCNSH%';

     SID    SERIAL# USERNAME     MACHINE                      STATUS
-------- ---------- --------------- ------------------------------- --------
     366      14303 PCNSH197    client197.yourdomain.com     INACTIVE
     369       1745 PCNSH003    server009                    INACTIVE
     370      10165 PCNSH049    client049.yourdomain.com     INACTIVE
     371      18999 PCNSH056    client056                    INACTIVE
     372       6207 PCNSH056    client056                    INACTIVE
     373       7688 PCNSH197    client197.yourdomain.com     INACTIVE
     374      19246 PCNSH003    server009                    INACTIVE
     377      17649 PCNSH003    server009                    INACTIVE

在Oracle中终止掉的会话只有在这个进程再次尝试连接Oracle时才会被pmon清除,在进程再次尝试连接之前,查询V$SESSION视图时还是可以看到该会话。

当用户会话无法响应时,上面的方法可能无法终止用户会话,只好直接杀死系统进程(谨慎)。

用户会话对应的系统进程可以通过V$SESSION和V$PROCESS两个视图来查询,通过会话的SID和SERIAL#可以查询到系统进程号。

SQL> select p.spid from v$session s, v$process p 
  where p.addr=s.paddr and s.sid=518 and s.serial#=41831;

SPID
------------
16782

然后在操作系统中杀死进程:

kill -9 16782

某些软件会在启动时打开多个会话,当软件异常退出时,要批量的终止这些会话。存储过程基于用户名条件批量终止会话,创建存储过程脚本kill_user.sql如下:

create or replace procedure kill_user(v_name in varchar2)
as
message varchar2(50);
cursor loguser is select sid,serial# from v$session where username=upper(v_name);
v_info loguser%rowtype;
sql_mgr varchar2(1000);
i number default 0;
begin
open loguser;
loop
fetch loguser into v_info;
exit when loguser%notfound;
i :=1;
sql_mgr :='alter system kill session '''||v_info.sid||','||v_info.serial#||''' immediate';
execute immediate sql_mgr;
dbms_output.put_line('All the sessions of '||v_name||' have been killed');
end loop;
close loguser;
if i=0 then
raise_application_error(-20004,'The user '||v_name||' is not login the database currently!');
end if;
exception
when no_data_found then
raise_application_error(-20004,'The user '||v_name||' is not login the database currently!');
end;
/

调用上面存储过程,终止用户所有进程的方法如下:

SQL> execute kill_user('user_name');
Currently unrated

Comments

There are currently no comments

New Comment

required

required (not published)

optional

required