Oracle8i SQL Reference
Release 3 (8.1.7)

Part Number A85397-01

Library

Product

Contents

Index

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

SQL Statements:
CREATE CLUSTER to CREATE SEQUENCE, 20 of 25


CREATE PROCEDURE

Purpose

Use the CREATE PROCEDURE statement to create a standalone stored procedure or a call specification.

A procedure is a group of PL/SQL statements that you can call by name. A call specification ("call spec") declares a Java method or a third-generation language (3GL) routine so that it can be called from SQL and PL/SQL. The call spec tells Oracle which Java method to invoke when a call is made. It also tells Oracle what type conversions to make for the arguments and return value.

Stored procedures offer advantages in the areas of development, integrity, security, performance, and memory allocation.

See Also:

 

Prerequisites

Before creating a procedure, the user SYS must run the SQL script DBMSSTDX.SQL. The exact name and location of this script depends on your operating system.

To create a procedure in your own schema, you must have the CREATE PROCEDURE system privilege. To create a procedure in another user's schema, you must have CREATE ANY PROCEDURE system privilege. To replace a procedure in another schema, you must have the ALTER ANY PROCEDURE system privilege.

To invoke a call spec, you may need additional privileges (for example, EXECUTE privileges on the C library for a C call spec).

To embed a CREATE PROCEDURE statement inside an Oracle precompiler program, you must terminate the statement with the keyword END-EXEC followed by the embedded SQL statement terminator for the specific language.

See Also: PL/SQL User's Guide and Reference or Oracle8i Java Stored Procedures Developer's Guide for more information on such prerequisites 

Syntax


invoker_rights_clause::=


call_spec::=


Java_declaration::=


C_declaration::=


Keywords and Parameters

OR REPLACE

Specify OR REPLACE to re-create the procedure if it already exists. Use this clause to change the definition of an existing procedure without dropping, re-creating, and regranting object privileges previously granted on it. If you redefine a procedure, Oracle recompiles it.

Users who had previously been granted privileges on a redefined procedure can still access the procedure without being regranted the privileges.

If any function-based indexes depend on the package, Oracle marks the indexes DISABLED.

See Also: ALTER PROCEDURE for information on recompiling procedures 

schema

Specify the schema to contain the procedure. If you omit schema, Oracle creates the procedure in your current schema.

procedure

Specify the name of the procedure to be created.

If creating the procedure results in compilation errors, Oracle returns an error. You can see the associated compiler error messages with the SQL*Plus command SHOW ERRORS.

argument

argument 

Specify the name of an argument to the procedure. If the procedure does not accept arguments, you can omit the parentheses following the procedure name.  

IN 

Specify IN to indicate that you must specify a value for the argument when calling the procedure.  

OUT  

Specify OUT to indicate that the procedure passes a value for this argument back to its calling environment after execution.  

IN OUT 

Specify IN OUT to indicate that you must specify a value for the argument when calling the procedure and that the procedure passes a value back to its calling environment after execution.  

 

If you omit IN, OUT, and IN OUT, the argument defaults to IN.  

NOCOPY  

Specify NOCOPY to instruct Oracle to pass this argument as fast as possible. This clause can significantly enhance performance when passing a large value like a record, an index-by table, or a varray to an OUT or IN OUT parameter. (IN parameter values are always passed NOCOPY.) 

 

  • When you specify NOCOPY, assignments made to a package variable may show immediately in this parameter (or assignments made to this parameter may show immediately in a package variable) if the package variable is passed as the actual assignment corresponding to this parameter.

  • Similarly, changes made either to this parameter or to another parameter may be visible immediately through both names if the same variable is passed to both.

  • If the procedure is exited with an unhandled exception, any assignment made to this parameter may be visible in the caller's variable.

 

 

These effects may or may not occur on any particular call. You should use NOCOPY only when these effects would not matter. 

datatype 

Specify the datatype of the argument. An argument can have any datatype supported by PL/SQL. 

 

Datatypes cannot specify length, precision, or scale. For example, VARCHAR2(10) is not valid, but VARCHAR2 is valid. Oracle derives the length, precision, and scale of an argument from the environment from which the procedure is called.  

invoker_rights_clause

The invoker_rights_clause lets you specify whether the procedure executes with the privileges and in the schema of the user who owns it or with the privileges and in the schema of CURRENT_USER.

This clause also determines how Oracle resolves external names in queries, DML operations, and dynamic SQL statements in the procedure.

AUTHID CURRENT_USER 

Specify CURRENT_USER to indicate that the procedure executes with the privileges of CURRENT_USER. This clause creates an "invoker-rights procedure."

This clause also specifies that external names in queries, DML operations, and dynamic SQL statements resolve in the schema of CURRENT_USER. External names in all other statements resolve in the schema in which the procedure resides.  

AUTHID DEFINER 

Specify DEFINER to indicate that the procedure executes with the privileges of the owner of the schema in which the procedure resides, and that external names resolve in the schema where the procedure resides. This is the default. 

See Also:

 

IS | AS

pl/sql_subprogram_body 

In the PL/SQL subprogram body, declare the procedure in a PL/SQL subprogram body.

See Also: Oracle8i Application Developer's Guide - Fundamentals for more information on PL/SQL subprograms

 

call_spec 

Use the call_spec to map a Java or C method name, parameter types, and return type to their SQL counterparts.

In Java_declaration, 'string' identifies the Java implementation of the method.

See Also:

- Oracle8i Java Stored Procedures Developer's Guide

- Oracle8i Application Developer's Guide - Fundamentals for an explanation of the parameters and semantics of the C_declaration

 

 

AS EXTERNAL 

The AS EXTERNAL clause is an alternative way of declaring a C method. This clause has been deprecated and is supported for backward compatibility only. Oracle Corporation recommends that you use the AS LANGUAGE C syntax. 

Examples

CREATE PROCEDURE Example

The following statement creates the procedure credit in the schema sam:

CREATE PROCEDURE sam.credit (acc_no IN NUMBER, amount IN NUMBER) AS 
   BEGIN
      UPDATE accounts 
      SET balance = balance + amount 
      WHERE account_id = acc_no; 
   END;

The credit procedure credits a specified bank account with a specified amount. When you call the procedure, you must specify the following arguments:

ACC_NO 

is the number of the bank account to be credited. The argument's datatype is NUMBER.  

AMOUNT 

is the amount of the credit. The argument's datatype is NUMBER.  

The procedure uses an UPDATE statement to increase the value in the balance column of the accounts table by the value of the argument amount for the account identified by the argument acc_no.

In the following example, external procedure c_find_root expects a pointer as a parameter. Procedure find_root passes the parameter by reference using the BY REF phrase:

CREATE PROCEDURE find_root
   ( x IN REAL ) 
   IS LANGUAGE C
      NAME "c_find_root"
      LIBRARY c_utils
      PARAMETERS ( x BY REF );

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

All Rights Reserved.

Library

Product

Contents

Index