Find the most I/O-intensive SQL statements

This tip helps you in identifying expensive SQL statements running on your Oracle system.

This tip helps you in identifying "expensive" SQL statements running on your Oracle system and identifies the reasons for them being so poorly performing. It might indicate poor coding or inappropriate usage of indexes in these statements, which can then be tuned. As always, execute this script on your development system before trying it on your production system. It has been tested on Oracle 8, 8i and 9i. It is to be executed under...

SQL*PLUS with user INTERNAL.

-- Top 30 I/O Intensive SQL Statements Identification : top30iosql.sql
set linesize 80
set pagesize 58
set heading on
set serveroutput on

spool top30iosql.txt

declare
cursor curs1 is
select executions, disk_reads, buffer_gets, first_load_time, sql_text
from v$sqlarea order by disk_reads / decode(executions,0,1,executions) desc;
stmnt_ctr number(3);
wrt1 number(3);

begin
dbms_output.enable(50000);
stmnt_ctr := 0;

for inrec in curs1 loop
stmnt_ctr := stmnt_ctr + 1;
if stmnt_ctr >= 31 then
exit;
end if;

dbms_output.put_line('--------------------------------------' ||
'--------------------------------------');
dbms_output.put_line('SQL Stmnt Number: ' || to_char(stmnt_ctr));
dbms_output.put_line('--------------------------------------' ||
'--------------------------------------');
dbms_output.put_line('Executions : ' ||
to_char(inrec.executions));
dbms_output.put_line('Disk Reads : ' || to_char(inrec.disk_reads) ||
' Buffer Gets : ' || to_char(inrec.buffer_gets));
dbms_output.put_line('First Load Time: ' || inrec.first_load_time);
dbms_output.put_line('SQL Statement-------->');
wrt1 := 1;
while wrt1 <= ceil(length(inrec.sql_text) / 72) loop
dbms_output.put_line('.....' ||
substr(inrec.sql_text,((wrt1-1)*72)+1,72));
wrt1 := wrt1 + 1;
end loop;
dbms_output.put_line('--------------------------------------' ||
'--------------------------------------');
dbms_output.put_line(' ');
end loop;
end;
/
spool off
set serveroutput off
set termout on
Now Edit/view The output file top30iosql.txt in suitable viewer of your O/s and finetune... Best of Luck!

For More Information

  • Feedback: E-mail the editor with your thoughts about this tip.
  • More tips: Hundreds of free Oracle tips and scripts.
  • Tip contest: Have an Oracle tip to offer your fellow DBAs and developers? The best tips submitted will receive a cool prize -- submit your tip today!
  • Ask the Experts: Our applications, SQL, database administration, and data warehousing gurus are waiting to answer your toughest questions.
  • Forums: Ask your technical Oracle questions--or help out your peers by answering them--in our active forums.
  • Best Web Links: Oracle tips, tutorials, and scripts from around the Web.

This was first published in October 2003

Dig deeper on Oracle and SQL

Pro+

Features

Enjoy the benefits of Pro+ membership, learn more and join.

0 comments

Oldest 

Forgot Password?

No problem! Submit your e-mail address below. We'll send you an email containing your password.

Your password has been sent to:

-ADS BY GOOGLE

SearchDataManagement

SearchBusinessAnalytics

SearchSAP

SearchSQLServer

TheServerSide

SearchDataCenter

SearchContentManagement

SearchFinancialApplications

Close