J.1. Working with Packages #

Postgres Pro provides packages, which are similar to packages in Oracle, and can be useful when porting from PL/SQL to PL/pgSQL. This section explains differences between Postgres Pro's and Oracle's packages.

In Oracle, a package is a schema object that groups logically related types, global variables, and subprograms (procedures and functions). A package consists of a package specification and a package body (in general, the package body is optional). In the package specification, those items are declared that can be referenced from outside the package and used in applications: types, variables, constants, exceptions, cursors, and subprograms. The package body contains package subprogram implementation, private variable declarations, and the initialization section. The variables, types and subprograms declared in the package body cannot be used from outside the package.

The example below shows the package specification of the PL/SQL counter package in Oracle, which contains the global variable n and the function inc:

CREATE PACKAGE counter IS
    n int;

    FUNCTION inc RETURN int;
END;

The function inc and the global variable k (available only in the package body) are declared in the counter package body in Oracle.

CREATE PACKAGE BODY counter IS
    k int := 3; -- the variable is available only in the package body

    FUNCTION inc RETURN int IS
    BEGIN
        n := n + 1;
        RETURN n;
    END;

-- Package initialization
BEGIN
    n := 1;
    FOR i IN 1..10 LOOP
        n := n + n;
    END LOOP;
END;

Global package variables exist during the session lifetime. Note that the package body contains the initialization section — the code block executed once a session when any package element is accessed for the first time. In Oracle, package elements could be accessed using dot notation as follows: package_name.package_element.

SET SERVEROUTPUT ON

BEGIN
    dbms_output.put_line(counter.n);
    dbms_output.put_line(counter.inc());
END;
/

1024
1025

A package in Postgres Pro is essentially a schema that contains the initialization function and may contain only functions, procedures and composite types. The initialization function is a PL/pgSQL function named __init__ that has no arguments and returns void. The initialization function must be defined before any other package function. By default, all the variables declared in the package initialization function, package functions and package procedures are public, so they can be called using dot notation from outside the package by other functions, procedures and anonymous blocks that import the package. The #private modifier defines functions and procedures as private, and the #export modifier defines which package variables are public. For example, the bar variable declared in the __init__ function of the foo package can be referenced as foo.bar.

Package variables can be accessed only from PL/pgSQL code. To retrieve the value of the global variable in an SQL query (SELECT) or in a DML operation (INSERT, UPDATE, DELETE), add a getter function that returns the value to the caller. For package variables declared as constant, default definition syntax in PL/pgSQL is used. The package initialization function is invoked automatically when any of the following elements is accessed in the current session:

  • Any function in this package with the #package modifier
  • Code block (anonymous or a function) importing this package

The initialization function can be invoked manually to reset values of package variables. To do that, you can also use a built-in function plpgsql_reset_packages() but it resets all the packages in the current session (similar to DBMS_SESSION.RESET_PACKAGES in Oracle).

The above example of the Oracle's counter package after porting to Postgres Pro will look like this:

CREATE PACKAGE counter

    CREATE FUNCTION __init__() RETURNS void AS $$ -- package initialization
    #export n
    DECLARE
        n int := 1; -- n public variable, available both inside and outside the package
        k int := 3; -- k private variable, only available inside the package
    BEGIN
        FOR i IN 1..10 LOOP
            n := n + n;
        END LOOP;
    END;
    $$

    CREATE FUNCTION inc() RETURNS int AS $$
    BEGIN
        n := n + 1;
        RETURN n;
    END;
    $$
;

You can use this package in Postgres Pro as follows:

DO $$
#import counter
BEGIN
    RAISE NOTICE '%', counter.n;
    RAISE NOTICE '%', counter.inc();
END;
$$;

NOTICE:  1024
NOTICE:  1025

There are some points worth noting.

  • Schemas cannot contain packages, as the package itself is a schema.

  • The package name must be distinct from the name of any existing package or schema in the current database.

  • A package may contain only composite types, global variables, procedures, and functions (for example, tables, views, sequences cannot be created in packages).

  • All package variables are public if the #export on modifier is used or if there is no #export modifier at all. All the package functions and procedures are public unless the #private modifier is used. Public package variables are available from any code block importing the package.

  • Package specification and package body are not defined separately.

  • Package functions and code blocks importing them must be written in PL/pgSQL.

  • All package elements must be accessed from outside the package using qualified names, i.e. using package name. From inside the package, functions can access them directly.

  • Global package variables can be initialized when declared:

    DECLARE x int := 42;
    

    or later in the initialization function __init__. For the external code using the package, it doesn't matter.

  • Types must be declared in the beginning of the package before the first subprogram.

  • The __init__ function must be the first subprogram defined in the package.

To support packages in Postgres Pro, the following enhancements were introduced:

