Thursday, December 31, 2015

Performance Tuning scripts

Top Recent Wait Events

col EVENT format a60 

select * from (
select active_session_history.event,
sum(active_session_history.wait_time +
active_session_history.time_waited) ttl_wait_time
from v$active_session_history active_session_history
where active_session_history.event is not null
group by active_session_history.event
order by 2 desc)
where rownum < 6
/

Top Wait Events Since Instance Startup

col event format a60

select event, total_waits, time_waited
from v$system_event e, v$event_name n
where n.event_id = e.event_id
and n.wait_class !='Idle'
and n.wait_class = (select wait_class from v$session_wait_class
 where wait_class !='Idle'
 group by wait_class having
sum(time_waited) = (select max(sum(time_waited)) from v$session_wait_class
where wait_class !='Idle'
group by (wait_class)))
order by 3;

List Of Users Currently Waiting

col username format a12
col sid format 9999
col state format a15
col event format a50
col wait_time format 99999999
set pagesize 100
set linesize 120

select s.sid, s.username, se.event, se.state, se.wait_time
from v$session s, v$session_wait se
where s.sid=se.sid
and se.event not like 'SQL*Net%'
and se.event not like '%rdbms%'
and s.username is not null
order by se.wait_time;

Find The Main Database Wait Events In A Particular Time Interval

First determine the snapshot id values for the period in question.
In this example we need to find the SNAP_ID for the period 10 PM to 11 PM on the 14th of November, 2012.
select snap_id,begin_interval_time,end_interval_time
from dba_hist_snapshot
where to_char(begin_interval_time,'DD-MON-YYYY')='14-NOV-2012'
and EXTRACT(HOUR FROM begin_interval_time) between 22 and 23;
set verify off
select * from (
select active_session_history.event,
sum(active_session_history.wait_time +
active_session_history.time_waited) ttl_wait_time
from dba_hist_active_sess_history active_session_history
where event is not null
and SNAP_ID between &ssnapid and &esnapid
group by active_session_history.event
order by 2 desc)
where rownum <  6

Top CPU Consuming SQL During A Certain Time Period

Note – in this case we are finding the Top 5 CPU intensive SQL statements executed between 9.00 AM and 11.00 AM
select * from (
select
SQL_ID,
 sum(CPU_TIME_DELTA),
sum(DISK_READS_DELTA),
count(*)
from
DBA_HIST_SQLSTAT a, dba_hist_snapshot s
where
s.snap_id = a.snap_id
and s.begin_interval_time > sysdate -1
and EXTRACT(HOUR FROM S.END_INTERVAL_TIME) between 9 and 11
group by
SQL_ID
order by
sum(CPU_TIME_DELTA) desc)
where rownum < 6

Which Database Objects Experienced the Most Number of Waits in the Past One Hour

set linesize 120
col event format a40
col object_name format a40

select * from 
(
  select dba_objects.object_name,
 dba_objects.object_type,
active_session_history.event,
 sum(active_session_history.wait_time +
  active_session_history.time_waited) ttl_wait_time
from v$active_session_history active_session_history,
    dba_objects
 where 
active_session_history.sample_time between sysdate - 1/24 and sysdate
and active_session_history.current_obj# = dba_objects.object_id
 group by dba_objects.object_name, dba_objects.object_type, active_session_history.event
 order by 4 desc)
where rownum < 6;

Top Segments ordered by Physical Reads

col segment_name format a20
col owner format a10 
select segment_name,object_type,total_physical_reads
 from ( select owner||'.'||object_name as segment_name,object_type,
value as total_physical_reads
from v$segment_statistics
 where statistic_name in ('physical reads')
 order by total_physical_reads desc)
 where rownum < 6 

Top 5 SQL statements in the past one hour

select * from (
select active_session_history.sql_id,
 dba_users.username,
 sqlarea.sql_text,
sum(active_session_history.wait_time +
active_session_history.time_waited) ttl_wait_time
from v$active_session_history active_session_history,
v$sqlarea sqlarea,
 dba_users
where 
active_session_history.sample_time between sysdate -  1/24  and sysdate
  and active_session_history.sql_id = sqlarea.sql_id
and active_session_history.user_id = dba_users.user_id
 group by active_session_history.sql_id,sqlarea.sql_text, dba_users.username
 order by 4 desc )
where rownum < 6

SQL with the highest I/O in the past one day

select * from 
(
SELECT /*+LEADING(x h) USE_NL(h)*/ 
       h.sql_id
,      SUM(10) ash_secs
FROM   dba_hist_snapshot x
,      dba_hist_active_sess_history h
WHERE   x.begin_interval_time > sysdate -1
AND    h.SNAP_id = X.SNAP_id
AND    h.dbid = x.dbid
AND    h.instance_number = x.instance_number
AND    h.event in  ('db file sequential read','db file scattered read')
GROUP BY h.sql_id
ORDER BY ash_secs desc )
where rownum < 6

