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 


 

 

 


 

 

 
 

Monitor Oracle I/O with PL/SQL and gv$sysstat

Oracle Database Tips by Donald BurlesonApril 29,  2015

Oracle's I/O guru Kevin Closson has this great article on how to capture I/O statistics using v$sysstat and gv$sysstat (for RAC I/O) monitoring:

"The method I used to produce that data is a simple PL/SQL loop that evaluates differences in gv$sysstat contents over time and produces its output into a file in the filesystem with appending writes."

Kevin supplies a handy PL/SQL script that does a 5 second sleep and counts the total I/O during the elapsed time period and write the data to a flat file:

Note that it uses these metrics from statistic# in gv$sysstat:

  • Physical disk I/O - select  sum(value) into bpio from gv$sysstat where statistic# = '43';
  • Physical Writes - select  sum(value) into bptwb from gv$sysstat where statistic# = '42';
  • Physical Reads - select  sum(value) into bptrb from gv$sysstat where statistic# = '39';

Here is the script for monitoring I/O in 5 second intervals.  This data would be vewry similar to the UNIX/Linux iostat utility, spaced over 5 second intervals:

set serveroutput on format wrapped size 1000000   
  
create or replace directory mytmp as '/tmp';   
  
DECLARE  
n number;   
m number;   
  
gb number := 1024 * 1024 * 1024;   
mb number := 1024 * 1024 ;   
  
bpio number; -- 43 physical IO disk bytes   
apio number;   
disp_pio number(8,0);   
  
bptrb number; -- 39 physical read total bytes   
aptrb number;   
disp_trb number(8,0);   
  
bptwb number; -- 42 physical write total bytes   
aptwb number;   
disp_twb number(8,0);   
  
x number := 1;   
y number := 0;   
fd1 UTL_FILE.FILE_TYPE;   
BEGIN  
        fd1 := UTL_FILE.FOPEN('MYTMP', 'mon.log', 'w');   
  
        LOOP   
                bpio := 0;   
                apio := 0;   
  
                select  sum(value) into bpio from gv$sysstat where statistic# = '43';   
                select  sum(value) into bptwb from gv$sysstat where statistic# = '42';   
                select  sum(value) into bptrb from gv$sysstat where statistic# = '39';   
  
                n := DBMS_UTILITY.GET_TIME;   
                DBMS_LOCK.SLEEP(5);   
  
                select  sum(value) into apio from gv$sysstat where statistic# = '43';   
                select  sum(value) into aptwb from gv$sysstat where statistic# = '42';   
                select  sum(value) into aptrb from gv$sysstat where statistic# = '39';   
  
                m := DBMS_UTILITY.GET_TIME - n ;   
  
                disp_pio := ( (apio - bpio)   / ( m / 100 )) / mb ;   
                disp_trb := ( (aptrb - bptrb) / ( m / 100 )) / mb ;   
                disp_twb := ( (aptwb - bptwb) / ( m / 100 )) / mb ;   
  
                UTL_FILE.PUT_LINE(fd1, TO_CHAR(SYSDATE,'HH24:MI:SS') || '|' || disp_pio || '|' || disp_trb || '|' || disp_twb || '|');   
                UTL_FILE.FFLUSH(fd1);   
                x := x + 1;   
        END LOOP;   
  
        UTL_FILE.FCLOSE(fd1);   
END;   
/  


 

 

��  
 
 
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.