J.1.1. Function and Variable Modifiers #

Function and variable modifiers start with # and are placed between the name and the DECLARE statement (see example below).

J.1.1.1. #package Modifier #

The modifier #package indicates that the function should be treated as a package function, which means the following:

  • When the function is called, the package is initialized automatically if it hasn't been initialized in the current session.

  • The function can access the variables of its package directly.

The __init__ function must not contain the #package modifier. A function with the #package modifier can be created only in a schema that already contains the __init__ function (that is, in a package). If you create a function within the CREATE OR REPLACE PACKAGE, the #package modifier may be omitted as it is added automatically in this command.

J.1.1.2. #import Modifier #

The modifier #import indicates that the function is supposed to work with variables of an outside package (or a number of packages). This is called package import and means the following:

  • When this function is accessed, the imported package is initialized automatically if it hasn't been initialized in the current session.

  • The function can access the variables of the imported package using package name. To import the package, use the following syntax:

    #import packages_list
    

    Here packages_list is the list of imported package names. You can also import packages separately, for example:

    #import foo, bar
    

    would mean the same as:

    #import foo
    #import bar
    

All the packages imported in the __init__ function are automatically imported for other functions of the package.

In the below example of using the #import modifier, the showValues procedure calls p of the htp package and set_action of the dbms_application_info package.

CREATE OR REPLACE PROCEDURE showValues(p_Str varchar) AS $$
#import htp, dbms_application_info
BEGIN
  CALL dbms_application_info.set_action('Show hello');

  CALL htp.p('<p>' || p_Str || '</p>');
END;
$$LANGUAGE plpgsql;

J.1.1.3. #private Modifier #

The #private modifier indicates that the function is private, meaning that it is only available inside the package and cannot be referenced from outside it. Private functions are necessary for the internal processes of the package. They are only available in the package that specifies them.

J.1.1.4. #export Modifier #

The modifier #export indicates that the package variable is public, meaning it can be referenced from outside the package. The #export modifier is used when initializing a package:

#export var_name_1, var_name_2, ... var_name_N

  • If the package does not contain the #export modifier, all the package variables are public. The same result is achieved with the #export on modifier.

  • If the package contains the #export modifier with specified variables, these variables are public, while all other package variables are private.

  • The #export modifier can be used several times in the __init__ function, and all the specified variables are considered public.

  • The #export off modifier means no variables should be public, and specifying exported variables in this case will result in error.

  • The #export on modifier renders all the variables public, and using the #export modifier again will result in error.

  • The #export modifer must contain at least one variable.

  • Private variables can only be used inside the package that specifies them. They can be called from functions and procedures from the package with the #package modifier. If they are declared separately, the package name must be specified.

  • Public variables can be used both inside and outside the package in case functions, procedures and anonymous blocks have the #import modifier that specifies the package name.

J.1.2. Built-in Functions #

PL/pgSQL provides a built-in function plpgsql_reset_packages() that deinstantiates all the packages in this session to bring the session to the original state.

SELECT plpgsql_reset_packages();

J.1.3. SQL Commands #

You can work with packages using regular schema-oriented commands (like CREATE SCHEMA and DROP SCHEMA) with function modifiers but CREATE OR REPLACE PACKAGE and DROP PACKAGE commands are more convenient.

J.1.3.1. CREATE OR REPLACE PACKAGE #

CREATE OR REPLACE PACKAGE will either create a new package, or replace the existing definition.

CREATE [OR REPLACE] PACKAGE package_name package_body;

Here package_name is the name of the schema, and package_body is the set of package creation commands with several caveats to be aware of:

  • The CREATE SCHEMA is executed automatically.

  • The #package modifier can be omitted — all the functions are modified automatically.

  • No language is specified when creating functions.

  • Function and type names are specified without the package name.

  • The individual top-level subcommands in the package body do not end with semicolons.

  • The package name must be distinct from the name of any existing package or schema in the current database.

The example below shows how the package can be created using the CREATE SCHEMA command.

CREATE SCHEMA foo;
CREATE TYPE foo.footype AS (a int, b int);
CREATE FUNCTION foo.__init__() RETURNS void AS $$
DECLARE x int := 1;
BEGIN
  RAISE NOTICE 'foo initialized';
END;
$$ LANGUAGE plpgsql;

CREATE FUNCTION foo.get() RETURNS int AS $$
#package
BEGIN
  RETURN x;
END;
$$ LANGUAGE plpgsql;

CREATE FUNCTION foo.inc() returns void AS $$
#package
BEGIN
  x := x + 1;
END;
$$ LANGUAGE plpgsql;

The following is an equivalent way of achieving the same result using the CREATE PACKAGE command:

