Skip Headers

PL/SQL User's Guide and Reference
Release 2 (9.2)

Part Number A96624-01
Go To Documentation Library
Home
Go To Product List
Book List
Go To Table Of Contents
Contents
Go To Index
Index

Master Index

Feedback

Go to previous page Go to beginning of chapter Go to next page

PL/SQL Language Elements, 37 of 52


Procedures

A procedure is a subprogram that can take parameters and be invoked. Generally, you use a procedure to perform an action. A procedure has two parts: the specification and the body. The specification (spec for short) begins with the keyword PROCEDURE and ends with the procedure name or a parameter list. Parameter declarations are optional. Procedures that take no parameters are written without parentheses. The procedure body begins with the keyword IS (or AS) and ends with the keyword END followed by an optional procedure name.

The procedure body has three parts: an optional declarative part, an executable part, and an optional exception-handling part. The declarative part contains declarations of types, cursors, constants, variables, exceptions, and subprograms. These items are local and cease to exist when you exit the procedure. The executable part contains statements that assign values, control execution, and manipulate Oracle data. The exception-handling part contains handlers that deal with exceptions raised during execution. For more information, see "Understanding PL/SQL Procedures".

Syntax

Text description of procedure_specification.gif follows
Text description of the illustration procedure_specification.gif


Text description of procedure_body.gif follows
Text description of the illustration procedure_body.gif


Keyword and Parameter Description

AUTHID

This clause determines whether a stored procedure executes with the privileges of its owner (the default) or current user and whether its unqualified references to schema objects are resolved in the schema of the owner or current user. You can override the default behavior by specifying CURRENT_USER. For more information, see "Invoker Rights Versus Definer Rights".

CREATE

The optional CREATE clause lets you create standalone procedures, which are stored in the Oracle database. You can execute the CREATE statement interactively from SQL*Plus or from a program using native dynamic SQL.

datatype

This is a type specifier. For the syntax of datatype, see "Constants and Variables".

exception_handler

This associates an exception with a sequence of statements, which is executed when that exception is raised. For the syntax of exception_handler, see "Exceptions".

expression

This is an arbitrarily complex combination of variables, constants, literals, operators, and function calls. The simplest expression consists of a single variable. When the declaration is elaborated, the value of expression is assigned to the parameter. The value and the parameter must have compatible datatypes.

function_declaration

This declares a function. For the syntax of function_declaration, see "Functions".

IN, OUT, IN OUT

These parameter modes define the behavior of formal parameters. An IN parameter lets you pass values to the subprogram being called. An OUT parameter lets you return values to the caller of the subprogram. An IN OUT parameter lets you pass initial values to the subprogram being called and return updated values to the caller.

item_declaration

This declares a program object. For the syntax of item_declaration, see "Blocks".

NOCOPY

This is a compiler hint (not directive), which allows the PL/SQL compiler to pass OUT and IN OUT parameters by reference instead of by value (the default). For more information, see "Passing Large Data Structures with the NOCOPY Compiler Hint".

parameter_name

This identifies a formal parameter, which is a variable declared in a procedure spec and referenced in the procedure body.

PRAGMA AUTONOMOUS_TRANSACTION

This pragma instructs the PL/SQL compiler to mark a function as autonomous (independent). An autonomous transaction is an independent transaction started by another transaction, the main transaction. Autonomous transactions let you suspend the main transaction, do SQL operations, commit or roll back those operations, then resume the main transaction. For more information, see "Doing Independent Units of Work with Autonomous Transactions".

procedure_name

This identifies a user-defined procedure.

type_definition

This specifies a user-defined datatype. For the syntax of type_definition, see "Blocks".

:= | DEFAULT

This operator or keyword lets you initialize IN parameters to default values.

Usage Notes

A procedure is called as a PL/SQL statement. For example, the procedure raise_salary might be called as follows:

raise_salary(emp_num, amount);

Inside a procedure, an IN parameter acts like a constant. So, you cannot assign it a value. An OUT parameter acts like a local variable. So, you can change its value and reference the value in any way. An IN OUT parameter acts like an initialized variable. So, you can assign it a value, which can be assigned to another variable. For summary information about the parameter modes, see Table 8-1.

Unlike OUT and IN OUT parameters, IN parameters can be initialized to default values. For more information, see "Using Default Values for Subprogram Parameters".

Before exiting a procedure, explicitly assign values to all OUT formal parameters. An OUT actual parameter can have a value before the subprogram is called. However, when you call the subprogram, the value is lost unless you specify the compiler hint NOCOPY or the subprogram exits with an unhandled exception.

You can write the procedure spec and body as a unit. Or, you can separate the procedure spec from its body. That way, you can hide implementation details by placing the procedure in a package. You can define procedures in a package body without declaring their specs in the package spec. However, such procedures can be called only from inside the package.

At least one statement must appear in the executable part of a procedure. The NULL statement meets this requirement.

Examples

The following procedure debits a bank account:

PROCEDURE debit_account (acct_id INTEGER, amount REAL) IS
   old_balance REAL;
   new_balance REAL;
   overdrawn   EXCEPTION;
BEGIN
   SELECT bal INTO old_balance FROM accts WHERE acctno = acct_id;
   new_balance := old_balance - amount;
   IF new_balance < 0 THEN
      RAISE overdrawn;
   ELSE
      UPDATE accts SET bal = new_balance WHERE acctno = acct_id;
   END IF;
EXCEPTION
   WHEN overdrawn THEN
      ...
END debit_account;

In the following example, you call the procedure using named notation:

debit_account(amount => 500, acct_id => 10261);

Related Topics

Collection Methods, Functions, Packages


Go to previous page Go to beginning of chapter Go to next page
Oracle
Copyright © 1996, 2002 Oracle Corporation.

All Rights Reserved.
Go To Documentation Library
Home
Go To Product List
Book List
Go To Table Of Contents
Contents
Go To Index
Index

Master Index

Feedback