Labels

Script categories

Showing posts with label Performance. Show all posts
Showing posts with label Performance. Show all posts

Wednesday, 16 November 2011

Report historical wait times per event for a specific Table

I always try and name my constraint and index names
with the same prefix as my table name and then suffix it with
a few characters to indicate what type of constraint or index it is.

For Example;

For a table such as TRADE_DEAL;

create table Trade_Deal
(Deal_ID      number          not null
,Deal_Type    varchar2(10)
,Deal_version integer
,Created      timestamp default current_timestamp
,Trade_Risk   integer
,GBP_Amnt     number          not null
,USD_Amnt     number);

The primary key would be named as follows;

alter table trade_deal 
add constraint TRADE_DEAL_PK primary key (deal_id);

A check constraint might be named as follows;

alter table trade_deal add constraint
TRADE_DEAL_CK_RISK check (trade_risk in (1,2,3,4,5,6,7,8,9));

The main reason for naming my objects using the above convention
is that it simplifies running queries to asses performance
stats on a particular set of related objects.

For example, the AWR query below will output the time waited
per wait event for a set of related table and indexes.

First set the start and end snapshot ID as variables before
attempting to run the query below. Use this script if you want;
http://bluefrog-oracle.blogspot.com/2011/11/set-start-and-end-snapshot-id-for-awr.html

variable p_Schema varchar2(30);
exec :p_Schema := sys_context('USERENV','CURRENT_SCHEMA');

col Object_Name format a32
col Object_Type format a10
col Event_Name  format a40
select
  /*+ all_rows */
   ds.Instance        as Instance_Number
  ,ao.Object_Name     as Object_Name
  ,ao.Object_Type     as Object_Type
  ,ds.Event           as Event_Name
  ,sum(ds.Cnt)        as Event_Wait_Cnt
  ,sum(Time_Waited)   as Time_Waited
from
  (
   select    /*+ all_rows */
             au.Username
            ,e.Name          as Event
            ,count(*)        as Cnt
            ,sum(Wait_Time)  as Time_Waited
            ,da.Current_Obj# as Object_ID
            ,Instance_Number as Instance
   from
             dba_hist_active_sess_history da
            ,v$Event_Name e
            ,all_users   au
   where     da.Event_ID = e.Event_ID
   and       da.User_ID  = au.User_ID
   and       da.Snap_ID  between :p_Start_Snap_ID and :p_End_Snap_ID
   and       au.Username = :p_Schema
   group by  au.Username
            ,e.Name
            ,da.Current_Obj#
            ,da.Instance_Number
   order by 3 desc
  )                     ds
  ,dba_Objects          ao
where
          ao.Object_ID          = ds.Object_ID
and       ao.Object_name        like  '&Object%'
and       ao.Object_Type        in ('TABLE','INDEX')
-- Exclude SQL Client type of waits
and       ds.Event              not like 'SQL*Net%'
group by  ao.Object_Name
         ,ao.Object_Type
         ,ds.Event
         ,ds.Instance
order by 5 desc, 4
/

Friday, 11 November 2011

Identify SQL in blocking and waiting sessions

col Event format a25
col DML_BLOCKING format a45
col DML_In_Waiting format a45
set linesize 400
set pagesize 3000

-- LABEL: STATEMENT A
select  distinct
        a.sid                     as Waiting_SID
       ,d.sql_text                as DML_In_Waiting
       ,o.Owner                   as Object_Owner
       ,o.Object_Name             as Locked_Object
       ,a.Blocking_Session        as Blocking_SID
       ,c.sql_text                as DML_Blocking
from
        v$session                 a
       ,v$active_session_history  b
       ,v$sql                     c
       ,v$sql                     d
       ,all_objects               o
where
        a.event                   = 'enq: TX - row lock contention'
and     a.sql_id                  = d.sql_id
and     a.blocking_session        = b.session_id
and     c.sql_id                  = b.sql_id
and     a.Row_Wait_Obj#           = o.Object_ID
and     b.Current_Obj#            = a.Row_Wait_Obj#
and     b.Current_File#           = a.Row_Wait_File#
and     b.Current_Block#          = a.Row_Wait_Block#

