Oracle8i Concepts
Release 2 (8.1.6)

Part Number A76965-01

Library

Product

Contents

Index

Go to previous page Go to next page

17
Procedures and Packages

This chapter discusses the procedural capabilities of Oracle. It includes:

Introduction to Stored Procedures and Packages

Oracle allows you to access and manipulate database information using procedural schema objects called PL/SQL program units. Procedures, functions, and packages are all examples of PL/SQL program units.

PL/SQL is Oracle's procedural language extension to SQL. It extends SQL with flow control and other statements that make it possible to write complex programs. The PL/SQL engine is the tool you use to define, compile, and execute PL/SQL program units. This engine is a special component of many Oracle products, including the Oracle server.

While many Oracle products have PL/SQL components, this chapter specifically covers the procedures and packages that can be stored in an Oracle database and processed using the Oracle server PL/SQL engine. The PL/SQL capabilities of each Oracle tool are described in the appropriate tool's documentation.

See Also:

"PL/SQL" 

Stored Procedures and Functions

Procedures and functions are schema objects that logically group a set of SQL and other PL/SQL programming language statements together to perform a specific task. Procedures and functions are created in a user's schema and stored in a database for continued use. You can execute a procedure or function interactively by:

Figure 17-1 illustrates a simple procedure that is stored in the database and called by several different database applications.

Procedures and functions are identical except that functions always return a single value to the caller, while procedures do not. For simplicity, procedure as used in the remainder of this chapter means procedure or function.

Figure 17-1 A Stored Procedure


The stored procedure in Figure 17-1, which inserts an employee record into the EMP table, is shown in Figure 17-2.

Figure 17-2 The HIRE_EMP Procedure


All of the database applications in Figure 17-1 call the HIRE_EMP procedure. Alternatively, a privileged user might use Oracle Enterprise Manager or SQL*Plus to execute the HIRE_EMP procedure using the following statement:

EXECUTE hire_emp ('TSMITH', 'CLERK', 1037, SYSDATE, \ 
                      500, NULL, 20); 

This statement places a new employee record for TSMITH in the EMP table.

See Also:

PL/SQL User's Guide and Reference 

Packages

A package is a group of related procedures and functions, together with the cursors and variables they use, stored together in the database for continued use as a unit. Similar to standalone procedures and functions, packaged procedures and functions can be called explicitly by applications or users.

Figure 17-3 illustrates a package that encapsulates a number of procedures used to manage an employee database.

Figure 17-3 A Stored Package


Database applications explicitly call packaged procedures as necessary. After being granted the privileges for the EMP_MGMT package, a user can explicitly execute any of the procedures contained in it. For example, Oracle Enterprise Manager or SQL*Plus might issue the following statement to execute the HIRE_EMP package procedure:

EXECUTE emp_mgmt.hire_emp ('TSMITH', 'CLERK', 1037, SYSDATE, 500, NULL, 20); 

Packages offer several development and performance advantages over standalone stored procedures.

See Also:

"Packages" 

Procedures and Functions

A procedure or function is a schema object that consists of a set of SQL statements and other PL/SQL constructs, grouped together, stored in the database, and executed as a unit to solve a specific problem or perform a set of related tasks. Procedures and functions permit the caller to provide parameters that can be input only, output only, or input and output values.

Procedures and functions allow you to combine the ease and flexibility of SQL with the procedural functionality of a structured programming language. For example, the following statement creates the CREDIT_ACCOUNT procedure, which credits money to a bank account:

CREATE PROCEDURE credit_account 
      (acct NUMBER, credit NUMBER) AS 
/* This procedure accepts two arguments: an account number and an 
   amount of money to credit to the specified account. If the 
   specified account does not exist, a new account is created. */ 

        old_balance  NUMBER; 
        new_balance  NUMBER; 
   BEGIN 
        SELECT balance INTO old_balance FROM accounts 
          WHERE acct_id = acct 
          FOR UPDATE OF balance; 

        new_balance := old_balance + credit; 
        UPDATE accounts SET balance = new_balance 
          WHERE acct_id = acct; 
        COMMIT; 

        EXCEPTION 
          WHEN NO_DATA_FOUND THEN 
            INSERT INTO accounts (acct_id, balance) 
                VALUES(acct, credit); 
          WHEN OTHERS THEN 
        ROLLBACK; 
END credit_account; 

Notice that this sample procedure includes both SQL and PL/SQL statements.

See Also:

PL/SQL User's Guide and Reference 

Definer Rights and Invoker Rights

