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 


 

 

 


 

 

 
 

Gathering SQL execution details

Oracle Tips by Burleson Consulting
Match 5, 2008

 

In addition to TKPROF (SQL*Trace) and the SQL*Plus "set autotrace on" command, we see new tools for getting additional SQL execution information.

Staring with Oracle, we see several exciting new execution plan columns and you can ruin specialized queries to see estimates of resource usage associated with specific steps of Oracle SQL execution: 

  • CPU_COST - The CPU cost of the operation as estimated by the optimizer's cost-based approach. For statements that use the rule-based approach, this column is null. The value of this column is proportional to the number of machine cycles required for the operation. 

  • IO_COST - The I/O cost of the operation as estimated by the optimizer's cost-based approach. For statements that use the rule-based approach, this column is null. The value of this column is proportional to the number of data blocks read by the operation  

  • TEMP_SPACE - The temporary space, in bytes, used by the operation as estimated by the optimizer's cost-based approach. For statements that use the rule-based approach, or for operations that don't use any temporary space, this column is null.

In Oracle 10g, also see gather_plan_statistics hint tips where you can gather estimated rows vs. actual rows.  Oracle claims to use this information to make more intelligent choices of execution plans, but there is a serious problem with this approach. 

1: The CBO has no a-priori knowledge of the data buffer contents:  Because of this shortcoming, the CBO cannot know if the data blocks are already in the RAM data buffers.

2:  CPU costs depend upon system load: The CPU costs associated with servicing an Oracle query depend upon the server load, and CPU costs are generally not important unless the entire Oracle instance is using excessive CPU resources.

 3: Temporary segment space is transient:  Even though the CBO estimates the TEMP_SPACE costs at optimization time, this execution plan will become permanent for the SQL query until the executable is flushed from the library cache.  Hence, obsolete execution plans may be used to execute a query.

Oracle also has two new views to show active work area space, the v$sql_workarea and the v$sql_workarea_active views.  The v$sql_workarea_active view will display all of the work areas that are currently executing in the instance.  Note that small sorts (under 65,535 bytes) are excluded from the view. The v$sql_workarea_active view can be used to quickly monitor the size of all large active work areas.

workarea.sql 

select
   to_number(decode(SID, 65535, NULL, SID)) sid,
   operation_type              OPERATION,
   trunc(WORK_AREA_SIZE/1024)  WSIZE,
   trunc(EXPECTED_SIZE/1024)   ESIZE,
   trunc(ACTUAL_MEM_USED/1024) MEM,
   trunc(MAX_MEM_USED/1024)    "MAX MEM",
   number_passes               PASS
from
   v$sql_workarea_active
order by
   1,2;

Here is a sample listing from this script, showing the work area estimated vs. actual size, plus the memory used for the specific operation.  This is a great way to see the actual RAM used in a sort or hash join operation.

SID OPERATION             WSIZE     ESIZE       MEM   MAX MEM PASS
--- --------------------- ----- --------- --------- --------- ----
 27 GROUP BY (SORT)          73        73        64        64    0
 44 HASH-JOIN              3148      3147      2437      6342    1
 71 HASH-JOIN             13241     19200     12884     34684    1

For more details on gathering run-time SQL execution statistics see my book "Oracle Tuning: The Definitive Reference".

This output shows that session 44 is running a hash join whose work area is running in one-pass mode. This work area is currently using 2 megabytes of PGA memory and in the past, has used up to 6.5 megabytes.

This view is very useful for assessing the current memory operations within Oracle. You can use the SID column to join into the v$process and v$session views for additional information about each task.

This script is good for finding the top ten work areas currently allocated in the PGA RAM:

select
   c.sql_text,
   w.operation_type,
   top_ten.wasize
from
   (Select *
    from
      (Select workarea_address, actual_mem_used wasize
       from v$sql_workarea_active
order by actual_mem_used)
where
   ROWNUM <=10) top_ten,
   v$sql_workarea w,
   v$sql c
where
   w.workarea_address=top_ten.workarea_address
and
   c.address=w.address
and
   c.child_number = w.child_number
and
   c.hash_value=w.hash_value;


This script is good for finding the percentage of RAM that is over and under allocated:

select
   total_used,
   under*100/(total_used+1) percent_under_use,
   over*100/(total_used+1) percent_over_used
from
   (Select
    sum(case when expected_size > actual_mem_used
      then actual_mem_used else 0 end) under,
    sum(case when expected_size<> actual_mem_used
       then actual_mem_used else 0 end) over,
    sum(actual_mem_used) total_used
from
   v$sql_workarea_active
where policy='AUTO') usage;

For full scripts, download the Oracle script collection.


 
Get the Complete
Oracle SQL Tuning Information 

The landmark book "Advanced Oracle SQL Tuning  The Definitive Reference"  is filled with valuable information on Oracle SQL Tuning. This book includes scripts and tools to hypercharge Oracle 11g performance and you can buy it for 30% off directly from the publisher.

 

 

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