Call now: 252-767-6166  
Oracle Training Oracle Support Development Oracle Apps

 
 Home
 E-mail Us
 Oracle Articles
New Oracle Articles


 Oracle Training
 Oracle Tips

 Oracle Forum
 Class Catalog


 Remote DBA
 Oracle Tuning
 Emergency 911
 RAC Support
 Apps Support
 Analysis
 Design
 Implementation
 Oracle Support


 SQL Tuning
 Security

 Oracle UNIX
 Oracle Linux
 Monitoring
 Remote s
upport
 Remote plans
 Remote
services
 Application Server

 Applications
 Oracle Forms
 Oracle Portal
 App Upgrades
 SQL Server
 Oracle Concepts
 Software Support

 Remote S
upport  
 Development  

 Implementation


 Consulting Staff
 Consulting Prices
 Help Wanted!

 


 Oracle Posters
 Oracle Books

 Oracle Scripts
 Ion
 Excel-DB  

Don Burleson Blog 


 

 

 


 

 

 
 

Oracle v$log_history scripts

Oracle Tips by Burleson Consulting

February 26, 2016

In a busy production environment, it is important to ensure that the frequency of redo log switches is not more than 5 per hour and the v$log_history view can help.

As Oracle offloads redo log images from the redo log filesystem onto the archived redo log filesystem, excessive I/O can occur and the archived redo log must be promptly written to tape to keep the free space in the filesystem. If the archived redo log filesystem becomes full, the database grinds to a halt.

Other scripts for measuring v$log_history can be found in our Oracle script collection of over 600 Oracle scripts.  I also have details and diagnostic scripts for Oracle log optimization in my book "Oracle Tuning: The Definitive Reference".
 

Inside log buffer switches

Not many DBA's are aware of the v$log_history view, and how it can be used to plot the frequency of online redo log switches.  The Oracle web site offers this query to show log switches by date.

col c1 format a10 heading "Month"
col c2 format a25 heading "Archive Date"
col c3 format 999 heading "Switches"

compute AVG of C on A
compute AVG of C on REPORT

break on A skip 1 on REPORT skip 1

select
   to_char(trunc(first_time), 'Month') c1,
   to_char(trunc(first_time), 'Day : DD-Mon-YYYY') c2,
   count(*) c3
from
   v$log_history
See code depot for full script
where
   trunc(first_time) > last_day(sysdate-100) +1
group by
   trunc(first_time);

 

Switching too frequently may sometimes cause performance problems.  The same is true for Oracle RAC databases except that each instance should have three to four redo log switches per hour. The following script can be used in Oracle RAC databases to determine the max number of log switches in any one hour.
 
--  max_hourly_log_switches.sql
 declare
     cursor c1 is
     select
        inst_id,
        count(*)
     from
        gv$log
     group by
        inst_id,
        to_char(first_time,'YYYY-MM-DD HH24')
     order by
        inst_id;
 
     v_inst number;
     v_curr number;
     v_cnt  number;
     v_max  number;
     v_name varchar2(16);
 
  begin
 
     open c1;
     v_curr:=0;
 
     loop
        fetch c1 into v_inst,v_cnt;
        exit when c1%notfound;
        if (v_curr<>v_inst) then
           if (v_curr<>0) then
              select
                 instance_name into v_name
              from
                 gv$instance
              where
                 inst_id=v_curr;
                   See code depot for full script
           dbms_output.put_line('Instance: '||v_name||
                       '   Max Hourly Switches: '||v_max);
           end if;
           v_max := -1;
           v_curr := v_inst;
        end if;
        if (v_max < v_cnt) then
           v_max := v_cnt;
        end if;
 
     end loop;
     select
        instance_name into v_name
     from
        gv$instance
     where
        inst_id=v_curr;
     dbms_output.put_line('Instance: '||v_name||
                 '   Max Hourly Switches: '||v_max);
 
  end;
/
 
Instance: orcl1   Max Hourly Switches: 5
Instance: orcl2   Max Hourly Switches: 8
Instance: orcl3   Max Hourly Switches: 3
 
PL/SQL procedure successfully completed.
 