A PL/SQL procedure can be executed with the privileges of its owner (definer rights) or with the privileges of the current user (invoker rights), depending on the procedure definition.

The Current User

The current user starts out as the session user, who is either the logged-in user or the user associated with the remote procedure call session. On entering or exiting an invoker-rights procedure or an anonymous block, the current user does not change.

On entering a definer-rights procedure, the owner of that procedure becomes the current user. On exiting a definer-rights procedure, the current user reverts to the previous current user, that is, the current user before entry to the definer-rights procedure.

Resolution of External References

An external reference in a PL/SQL procedure is a name that refers to an object outside the program unit:

Name resolution in the invoker's schema allows applications to access user-specific tables by not specifying the schema.

See Also:

"Name Resolution for Database Objects and Program Units" 

Benefits of Procedures

Procedures provide advantages in the following areas:

Security with Definer-Rights Procedures

Stored procedures can help enforce data security. You can restrict the database operations that users can perform by allowing them to access data only through procedures and functions that execute with the definer's privileges. For example, you can grant users access to a procedure that updates a table, but not grant them access to the table itself. When a user invokes the procedure, the procedure executes with the privileges of the procedure's owner. Users who have only the privilege to execute the procedure (but not the privileges to query, update, or delete from the underlying tables) can invoke the procedure, but they cannot manipulate table data in any other way.

See Also:

"Dependency Tracking for Stored Procedures" 

Inherited Privileges and Schema Context with Invoker-Rights Procedures

An invoker-rights procedure inherits privileges and schema context from the procedure that calls it. In other words, an invoker-rights procedure is not tied to a particular user or schema, and each invocation of an invoker-rights procedure operates in the current user's schema with the current user's privileges. If you are an application developer, invoker-rights procedures make it easy for you to centralize application logic, even when the underlying data is divided among user schemas.

For example, a a user who executes an update procedure on the EMP table as a manager can update salary, whereas a user who executes the same procedure as a clerk can be restricted to updating address data.

Performance

Stored procedures can improve database performance in several ways:

Memory Allocation

Because stored procedures take advantage of the shared memory capabilities of Oracle, only a single copy of the procedure needs to be loaded into memory for execution by multiple users. Sharing the same code among many users results in a substantial reduction in Oracle memory requirements for applications.

Productivity

Stored procedures increase development productivity. By designing applications around a common set of procedures, you can avoid redundant coding and increase your productivity.

For example, procedures can be written to insert, update, or delete employee records from the EMP table. These procedures can then be called by any application without rewriting the SQL statements necessary to accomplish these tasks. If the methods of data management change, only the procedures need to be modified, not all of the applications that use the procedures.

Integrity

Stored procedures improve the integrity and consistency of your applications. By developing all of your applications around a common group of procedures, you can reduce the likelihood of committing coding errors.

For example, you can test a procedure or function to guarantee that it returns an accurate result and, once it is verified, reuse it in any number of applications without testing it again. If the data structures referenced by the procedure are altered in any way, only the procedure needs to be recompiled; applications that call the procedure do not necessarily require any modifications.

Procedure Guidelines

Use the following guidelines when designing stored procedures:

Anonymous PL/SQL Blocks versus Stored Procedures

A stored procedure is created and stored in the database as a schema object. Once created and compiled, it is a named object that can be executed without recompiling. Additionally, dependency information is stored in the data dictionary to guarantee the validity of each stored procedure.

As an alternative to a stored procedure, you can create an anonymous PL/SQL block by sending an unnamed PL/SQL block to the Oracle server from an Oracle tool or an application. Oracle compiles the PL/SQL block and places the compiled version in the shared pool of the SGA, but does not store the source code or compiled version in the database for reuse beyond the current instance. Shared SQL allows anonymous PL/SQL blocks in the shared pool to be reused and shared until they are flushed out of the shared pool.

In either case, moving PL/SQL blocks out of a database application and into database procedures stored either in the database or in memory, you avoid unnecessary procedure recompilations by Oracle at runtime, improving the overall performance of the application and Oracle.

See Also:

"How Oracle Stores Procedures and Packages" 

Standalone Procedures

Stored procedures not defined within the context of a package are called standalone procedures. Procedures defined within a package are considered a part of the package.

See Also:

"Packages" for information on the advantages of packages 

Dependency Tracking for Stored Procedures

A stored procedure depends on the objects referenced in its body. Oracle automatically tracks and manages such dependencies. For example, if you alter the definition of a table referenced by a procedure, the procedure must be recompiled to validate that it will continue to work as designed. Usually, Oracle automatically administers such dependency management.

See Also:

