Compute
Elastic Cloud Server
Huawei Cloud Flexus
Bare Metal Server
Auto Scaling
Image Management Service
Dedicated Host
FunctionGraph
Cloud Phone Host
Huawei Cloud EulerOS
Networking
Virtual Private Cloud
Elastic IP
Elastic Load Balance
NAT Gateway
Direct Connect
Virtual Private Network
VPC Endpoint
Cloud Connect
Enterprise Router
Enterprise Switch
Global Accelerator
Management & Governance
Cloud Eye
Identity and Access Management
Cloud Trace Service
Resource Formation Service
Tag Management Service
Log Tank Service
Config
OneAccess
Resource Access Manager
Simple Message Notification
Application Performance Management
Application Operations Management
Organizations
Optimization Advisor
IAM Identity Center
Cloud Operations Center
Resource Governance Center
Migration
Server Migration Service
Object Storage Migration Service
Cloud Data Migration
Migration Center
Cloud Ecosystem
KooGallery
Partner Center
User Support
My Account
Billing Center
Cost Center
Resource Center
Enterprise Management
Service Tickets
HUAWEI CLOUD (International) FAQs
ICP Filing
Support Plans
My Credentials
Customer Operation Capabilities
Partner Support Plans
Professional Services
Analytics
MapReduce Service
Data Lake Insight
CloudTable Service
Cloud Search Service
Data Lake Visualization
Data Ingestion Service
GaussDB(DWS)
DataArts Studio
Data Lake Factory
DataArts Lake Formation
IoT
IoT Device Access
Others
Product Pricing Details
System Permissions
Console Quick Start
Common FAQs
Instructions for Associating with a HUAWEI CLOUD Partner
Message Center
Security & Compliance
Security Technologies and Applications
Web Application Firewall
Host Security Service
Cloud Firewall
SecMaster
Anti-DDoS Service
Data Encryption Workshop
Database Security Service
Cloud Bastion Host
Data Security Center
Cloud Certificate Manager
Edge Security
Managed Threat Detection
Blockchain
Blockchain Service
Web3 Node Engine Service
Media Services
Media Processing Center
Video On Demand
Live
SparkRTC
MetaStudio
Storage
Object Storage Service
Elastic Volume Service
Cloud Backup and Recovery
Storage Disaster Recovery Service
Scalable File Service Turbo
Scalable File Service
Volume Backup Service
Cloud Server Backup Service
Data Express Service
Dedicated Distributed Storage Service
Containers
Cloud Container Engine
SoftWare Repository for Container
Application Service Mesh
Ubiquitous Cloud Native Service
Cloud Container Instance
Databases
Relational Database Service
Document Database Service
Data Admin Service
Data Replication Service
GeminiDB
GaussDB
Distributed Database Middleware
Database and Application Migration UGO
TaurusDB
Middleware
Distributed Cache Service
API Gateway
Distributed Message Service for Kafka
Distributed Message Service for RabbitMQ
Distributed Message Service for RocketMQ
Cloud Service Engine
Multi-Site High Availability Service
EventGrid
Dedicated Cloud
Dedicated Computing Cluster
Business Applications
Workspace
ROMA Connect
Message & SMS
Domain Name Service
Edge Data Center Management
Meeting
AI
Face Recognition Service
Graph Engine Service
Content Moderation
Image Recognition
Optical Character Recognition
ModelArts
ImageSearch
Conversational Bot Service
Speech Interaction Service
Huawei HiLens
Video Intelligent Analysis Service
Developer Tools
SDK Developer Guide
API Request Signing Guide
Terraform
Koo Command Line Interface
Content Delivery & Edge Computing
Content Delivery Network
Intelligent EdgeFabric
CloudPond
Intelligent EdgeCloud
Solutions
SAP Cloud
High Performance Computing
Developer Services
ServiceStage
CodeArts
CodeArts PerfTest
CodeArts Req
CodeArts Pipeline
CodeArts Build
CodeArts Deploy
CodeArts Artifact
CodeArts TestPlan
CodeArts Check
CodeArts Repo
Cloud Application Engine
MacroVerse aPaaS
KooMessage
KooPhone
KooDrive
On this page

CREATE PACKAGE

Updated on 2024-05-07 GMT+08:00

Description

Creates a package.

Precautions

  • The functions or stored procedures declared in the package specification must be defined in the package body.
  • During instantiation, the stored procedure with commit or rollback cannot be called.
  • 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.
  • 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 other 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 A-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 granted 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 a package is created, it depends on an undefined object. If behavior_compat_options is set to 'plpgsql_dependency', the creation can be executed and a warning message is displayed. If behavior_compat_options is not set to 'plpgsql_dependency', the creation cannot be executed.
  • If a view directly depends on an A-compatible function in a package and the behavior_compat_options parameter is set to 'plpgsql_dependency', the view can be accessed if the package is created again. However, if the behavior_compat_options parameter is not set to 'plpgsql_dependency', the view cannot be accessed.
  • When you create a package function, the default parameter value cannot contain variables.
  • The package specification in PG_OBJECT is set to 'S', and the package body in PG_OBJECT is set to 'B'. When a created package object becomes invalid, you can use the VALID column in PG_OBJECT to search for the OID of the invalid package object and run ALTER PACKAGE PKG_NAME COMPILE; to recompile the package to make it valid.
  • When creating a function in a package, if the function name is in the schema.func or package.func format, only the func name is obtained. The schema declaration or package declaration is invalid. To disable this behavior by default, set the GUC parameter behavior_compat_options to 'forbid_package_function_with_prefix'.

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.

    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 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 function.

    The package body also has an initialization part to initialize the package. For details, see the example.

Examples

  • Example of CREATE PACKAGE SPECIFICATION
    gaussdb=# CREATE OR REPLACE PACKAGE emp_bonus IS
    var1 int:=1;-- Public variable
    var2 int:=2;
    PROCEDURE testpro1(var3 int);-- Public stored procedure, which can be called by external systems.
    END emp_bonus;
    /
  • Example of CREATE PACKAGE BODY
    gaussdb=# drop table if exists test1;
    gaussdb=# create or replace package body emp_bonus is
    var3 int:=3;
    var4 int:=4;
    procedure testpro1(var3 int)
    is
    begin
    create table if not exists test1(col1 int);
    insert into test1 values(var1);
    insert into test1 values(var4);
    end;
    begin:  -- The instantiation starts.
    var4:=9;
    testpro1(var4);
    end emp_bonus;
    /
  • Example of ALTER PACKAGE OWNER
    -- Change the owner of PACKAGE emp_bonus to omm.
    gaussdb=# ALTER PACKAGE emp_bonus OWNER TO omm;
  • Example of calling a package
    -- Use CALL to call the package stored procedure.
    gaussdb=# call emp_bonus.testpro1(1); 
    
    -- Use SELECT to call the package stored procedure.
    gaussdb=# select emp_bonus.testpro1(1); 
    -- Call the stored procedure of a package in an anonymous block.
    gaussdb=# begin
    emp_bonus.testpro1(1);
    end;
    /

We use cookies to improve our site and your experience. By continuing to browse our site you accept our cookie policy. Find out more

Feedback

Feedback

Feedback

0/500

Selected Content

Submit selected content with the feedback