The script above will work for any number of instances supporting the Oracle RAC database. Since each instance has its own thread of redo, we need to examine the maximum number of log switches per hour in each instance.

This v$log_history script shows a count and size of the redo log files by day:

-- Daily Count and Size of Redo Log Space (Single Instance)
--
SELECT A.*,
Round(A.Count#*B.AVG#/1024/1024) Daily_Avg_Mb
FROM
(
   SELECT
   To_Char(First_Time,'YYYY-MM-DD') DAY,
   Count(1) Count#,
   Min(RECID) Min#,
   Max(RECID) Max#
FROM
   v$log_history
GROUP BY
   To_Char(First_Time,'YYYY-MM-DD')
ORDER
BY 1 DESC
) A,
(
SELECT
Avg(BYTES) AVG#,
Count(1) Count#,
Max(BYTES) Max_Bytes,
Min(BYTES) Min_Bytes
FROM
v$log
) B
;


During the RESETLOGS operation, the information in v$log_history and v$offline_range records are no longer cleared. In addition, two new columns have been added to indicate the incarnation the records belong to: resetlogs_change# and resetlogs_time.

select
   recid,
   thread#,
   sequence#,
   resetlogs_change#,
   resetlogs_time
from
   v$log_history
where
   rownum < 20;

This script will show the exact times when you get a log switch. You enter the start date and end date in th script:

break on day skip 1  

select
    trunc(first_time) day,  
    substr(to_char(first_time, 'hh24:mi'), 1, 4) || '0' as time,  
    count(*) switches  
  from
   v$log_history  
 where 
   trunc(first_time) between 
       trunc(to_date('01.02.2016', 'dd.mm.yyyy')) 
   and 
       trunc(to_date('29.02.2016', 'dd.mm.yyyy'))  
 group by 
   trunc(first_time), 
   substr(to_char(first_time, 'hh24:mi'), 1, 4)  
having 
   count(*) > 1  
 order by 1, 2; 

 

The following script can be run to provide a complete log history with the v$log_history view:

set lines 120;
set pages 999;
SELECT
to_char(first_time,'YYYY-MON-DD') day,
to_char(sum(decode(to_char(first_time,'HH24'),'00',1,0)),'99') "00",
to_char(sum(decode(to_char(first_time,'HH24'),'01',1,0)),'99') "01",
to_char(sum(decode(to_char(first_time,'HH24'),'02',1,0)),'99') "02",
to_char(sum(decode(to_char(first_time,'HH24'),'03',1,0)),'99') "03",
to_char(sum(decode(to_char(first_time,'HH24'),'04',1,0)),'99') "04",
to_char(sum(decode(to_char(first_time,'HH24'),'05',1,0)),'99') "05",
to_char(sum(decode(to_char(first_time,'HH24'),'06',1,0)),'99') "06",
to_char(sum(decode(to_char(first_time,'HH24'),'07',1,0)),'99') "07",
to_char(sum(decode(to_char(first_time,'HH24'),'08',1,0)),'99') "0",
to_char(sum(decode(to_char(first_time,'HH24'),'09',1,0)),'99') "09",
to_char(sum(decode(to_char(first_time,'HH24'),'10',1,0)),'99') "10",
to_char(sum(decode(to_char(first_time,'HH24'),'11',1,0)),'99') "11",
to_char(sum(decode(to_char(first_time,'HH24'),'12',1,0)),'99') "12",
to_char(sum(decode(to_char(first_time,'HH24'),'13',1,0)),'99') "13",
to_char(sum(decode(to_char(first_time,'HH24'),'14',1,0)),'99') "14",
to_char(sum(decode(to_char(first_time,'HH24'),'15',1,0)),'99') "15",
to_char(sum(decode(to_char(first_time,'HH24'),'16',1,0)),'99') "16",
to_char(sum(decode(to_char(first_time,'HH24'),'17',1,0)),'99') "17",
to_char(sum(decode(to_char(first_time,'HH24'),'18',1,0)),'99') "18",
to_char(sum(decode(to_char(first_time,'HH24'),'19',1,0)),'99') "19",
to_char(sum(decode(to_char(first_time,'HH24'),'20',1,0)),'99') "20",
to_char(sum(decode(to_char(first_time,'HH24'),'21',1,0)),'99') "21",
to_char(sum(decode(to_char(first_time,'HH24'),'22',1,0)),'99') "22",
to_char(sum(decode(to_char(first_time,'HH24'),'23',1,0)),'99') "23"
from
   v$log_history
GROUP by
   to_char(first_time,'YYYY-MON-DD');


 

Using v$log_history prior to Oracle8i

Prior to Oracle8i the FIRST_TIME column was named TIME, and this query applies:

select substr(time,1,5) day,
to_char(sum(decode(substr(time,10,2),'00',1,0)),'99') "00",
to_char(sum(decode(substr(time,10,2),'01',1,0)),'99') "01",
to_char(sum(decode(substr(time,10,2),'02',1,0)),'99') "02",
to_char(sum(decode(substr(time,10,2),'03',1,0)),'99') "03",
to_char(sum(decode(substr(time,10,2),'04',1,0)),'99') "04",
to_char(sum(decode(substr(time,10,2),'05',1,0)),'99') "05",
to_char(sum(decode(substr(time,10,2),'06',1,0)),'99') "06",
to_char(sum(decode(substr(time,10,2),'07',1,0)),'99') "07",
to_char(sum(decode(substr(time,10,2),'08',1,0)),'99') "08",
to_char(sum(decode(substr(time,10,2),'09',1,0)),'99') "09",
to_char(sum(decode(substr(time,10,2),'10',1,0)),'99') "10",
to_char(sum(decode(substr(time,10,2),'11',1,0)),'99') "11",
to_char(sum(decode(substr(time,10,2),'12',1,0)),'99') "12",
to_char(sum(decode(substr(time,10,2),'13',1,0)),'99') "13",
to_char(sum(decode(substr(time,10,2),'14',1,0)),'99') "14",
to_char(sum(decode(substr(time,10,2),'15',1,0)),'99') "15",
to_char(sum(decode(substr(time,10,2),'16',1,0)),'99') "16",
to_char(sum(decode(substr(time,10,2),'17',1,0)),'99') "17",
to_char(sum(decode(substr(time,10,2),'18',1,0)),'99') "18",
to_char(sum(decode(substr(time,10,2),'19',1,0)),'99') "19",
to_char(sum(decode(substr(time,10,2),'20',1,0)),'99') "20",
to_char(sum(decode(substr(time,10,2),'21',1,0)),'99') "21",
to_char(sum(decode(substr(time,10,2),'22',1,0)),'99') "22",
to_char(sum(decode(substr(time,10,2),'23',1,0)),'99') "23"
from
   v$log_history
group by
   substr(time,1,5);

In sum, this v$log_history script is great for showing the relative update activity of your database and it's one of many tools used by the Oracle tuning professional. 

If you like Oracle tuning, see the book "Oracle Tuning: The Definitive Reference", with 950 pages of tuning tips and scripts. 

You can buy it direct from the publisher for 30%-off and get instant access to the code depot of Oracle tuning scripts.



 

 

��  
 
 
Oracle Training at Sea
 
 
 
 
oracle dba poster
 

 
Follow us on Twitter 
 
Oracle performance tuning software 
 
Oracle Linux poster
 
 
 

 

Burleson is the American Team

Note: This Oracle documentation was created as a support and Oracle training reference for use by our DBA performance tuning consulting professionals.  Feel free to ask questions on our Oracle forum.

Verify experience! Anyone considering using the services of an Oracle support expert should independently investigate their credentials and experience, and not rely on advertisements and self-proclaimed expertise. All legitimate Oracle experts publish their Oracle qualifications.

Errata?  Oracle technology is changing and we strive to update our BC Oracle support information.  If you find an error or have a suggestion for improving our content, we would appreciate your feedback.  Just  e-mail:  

and include the URL for the page.


                    









Burleson Consulting

The Oracle of Database Support

Oracle Performance Tuning

Remote DBA Services


 

Copyright © 1996 -  2020

All rights reserved by Burleson

Oracle ® is the registered trademark of Oracle Corporation.