-- LABEL: STATEMENT B
select  distinct
        a.sid                     as Waiting_SID
       ,a.event                   as Event
       ,c.sql_text                as DML_Blocking
       ,b.sid                     as Blocking_SID
       ,b.event                   as Event
       ,b.sql_id                  as Blocking_SQL_ID
       ,b.prev_sql_id             as Blocking_Prev_SQL_ID
       ,d.sql_text                as DML_Blocking
from
        v$session                 a
       ,v$session                 b
       ,v$sql                     c
       ,v$sql                     d
where
        a.event                   = 'enq: TX - row lock contention'
and     a.blocking_session        = b.sid
and     c.sql_id                  = a.sql_id
and     d.sql_id                  = nvl(b.sql_id,b.prev_sql_id);

The first statement is generally more accurate than the second, since
the session holding the lock may have issued several DML
statements since issuing the lock, so the DML that is output
as holding the lock may not be related to the blocking DML.

Occasionally you may find that the SQL_ID for the
session holding the lock is NULL, reason being that since issuing the
lock some PL/SQL code may have executed or a COMMIT is being performed
or some other ongoing latch activity is busy, in which case there
is no SQL_ID to identify the session with.

In such cases, join to NVL(B.SQL_ID,B.PREV_SQL_ID).


Sample output after simulating a blocking and waiting session;

In session 1, issue a full table lock;

create table test_lock (a varchar2(2), bb varchar2(2));
insert into test_lock values ('i', '1');
insert into test_lock values ('ii','2');
commit;
select * from test_lock for update;

In session 2, issue an update on one of the rows in table TEST_LOCK

update test_lock set a='i' where bb='1';

The above UPDATE statement will simply hang. Do not issue a rollback
in session1.

In Session 1, run the first SQL statement, labelled as "STATEMENT A" above.

Sample output;

WAITING_SID DML_IN_WAITING                          OBJECT_OWNER LOCKED_OBJECT                  BLOCKING_SID DML_BLOCKING
----------- --------------------------------------- ------------ ------------------------------ ------------ ----------------------------------
       2081 update test_lock set a='i' where bb='1' USER1        TEST_LOCK                               382 select * from test_lock for update

Thursday, 10 November 2011

Identify blocking session for an UPDATE

Simulate a blocking session first:

Open 2 session windows, either in SQL Plus or any other cilent tool
you may be using.
In session 1 create a table and insert some data

create table test_lock (a varchar2(2), bb varchar2(2));
insert into test_lock values ('i','1');
insert into test_lock values ('ii', '2');
select * from test_lock;
commit;

Before starting the simulation, obtain the unique session ID's
for both sessions by using the following statement;

select distinct sid from v$mystat;

Obtain an exclusive lock in session 1 as follows;

select * from test_lock for update;



Now, in session 2, run these queries to identify blocking sessions;

update test_lock set a='i' where bb='1';

This statement will simply hang, since session 1 holds an exclusive lock on all rows within the table. Do not issue a rollback or commit;

Now query V$LOCK in session 1 using the following 3 statements;

set pagesize 3000
set linesize 1000
select * from v$lock;

select l1.sid, ' IS BLOCKING ', l2.sid, l1.lmode, l2.request
from   v$lock l1, v$lock l2
where   l1.block    = 1
and     l2.request  > 0
and     l1.id1      =l2.id1
and    l1.id2       =l2.id2;

select    s1.username
       || '@'
       || s1.machine
       || ' ( SID='
       || s1.sid
       || ' )  is blocking '
       || s2.username
       || '@'
       || s2.machine
       || ' ( SID='
       || s2.sid
       || ' ) ' AS blocking_status
from  v$lock    l1
     ,v$session s1
     ,v$lock    l2
     ,v$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;

Finally, use the next few statements to identify the object ID and
blocked row information.

Replace the session id in the where clause with the
waiting session id, session 2.

select row_wait_obj#, row_wait_file#, row_wait_block#, row_wait_row#
from v$session
where sid=&sid;


Replace the SID in the where clause with that of session 2
to obtain the Object name and ROWID

