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 


 

 

 


 

 

 
 

Procedures, Functions and Packages


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:

Procedures and functions allow code to be named and stored in the database, making code reuse simpler and more efficient.  Procedures and functions still retain the block format. But the DECLARE keyword is replaced by PROCEDURE or FUNCTION definitions, which are similar except for the additional return type definition for a function. 

The following procedure displays numbers between upper and lower bounds defined by two parameters. It then shows the output when it is run.

CREATE OR REPLACE PROCEDURE display_numbers (
  p_lower  IN   NUMBER,
  p_upper  IN   NUMBER)
AS
BEGIN
  FOR i IN p_lower .. p_upper LOOP
    DBMS_OUTPUT.put_line(i);
  END LOOP;
END;

SET SERVEROUTPUT ON
EXECUTE display_numbers(2, 6);
2
3
4
5
6

PL/SQL procedure successfully completed.

The following function returns the difference between upper and lower bounds defined by two parameters.

CREATE OR REPLACE FUNCTION difference (
  p_lower  IN   NUMBER,
  p_upper  IN   NUMBER)
  RETURN NUMBER
AS
BEGIN
  RETURN p_upper - p_lower;
END;

VARIABLE l_result NUMBER
BEGIN
  :l_result := difference(2, 6);
END;
/
 
PL/SQL procedure successfully completed.

PRINT l_result

  L_RESULT
----------
         4

Packages allow related code, along with supporting types, variables and cursors, to be grouped together.  The package is made up of a specification that defines the external interface of the package, and a body that contains all the implementation code.  The following code shows how the previous procedure and function could be grouped into a package.

CREATE OR REPLACE PACKAGE my_package AS
 
PROCEDURE display_numbers (
  p_lower  IN   NUMBER,
  p_upper  IN   NUMBER); 

FUNCTION difference (
  p_lower  IN   NUMBER,
  p_upper  IN   NUMBER)
  RETURN NUMBER; 

END;

CREATE OR REPLACE PACKAGE BODY my_package AS 

PROCEDURE display_numbers (
  p_lower  IN   NUMBER,
  p_upper  IN   NUMBER)
AS
BEGIN
  FOR i IN p_lower .. p_upper LOOP
    DBMS_OUTPUT.put_line(i);
  END LOOP;
END;

FUNCTION difference (
  p_lower  IN   NUMBER,
  p_upper  IN   NUMBER)
  RETURN NUMBER
AS
BEGIN
  RETURN p_upper - p_lower;
END;

END;
/

Once the package specification and body are compiled, they can be executed as before, provided the procedure and function names are prefixed with the package name.

SET SERVEROUTPUT ON
EXECUTE my_package.display_numbers(2, 6);
2
3
4
5

PL/SQL procedure successfully completed.

VARIABLE l_result NUMBER
BEGIN
  :l_result := my_package.difference(2, 6);
END;

PL/SQL procedure successfully completed.

PRINT l_result 

  L_RESULT
----------
         4

Since the package specification defines the interface to the package, the implementation within the package body can be modified without invalidating any dependent code, thus breaking complex dependency chains.  A call to any element in the package causes the whole package to be loaded into memory, improving performance compared to loading several individual procedures and functions.

Records in PL/SQL

Record types are composite data structures or groups of data elements, each with its own definition.  Records can be used to mimic the row structures of tables and cursors, or as a convenient way to pass data between subprograms without listing large number of parameters.

When a record type must match a particular table or cursor structure, it can be defined using the %ROWTYPE attribute. This removes the need to define each column within the record manually.  However, the record can be specified manually.  The following code provides an example of how records can be declared and used in PL/SQL.

SET SERVEROUTPUT ON
DECLARE
  -- Define a record type manually.
  TYPE t_all_users_record IS RECORD (
    username  VARCHAR2(30),
    user_id   NUMBER,
    created   DATE
  ); 

  -- Declare record variables using the manual and %ROWTYPE methods.
  l_all_users_record_1  t_all_users_record;
  l_all_users_record_2  all_users%ROWTYPE;
BEGIN
  -- Return some data into once record structure.
  SELECT *
  INTO   l_all_users_record_1
  FROM   all_users
  WHERE  username = 'SYS'; 

  -- Display the contents of the first record.
  DBMS_OUTPUT.put_line('l_all_users_record_1.username=' ||
                        l_all_users_record_1.username);
  DBMS_OUTPUT.put_line('l_all_users_record_1.user_id=' ||
                        l_all_users_record_1.user_id);
  DBMS_OUTPUT.put_line('l_all_users_record_1.created=' ||
                        l_all_users_record_1.created); 

  -- Assign the values to the second record structure in a single operation.
  l_all_users_record_2 := l_all_users_record_1;   

  -- Display the contents of the second record.
  DBMS_OUTPUT.put_line('l_all_users_record_2.username=' ||
                        l_all_users_record_2.username);
  DBMS_OUTPUT.put_line('l_all_users_record_2.user_id=' ||
                        l_all_users_record_2.user_id);
  DBMS_OUTPUT.put_line('l_all_users_record_2.created=' ||
                        l_all_users_record_2.created); 

  l_all_users_record_1 := NULL; 

  -- Display the contents of the first record after deletion.
  DBMS_OUTPUT.put_line('l_all_users_record_1.username=' ||
                        l_all_users_record_1.username);
  DBMS_OUTPUT.put_line('l_all_users_record_1.user_id=' ||
                        l_all_users_record_1.user_id);
  DBMS_OUTPUT.put_line('l_all_users_record_1.created=' ||
                        l_all_users_record_1.created);

END;
/

l_all_users_record_1.username=SYS
l_all_users_record_1.user_id=0
l_all_users_record_1.created=18-MAR-2004 08:02:17
l_all_users_record_2.username=SYS
l_all_users_record_2.user_id=0
l_all_users_record_2.created=18-MAR-2004 08:02:17
l_all_users_record_1.username=
l_all_users_record_1.user_id=
l_all_users_record_1.created=

PL/SQL procedure successfully completed.


Notice how the records can be assigned to each other directly, and how all elements within a record can be initialized with a single assignment of a NULL value.

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