Chapter 20, "Oracle Dependency Management" for more information about dependency tracking 

External Procedures

A PL/SQL procedure executing on an Oracle server can call an external procedure or function that is written in the C programming language and stored in a shared library. The C routine executes in a separate address space from that of the Oracle server.

See Also:

Oracle8i Application Developer's Guide - Fundamentals for more information about external procedures and Inter-Language Method Services 

Packages

Packages encapsulate related procedures, functions, and associated cursors and variables together as a unit in the database.

You create a package in two parts: the specification and the body. A package's specification declares all public constructs of the package and the body defines all constructs (public and private) of the package. This separation of the two parts provides the following advantages:

The following example creates the specification and body for a package that contains several procedures and functions that process banking transactions.

CREATE PACKAGE bank_transactions (null) AS 
  minimum_balance  CONSTANT NUMBER := 100.00; 
  PROCEDURE apply_transactions; 
  PROCEDURE enter_transaction (acct   NUMBER, 
                               kind   CHAR, 
                               amount NUMBER); 
END bank_transactions; 

CREATE PACKAGE BODY bank_transactions AS 

/*  Package to input bank transactions */ 

   new_status  CHAR(20);  /* Global variable to record status 
                             of transaction being applied. Used 
                             for update in APPLY_TRANSACTIONS. */ 

   PROCEDURE do_journal_entry (acct NUMBER, 
                               kind CHAR) IS 

/*  Records a journal entry for each bank transaction applied 
    by the APPLY_TRANSACTIONS procedure. */ 

  BEGIN 
        INSERT INTO journal 
          VALUES (acct, kind, sysdate); 
        IF kind = 'D' THEN 
          new_status := 'Debit applied'; 
        ELSIF kind = 'C' THEN 
          new_status := 'Credit applied'; 
        ELSE 
          new_status := 'New account'; 
        END IF; 
  END do_journal_entry; 

  PROCEDURE credit_account (acct NUMBER, credit NUMBER) IS 

/* Credits a bank account the specified amount. If the account 
   does not exist, the procedure creates a new account first. */ 

        old_balance  NUMBER; 
        new_balance  NUMBER; 

  BEGIN 
        SELECT balance INTO old_balance FROM accounts 
          WHERE acct_id = acct 
          FOR UPDATE OF balance; /* Locks account for credit update */ 

        new_balance := old_balance + credit; 
        UPDATE accounts SET balance = new_balance 
          WHERE acct_id = acct; 
        do_journal_entry(acct, 'C'); 

  EXCEPTION 
        WHEN NO_DATA_FOUND THEN  /* Create new account if not found */ 
          INSERT INTO accounts (acct_id, balance) 
            VALUES(acct, credit); 
          do_journal_entry(acct, 'N'); 
        WHEN OTHERS THEN  /* Return other errors to application */ 
          new_status := 'Error: ' || SQLERRM(SQLCODE); 
  END credit_account; 

  PROCEDURE debit_account (acct  NUMBER, debit NUMBER) IS 

/* Debits an existing account if result is greater than the 
   allowed minimum balance. */ 

        old_balance         NUMBER; 
        new_balance         NUMBER; 
        insufficient_funds  EXCEPTION; 

  BEGIN 
        SELECT balance INTO old_balance FROM accounts 
          WHERE acct_id = acct 
          FOR UPDATE OF balance; 
        new_balance := old_balance - debit; 
        IF new_balance >= minimum_balance THEN 
          UPDATE accounts SET balance = new_balance 

            WHERE acct_id = acct; 
        do_journal_entry(acct, 'D'); 
        ELSE 
          RAISE insufficient_funds; 
        END IF; 

  EXCEPTION 
        WHEN NO_DATA_FOUND THEN 
          new_status := 'Nonexistent account'; 
        WHEN insufficient_funds THEN 
          new_status := 'Insufficient funds';  
        WHEN OTHERS THEN  /* Returns other errors to application */  
          new_status := 'Error: ' || SQLERRM(SQLCODE);  
  END debit_account; 

  PROCEDURE apply_transactions IS 

/* Applies pending transactions in the table TRANSACTIONS to the 
   ACCOUNTS table. Used at regular intervals to update bank 
   accounts without interfering with input of new transactions. */ 