select do.object_name
      ,row_wait_obj#
      ,row_wait_file#
      ,row_wait_block#
      ,row_wait_row#
      ,dbms_rowid.rowid_create ( 1, ROW_WAIT_OBJ#
                                   ,ROW_WAIT_FILE#
                                   ,ROW_WAIT_BLOCK#
                                   ,ROW_WAIT_ROW# )
from   v$session       s
      ,dba_objects     do
where  sid             = &sid -- this is the SID from session2
and    s.ROW_WAIT_OBJ# = do.OBJECT_ID;



Replace the ROWID from the previous result set to obtain the
actual row data

select *
from test_lock
where rowid='AAAVnHAAQAAAp0tAAA';

Wednesday, 9 November 2011

Identify most scanned tables

Identify the top 20 most scanned tables.

set linesize 400
set pagesize 3000
col Owner format a15
col Object_Name format a30

select /*+ all_rows */
       *
from
    (select Inst_ID
           ,owner
           ,object_name
           ,value
     from   gv$segment_statistics
     where  statistic_name ='logical  reads'
     and    object_type='TABLE'
     order by 3 desc)
where rownum < 21
/

Friday, 4 November 2011

Identify hot blocks using AWR

First set the start and end snapshot ID as variables. 
Use this script if you want; http://bluefrog-oracle.blogspot.com/2011/11/set-start-and-end-snapshot-id-for-awr.html

To get a general idea of where the majority of WAITS's occur,
run the following SQL statement to view the counts of wait classes
in descending order;

---------------------------------------------------------

select   d.wait_class_id                as Wait_Class_ID
        ,d.wait_class                   as Wait_Class
        ,count(*)                       as Cnt
from     dba_hist_active_sess_history   d
where    d.nap_id between :p_Start_Snap_ID and :p_End_Snap_ID
group by d.wait_class_id
        ,d.wait_class
order by 3 desc;


Next, List a breakdown of Events per Wait class identified
in the previous result set;
---------------------------------------------------------
select   d.wait_class_id                as Wait_Class_id
        ,d.wait_class                   as Wait_Class_Name
        ,e.Name                         as Event_Name
        ,count(*)                       as Cnt
from     dba_hist_active_sess_history   d
        ,v$Event_Name                   e
where    d.snap_id between :p_Start_Snap_ID and :p_End_Snap_ID
and      d.Event_ID                     = e.Event_ID
group by d.wait_class_id
        ,d.wait_class
        ,e.Name
order by 4 desc;


Now attempt to identify which users are responsible for the
waits (broken down per event type).

select   d.wait_class_id                as Wait_Class_ID
        ,d.wait_class                   as Wait_Class_Name
        ,u.Username                     as User_Name
        ,e.Name                         as Event_Name
        ,count(*)                       as Cnt
from     dba_hist_active_sess_history   d
        ,v$Event_Name                   e
        ,all_users                      u
where    d.snap_id between :p_Start_Snap_ID and :p_End_Snap_ID
and      d.Event_ID         = e.Event_ID
and      d.User_id          = u.User_ID
group by u.Username
        ,d.wait_class_id
        ,d.wait_class
        ,e.Name
order by 4, 5 desc;


You may want to exclude WAITS's for SYS and focus only on the
application specific schemas, in which case, add
the additional predicate "u.Username != 'SYS'"

Also, you would probably want to exclude SQL*Net related WAIT's,
therefore add "e.Name not like 'SQL*Net%'" as a predicate.

select   d.wait_class                   as Wait_Class_Name
        ,u.Username                     as User_Name
        ,e.Name                         as Event_Name
        ,count(*)                       as Cnt
from     dba_hist_active_sess_history   d
        ,v$Event_Name                   e
        ,all_users                      u
where    d.snap_id between  :p_Start_Snap_ID and :p_End_Snap_ID
and      d.Event_ID         =     e.Event_ID
and      d.User_id          =     u.User_ID
and      u.Username         !=    'SYS'
and      e.Name not         like  'SQL*Net%'
group by u.Username
        ,d.wait_class
        ,e.Name
order by 4, 5 desc;


To drill down on hot blocks, the WAIT class to target would be;
"User I/O".
Therefore add an additional predicate;
      "d.Wait_Class       like  'User I/O'".

select   d.wait_class                   as Wait_Class_Name
        ,u.Username                     as User_Name
        ,e.Name                         as Event_Name
        ,count(*)                       as Cnt
from     dba_hist_active_sess_history   d
        ,v$Event_Name                   e
        ,all_users                      u
where    d.snap_id between  :p_Start_Snap_ID and :p_End_Snap_ID
and      d.Event_ID         =     e.Event_ID
and      d.User_id          =     u.User_ID
and      u.Username         !=    'SYS'
and      e.Name not         like  'SQL*Net%'
and      d.Wait_Class       like  'User I/O'
group by u.Username
        ,d.wait_class
        ,e.Name
order by 1, 4 desc;


To drill down on which Objects the hot blocks occur in,
join to the all_Objects dictionary view.

Remove the Event Name from the grouping and select list
since we know longer want to focus on individual reasons
for the general "User I/O" (of which there are several).

select   d.wait_class                   as Wait_Class_Name
        ,u.Username                     as User_Name
        ,a.Object_Name                  as Object_Name
        ,count(*)                       as Cnt
from     dba_hist_active_sess_history   d
        ,all_users                      u
        ,all_objects                    a
        ,v$Event_Name                   e
where    d.snap_id between  :p_Start_Snap_ID and :p_End_Snap_ID
and      d.Event_ID         =     e.Event_ID
and      d.User_id          =     u.User_ID
and      u.Username         !=    'SYS'
and      e.Name not         like  'SQL*Net%'
and      d.Wait_Class       like  'User I/O'
and      d.Current_Obj#     =     a.Object_ID
and      a.Object_Type      =     'TABLE'
group by u.Username
        ,d.wait_class
        ,a.Object_Name
order by 4 desc,  2, 3;


And finally, to identify the most read ROWs relative to a Top-N
number passed in as a parameter.

select User_Name
      ,Object_Name
      ,Hot_Row_ID
      ,Cnt
from
  (
  select   u.Username                     as User_Name
          ,a.Object_Name                  as Object_Name
          ,dbms_rowid.rowid_create(1, d.Current_Obj#
                                     ,d.Current_File#
                                     ,d.Current_Block#
                                     ,d.Current_Row#) as Hot_Row_ID
          ,count(*)                       as Cnt
  from     dba_hist_active_sess_history   d
          ,all_users                      u
          ,all_objects                    a
          ,v$Event_Name                   e
  where    d.snap_id between  :p_Start_Snap_ID and :p_End_Snap_ID
  and      d.Event_ID         =     e.Event_ID
  and      d.User_id          =     u.User_ID
  and      u.Username         !=    'SYS'
  and      e.Name not         like  'SQL*Net%'
  and      d.Wait_Class       like  'User I/O'
  and      d.Current_Obj#     =     a.Object_ID
  and      a.Object_Type      =     'TABLE'
  group by u.Username
          ,a.Object_Name
          ,dbms_rowid.rowid_create(1, d.Current_Obj#
                                     ,d.Current_File#
                                     ,d.Current_Block#
                                     ,d.Current_Row#)
  order by 4 desc,  2
  )
where rownum < &top_n;

Wednesday, 2 November 2011

Identify excessively read blocks (hot blocks)

Use the following query to identify which files the hot blocks occur in;

select p1 "file#"
      ,p2 "block#"
      ,p3 "class#"
from   v$session_wait
where  event = 'read by other session'
/

Once the above query has been run several times over, a pattern may emerge which highlights a specific range of blocks.

Then run the following SQL statement to identify which object(s) the blocks are associated with;

select relative_fno
      ,owner
      ,segment_name
      ,segment_type
from   dba_extents
-- the file parameter comes from the result set above
where  file_id      = &file
-- the block parameter comes from the result set above
and    &block       between block_id and block_id + blocks - 1
/

Monday, 31 October 2011

View waits per Segment for a specific session

set timing on
col event format a30
col owner format a10
col segment_type format a20
col segment_name format a32
set linesize 400
set pagesize 2000

select distinct
       a.sql_id           as SQL_ID
      ,a.segment_name     as Segment_Name
      ,a.owner            as Owner
      ,a.segment_type     as Segment_Type
      ,a.event            as Event
      ,a.count            as Count
from
(
  select /*+ all_rows */
          de.Owner
         ,de.Segment_Name
         ,de.Segment_Type
         ,ash.Event
         ,ash.SQL_ID
         ,round(sum(ash.time_waited)/100000)    as Total_Time
         ,count(*)                              as Cnt
         ,round( (sum(ash.time_waited)/100000)
          / count(*), 2)                        as Avg_wait
  from
          v$active_session_history  ash
         ,dba_extents               de
  where
          ash.p1           = de.file_id
  and     ash.time_waited  > 0
  and     ash.p2           between de.block_id
                           and (de.block_id+de.blocks-1)
  and     ash.session_id   = &sid
  and     de.owner         not in ('SYS', 'SYSTEM')
  group by de.owner
          ,de.segment_name
          ,de.segment_type
          ,ash.event
          ,ash.sql_id
  order by 6 desc
) a
where rownum <= 30 -- Only look at worst performing
order by 6 desc, 4 asc
/

Useful way to improve peformance of bulk DELETE

delete from table1
where
rowid in ( select rowid
           from table1 group by rowid, col_id
           minus
           select max(rowid)
           from table1 group by col_id);
 

View SQL that run more than one hour from AWR views

select  sql_text
from    dba_hist_sqltext
where   sql_id in 
  (select   sql_id
   from     dba_hist_sqlstat
   where    snap_id between &Start_SnapID and &End_SnapID
   and      elapsed_time_total > 7200000000 -- number for 1 hour
)
/

What to query when SQL_ID is NULL

Sometimes the SQL_ID in V$SESSION will be NULL even though a long running SQL statement appears to be executing. Reason being that something other than the SQL is in fact executing. It could be PL/SQL code, latching activity in the shared pool (which is common for very long running SQL statements) or a COMMIT is currently underway.

One can query the V$ACTIVE_SESSION_HISTORY dictionary view to identify the current elapsed time per wait event for the session;

select    /*+ all_rows */
          count(*)                  as Wait_Event_Count
         ,sum(ah.time_waited)       as Total_Time_Waited
         ,ah.session_id             as SID
         ,ev.name                   as Event_Name
         ,sql_id                    as SQL_ID
         ,ah.session_type           as Session_Type
from     
          v$active_session_history  ah
         ,v$event_name              ev
where     ah.sample_time between sysdate - 30/(24*60) and sysdate
and       ah.event#      = ev.event#(+)
and       ah.session_id  = &sid
group by 
          ev.name
         ,ah.session_id
         ,ah.sql_id
         ,ah.session_type
/


The following statement indicates the sessions that have caused the most load as a percentage of all foreground sessions;

select ah.session_id
      ,ah.session_type
      ,nvl(ah.sql_id,'xx')                     as SQL_ID
      ,count(*)                                as Session_Cnt
      ,round(count(*)/sum(count(*)) over(), 2) as Percent_Load
from
       v$active_session_history ah
where
       ah.sample_time >to_date('31-OCT-11 11:40','dd-MON-yy hh24:mi')
and    ah.session_type='FOREGROUND'
group by
       ah.session_id
      ,ah.session_type
      ,ah.sql_id
order by count(*) desc
/

The following SQL shows information on the PL/SQL units, which might be relevant if PL/SQL is busy executing and the SQL_ID is null;


select    ah.session_id               as SID
         ,ah.session_state            as State
         ,event                       as Event_name
         ,ah.sql_id                   as SQL_ID
         ,ah.top_level_sql_id
         ,ah.plsql_entry_object_id
         ,ah.plsql_entry_subprogram_id
         ,ah.plsql_object_id
         ,ah.plsql_subprogram_id
         ,count(*)                    as Wait_Event_Count
from
          v$active_session_history    ah
where
          ah.sample_time     between sysdate - 60/(24*60) and sysdate
and       ah.session_state   in ('ON CPU', 'WAITING')
and       ah.session_id      = &sid
group by  ah.session_id
         ,ah.session_state
         ,ah.event
         ,ah.sql_id
         ,ah.top_level_sql_id
         ,ah.plsql_entry_object_id
         ,ah.plsql_entry_subprogram_id
         ,ah.plsql_object_id
         ,ah.plsql_subprogram_id
order by
          ah.session_id
/


The following SQL shows operations that are currently executing specific to a session, which will give you an indication of what the wait is for if the SQL_ID is null.


alter session set nls_date_format = 'dd/mm/yyyy hh24:mi';
col target format a25
col opname format a40
select sid
      ,opname
      ,target
      ,round(sofar/totalwork*100,2)   as percent_done
      ,start_time
      ,last_update_time
      ,time_remaining
from 
       v$session_longops
where
       sid = &sid
/