CREATE PACKAGE foo
  CREATE TYPE footype AS (a int, b int)

  CREATE FUNCTION __init__() RETURNS void AS $$
  DECLARE
    x int := 1;
  BEGIN
    RAISE NOTICE 'foo initialized';
  END;
  $$

  CREATE FUNCTION get() RETURNS int AS $$
  BEGIN
    RETURN x;
  END;
  $$

  CREATE FUNCTION inc() RETURNS void AS $$
  BEGIN
    x := x + 1;
  ENG;
  $$
;

You can replace the existing package with the following special considerations:

  • You can use the CREATE OR REPLACE PACKAGE to replace only schemas that are packages (i.e. containing only functions and composite types and the initialization function).

  • When any elements of the old package are not defined in the new package, they are dropped if there are no dependent objects, otherwise the CREATE OR REPLACE PACKAGE is forced to fail.

  • If you replace the package without changing the function signature, its body is replaced, while dependent objects still remain. If the function signature changes, you would actually be creating a new, distinct function. The latter would only work when there are no dependent objects, otherwise the CREATE OR REPLACE PACKAGE is forced to fail.

  • The same restriction applies to replacing types.

  • If the command fails due to existing dependent objects, the containing package is referenced by the error rather than the objects themselves.

CREATE OR REPLACE PACKAGE is a fully transactional command so any mistakes when defining package elements would cause it to fail entirely, and all the changes are discarded.

J.1.3.2. DROP PACKAGE #

DROP PACKAGE removes packages (schemas) from the database along with dependent objects.

DROP PACKAGE [IF EXISTS] package_name_list [CASCADE];

Here package_name_list is the list of packages to be dropped. The command is fully transactional so either all of the packages are dropped, or none if the command fails. This command is similar to DROP SCHEMA with several caveats to be aware of:

  • You can use DROP PACKAGE to drop only schemas that are packages (i.e. containing only functions and composite types and the initialization function).

  • If the command fails due to existing dependent objects, the containing package is referenced by the error rather than the objects themselves.

  • Using the CASCADE option might make the command find objects to be removed in other packages besides the one(s) named. In this case, other packages are dropped as well.

All the dependencies mentioned in this section are standard Postgres Pro dependencies (see Section 5.14). For example, if a function uses other function signature in its own definition, the dependency is created but a single function call does not create one. When a function accesses package variables from outside the package, no dependency is created either (even a getter function).

J.1.4. Limitations #

  • In Oracle, a package is an atomic structure that can be modified only as a whole with CREATE OR REPLACE. As far as Postgres Pro Enterprise is concerned, a package is a schema so its elements can be modified separately with CREATE OR REPLACE PROCEDURE, CREATE OR REPLACE FUNCTION, or ALTER TYPE. Thus, you can easily replace a function or a type that does not have dependencies rather than replace the package itself. If you replace the package, you also need to replace all the dependent packages and functions manually.

  • Since a package in Postgres Pro is a schema, the user should have the rights on the schema:

    GRANT USAGE ON SCHEMA foo, bar TO hr_user;
    

    If the package must be run with definer's rights, the user should have all the rights on the schema:

    GRANT ALL ON SCHEMA hr_main TO hr_user;
    

    If the package must be run with invoker's rights, the user should have specific rights on tables and views to be used in the package, for example:

    GRANT SELECT demo.employee_tab TO hr_user;
    

  • Unlike Oracle, which stores all the information about package dependencies and in general about all PL/SQL objects (triggers, functions, procedures, etc.), Postgres Pro doesn't store dependencies at the level of function body and variables so these dependencies cannot be tracked when the package changes.

  • In Oracle, when the dependencies are broken, the package becomes INVALID. In this case, the package still exists in the database but it is not working. Unlike that, in Postgres Pro any object created or modified in the database must be valid. So if any operation in Postgres Pro leads to package invalidation (for example, the table used in package type declaration is dropped), it cannot be executed — first, the package must be deleted as it cannot remain invalid in the database.

  • When modifying packages, make sure that no other sessions use them (which can be done by stopping the application before replacing the packages). Once done, restart the application, and updated package versions will be available in all the sessions. This limitation is caused by the lack of library cache in Postgres Pro (unlike Oracle) since each backend caches PL/pgSQL code. If the package is modified in one session, and another session still works with the old package version, it would cause inconsistency, especially if the list of global package variables changes. Currently there are no global locks for package modification (like latch in Oracle) and no package modification tracking (like ORA-04068: existing state of packages has been discarded in Oracle).

  • Unlike Oracle, packages are not separated into specification and body.

  • Clauses modifying procedure declaration (like RESULT_CACHE, DETERMINISTIC in Oracle) are not supported. PL/SQL compiler directives are not supported either (like INLINE pragma, UDF pragma, etc.).