/* Cursor fetches and locks all rows from the TRANSACTIONS 
   table with a status of 'Pending'. Locks released after all
         pending transactions have been applied. */ 

        CURSOR trans_cursor IS 
          SELECT acct_id, kind, amount FROM transactions 
            WHERE status = 'Pending' 
            ORDER BY time_tag 
            FOR UPDATE OF status; 

   BEGIN 
        FOR trans IN trans_cursor LOOP   /* implicit open and fetch */ 
          IF trans.kind = 'D' THEN 
            debit_account(trans.acct_id, trans.amount); 
          ELSIF trans.kind = 'C' THEN 
            credit_account(trans.acct_id, trans.amount); 
          ELSE 
            new_status := 'Rejected'; 
          END IF; 
          /* Update TRANSACTIONS table to return result of applying 
             this transaction. */ 
          UPDATE transactions SET status = new_status 
            WHERE CURRENT OF trans_cursor; 
        END LOOP; 
        COMMIT;  /* Release row locks in TRANSACTIONS table. */ 
  END apply_transactions; 
  PROCEDURE enter_transaction (acct   NUMBER, 
                               kind   CHAR, 
                               amount NUMBER) IS 

/* Enters a bank transaction into the TRANSACTIONS table. A new 
   transaction is always put into this 'queue' before being 
   applied to the specified account by the APPLY_TRANSACTIONS 
   procedure. Therefore, many transactions can be simultaneously 
   input without interference. */ 
 
  BEGIN 
        INSERT INTO transactions 
          VALUES (acct, kind, amount, 'Pending', sysdate); 
        COMMIT; 
  END enter_transaction; 

END bank_transactions; 

Packages allow the database administrator or application developer to organize similar routines. They also offer increased functionality and database performance.

See ALso:

Chapter 20, "Oracle Dependency Management" 

Benefits of Packages

Packages are used to define related procedures, variables, and cursors and are often implemented to provide advantages in the following areas:

Encapsulation

Stored packages allow you to encapsulate or group stored procedures, variables, datatypes, and so forth in a single named, stored unit in the database. This strategy provides better organization during the development process.

Encapsulation of procedural constructs in a package also makes privilege management easier. Granting the privilege to use a package makes all constructs of the package accessible to the grantee.

Public and Private Data and Procedures

The methods of package definition allow you to specify which variables, cursors, and procedures are

public 

Directly accessible to the user of a package.  

private 

Hidden from the user of a package.  

For example, a package might contain ten procedures. You can define the package so that only three procedures are public and therefore available for execution by a user of the package; the remainder of the procedures are private and can only be accessed by the procedures within the package.

Do not confuse public and private package variables with grants to PUBLIC.

See Also:

Chapter 26, "Controlling Database Access" for more information about grants to PUBLIC 

Performance Improvement

An entire package is loaded into memory when a procedure within the package is called for the first time. This load is completed in one operation, as opposed to the separate loads required for standalone procedures. Therefore, when calls to related packaged procedures occur, no disk I/O is necessary to execute the compiled code already in memory.

A package body can be replaced and recompiled without affecting the specification. As a result, schema objects that reference a package's constructs (always via the specification) need not be recompiled unless the package specification is also replaced. By using packages, unnecessary recompilations can be minimized, resulting in less impact on overall database performance.

Dependency Tracking for Packages

A package depends on the objects referenced by the procedures and functions defined in its body. Oracle automatically tracks and manages such dependencies.

See Also:

Chapter 20, "Oracle Dependency Management" 

Oracle Supplied Packages

Oracle supplies many PL/SQL packages that contain procedures for extending the functionality of the database or PL/SQL. Most of these packages have names that start with the DBMS_ prefix, such as DBMS_SQL, DBMS_LOCK, and DBMS_JOB. Some supplied packages have the UTL_ prefix, such as UTL_HTTP and UTL_FILE, or other prefixes including DEBUG_ and OUTLN_.

See Also:

Oracle8i Supplied PL/SQL Packages Reference for detailed documentation of the Oracle supplied packages 

How Oracle Stores Procedures and Packages

When you create a procedure or package, Oracle:

Compiling Procedures and Packages

The PL/SQL compiler compiles the source code. The PL/SQL compiler is part of the PL/SQL engine contained in Oracle. If an error occurs during compilation, a message is returned. You can anticipate errors by using an error handler within the program, thus preventing Oracle from terminating the procedure.

See Also:

Oracle8i Application Developer's Guide - Fundamentals for information about identifying compilation errors 

Storing the Compiled Code in Memory

Oracle caches the compiled procedure or package in the shared pool of the system global area (SGA). This allows the code to be executed quickly and shared among many users. The compiled version of the procedure or package remains in the shared pool according to the modified least-recently-used algorithm used by the shared pool, even if the original caller of the procedure terminates his or her session.

See Also:

"The Shared Pool" for specific information about the shared pool buffer 

