Category Archives: Diagnostic and Tuning

This category contains scripts meant to help diagnose or troubleshoot performance problems related to the Oracle Database.

Find missing or stale statistics

Purpose

Statistics are primordial for the optimizer to choose the best execution plan possible. Sometimes you encounter a sub-optimal plan and need to find out if the tables involved in the statement are up to date. This query will help you find out which tables have been modified significantly since the last statistics gathering. For this query to work you will need the MONITORING to be activated on your tables, this is automatically the case since 11g.

Continue reading Find missing or stale statistics

Analyze database activity using v$log_history

The v$log_history view contains important information on how application’s users use the database , this view can help you define periods with the most activity in the database.

v$log_history queries

You can adapt the query to your needs, you just have to change the way you format the date to be able to drilldown to the precision you want.

select round(avg(LOG_SWITCHES)) LOG_SWITCHES, DAY 
from (
		select to_char(trunc(first_time), 'Day') DAY, TRUNC(FIRST_TIME, 'DDD'), count(*) LOG_SWITCHES
		from v$log_history 
		group by TRUNC(FIRST_TIME, 'DDD'), to_char(trunc(first_time), 'Day')
		order by 2
	 )
group by day;

This one gives the following output :

LOG_SWITCHES DAY
------------ ---------
207 Sunday
212 Monday
218 Friday
192 Thursday
207 Wednesday
216 Tuesday
209 Saturday

You can find out which day of the week is the most active. You can also have a day to day analysis for the last month :

select round(avg(LOG_SWITCHES)) LOG_SWITCHES, DAY 
from (
		select TRUNC(FIRST_TIME, 'DDD') DAY, count(*) LOG_SWITCHES
		from v$log_history 
		where first_time between sysdate -30 and sysdate
		group by TRUNC(FIRST_TIME, 'DDD'), to_char(trunc(first_time), 'Day')
		order by 1
	 )
group by day
order by 2;

here is the output :

LOG_SWITCHES DAY
------------ ---------
91 10-AUG-15
225 11-AUG-15
233 12-AUG-15
224 13-AUG-15
221 14-AUG-15
218 15-AUG-15
217 16-AUG-15
225 17-AUG-15
218 18-AUG-15
215 19-AUG-15
212 20-AUG-15
203 21-AUG-15
198 22-AUG-15
198 23-AUG-15
200 24-AUG-15
201 25-AUG-15
202 26-AUG-15
202 27-AUG-15
190 28-AUG-15
150 29-AUG-15
151 30-AUG-15
153 31-AUG-15
182 01-SEP-15
202 02-SEP-15
201 03-SEP-15
203 04-SEP-15
203 05-SEP-15
199 06-SEP-15
202 07-SEP-15
205 08-SEP-15
124 09-SEP-15

 

You can also drilldown to hours in the day :

select Hour , round(avg(LOG_SWITCHES)) LOG_SWITCHES
from (
		select to_char(trunc(first_time, 'HH'),'HH24') Hour, TRUNC(FIRST_TIME, 'DDD'), count(*) LOG_SWITCHES
		from v$log_history 
		group by TRUNC(FIRST_TIME, 'DDD'), trunc(first_time, 'HH')
		order by 1
	 )
group by Hour
order by Hour;

Here the output :

HO LOG_SWITCHES
-- ------------
00 8
01 9
02 8
03 8
04 25
05 7
06 8
07 8
08 8
09 8
10 8
11 8
12 8
13 8
14 8
15 8
16 8
17 8
18 8
19 7
20 8
21 7
22 8
23 15

Be creative 🙂

Top 5 wait events from v$active_session_history

This query returns the top 5 wait events for the last hour from the v$active_session_history view.

Be careful, this view is part of the diagnostic pack, you should not query this view if you not licensed for it.

Top 5 wait events from v$active_session_history

select * from (
	select
		 WAIT_CLASS ,
		 EVENT,
		 count(sample_time) as EST_SECS_IN_WAIT
	from v$active_session_history
	where sample_time between sysdate - interval '1' hour and sysdate
	group by WAIT_CLASS,EVENT
	order by count(sample_time) desc
	)
where rownum <6

This is obviously an approximation, because v$active_session_history contains only 1 second samples, and who knows what happens during each second sample. If you compare the time given by this query with information from v$system_event it will not exactly match but you should be close if you choose a sufficiently long period.