Top CPU consuming queries since past one day

select * from (
select 
 SQL_ID, 
 sum(CPU_TIME_DELTA), 
 sum(DISK_READS_DELTA),
 count(*)
from 
 DBA_HIST_SQLSTAT a, dba_hist_snapshot s
where
 s.snap_id = a.snap_id
 and s.begin_interval_time > sysdate -1
 group by 
 SQL_ID
order by 
 sum(CPU_TIME_DELTA) desc)
where rownum < 6

Find what the top SQL was at a particular reported time of day

First determine the snapshot id values for the period in question.
In thos example we need to find the SNAP_ID for the period 10 PM to 11 PM on the 14th of November, 2012.
select snap_id,begin_interval_time,end_interval_time
from dba_hist_snapshot
where to_char(begin_interval_time,'DD-MON-YYYY')='14-NOV-2012'
and EXTRACT(HOUR FROM begin_interval_time) between 22 and 23;
select * from
 (
select
 sql.sql_id c1,
sql.buffer_gets_delta c2,
sql.disk_reads_delta c3,
sql.iowait_delta c4
 from
dba_hist_sqlstat sql,
dba_hist_snapshot s
 where
 s.snap_id = sql.snap_id
and
 s.snap_id= &snapid
 order by
 c3 desc)
 where rownum < 6 
/

Analyse a particular SQL ID and see the trends for the past day

select
 s.snap_id,
 to_char(s.begin_interval_time,'HH24:MI') c1,
 sql.executions_delta c2,
 sql.buffer_gets_delta c3,
 sql.disk_reads_delta c4,
 sql.iowait_delta c5,
sql.cpu_time_delta c6,
 sql.elapsed_time_delta c7
 from
 dba_hist_sqlstat sql,
 dba_hist_snapshot s
 where
 s.snap_id = sql.snap_id
 and s.begin_interval_time > sysdate -1
 and
sql.sql_id='&sqlid'
 order by c7
 /

Do we have multiple plan hash values for the same SQL ID – in that case may be changed plan is causing bad performance

select 
  SQL_ID 
, PLAN_HASH_VALUE 
, sum(EXECUTIONS_DELTA) EXECUTIONS
, sum(ROWS_PROCESSED_DELTA) CROWS
, trunc(sum(CPU_TIME_DELTA)/1000000/60) CPU_MINS
, trunc(sum(ELAPSED_TIME_DELTA)/1000000/60)  ELA_MINS
from DBA_HIST_SQLSTAT 
where SQL_ID in (
'&sqlid') 
group by SQL_ID , PLAN_HASH_VALUE
order by SQL_ID, CPU_MINS;

Top 5 Queries for past week based on ADDM recommendations

/*
Top 10 SQL_ID's for the last 7 days as identified by ADDM
from DBA_ADVISOR_RECOMMENDATIONS and dba_advisor_log
*/

col SQL_ID form a16
col Benefit form 9999999999999
select * from (
select b.ATTR1 as SQL_ID, max(a.BENEFIT) as "Benefit" 
from DBA_ADVISOR_RECOMMENDATIONS a, DBA_ADVISOR_OBJECTS b 
where a.REC_ID = b.OBJECT_ID
and a.TASK_ID = b.TASK_ID
and a.TASK_ID in (select distinct b.task_id
from dba_hist_snapshot a, dba_advisor_tasks b, dba_advisor_log l
where a.begin_interval_time > sysdate - 7 
and  a.dbid = (select dbid from v$database) 
and a.INSTANCE_NUMBER = (select INSTANCE_NUMBER from v$instance) 
and to_char(a.begin_interval_time, 'yyyymmddHH24') = to_char(b.created, 'yyyymmddHH24') 
and b.advisor_name = 'ADDM' 
and b.task_id = l.task_id 
and l.status = 'COMPLETED') 
and length(b.ATTR4) > 1 group by b.ATTR1
order by max(a.BENEFIT) desc) where rownum < 6;

Wednesday, July 22, 2015

Show the TEMP tablespace history of sort usage

Script that will show the TEMP tablespace history of sort usage

select distinct
c.username "user",
c.osuser ,
c.sid,
c.serial#,
b.spid "unix_pid",
c.machine,
c.program "program",
a.blocks * e.block_size/1024/1024 mb_temp_used  ,
a.tablespace,
d.sql_text
from
v$sort_usage a,
v$process b,
v$session c,
v$sqlarea d,
dba_tablespaces e
where c.saddr=a.session_addr
and b.addr=c.paddr
and c.sql_address=d.address(+)
and a.tablespace = e.tablespace_name;

Wednesday, April 29, 2015

How to find out mapped oracle ASM disk.

First you need enter into root.

sudo su -

Then change directory into cd /etc/init.d

