Oracle® Database SQL Reference 10g Release 1 (10.1) Part Number B10759-01 |
|
|
View PDF |
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 package specification declares these objects. The package body, specified subsequently, defines these objects.
See Also:
|
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 Database precompiler program, you must terminate the statement with the keyword END-EXEC
followed by the embedded SQL statement terminator for the specific language.
Syntax
Semantics
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, then Oracle Database 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, then the database marks the indexes DISABLED
.
Specify the schema to contain the package. If you omit schema
, then the database creates the package in your own schema.
Specify the name of the package to be created.
If creating the package results in compilation errors, then the database returns an error. You can see the associated compiler error messages with the SQL*Plus command SHOW
ERRORS
.
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 the package 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 Database resolves external names in queries, DML operations, and dynamic SQL statements in the package.
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.
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:
|
Specify the package specification, which can contain type definitions, cursor declarations, variable declarations, constant declarations, exception declarations, PL/SQL subprogram specifications, and call specifications, which are declarations of a C or Java routine expressed in PL/SQL.
See Also:
|
Example
The following SQL statement creates the specification of the emp_mgmt
package. The PL/SQL is shown 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:
The functions hire
and create_dept
The procedures remove_emp
, remove_dept
, increase_sal
, and increase_comm
The exceptions no_comm
and no_sal
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 these public procedures or functions or raise any of the public exceptions of the package.
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 .