Storing Procedures or Packages in Database

At creation and compile time, Oracle automatically stores the following information about stored procedures or packages in the database:

schema object name 

This name identifies the procedure or package. You specify this name in the CREATE PROCEDURE, CREATE FUNCTION, CREATE PACKAGE, or CREATE PACKAGE BODY statement.  

source code and parse tree 

The PL/SQL compiler parses the source code and produces a parsed representation of the source code, called a parse tree.  

pseudocode (P code) 

The PL/SQL compiler generates the pseudocode, or P code, based on the parsed code. The PL/SQL engine executes this when the procedure or package is invoked.  

error messages 

Oracle might generate errors during the compilation of a procedure or package.  

To avoid unnecessary recompilation of a procedure or package, both the parse tree and the P code of an object are stored in the database. This allows the PL/SQL engine to read the compiled version of a procedure or package into the shared pool buffer of the SGA when it is invoked and not currently in the SGA. The parse tree is used when the code calling the procedure is compiled.

All parts of database procedures are stored in the data dictionary (which is in the SYSTEM tablespace) of the corresponding database. When planning the size of the SYSTEM tablespace, the database administrator should keep in mind that all stored procedures require space in this tablespace.

How Oracle Executes Procedures and Packages

When you invoke a standalone or packaged procedure, Oracle performs the following tasks:

The verification and execution differ for definer-rights procedures and invoker-rights procedures.

See Also:

"Dependency Tracking for Stored Procedures" 

Verifying User Access

Oracle verifies that the calling user owns or has the EXECUTE privilege on the procedure or encapsulating package. The user who executes a procedure does not require access to any procedures or objects referenced within the procedure; only the creator of a procedure or package requires privileges to access referenced schema objects.

Verifying Procedure Validity

Oracle checks the data dictionary to determine whether the status of the procedure or package is valid or invalid. A procedure or package is invalid when one of the following has occurred since the procedure or package was last compiled:

A procedure is valid if it has not been invalidated by any of the above operations. If a valid standalone or packaged procedure is called, then the compiled code is executed. If an invalid standalone or packaged procedure is called, then it is automatically recompiled before being executed.

See Also:

Chapter 20, "Oracle Dependency Management" for a complete discussion of valid and invalid procedures and packages, recompiling procedures, and a thorough discussion of dependency issues 

Executing a Procedure

The PL/SQL engine executes the procedure or package using different steps, depending on the situation:

The PL/SQL engine processes a procedure statement by statement, handling all procedural statements by itself and passing SQL statements to the SQL statement executor, as illustrated in Figure 15-2.

Name Resolution for Database Objects and Program Units

For a definer-rights procedure, all external references are resolved in the definer's schema. For an invoker-rights procedure, the resolution of external references depends on the kind of statement they appear in.

Name Resolution for Database Links

Database link names in PL/SQL procedures are resolved following the rules in the previous section. The authorization ID used to connect to the remote database is one of the following:

  1. For fixed user links, Oracle uses the username specified in the link to connect to the remote database. This behavior is the same in definer-rights procedures and invoker-rights procedures.

    CREATE DATABASE LINK link1 
        CONNECT TO scott IDENTIFIED BY tiger 
        USING connect_string; 
    
    

    If a procedure owned by JOE uses LINK1, no matter who invokes the procedure, the connection is as SCOTT because that is the name specified in the link.

  2. For connected user links, Oracle uses the session username to connect to the remote database. This behavior is the same in definer-rights procedures and invoker-rights procedures.

    CREATE DATABASE LINK link2 
        USING connect_string; 
    
    

    If a procedure owned by JOE uses a connected user link LINK2, and a user SCOTT invokes the procedure, the connection to the remote database is as SCOTT.

  3. For current user links, the behavior differs for definer-rights procedures and invoker-rights procedures:

    • For an invoker-rights procedure, Oracle uses the invoker's authorization ID to connect as a remote user.

      CREATE DATABASE LINK link3 
          CONNECT TO CURRENT_USER 
          USING connect_string; 
      
      

      If a global user SCOTT invokes the invoker-rights procedure owned by JOE, then LINK3 connects to the remote database as user SCOTT because SCOTT is the current user.

    • For a definer-rights procedure, Oracle uses the owner's authorization ID to connect as a remote user. If the definer-rights procedure is owned by JOE, LINK3 connects to the remote database as global user JOE who then becomes the current user.


Go to previous page Go to next page
Oracle
Copyright © 1996-2000, Oracle Corporation.

All Rights Reserved.

Library

Product

Contents

Index