Skip Headers

Oracle9i SQL Reference
Release 2 (9.2)

Part Number A96540-02
Go to Documentation Home
Home
Go to Book List
Book List
Go to Table of Contents
Contents
Go to Index
Index
Go to Master Index
Master Index
Go to Feedback page
Feedback

Go to previous page Go to next page
View PDF

CREATE PACKAGE

Purpose

Use the CREATE PACKAGE statement to create the specification for a stored package, which is an encapsulated collection of related procedures, functions, and other program objects stored together in the database. The specification declares these objects.

See Also:

Prerequisites

Before a package can be created, the user SYS must run a SQL script commonly called DBMSSTDX.SQL. The exact name and location of this script depend on your operating system.

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

To embed a CREATE PACKAGE 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

Syntax

create_package::=

Text description of statements_65.gif follows
Text description of create_package


invoker_rights_clause::=

Text description of statements_68.gif follows
Text description of invoker_rights_clause


Semantics

OR REPLACE

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

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

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

See Also:

ALTER PACKAGE for information on recompiling package specifications

schema

Specify the schema to contain the package. If you omit schema, Oracle creates the package in your own schema.

package

Specify the name of the package to be created.

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

invoker_rights_clause

The invoker_rights_clause lets you specify whether the functions and procedures in the package execute 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 specification applies to the corresponding package body as well.

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

AUTHID CURRENT_USER

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

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 package resides.

AUTHID DEFINER

Specify DEFINER to indicate that the package executes with the privileges of the owner of the schema in which the package resides and that external names resolve in the schema where the package resides. This is the default and creates a definer-rights package.

See Also:

pl/sql_package_spec

Specify the package specification, which can contain type definitions, cursor declarations, variable declarations, constant declarations, exception declarations, PL/SQL subprogram specifications, and call specifications (declarations of a C or Java routine expressed in PL/SQL).

See Also:

Example

Creating a Package: Example

The following SQL statement creates the specification of the emp_mgmt package (PL/SQL is show in italics):

CREATE OR REPLACE PACKAGE emp_mgmt AS 
 FUNCTION hire (last_name VARCHAR2, job_id VARCHAR2, 
    manager_id NUMBER, salary NUMBER, 
    commission_pct NUMBER, department_id NUMBER) 
    RETURN NUMBER; 
 FUNCTION create_dept(department_id NUMBER, location_id NUMBER) 
    RETURN NUMBER; 
 PROCEDURE remove_emp(employee_id NUMBER); 
 PROCEDURE remove_dept(department_id NUMBER); 
 PROCEDURE increase_sal(employee_id NUMBER, salary_incr NUMBER); 
 PROCEDURE increase_comm(employee_id NUMBER, comm_incr NUMBER); 
 no_comm EXCEPTION; 
 no_sal EXCEPTION; 
END emp_mgmt; 
/ 

The specification for the emp_mgmt package declares the following public program objects:

All of these objects are available to users who have access to the package. After creating the package, you can develop applications that call any of the package's public procedures or functions or raise any of the package's public exceptions.

Before you can call this package's procedures and functions, you must define these procedures and functions in the package body. For an example of a CREATE PACKAGE BODY statement that creates the body of the emp_mgmt package, see CREATE PACKAGE BODY.