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 


 

 

 


 

 

 
 

Efficient Function Calls


Oracle Tips by Burleson Consulting

 

The following Tip is from the outstanding book "Oracle PL/SQL Tuning: Expert Secrets for High Performance Programming" by Dr. Tim Hall, Oracle ACE of the year, 2006:

When calling functions as part of select statements the function may be called for every row returned by the query.  To improve efficiency it makes sense to filter the data first so that the function is only called for the required rows.  The efficient_functions_setup.sql script creates and populates a test table to demonstrate this issue.

efficient_functions_setup.sql

CREATE TABLE efficient_functions AS
SELECT data_length
FROM   all_tab_columns;

INSERT /*+ APPEND */ INTO efficient_functions
SELECT data_length
FROM   all_tab_columns;
COMMIT;

INSERT /*+ APPEND */ INTO efficient_functions
SELECT data_length
FROM   all_tab_columns;
COMMIT;

CREATE INDEX efficient_functions_idx ON efficient_functions (data_length);

EXEC DBMS_STATS.gather_table_stats(USER, 'efficient_functions', cascade => TRUE);

The efficient_functions.sql script uses this table to compare two queries, one that performs a function on all rows and one that that filters the rows before applying the function.

efficient_functions.sql

SET SERVEROUTPUT ON
DECLARE
  l_start   NUMBER;
BEGIN
  -- Time inefficient query.
  l_start := DBMS_UTILITY.get_time; 

  FOR i IN (SELECT SQRT(data_length), COUNT(*) AS amount
            FROM   efficient_functions
            GROUP BY SQRT(data_length))
  LOOP
    NULL;
  END LOOP; 

  DBMS_OUTPUT.put_line('Inefficient : ' ||
                       (DBMS_UTILITY.get_time - l_start));

  -- Time efficient query.
  l_start := DBMS_UTILITY.get_time; 

  FOR i IN (SELECT SQRT(data_length), amount
            FROM   (SELECT data_length, COUNT(*) AS amount
                    FROM efficient_functions
                    GROUP BY data_length))
  LOOP
    NULL;
  END LOOP; 

  DBMS_OUTPUT.put_line('Efficient   : ' ||
                       (DBMS_UTILITY.get_time - l_start));
END; /

The output from the script clearly shows the performance improvement associated with filtering the data prior to the function call.

SQL> @efficient_functions.sql

Inefficient : 31
Efficient   : 12

PL/SQL procedure successfully completed.

An alternative approach it to use function-based indexes where functions are performed on columns in the where clause of a query, as demonstrated by the efficient_functions_fb_index.sql script.

efficient_functions_fb_index.sql

ALTER SESSION SET QUERY_REWRITE_INTEGRITY = TRUSTED;
ALTER SESSION SET QUERY_REWRITE_ENABLED = TRUE;

SET SERVEROUTPUT ON
DECLARE
  l_number  NUMBER;
  l_start   NUMBER;
BEGIN
  -- Time no function based index.
  l_start := DBMS_UTILITY.get_time; 

  SELECT COUNT(*)
  INTO   l_number
  FROM   efficient_functions ef
  WHERE  SQRT(ef.data_length) = 5.47722558; 

  DBMS_OUTPUT.put_line('No function based index: ' ||
                       (DBMS_UTILITY.get_time - l_start));

  -- Create function based index.

  EXECUTE IMMEDIATE 'CREATE INDEX efficient_functions_fbidx ON efficient_functions
(SQRT(data_length))';
  DBMS_STATS.gather_table_stats(USER, 'efficient_functions', cascade => TRUE);

  -- Time function based index.

  l_start := DBMS_UTILITY.get_time; 

  SELECT COUNT(*)
  INTO   l_number
  FROM   efficient_functions ef
  WHERE  SQRT(ef.data_length) = 5.47722558; 

  DBMS_OUTPUT.put_line('Function based index   : ' ||
                       (DBMS_UTILITY.get_time - l_start));

  EXECUTE IMMEDIATE 'DROP INDEX efficient_functions_fbidx';
END; /

The script enables query rewrites and displays the speed of a query before and after building a function based index.  The results of the script are displayed below.

SQL> @efficient_functions_fb_index.sql

Session altered.

Session altered.

No function based index: 22
Function based index   : 1

PL/SQL procedure successfully completed.

This proves that function based indexes do indeed improve performance, but they may impact performance in other areas as the cost of maintaining them is higher than regular indexes.  In addition, they may increase disk space requirements as some columns may require both regular and function-based indexes.

The next section will look at the performance gains associated with passing parameter values by reference using the NOCOPY hint.

 

This is an excerpt from the bestselling book "Oracle PL/SQL Tuning: Expert Secrets for High Performance Programming" by Dr. Tim Hall, Oracle ACE of the year, 2006.

You can buy the book for only $23.95 (30%-off) when you buy directly from the publisher, and you also get instant access to the code depot of PL/SQL 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 -  2017

All rights reserved by Burleson

Oracle ® is the registered trademark of Oracle Corporation.

Remote Emergency Support provided by Conversational