问题:V$SESSION SQL_ID 为空,找不到SQL_ID

问题:V$SESSION SQL_ID 为空,找不到SQL_ID

首先我们来做个实验:

SQL> select sid from v$mystat where rownum=1;
 
       SID
----------
      1150
 
SQL> update test set owner='BIGSB' where object_id<100;
 
98 rows updated

在1150这个SESSION里面执行一个UPDATE,不要提交。

SQL> select sid from v$mystat where rownum=1;
 
       SID
----------
      1338
 
SQL>  update test set owner='SB' where object_id<10;

在1338里面跑另外一个UPDATE,因为1150没提交,1138处于行锁等待。

这个时候通过如下脚本去查询数据库:

  select inst_id,  
       sid,  
       sql_id,  
       event,  
       blocking_session,  
       blocking_instance  
    from gv$session a  
   where blocking_session is not null; 

       INST_ID        SID SQL_ID        EVENT                                   BLOCKING_SESSION BLOCKING_INSTANCE  
    ---------- ---------- ------------- --------------------------------------- ---------------- ----------------  
             1       1338 852mvmth18w37 enq: TX - row lock contention           1150                 1  
               
 select sql_id from gv$session where inst_id=1 and sid=1150;  
       
    SQL_ID  
    -------------  


确实,SQL_ID是空的,也许有人会说,那我去查询PREV_SQL_ID,恩你去试一试吧,那个SQL_ID是事物的SQL_ID,并不是UPDATE的SQL_ID

   select prev_sql_id from gv$session where inst_id=1 and sid=1150;  
       
    PREV_SQL_ID  
    -------------  
    9m7787camwh4m  
       
    select sql_text from gv$sql where sql_id='9m7787camwh4m';  
       
    SQL_TEXT  
    --------------------------------------------------------------------------------  
    begin :id := sys.dbms_transaction.local_transaction_id; end;  


所以很多人这个时候就蛋疼了,不知道咋办。现在教大家另外一种方法


    select PREV_EXEC_START,USERNAME,MODULE,ACTION FROM GV$SESSION WHERE INST_ID=1 AND SID=1150;  
       
    PREV_EXEC_START     USERNAME    MODULE               ACTION  
    ---------------     ------------------------------ -----------------------  
    2015-04-10 18:01:44 SCOTT       PL/SQL Developer    Command Window - New  
      
    SELECT SQL_ID,SQL_TEXT,LAST_ACTIVE_TIME,MODULE,ACTION FROM GV$SQL WHERE INST_ID=1 AND LAST_ACTIVE_TIME=TO_DATE('2015-04-10 18:01:44','YYYY-MM-DD HH24:MI:SS');  
       
    SQL_ID        SQL_TEXT                                                                         LAST_ACTIVE_TIME MODULE              ACTION  
    ------------- -------------------------------------------------------------------------------- ---------------- 
    2syvqzbxp4k9z select u.name, o.name, a.interface_version#, o.obj#      from association$ a, us 2015/4/10 :01:                                                                    
    6c9wx6z8w9qpu select a.default_selectivity                             from association$ a     2015/4/10 18:01:                      
    2xyb5d6xg9srh select a.default_cpu_cost, a.default_io_cost             from association$ a     2015/4/10 :01:                                                                    
    d1s917pgj7650  update test set owner='BIGSB' where object_id<100                               2015/4/10 18:01: PL/SQL Developer    Command Window - New  
       


现在就可以把SQL 抓到了

请注意:

1.在高并发的情况下,可能会出现多个可疑SQL
2.UPDATE执行过后,又继续执行新的SQL,就悲催了,这个时候要自己把所有SQL抓出来,按照时间线排序,CHECK


反正,提供了一种思路,具体的时候请自己判断,脑袋不要太笨。

    select a.inst_id, a.sid, a.sql_id, b.sql_id, b.sql_text  
      from gv$session a, gv$sql b  
     where a.inst_id = b.inst_id  
       and a.PREV_EXEC_START = b.LAST_ACTIVE_TIME  
       and a.USERNAME = b.PARSING_SCHEMA_NAME  
       and a.MODULE = b.MODULE  
       --and a.ACTION_HASH = b.ACTION_HASH  
         
         
    select a.inst_id,  
           a.sid,  
           a.event,  
           a.sql_id,  
           b.sql_text          running_sql,  
           c.sql_in_session,  
           c.sql_id_in_v$sql,  
           c.sql_text          blocking_sql,  
           a.blocking_session,  
           a.blocking_instance  
      from gv$session a,  
           (select sql_id, sql_text  
              from (select sql_id,  
                           sql_text,  
                           row_number() over(partition by sql_id order by sql_id) as rn  
                      from gv$sql)  
             where rn = 1) b,  
           (select a.inst_id,  
                   a.sid,  
                   a.sql_id   sql_in_session,  
                   b.sql_id   sql_id_in_v$sql,  
                   b.sql_text  
              from gv$session a, gv$sql b  
             where a.inst_id = b.inst_id  
               and a.PREV_EXEC_START =b.LAST_ACTIVE_TIME  
               and a.USERNAME = b.PARSING_SCHEMA_NAME  
               and a.MODULE = b.MODULE  
            ) c  
     where a.sql_id = b.sql_id  
       and a.blocking_session is not null  
       and a.BLOCKING_SESSION = c.sid  
       and a.BLOCKING_INSTANCE = c.inst_id; 
请使用浏览器的分享功能分享到微信等