[root@test200 init.d]# ./oracleasm listdisks
DATA01
FRA01
OCRVOTE01

If you want find which ASM disk is mapped which device, then you must use oracleasm querydisk with ASM disk name.


[root@test200 init.d]# oracleasm querydisk -d DATA01
Disk "DATA01" is a valid ASM disk on device [8,15]

As see you, DATA01 is valid ASM disk on device [8,15].

What is means?
It means DATA01 is mapped to device [8,15].

How to find [8,15] device?
We must use Linux ls –l  command as below.

[root@test200 init.d]# ls -l /dev/* | grep 8, | grep 15
brw-rw---- 1 root disk      8,  15 Jan  12 13:22 /dev/sdf

Now, we can say DATA01 is mapped to /dev/sdf

Tuesday, April 21, 2015

ORA-17628, ORA-19505 during RMAN DUPLICATE FROM ACTIVE

The following error is reported trying to create a Physical Standby database or clone  your database different location    using "duplicate from active database" :


input datafile file number=00032 name=+test/datafile/test01.425.877491083
RMAN-03009: failure of backup command on ch01 channel at 04/20/2015 20:39:29
ORA-17628: Oracle error 19505 returned by remote Oracle server
continuing other job steps, job failed will not be re-run
channel ch01: starting datafile copy
input datafile file number=00035 name=+test/datafile/test02.386.877491081
RMAN-03009: failure of backup command on ch02 channel at 04/20/2015 20:39:30
ORA-17628: Oracle error 19505 returned by remote Oracle server
continuing other job steps, job failed will not be re-run
channel ch02: starting datafile copy
input datafile file number=00115 name=+test/datafile/test03.260.877491083
RMAN-03009: failure of backup command on ch01 channel at 04/20/2015 20:39:30
ORA-17628: Oracle error 19505 returned by remote Oracle server

One datafile  is not using OMF name while the rest of the datafiles are using OMF name.

It is not oracle bug and this expected behavior.

The reason the duplicate of the database is failing is because there is no db_file_name_convert and the datafile that has an alias is not using an OMF name, so a new OMF name is not created for it and the filename is unchanged.

The parameter "parameter_value_convert"  changes the string  from 'xxx' to 'yyy' in other  initialization parameters, but not in the datafile names.  If the names of the datafiles are desired to be changed,  then  db_file_name_convert should be used


Solution:

1. Use the parameter DB_FILE_NAME_CONVERT and specify the complete location of the datafile using alias :

SET DB_FILE_NAME_CONVERT='+DATA/xxx/datafile','+DATA/yyy/datafile/'


or

2. Create the directory "xxx" in the diskgroup where the image copy is being created by the auxiliary database.



 

Wednesday, March 25, 2015

Backup cron jobs

If you have corn jobs in your server, below script helpful to take backup cronjobs details.



#!/bin/ksh
#
#   Keep a backup on crontab entries for 90 days
#
#- ENV VARIABLES -#

. ~oracle/.env
DATE=`date +%y%m%d`
CRONTAB_DIR=/u01/app/oracle/prod/
MACHINE=`hostname`
export DATE MACHINE

# Keep last 30  days of crontab entries
find $CRONTAB_DIR -name "crontab.*.txt" -mtime +30 -exec rm {} \;

crontab -l > $CRONTAB_DIR/crontab.$DATE.txt

if [[ $? -gt 0 ]];then
mail -s 'Error creating backup crontab on '$MACHINE'' $DBAEMAIL << EOF
Problems creating backup crontab. Check $CRONTAB_DIR for backup crontabs.
EOF
exit
fi

exit 0

Friday, January 23, 2015

RMAN DUPLICATE: Errors In Krbm_getDupCopy found in alert.log

Issue.

Executing active duplicate for standby:
duplicate target database for standby from active database ...

In the alert.log appear messages like this:
RMAN DUPLICATE: Errors in krbm_getDupCopy
Errors in file /u02/app/oracle/diag/rdbms/odocdr/odOCDR/trace/odOCDR_ora_27666.trc:
ORA-19625: error identifying file +DATA/orcl/datafile/users_ts.895.787168577
ORA-17503: ksfdopn:2 Failed to open file +DATA/orcl/datafile/users_ts.895.787168577
ORA-15012: ASM file '+DATA/orcl/datafile/users_ts.895.7871685777' does not exist
 
Solution:
 
As files have already been deleted from auxiliary destination, ignore those messages.

When the files already copied can be used by next duplicate trial then don't remove the files. If you don't delete the files after a failed duplicate then krbm_getDupCopy will find the files and you will see no errors.

If you don't want to see those messages in alert.log but datafiles have already been deleted, on
Auxiliary host, delete the file $ORACLE_HOME/dbs/_rm_dup_<dup_db>.dat  where dup_db is the name of the clone instance.

Inside this file rman finds the name of the datafiles already copied to auxiliary host.