CREATE PACKAGE
Description
Creates a package.
Precautions
- In the current version, PACKAGE can be used only in an ORA-compatible database.
- The functions or stored procedures declared in the package specification must be defined in the package body.
- When a stored procedure is created, a write lock is added only to the CREATE stored procedure or package, and a read lock is added only to the functions and packages on which the functions depend during compilation and execution.
- During instantiation, the stored procedure with COMMIT or ROLLBACK cannot be called.
- Package functions cannot be called in triggers.
- Variables in a package cannot be directly used in external SQL statements.
- Private variables and stored procedures in a package cannot be called outside the package.
- Usage that stored procedures do not support are not supported. For example, if COMMIT or ROLLBACK cannot be called in a function, COMMIT or ROLLBACK cannot be called in the function of a package.
- The name of a schema cannot be the same as that of a package.
- Only ORA-version stored procedures and function definitions are supported.
- Variables with the same name in a package, including parameters with the same name in a package, are not supported.
- The global variables in a package are at the session level. The variables in packages cannot be shared in different sessions.
- When a function of an autonomous transaction is called in a package, the cursor variables in the package and recursive functions that use the cursor variables in the package are not allowed.
- The package does not declare the ref cursor variables.
- The default permission on a package is SECURITY INVOKER. To change the default permission to SECURITY DEFINER, set the GUC parameter behavior_compat_options to 'plsql_security_definer'.
- A user with the CREATE ANY PACKAGE permission can create packages in the public and user schemas.
- If the name of a package to be created contains special characters, the special characters cannot contain spaces. You are advised to set the GUC parameter behavior_compat_options to "skip_insert_gs_source". Otherwise, an error may occur.
- When you create a package function, the default parameter value can contain variables in the package but cannot contain cross-package variables.
- When the complex function is called in a package, for example, func(x).a, a composite type is returned. Cross-schema call is supported, but the database.schema.package.func(x).b call is not supported.
- When a stored procedure in a package is created, if the stored procedure name is in the schema.func or package.func format, only the value of func is obtained, and the declaration of schema or package is invalid. To disable this behavior by default, set the GUC parameter behavior_compat_options to 'forbid_package_function_with_prefix'.
- view %rowtype cannot be used as a function parameter.
- Composite records cannot be used in INSERT VALUES in stored procedures or functions.
-
In distributed mode, SAVE EXCEPTIONS (used in called stored procedures) is not supported.
- Expressions do not support COMMIT/ROLLBACK.
-
Parentheses cannot be omitted for functions without parameters.
- When a stored procedure in a package is created, if the input parameters of the stored procedure contain pseudo-type parameters (for example, anyelement), variable-length parameters cannot be specified during a call.
- Cursors created in a package or cursors in functions with parameters can be referenced (%RowType) and opened across packages. The restrictions are as follows:
- Currently, cursors cannot be called in database.schema.package.cursor mode.
- In distributed mode, cursors cannot be defined as function parameters.
- cursor %RowType is not supported when a cursor is referenced.
- If the PRAGMA AUTONOMOUS_TRANSACTION syntax is declared in PACKAGE SPECIFICATION or PACKAGE BODY SPECIFICATION, a package can be created, but the autonomous transaction does not take effect.
- Only the initial user can perform the REPLACE operation on the packages of the initial user.
Syntax
- CREATE PACKAGE SPECIFICATION
CREATE [ OR REPLACE ] PACKAGE [ schema ] package_name [ invoker_rights_clause ] { IS | AS } item_list_1 END [ package_name ];
- invoker_rights_clause can be declared as AUTHID DEFINER or AUTHID CURRENT_USER, which indicate the definer permission and caller permission, respectively.
- item_list_1 can be a declared variable, stored procedure, or function.
- The package_name after END can be omitted. (In the SQL file generated by gs_dump, the name after END is automatically added to the package definition.)
PACKAGE SPECIFICATION (header) declares public variables, functions, and exceptions in a package, which can be called by external functions or stored procedures. It can only declare stored procedures and functions but cannot define them.
- CREATE PACKAGE BODY
CREATE [ OR REPLACE ] PACKAGE BODY [ schema ] package_name { IS | AS } declare_section [ initialize_section ] END [ package_name ];
The package_name after END can be omitted. (In the SQL file generated by gs_dump, the name after END is automatically added to the package definition.)
PACKAGE BODY defines private variables and functions in a package. If a variable or function is not declared by the package specification, it is a private variable or private function.
The package body also has an initialization part to initialize the package. For details, see the example.
Examples
- CREATE PACKAGE
-- Create a database. gaussdb=# CREATE DATABASE test DBCOMPATIBILITY 'ORA'; gaussdb=# \c test -- Create a test table tbl_test. test=# CREATE TABLE tbl_test(uid varchar(6) PRIMARY KEY, area_id varchar(5), level int); -- Create a package header. test=# CREATE OR REPLACE PACKAGE pkg_test AS -- Public stored procedures can be called by external systems. PROCEDURE proc_ist_tbl_test(v_uid in varchar, v_area_id varchar, v_level int); PROCEDURE proc_del_tbl_test(v_uid in varchar); PROCEDURE proc_upd_tbl_test(v_uid in varchar, v_area_id varchar, v_level int); END pkg_test; / -- Create a package body. test=# CREATE OR REPLACE PACKAGE BODY pkg_test AS PROCEDURE proc_ist_tbl_test(v_uid in varchar, v_area_id varchar, v_level int) AS BEGIN INSERT INTO tbl_test VALUES (v_uid, v_area_id, v_level); END; PROCEDURE proc_del_tbl_test(v_uid in varchar) AS BEGIN DELETE FROM tbl_test WHERE uid = v_uid; END; PROCEDURE proc_upd_tbl_test(v_uid in varchar, v_area_id varchar, v_level int) AS BEGIN UPDATE tbl_test SET area_id = v_area_id, level = v_level WHERE uid = v_uid; END; var4 int := 10; -- The instantiation starts. BEGIN var4 := 10; dbe_output.print_line(var4); END pkg_test; /
- Calling a package
-- Use CALL to call the stored procedure of a package. test=# CALL pkg_test.proc_ist_tbl_test('0A00B1','01001',24); test=# SELECT * FROM tbl_test; uid | area_id | level --------+---------+--------- 0A00B1 | 01001 | 24 (1 row) -- Use SELECT to call the stored procedure of a package. test=# SELECT pkg_test.proc_upd_tbl_test('0A00B1','01001','26'); test=# SELECT * FROM tbl_test; uid | area_id | level --------+---------+------- 0A00B1 | 01001 | 26 (1 row) -- Call a stored procedure of a package in an anonymous block. test=# BEGIN pkg_test.proc_del_tbl_test('0A00B1'); END; / test=# SELECT * FROM tbl_test; uid | area_id | level -----+---------+------- (0 rows) -- Drop. test=# DROP TABLE tbl_test; test=# DROP PACKAGE pkg_test; -- Switch to the default database and delete the test database. Change the database name as required. test=# \c postgres gaussdb=# DROP DATABASE test;
Helpful Links
Feedback
Was this page helpful?
Provide feedbackThank you very much for your feedback. We will continue working to improve the documentation.See the reply and handling status in My Cloud VOC.
For any further questions, feel free to contact us through the chatbot.
Chatbot