PK wDoa,mimetypeapplication/epub+zipPKwDiTunesMetadata.plistM artistName Oracle Corporation book-info cover-image-hash 736888322 cover-image-path OEBPS/dcommon/oracle-logo.jpg package-file-hash 56361454 publisher-unique-id E50727-04 unique-id 171663240 genre Oracle Documentation itemName Oracle® Database PL/SQL Language Reference, 12c Release 1 (12.1) releaseDate 2014-06-30T14:41:16Z year 2014 PKG̠JRMPKwDMETA-INF/container.xml PKYuPKwDOEBPS/goto_statement.htm GOTO Statement

GOTO Statement

The GOTO statement transfers control to a labeled block or statement.

If a GOTO statement exits a cursor FOR LOOP statement prematurely, the cursor closes.

Restrictions on GOTO Statement

Topics

Syntax

goto_statement ::=

Description of goto_statement.gif follows

Semantics

label

Identifies either a block or a statement (see "plsql_block ::=", "statement ::=", and "label").

If label is not in the current block, then the GOTO statement transfers control to the first enclosing block in which label appears.

Related Topics

In this chapter:

In other chapters:

PKٸPKwDOEBPS/if_statement.htm IF Statement

IF Statement

The IF statement either runs or skips a sequence of one or more statements, depending on the value of a BOOLEAN expression.

Topics

Syntax

if_statement ::=

Description of if_statement.gif follows

See:

Semantics

boolean_expression

Expression whose value is TRUE, FALSE, or NULL.

The first boolean_expression is always evaluated. Each other boolean_expression is evaluated only if the values of the preceding expressions are FALSE.

If a boolean_expression is evaluated and its value is TRUE, the statements after the corresponding THEN run. The succeeding expressions are not evaluated, and the statements associated with them do not run.

ELSE

If no boolean_expression has the value TRUE, the statements after ELSE run.

Related Topics

In this chapter:

In other chapters:

PKMwPKwDOEBPS/triggers.htm PL/SQL Triggers

9 PL/SQL Triggers

A trigger is like a stored procedure that Oracle Database invokes automatically whenever a specified event occurs.


Note:

The database can detect only system-defined events. You cannot define your own events.

Topics

Overview of Triggers

Like a stored procedure, a trigger is a named PL/SQL unit that is stored in the database and can be invoked repeatedly. Unlike a stored procedure, you can enable and disable a trigger, but you cannot explicitly invoke it. While a trigger is enabled, the database automatically invokes it—that is, the trigger fires—whenever its triggering event occurs. While a trigger is disabled, it does not fire.

You create a trigger with the CREATE TRIGGER statement. You specify the triggering event in terms of triggering statements and the item on which they act. The trigger is said to be created on or defined on the item, which is either a table, a view, a schema, or the database. You also specify the timing point, which determines whether the trigger fires before or after the triggering statement runs and whether it fires for each row that the triggering statement affects. By default, a trigger is created in the enabled state. For more information about the CREATE TRIGGER statement, see "CREATE TRIGGER Statement".

If the trigger is created on a table or view, then the triggering event is composed of DML statements, and the trigger is called a DML trigger. For more information, see "DML Triggers".

A crossedition trigger is a DML trigger for use only in edition-based redefinition. For information about crossedition triggers, see Oracle Database Development Guide.

If the trigger is created on a schema or the database, then the triggering event is composed of either DDL or database operation statements, and the trigger is called a system trigger. For more information, see "System Triggers".

A conditional trigger is a DML or system trigger that has a WHEN clause that specifies a SQL condition that the database evaluates for each row that the triggering statement affects. DML and system triggers For information about the WHEN clause, see "CREATE TRIGGER Statement".

When a trigger fires, tables that the trigger references might be undergoing changes made by SQL statements in other users' transactions. SQL statements running in triggers follow the same rules that standalone SQL statements do. Specifically:

  • Queries in the trigger see the current read-consistent materialized view of referenced tables and any data changed in the same transaction.

  • Updates in the trigger wait for existing data locks to be released before proceeding.

An INSTEAD OF trigger is either:

  • A DML trigger created on either a noneditioning view or a nested table column of a noneditioning view

  • A system trigger defined on a CREATE statement

The database fires the INSTEAD OF trigger instead of running the triggering statement.


Note:

A trigger is often called by the name of its triggering statement (for example, DELETE trigger or LOGON trigger), the name of the item on which it is defined (for example, DATABASE trigger or SCHEMA trigger), or its timing point (for example, BEFORE statement trigger or AFTER each row trigger).

Reasons to Use Triggers

Triggers let you customize your database management system. For example, you can use triggers to:

  • Automatically generate virtual column values

  • Log events

  • Gather statistics on table access

  • Modify table data when DML statements are issued against views

  • Enforce referential integrity when child and parent tables are on different nodes of a distributed database

  • Publish information about database events, user events, and SQL statements to subscribing applications

  • Prevent DML operations on a table after regular business hours

  • Prevent invalid transactions

  • Enforce complex business or referential integrity rules that you cannot define with constraints (see "How Triggers and Constraints Differ")


Caution:

Triggers are not reliable security mechanisms, because they are programmatic and easy to disable. For high-assurance security, use Oracle Database Vault, described in Oracle Database Vault Administrator's Guide.

How Triggers and Constraints Differ

Both triggers and constraints can constrain data input, but they differ significantly.

A trigger always applies to new data only. For example, a trigger can prevent a DML statement from inserting a NULL value into a database column, but the column might contain NULL values that were inserted into the column before the trigger was defined or while the trigger was disabled.

A constraint can apply either to new data only (like a trigger) or to both new and existing data. Constraint behavior depends on constraint state, as explained in Oracle Database SQL Language Reference.

Constraints are easier to write and less error-prone than triggers that enforce the same rules. However, triggers can enforce some complex business rules that constraints cannot. Oracle strongly recommends that you use triggers to constrain data input only in these situations:

  • To enforce referential integrity when child and parent tables are on different nodes of a distributed database

  • To enforce complex business or referential integrity rules that you cannot define with constraints


See Also:


DML Triggers

A DML trigger is created on either a table or view, and its triggering event is composed of the DML statements DELETE, INSERT, and UPDATE. To create a trigger that fires in response to a MERGE statement, create triggers on the INSERT and UPDATE statements to which the MERGE operation decomposes.

A DML trigger is either simple or compound.

A simple DML trigger fires at exactly one of these timing points:

  • Before the triggering statement runs

    (The trigger is called a BEFORE statement trigger or statement-level BEFORE trigger.)

  • After the triggering statement runs

    (The trigger is called an AFTER statement trigger or statement-level AFTER trigger.)

  • Before each row that the triggering statement affects

    (The trigger is called a BEFORE each row trigger or row-level BEFORE trigger.)

  • After each row that the triggering statement affects

    (The trigger is called an AFTER each row trigger or row-level AFTER trigger.)

A compound DML trigger created on a table or editioning view can fire at one, some, or all of the preceding timing points. Compound DML triggers help program an approach where you want the actions that you implement for the various timing points to share common data. For more information, see "Compound DML Triggers".

A simple or compound DML trigger that fires at row level can access the data in the row that it is processing. For details, see "Correlation Names and Pseudorecords".

An INSTEAD OF DML trigger is a DML trigger created on either a noneditioning view or a nested table column of a noneditioning view. For more information, see "INSTEAD OF DML Triggers".

Except in an INSTEAD OF trigger, a triggering UPDATE statement can include a column list. With a column list, the trigger fires only when a specified column is updated. Without a column list, the trigger fires when any column of the associated table is updated.

Topics

Conditional Predicates for Detecting Triggering DML Statement

The triggering event of a DML trigger can be composed of multiple triggering statements. When one of them fires the trigger, the trigger can determine which one by using these conditional predicates:

Conditional PredicateTRUE if and only if:
INSERTINGAn INSERT statement fired the trigger.
UPDATINGAn UPDATE statement fired the trigger.
UPDATING ('column')An UPDATE statement that affected the specified column fired the trigger.
DELETINGA DELETE statement fired the trigger.

A conditional predicate can appear wherever a BOOLEAN expression can appear.

Example 9-1 creates a DML trigger that uses conditional predicates to determine which of its four possible triggering statements fired it.

Example 9-1 Trigger Uses Conditional Predicates to Detect Triggering Statement

CREATE OR REPLACE TRIGGER t
  BEFORE
    INSERT OR
    UPDATE OF salary, department_id OR
    DELETE
  ON employees
BEGIN
  CASE
    WHEN INSERTING THEN
      DBMS_OUTPUT.PUT_LINE('Inserting');
    WHEN UPDATING('salary') THEN
      DBMS_OUTPUT.PUT_LINE('Updating salary');
    WHEN UPDATING('department_id') THEN
      DBMS_OUTPUT.PUT_LINE('Updating department ID');
    WHEN DELETING THEN
      DBMS_OUTPUT.PUT_LINE('Deleting');
  END CASE;
END;
/

INSTEAD OF DML Triggers

An INSTEAD OF DML trigger is a DML trigger created on a noneditioning view, or on a nested table column of a noneditioning view. The database fires the INSTEAD OF trigger instead of running the triggering DML statement. An INSTEAD OF trigger cannot be conditional.

An INSTEAD OF trigger is the only way to update a view that is not inherently updatable. (For information about inherently updatable views, see Oracle Database SQL Language Reference.) Design the INSTEAD OF trigger to determine what operation was intended and do the appropriate DML operations on the underlying tables.

An INSTEAD OF trigger is always a row-level trigger. An INSTEAD OF trigger can read OLD and NEW values, but cannot change them.

Example 9-2 creates the view oe.order_info to display information about customers and their orders. The view is not inherently updatable (because the primary key of the orders table, order_id, is not unique in the result set of the join view). The example creates an INSTEAD OF trigger to process INSERT statements directed to the view. The trigger inserts rows into the base tables of the view, customers and orders.

Example 9-2 INSTEAD OF Trigger

CREATE OR REPLACE VIEW order_info AS
   SELECT c.customer_id, c.cust_last_name, c.cust_first_name,
          o.order_id, o.order_date, o.order_status
   FROM customers c, orders o
   WHERE c.customer_id = o.customer_id;

CREATE OR REPLACE TRIGGER order_info_insert
   INSTEAD OF INSERT ON order_info
   DECLARE
     duplicate_info EXCEPTION;
     PRAGMA EXCEPTION_INIT (duplicate_info, -00001);
   BEGIN
     INSERT INTO customers
       (customer_id, cust_last_name, cust_first_name)
     VALUES (
     :new.customer_id,
     :new.cust_last_name,
     :new.cust_first_name);
   INSERT INTO orders (order_id, order_date, customer_id)
   VALUES (
     :new.order_id,
     :new.order_date,
     :new.customer_id);
   EXCEPTION
     WHEN duplicate_info THEN
       RAISE_APPLICATION_ERROR (
         num=> -20107,
         msg=> 'Duplicate customer or order ID');
   END order_info_insert;
/

Query to show that row to be inserted does not exist:

SELECT COUNT(*) FROM order_info WHERE customer_id = 999;

Result:

  COUNT(*)
----------
         0
 
1 row selected.

Insert row into view:

INSERT INTO order_info VALUES
   (999, 'Smith', 'John', 2500, TO_DATE('13-MAR-2001', 'DD-MON-YYYY'), 0);

Result:

1 row created.

Query to show that row has been inserted in view:

SELECT COUNT(*) FROM order_info WHERE customer_id = 999;

Result:

  COUNT(*)
----------
         1
 
1 row selected.

Query to show that row has been inserted in customers table:

SELECT COUNT(*) FROM customers WHERE customer_id = 999;

Result:

  COUNT(*)
----------
         1
 
1 row selected.

Query to show that row has been inserted in orders table:

SELECT COUNT(*) FROM orders WHERE customer_id = 999;

Result:

  COUNT(*)
----------
         1
 
1 row selected.

INSTEAD OF Triggers on Nested Table Columns of Views

An INSTEAD OF trigger with the NESTED TABLE clause fires only if the triggering statement operates on the elements of the specified nested table column of the view. The trigger fires for each modified nested table element.

In Example 9-3, the view dept_view contains a nested table of employees, emplist, created by the CAST function (described in Oracle Database SQL Language Reference). To modify the emplist column, the example creates an INSTEAD OF trigger on the column.

Example 9-3 INSTEAD OF Trigger on Nested Table Column of View

-- Create type of nested table element:
 
CREATE OR REPLACE TYPE nte
AUTHID DEFINER IS
OBJECT (
  emp_id     NUMBER(6),
  lastname   VARCHAR2(25),
  job        VARCHAR2(10),
  sal        NUMBER(8,2)
);
/
 
-- Created type of nested table:
 
CREATE OR REPLACE TYPE emp_list_ IS
  TABLE OF nte;
/
 
-- Create view:

CREATE OR REPLACE VIEW dept_view AS
  SELECT d.department_id, 
         d.department_name,
         CAST (MULTISET (SELECT e.employee_id, e.last_name, e.job_id, e.salary
                         FROM employees e
                         WHERE e.department_id = d.department_id
                        )
                        AS emp_list_
              ) emplist
  FROM departments d;
 
-- Create trigger:
 
CREATE OR REPLACE TRIGGER dept_emplist_tr
  INSTEAD OF INSERT ON NESTED TABLE emplist OF dept_view
  REFERENCING NEW AS Employee
              PARENT AS Department
  FOR EACH ROW
BEGIN
  -- Insert on nested table translates to insert on base table:
  INSERT INTO employees (
    employee_id,
    last_name,
    email,
    hire_date,
    job_id,
    salary,
    department_id
  )
  VALUES (
    :Employee.emp_id,                      -- employee_id
    :Employee.lastname,                    -- last_name
    :Employee.lastname || '@company.com',  -- email
    SYSDATE,                               -- hire_date
    :Employee.job,                         -- job_id
    :Employee.sal,                         -- salary
    :Department.department_id              -- department_id
  );
END;
/

Query view before inserting row into nested table:

SELECT emplist FROM dept_view WHERE department_id=10;

Result:

EMPLIST(EMP_ID, LASTNAME, JOB, SAL)
----------------------------------------------
 
EMP_LIST_(NTE(200, 'Whalen', 'AD_ASST', 4200))
 
1 row selected.

Query table before inserting row into nested table:

SELECT employee_id, last_name, job_id, salary
FROM employees
WHERE department_id = 10;

Result:

EMPLOYEE_ID LAST_NAME                 JOB_ID         SALARY
----------- ------------------------- ---------- ----------
        200 Whalen                    AD_ASST          4200
 
1 row selected.

Insert a row into nested table:

INSERT INTO TABLE (
  SELECT d.emplist 
  FROM dept_view d
  WHERE department_id = 10
)
VALUES (1001, 'Glenn', 'AC_MGR', 10000);

Query view after inserting row into nested table:

SELECT emplist FROM dept_view WHERE department_id=10;

Result (formatted to fit page):

EMPLIST(EMP_ID, LASTNAME, JOB, SAL)
--------------------------------------------------------------------------------
 
EMP_LIST_(NTE(200, 'Whalen', 'AD_ASST', 4200),
          NTE(1001, 'Glenn', 'AC_MGR', 10000))
 
1 row selected.

Query table after inserting row into nested table:

SELECT employee_id, last_name, job_id, salary
FROM employees
WHERE department_id = 10;

Result:

EMPLOYEE_ID LAST_NAME                 JOB_ID         SALARY
----------- ------------------------- ---------- ----------
        200 Whalen                    AD_ASST          4200
       1001 Glenn                     AC_MGR          10000
 
2 rows selected.

See Also:

"Compound DML Trigger Structure" for information about compound DML triggers with the INSTEAD OF EACH ROW section

Compound DML Triggers

A compound DML trigger created on a table or editioning view can fire at multiple timing points. Each timing point section has its own executable part and optional exception-handling part, but all of these parts can access a common PL/SQL state. The common state is established when the triggering statement starts and is destroyed when the triggering statement completes, even when the triggering statement causes an error.

A compound DML trigger created on a noneditioning view is not really compound, because it has only one timing point section.

A compound trigger can be conditional, but not autonomous.

Two common uses of compound triggers are:

  • To accumulate rows destined for a second table so that you can periodically bulk-insert them

  • To avoid the mutating-table error (ORA-04091)

Topics

Compound DML Trigger Structure

The optional declarative part of a compound trigger declares variables and subprograms that all of its timing-point sections can use. When the trigger fires, the declarative part runs before any timing-point sections run. The variables and subprograms exist for the duration of the triggering statement.

A compound DML trigger created on a noneditioning view is not really compound, because it has only one timing point section. The syntax for creating the simplest compound DML trigger on a noneditioning view is:

CREATE trigger FOR dml_event_clause ON view
COMPOUND TRIGGER
INSTEAD OF EACH ROW IS BEGIN
  statement;
END INSTEAD OF EACH ROW;

A compound DML trigger created on a table or editioning view has at least one timing-point section in Table 9-1. If the trigger has multiple timing-point sections, they can be in any order, but no timing-point section can be repeated. If a timing-point section is absent, then nothing happens at its timing point.

Table 9-1 Compound Trigger Timing-Point Sections

Timing PointSection

Before the triggering statement runs

BEFORE STATEMENT

After the triggering statement runs

AFTER STATEMENT

Before each row that the triggering statement affects

BEFORE EACH ROW

After each row that the triggering statement affects

AFTER EACH ROW



See Also:

"CREATE TRIGGER Statement" for more information about the syntax of compound triggers

A compound DML trigger does not have an initialization section, but the BEFORE STATEMENT section, which runs before any other timing-point section, can do any necessary initialization.

If a compound DML trigger has neither a BEFORE STATEMENT section nor an AFTER STATEMENT section, and its triggering statement affects no rows, then the trigger never fires.

Compound DML Trigger Restrictions

In addition to the "Trigger Restrictions"), compound DML triggers have these restrictions:

  • OLD, NEW, and PARENT cannot appear in the declarative part, the BEFORE STATEMENT section, or the AFTER STATEMENT section.

  • Only the BEFORE EACH ROW section can change the value of NEW.

  • A timing-point section cannot handle exceptions raised in another timing-point section.

  • If a timing-point section includes a GOTO statement, the target of the GOTO statement must be in the same timing-point section.

Performance Benefit of Compound DML Triggers

A compound DML trigger has a performance benefit when the triggering statement affects many rows.

For example, suppose that this statement triggers a compound DML trigger that has all four timing-point sections in Table 9-1:

INSERT INTO Target
  SELECT c1, c2, c3
  FROM Source
  WHERE Source.c1 > 0

Although the BEFORE EACH ROW and AFTER EACH ROW sections of the trigger run for each row of Source whose column c1 is greater than zero, the BEFORE STATEMENT section runs only before the INSERT statement runs and the AFTER STATEMENT section runs only after the INSERT statement runs.

A compound DML trigger has a greater performance benefit when it uses bulk SQL, described in "Bulk SQL and Bulk Binding".

Using Compound DML Triggers with Bulk Insertion

A compound DML trigger is useful for accumulating rows destined for a second table so that you can periodically bulk-insert them. To get the performance benefit from the compound trigger, you must specify BULK COLLECT INTO in the FORALL statement (otherwise, the FORALL statement does a single-row DML operation multiple times). For more information about using the BULK COLLECT clause with the FORALL statement, see "Using FORALL Statement and BULK COLLECT Clause Together".


See Also:

"FORALL Statement"

Scenario: You want to log every change to hr.employees.salary in a new table, employee_salaries. A single UPDATE statement updates many rows of the table hr.employees; therefore, bulk-inserting rows into employee.salaries is more efficient than inserting them individually.

Solution: Define a compound trigger on updates of the table hr.employees, as in Example 9-4. You do not need a BEFORE STATEMENT section to initialize idx or salaries, because they are state variables, which are initialized each time the trigger fires (even when the triggering statement is interrupted and restarted).


Note:

To run Example 9-4, you must have the EXECUTE privilege on the package DBMS_LOCK.

Example 9-4 Compound Trigger Logs Changes to One Table in Another Table

CREATE TABLE employee_salaries (
  employee_id NUMBER NOT NULL,
  change_date DATE   NOT NULL,
  salary NUMBER(8,2) NOT NULL,
  CONSTRAINT pk_employee_salaries PRIMARY KEY (employee_id, change_date),
  CONSTRAINT fk_employee_salaries FOREIGN KEY (employee_id)
    REFERENCES employees (employee_id)
      ON DELETE CASCADE)
/
CREATE OR REPLACE TRIGGER maintain_employee_salaries
  FOR UPDATE OF salary ON employees
    COMPOUND TRIGGER

-- Declarative Part:
-- Choose small threshhold value to show how example works:
  threshhold CONSTANT SIMPLE_INTEGER := 7;

  TYPE salaries_t IS TABLE OF employee_salaries%ROWTYPE INDEX BY SIMPLE_INTEGER;
  salaries  salaries_t;
  idx       SIMPLE_INTEGER := 0;

  PROCEDURE flush_array IS
    n CONSTANT SIMPLE_INTEGER := salaries.count();
  BEGIN
    FORALL j IN 1..n
      INSERT INTO employee_salaries VALUES salaries(j);
    salaries.delete();
    idx := 0;
    DBMS_OUTPUT.PUT_LINE('Flushed ' || n || ' rows');
  END flush_array;

  -- AFTER EACH ROW Section:

  AFTER EACH ROW IS
  BEGIN
    idx := idx + 1;
    salaries(idx).employee_id := :NEW.employee_id;
    salaries(idx).change_date := SYSTIMESTAMP;
    salaries(idx).salary := :NEW.salary;
    IF idx >= threshhold THEN
      flush_array();
    END IF;
  END AFTER EACH ROW;

  -- AFTER STATEMENT Section:

  AFTER STATEMENT IS
  BEGIN
    flush_array();
  END AFTER STATEMENT;
END maintain_employee_salaries;
/

Increase salary of every employee in department 50 by 10%:

UPDATE employees
  SET salary = salary * 1.1
  WHERE department_id = 50
/

Result:

Flushed 7 rows
Flushed 7 rows
Flushed 7 rows
Flushed 7 rows
Flushed 7 rows
Flushed 7 rows
Flushed 3 rows
 
45 rows updated.

Wait two seconds:

BEGIN
  DBMS_LOCK.SLEEP(2);
END;
/

Increase salary of every employee in department 50 by 5%:

UPDATE employees
  SET salary = salary * 1.05
  WHERE department_id = 50
/

Result:

Flushed 7 rows
Flushed 7 rows
Flushed 7 rows
Flushed 7 rows
Flushed 7 rows
Flushed 7 rows
Flushed 3 rows
 
45 rows updated.

See changes to employees table reflected in employee_salaries table:

SELECT employee_id, count(*) c
  FROM employee_salaries
  GROUP BY employee_id
/

Result:

EMPLOYEE_ID          C
----------- ----------
        120          2
        121          2
        122          2
        123          2
        124          2
        125          2
...
        199          2
 
45 rows selected.

Using Compound DML Triggers to Avoid Mutating-Table Error

A compound DML trigger is useful for avoiding the mutating-table error (ORA-04091) explained in "Mutating-Table Restriction".

Scenario: A business rule states that an employee's salary increase must not exceed 10% of the average salary for the employee's department. This rule must be enforced by a trigger.

Solution: Define a compound trigger on updates of the table hr.employees, as in Example 9-5. The state variables are initialized each time the trigger fires (even when the triggering statement is interrupted and restarted).

Example 9-5 Compound Trigger Avoids Mutating-Table Error

CREATE OR REPLACE TRIGGER Check_Employee_Salary_Raise
  FOR UPDATE OF Salary ON Employees
COMPOUND TRIGGER
  Ten_Percent                 CONSTANT NUMBER := 0.1;
  TYPE Salaries_t             IS TABLE OF Employees.Salary%TYPE;
  Avg_Salaries                Salaries_t;
  TYPE Department_IDs_t       IS TABLE OF Employees.Department_ID%TYPE;
  Department_IDs              Department_IDs_t;

  -- Declare collection type and variable:

  TYPE Department_Salaries_t  IS TABLE OF Employees.Salary%TYPE
                                INDEX BY VARCHAR2(80);
  Department_Avg_Salaries     Department_Salaries_t;

  BEFORE STATEMENT IS
  BEGIN
    SELECT               AVG(e.Salary), NVL(e.Department_ID, -1)
      BULK COLLECT INTO  Avg_Salaries, Department_IDs
      FROM               Employees e
      GROUP BY           e.Department_ID;
    FOR j IN 1..Department_IDs.COUNT() LOOP
      Department_Avg_Salaries(Department_IDs(j)) := Avg_Salaries(j);
    END LOOP;
  END BEFORE STATEMENT;

  AFTER EACH ROW IS
  BEGIN
    IF :NEW.Salary - :Old.Salary >
      Ten_Percent*Department_Avg_Salaries(:NEW.Department_ID)
    THEN
      Raise_Application_Error(-20000, 'Raise too big');
    END IF;
  END AFTER EACH ROW;
END Check_Employee_Salary_Raise;

Triggers for Ensuring Referential Integrity

You can use triggers and constraints to maintain referential integrity between parent and child tables, as Table 9-2 shows. (For more information about constraints, see Oracle Database SQL Language Reference.)

Table 9-2 Constraints and Triggers for Ensuring Referential Integrity

TableConstraint to Declare on TableTriggers to Create on Table

Parent

PRIMARY KEY or UNIQUE

One or more triggers that ensure that when PRIMARY KEY or UNIQUE values are updated or deleted, the desired action (RESTRICT, CASCADE, or SET NULL) occurs on corresponding FOREIGN KEY values.

No action is required for inserts into the parent table, because no dependent foreign keys exist.

Child

FOREIGN KEY, if parent and child are in the same database. (The database does not support declarative referential constraints between tables on different nodes of a distributed database.)

Disable this foreign key constraint to prevent the corresponding PRIMARY KEY or UNIQUE constraint from being dropped (except explicitly with the CASCADE option).

One trigger that ensures that values inserted or updated in the FOREIGN KEY correspond to PRIMARY KEY or UNIQUE values in the parent table.


Topics


Note:

The examples in the following topics use these tables, which share the column Deptno:
CREATE TABLE emp (
  Empno     NUMBER NOT NULL,
  Ename     VARCHAR2(10),
  Job       VARCHAR2(9),
  Mgr       NUMBER(4),
  Hiredate  DATE,
  Sal       NUMBER(7,2),
  Comm      NUMBER(7,2),
  Deptno    NUMBER(2) NOT NULL);

CREATE TABLE dept (
  Deptno    NUMBER(2) NOT NULL,
  Dname     VARCHAR2(14),
  Loc       VARCHAR2(13),
  Mgr_no    NUMBER,
  Dept_type NUMBER);

Several triggers include statements that lock rows (SELECT FOR UPDATE). This operation is necessary to maintain concurrency while the rows are being processed.

These examples are not meant to be used exactly as written. They are provided to assist you in designing your own triggers.


Foreign Key Trigger for Child Table

The trigger in Example 9-6 ensures that before an INSERT or UPDATE statement affects a foreign key value, the corresponding value exists in the parent key. The exception ORA-04091 (mutating-table error) allows the trigger emp_dept_check to be used with the UPDATE_SET_DEFAULT and UPDATE_CASCADE triggers. This exception is unnecessary if the trigger emp_dept_check is used alone.

Example 9-6 Foreign Key Trigger for Child Table

CREATE OR REPLACE TRIGGER emp_dept_check
  BEFORE INSERT OR UPDATE OF Deptno ON emp
  FOR EACH ROW WHEN (NEW.Deptno IS NOT NULL)

  -- Before row is inserted or DEPTNO is updated in emp table,
  -- fire this trigger to verify that new foreign key value (DEPTNO)
  -- is present in dept table.
DECLARE
  Dummy               INTEGER;  -- Use for cursor fetch
  Invalid_department  EXCEPTION;
  Valid_department    EXCEPTION;
  Mutating_table      EXCEPTION;
  PRAGMA EXCEPTION_INIT (Invalid_department, -4093);
  PRAGMA EXCEPTION_INIT (Valid_department, -4092);
  PRAGMA EXCEPTION_INIT (Mutating_table, -4091);

  -- Cursor used to verify parent key value exists.
  -- If present, lock parent key's row so it cannot be deleted
  -- by another transaction until this transaction is
  -- committed or rolled back.

  CURSOR Dummy_cursor (Dn NUMBER) IS
    SELECT Deptno FROM dept
    WHERE Deptno = Dn
    FOR UPDATE OF Deptno;
BEGIN
  OPEN Dummy_cursor (:NEW.Deptno);
  FETCH Dummy_cursor INTO Dummy;

  -- Verify parent key.
  -- If not found, raise user-specified error code and message.
  -- If found, close cursor before allowing triggering statement to complete:

  IF Dummy_cursor%NOTFOUND THEN
    RAISE Invalid_department;
  ELSE
    RAISE Valid_department;
  END IF;
  CLOSE Dummy_cursor;
EXCEPTION
  WHEN Invalid_department THEN
    CLOSE Dummy_cursor;
    Raise_application_error(-20000, 'Invalid Department'
      || ' Number' || TO_CHAR(:NEW.deptno));
  WHEN Valid_department THEN
    CLOSE Dummy_cursor;
  WHEN Mutating_table THEN
    NULL;
END;
/

UPDATE and DELETE RESTRICT Trigger for Parent Table

The trigger in Example 9-7 enforces the UPDATE and DELETE RESTRICT referential action on the primary key of the dept table.


Caution:

The trigger in Example 9-7 does not work with self-referential tables (tables with both the primary/unique key and the foreign key). Also, this trigger does not allow triggers to cycle (such as when A fires B, which fires A).

Example 9-7 UPDATE and DELETE RESTRICT Trigger for Parent Table

CREATE OR REPLACE TRIGGER dept_restrict
  BEFORE DELETE OR UPDATE OF Deptno ON dept
  FOR EACH ROW

  -- Before row is deleted from dept or primary key (DEPTNO) of dept is updated,
  -- check for dependent foreign key values in emp;
  -- if any are found, roll back.

DECLARE
  Dummy                  INTEGER;  -- Use for cursor fetch
  employees_present      EXCEPTION;
  employees_not_present  EXCEPTION;
  PRAGMA EXCEPTION_INIT (employees_present, -4094);
  PRAGMA EXCEPTION_INIT (employees_not_present, -4095);

  -- Cursor used to check for dependent foreign key values.
  CURSOR Dummy_cursor (Dn NUMBER) IS
    SELECT Deptno FROM emp WHERE Deptno = Dn;

BEGIN
  OPEN Dummy_cursor (:OLD.Deptno);
  FETCH Dummy_cursor INTO Dummy;

  -- If dependent foreign key is found, raise user-specified
  -- error code and message. If not found, close cursor
  -- before allowing triggering statement to complete.

  IF Dummy_cursor%FOUND THEN
    RAISE employees_present;     -- Dependent rows exist
  ELSE
    RAISE employees_not_present; -- No dependent rows exist
  END IF;
  CLOSE Dummy_cursor;

EXCEPTION
  WHEN employees_present THEN
    CLOSE Dummy_cursor;
    Raise_application_error(-20001, 'Employees Present in'
      || ' Department ' || TO_CHAR(:OLD.DEPTNO));
  WHEN employees_not_present THEN
    CLOSE Dummy_cursor;
END;

UPDATE and DELETE SET NULL Trigger for Parent Table

The trigger in Example 9-8 enforces the UPDATE and DELETE SET NULL referential action on the primary key of the dept table.

Example 9-8 UPDATE and DELETE SET NULL Trigger for Parent Table

CREATE OR REPLACE TRIGGER dept_set_null
  AFTER DELETE OR UPDATE OF Deptno ON dept
  FOR EACH ROW

  -- Before row is deleted from dept or primary key (DEPTNO) of dept is updated,
  -- set all corresponding dependent foreign key values in emp to NULL:

BEGIN
  IF UPDATING AND :OLD.Deptno != :NEW.Deptno OR DELETING THEN
    UPDATE emp SET emp.Deptno = NULL
    WHERE emp.Deptno = :OLD.Deptno;
  END IF;
END;
/

DELETE CASCADE Trigger for Parent Table

The trigger in Example 9-9 enforces the DELETE CASCADE referential action on the primary key of the dept table.

Example 9-9 DELETE CASCADE Trigger for Parent Table

CREATE OR REPLACE TRIGGER dept_del_cascade
  AFTER DELETE ON dept
  FOR EACH ROW

  -- Before row is deleted from dept,
  -- delete all rows from emp table whose DEPTNO is same as
  -- DEPTNO being deleted from dept table:

BEGIN
  DELETE FROM emp
  WHERE emp.Deptno = :OLD.Deptno;
END;
/

Note:

Typically, the code for DELETE CASCADE is combined with the code for UPDATE SET NULL or UPDATE SET DEFAULT, to account for both updates and deletes.

UPDATE CASCADE Trigger for Parent Table

The triggers in Example 9-10 ensure that if a department number is updated in the dept table, then this change is propagated to dependent foreign keys in the emp table.

Example 9-10 UPDATE CASCADE Trigger for Parent Table

-- Generate sequence number to be used as flag
-- for determining if update occurred on column:

CREATE SEQUENCE Update_sequence
  INCREMENT BY 1 MAXVALUE 5000 CYCLE;

CREATE OR REPLACE PACKAGE Integritypackage AUTHID DEFINER AS
  Updateseq NUMBER;
END Integritypackage;
/
CREATE OR REPLACE PACKAGE BODY Integritypackage AS
END Integritypackage;
/
-- Create flag col:

ALTER TABLE emp ADD Update_id NUMBER;

CREATE OR REPLACE TRIGGER dept_cascade1
  BEFORE UPDATE OF Deptno ON dept
DECLARE
  -- Before updating dept table (this is a statement trigger),
  -- generate sequence number
  -- & assign it to public variable UPDATESEQ of
  -- user-defined package named INTEGRITYPACKAGE:
BEGIN
  Integritypackage.Updateseq := Update_sequence.NEXTVAL;
END;
/
CREATE OR REPLACE TRIGGER dept_cascade2
  AFTER DELETE OR UPDATE OF Deptno ON dept
  FOR EACH ROW

  -- For each department number in dept that is updated,
  -- cascade update to dependent foreign keys in emp table.
  -- Cascade update only if child row was not updated by this trigger:
BEGIN
  IF UPDATING THEN
    UPDATE emp
    SET Deptno = :NEW.Deptno,
        Update_id = Integritypackage.Updateseq   --from 1st
    WHERE emp.Deptno = :OLD.Deptno
    AND Update_id IS NULL;

    /* Only NULL if not updated by 3rd trigger
       fired by same triggering statement */
  END IF;
  IF DELETING THEN
    -- After row is deleted from dept,
    -- delete all rows from emp table whose DEPTNO is same as
    -- DEPTNO being deleted from dept table:
    DELETE FROM emp
    WHERE emp.Deptno = :OLD.Deptno;
  END IF;
END;
/
CREATE OR REPLACE TRIGGER dept_cascade3
  AFTER UPDATE OF Deptno ON dept
BEGIN UPDATE emp
  SET Update_id = NULL
  WHERE Update_id = Integritypackage.Updateseq;
END;
/

Note:

Because the trigger dept_cascade2 updates the emp table, the emp_dept_check trigger in Example 9-6, if enabled, also fires. The resulting mutating-table error is trapped by the emp_dept_check trigger. Carefully test any triggers that require error trapping to succeed to ensure that they always work properly in your environment.

Triggers for Complex Constraint Checking

Triggers can enforce integrity rules other than referential integrity. The trigger in Example 9-11 does a complex check before allowing the triggering statement to run.


Note:

Example 9-11 needs this data structure:
CREATE TABLE Salgrade (
  Grade               NUMBER,
  Losal               NUMBER,
  Hisal               NUMBER,
  Job_classification  VARCHAR2(9));

Example 9-11 Trigger Checks Complex Constraints

CREATE OR REPLACE TRIGGER salary_check
  BEFORE INSERT OR UPDATE OF Sal, Job ON Emp
  FOR EACH ROW

DECLARE
  Minsal               NUMBER;
  Maxsal               NUMBER;
  Salary_out_of_range  EXCEPTION;
  PRAGMA EXCEPTION_INIT (Salary_out_of_range, -4096);

BEGIN
  /* Retrieve minimum & maximum salary for employee's new job classification
     from SALGRADE table into MINSAL and MAXSAL: */

  SELECT Losal, Hisal INTO Minsal, Maxsal
  FROM Salgrade
  WHERE Job_classification = :NEW.Job;

  /* If employee's new salary is less than or greater than
     job classification's limits, raise exception.
     Exception message is returned and pending INSERT or UPDATE statement
     that fired the trigger is rolled back: */

  IF (:NEW.Sal < Minsal OR :NEW.Sal > Maxsal) THEN
    RAISE Salary_out_of_range;
  END IF;
EXCEPTION
  WHEN Salary_out_of_range THEN
    Raise_application_error (
      -20300,
      'Salary '|| TO_CHAR(:NEW.Sal) ||' out of range for '
      || 'job classification ' ||:NEW.Job
      ||' for employee ' || :NEW.Ename
    );
  WHEN NO_DATA_FOUND THEN
    Raise_application_error(-20322, 'Invalid Job Classification');
END;
/

Triggers for Complex Security Authorizations

Triggers are commonly used to enforce complex security authorizations for table data. Use triggers only to enforce complex security authorizations that you cannot define using the database security features provided with the database. For example, use a trigger to prohibit updates to the employee table during weekends and nonworking hours.

When using a trigger to enforce a complex security authorization, it is best to use a BEFORE statement trigger. Using a BEFORE statement trigger has these benefits:

  • The security check is done before the triggering statement is allowed to run, so that no wasted work is done by an unauthorized statement.

  • The security check is done only for the triggering statement, not for each row affected by the triggering statement.

The trigger in Example 9-12 enforces security by raising exceptions when anyone tries to update the table employees during weekends or nonworking hours.

Example 9-12 Trigger Enforces Security Authorizations

CREATE OR REPLACE TRIGGER Employee_permit_changes
  BEFORE INSERT OR DELETE OR UPDATE ON employees
DECLARE
  Dummy             INTEGER;
  Not_on_weekends   EXCEPTION;
  Nonworking_hours  EXCEPTION;
  PRAGMA EXCEPTION_INIT (Not_on_weekends, -4097);
  PRAGMA EXCEPTION_INIT (Nonworking_hours, -4099);
BEGIN
   -- Check for weekends:
 
   IF (TO_CHAR(Sysdate, 'DAY') = 'SAT' OR
     TO_CHAR(Sysdate, 'DAY') = 'SUN') THEN
       RAISE Not_on_weekends;
   END IF;
 
  -- Check for work hours (8am to 6pm):
 
  IF (TO_CHAR(Sysdate, 'HH24') < 8 OR
    TO_CHAR(Sysdate, 'HH24') > 18) THEN
      RAISE Nonworking_hours;
  END IF;
 
EXCEPTION
  WHEN Not_on_weekends THEN
    Raise_application_error(-20324,'Might not change '
      ||'employee table during the weekend');
  WHEN Nonworking_hours THEN
    Raise_application_error(-20326,'Might not change '
     ||'emp table during Nonworking hours');
END;
/

See Also:

Oracle Database Security Guide for detailed information about database security features

Triggers for Transparent Event Logging

Triggers are very useful when you want to transparently do a related change in the database following certain events.

The REORDER trigger example shows a trigger that reorders parts as necessary when certain conditions are met. (In other words, a triggering statement is entered, and the PARTS_ON_HAND value is less than the REORDER_POINT value.)

Triggers for Deriving Column Values

Triggers can derive column values automatically, based upon a value provided by an INSERT or UPDATE statement. This type of trigger is useful to force values in specific columns that depend on the values of other columns in the same row. BEFORE row triggers are necessary to complete this type of operation for these reasons:

  • The dependent values must be derived before the INSERT or UPDATE occurs, so that the triggering statement can use the derived values.

  • The trigger must fire for each row affected by the triggering INSERT or UPDATE statement.

The trigger in Example 9-13 derives new column values for a table whenever a row is inserted or updated.


Note:

Example 9-13 needs this change to this data structure:
ALTER TABLE Emp ADD(
   Uppername   VARCHAR2(20),
   Soundexname VARCHAR2(20));

Example 9-13 Trigger Derives New Column Values

CREATE OR REPLACE TRIGGER Derived 
BEFORE INSERT OR UPDATE OF Ename ON Emp

/* Before updating the ENAME field, derive the values for
   the UPPERNAME and SOUNDEXNAME fields. Restrict users
   from updating these fields directly: */
FOR EACH ROW
BEGIN
  :NEW.Uppername := UPPER(:NEW.Ename);
  :NEW.Soundexname := SOUNDEX(:NEW.Ename);
END;
/

Triggers for Building Complex Updatable Views

Views are an excellent mechanism to provide logical windows over table data. However, when the view query gets complex, the system implicitly cannot translate the DML on the view into those on the underlying tables. INSTEAD OF triggers help solve this problem. These triggers can be defined over views, and they fire instead of the actual DML.

Consider a library system where books are arranged by title. The library consists of a collection of book type objects:

CREATE OR REPLACE TYPE Book_t AS OBJECT (
  Booknum    NUMBER,
  Title      VARCHAR2(20),
  Author     VARCHAR2(20),
  Available  CHAR(1)
);
/
CREATE OR REPLACE TYPE Book_list_t AS TABLE OF Book_t;
/

The table Book_table is created and populated like this:

DROP TABLE Book_table;
CREATE TABLE Book_table (
  Booknum    NUMBER,
  Section    VARCHAR2(20),
  Title      VARCHAR2(20),
  Author     VARCHAR2(20),
  Available  CHAR(1)
);
 
INSERT INTO Book_table (
  Booknum, Section, Title, Author, Available
) 
VALUES (
  121001, 'Classic', 'Iliad', 'Homer', 'Y'
);
 
INSERT INTO Book_table (
  Booknum, Section, Title, Author, Available
) 
VALUES ( 
  121002, 'Novel', 'Gone with the Wind', 'Mitchell M', 'N'
);
 
SELECT * FROM Book_table ORDER BY Booknum;

Result:

   BOOKNUM SECTION              TITLE                AUTHOR               A
---------- -------------------- -------------------- -------------------- -
    121001 Classic              Iliad                Homer                Y
    121002 Novel                Gone with the Wind   Mitchell M           N
 
2 rows selected.

The table Library_table is created and populated like this:

DROP TABLE Library_table;
CREATE TABLE Library_table (Section VARCHAR2(20));
 
INSERT INTO Library_table (Section)
VALUES ('Novel');
 
INSERT INTO Library_table (Section)
VALUES ('Classic');
 
SELECT * FROM Library_table ORDER BY Section;

Result:

SECTION
--------------------
Classic
Novel
 
2 rows selected.

You can define a complex view over the tables Book_table and Library_table to create a logical view of the library with sections and a collection of books in each section:

CREATE OR REPLACE VIEW Library_view AS
  SELECT i.Section, CAST (
    MULTISET (
      SELECT b.Booknum, b.Title, b.Author, b.Available
      FROM Book_table b
      WHERE b.Section = i.Section
    ) AS Book_list_t
  ) BOOKLIST
  FROM Library_table i;

(For information about the CAST function, see Oracle Database SQL Language Reference.)

Make Library_view updatable by defining an INSTEAD OF trigger on it:

CREATE OR REPLACE TRIGGER Library_trigger
  INSTEAD OF
  INSERT ON Library_view
  FOR EACH ROW
DECLARE
  Bookvar  Book_t;
  i        INTEGER;
BEGIN
  INSERT INTO Library_table
  VALUES (:NEW.Section);
 
  FOR i IN 1..:NEW.Booklist.COUNT LOOP
    Bookvar := :NEW.Booklist(i);
 
    INSERT INTO Book_table (
      Booknum, Section, Title, Author, Available      
    )
    VALUES (
      Bookvar.booknum, :NEW.Section, Bookvar.Title,
      Bookvar.Author, bookvar.Available
    );
  END LOOP;
END;
/

Insert a new row into Library_view:

INSERT INTO Library_view (Section, Booklist)
VALUES (
  'History', 
  book_list_t (book_t (121330, 'Alexander', 'Mirth', 'Y'))
);

See the effect on Library_view:

SELECT * FROM Library_view ORDER BY Section;

Result:

SECTION
--------------------
BOOKLIST(BOOKNUM, TITLE, AUTHOR, AVAILABLE)
--------------------------------------------------------------------
 
Classic
BOOK_LIST_T(BOOK_T(121001, 'Iliad', 'Homer', 'Y'))
 
History
BOOK_LIST_T(BOOK_T(121330, 'Alexander', 'Mirth', 'Y'))
 
Novel
BOOK_LIST_T(BOOK_T(121002, 'Gone with the Wind', 'Mitchell M', 'N'))
 
 
3 rows selected.

See the effect on Book_table:

SELECT * FROM Book_table ORDER BY Booknum;

Result:

   BOOKNUM SECTION              TITLE                AUTHOR               A
---------- -------------------- -------------------- -------------------- -
    121001 Classic              Iliad                Homer                Y
    121002 Novel                Gone with the Wind   Mitchell M           N
    121330 History              Alexander            Mirth                Y
 
3 rows selected.

See the effect on Library_table:

SELECT * FROM Library_table ORDER BY Section;

Result:

SECTION
--------------------
Classic
History
Novel
 
3 rows selected.

Similarly, you can also define triggers on the nested table booklist to handle modification of the nested table element.

Triggers for Fine-Grained Access Control

You can use LOGON triggers to run the package associated with an application context. An application context captures session-related information about the user who is logging in to the database. From there, your application can control how much access this user has, based on his or her session information.


Note:

If you have very specific logon requirements, such as preventing users from logging in from outside the firewall or after work hours, consider using Oracle Database Vault instead of LOGON triggers. With Oracle Database Vault, you can create custom rules to strictly control user access.


See Also:


Correlation Names and Pseudorecords


Note:

This topic applies only to triggers that fire at row level. That is:
  • Row-level simple DML triggers

  • Compound DML triggers with row-level timing point sections


A trigger that fires at row level can access the data in the row that it is processing by using correlation names. The default correlation names are OLD, NEW, and PARENT. To change the correlation names, use the REFERENCING clause of the CREATE TRIGGER statement (see "referencing_clause ::=").

If the trigger is created on a nested table, then OLD and NEW refer to the current row of the nested table, and PARENT refers to the current row of the parent table. If the trigger is created on a table or view, then OLD and NEW refer to the current row of the table or view, and PARENT is undefined.

OLD, NEW, and PARENT are also called pseudorecords, because they have record structure, but are allowed in fewer contexts than records are. The structure of a pseudorecord is table_name%ROWTYPE, where table_name is the name of the table on which the trigger is created (for OLD and NEW) or the name of the parent table (for PARENT).

In the trigger_body of a simple trigger or the tps_body of a compound trigger, a correlation name is a placeholder for a bind variable. Reference the field of a pseudorecord with this syntax:

:pseudorecord_name.field_name

In the WHEN clause of a conditional trigger, a correlation name is not a placeholder for a bind variable. Therefore, omit the colon in the preceding syntax.

Table 9-3 shows the values of OLD and NEW fields for the row that the triggering statement is processing.

Table 9-3 OLD and NEW Pseudorecord Field Values

Triggering StatementOLD.field ValueNEW.field Value

INSERT

NULL

Post-insert value

UPDATE

Pre-update value

Post-update value

DELETE

Pre-delete value

NULL


The restrictions on pseudorecords are:

  • A pseudorecord cannot appear in a record-level operation.

    For example, the trigger cannot include this statement:

    :NEW := NULL;
    
  • A pseudorecord cannot be an actual subprogram parameter.

    (A pseudorecord field can be an actual subprogram parameter.)

  • The trigger cannot change OLD field values.

    Trying to do so raises ORA-04085.

  • If the triggering statement is DELETE, then the trigger cannot change NEW field values.

    Trying to do so raises ORA-04084.

  • An AFTER trigger cannot change NEW field values, because the triggering statement runs before the trigger fires.

    Trying to do so raises ORA-04084.

A BEFORE trigger can change NEW field values before a triggering INSERT or UPDATE statement puts them in the table.

If a statement triggers both a BEFORE trigger and an AFTER trigger, and the BEFORE trigger changes a NEW field value, then the AFTER trigger "sees" that change.

Example 9-14 creates a log table and a trigger that inserts a row in the log table after any UPDATE statement affects the SALARY column of the EMPLOYEES table, and then updates EMPLOYEES.SALARY and shows the log table.

Example 9-14 Trigger Logs Changes to EMPLOYEES.SALARY

Create log table:

DROP TABLE Emp_log;
CREATE TABLE Emp_log (
  Emp_id     NUMBER,
  Log_date   DATE,
  New_salary NUMBER,
  Action     VARCHAR2(20));
 

Create trigger that inserts row in log table after EMPLOYEES.SALARY is updated:

CREATE OR REPLACE TRIGGER log_salary_increase
  AFTER UPDATE OF salary ON employees
  FOR EACH ROW
BEGIN
  INSERT INTO Emp_log (Emp_id, Log_date, New_salary, Action)
  VALUES (:NEW.employee_id, SYSDATE, :NEW.salary, 'New Salary');
END;
/

Update EMPLOYEES.SALARY:

UPDATE employees
SET salary = salary + 1000.0
WHERE Department_id = 20;
 

Result:

2 rows updated.
 

Show log table:

SELECT * FROM Emp_log;
 

Result:

    EMP_ID LOG_DATE  NEW_SALARY ACTION
---------- --------- ---------- --------------------
       201 28-APR-10      13650 New Salary
       202 28-APR-10       6300 New Salary
 
2 rows selected.

Example 9-15 creates a conditional trigger that prints salary change information whenever a DELETE, INSERT, or UPDATE statement affects the EMPLOYEES table—unless that information is about the President. The database evaluates the WHEN condition for each affected row. If the WHEN condition is TRUE for an affected row, then the trigger fires for that row before the triggering statement runs. If the WHEN condition is not TRUE for an affected row, then trigger does not fire for that row, but the triggering statement still runs.

Example 9-15 Conditional Trigger Prints Salary Change Information

CREATE OR REPLACE TRIGGER print_salary_changes
  BEFORE DELETE OR INSERT OR UPDATE ON employees
  FOR EACH ROW
  WHEN (NEW.job_id <> 'AD_PRES')  -- do not print information about President
DECLARE
  sal_diff  NUMBER;
BEGIN
  sal_diff  := :NEW.salary  - :OLD.salary;
  DBMS_OUTPUT.PUT(:NEW.last_name || ': ');
  DBMS_OUTPUT.PUT('Old salary = ' || :OLD.salary || ', ');
  DBMS_OUTPUT.PUT('New salary = ' || :NEW.salary || ', ');
  DBMS_OUTPUT.PUT_LINE('Difference: ' || sal_diff);
END;
/

Query:

SELECT last_name, department_id, salary, job_id
FROM employees
WHERE department_id IN (10, 20, 90)
ORDER BY department_id, last_name;
 

Result:

LAST_NAME                 DEPARTMENT_ID     SALARY JOB_ID
------------------------- ------------- ---------- ----------
Whalen                               10       4200 AD_ASST
Fay                                  20       6000 MK_REP
Hartstein                            20      13000 MK_MAN
De Haan                              90      17000 AD_VP
King                                 90      24000 AD_PRES
Kochhar                              90      17000 AD_VP
 
6 rows selected.

Triggering statement:

UPDATE employees
SET salary = salary * 1.05
WHERE department_id IN (10, 20, 90);

Result:

Whalen: Old salary = 4200, New salary = 4410, Difference: 210
Hartstein: Old salary = 13000, New salary = 13650, Difference: 650
Fay: Old salary = 6000, New salary = 6300, Difference: 300
Kochhar: Old salary = 17000, New salary = 17850, Difference: 850
De Haan: Old salary = 17000, New salary = 17850, Difference: 850
 
6 rows updated.

Query:

SELECT salary FROM employees WHERE job_id = 'AD_PRES';

Result:

    SALARY
----------
     25200
 
1 row selected.

Example 9-16 creates an UPDATE trigger that modifies CLOB columns. (For information about TO_CLOB and other conversion functions, see Oracle Database SQL Language Reference.)

Example 9-16 Trigger Modifies CLOB Columns

DROP TABLE tab1;
CREATE TABLE tab1 (c1 CLOB);
INSERT INTO tab1 VALUES ('<h1>HTML Document Fragment</h1><p>Some text.', 3);

CREATE OR REPLACE TRIGGER trg1
  BEFORE UPDATE ON tab1
  FOR EACH ROW
BEGIN
  DBMS_OUTPUT.PUT_LINE('Old value of CLOB column: '||:OLD.c1);
  DBMS_OUTPUT.PUT_LINE('Proposed new value of CLOB column: '||:NEW.c1);

  :NEW.c1 := :NEW.c1 || TO_CLOB('<hr><p>Standard footer paragraph.');

  DBMS_OUTPUT.PUT_LINE('Final value of CLOB column: '||:NEW.c1);
END;
/ 

SET SERVEROUTPUT ON;
UPDATE tab1 SET c1 = '<h1>Different Document Fragment</h1><p>Different text.';

SELECT * FROM tab1;

Example 9-17 creates a table with the same name as a correlation name, new, and then creates a trigger on that table. To avoid conflict between the table name and the correlation name, the trigger references the correlation name as Newest.

Example 9-17 Trigger with REFERENCING Clause

CREATE TABLE new (
  field1  NUMBER,
  field2  VARCHAR2(20)
);

CREATE OR REPLACE TRIGGER Print_salary_changes
BEFORE UPDATE ON new
REFERENCING new AS Newest
FOR EACH ROW
BEGIN
  :Newest.Field2 := TO_CHAR (:newest.field1);
END;
/

OBJECT_VALUE Pseudocolumn

A DML trigger on an object table can reference the SQL pseudocolumn OBJECT_VALUE, which returns system-generated names for the columns of the object table. The trigger can also invoke a PL/SQL subprogram that has a formal IN parameter whose data type is OBJECT_VALUE.


See Also:


Example 9-18 creates object table tbl, table tbl_history for logging updates to tbl, and trigger Tbl_Trg. The trigger runs for each row of tb1 that is affected by a DML statement, causing the old and new values of the object t in tbl to be written in tbl_history. The old and new values are :OLD.OBJECT_VALUE and :NEW.OBJECT_VALUE.

Example 9-18 Trigger References OBJECT_VALUE Pseudocolumn

Create, populate, and show object table:

CREATE OR REPLACE TYPE t AUTHID DEFINER AS OBJECT (n NUMBER, m NUMBER)
/
CREATE TABLE tbl OF t
/
BEGIN
  FOR j IN 1..5 LOOP
    INSERT INTO tbl VALUES (t(j, 0));
  END LOOP;
END;
/
SELECT * FROM tbl ORDER BY n;

Result:

         N          M
---------- ----------
         1          0
         2          0
         3          0
         4          0
         5          0

5 rows selected.

Create history table and trigger:

CREATE TABLE tbl_history ( d DATE, old_obj t, new_obj t)
/
CREATE OR REPLACE TRIGGER Tbl_Trg
  AFTER UPDATE ON tbl
  FOR EACH ROW
BEGIN
  INSERT INTO tbl_history (d, old_obj, new_obj)
  VALUES (SYSDATE, :OLD.OBJECT_VALUE, :NEW.OBJECT_VALUE);
END Tbl_Trg;
/
 

Update object table:

UPDATE tbl SET tbl.n = tbl.n+1
/
 

Result:

5 rows updated.

Show old and new values:

BEGIN
  FOR j IN (SELECT d, old_obj, new_obj FROM tbl_history) LOOP
    DBMS_OUTPUT.PUT_LINE (
      j.d ||
      ' -- old: ' || j.old_obj.n || ' ' || j.old_obj.m ||
      ' -- new: ' || j.new_obj.n || ' ' || j.new_obj.m
    );
  END LOOP;
END;
/

Result:

28-APR-10 -- old: 1 0 -- new: 2 0
28-APR-10 -- old: 2 0 -- new: 3 0
28-APR-10 -- old: 3 0 -- new: 4 0
28-APR-10 -- old: 4 0 -- new: 5 0
28-APR-10 -- old: 5 0 -- new: 6 0

All values of column n were increased by 1. The value of m remains 0.

System Triggers

A system trigger is created on either a schema or the database. Its triggering event is composed of either DDL statements (listed in "ddl_event") or database operation statements (listed in "database_event").

A system trigger fires at exactly one of these timing points:

  • Before the triggering statement runs

    (The trigger is called a BEFORE statement trigger or statement-level BEFORE trigger.)

  • After the triggering statement runs

    (The trigger is called a AFTER statement trigger or statement-level AFTER trigger.)

  • Instead of the triggering CREATE statement

    (The trigger is called an INSTEAD OF CREATE trigger.)

Topics

SCHEMA Triggers

A SCHEMA trigger is created on a schema and fires whenever the user who owns it is the current user and initiates the triggering event.

Suppose that both user1 and user2 own schema triggers, and user1 invokes a DR unit owned by user2. Inside the DR unit, user2 is the current user. Therefore, if the DR unit initiates the triggering event of a schema trigger that user2 owns, then that trigger fires. However, if the DR unit initiates the triggering event of a schema trigger that user1 owns, then that trigger does not fire.

Example 9-19 creates a BEFORE statement trigger on the sample schema HR. When a user connected as HR tries to drop a database object, the database fires the trigger before dropping the object.

Example 9-19 BEFORE Statement Trigger on Sample Schema HR

CREATE OR REPLACE TRIGGER drop_trigger
  BEFORE DROP ON hr.SCHEMA
  BEGIN
    RAISE_APPLICATION_ERROR (
      num => -20000,
      msg => 'Cannot drop object');
  END;
/

DATABASE Triggers

A DATABASE trigger is created on the database and fires whenever any database user initiates the triggering event.

Example 9-20 shows the basic syntax for a trigger to log errors. This trigger fires after an unsuccessful statement execution, such as unsuccessful logon.


Note:

An AFTER SERVERERROR trigger fires only if Oracle relational database management system (RDBMS) determines that it is safe to fire error triggers. For more information about AFTER SERVERERROR triggers, see "AFTER SERVERERROR".

Example 9-20 AFTER Statement Trigger on Database

CREATE TRIGGER log_errors
  AFTER SERVERERROR ON DATABASE
  BEGIN
    IF (IS_SERVERERROR (1017)) THEN
      NULL;  -- (substitute code that processes logon error)
    ELSE
      NULL;  -- (substitute code that logs error code)
    END IF;
  END;
/

The trigger in Example 9-21 runs the procedure check_user after a user logs onto the database.

Example 9-21 Trigger Monitors Logons

CREATE OR REPLACE TRIGGER check_user
  AFTER LOGON ON DATABASE
  BEGIN
    check_user;
  EXCEPTION
    WHEN OTHERS THEN
      RAISE_APPLICATION_ERROR
        (-20000, 'Unexpected error: '|| DBMS_Utility.Format_Error_Stack);
 END;
/

INSTEAD OF CREATE Triggers

An INSTEAD OF CREATE trigger is a SCHEMA trigger whose triggering event is a CREATE statement. The database fires the trigger instead of executing its triggering statement.

Example 9-22 shows the basic syntax for an INSTEAD OF CREATE trigger on the current schema. This trigger fires when the owner of the current schema issues a CREATE statement in the current schema.

Example 9-22 INSTEAD OF CREATE Trigger on Schema

CREATE OR REPLACE TRIGGER t
  INSTEAD OF CREATE ON SCHEMA
  BEGIN
    EXECUTE IMMEDIATE 'CREATE TABLE T (n NUMBER, m NUMBER)';
  END;
/

Subprograms Invoked by Triggers

Triggers can invoke subprograms written in PL/SQL, C, and Java. The trigger in Example 9-4 invokes a PL/SQL subprogram. The trigger in Example 9-23 invokes a Java subprogram.

Example 9-23 Trigger Invokes Java Subprogram

CREATE OR REPLACE PROCEDURE Before_delete (Id IN NUMBER, Ename VARCHAR2)
IS LANGUAGE Java
name 'thjvTriggers.beforeDelete (oracle.sql.NUMBER, oracle.sql.CHAR)';

CREATE OR REPLACE TRIGGER Pre_del_trigger BEFORE DELETE ON Tab 
FOR EACH ROW
CALL Before_delete (:OLD.Id, :OLD.Ename)
/

The corresponding Java file is thjvTriggers.java:

import java.sql.*
import java.io.*
import oracle.sql.*
import oracle.oracore.*
public class thjvTriggers
{
public static void
beforeDelete (NUMBER old_id, CHAR old_name)
Throws SQLException, CoreException
   {
   Connection conn = JDBCConnection.defaultConnection();
   Statement stmt = conn.CreateStatement();
   String sql = "insert into logtab values
   ("+ old_id.intValue() +", '"+ old_ename.toString() + ", BEFORE DELETE');
   stmt.executeUpdate (sql);
   stmt.close();
   return;
   }
}

A subprogram invoked by a trigger cannot run transaction control statements, because the subprogram runs in the context of the trigger body.

If a trigger invokes an invoker rights (IR) subprogram, then the user who created the trigger, not the user who ran the triggering statement, is considered to be the current user. For information about IR subprograms, see "Invoker's Rights and Definer's Rights (AUTHID Property)".

If a trigger invokes a remote subprogram, and a time stamp or signature mismatch is found during execution of the trigger, then the remote subprogram does not run and the trigger is invalidated.

Trigger Compilation, Invalidation, and Recompilation

The CREATE TRIGGER statement compiles the trigger and stores its code in the database. If a compilation error occurs, the trigger is still created, but its triggering statement fails, except in these cases:

  • The trigger was created in the disabled state.

  • The triggering event is AFTER STARTUP ON DATABASE.

  • The triggering event is either AFTER LOGON ON DATABASE or AFTER LOGON ON SCHEMA, and someone logs on as SYSTEM.

To see trigger compilation errors, either use the SHOW ERRORS command in SQL*Plus or Enterprise Manager, or query the static data dictionary view *_ERRORS (described in Oracle Database Reference).

If a trigger does not compile successfully, then its exception handler cannot run. For an example, see "Remote Exception Handling".

If a trigger references another object, such as a subprogram or package, and that object is modified or dropped, then the trigger becomes invalid. The next time the triggering event occurs, the compiler tries to revalidate the trigger (for details, see Oracle Database Development Guide).


Note:

Because the DBMS_AQ package is used to enqueue a message, dependency between triggers and queues cannot be maintained.

To recompile a trigger manually, use the ALTER TRIGGER statement, described in "ALTER TRIGGER Statement".

Exception Handling in Triggers

In most cases, if a trigger runs a statement that raises an exception, and the exception is not handled by an exception handler, then the database rolls back the effects of both the trigger and its triggering statement.

In the following cases, the database rolls back only the effects of the trigger, not the effects of the triggering statement (and logs the error in trace files and the alert log):

  • The triggering event is either AFTER STARTUP ON DATABASE or BEFORE SHUTDOWN ON DATABASE.

  • The triggering event is AFTER LOGON ON DATABASE and the user has the ADMINISTER DATABASE TRIGGER privilege.

  • The triggering event is AFTER LOGON ON SCHEMA and the user either owns the schema or has the ALTER ANY TRIGGER privilege.

In the case of a compound DML trigger, the database rolls back only the effects of the triggering statement, not the effects of the trigger. However, variables declared in the trigger are re-initialized, and any values computed before the triggering statement was rolled back are lost.


Note:

Triggers that enforce complex security authorizations or constraints typically raise user-defined exceptions, which are explained in "User-Defined Exceptions".


See Also:

Chapter 11, "PL/SQL Error Handling," for general information about exception handling

Remote Exception Handling

A trigger that accesses a remote database can do remote exception handling only if the remote database is available. If the remote database is unavailable when the local database must compile the trigger, then the local database cannot validate the statement that accesses the remote database, and the compilation fails. If the trigger cannot be compiled, then its exception handler cannot run.

The trigger in Example 9-24 has an INSERT statement that accesses a remote database. The trigger also has an exception handler. However, if the remote database is unavailable when the local database tries to compile the trigger, then the compilation fails and the exception handler cannot run.

Example 9-24 Trigger Cannot Handle Exception if Remote Database is Unavailable

CREATE OR REPLACE TRIGGER employees_tr
  AFTER INSERT ON employees
  FOR EACH ROW
BEGIN
  -- When remote database is unavailable, compilation fails here:
  INSERT INTO employees@remote (
    employee_id, first_name, last_name, email, hire_date, job_id
  ) 
  VALUES (
    99, 'Jane', 'Doe', 'jane.doe@example.com', SYSDATE, 'ST_MAN'
  );
EXCEPTION
  WHEN OTHERS THEN
    INSERT INTO emp_log (Emp_id, Log_date, New_salary, Action)
      VALUES (99, SYSDATE, NULL, 'Could not insert');
    RAISE;
END;
/

Example 9-25 shows the workaround for the problem in Example 9-24: Put the remote INSERT statement and exception handler in a stored subprogram and have the trigger invoke the stored subprogram. The subprogram is stored in the local database in compiled form, with a validated statement for accessing the remote database. Therefore, when the remote INSERT statement fails because the remote database is unavailable, the exception handler in the subprogram can handle it.

Example 9-25 Workaround for Example 9-24

CREATE OR REPLACE PROCEDURE insert_row_proc AUTHID CURRENT_USER AS
  no_remote_db EXCEPTION;  -- declare exception
  PRAGMA EXCEPTION_INIT (no_remote_db, -20000);
                           -- assign error code to exception
BEGIN
  INSERT INTO employees@remote (
    employee_id, first_name, last_name, email, hire_date, job_id
  ) 
  VALUES (
    99, 'Jane', 'Doe', 'jane.doe@example.com', SYSDATE, 'ST_MAN'
  );
EXCEPTION
  WHEN OTHERS THEN
    INSERT INTO emp_log (Emp_id, Log_date, New_salary, Action)
      VALUES (99, SYSDATE, NULL, 'Could not insert row.');
 
  RAISE_APPLICATION_ERROR (-20000, 'Remote database is unavailable.');
END;
/
 
CREATE OR REPLACE TRIGGER employees_tr
  AFTER INSERT ON employees
  FOR EACH ROW
BEGIN
  insert_row_proc;
END;
/

Trigger Design Guidelines

  • Use triggers to ensure that whenever a specific event occurs, any necessary actions are done (regardless of which user or application issues the triggering statement).

    For example, use a trigger to ensure that whenever anyone updates a table, its log file is updated.

  • Do not create triggers that duplicate database features.

    For example, do not create a trigger to reject invalid data if you can do the same with constraints (see "How Triggers and Constraints Differ").

  • Do not create triggers that depend on the order in which a SQL statement processes rows (which can vary).

    For example, do not assign a value to a global package variable in a row trigger if the current value of the variable depends on the row being processed by the row trigger. If a trigger updates global package variables, initialize those variables in a BEFORE statement trigger.

  • Use BEFORE row triggers to modify the row before writing the row data to disk.

  • Use AFTER row triggers to obtain the row ID and use it in operations.

    An AFTER row trigger fires when the triggering statement results in ORA-02292.


    Note:

    AFTER row triggers are slightly more efficient than BEFORE row triggers. With BEFORE row triggers, affected data blocks are read first for the trigger and then for the triggering statement. With AFTER row triggers, affected data blocks are read only for the trigger.

  • If the triggering statement of a BEFORE statement trigger is an UPDATE or DELETE statement that conflicts with an UPDATE statement that is running, then the database does a transparent ROLLBACK to SAVEPOINT and restarts the triggering statement. The database can do this many times before the triggering statement completes successfully. Each time the database restarts the triggering statement, the trigger fires. The ROLLBACK to SAVEPOINT does not undo changes to package variables that the trigger references. To detect this situation, include a counter variable in the package.

  • Do not create recursive triggers.

    For example, do not create an AFTER UPDATE trigger that issues an UPDATE statement on the table on which the trigger is defined. The trigger fires recursively until it runs out of memory.

  • If you create a trigger that includes a statement that accesses a remote database, then put the exception handler for that statement in a stored subprogram and invoke the subprogram from the trigger.

    For more information, see "Remote Exception Handling".

  • Use DATABASE triggers judiciously. They fire every time any database user initiates a triggering event.

  • If a trigger runs the following statement, the statement returns the owner of the trigger, not the user who is updating the table:

    SELECT Username FROM USER_USERS;
    
  • Only committed triggers fire.

    A trigger is committed, implicitly, after the CREATE TRIGGER statement that creates it succeeds. Therefore, the following statement cannot fire the trigger that it creates:

    CREATE OR REPLACE TRIGGER my_trigger
      AFTER CREATE ON DATABASE
    BEGIN
      NULL;
    END;
    /
    
  • To allow the modular installation of applications that have triggers on the same tables, create multiple triggers of the same type, rather than a single trigger that runs a sequence of operations.

    Each trigger sees the changes made by the previously fired triggers. Each trigger can see OLD and NEW values.

Trigger Restrictions

In addition to the restrictions that apply to all PL/SQL units (see Table C-1), triggers have these restrictions:

Trigger Size Restriction

The size of the trigger cannot exceed 32K.

If the logic for your trigger requires much more than 60 lines of PL/SQL source text, then put most of the source text in a stored subprogram and invoke the subprogram from the trigger. For information about subprograms invoked by triggers, see "Subprograms Invoked by Triggers".

Trigger LONG and LONG RAW Data Type Restrictions


Note:

Oracle supports the LONG and LONG RAW data types only for backward compatibility with existing applications.

In addition to the restrictions that apply to all PL/SQL units (see "LONG and LONG RAW Variables"), triggers have these restrictions:

  • A trigger cannot declare a variable of the LONG or LONG RAW data type.

  • A SQL statement in a trigger can reference a LONG or LONG RAW column only if the column data can be converted to the data type CHAR or VARCHAR2.

  • A trigger cannot use the correlation name NEW or PARENT with a LONG or LONG RAW column.

Mutating-Table Restriction


Note:

This topic applies only to row-level simple DML triggers.

A mutating table is a table that is being modified by a DML statement (possibly by the effects of a DELETE CASCADE constraint). (A view being modified by an INSTEAD OF trigger is not considered to be mutating.)

The mutating-table restriction prevents the trigger from querying or modifying the table that the triggering statement is modifying. When a row-level trigger encounters a mutating table, ORA-04091 occurs, the effects of the trigger and triggering statement are rolled back, and control returns to the user or application that issued the triggering statement, as Example 9-26 shows.


Caution:

Oracle Database does not enforce the mutating-table restriction for a trigger that accesses remote nodes, because the database does not support declarative referential constraints between tables on different nodes of a distributed database.

Similarly, the database does not enforce the mutating-table restriction for tables in the same database that are connected by loop-back database links. A loop-back database link makes a local table appear remote by defining an Oracle Net path back to the database that contains the link.


Example 9-26 Trigger Causes Mutating-Table Error

-- Create log table
 
DROP TABLE log;
CREATE TABLE log (
  emp_id  NUMBER(6),
  l_name  VARCHAR2(25),
  f_name  VARCHAR2(20)
);
 
-- Create trigger that updates log and then reads employees
 
CREATE OR REPLACE TRIGGER log_deletions
  AFTER DELETE ON employees
  FOR EACH ROW
DECLARE
  n INTEGER;
BEGIN
  INSERT INTO log VALUES (
    :OLD.employee_id,
    :OLD.last_name,
    :OLD.first_name
  );
 
  SELECT COUNT(*) INTO n FROM employees;
  DBMS_OUTPUT.PUT_LINE('There are now ' || n || ' employees.');
END;
/
 
-- Issue triggering statement:
 
DELETE FROM employees WHERE employee_id = 197;

Result:

DELETE FROM employees WHERE employee_id = 197
            *
ERROR at line 1:
ORA-04091: table HR.EMPLOYEES is mutating, trigger/function might not see it
ORA-06512: at "HR.LOG_DELETIONS", line 10
ORA-04088: error during execution of trigger 'HR.LOG_DELETIONS'

Show that effect of trigger was rolled back:

SELECT count(*) FROM log;

Result:

  COUNT(*)
----------
         0
 
1 row selected.

Show that effect of triggering statement was rolled back:

SELECT employee_id, last_name FROM employees WHERE employee_id = 197;

Result:

EMPLOYEE_ID LAST_NAME
----------- -------------------------
        197 Feeney
 
1 row selected.

If you must use a trigger to update a mutating table, you can avoid the mutating-table error in either of these ways:

  • Use a compound DML trigger (see "Using Compound DML Triggers to Avoid Mutating-Table Error").

  • Use a temporary table.

    For example, instead of using one AFTER each row trigger that updates the mutating table, use two triggers—an AFTER each row trigger that updates the temporary table and an AFTER statement trigger that updates the mutating table with the values from the temporary table.

Mutating-Table Restriction Relaxed

As of Oracle Database 8g Release 1, a deletion from the parent table causes BEFORE and AFTER triggers to fire once. Therefore, you can create row-level and statement-level triggers that query and modify the parent and child tables. This allows most foreign key constraint actions to be implemented through their after-row triggers (unless the constraint is self-referential). Update cascade, update set null, update set default, delete set default, inserting a missing parent, and maintaining a count of children can all be implemented easily—see "Triggers for Ensuring Referential Integrity".

However, cascades require care for multiple-row foreign key updates. The trigger cannot miss rows that were changed but not committed by another transaction, because the foreign key constraint guarantees that no matching foreign key rows are locked before the after-row trigger is invoked.

In Example 9-27, the triggering statement updates p correctly but causes problems when the trigger updates f. First, the triggering statement changes (1) to (2) in p, and the trigger updates (1) to (2) in f, leaving two rows of value (2) in f. Next, the triggering statement updates (2) to (3) in p, and the trigger updates both rows of value (2) to (3) in f. Finally, the statement updates (3) to (4) in p, and the trigger updates all three rows in f from (3) to (4). The relationship between the data items in p and f is lost.

Example 9-27 Update Cascade

DROP TABLE p;
CREATE TABLE p (p1 NUMBER CONSTRAINT pk_p_p1 PRIMARY KEY);
INSERT INTO p VALUES (1);
INSERT INTO p VALUES (2);
INSERT INTO p VALUES (3);
 
DROP TABLE f;
CREATE TABLE f (f1 NUMBER CONSTRAINT fk_f_f1 REFERENCES p);
INSERT INTO f VALUES (1);
INSERT INTO f VALUES (2);
INSERT INTO f VALUES (3);
 
CREATE TRIGGER pt
  AFTER UPDATE ON p
  FOR EACH ROW
BEGIN
  UPDATE f SET f1 = :NEW.p1 WHERE f1 = :OLD.p1;
END;
/
 

Query:

SELECT * FROM p ORDER BY p1;
 

Result:

        P1
----------
         1
         2
         3

Query:

SELECT * FROM f ORDER BY f1;
 

Result:

        F1
----------
         1
         2
         3

Issue triggering statement:

UPDATE p SET p1 = p1+1;
 

Query:

SELECT * FROM p ORDER BY p1;
 

Result:

        P1
----------
         2
         3
         4

Query:

SELECT * FROM f ORDER BY f1;
 

Result:

        F1
----------
         4
         4
         4

To avoid this problem, either forbid multiple-row updates to p that change the primary key and reuse existing primary key values, or track updates to foreign key values and modify the trigger to ensure that no row is updated twice.

Order in Which Triggers Fire

If two or more triggers with different timing points are defined for the same statement on the same table, then they fire in this order:

  1. All BEFORE STATEMENT triggers

  2. All BEFORE EACH ROW triggers

  3. All AFTER EACH ROW triggers

  4. All AFTER STATEMENT triggers

If it is practical, replace the set of individual triggers with different timing points with a single compound trigger that explicitly codes the actions in the order you intend. For information about compound triggers, see "Compound DML Triggers".

If you are creating two or more triggers with the same timing point, and the order in which they fire is important, then you can control their firing order using the FOLLOWS and PRECEDES clauses (see "FOLLOWS | PRECEDES").

If multiple compound triggers are created on a table, then:

  • All BEFORE STATEMENT sections run at the BEFORE STATEMENT timing point, BEFORE EACH ROW sections run at the BEFORE EACH ROW timing point, and so forth.

    If trigger execution order was specified using the FOLLOWS clause, then the FOLLOWS clause determines the order of execution of compound trigger sections. If FOLLOWS is specified for some but not all triggers, then the order of execution of triggers is guaranteed only for those that are related using the FOLLOWS clause.

  • All AFTER STATEMENT sections run at the AFTER STATEMENT timing point, AFTER EACH ROW sections run at the AFTER EACH ROW timing point, and so forth.

    If trigger execution order was specified using the PRECEDES clause, then the PRECEDES clause determines the order of execution of compound trigger sections. If PRECEDES is specified for some but not all triggers, then the order of execution of triggers is guaranteed only for those that are related using the PRECEDES clause.


    Note:

    PRECEDES applies only to reverse crossedition triggers, which are described in Oracle Database Development Guide.

The firing of compound triggers can be interleaved with the firing of simple triggers.

When one trigger causes another trigger to fire, the triggers are said to be cascading. The database allows up to 32 triggers to cascade simultaneously. To limit the number of trigger cascades, use the initialization parameter OPEN_CURSORS (described in Oracle Database Reference), because a cursor opens every time a trigger fires.

Trigger Enabling and Disabling

By default, the CREATE TRIGGER statement creates a trigger in the enabled state. To create a trigger in the disabled state, specify DISABLE. Creating a trigger in the disabled state lets you ensure that it compiles without errors before you enable it.

Some reasons to temporarily disable a trigger are:

  • The trigger refers to an unavailable object.

  • You must do a large data load, and you want it to proceed quickly without firing triggers.

  • You are reloading data.

To enable or disable a single trigger, use this statement:

ALTER TRIGGER [schema.]trigger_name { ENABLE | DISABLE };

To enable or disable all triggers created on a specific table, use this statement:

ALTER TABLE table_name { ENABLE | DISABLE } ALL TRIGGERS;

In both of the preceding statements, schema is the name of the schema containing the trigger, and the default is your schema.


See Also:


Trigger Changing and Debugging

To change a trigger, you must either replace or re-create it. (The ALTER TRIGGER statement only enables, disables, compiles, or renames a trigger.)

To replace a trigger, use the CREATE TRIGGER statement with the OR REPLACE clause.

To re-create a trigger, first drop it with the DROP TRIGGER statement and then create it again with the CREATE TRIGGER statement.

To debug a trigger, you can use the facilities available for stored subprograms. For information about these facilities, see Oracle Database Development Guide.


See Also:


Triggers and Oracle Database Data Transfer Utilities

The Oracle database utilities that transfer data to your database, possibly firing triggers, are:

  • SQL*Loader (sqlldr)

    SQL*Loader loads data from external files into tables of an Oracle database.

    During a SQL*Loader conventional load, INSERT triggers fire.

    Before a SQL*Loader direct load, triggers are disabled.


    See Also:

    Oracle Database Utilities for more information about SQL*Loader

  • Data Pump Import (impdp)

    Data Pump Import (impdp) reads an export dump file set created by Data Pump Export (expdp) and writes it to an Oracle database.

    If a table to be imported does not exist on the target database, or if you specify TABLE_EXISTS_ACTION=REPLACE, then impdp creates and loads the table before creating any triggers, so no triggers fire.

    If a table to be imported exists on the target database, and you specify either TABLE_EXISTS_ACTION=APPEND or TABLE_EXISTS_ACTION=TRUNCATE, then impdp loads rows into the existing table, and INSERT triggers created on the table fire.


    See Also:

    Oracle Database Utilities for more information about Data Pump Import

  • Original Import (imp)

    Original Import (the original Import utility, imp) reads object definitions and table data from dump files created by original Export (the original Export utility, exp) and writes them to the target database.


    Note:

    To import files that original Export created, you must use original Import. In all other cases, Oracle recommends that you use Data Pump Import instead of original Import.

    If a table to be imported does not exist on the target database, then imp creates and loads the table before creating any triggers, so no triggers fire.

    If a table to be imported exists on the target database, then the Import IGNORE parameter determines whether triggers fire during import operations. The IGNORE parameter specifies whether object creation errors are ignored or not, resulting in the following behavior:

    • If IGNORE=n (default), then imp does not change the table and no triggers fire.

    • If IGNORE=y, then imp loads rows into the existing table, and INSERT triggers created on the table fire.


    See Also:


Triggers for Publishing Events

To use a trigger to publish an event, create a trigger that:

By enabling and disabling such triggers, you can turn event notification on and off. For information about enabling and disabling triggers, see "Trigger Enabling and Disabling".

How Triggers Publish Events

When the database detects an event, it fires all enabled triggers that are defined on that event, except:

  • Any trigger that is the target of the triggering event.

    For example, a trigger for all DROP events does not fire when it is dropped itself.

  • Any trigger that was modified, but not committed, in the same transaction as the triggering event.

    For example, if a recursive DDL statement in a system trigger modifies another trigger, then events in the same transaction cannot fire the modified trigger.

When a trigger fires and invokes AQ, AQ publishes the event and passes to the trigger the publication context and specified attributes. The trigger can access the attributes by invoking event attribute functions.

The attributes that a trigger can specify to AQ (by passing them to AQ as IN parameters) and then access with event attribute functions depends on the triggering event, which is either a database event or a client event.


Note:

  • A trigger always behaves like a definer rights (DR) unit. The trigger action of an event runs as the definer of the action (as the definer of the package or function in callouts, or as owner of the trigger in queues). Because the owner of the trigger must have EXECUTE privileges on the underlying queues, packages, or subprograms, this action is consistent. For information about DR units, see "Invoker's Rights and Definer's Rights (AUTHID Property)".

  • The database ignores the return status from callback functions for all events. For example, the database does nothing with the return status from a SHUTDOWN event.


Topics

Event Attribute Functions

By invoking system-defined event attribute functions in Table 9-4, a trigger can retrieve certain attributes of the triggering event. Not all triggers can invoke all event attribute functions—for details, see "Event Attribute Functions for Database Event Triggers" and "Event Attribute Functions for Client Event Triggers".


Note:

  • In earlier releases, you had to access these functions through the SYS package. Now Oracle recommends accessing them with their public synonyms (the names starting with ora_ in the first column of Table 9-4).

  • The function parameter ora_name_list_t is defined in package DBMS_STANDARD as:

    TYPE ora_name_list_t IS TABLE OF VARCHAR2(64);
    

Table 9-4 System-Defined Event Attributes

AttributeReturn Type and ValueExample
ora_client_ip_address

VARCHAR2: IP address of client in LOGON event when underlying protocol is TCP/IP

DECLARE
  v_addr VARCHAR2(11);
BEGIN
  IF (ora_sysevent = 'LOGON') THEN
    v_addr := ora_client_ip_address;
  END IF;
END;
/
ora_database_name

VARCHAR2(50): Database name

DECLARE
  v_db_name VARCHAR2(50);
BEGIN
  v_db_name := ora_database_name;
END;
/
ora_des_encrypted_password

VARCHAR2: DES-encrypted password of user being created or altered

IF (ora_dict_obj_type = 'USER') THEN
  INSERT INTO event_table
  VALUES (ora_des_encrypted_password);
END IF;
ora_dict_obj_name

VARCHAR2(30): Name of dictionary object on which DDL operation occurred

INSERT INTO event_table 
VALUES ('Changed object is ' ||
        ora_dict_obj_name);
ora_dict_obj_name_list (
name_list OUT ora_name_list_t
)

PLS_INTEGER: Number of object names modified in event

OUT parameter: List of object names modified in event

DECLARE
  name_list ora_name_list_t;
  number_modified PLS_INTEGER;
BEGIN
  IF (ora_sysevent='ASSOCIATE STATISTICS') THEN
    number_modified :=
     ora_dict_obj_name_list(name_list);
  END IF;
END;
ora_dict_obj_owner

VARCHAR2(30): Owner of dictionary object on which DDL operation occurred

INSERT INTO event_table
VALUES ('object owner is' || 
        ora_dict_obj_owner);
ora_dict_obj_owner_list (
owner_list OUT ora_name_list_t
)

PLS_INTEGER: Number of owners of objects modified in event

OUT parameter: List of owners of objects modified in event

DECLARE
  owner_list ora_name_list_t;
  number_modified PLS_INTEGER;
BEGIN
  IF (ora_sysevent='ASSOCIATE STATISTICS') THEN
    number_modified :=
      ora_dict_obj_name_list(owner_list);
  END IF;
END;
ora_dict_obj_type

VARCHAR2(20): Type of dictionary object on which DDL operation occurred

INSERT INTO event_table
VALUES ('This object is a ' || 
        ora_dict_obj_type);
ora_grantee (
user_list OUT ora_name_list_t
)

PLS_INTEGER: Number of grantees in grant event

OUT parameter: List of grantees in grant event

DECLARE
  user_list ora_name_list_t;
  number_of_grantees PLS_INTEGER;
BEGIN
  IF (ora_sysevent = 'GRANT') THEN
    number_of_grantees := 
     ora_grantee(user_list);
  END IF;
END;
ora_instance_num

NUMBER: Instance number

IF (ora_instance_num = 1) THEN
  INSERT INTO event_table VALUES ('1');
END IF;
ora_is_alter_column (
column_name IN VARCHAR2
)

BOOLEAN: TRUE if specified column is altered, FALSE otherwise

IF (ora_sysevent = 'ALTER' AND
  ora_dict_obj_type = 'TABLE') THEN 
    alter_column := ora_is_alter_column('C');
END IF;
ora_is_creating_nested_table

BOOLEAN: TRUE if current event is creating nested table, FALSE otherwise

IF (ora_sysevent = 'CREATE' AND
  ora_dict_obj_type = 'TABLE' AND
  ora_is_creating_nested_table) THEN
    INSERT INTO event_table
    VALUES ('A nested table is created');
END IF;
ora_is_drop_column (
column_name IN VARCHAR2
)

BOOLEAN: TRUE if specified column is dropped, FALSE otherwise

IF (ora_sysevent = 'ALTER' AND
  ora_dict_obj_type = 'TABLE') THEN
    drop_column := ora_is_drop_column('C');
END IF;
ora_is_servererror (
error_number IN VARCHAR2
)

BOOLEAN: TRUE if given error is on error stack, FALSE otherwise

IF ora_is_servererror(error_number) THEN
  INSERT INTO event_table
  VALUES ('Server error!!');
END IF;
ora_login_user

VARCHAR2(30): Login user name

SELECT ora_login_user FROM DUAL;
ora_partition_pos

PLS_INTEGER: In INSTEAD OF trigger for CREATE TABLE, position in SQL text where you can insert PARTITION clause

-- Retrieve ora_sql_txt into  sql_text variable
v_n := ora_partition_pos;
v_new_stmt := SUBSTR(sql_text,1,v_n - 1)
              || ' ' || my_partition_clause
              || ' ' || SUBSTR(sql_text, v_n));
ora_privilege_list (
privilege_list OUT ora_name_list_t
)

PLS_INTEGER: Number of privileges in grant or revoke event

OUT parameter: List of privileges granted or revoked in event

DECLARE
  privilege_list ora_name_list_t;
  number_of_privileges PLS_INTEGER;
BEGIN
  IF (ora_sysevent = 'GRANT' OR
      ora_sysevent = 'REVOKE') THEN
    number_of_privileges :=
      ora_privilege_list(privilege_list);
  END IF;
END;
ora_revokee (
user_list OUT ora_name_list_t
)

PLS_INTEGER: Number of revokees in revoke event

OUT parameter: List of revokees in event

DECLARE
  user_list ora_name_list_t;
  number_of_users PLS_INTEGER;
BEGIN
  IF (ora_sysevent = 'REVOKE') THEN
    number_of_users := ora_revokee(user_list);
  END IF;
END;
ora_server_error (
position IN PLS_INTEGER
)

NUMBER: Error code at given position on error stackFoot 1 

INSERT INTO event_table
VALUES ('top stack error ' || 
        ora_server_error(1));
ora_server_error_depth

PLS_INTEGER: Number of error messages on error stack

n := ora_server_error_depth;
-- Use n with functions such as ora_server_error
ora_server_error_msg (
position IN PLS_INTEGER
)

VARCHAR2: Error message at given position on error stackFootref 1

INSERT INTO event_table
VALUES ('top stack error message' ||
        ora_server_error_msg(1));
ora_server_error_num_params (
position IN PLS_INTEGER
)

PLS_INTEGER: Number of strings substituted into error message (using format like %s) at given position on error stackFootref 1

n := ora_server_error_num_params(1);
ora_server_error_param (
position IN PLS_INTEGER,
param IN PLS_INTEGER
)

VARCHAR2: Matching substitution value (%s, %d, and so on) in error message at given position and parameter numberFootref 1

-- Second %s in "Expected %s, found %s":
param := ora_server_error_param(1,2);
ora_sql_txt (
sql_text OUT ora_name_list_t
)

PLS_INTEGER: Number of elements in PL/SQL table

OUT parameter: SQL text of triggering statement (broken into multiple collection elements if statement is long)

CREATE TABLE event_table (col VARCHAR2(2030));

DECLARE
  sql_text ora_name_list_t;
  n PLS_INTEGER;
  v_stmt VARCHAR2(2000);
BEGIN
  n := ora_sql_txt(sql_text);

  FOR i IN 1..n LOOP
    v_stmt := v_stmt || sql_text(i);
  END LOOP;

  INSERT INTO event_table VALUES ('text of
    triggering statement: ' || v_stmt);
END;
ora_sysevent

VARCHAR2(20): Name of triggering event, as given in syntax

INSERT INTO event_table
VALUES (ora_sysevent);
ora_with_grant_option

BOOLEAN: TRUE if privileges are granted with GRANT option, FALSE otherwise

IF (ora_sysevent = 'GRANT' AND
  ora_with_grant_option = TRUE) THEN
    INSERT INTO event_table 
    VALUES ('with grant option');
END IF;
ora_space_error_info (
error_number OUT NUMBER,
error_type OUT VARCHAR2,
object_owner OUT VARCHAR2,
table_space_name OUT VARCHAR2,
object_name OUT VARCHAR2,
sub_object_name OUT VARCHAR2
)

BOOLEAN: TRUE if error is related to out-of-space condition, FALSE otherwise

OUT parameters: Information about object that caused error

IF (ora_space_error_info (
     eno,typ,owner,ts,obj,subobj) = TRUE) THEN
  DBMS_OUTPUT.PUT_LINE('The object '|| obj
     || ' owned by ' || owner ||
     ' has run out of space.');
END IF;

Footnote 1 Position 1 is the top of the stack.

Event Attribute Functions for Database Event Triggers

Table 9-5 summarizes the database event triggers that can invoke event attribute functions. For more information about the triggering events in Table 9-5, see "database_event".

Table 9-5 Database Event Triggers

Triggering EventWhen Trigger FiresWHEN ConditionsRestrictionsTransactionAttribute Functions
AFTER STARTUP

When database is opened.

None allowed

Trigger cannot do database operations.

Starts a separate transaction and commits it after firing the triggers.

ora_sysevent
ora_login_user
ora_instance_num
ora_database_name
BEFORE SHUTDOWN

Just before server starts shutdown of an instance.

This lets the cartridge shutdown completely. For abnormal instance shutdown, this trigger might not fire.

None allowed

Trigger cannot do database operations.

Starts separate transaction and commits it after firing triggers.

ora_sysevent
ora_login_user
ora_instance_num
ora_database_name
AFTER DB_ROLE_CHANGE

When database is opened for first time after role change.

None allowed

None

Starts separate transaction and commits it after firing triggers.

ora_sysevent
ora_login_user
ora_instance_num
ora_database_name
AFTER SERVERERROR

With condition, whenever specified error occurs. Without condition, whenever any error occurs.

Trigger does not fire for errors listed in "database_event".

ERRNO = eno

Depends on error.

Starts separate transaction and commits it after firing triggers.

ora_sysevent
ora_login_user
ora_instance_num
ora_database_name
ora_server_error
ora_is_servererror
ora_space_error_info

Event Attribute Functions for Client Event Triggers

Table 9-6 summarizes the client event triggers that can invoke event attribute functions. For more information about the triggering events in Table 9-6, see "ddl_event" and "database_event".


Note:

If a client event trigger becomes the target of a DDL operation (such as CREATE OR REPLACE TRIGGER), then it cannot fire later during the same transaction.

Table 9-6 Client Event Triggers

Triggering EventWhen Trigger FiresWHEN ConditionsRestrictionsTransactionAttribute Functions
BEFORE ALTER

AFTER ALTER

When catalog object is altered

Simple conditions on type and name of object, UID, and USER

Trigger cannot do DDL operations on object that caused event to be generated.

DDL on other objects is limited to compiling an object, creating a trigger, and creating, altering, and dropping a table.

Fires triggers in current transaction.

ora_sysevent 
ora_login_user
ora_instance_num
ora_database_name
ora_dict_obj_type 
ora_dict_obj_name
ora_dict_obj_owner
ora_des_encrypted_password
 (for ALTER USER events)
ora_is_alter_column
 (for ALTER TABLE events)
ora_is_drop_column
 (for ALTER TABLE events)
BEFORE DROP

AFTER DROP

When catalog object is dropped

Simple conditions on type and name of object, UID, and USER

Trigger cannot do DDL operations on object that caused event to be generated.

DDL on other objects is limited to compiling an object, creating a trigger, and creating, altering, and dropping a table.

Fires triggers in current transaction.

ora_sysevent
ora_login_user
ora_instance_num
ora_database_name
ora_dict_obj_type
ora_dict_obj_name
ora_dict_obj_owner
BEFORE ANALYZE

AFTER ANALYZE

When ANALYZE statement is issued

Simple conditions on type and name of object, UID, and USER

Trigger cannot do DDL operations on object that caused event to be generated.

DDL on other objects is limited to compiling an object, creating a trigger, and creating, altering, and dropping a table.

Fires triggers in current transaction.

ora_sysevent
ora_login_user
ora_instance_num
ora_database_name
ora_dict_obj_name
ora_dict_obj_type
ora_dict_obj_owner
BEFORE ASSOCIATE STATISTICS

AFTER ASSOCIATE STATISTICS

When ASSOCIATE STATISTICS statement is issued

Simple conditions on type and name of object, UID, and USER

Trigger cannot do DDL operations on object that caused event to be generated.

DDL on other objects is limited to compiling an object, creating a trigger, and creating, altering, and dropping a table.

Fires triggers in current transaction.

ora_sysevent
ora_login_user
ora_instance_num
ora_database_name
ora_dict_obj_name
ora_dict_obj_type
ora_dict_obj_owner
ora_dict_obj_name_list
ora_dict_obj_owner_list
BEFORE AUDIT

AFTER AUDIT

BEFORE NOAUDIT

AFTER NOAUDIT

When AUDIT or NOAUDIT statement is issued

Simple conditions on type and name of object, UID, and USER

Trigger cannot do DDL operations on object that caused event to be generated.

DDL on other objects is limited to compiling an object, creating a trigger, and creating, altering, and dropping a table.

Fires triggers in current transaction.

ora_sysevent
ora_login_user
ora_instance_num
ora_database_name
BEFORE COMMENT

AFTER COMMENT

When object is commented

Simple conditions on type and name of object, UID, and USER

Trigger cannot do DDL operations on object that caused event to be generated.

DDL on other objects is limited to compiling an object, creating a trigger, and creating, altering, and dropping a table.

Fires triggers in current transaction.

ora_sysevent
ora_login_user
ora_instance_num
ora_database_name
ora_dict_obj_name
ora_dict_obj_type
ora_dict_obj_owner
BEFORE CREATE

AFTER CREATE

When catalog object is created

Simple conditions on type and name of object, UID, and USER

Trigger cannot do DDL operations on object that caused event to be generated.

DDL on other objects is limited to compiling an object, creating a trigger, and creating, altering, and dropping a table.

Fires triggers in current transaction.

ora_sysevent 
ora_login_user
ora_instance_num
ora_database_name
ora_dict_obj_type 
ora_dict_obj_name
ora_dict_obj_owner
ora_is_creating_nested_table
 (for CREATE TABLE events)
BEFORE DDL

AFTER DDL

When most SQL DDL statements are issued. Not fired for ALTER DATABASE, CREATE CONTROLFILE, CREATE DATABASE, and DDL issued through the PL/SQL subprogram interface, such as creating an advanced queue.

Simple conditions on type and name of object, UID, and USER

Trigger cannot do DDL operations on object that caused event to be generated.

DDL on other objects is limited to compiling an object, creating a trigger, and creating, altering, and dropping a table.

Fires triggers in current transaction.

ora_sysevent
ora_login_user
ora_instance_num
ora_database_name
ora_dict_obj_name
ora_dict_obj_type
ora_dict_obj_owner
BEFORE DISASSOCIATE STATISTICS

AFTER DISASSOCIATE STATISTICS

When DISASSOCIATE STATISTICS statement is issued

Simple conditions on type and name of object, UID, and USER

Trigger cannot do DDL operations on object that caused event to be generated.

DDL on other objects is limited to compiling an object, creating a trigger, and creating, altering, and dropping a table.

Fires triggers in current transaction.

ora_sysevent
ora_login_user
ora_instance_num
ora_database_name
ora_dict_obj_name
ora_dict_obj_type
ora_dict_obj_owner
ora_dict_obj_name_list
ora_dict_obj_owner_list
BEFORE GRANT

AFTER GRANT

When GRANT statement is issued

Simple conditions on type and name of object, UID, and USER

Trigger cannot do DDL operations on object that caused event to be generated.

DDL on other objects is limited to compiling an object, creating a trigger, and creating, altering, and dropping a table.

Fires triggers in current transaction.

ora_sysevent
ora_login_user
ora_instance_num
ora_database_name
ora_dict_obj_name
ora_dict_obj_type
ora_dict_obj_owner
ora_grantee
ora_with_grant_option
ora_privilege_list
BEFORE LOGOFF

At start of user logoff

Simple conditions on UID and USER

DDL on other objects is limited to compiling an object, creating a trigger, and creating, altering, and dropping a table.

Fires triggers in current transaction.

ora_sysevent
ora_login_user
ora_instance_num
ora_database_name
AFTER LOGON

After successful user logon

Simple conditions on UID and USER

DDL on other objects is limited to compiling an object, creating a trigger, and creating, altering, and dropping a table.

Starts separate transaction and commits it after firing triggers.

ora_sysevent
ora_login_user
ora_instance_num
ora_database_name
ora_client_ip_address
BEFORE RENAME

AFTER RENAME

When RENAME statement is issued

Simple conditions on type and name of object, UID, and USER

Trigger cannot do DDL operations on object that caused event to be generated.

DDL on other objects is limited to compiling an object, creating a trigger, and creating, altering, and dropping a table.

Fires triggers in current transaction.

ora_sysevent
ora_login_user
ora_instance_num
ora_database_name
ora_dict_obj_name
ora_dict_obj_owner
ora_dict_obj_type
BEFORE REVOKE

AFTER REVOKE

When REVOKE statement is issued

Simple conditions on type and name of object, UID, and USER

Trigger cannot do DDL operations on object that caused event to be generated.

DDL on other objects is limited to compiling an object, creating a trigger, and creating, altering, and dropping a table.

Fires triggers in current transaction.

ora_sysevent
ora_login_user
ora_instance_num
ora_database_name
ora_dict_obj_name
ora_dict_obj_type
ora_dict_obj_owner
ora_revokee
ora_privilege_list
AFTER SUSPEND

After SQL statement is suspended because of out-of-space condition.

(Trigger must correct condition so statement can be resumed.)

Simple conditions on type and name of object, UID, and USER

Trigger cannot do DDL operations on object that caused event to be generated.

DDL on other objects is limited to compiling an object, creating a trigger, and creating, altering, and dropping a table.

Fires triggers in current transaction.

ora_sysevent
ora_login_user
ora_instance_num
ora_database_name
ora_server_error
ora_is_servererror
ora_space_error_info
BEFORE TRUNCATE

AFTER TRUNCATE

When object is truncated

Simple conditions on type and name of object, UID, and USER

Trigger cannot do DDL operations on object that caused event to be generated.

DDL on other objects is limited to compiling an object, creating a trigger, and creating, altering, and dropping a table.

Fires triggers in current transaction.

ora_sysevent
ora_login_user
ora_instance_num
ora_database_name
ora_dict_obj_name
ora_dict_obj_type
ora_dict_obj_owner

Views for Information About Triggers

The *_TRIGGERS static data dictionary views reveal information about triggers. For information about these views, see Oracle Database Reference.

Example 9-28 creates a trigger and queries the static data dictionary view USER_TRIGGERS twice—first to show its type, triggering event, and the name of the table on which it is created, and then to show its body.


Note:

The query results in Example 9-28 were formatted by these SQL*Plus commands:
COLUMN Trigger_type FORMAT A15
COLUMN Triggering_event FORMAT A16
COLUMN Table_name FORMAT A11
COLUMN Trigger_body FORMAT A50
SET LONG 9999

Example 9-28 Viewing Information About Triggers

CREATE OR REPLACE TRIGGER Emp_count
  AFTER DELETE ON employees
DECLARE
  n  INTEGER;
BEGIN
  SELECT COUNT(*) INTO n FROM employees;
  DBMS_OUTPUT.PUT_LINE('There are now ' || n || ' employees.');
END;
/

COLUMN Trigger_type FORMAT A15
COLUMN Triggering_event FORMAT A16
COLUMN Table_name FORMAT A11
COLUMN Trigger_body FORMAT A50

Query:

SELECT Trigger_type, Triggering_event, Table_name
FROM USER_TRIGGERS
WHERE Trigger_name = 'EMP_COUNT';

Result:

TRIGGER_TYPE    TRIGGERING_EVENT TABLE_NAME
--------------- ---------------- -----------
AFTER STATEMENT DELETE           EMPLOYEES

Query:

SELECT Trigger_body
FROM USER_TRIGGERS
WHERE Trigger_name = 'EMP_COUNT';

Result:

TRIGGER_BODY
--------------------------------------------------
DECLARE
  n  INTEGER;
BEGIN
  SELECT COUNT(*) INTO n FROM employees;
  DBMS_OUTPUT.PUT_LINE('There are now ' || n || '
employees.');
END;
 
 
1 row selected.
PKW3ToQPKwDOEBPS/drop_library.htm  DROP LIBRARY Statement

DROP LIBRARY Statement

The DROP LIBRARY statement drops an external procedure library from the database.

Topics

Prerequisites

You must have the DROP ANY LIBRARY system privilege.

Syntax

drop_library ::=

Description of drop_library.gif follows

Semantics

library_name

Name of the external procedure library being dropped.

Example

Dropping a Library: Example The following statement drops the ext_lib library, which was created in "Creating a Library: Examples":

DROP LIBRARY ext_lib;
PKq PKwDOEBPS/limits.htm*1 PL/SQL Program Limits

C PL/SQL Program Limits

This appendix describes the program limits that are imposed by the PL/SQL language. PL/SQL is based on the programming language Ada. As a result, PL/SQL uses a variant of Descriptive Intermediate Attributed Notation for Ada (DIANA), a tree-structured intermediate language. It is defined using a metanotation called Interface Definition Language (IDL). DIANA is used internally by compilers and other tools.

At compile time, PL/SQL source text is translated into system code. Both the DIANA and system code for a subprogram or package are stored in the database. At run time, they are loaded into the shared memory pool. The DIANA is used to compile dependent subprograms; the system code simply runs.

In the shared memory pool, a package specification, ADT specification, standalone subprogram, or anonymous block is limited to 67108864 (2**26) DIANA nodes which correspond to tokens such as identifiers, keywords, operators, and so on. This allows for ~6,000,000 lines of code unless you exceed limits imposed by the PL/SQL compiler, some of which are given in Table C-1.

Table C-1 PL/SQL Compiler Limits

ItemLimit

bind variables passed to a program unit

32768

exception handlers in a program unit

65536

fields in a record

65536

levels of block nesting

255

levels of record nesting

32

levels of subquery nesting

254

levels of label nesting

98

levels of nested collections

no predefined limit

magnitude of a PLS_INTEGER or BINARY_INTEGER value

-2147483648..2147483647

number of formal parameters in an explicit cursor, function, or procedure

65536

objects referenced by a program unit

65536

precision of a FLOAT value (binary digits)

126

precision of a NUMBER value (decimal digits)

38

precision of a REAL value (binary digits)

63

size of an identifier (characters)

30

size of a string literal (bytes)

32767

size of a CHAR value (bytes)

32767

size of a LONG value (bytes)

32760

size of a LONG RAW value (bytes)

32760

size of a RAW value (bytes)

32767

size of a VARCHAR2 value (bytes)

32767

size of an NCHAR value (bytes)

32767

size of an NVARCHAR2 value (bytes)

32767

size of a BFILE value (bytes)

4G * value of DB_BLOCK_SIZE parameter

size of a BLOB value (bytes)

4G * value of DB_BLOCK_SIZE parameter

size of a CLOB value (bytes)

4G * value of DB_BLOCK_SIZE parameter

size of an NCLOB value (bytes)

4G * value of DB_BLOCK_SIZE parameter

size of a trigger

32 K


To estimate how much memory a program unit requires, you can query the static data dictionary view USER_OBJECT_SIZE. The column PARSED_SIZE returns the size (in bytes) of the "flattened" DIANA. For example:

CREATE OR REPLACE PACKAGE pkg1 AS
  TYPE numset_t IS TABLE OF NUMBER;
  FUNCTION f1(x NUMBER) RETURN numset_t PIPELINED;
END pkg1;
/

CREATE PACKAGE BODY pkg1 AS
  -- FUNCTION f1 returns a collection of elements (1,2,3,... x)
  FUNCTION f1(x NUMBER) RETURN numset_t PIPELINED IS
  BEGIN
    FOR i IN 1..x LOOP
      PIPE ROW(i);
    END LOOP;
    RETURN;
  END f1;
END pkg1;
/

SQL*Plus commands for formatting results of next query:

COLUMN name FORMAT A4
COLUMN type FORMAT A12
COLUMN source_size FORMAT 999
COLUMN parsed_size FORMAT 999
COLUMN code_size FORMAT 999
COLUMN error_size FORMAT 999

Query:

SELECT * FROM user_object_size WHERE name = 'PKG1' ORDER BY type;

Result:

NAME TYPE         SOURCE_SIZE PARSED_SIZE CODE_SIZE ERROR_SIZE
---- ------------ ----------- ----------- --------- ----------
PKG1 PACKAGE              112         498       310          79
PKG1 PACKAGE BODY         233         106       334          0

Unfortunately, you cannot estimate the number of DIANA nodes from the parsed size. Two program units with the same parsed size might require 1500 and 2000 DIANA nodes, respectively because, for example, the second unit contains more complex SQL statements.

When a PL/SQL block, subprogram, package, or schema-level user-defined type exceeds a size limit, you get an error such as PLS-00123: program too large. Typically, this problem occurs with packages or anonymous blocks. With a package, the best solution is to divide it into smaller packages. With an anonymous block, the best solution is to redefine it as a group of subprograms, which can be stored in the database.

For more information about the limits on data types, see Chapter 3, "PL/SQL Data Types."

PKDx/1*1PKwDOEBPS/cover.htm  Cover

Oracle Corporation

PK@t` PKwDOEBPS/subprograms.htm PL/SQL Subprograms

8 PL/SQL Subprograms

A PL/SQL subprogram is a named PL/SQL block that can be invoked repeatedly. If the subprogram has parameters, their values can differ for each invocation.

A subprogram is either a procedure or a function. Typically, you use a procedure to perform an action and a function to compute and return a value.

Topics

Reasons to Use Subprograms

Subprograms support the development and maintenance of reliable, reusable code with the following features:

  • Modularity

    Subprograms let you break a program into manageable, well-defined modules.

  • Easier Application Design

    When designing an application, you can defer the implementation details of the subprograms until you have tested the main program, and then refine them one step at a time. (To define a subprogram without implementation details, use the NULL statement, as in Example 4-35.)

  • Maintainability

    You can change the implementation details of a subprogram without changing its invokers.

  • Packageability

    Subprograms can be grouped into packages, whose advantages are explained in "Reasons to Use Packages".

  • Reusability

    Any number of applications, in many different environments, can use the same package subprogram or standalone subprogram.

  • Better Performance

    Each subprogram is compiled and stored in executable form, which can be invoked repeatedly. Because stored subprograms run in the database server, a single invocation over the network can start a large job. This division of work reduces network traffic and improves response times. Stored subprograms are cached and shared among users, which lowers memory requirements and invocation overhead.

Subprograms are an important component of other maintainability features, such as packages (explained in Chapter 10, "PL/SQL Packages") and Abstract Data Types (explained in "Abstract Data Types").

Nested, Package, and Standalone Subprograms

You can create a subprogram either inside a PL/SQL block (which can be another subprogram), inside a package, or at schema level.

A subprogram created inside a PL/SQL block is a nested subprogram. You can either declare and define it at the same time, or you can declare it first and then define it later in the same block (see "Forward Declaration"). A nested subprogram is stored in the database only if it is nested in a standalone or package subprogram.

A subprogram created inside a package is a package subprogram. You declare it in the package specification and define it in the package body. It is stored in the database until you drop the package. (Packages are described in Chapter 10, "PL/SQL Packages.")

A subprogram created at schema level is a standalone subprogram. You create it with the CREATE FUNCTION or CREATE PROCEDURE statement. It is stored in the database until you drop it with the DROP FUNCTION or DROP PROCEDURE statement. (These statements are described in Chapter 14, "SQL Statements for Stored PL/SQL Units.")

A stored subprogram is either a package subprogram or a standalone subprogram. A stored subprogram is affected by the AUTHID and ACCESSIBLE BY clauses, which can appear in the CREATE FUNCTION, CREATE PROCEDURE, and CREATE PACKAGE statements. The AUTHID clause affects the name resolution and privilege checking of SQL statements that the subprogram issues at run time (for more information, see "Invoker's Rights and Definer's Rights (AUTHID Property)"). The ACCESSIBLE BY clause specifies a white list of PL/SQL units that can access the subprogram.

Subprogram Invocations

A subprogram invocation has this form:

subprogram_name [ ( [ parameter [, parameter]... ] ) ]

If the subprogram has no parameters, or specifies a default value for every parameter, you can either omit the parameter list or specify an empty parameter list.

A procedure invocation is a PL/SQL statement. For example:

raise_salary(employee_id, amount);

A function invocation is an expression. For example:

new_salary := get_salary(employee_id);
IF salary_ok(new_salary, new_title) THEN ...

See Also:

"Subprogram Parameters" for more information about specifying parameters in subprogram invocations

Subprogram Parts

A subprogram begins with a subprogram heading, which specifies its name and (optionally) its parameter list.

Like an anonymous block, a subprogram has these parts:

  • Declarative part (optional)

    This part declares and defines local types, cursors, constants, variables, exceptions, and nested subprograms. These items cease to exist when the subprogram completes execution.

    This part can also specify pragmas (described in "Pragmas").


    Note:

    The declarative part of a subprogram does not begin with the keyword DECLARE, as the declarative part of an anonymous block does.

  • Executable part (required)

    This part contains one or more statements that assign values, control execution, and manipulate data. (Early in the application design process, this part might contain only a NULL statement, as in Example 4-35.)

  • Exception-handling part (optional)

    This part contains code that handles runtime errors.

In Example 8-1, an anonymous block simultaneously declares and defines a procedure and invokes it three times. The third invocation raises the exception that the exception-handling part of the procedure handles.

Example 8-1 Declaring, Defining, and Invoking a Simple PL/SQL Procedure

DECLARE
  first_name employees.first_name%TYPE;
  last_name  employees.last_name%TYPE;
  email      employees.email%TYPE;
  employer   VARCHAR2(8) := 'AcmeCorp';
 
  -- Declare and define procedure
 
  PROCEDURE create_email (  -- Subprogram heading begins
    name1   VARCHAR2,
    name2   VARCHAR2,
    company VARCHAR2
  )                         -- Subprogram heading ends
  IS
                            -- Declarative part begins
    error_message VARCHAR2(30) := 'Email address is too long.';
  BEGIN                     -- Executable part begins
    email := name1 || '.' || name2 || '@' || company;
  EXCEPTION                      -- Exception-handling part begins
    WHEN VALUE_ERROR THEN
      DBMS_OUTPUT.PUT_LINE(error_message);
  END create_email;
 
BEGIN
  first_name := 'John';
  last_name  := 'Doe';
 
  create_email(first_name, last_name, employer);  -- invocation
  DBMS_OUTPUT.PUT_LINE ('With first name first, email is: ' || email);
 
  create_email(last_name, first_name, employer);  -- invocation
  DBMS_OUTPUT.PUT_LINE ('With last name first, email is: ' || email);
 
  first_name := 'Elizabeth';
  last_name  := 'MacDonald';
  create_email(first_name, last_name, employer);  -- invocation
END;
/

Result:

With first name first, email is: John.Doe@AcmeCorp
With last name first, email is: Doe.John@AcmeCorp
Email address is too long.

Topics


See Also:


Additional Parts for Functions

A function has the same structure as a procedure, except that:

  • A function heading must include a RETURN clause, which specifies the data type of the value that the function returns. (A procedure heading cannot have a RETURN clause.)

  • In the executable part of a function, every execution path must lead to a RETURN statement. Otherwise, the PL/SQL compiler issues a compile-time warning. (In a procedure, the RETURN statement is optional and not recommended. For details, see "RETURN Statement".)

  • Only a function heading can include these options:

OptionDescription
DETERMINISTIC optionHelps the optimizer avoid redundant function invocations.
PARALLEL_ENABLE optionEnables the function for parallel execution, making it safe for use in slave sessions of parallel DML evaluations.
PIPELINED optionMakes a table function pipelined, for use as a row source.
RESULT_CACHE optionStores function results in the PL/SQL function result cache (appears only in declaration).
RESULT_CACHE clauseStores function results in the PL/SQL function result cache (appears only in definition).


See Also:


In Example 8-2, an anonymous block simultaneously declares and defines a function and invokes it.

Example 8-2 Declaring, Defining, and Invoking a Simple PL/SQL Function

DECLARE
  -- Declare and define function

  FUNCTION square (original NUMBER)   -- parameter list
    RETURN NUMBER                     -- RETURN clause
  AS
                                      -- Declarative part begins
    original_squared NUMBER;
  BEGIN                               -- Executable part begins
    original_squared := original * original;
    RETURN original_squared;          -- RETURN statement
  END;
BEGIN
  DBMS_OUTPUT.PUT_LINE(square(100));  -- invocation
END;
/

Result:

10000

RETURN Statement

The RETURN statement immediately ends the execution of the subprogram or anonymous block that contains it. A subprogram or anonymous block can contain multiple RETURN statements.

Topics


See Also:

"RETURN Statement" for the syntax of the RETURN statement

RETURN Statement in Function

In a function, every execution path must lead to a RETURN statement and every RETURN statement must specify an expression. The RETURN statement assigns the value of the expression to the function identifier and returns control to the invoker, where execution resumes immediately after the invocation.


Note:

In a pipelined table function, a RETURN statement need not specify an expression. For information about the parts of a pipelined table function, see "Creating Pipelined Table Functions".

In Example 8-3, the anonymous block invokes the same function twice. The first time, the RETURN statement returns control to the inside of the invoking statement. The second time, the RETURN statement returns control to the statement immediately after the invoking statement.

Example 8-3 Execution Resumes After RETURN Statement in Function

DECLARE
  x INTEGER;
 
  FUNCTION f (n INTEGER)
  RETURN INTEGER
  IS
  BEGIN
    RETURN (n*n);
  END;
 
BEGIN
  DBMS_OUTPUT.PUT_LINE (
    'f returns ' || f(2) || '. Execution returns here (1).'
  );
  
  x := f(2);
  DBMS_OUTPUT.PUT_LINE('Execution returns here (2).');
END;
/

Result:

f returns 4. Execution returns here (1).Execution returns here (2).

In Example 8-4, the function has multiple RETURN statements, but if the parameter is not 0 or 1, then no execution path leads to a RETURN statement. The function compiles with warning PLW-05005: subprogram F returns without value at line 11.

Example 8-4 Function Where Not Every Execution Path Leads to RETURN Statement

CREATE OR REPLACE FUNCTION f (n INTEGER)
  RETURN INTEGER
  AUTHID DEFINER
IS
BEGIN
  IF n = 0 THEN
    RETURN 1;
  ELSIF n = 1 THEN
    RETURN n;
  END IF;
END;
/

Example 8-5 is like Example 8-4, except for the addition of the ELSE clause. Every execution path leads to a RETURN statement, and the function compiles without warning PLW-05005.

Example 8-5 Function Where Every Execution Path Leads to RETURN Statement

CREATE OR REPLACE FUNCTION f (n INTEGER)
  RETURN INTEGER
  AUTHID DEFINER
IS
BEGIN
  IF n = 0 THEN
    RETURN 1;
  ELSIF n = 1 THEN
    RETURN n;
  ELSE
    RETURN n*n;
  END IF;
END;
/
BEGIN
  FOR i IN 0 .. 3 LOOP
    DBMS_OUTPUT.PUT_LINE('f(' || i || ') = ' || f(i));
  END LOOP;
END;
/

Result:

f(0) = 1
f(1) = 1
f(2) = 4
f(3) = 9

RETURN Statement in Procedure

In a procedure, the RETURN statement returns control to the invoker, where execution resumes immediately after the invocation. The RETURN statement cannot specify an expression.

In Example 8-6, the RETURN statement returns control to the statement immediately after the invoking statement.

Example 8-6 Execution Resumes After RETURN Statement in Procedure

DECLARE
  PROCEDURE p IS
  BEGIN
    DBMS_OUTPUT.PUT_LINE('Inside p');
    RETURN;
    DBMS_OUTPUT.PUT_LINE('Unreachable statement.');
  END;
BEGIN
  p;
  DBMS_OUTPUT.PUT_LINE('Control returns here.');
END;
/

Result:

Inside p
Control returns here.

RETURN Statement in Anonymous Block

In an anonymous block, the RETURN statement exits its own block and all enclosing blocks. The RETURN statement cannot specify an expression.

In Example 8-7, the RETURN statement exits both the inner and outer block.

Example 8-7 Execution Resumes After RETURN Statement in Anonymous Block

BEGIN
  BEGIN
    DBMS_OUTPUT.PUT_LINE('Inside inner block.');
    RETURN;
    DBMS_OUTPUT.PUT_LINE('Unreachable statement.');
  END;
  DBMS_OUTPUT.PUT_LINE('Inside outer block. Unreachable statement.');
END;
/

Result:

Inside inner block.

Forward Declaration

If nested subprograms in the same PL/SQL block invoke each other, then one requires a forward declaration, because a subprogram must be declared before it can be invoked.

A forward declaration declares a nested subprogram but does not define it. You must define it later in the same block. The forward declaration and the definition must have the same subprogram heading.

In Example 8-8, an anonymous block creates two procedures that invoke each other.

Example 8-8 Nested Subprograms Invoke Each Other

DECLARE
  -- Declare proc1 (forward declaration):
  PROCEDURE proc1(number1 NUMBER);

  -- Declare and define proc2:
  PROCEDURE proc2(number2 NUMBER) IS
  BEGIN
    proc1(number2);
  END;

  -- Define proc 1:
  PROCEDURE proc1(number1 NUMBER) IS
  BEGIN
    proc2 (number1);
  END;

BEGIN
  NULL;
END;
/

Subprogram Parameters

If a subprogram has parameters, their values can differ for each invocation.

Topics

Formal and Actual Subprogram Parameters

If you want a subprogram to have parameters, declare formal parameters in the subprogram heading. In each formal parameter declaration, specify the name and data type of the parameter, and (optionally) its mode and default value. In the execution part of the subprogram, reference the formal parameters by their names.

When invoking the subprogram, specify the actual parameters whose values are to be assigned to the formal parameters. Corresponding actual and formal parameters must have compatible data types.


Note:

You can declare a formal parameter of a constrained subtype, like this:
DECLARE
  SUBTYPE n1 IS NUMBER(1);
  SUBTYPE v1 IS VARCHAR2(1);
 
  PROCEDURE p (n n1, v v1) IS ...

But you cannot include a constraint in a formal parameter declaration, like this:

DECLARE
  PROCEDURE p (n NUMBER(1), v VARCHAR2(1)) IS ...


Tip:

To avoid confusion, use different names for formal and actual parameters.


Note:

  • Actual parameters (including default values of formal parameters) can be evaluated in any order. If a program determines order of evaluation, then at the point where the program does so, its behavior is undefined.

  • You cannot use LOB parameters in a server-to-server remote procedure call (RPC).


In Example 8-9, the procedure has formal parameters emp_id and amount. In the first procedure invocation, the corresponding actual parameters are emp_num and bonus, whose value are 120 and 100, respectively. In the second procedure invocation, the actual parameters are emp_num and merit + bonus, whose value are 120 and 150, respectively.

Example 8-9 Formal Parameters and Actual Parameters

DECLARE
  emp_num NUMBER(6) := 120;
  bonus   NUMBER(6) := 100;
  merit   NUMBER(4) := 50;

  PROCEDURE raise_salary (
    emp_id NUMBER,  -- formal parameter
    amount NUMBER   -- formal parameter
  ) IS
  BEGIN
    UPDATE employees
    SET salary = salary + amount  -- reference to formal parameter
    WHERE employee_id = emp_id;   -- reference to formal parameter
  END raise_salary;

BEGIN
  raise_salary(emp_num, bonus);          -- actual parameters

  /* raise_salary runs this statement:
       UPDATE employees
       SET salary = salary + 100
       WHERE employee_id = 120;       */

  raise_salary(emp_num, merit + bonus);  -- actual parameters

  /* raise_salary runs this statement:
       UPDATE employees
       SET salary = salary + 150
       WHERE employee_id = 120;       */
END;
/

Topics:


See Also:


Formal Parameters of Constrained Subtypes

If the data type of a formal parameter is a constrained subtype, then:

  • If the subtype has the NOT NULL constraint, then the actual parameter inherits it.

  • If the subtype has the base type VARCHAR2, then the actual parameter does not inherit the size of the subtype.

  • If the subtype has a numeric base type, then the actual parameter inherits the range of the subtype, but not the precision or scale.


Note:

In a function, the clause RETURN datatype declares a hidden formal parameter and the statement RETURN value specifies the corresponding actual parameter. Therefore, if datatype is a constrained data type, then the preceding rules apply to value (see Example 8-11).

Example 8-10 shows that an actual subprogram parameter inherits the NOT NULL constraint but not the size of a VARCHAR2 subtype.

Example 8-10 Actual Parameter Inherits Only NOT NULL from Subtype

DECLARE
  SUBTYPE License IS VARCHAR2(7) NOT NULL;
  n  License := 'DLLLDDD';
 
  PROCEDURE p (x License) IS
  BEGIN
    DBMS_OUTPUT.PUT_LINE(x);
  END;
 
BEGIN
  p('1ABC123456789');  -- Succeeds; size is not inherited
  p(NULL);             -- Raises error; NOT NULL is inherited
END;
/

Result:

  p(NULL);             -- Raises error; NOT NULL is inherited
    *
ERROR at line 12:
ORA-06550: line 12, column 5:
PLS-00567: cannot pass NULL to a NOT NULL constrained formal parameter
ORA-06550: line 12, column 3:
PL/SQL: Statement ignored

As Appendix E, "PL/SQL Predefined Data Types" shows, PL/SQL has many predefined data types that are constrained subtypes of other data types. For example, INTEGER is a constrained subtype of NUMBER:

SUBTYPE INTEGER IS NUMBER(38,0);

In Example 8-11, the function has both an INTEGER formal parameter and an INTEGER return type. The anonymous block invokes the function with an actual parameter that is not an integer. Because the actual parameter inherits the range but not the precision and scale of INTEGER, and the actual parameter is in the INTEGER range, the invocation succeeds. For the same reason, the RETURN statement succeeds in returning the noninteger value.

Example 8-11 Actual Parameter and Return Value Inherit Only Range From Subtype

DECLARE
  FUNCTION test (p INTEGER) RETURN INTEGER IS
  BEGIN
    DBMS_OUTPUT.PUT_LINE('p = ' || p);
    RETURN p;
  END test;
 
BEGIN
  DBMS_OUTPUT.PUT_LINE('test(p) = ' || test(0.66));
END;
/

Result:

p = .66
test(p) = .66
 
PL/SQL procedure successfully completed.

In Example 8-12, the function implicitly converts its formal parameter to the constrained subtype INTEGER before returning it.

Example 8-12 Function Implicitly Converts Formal Parameter to Constrained Subtype

DECLARE
  FUNCTION test (p NUMBER) RETURN NUMBER IS
    q INTEGER := p;  -- Implicitly converts p to INTEGER
  BEGIN
    DBMS_OUTPUT.PUT_LINE('p = ' || q);  -- Display q, not p
    RETURN q;                           -- Return q, not p
  END test;
 
BEGIN
  DBMS_OUTPUT.PUT_LINE('test(p) = ' || test(0.66));
END;
/

Result:

p = 1
test(p) = 1
 
PL/SQL procedure successfully completed.

See Also:

"Constrained Subtypes" for general information about constrained subtypes

Subprogram Parameter Passing Methods

The PL/SQL compiler has two ways of passing an actual parameter to a subprogram:

  • By reference

    The compiler passes the subprogram a pointer to the actual parameter. The actual and formal parameters refer to the same memory location.

  • By value

    The compiler assigns the value of the actual parameter to the corresponding formal parameter. The actual and formal parameters refer to different memory locations.

    If necessary, the compiler implicitly converts the data type of the actual parameter to the data type of the formal parameter. For information about implicit data conversion, see Oracle Database SQL Language Reference.


    Tip:

    Avoid implicit data conversion (for the reasons in Oracle Database SQL Language Reference), in either of these ways:
    • Declare the variables that you intend to use as actual parameters with the same data types as their corresponding formal parameters (as in the declaration of variable x in Example 8-13).

    • Explicitly convert actual parameters to the data types of their corresponding formal parameters, using the SQL conversion functions described in Oracle Database SQL Language Reference (as in the third invocation of the procedure in Example 8-13).


In Example 8-13, the procedure p has one parameter, n, which is passed by value. The anonymous block invokes p three times, avoiding implicit conversion twice.

Example 8-13 Avoiding Implicit Conversion of Actual Parameters

CREATE OR REPLACE PROCEDURE p (
  n NUMBER
) AUTHID DEFINER IS
BEGIN
  NULL;
END;
/
DECLARE
  x NUMBER      :=  1;
  y VARCHAR2(1) := '1';
BEGIN
  p(x);             -- No conversion needed
  p(y);             -- z implicitly converted from VARCHAR2 to NUMBER
  p(TO_NUMBER(y));  -- z explicitly converted from VARCHAR2 to NUMBER
END;
/

The method by which the compiler passes a specific actual parameter depends on its mode, as explained in "Subprogram Parameter Modes".

Subprogram Parameter Modes

The mode of a formal parameter determines its behavior.

Table 8-1 summarizes and compares the characteristics of the subprogram parameter modes.

Table 8-1 PL/SQL Subprogram Parameter Modes

INOUTIN OUT

Default mode

Must be specified.

Must be specified.

Passes a value to the subprogram.

Returns a value to the invoker.

Passes an initial value to the subprogram and returns an updated value to the invoker.

Formal parameter acts like a constant: When the subprogram begins, its value is that of either its actual parameter or default value, and the subprogram cannot change this value.

Formal parameter is initialized to the default value of its type. The default value of the type is NULL except for a record type with a non-NULL default value (see Example 8-16).

When the subprogram begins, the formal parameter has its initial value regardless of the value of its actual parameter. Oracle recommends that the subprogram assign a value to the formal parameter.

Formal parameter acts like an initialized variable: When the subprogram begins, its value is that of its actual parameter. Oracle recommends that the subprogram update its value.

Actual parameter can be a constant, initialized variable, literal, or expression.

If the default value of the formal parameter type is NULL, then the actual parameter must be a variable whose data type is not defined as NOT NULL.

Actual parameter must be a variable (typically, it is a string buffer or numeric accumulator).

Actual parameter is passed by reference.

By default, actual parameter is passed by value; if you specify NOCOPY, it might be passed by reference.

By default, actual parameter is passed by value (in both directions); if you specify NOCOPY, it might be passed by reference.



Tip:

Do not use OUT and IN OUT for function parameters. Ideally, a function takes zero or more parameters and returns a single value. A function with IN OUT parameters returns multiple values and has side effects.


Note:

The specifications of many packages and types that Oracle Database supplies declare formal parameters with this notation:
i1 IN VARCHAR2 CHARACTER SET ANY_CS
i2 IN VARCHAR2 CHARACTER SET i1%CHARSET

Do not use this notation when declaring your own formal or actual parameters. It is reserved for Oracle implementation of the supplied packages types.


Regardless of how an OUT or IN OUT parameter is passed:

  • If the subprogram exits successfully, then the value of the actual parameter is the final value assigned to the formal parameter. (The formal parameter is assigned at least one value—the initial value.)

  • If the subprogram ends with an exception, then the value of the actual parameter is undefined.

  • Formal OUT and IN OUT parameters can be returned in any order. In this example, the final values of x and y are undefined:

    CREATE OR REPLACE PROCEDURE p (x OUT INTEGER, y OUT INTEGER) AS
    BEGIN
      x := 17; y := 93;
    END;
    /
    

When an OUT or IN OUT parameter is passed by reference, the actual and formal parameters refer to the same memory location. Therefore, if the subprogram changes the value of the formal parameter, the change shows immediately in the actual parameter (see "Subprogram Parameter Aliasing with Parameters Passed by Reference").

In Example 8-14, the procedure p has two IN parameters, one OUT parameter, and one IN OUT parameter. The OUT and IN OUT parameters are passed by value (the default). The anonymous block invokes p twice, with different actual parameters. Before each invocation, the anonymous block prints the values of the actual parameters. The procedure p prints the initial values of its formal parameters. After each invocation, the anonymous block prints the values of the actual parameters again.

Example 8-14 Parameter Values Before, During, and After Procedure Invocation

CREATE OR REPLACE PROCEDURE p (
  a        PLS_INTEGER,  -- IN by default
  b     IN PLS_INTEGER,
  c    OUT PLS_INTEGER,
  d IN OUT BINARY_FLOAT
) AUTHID DEFINER IS
BEGIN
  -- Print values of parameters:
 
  DBMS_OUTPUT.PUT_LINE('Inside procedure p:');
 
  DBMS_OUTPUT.PUT('IN a = ');
  DBMS_OUTPUT.PUT_LINE(NVL(TO_CHAR(a), 'NULL'));
 
  DBMS_OUTPUT.PUT('IN b = ');
  DBMS_OUTPUT.PUT_LINE(NVL(TO_CHAR(b), 'NULL'));
 
  DBMS_OUTPUT.PUT('OUT c = ');
  DBMS_OUTPUT.PUT_LINE(NVL(TO_CHAR(c), 'NULL'));
 
  DBMS_OUTPUT.PUT_LINE('IN OUT d = ' || TO_CHAR(d));
 
  -- Can reference IN parameters a and b,
  -- but cannot assign values to them.
 
  c := a+10;  -- Assign value to OUT parameter
  d := 10/b;  -- Assign value to IN OUT parameter
END;
/
DECLARE
  aa  CONSTANT PLS_INTEGER := 1;
  bb  PLS_INTEGER  := 2;
  cc  PLS_INTEGER  := 3;
  dd  BINARY_FLOAT := 4;
  ee  PLS_INTEGER;
  ff  BINARY_FLOAT := 5;
BEGIN
  DBMS_OUTPUT.PUT_LINE('Before invoking procedure p:');
 
  DBMS_OUTPUT.PUT('aa = ');
  DBMS_OUTPUT.PUT_LINE(NVL(TO_CHAR(aa), 'NULL'));
 
  DBMS_OUTPUT.PUT('bb = ');
  DBMS_OUTPUT.PUT_LINE(NVL(TO_CHAR(bb), 'NULL'));
 
  DBMS_OUTPUT.PUT('cc = ');
  DBMS_OUTPUT.PUT_LINE(NVL(TO_CHAR(cc), 'NULL'));
 
  DBMS_OUTPUT.PUT_LINE('dd = ' || TO_CHAR(dd));
 
  p (aa, -- constant
     bb, -- initialized variable
     cc, -- initialized variable 
     dd  -- initialized variable
  );
 
  DBMS_OUTPUT.PUT_LINE('After invoking procedure p:');
 
  DBMS_OUTPUT.PUT('aa = ');
  DBMS_OUTPUT.PUT_LINE(NVL(TO_CHAR(aa), 'NULL'));
 
  DBMS_OUTPUT.PUT('bb = ');
  DBMS_OUTPUT.PUT_LINE(NVL(TO_CHAR(bb), 'NULL'));
 
  DBMS_OUTPUT.PUT('cc = ');
  DBMS_OUTPUT.PUT_LINE(NVL(TO_CHAR(cc), 'NULL'));
 
  DBMS_OUTPUT.PUT_LINE('dd = ' || TO_CHAR(dd));
 
  DBMS_OUTPUT.PUT_LINE('Before invoking procedure p:');
 
  DBMS_OUTPUT.PUT('ee = ');
  DBMS_OUTPUT.PUT_LINE(NVL(TO_CHAR(ee), 'NULL'));
 
  DBMS_OUTPUT.PUT_LINE('ff = ' || TO_CHAR(ff));
 
  p (1,        -- literal 
     (bb+3)*4, -- expression 
     ee,       -- uninitialized variable 
     ff        -- initialized variable
   );
 
  DBMS_OUTPUT.PUT_LINE('After invoking procedure p:');
 
  DBMS_OUTPUT.PUT('ee = ');
  DBMS_OUTPUT.PUT_LINE(NVL(TO_CHAR(ee), 'NULL'));
 
  DBMS_OUTPUT.PUT_LINE('ff = ' || TO_CHAR(ff));
END;
/

Result:

Before invoking procedure p:
aa = 1
bb = 2
cc = 3
dd = 4.0E+000
Inside procedure p:
IN a = 1
IN b = 2
OUT c = NULL
IN OUT d = 4.0E+000
After invoking procedure p:
aa = 1
bb = 2
cc = 11
dd = 5.0E+000
Before invoking procedure p:
ee = NULL
ff = 5.0E+000
Inside procedure p:
IN a = 1
IN b = 20
OUT c = NULL
IN OUT d = 5.0E+000
After invoking procedure p:
ee = 11
ff = 5.0E-001
 
PL/SQL procedure successfully completed.

In Example 8-15, the anonymous block invokes procedure p (from Example 8-14) with an actual parameter that causes p to raise the predefined exception ZERO_DIVIDE, which p does not handle. The exception propagates to the anonymous block, which handles ZERO_DIVIDE and shows that the actual parameters for the IN and IN OUT parameters of p have retained the values that they had before the invocation. (Exception propagation is explained in "Exception Propagation".)

Example 8-15 OUT and IN OUT Parameter Values After Unhandled Exception

DECLARE
  j  PLS_INTEGER  := 10;
  k  BINARY_FLOAT := 15;
BEGIN
  DBMS_OUTPUT.PUT_LINE('Before invoking procedure p:');
 
  DBMS_OUTPUT.PUT('j = ');
  DBMS_OUTPUT.PUT_LINE(NVL(TO_CHAR(j), 'NULL'));
 
  DBMS_OUTPUT.PUT_LINE('k = ' || TO_CHAR(k));
 
  p(4, 0, j, k);  -- causes p to exit with exception ZERO_DIVIDE
 
EXCEPTION
  WHEN ZERO_DIVIDE THEN
    DBMS_OUTPUT.PUT_LINE('After invoking procedure p:');
 
    DBMS_OUTPUT.PUT('j = ');
    DBMS_OUTPUT.PUT_LINE(NVL(TO_CHAR(j), 'NULL'));
 
    DBMS_OUTPUT.PUT_LINE('k = ' || TO_CHAR(k));
END;
/

Result:

Before invoking procedure p:
j = 10
k = 1.5E+001
Inside procedure p:
IN a = 4
IN b = 0
OUT c = NULL
IN OUT d = 1.5E+001
After invoking procedure p:
j = 10
k = 1.5E+001
 
PL/SQL procedure successfully completed.

In Example 8-16, the procedure p has three OUT formal parameters: x, of a record type with a non-NULL default value; y, of a record type with no non-NULL default value; and z, which is not a record.

The corresponding actual parameters for x, y, and z are r1, r2, and s, respectively. s is declared with an initial value. However, when p is invoked, the value of s is initialized to NULL. The values of r1 and r2 are initialized to the default values of their record types, 'abcde' and NULL, respectively.

Example 8-16 OUT Formal Parameter of Record Type with Non-NULL Default Value

CREATE OR REPLACE PACKAGE r_types AUTHID DEFINER IS
  TYPE r_type_1 IS RECORD (f VARCHAR2(5) := 'abcde');
  TYPE r_type_2 IS RECORD (f VARCHAR2(5));
END;
/
 
CREATE OR REPLACE PROCEDURE p (
  x OUT r_types.r_type_1,
  y OUT r_types.r_type_2,
  z OUT VARCHAR2) 
AUTHID CURRENT_USER IS
BEGIN
  DBMS_OUTPUT.PUT_LINE('x.f is ' || NVL(x.f,'NULL'));
  DBMS_OUTPUT.PUT_LINE('y.f is ' || NVL(y.f,'NULL'));
  DBMS_OUTPUT.PUT_LINE('z is ' || NVL(z,'NULL'));
END;
/
DECLARE
  r1 r_types.r_type_1;
  r2 r_types.r_type_2;
  s  VARCHAR2(5) := 'fghij';
BEGIN
  p (r1, r2, s);
END;
/

Result:

x.f is abcde
y.f is NULL
z is NULL
 
PL/SQL procedure successfully completed.

Subprogram Parameter Aliasing

Aliasing is having two different names for the same memory location. If a stored item is visible by more than one path, and you can change the item by one path, then you can see the change by all paths.

Subprogram parameter aliasing always occurs when the compiler passes an actual parameter by reference, and can also occur when a subprogram has cursor variable parameters.

Topics

Subprogram Parameter Aliasing with Parameters Passed by Reference

When the compiler passes an actual parameter by reference, the actual and formal parameters refer to the same memory location. Therefore, if the subprogram changes the value of the formal parameter, the change shows immediately in the actual parameter.

The compiler always passes IN parameters by reference, but the resulting aliasing cannot cause problems, because subprograms cannot assign values to IN parameters.

The compiler might pass an OUT or IN OUT parameter by reference, if you specify NOCOPY for that parameter. NOCOPY is only a hint—each time the subprogram is invoked, the compiler decides, silently, whether to obey or ignore NOCOPY. Therefore, aliasing can occur for one invocation but not another, making subprogram results indeterminate. For example:

  • If the actual parameter is a global variable, then an assignment to the formal parameter might show in the global parameter (see Example 8-17).

  • If the same variable is the actual parameter for two formal parameters, then an assignment to either formal parameter might show immediately in both formal parameters (see Example 8-18).

  • If the actual parameter is a package variable, then an assignment to either the formal parameter or the package variable might show immediately in both the formal parameter and the package variable.

  • If the subprogram is exited with an unhandled exception, then an assignment to the formal parameter might show in the actual parameter.


See Also:

"NOCOPY" for the cases in which the compiler always ignores NOCOPY

In Example 8-17, the procedure has an IN OUT NOCOPY formal parameter, to which it assigns the value 'aardvark'. The anonymous block assigns the value 'aardwolf' to a global variable and then passes the global variable to the procedure. If the compiler obeys the NOCOPY hint, then the final value of the global variable is 'aardvark'. If the compiler ignores the NOCOPY hint, then the final value of the global variable is 'aardwolf'.

Example 8-17 Aliasing from Global Variable as Actual Parameter

DECLARE
  TYPE Definition IS RECORD (
    word     VARCHAR2(20),
    meaning  VARCHAR2(200)
  );

  TYPE Dictionary IS VARRAY(2000) OF Definition;

  lexicon  Dictionary := Dictionary();  -- global variable

  PROCEDURE add_entry (
    word_list IN OUT NOCOPY Dictionary  -- formal NOCOPY parameter
  ) IS
  BEGIN
    word_list(1).word := 'aardvark';
  END;

BEGIN
  lexicon.EXTEND;
  lexicon(1).word := 'aardwolf';
  add_entry(lexicon);  -- global variable is actual parameter
  DBMS_OUTPUT.PUT_LINE(lexicon(1).word);
END;
/

Result:

aardvark

In Example 8-18, the procedure has an IN parameter, an IN OUT parameter, and an IN OUT NOCOPY parameter. The anonymous block invokes the procedure, using the same actual parameter, a global variable, for all three formal parameters. The procedure changes the value of the IN OUT parameter before it changes the value of the IN OUT NOCOPY parameter. However, if the compiler obeys the NOCOPY hint, then the latter change shows in the actual parameter immediately. The former change shows in the actual parameter after the procedure is exited successfully and control returns to the anonymous block.

Example 8-18 Aliasing from Same Actual Parameter for Multiple Formal Parameters

DECLARE
  n NUMBER := 10;

  PROCEDURE p (
    n1 IN NUMBER,
    n2 IN OUT NUMBER,
    n3 IN OUT NOCOPY NUMBER
  ) IS
  BEGIN
    n2 := 20;  -- actual parameter is 20 only after procedure succeeds
    DBMS_OUTPUT.put_line(n1);  -- actual parameter value is still 10
    n3 := 30;  -- might change actual parameter immediately
    DBMS_OUTPUT.put_line(n1);  -- actual parameter value is either 10 or 30
  END;

BEGIN
  p(n, n, n);
  DBMS_OUTPUT.put_line(n);
END;
/

Result if the compiler obeys the NOCOPY hint:

10
30
20

Result if the compiler ignores the NOCOPY hint:

10
10
30

Subprogram Parameter Aliasing with Cursor Variable Parameters

Cursor variable parameters are pointers. Therefore, if a subprogram assigns one cursor variable parameter to another, they refer to the same memory location. This aliasing can have unintended results.

In Example 8-19, the procedure has two cursor variable parameters, emp_cv1 and emp_cv2. The procedure opens emp_cv1 and assigns its value (which is a pointer) to emp_cv2. Now emp_cv1 and emp_cv2 refer to the same memory location. When the procedure closes emp_cv1, it also closes emp_cv2. Therefore, when the procedure tries to fetch from emp_cv2, PL/SQL raises an exception.

Example 8-19 Aliasing from Cursor Variable Subprogram Parameters

DECLARE
  TYPE EmpCurTyp IS REF CURSOR;
  c1 EmpCurTyp;
  c2 EmpCurTyp;

  PROCEDURE get_emp_data (
    emp_cv1 IN OUT EmpCurTyp,
    emp_cv2 IN OUT EmpCurTyp
  )
  IS
    emp_rec employees%ROWTYPE;
  BEGIN
    OPEN emp_cv1 FOR SELECT * FROM employees;
    emp_cv2 := emp_cv1;  -- now both variables refer to same location
    FETCH emp_cv1 INTO emp_rec;  -- fetches first row of employees
    FETCH emp_cv1 INTO emp_rec;  -- fetches second row of employees
    FETCH emp_cv2 INTO emp_rec;  -- fetches third row of employees
    CLOSE emp_cv1;  -- closes both variables
    FETCH emp_cv2 INTO emp_rec; -- causes error when get_emp_data is invoked
  END;
BEGIN
  get_emp_data(c1, c2);
END;
/

Result:

DECLARE
*
ERROR at line 1:
ORA-01001: invalid cursor
ORA-06512: at line 19
ORA-06512: at line 22

Default Values for IN Subprogram Parameters

When you declare a formal IN parameter, you can specify a default value for it. A formal parameter with a default value is called an optional parameter, because its corresponding actual parameter is optional in a subprogram invocation. If the actual parameter is omitted, then the invocation assigns the default value to the formal parameter. A formal parameter with no default value is called a required parameter, because its corresponding actual parameter is required in a subprogram invocation.

Omitting an actual parameter does not make the value of the corresponding formal parameter NULL. To make the value of a formal parameter NULL, specify NULL as either the default value or the actual parameter.

In Example 8-20, the procedure has one required parameter and two optional parameters.

Example 8-20 Procedure with Default Parameter Values

DECLARE
  PROCEDURE raise_salary (
    emp_id IN employees.employee_id%TYPE,
    amount IN employees.salary%TYPE := 100,
    extra  IN employees.salary%TYPE := 50
  ) IS
  BEGIN
    UPDATE employees
    SET salary = salary + amount + extra
    WHERE employee_id = emp_id;
  END raise_salary;
 
BEGIN
  raise_salary(120);       -- same as raise_salary(120, 100, 50)
  raise_salary(121, 200);  -- same as raise_salary(121, 200, 50)
END;
/

In Example 8-20, the procedure invocations specify the actual parameters in the same order as their corresponding formal parameters are declared—that is, the invocations use positional notation. Positional notation does not let you omit the second parameter of raise_salary but specify the third; to do that, you must use either named or mixed notation. For more information, see "Positional, Named, and Mixed Notation for Actual Parameters".

The default value of a formal parameter can be any expression whose value can be assigned to the parameter; that is, the value and parameter must have compatible data types. If a subprogram invocation specifies an actual parameter for the formal parameter, then that invocation does not evaluate the default value.

In Example 8-21, the procedure p has a parameter whose default value is an invocation of the function f. The function f increments the value of a global variable. When p is invoked without an actual parameter, p invokes f, and f increments the global variable. When p is invoked with an actual parameter, p does not invoke f, and value of the global variable does not change.

Example 8-21 Function Provides Default Parameter Value

DECLARE
  global PLS_INTEGER := 0;
 
  FUNCTION f RETURN PLS_INTEGER IS
  BEGIN
    DBMS_OUTPUT.PUT_LINE('Inside f.');
    global := global + 1;
    RETURN global * 2;
  END f;
 
  PROCEDURE p (
    x IN PLS_INTEGER := f()
  ) IS
  BEGIN  
    DBMS_OUTPUT.PUT_LINE (
      'Inside p. ' || 
      '  global = ' || global ||
      ', x = ' || x || '.'
    );
    DBMS_OUTPUT.PUT_LINE('--------------------------------');
  END p;
 
  PROCEDURE pre_p IS
  BEGIN
    DBMS_OUTPUT.PUT_LINE (
     'Before invoking p,  global = ' || global || '.'
    );
    DBMS_OUTPUT.PUT_LINE('Invoking p.');
  END pre_p;
 
BEGIN
  pre_p;
  p();     -- default expression is evaluated
 
  pre_p;
  p(100);  -- default expression is not evaluated
 
  pre_p;
  p();     -- default expression is evaluated
END;
/

Result:

Before invoking p,  global = 0.
Invoking p.
Inside f.
Inside p.   global = 1, x = 2.
--------------------------------
Before invoking p,  global = 1.
Invoking p.
Inside p.   global = 1, x = 100.
--------------------------------
Before invoking p,  global = 1.
Invoking p.
Inside f.
Inside p.   global = 2, x = 4.
--------------------------------

Example 8-22 creates a procedure with two required parameters, invokes it, and then adds a third, optional parameter. Because the third parameter is optional, the original invocation remains valid.

Example 8-22 Adding Subprogram Parameter Without Changing Existing Invocations

Create procedure:

CREATE OR REPLACE PROCEDURE print_name (
  first VARCHAR2,
  last VARCHAR2
) AUTHID DEFINER IS
BEGIN
  DBMS_OUTPUT.PUT_LINE(first || ' ' || last);
END print_name;
/

Invoke procedure:

BEGIN
  print_name('John', 'Doe');
END;
/

Result:

John Doe

Add third parameter with default value:

CREATE OR REPLACE PROCEDURE print_name (
  first VARCHAR2,
  last VARCHAR2,
  mi   VARCHAR2 := NULL
) AUTHID DEFINER IS
BEGIN
  IF mi IS NULL THEN
    DBMS_OUTPUT.PUT_LINE(first || ' ' || last);
  ELSE
    DBMS_OUTPUT.PUT_LINE(first || ' ' || mi || '. ' || last);
  END IF;
END print_name;
/

Invoke procedure:

BEGIN
  print_name('John', 'Doe');          -- original invocation
  print_name('John', 'Public', 'Q');  -- new invocation
END;
/

Result:

John Doe
John Q. Public

Positional, Named, and Mixed Notation for Actual Parameters

When invoking a subprogram, you can specify the actual parameters using either positional, named, or mixed notation. Table 8-2 summarizes and compares these notations.

Table 8-2 PL/SQL Actual Parameter Notations

PositionalNamedMixed

Specify the actual parameters in the same order as the formal parameters are declared.

Specify the actual parameters in any order, using this syntax:

formal => actual

formal is the name of the formal parameter and actual is the actual parameter.

Start with positional notation, then use named notation for the remaining parameters.

You can omit trailing optional parameters.

You can omit any optional parameters.

In the positional notation, you can omit trailing optional parameters; in the named notation, you can omit any optional parameters.

Specifying actual parameters in the wrong order can cause problems that are hard to detect, especially if the actual parameters are literals.

There is no wrong order for specifying actual parameters.

In the positional notation, the wrong order can cause problems that are hard to detect, especially if the actual parameters are literals.

Subprogram invocations must change if the formal parameter list changes, unless the list only acquires new trailing optional parameters (as in Example 8-22).

Subprogram invocations must change only if the formal parameter list acquires new required parameters.

Changes to the formal parameter list might require changes in the positional notation.


Recommended when you invoke a subprogram defined or maintained by someone else.

Convenient when you invoke a subprogram that has required parameters followed by optional parameters, and you must specify only a few of the optional parameters.


In Example 8-23, the procedure invocations use different notations, but are equivalent.

Example 8-23 Equivalent Invocations with Different Notations in Anonymous Block

DECLARE
  emp_num NUMBER(6) := 120;
  bonus   NUMBER(6) := 50;

  PROCEDURE raise_salary (
    emp_id NUMBER,
    amount NUMBER
  ) IS
  BEGIN
    UPDATE employees
    SET salary = salary + amount
    WHERE employee_id = emp_id;
  END raise_salary;

BEGIN
  -- Equivalent invocations:

  raise_salary(emp_num, bonus);                      -- positional notation
  raise_salary(amount => bonus, emp_id => emp_num);  -- named notation
  raise_salary(emp_id => emp_num, amount => bonus);  -- named notation
  raise_salary(emp_num, amount => bonus);            -- mixed notation
END;
/

In Example 8-24, the SQL SELECT statements invoke the PL/SQL function compute_bonus, using equivalent invocations with different notations.

Example 8-24 Equivalent Invocations with Different Notations in SELECT Statements

CREATE OR REPLACE FUNCTION compute_bonus (
  emp_id NUMBER,
  bonus NUMBER
) RETURN NUMBER
  AUTHID DEFINER
IS
  emp_sal NUMBER;
BEGIN
  SELECT salary INTO emp_sal
  FROM employees
  WHERE employee_id = emp_id;

  RETURN emp_sal + bonus;
END compute_bonus;
/
SELECT compute_bonus(120, 50) FROM DUAL;                   -- positional
SELECT compute_bonus(bonus => 50, emp_id => 120) FROM DUAL; -- named
SELECT compute_bonus(120, bonus => 50) FROM DUAL;           -- mixed

Subprogram Invocation Resolution

When the PL/SQL compiler encounters a subprogram invocation, it searches for a matching subprogram declaration—first in the current scope and then, if necessary, in successive enclosing scopes.

A declaration and invocation match if their subprogram names and parameter lists match. The parameter lists match if each required formal parameter in the declaration has a corresponding actual parameter in the invocation.

If the compiler finds no matching declaration for an invocation, then it generates a semantic error.

Figure 8-1 shows how the PL/SQL compiler resolves a subprogram invocation.

Figure 8-1 How PL/SQL Compiler Resolves Invocations

Description of Figure 8-1 follows

In Example 8-25, the function balance tries to invoke the enclosing procedure swap, using appropriate actual parameters. However, balance contains two nested procedures named swap, and neither has parameters of the same type as the enclosing procedure swap. Therefore, the invocation causes compilation error PLS-00306.

Example 8-25 Resolving PL/SQL Procedure Names

DECLARE
  PROCEDURE swap (
    n1 NUMBER,
    n2 NUMBER
  )
  IS
    num1 NUMBER;
    num2 NUMBER;

    FUNCTION balance
      (bal NUMBER)
      RETURN NUMBER
    IS
      x NUMBER := 10;

      PROCEDURE swap (
        d1 DATE,
        d2 DATE
      ) IS
      BEGIN
        NULL;
      END;

      PROCEDURE swap (
        b1 BOOLEAN,
        b2 BOOLEAN
      ) IS
      BEGIN
        NULL;
      END;

    BEGIN  -- balance
      swap(num1, num2);
      RETURN x;
    END balance;

  BEGIN  -- enclosing procedure swap
    NULL;
  END swap;

BEGIN  -- anonymous block
  NULL;
END;   -- anonymous block
/

Result:

      swap(num1, num2);
      *
ERROR at line 33:
ORA-06550: line 33, column 7:
PLS-00306: wrong number or types of arguments in call to 'SWAP'
ORA-06550: line 33, column 7:
PL/SQL: Statement ignored

Overloaded Subprograms

PL/SQL lets you overload nested subprograms, package subprograms, and type methods. You can use the same name for several different subprograms if their formal parameters differ in name, number, order, or data type family. (A data type family is a data type and its subtypes. For the data type families of predefined PL/SQL data types, see Appendix E, "PL/SQL Predefined Data Types". For information about user-defined PL/SQL subtypes, see "User-Defined PL/SQL Subtypes".) If formal parameters differ only in name, then you must use named notation to specify the corresponding actual parameters. (For information about named notation, see "Positional, Named, and Mixed Notation for Actual Parameters".)

Example 8-26 defines two subprograms with the same name, initialize. The procedures initialize different types of collections. Because the processing in the procedures is the same, it is logical to give them the same name.

You can put the two initialize procedures in the same block, subprogram, package, or type body. PL/SQL determines which procedure to invoke by checking their formal parameters. The version of initialize that PL/SQL uses depends on whether you invoke the procedure with a date_tab_typ or num_tab_typ parameter.

Example 8-26 Overloaded Subprogram

DECLARE
  TYPE date_tab_typ IS TABLE OF DATE   INDEX BY PLS_INTEGER;
  TYPE num_tab_typ  IS TABLE OF NUMBER INDEX BY PLS_INTEGER;

  hiredate_tab  date_tab_typ;
  sal_tab       num_tab_typ;

  PROCEDURE initialize (tab OUT date_tab_typ, n INTEGER) IS
  BEGIN
    DBMS_OUTPUT.PUT_LINE('Invoked first version');
    FOR i IN 1..n LOOP
      tab(i) := SYSDATE;
    END LOOP;
  END initialize;

  PROCEDURE initialize (tab OUT num_tab_typ, n INTEGER) IS
  BEGIN
    DBMS_OUTPUT.PUT_LINE('Invoked second version');
    FOR i IN 1..n LOOP
      tab(i) := 0.0;
    END LOOP;
  END initialize;

BEGIN
  initialize(hiredate_tab, 50);
  initialize(sal_tab, 100);
END;
/

Result:

Invoked first version
Invoked second version

For an example of an overloaded procedure in a package, see Example 10-9.

Topics

Formal Parameters that Differ Only in Numeric Data Type

You can overload subprograms if their formal parameters differ only in numeric data type. This technique is useful in writing mathematical application programming interfaces (APIs), because several versions of a function can use the same name, and each can accept a different numeric type. For example, a function that accepts BINARY_FLOAT might be faster, while a function that accepts BINARY_DOUBLE might be more precise.

To avoid problems or unexpected results when passing parameters to such overloaded subprograms:

  • Ensure that the expected version of a subprogram is invoked for each set of expected parameters.

    For example, if you have overloaded functions that accept BINARY_FLOAT and BINARY_DOUBLE, which is invoked if you pass a VARCHAR2 literal like '5.0'?

  • Qualify numeric literals and use conversion functions to make clear what the intended parameter types are.

    For example, use literals such as 5.0f (for BINARY_FLOAT), 5.0d (for BINARY_DOUBLE), or conversion functions such as TO_BINARY_FLOAT, TO_BINARY_DOUBLE, and TO_NUMBER.

PL/SQL looks for matching numeric parameters in this order:

  1. PLS_INTEGER (or BINARY_INTEGER, an identical data type)

  2. NUMBER

  3. BINARY_FLOAT

  4. BINARY_DOUBLE

A VARCHAR2 value can match a NUMBER, BINARY_FLOAT, or BINARY_DOUBLE parameter.

PL/SQL uses the first overloaded subprogram that matches the supplied parameters. For example, the SQRT function takes a single parameter. There are overloaded versions that accept a NUMBER, a BINARY_FLOAT, or a BINARY_DOUBLE parameter. If you pass a PLS_INTEGER parameter, the first matching overload is the one with a NUMBER parameter.

The SQRT function that takes a NUMBER parameter is likely to be slowest. To use a faster version, use the TO_BINARY_FLOAT or TO_BINARY_DOUBLE function to convert the parameter to another data type before passing it to the SQRT function.

If PL/SQL must convert a parameter to another data type, it first tries to convert it to a higher data type. For example:

  • The ATAN2 function takes two parameters of the same type. If you pass parameters of different types—for example, one PLS_INTEGER and one BINARY_FLOAT—PL/SQL tries to find a match where both parameters use the higher type. In this case, that is the version of ATAN2 that takes two BINARY_FLOAT parameters; the PLS_INTEGER parameter is converted upwards.

  • A function takes two parameters of different types. One overloaded version takes a PLS_INTEGER and a BINARY_FLOAT parameter. Another overloaded version takes a NUMBER and a BINARY_DOUBLE parameter. If you invoke this function and pass two NUMBER parameters, PL/SQL first finds the overloaded version where the second parameter is BINARY_FLOAT. Because this parameter is a closer match than the BINARY_DOUBLE parameter in the other overload, PL/SQL then looks downward and converts the first NUMBER parameter to PLS_INTEGER.

Subprograms that You Cannot Overload

You cannot overload these subprograms:

  • Standalone subprograms

  • Subprograms whose formal parameters differ only in mode; for example:

    PROCEDURE s (p IN  VARCHAR2) IS ...
    PROCEDURE s (p OUT VARCHAR2) IS ...
    
  • Subprograms whose formal parameters differ only in subtype; for example:

    PROCEDURE s (p INTEGER) IS ...
    PROCEDURE s (p REAL) IS ...
    

    INTEGER and REAL are subtypes of NUMBER, so they belong to the same data type family.

  • Functions that differ only in return value data type, even if the data types are in different families; for example:

    FUNCTION f (p INTEGER) RETURN BOOLEAN IS ...
    FUNCTION f (p INTEGER) RETURN INTEGER IS ...
    

Subprogram Overload Errors

The PL/SQL compiler catches overload errors as soon as it determines that it cannot tell which subprogram was invoked. When subprograms have identical headings, the compiler catches the overload error when you try to compile the subprograms themselves (if they are nested) or when you try to compile the package specification that declares them. Otherwise, the compiler catches the error when you try to compile an ambiguous invocation of a subprogram.

When you try to compile the package specification in Example 8-27, which declares subprograms with identical headings, you get compile-time error PLS-00305.

Example 8-27 Overload Error Causes Compile-Time Error

CREATE OR REPLACE PACKAGE pkg1 AUTHID DEFINER IS
  PROCEDURE s (p VARCHAR2);
  PROCEDURE s (p VARCHAR2);
END pkg1;
/

Although the package specification in Example 8-28 violates the rule that you cannot overload subprograms whose formal parameters differ only in subtype, you can compile it without error.

Example 8-28 Overload Error Compiles Successfully

CREATE OR REPLACE PACKAGE pkg2 AUTHID DEFINER IS
  SUBTYPE t1 IS VARCHAR2(10);
  SUBTYPE t2 IS VARCHAR2(10);
  PROCEDURE s (p t1);
  PROCEDURE s (p t2);
END pkg2;
/

However, when you try to compile an invocation of pkg2.s, as in Example 8-29, you get compile-time error PLS-00307.

Example 8-29 Invoking Subprogram in Example 8-28 Causes Compile-Time Error

CREATE OR REPLACE PROCEDURE p AUTHID DEFINER IS
  a pkg2.t1 := 'a';
BEGIN
  pkg2.s(a);  -- Causes compile-time error PLS-00307
END p;
/

Suppose that you correct the overload error in Example 8-28 by giving the formal parameters of the overloaded subprograms different names, as in Example 8-30.

Example 8-30 Correcting Overload Error in Example 8-28

CREATE OR REPLACE PACKAGE pkg2 AUTHID DEFINER IS
  SUBTYPE t1 IS VARCHAR2(10);
  SUBTYPE t2 IS VARCHAR2(10);
  PROCEDURE s (p1 t1);
  PROCEDURE s (p2 t2);
END pkg2;
/

Now you can compile an invocation of pkg2.s without error if you specify the actual parameter with named notation, as in Example 8-31. (If you specify the actual parameter with positional notation, as in Example 8-29, you still get compile-time error PLS-00307.)

Example 8-31 Invoking Subprogram in Example 8-30

CREATE OR REPLACE PROCEDURE p AUTHID DEFINER IS
  a pkg2.t1 := 'a';
BEGIN
  pkg2.s(p1=>a);  -- Compiles without error
END p;
/

The package specification in Example 8-32 violates no overload rules and compiles without error. However, you can still get compile-time error PLS-00307 when invoking its overloaded procedure, as in the second invocation in Example 8-33.

Example 8-32 Package Specification Without Overload Errors

CREATE OR REPLACE PACKAGE pkg3 AUTHID DEFINER IS
  PROCEDURE s (p1 VARCHAR2);
  PROCEDURE s (p1 VARCHAR2, p2 VARCHAR2 := 'p2');
END pkg3;
/

Example 8-33 Improper Invocation of Properly Overloaded Subprogram

CREATE OR REPLACE PROCEDURE p AUTHID DEFINER IS
  a1 VARCHAR2(10) := 'a1';
  a2 VARCHAR2(10) := 'a2';
BEGIN
  pkg3.s(p1=>a1, p2=>a2);  -- Compiles without error
  pkg3.s(p1=>a1);          -- Causes compile-time error PLS-00307
END p;
/

When trying to determine which subprogram was invoked, if the PL/SQL compiler implicitly converts one parameter to a matching type, then the compiler looks for other parameters that it can implicitly convert to matching types. If there is more than one match, then compile-time error PLS-00307 occurs, as in Example 8-34.

Example 8-34 Implicit Conversion of Parameters Causes Overload Error

CREATE OR REPLACE PACKAGE pack1 AUTHID DEFINER AS
  PROCEDURE proc1 (a NUMBER, b VARCHAR2);
  PROCEDURE proc1 (a NUMBER, b NUMBER);
END;
/
CREATE OR REPLACE PACKAGE BODY pack1 AS
  PROCEDURE proc1 (a NUMBER, b VARCHAR2) IS BEGIN NULL; END;
  PROCEDURE proc1 (a NUMBER, b NUMBER) IS BEGIN NULL; END;
END;
/
BEGIN
  pack1.proc1(1,'2');    -- Compiles without error
  pack1.proc1(1,2);      -- Compiles without error
  pack1.proc1('1','2');  -- Causes compile-time error PLS-00307
  pack1.proc1('1',2);    -- Causes compile-time error PLS-00307
END;
/

Recursive Subprograms

A recursive subprogram invokes itself. Recursion is a powerful technique for simplifying an algorithm.

A recursive subprogram must have at least two execution paths—one leading to the recursive invocation and one leading to a terminating condition. Without the latter, recursion continues until PL/SQL runs out of memory and raises the predefined exception STORAGE_ERROR.

In Example 8-35, the function implements the following recursive definition of n factorial (n!), the product of all integers from 1 to n:

n! = n * (n - 1)!

Example 8-35 Recursive Function Returns n Factorial (n!)

CREATE OR REPLACE FUNCTION factorial (
  n POSITIVE
) RETURN POSITIVE
  AUTHID DEFINER
IS
BEGIN
  IF n = 1 THEN                 -- terminating condition
    RETURN n;
  ELSE
    RETURN n * factorial(n-1);  -- recursive invocation
  END IF;
END;
/
BEGIN
  FOR i IN 1..5 LOOP
    DBMS_OUTPUT.PUT_LINE(i || '! = ' || factorial(i));
  END LOOP;
END;
/

Result:

1! = 1
2! = 2
3! = 6
4! = 24
5! = 120

In Example 8-36, the function returns the nth Fibonacci number, which is the sum of the n-1st and n-2nd Fibonacci numbers. The first and second Fibonacci numbers are zero and one, respectively.

Example 8-36 Recursive Function Returns nth Fibonacci Number

CREATE OR REPLACE FUNCTION fibonacci (
  n PLS_INTEGER
) RETURN PLS_INTEGER
  AUTHID DEFINER
IS
  fib_1 PLS_INTEGER := 0;
  fib_2 PLS_INTEGER := 1;
BEGIN
  IF n = 1 THEN                              -- terminating condition
    RETURN fib_1;
  ELSIF n = 2 THEN
    RETURN fib_2;                           -- terminating condition
  ELSE
    RETURN fibonacci(n-2) + fibonacci(n-1);  -- recursive invocations
  END IF;
END;
/
BEGIN
  FOR i IN 1..10 LOOP
    DBMS_OUTPUT.PUT(fibonacci(i));
    IF i < 10 THEN
      DBMS_OUTPUT.PUT(', ');
    END IF;
  END LOOP;
 
  DBMS_OUTPUT.PUT_LINE(' ...');
END;
/

Result:

0, 1, 1, 2, 3, 5, 8, 13, 21, 34 ...

Note:

The function in Example 8-36 is a good candidate for result caching. For more information, see "Result-Cached Recursive Function".

Each recursive invocation of a subprogram creates an instance of each item that the subprogram declares and each SQL statement that it executes.

A recursive invocation inside a cursor FOR LOOP statement, or between an OPEN or OPEN FOR statement and a CLOSE statement, opens another cursor at each invocation, which might cause the number of open cursors to exceed the limit set by the database initialization parameter OPEN_CURSORS.

Subprogram Side Effects

A subprogram has side effects if it changes anything except the values of its own local variables. For example, a subprogram that changes any of the following has side effects:

  • Its own OUT or IN OUT parameter

  • A global variable

  • A public variable in a package

  • A database table

  • The database

  • The external state (by invoking DBMS_OUTPUT or sending e-mail, for example)

Side effects can prevent the parallelization of a query, yield order-dependent (and therefore, indeterminate) results, or require that package state be maintained across user sessions.

Minimizing side effects is especially important when defining a result-cached function or a stored function for SQL statements to invoke.


See Also:

Oracle Database Development Guide for information about controlling side effects in PL/SQL functions invoked from SQL statements

PL/SQL Function Result Cache

The PL/SQL function result caching mechanism provides a language-supported and system-managed way to cache the results of PL/SQL functions in a shared global area (SGA), which is available to every session that runs your application. The caching mechanism is both efficient and easy to use, and relieves you of the burden of designing and developing your own caches and cache-management policies.

When a result-cached function is invoked, the system checks the cache. If the cache contains the result from a previous invocation of the function with the same parameter values, the system returns the cached result to the invoker and does not re-execute the function body. If the cache does not contain the result, the system runs the function body and adds the result (for these parameter values) to the cache before returning control to the invoker.


Note:

If function execution results in an unhandled exception, the exception result is not stored in the cache.

The cache can accumulate very many results—one result for every unique combination of parameter values with which each result-cached function was invoked. If the system needs more memory, it ages out (deletes) one or more cached results.

Oracle Database automatically detects all data sources (tables and views) that are queried while a result-cached function is running. If changes to any of these data sources are committed, the cached result becomes invalid and must be recomputed. The best candidates for result-caching are functions that are invoked frequently but depend on information that changes infrequently or never.

Topics

Enabling Result-Caching for a Function

To make a function result-cached, include the RESULT_CACHE clause in the function definition. (If you declare the function before defining it, you must also include the RESULT_CACHE option in the function declaration.) For syntax details, see "Function Declaration and Definition".


Note:

The database initialization parameter RESULT_CACHE_MODE does not make a PL/SQL function result-cached. However, when RESULT_CACHE_MODE=FORCE, the database stores the results of all queries in the SQL query result cache, including queries issued by PL/SQL code and queries that call nondeterministic PL/SQL functions.

For information about RESULT_CACHE_MODE, see Oracle Database Reference and Oracle Database Performance Tuning Guide.


In Example 8-37, the package department_pkg declares and then defines a result-cached function, get_dept_info, which returns a record of information about a given department. The function depends on the database tables DEPARTMENTS and EMPLOYEES.

Example 8-37 Declaring and Defining Result-Cached Function

CREATE OR REPLACE PACKAGE department_pkg AUTHID DEFINER IS
 
  TYPE dept_info_record IS RECORD (
    dept_name  departments.department_name%TYPE,
    mgr_name   employees.last_name%TYPE,
    dept_size  PLS_INTEGER
  );
 
  -- Function declaration
 
  FUNCTION get_dept_info (dept_id NUMBER)
    RETURN dept_info_record
    RESULT_CACHE;
 
END department_pkg;
/
CREATE OR REPLACE PACKAGE BODY department_pkg IS
  -- Function definition
  FUNCTION get_dept_info (dept_id NUMBER)
    RETURN dept_info_record
    RESULT_CACHE
  IS
    rec  dept_info_record;
  BEGIN
    SELECT department_name INTO rec.dept_name
    FROM departments
    WHERE department_id = dept_id;
 
    SELECT e.last_name INTO rec.mgr_name
    FROM departments d, employees e
    WHERE d.department_id = dept_id
    AND d.manager_id = e.employee_id;
 
    SELECT COUNT(*) INTO rec.dept_size
    FROM EMPLOYEES
    WHERE department_id = dept_id;
 
    RETURN rec;
  END get_dept_info;
END department_pkg;
/

You invoke the function get_dept_info as you invoke any function. For example, this invocation returns a record of information about department number 10:

department_pkg.get_dept_info(10);

This invocation returns only the name of department number 10:

department_pkg.get_dept_info(10).department_name;

If the result for get_dept_info(10) is in the result cache, the result is returned from the cache; otherwise, the result is computed and added to the cache. Because get_dept_info depends on the DEPARTMENTS and EMPLOYEES tables, any committed change to DEPARTMENTS or EMPLOYEES invalidates all cached results for get_dept_info, relieving you of programming cache invalidation logic everywhere that DEPARTMENTS or EMPLOYEES might change.

Developing Applications with Result-Cached Functions

When developing an application that uses a result-cached function, make no assumptions about the number of times the body of the function will run for a given set of parameter values.

Some situations in which the body of a result-cached function runs are:

  • The first time a session on this database instance invokes the function with these parameter values

  • When the cached result for these parameter values is invalid

    When a change to any data source on which the function depends is committed, the cached result becomes invalid.

  • When the cached results for these parameter values have aged out

    If the system needs memory, it might discard the oldest cached values.

  • When the function bypasses the cache (see "Result Cache Bypass")

Restrictions on Result-Cached Functions

To be result-cached, a function must meet all of these criteria:

  • It is not defined in an anonymous block.

  • It is not a pipelined table function.

  • It does not reference dictionary tables, temporary tables, sequences, or nondeterministic SQL functions.

    For more information, see Oracle Database Performance Tuning Guide.

  • It has no OUT or IN OUT parameters.

  • No IN parameter has one of these types:

    • BLOB

    • CLOB

    • NCLOB

    • REF CURSOR

    • Collection

    • Object

    • Record

  • The return type is none of these:

    • BLOB

    • CLOB

    • NCLOB

    • REF CURSOR

    • Object

    • Record or PL/SQL collection that contains an unsupported return type

It is recommended that a result-cached function also meet these criteria:

Examples of Result-Cached Functions

The best candidates for result-caching are functions that are invoked frequently but depend on information that changes infrequently (as might be the case in the first example). Result-caching avoids redundant computations in recursive functions.

Examples:

Result-Cached Application Configuration Parameters

Consider an application that has configuration parameters that can be set at either the global level, the application level, or the role level. The application stores the configuration information in these tables:

-- Global Configuration Settings
DROP TABLE global_config_params;
CREATE TABLE global_config_params
  (name  VARCHAR2(20), -- parameter NAME
   val   VARCHAR2(20), -- parameter VALUE
   PRIMARY KEY (name)
  );

-- Application-Level Configuration Settings
CREATE TABLE app_level_config_params
  (app_id  VARCHAR2(20), -- application ID
   name    VARCHAR2(20), -- parameter NAME
   val     VARCHAR2(20), -- parameter VALUE
   PRIMARY KEY (app_id, name)
  );

-- Role-Level Configuration Settings
CREATE TABLE role_level_config_params
  (role_id  VARCHAR2(20), -- application (role) ID
   name     VARCHAR2(20),  -- parameter NAME
   val      VARCHAR2(20),  -- parameter VALUE
   PRIMARY KEY (role_id, name)
  );

For each configuration parameter, the role-level setting overrides the application-level setting, which overrides the global setting. To determine which setting applies to a parameter, the application defines the PL/SQL function get_value. Given a parameter name, application ID, and role ID, get_value returns the setting that applies to the parameter.

The function get_value is a good candidate for result-caching if it is invoked frequently and if the configuration information changes infrequently.

Example 8-38 shows a possible definition for get_value. Suppose that for one set of parameter values, the global setting determines the result of get_value. While get_value is running, the database detects that three tables are queried—role_level_config_params, app_level_config_params, and global_config_params. If a change to any of these three tables is committed, the cached result for this set of parameter values is invalidated and must be recomputed.

Now suppose that, for a second set of parameter values, the role-level setting determines the result of get_value. While get_value is running, the database detects that only the role_level_config_params table is queried. If a change to role_level_config_params is committed, the cached result for the second set of parameter values is invalidated; however, committed changes to app_level_config_params or global_config_params do not affect the cached result.

Example 8-38 Result-Cached Function Returns Configuration Parameter Setting

CREATE OR REPLACE FUNCTION get_value
  (p_param VARCHAR2,
   p_app_id  NUMBER,
   p_role_id NUMBER
  )
  RETURN VARCHAR2
  RESULT_CACHE
  AUTHID DEFINER
IS
  answer VARCHAR2(20);
BEGIN
  -- Is parameter set at role level?
  BEGIN
    SELECT val INTO answer
      FROM role_level_config_params
        WHERE role_id = p_role_id
          AND name = p_param;
    RETURN answer;  -- Found
    EXCEPTION
      WHEN no_data_found THEN
        NULL;  -- Fall through to following code
  END;
  -- Is parameter set at application level?
  BEGIN
    SELECT val INTO answer
      FROM app_level_config_params
        WHERE app_id = p_app_id
          AND name = p_param;
    RETURN answer;  -- Found
    EXCEPTION
      WHEN no_data_found THEN
        NULL;  -- Fall through to following code
  END;
  -- Is parameter set at global level?
    SELECT val INTO answer
     FROM global_config_params
      WHERE name = p_param;
    RETURN answer;
END;

Result-Cached Recursive Function

A recursive function for finding the nth term of a Fibonacci series that mirrors the mathematical definition of the series might do many redundant computations. For example, to evaluate fibonacci(7), the function must compute fibonacci(6) and fibonacci(5). To compute fibonacci(6), the function must compute fibonacci(5) and fibonacci(4). Therefore, fibonacci(5) and several other terms are computed redundantly. Result-caching avoids these redundant computations.


Note:

The maximum number of recursive invocations cached is 128.

CREATE OR REPLACE FUNCTION fibonacci (n NUMBER)
  RETURN NUMBER
  RESULT_CACHE
  AUTHID DEFINER
IS
BEGIN
  IF (n =0) OR (n =1) THEN
    RETURN 1;
  ELSE
    RETURN fibonacci(n - 1) + fibonacci(n - 2);
  END IF;
END;
/

Advanced Result-Cached Function Topics

Topics

Rules for a Cache Hit

Each time a result-cached function is invoked with different parameter values, those parameters and their result are stored in the cache. Subsequently, when the same function is invoked with the same parameter values (that is, when there is a cache hit), the result is retrieved from the cache, instead of being recomputed.

The rules for parameter comparison for a cache hit differ from the rules for the PL/SQL "equal to" (=) operator, as follows:

Cache Hit Rules"Equal To" Operator Rules
NULL equals NULLNULL = NULL evaluates to NULL.
Non-null scalars are the same if and only if their values are identical; that is, if and only if their values have identical bit patterns on the given platform. For example, CHAR values 'AA' and 'AA ' are different. (This rule is stricter than the rule for the "equal to" operator.)Non-null scalars can be equal even if their values do not have identical bit patterns on the given platform; for example, CHAR values 'AA' and 'AA ' are equal.

Result Cache Bypass

In some situations, the cache is bypassed. When the cache is bypassed:

  • The function computes the result instead of retrieving it from the cache.

  • The result that the function computes is not added to the cache.

Some examples of situations in which the cache is bypassed are:

  • The cache is unavailable to all sessions.

    For example, the database administrator has disabled the use of the result cache during application patching (as in "Hot-Patching PL/SQL Units on Which Result-Cached Functions Depend").

  • A session is performing a DML statement on a table or view on which a result-cached function depends.

    The session bypasses the result cache for that function until the DML statement is completed—either committed or rolled back. If the statement is rolled back, the session resumes using the cache for that function.

    Cache bypass ensures that:

    • The user of each session sees his or her own uncommitted changes.

    • The PL/SQL function result cache has only committed changes that are visible to all sessions, so that uncommitted changes in one session are not visible to other sessions.

Making Result-Cached Functions Handle Session-Specific Settings

If a function depends on settings that might vary from session to session (such as NLS_DATE_FORMAT and TIME ZONE), make the function result-cached only if you can modify it to handle the various settings.

Consider this function:

Example 8-39 Result-Cached Function Handles Session-Specific Settings

CREATE OR REPLACE FUNCTION get_hire_date (emp_id NUMBER)
  RETURN VARCHAR
  RESULT_CACHE
  AUTHID DEFINER
IS
  date_hired DATE;
BEGIN
  SELECT hire_date INTO date_hired
    FROM HR.EMPLOYEES
      WHERE EMPLOYEE_ID = emp_id;
  RETURN TO_CHAR(date_hired);
END;
/

The preceding function, get_hire_date, uses the TO_CHAR function to convert a DATE item to a VARCHAR item. The function get_hire_date does not specify a format mask, so the format mask defaults to the one that NLS_DATE_FORMAT specifies. If sessions that invoke get_hire_date have different NLS_DATE_FORMAT settings, cached results can have different formats. If a cached result computed by one session ages out, and another session recomputes it, the format might vary even for the same parameter value. If a session gets a cached result whose format differs from its own format, that result is probably incorrect.

Some possible solutions to this problem are:

  • Change the return type of get_hire_date to DATE and have each session invoke the TO_CHAR function.

  • If a common format is acceptable to all sessions, specify a format mask, removing the dependency on NLS_DATE_FORMAT. For example:

    TO_CHAR(date_hired, 'mm/dd/yy');
    
  • Add a format mask parameter to get_hire_date. For example:

    CREATE OR REPLACE FUNCTION get_hire_date (emp_id NUMBER, fmt VARCHAR)
      RETURN VARCHAR
      RESULT_CACHE
      AUTHID DEFINER
    IS
      date_hired DATE;
    BEGIN
      SELECT hire_date INTO date_hired
        FROM HR.EMPLOYEES
          WHERE EMPLOYEE_ID = emp_id;
      RETURN TO_CHAR(date_hired, fmt);
    END;
    /
    

Making Result-Cached Functions Handle Session-Specific Application Contexts

An application context, which can be either global or session-specific, is a set of attributes and their values. A PL/SQL function depends on session-specific application contexts if it does one or more of the following:

  • Directly invokes the SQL function SYS_CONTEXT, which returns the value of a specified attribute in a specified context

  • Indirectly invokes SYS_CONTEXT by using Virtual Private Database (VPD) mechanisms for fine-grained security

    (For information about VPD, see Oracle Database Security Guide.)

The PL/SQL function result-caching feature does not automatically handle dependence on session-specific application contexts. If you must cache the results of a function that depends on session-specific application contexts, you must pass the application context to the function as a parameter. You can give the parameter a default value, so that not every user must specify it.

In Example 8-40, assume that a table, config_tab, has a VPD policy that translates this query:

SELECT value FROM config_tab WHERE name = param_name;

To this query:

SELECT value FROM config_tab
WHERE name = param_name
AND app_id = SYS_CONTEXT('Config', 'App_ID');

Example 8-40 Result-Cached Function Handles Session-Specific Application Context

CREATE OR REPLACE FUNCTION get_param_value (
  param_name VARCHAR,
  appctx     VARCHAR  DEFAULT SYS_CONTEXT('Config', 'App_ID')
) RETURN VARCHAR
  RESULT_CACHE
  AUTHID DEFINER
IS
  rec VARCHAR(2000);
BEGIN
  SELECT val INTO rec
  FROM config_tab
  WHERE name = param_name;
 
  RETURN rec;
END;
/

Choosing Result-Caching Granularity

PL/SQL provides the function result cache, but you choose the caching granularity. To understand the concept of granularity, consider the Product_Descriptions table in the Order Entry (OE) sample schema:

NAME                     NULL?      TYPE
----------------------   --------   ---------------
PRODUCT_ID               NOT NULL   NUMBER(6)
LANGUAGE_ID              NOT NULL   VARCHAR2(3)
TRANSLATED_NAME          NOT NULL   NVARCHAR2(50)
TRANSLATED_DESCRIPTION   NOT NULL   NVARCHAR2(2000)

The table has the name and description of each product in several languages. The unique key for each row is PRODUCT_ID,LANGUAGE_ID.

Suppose that you must define a function that takes a PRODUCT_ID and a LANGUAGE_ID and returns the associated TRANSLATED_NAME. You also want to cache the translated names. Some of the granularity choices for caching the names are:

  • One name at a time (finer granularity)

  • One language at a time (coarser granularity)

Table 8-3 Finer and Coarser Caching Granularity

Finer GranularityCoarser Granularity

Each function result corresponds to one logical result.

Each function result contains many logical subresults.

Stores only data that is needed at least once.

Might store data that is never used.

Each data item ages out individually.

One aged-out data item ages out the whole set.

Does not allow bulk loading optimizations.

Allows bulk loading optimizations.


In Example 8-41 and Example 8-42, the function productName takes a PRODUCT_ID and a LANGUAGE_ID and returns the associated TRANSLATED_NAME. Each version of productName caches translated names, but at a different granularity.

In Example 8-41, get_product_name_1 is a result-cached function. Whenever get_product_name_1 is invoked with a different PRODUCT_ID and LANGUAGE_ID, it caches the associated TRANSLATED_NAME. Each invocation of get_product_name_1 adds at most one TRANSLATED_NAME to the cache.

Example 8-41 Caching One Name at a Time (Finer Granularity)

CREATE OR REPLACE FUNCTION get_product_name_1 (
  prod_id NUMBER,
  lang_id VARCHAR2
)
  RETURN NVARCHAR2
  RESULT_CACHE
  AUTHID DEFINER
IS
  result_ VARCHAR2(50);
BEGIN
  SELECT translated_name INTO result_
  FROM OE.Product_Descriptions
  WHERE PRODUCT_ID = prod_id
  AND LANGUAGE_ID = lang_id;
  RETURN result_;
END;
/

In Example 8-42, get_product_name_2 defines a result-cached function, all_product_names. Whenever get_product_name_2 invokes all_product_names with a different LANGUAGE_ID, all_product_names caches every TRANSLATED_NAME associated with that LANGUAGE_ID. Each invocation of all_product_names adds every TRANSLATED_NAME of at most one LANGUAGE_ID to the cache.

Example 8-42 Caching Translated Names One Language at a Time (Coarser Granularity)

CREATE OR REPLACE FUNCTION get_product_name_2 (
  prod_id NUMBER,
  lang_id VARCHAR2
)
  RETURN NVARCHAR2
  AUTHID DEFINER
IS
  TYPE product_names IS TABLE OF NVARCHAR2(50) INDEX BY PLS_INTEGER;
 
  FUNCTION all_product_names (lang_id VARCHAR2)
    RETURN product_names
    RESULT_CACHE
  IS
    all_names product_names;
  BEGIN
    FOR c IN (SELECT * FROM OE.Product_Descriptions
              WHERE LANGUAGE_ID = lang_id) LOOP
      all_names(c.PRODUCT_ID) := c.TRANSLATED_NAME;
    END LOOP;
    RETURN all_names;
  END;
BEGIN
  RETURN all_product_names(lang_id)(prod_id);
END;
/

Result Caches in Oracle RAC Environment

Cached results are stored in the system global area (SGA). In an Oracle RAC environment, each database instance manages its own local function result cache. However, the contents of the local result cache are accessible to sessions attached to other Oracle RAC instances. If a required result is missing from the result cache of the local instance, the result might be retrieved from the local cache of another instance, instead of being locally computed.

The access pattern and work load of an instance determine the set of results in its local cache; therefore, the local caches of different instances can have different sets of results.

Although each database instance might have its own set of cached results, the mechanisms for handling invalid results are Oracle RAC environment-wide. If results were invalidated only in the local instance's result cache, other instances might use invalid results. For example, consider a result cache of item prices that are computed from data in database tables. If any of these database tables is updated in a way that affects the price of an item, the cached price of that item must be invalidated in every database instance in the Oracle RAC environment.

Result Cache Management

The PL/SQL function result cache shares its administrative and manageability infrastructure with the Result Cache. For information about the Result Cache, see Oracle Database Performance Tuning Guide.

The database administrator can use the following to manage the Result Cache:

Hot-Patching PL/SQL Units on Which Result-Cached Functions Depend

When you hot-patch a PL/SQL unit on which a result-cached function depends (directly or indirectly), the cached results associated with the result-cached function might not be automatically flushed in all cases.

For example, suppose that the result-cached function P1.foo() depends on the package subprogram P2.bar(). If a new version of the body of package P2 is loaded, the cached results associated with P1.foo() are not automatically flushed.

Therefore, this is the recommended procedure for hot-patching a PL/SQL unit:


Note:

To follow these steps, you must have the EXECUTE privilege on the package DBMS_RESULT_CACHE.

  1. Put the result cache in bypass mode and flush existing results:

    BEGIN
      DBMS_RESULT_CACHE.Bypass(TRUE);
      DBMS_RESULT_CACHE.Flush;
    END;
    /
    

    In an Oracle RAC environment, perform this step for each database instance.

  2. Patch the PL/SQL code.

  3. Resume using the result cache:

    BEGIN
      DBMS_RESULT_CACHE.Bypass(FALSE);
    END;
    /
    

    In an Oracle RAC environment, perform this step for each database instance.

PL/SQL Functions that SQL Statements Can Invoke

To be invocable from SQL statements, a stored function (and any subprograms that it invokes) must obey the following purity rules, which are meant to control side effects:

  • When invoked from a SELECT statement or a parallelized INSERT, UPDATE, DELETE, or MERGE statement, the subprogram cannot modify any database tables.

  • When invoked from an INSERT, UPDATE, DELETE, or MERGE statement, the subprogram cannot query or modify any database tables modified by that statement.

    If a function either queries or modifies a table, and a DML statement on that table invokes the function, then ORA-04091 (mutating-table error) occurs. There is one exception: ORA-04091 does not occur if a single-row INSERT statement that is not in a FORALL statement invokes the function in a VALUES clause.

  • When invoked from a SELECT, INSERT, UPDATE, DELETE, or MERGE statement, the subprogram cannot execute any of the following SQL statements (unless PRAGMA AUTONOMOUS_TRANSACTION was specified):

    • Transaction control statements (such as COMMIT)

    • Session control statements (such as SET ROLE)

    • System control statements (such as ALTER SYSTEM)

    • Database definition language (DDL) statements (such as CREATE), which are committed automatically

    (For the description of PRAGMA AUTONOMOUS_TRANSACTION, see "AUTONOMOUS_TRANSACTION Pragma".)

If any SQL statement in the execution part of the function violates a rule, then a runtime error occurs when that statement is parsed.

The fewer side effects a function has, the better it can be optimized in a SELECT statement, especially if the function is declared with the option DETERMINISTIC or PARALLEL_ENABLE (for descriptions of these options, see "DETERMINISTIC" and "PARALLEL_ENABLE").


See Also:


Invoker's Rights and Definer's Rights (AUTHID Property)

The AUTHID property of a stored PL/SQL unit affects the name resolution and privilege checking of SQL statements that the unit issues at run time. The AUTHID property does not affect compilation, and has no meaning for units that have no code, such as collection types.

AUTHID property values are exposed in the static data dictionary view *_PROCEDURES. For units for which AUTHID has meaning, the view shows the value CURRENT_USER or DEFINER; for other units, the view shows NULL.

For stored PL/SQL units that you create or alter with the following statements, you can use the optional AUTHID clause to specify either DEFINER (the default, for backward compatibility) or CURRENT_USER (the preferred usage):

A unit whose AUTHID value is CURRENT_USER is called an invoker's rights unit, or IR unit. A unit whose AUTHID value is DEFINER (the default) is called a definer's rights unit, or DR unit. PL/SQL units and schema objects for which you cannot specify an AUTHID value behave like this:

PL/SQL Unit or Schema ObjectBehavior
Anonymous blockIR unit
BEQUEATH CURRENT_USER viewSomewhat like an IR unit—see Oracle Database Security Guide.
BEQUEATH DEFINER viewDR unit
TriggerDR unit

The AUTHID property of a unit determines whether the unit is IR or DR, and it affects both name resolution and privilege checking at run time:

  • The context for name resolution is CURRENT_SCHEMA.

  • The privileges checked are those of the CURRENT_USER and the enabled roles.

When a session starts, CURRENT_SCHEMA has the value of the schema owned by SESSION_USER, and CURRENT_USER has the same value as SESSION_USER. (To get the current value of CURRENT_SCHEMA, CURRENT_USER, or SESSION_USER, use the SYS_CONTEXT function, documented in Oracle Database SQL Language Reference.)

CURRENT_SCHEMA can be changed during the session with the SQL statement ALTER SESSION SET CURRENT_SCHEMA. CURRENT_USER cannot be changed programmatically, but it might change when a PL/SQL unit or a view is pushed onto, or popped from, the call stack.


Note:

Oracle recommends against issuing ALTER SESSION SET CURRENT_SCHEMA from in a stored PL/SQL unit.

During a server call, when a DR unit is pushed onto the call stack, the database stores the currently enabled roles and the current values of CURRENT_USER and CURRENT_SCHEMA. It then changes both CURRENT_USER and CURRENT_SCHEMA to the owner of the DR unit, and enables only the role PUBLIC. (The stored and new roles and values are not necessarily different.) When the DR unit is popped from the call stack, the database restores the stored roles and values. In contrast, when an IR unit is pushed onto, or popped from, the call stack, the values of CURRENT_USER and CURRENT_SCHEMA, and the currently enabled roles do not change (unless roles are granted to the IR unit itself—see "Granting Roles to PL/SQL Packages and Standalone Subprograms").

For dynamic SQL statements issued by a PL/SQL unit, name resolution and privilege checking are done once, at run time. For static SQL statements, name resolution and privilege checking are done twice: first, when the PL/SQL unit is compiled, and then again at run time. At compile time, the AUTHID property has no effect—both DR and IR units are treated like DR units. At run time, however, the AUTHID property determines whether a unit is IR or DR, and the unit is treated accordingly.

Upon entry into an IR unit, the runtime system checks privileges before doing any initialization or running any code. If the unit owner has neither the INHERIT PRIVILEGES privilege on the invoker nor the INHERIT ANY PRIVILEGES privilege, then the runtime system raises error ORA-06598.


Note:

If the unit owner has the required privilege, then one of these statements granted it:
GRANT INHERIT PRIVILEGES ON current_user TO PUBLIC
GRANT INHERIT PRIVILEGES ON current_user TO unit_owner
GRANT INHERIT ANY PRIVILEGES TO unit_owner

For information about the GRANT statement, see Oracle Database SQL Language Reference.



See Also:

Oracle Database Security Guide for information about managing security for DR and IR units

Topics

Granting Roles to PL/SQL Packages and Standalone Subprograms

Using the SQL GRANT command, you can grant roles to PL/SQL packages and standalone subprograms. Roles granted to a PL/SQL unit do not affect compilation. They affect the privilege checking of SQL statements that the unit issues at run time: The unit runs with the privileges of both its own roles and any other currently enabled roles.

Typically, you grant roles to an IR unit, so that users with lower privileges than yours can run the unit with only the privileges needed to do so. You grant roles to a DR unit (whose invokers run it with all your privileges) only if the DR unit issues dynamic SQL, which is checked only at run time.

The basic syntax for granting roles to PL/SQL units is:

GRANT role [, role ]... TO unit [, unit ]...

For example, this command grants the roles read and execute to the function scott.func and the package sys.pkg:

GRANT read, execute TO FUNCTION scott.func, PACKAGE sys.pkg

For the complete syntax and semantics of the GRANT command, see Oracle Database SQL Language Reference.


See Also:


IR Units Need Template Objects

One user (that is, one schema) owns an IR unit and other users run it in their schemas. If the IR unit issues static SQL statements, then the schema objects that these statements affect must exist in the owner's schema at compile time (so that the compiler can resolve references) and in the invoker's schema at run time. The definitions of corresponding schema objects must match (for example, corresponding tables must have the same names and columns); otherwise, you get an error or unexpected results. However, the objects in the owner's schema need not contain data, because the compiler does not need it; therefore, they are called template objects.

External Subprograms

If a C procedure or Java method is stored in the database, you can publish it as an external subprogram and then invoke it from PL/SQL.

To publish an external subprogram, define a stored PL/SQL subprogram with a call specification. The call specification maps the name, parameter types, and return type of the external subprogram to PL/SQL equivalents. Invoke the published external subprogram by its PL/SQL name.

For example, suppose that this Java class, Adjuster, is stored in the database:

import java.sql.*;
import oracle.jdbc.driver.*;
public class Adjuster {
  public static void raiseSalary (int empNo, float percent)
  throws SQLException {
    Connection conn = new OracleDriver().defaultConnection();
    String sql = "UPDATE employees SET salary = salary * ?
                    WHERE employee_id = ?";
    try {
      PreparedStatement pstmt = conn.prepareStatement(sql);
      pstmt.setFloat(1, (1 + percent / 100));
      pstmt.setInt(2, empNo);
      pstmt.executeUpdate();
      pstmt.close();
    } catch (SQLException e)
          {System.err.println(e.getMessage());}
    }
}

The Java class Adjuster has one method, raiseSalary, which raises the salary of a specified employee by a specified percentage. Because raiseSalary is a void method, you publish it as a PL/SQL procedure (rather than a function).

Example 8-43 publishes the stored Java method Adjuster.raiseSalary as a PL/SQL standalone procedure, mapping the Java method name Adjuster.raiseSalary to the PL/SQL procedure name raise_salary and the Java data types int and float to the PL/SQL data type NUMBER. Then the anonymous block invokes raise_salary.

Example 8-43 PL/SQL Anonymous Block Invokes External Procedure

-- Publish Adjuster.raiseSalary as standalone PL/SQL procedure:

CREATE OR REPLACE PROCEDURE raise_salary (
  empid NUMBER,
  pct   NUMBER
) AS
  LANGUAGE JAVA NAME 'Adjuster.raiseSalary (int, float)';  -- call specification
/

BEGIN
  raise_salary(120, 10);  -- invoke Adjuster.raiseSalary by PL/SQL name
END;
/

Example 8-44 publishes the stored Java method java.lang.Thread.sleep as a PL/SQL standalone procedure, mapping the Java method name to the PL/SQL procedure name java_sleep and the Java data type long to the PL/SQL data type NUMBER. The PL/SQL standalone procedure sleep invokes java_sleep.

Example 8-44 PL/SQL Standalone Procedure Invokes External Procedure

-- Java call specification:

CREATE PROCEDURE java_sleep (
  milli_seconds IN NUMBER
) AS LANGUAGE JAVA NAME 'java.lang.Thread.sleep(long)';
/

CREATE OR REPLACE PROCEDURE sleep (
  milli_seconds IN NUMBER
) AUTHID DEFINER IS
BEGIN
  DBMS_OUTPUT.PUT_LINE(DBMS_UTILITY.get_time());
  java_sleep (milli_seconds);
  DBMS_OUTPUT.PUT_LINE(DBMS_UTILITY.get_time());
END;
/

Call specifications can appear in PL/SQL standalone subprograms, package specifications and bodies, and type specifications and bodies. They cannot appear inside PL/SQL blocks.


See Also:

Oracle Database Development Guide for more information about calling external programs

PKwsppPKwDOEBPS/create_type.htm CREATE TYPE Statement

CREATE TYPE Statement

The CREATE TYPE statement creates or replaces the specification of one of these:

  • Abstract Data Type (ADT) (including a SQLJ object type)

  • Standalone varying array (varray) type

  • Standalone nested table type

  • Incomplete object type

    An incomplete type is a type created by a forward type definition. It is called incomplete because it has a name but no attributes or methods. It can be referenced by other types, allowing you define types that refer to each other. However, you must fully specify the type before you can use it to create a table or an object column or a column of a nested table type.

The CREATE TYPE statement specifies the name of the type and its attributes, methods, and other properties. The CREATE TYPE BODY statement contains the code for the methods that implement the type.


Notes:

  • If you create a type whose specification declares only attributes but no methods, then you need not specify a type body.

  • If you create a SQLJ object type, then you cannot specify a type body. The implementation of the type is specified as a Java class.

  • A standalone collection type that you create with the CREATE TYPE statement differs from a collection type that you define with the keyword TYPE in a PL/SQL block or package. For information about the latter, see "Collection Variable Declaration".

  • With the CREATE TYPE statement, you can create nested table and VARRAY types, but not associative arrays. In a PL/SQL block or package, you can define all three collection types.


Topics

Prerequisites

To create a type in your schema, you must have the CREATE TYPE system privilege. To create a type in another user's schema, you must have the CREATE ANY TYPE system privilege. You can acquire these privileges explicitly or be granted them through a role.

To create a subtype, you must have the UNDER ANY TYPE system privilege or the UNDER object privilege on the supertype.

The owner of the type must be explicitly granted the EXECUTE object privilege to access all other types referenced in the definition of the type, or the type owner must be granted the EXECUTE ANY TYPE system privilege. The owner cannot obtain these privileges through roles.

If the type owner intends to grant other users access to the type, then the owner must be granted the EXECUTE object privilege on the referenced types with the GRANT OPTION or the EXECUTE ANY TYPE system privilege with the ADMIN OPTION. Otherwise, the type owner has insufficient privileges to grant access on the type to other users.

Syntax

create_type ::=

Description of create_type.gif follows

plsql_type_source ::=

Description of plsql_type_source.gif follows

See:

object_type_def ::=

Description of object_type_def.gif follows

See:

invoker_rights_clause ::=

Description of invoker_rights_clause.gif follows

sqlj_object_type ::=

Description of sqlj_object_type.gif follows

sqlj_object_type_attr ::=

Description of sqlj_object_type_attr.gif follows

element_spec ::=

Description of element_spec.gif follows

See:

inheritance_clauses ::=

Description of inheritance_clauses.gif follows

subprogram_spec ::=

Description of subprogram_spec.gif follows

procedure_spec ::=

Description of procedure_spec.gif follows

See "call_spec ::=".

function_spec ::=

Description of function_spec.gif follows

return_clause ::=

Description of return_clause.gif follows

See "call_spec ::=".

constructor_spec ::=

Description of constructor_spec.gif follows

See "call_spec ::=".

map_order_function_spec ::=

Description of map_order_function_spec.gif follows

See "function_spec ::=".

sqlj_object_type_sig ::=

Description of sqlj_object_type_sig.gif follows

Semantics

OR REPLACE

Re-creates the type if it exists, and recompiles it.

Users who were granted privileges on the type before it was redefined can still access the type without being regranted the privileges.

If any function-based indexes depend on the type, then the database marks the indexes DISABLED.

[ EDITIONABLE | NONEDITIONABLE ]

Specifies whether the type is an editioned or noneditioned object if editioning is enabled for the schema object type TYPE in schema. Default: EDITIONABLE. For information about editioned and noneditioned objects, see Oracle Database Development Guide.

schema

Name of the schema containing the type. Default: your schema.

type_name

Name of an ADT, a nested table type, or a VARRAY type.

If creating the type 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 database implicitly defines a constructor method for each user-defined type that you create. A constructor is a system-supplied procedure that is used in SQL statements or in PL/SQL code to construct an instance of the type value. The name of the constructor method is the name of the user-defined type. You can also create a user-defined constructor using the constructor_spec syntax.

The parameters of the ADT constructor method are the data attributes of the ADT. They occur in the same order as the attribute definition order for the ADT. The parameters of a nested table or varray constructor are the elements of the nested table or the varray.

FORCE

If type_name exists and has type dependents, but not table dependents, FORCE forces the statement to replace the type. (If type_name has table dependents, the statement fails with or without FORCE.)


Note:

If type t1 has type dependent t2, and type t2 has table dependents, then type t1 also has table dependents.

object_type_def

Creates an ADT. The variables that form the data structure are called attributes. The member subprograms that define the behavior of the ADT are called methods. The keywords AS OBJECT are required when creating an ADT.


See Also:

"ADT Examples"

invoker_rights_clause

Specifies the AUTHID property of the member functions and procedures of the ADT. For information about the AUTHID property, see "Invoker's Rights and Definer's Rights (AUTHID Property)".

Restrictions on invoker_rights_clause This clause is subject to these restrictions:

  • You can specify this clause only for an ADT, not for a nested table or VARRAY type.

  • You can specify this clause for clarity if you are creating a subtype. However, a subtype inherits the AUTHID property of its supertype, so you cannot specify a different value than was specified for the supertype.

  • If the supertype was created with AUTHID DEFINER, then you must create the subtype in the same schema as the supertype.

accessible_by_clause

Has the same behavior for a type as it does for a function. See the CREATE FUNCTION "accessible_by_clause".

OID 'object_identifier'

Establishes type equivalence of identical objects in multiple databases. See Oracle Database Object-Relational Developer's Guide for information about this clause.

AS OBJECT

Creates a schema-level ADT. Such ADTs are sometimes called root ADTs.

UNDER supertype

Creates a subtype of an existing type. The existing supertype must be an ADT. The subtype you create in this statement inherits the properties of its supertype. It must either override some of those properties or add properties to distinguish it from the supertype.

sqlj_object_type

Creates a SQLJ object type. With a SQLJ object type, you map a Java class to a SQL user-defined type. You can then define tables or columns of the SQLJ object type as you can with any other user-defined type.

You can map one Java class to multiple SQLJ object types. If there exists a subtype or supertype of a SQLJ object type, then it must also be a SQLJ object type. All types in the hierarchy must be SQLJ object types.


See Also:

Oracle Database Object-Relational Developer's Guide for more information about creating SQLJ object types

java_ext_name

Name of the Java class. If the class exists, then it must be public. The Java external name, including the schema, is validated.

Multiple SQLJ object types can be mapped to the same class. However:

  • A subtype must be mapped to a class that is an immediate subclass of the class to which its supertype is mapped.

  • Two subtypes of a common supertype cannot be mapped to the same class.

SQLData | CustomDatum | OraData

Specifies the mechanism for creating the Java instance of the type. SQLData, CustomDatum, and OraData are the interfaces that determine which mechanism to use.


See Also:

Oracle Database JDBC Developer's Guide for information about these three interfaces and "SQLJ Object Type Example"

element_spec

Specifies each attribute of the ADT.

attribute

Name of an ADT attribute. An ADT attribute is a data item with a name and a type specifier that forms the structure of the ADT. You must specify at least one attribute for each ADT. The name must be unique in the ADT, but can be used in other ADTs.

If you are creating a subtype, then the attribute name cannot be the same as any attribute or method name declared in the supertype chain.

datatype

The data type of an ADT attribute. This data type must be stored in the database; that is, either a predefined data type or a user-defined standalone collection type. For information about predefined data types, see Chapter 3, "PL/SQL Data Types." For information about user-defined standalone collection types, see "Collection Types".

Restrictions on datatype 

  • You cannot impose the NOT NULL constraint on an attribute.

  • You cannot specify attributes of type ROWID, LONG, or LONG RAW.

  • You cannot specify a data type of UROWID for an ADT.

  • If you specify an object of type REF, then the target object must have an object identifier.

  • If you are creating a collection type for use as a nested table or varray column of a table, then you cannot specify attributes of type ANYTYPE, ANYDATA, or ANYDATASET.

sqlj_object_type_attr

This clause is valid only if you have specified the sqlj_object_type clause to map a Java class to a SQLJ object type. Specify the external name of the Java field that corresponds to the attribute of the SQLJ object type. The Java field_name must exist in the class. You cannot map a Java field_name to multiple SQLJ object type attributes in the same type hierarchy.

This clause is optional when you create a SQLJ object type.

subprogram_spec

Associates a procedure subprogram with the ADT.

MEMBER

A function or procedure subprogram associated with the ADT that is referenced as an attribute. Typically, you invoke MEMBER methods in a selfish style, such as object_expression.method(). This class of method has an implicit first argument referenced as SELF in the method body, which represents the object on which the method was invoked.

Restriction on MEMBER You cannot specify a MEMBER method if you are mapping a Java class to a SQLJ object type.

STATIC

A function or procedure subprogram associated with the ADT. Unlike MEMBER methods, STATIC methods do not have any implicit parameters. You cannot reference SELF in their body. They are typically invoked as type_name.method().

Restrictions on STATIC 

  • You cannot map a MEMBER method in a Java class to a STATIC method in a SQLJ object type.

  • For both MEMBER and STATIC methods, you must specify a corresponding method body in the type body for each procedure or function specification.

[NOT] FINAL, [NOT] INSTANTIABLE

At the schema level of the syntax, these clauses specify the inheritance attributes of the type.

Use the [NOT] FINAL clause to indicate whether any further subtypes can be created for this type:

  • (Default) Specify FINAL if no further subtypes can be created for this type.

  • Specify NOT FINAL if further subtypes can be created under this type.

Use the [NOT] INSTANTIABLE clause to indicate whether any object instances of this type can be constructed:

  • (Default) Specify INSTANTIABLE if object instances of this type can be constructed.

  • Specify NOT INSTANTIABLE if no default or user-defined constructor exists for this ADT. You must specify these keywords for any type with noninstantiable methods and for any type that has no attributes, either inherited or specified in this statement.

inheritance_clauses

Specify the relationship between supertypes and subtypes.

OVERRIDING

Specifies that this method overrides a MEMBER method defined in the supertype. This keyword is required if the method redefines a supertype method. Default: NOT OVERRIDING.

Restriction on OVERRIDING The OVERRIDING clause is not valid for a STATIC method or for a SQLJ object type.

FINAL

Specifies that this method cannot be overridden by any subtype of this type. Default: NOT FINAL.

NOT INSTANTIABLE

Specifies that the type does not provide an implementation for this method. Default: all methods are INSTANTIABLE.

Restriction on NOT INSTANTIABLE If you specify NOT INSTANTIABLE, then you cannot specify FINAL or STATIC.


See Also:

constructor_spec

procedure_spec or function_spec

Specifies the parameters and data types of the procedure or function. If this subprogram does not include the declaration of the procedure or function, then you must issue a corresponding CREATE TYPE BODY statement.

Restriction on procedure_spec or function_spec If you are creating a subtype, then the name of the procedure or function cannot be the same as the name of any attribute, whether inherited or not, declared in the supertype chain.

return_clause

The first form of the return_clause is valid only for a function. The syntax shown is an abbreviated form.


See Also:


sqlj_object_type_sig

Use this form of the return_clause if you intend to create SQLJ object type functions or procedures.

  • If you are mapping a Java class to a SQLJ object type and you specify EXTERNAL NAME, then the value of the Java method returned must be compatible with the SQL returned value, and the Java method must be public. Also, the method signature (method name plus parameter types) must be unique in the type hierarchy.

  • If you specify EXTERNAL VARIABLE NAME, then the type of the Java static field must be compatible with the return type.

call_spec, EXTERNAL

See "call_spec" and "EXTERNAL".

restrict_references_pragma

Deprecated clause, described in "RESTRICT_REFERENCES Pragma".

constructor_spec

Creates a user-defined constructor, which is a function that returns an initialized instance of an ADT. You can declare multiple constructors for a single ADT, if the parameters of each constructor differ in number, order, or data type.

  • User-defined constructor functions are always FINAL and INSTANTIABLE, so these keywords are optional.

  • The parameter-passing mode of user-defined constructors is always SELF IN OUT. Therefore you need not specify this clause unless you want to do so for clarity.

  • RETURN SELF AS RESULT specifies that the runtime type of the value returned by the constructor is runtime type of the SELF argument.


See Also:

Oracle Database Object-Relational Developer's Guide for more information about and examples of user-defined constructors and "Constructor Example"

map_order_function_spec

You can define either one MAP method or one ORDER method in a type specification, regardless of how many MEMBER or STATIC methods you define. If you declare either method, then you can compare object instances in SQL.

You cannot define either MAP or ORDER methods for subtypes. However, a subtype can override a MAP method if the supertype defines a n M߲onfinal MAP method. A subtype cannot override an ORDER method at all.

You can specify either MAP or ORDER when mapping a Java class to a SQL type. However, the MAP or ORDER methods must map to MEMBER functions in the Java class.

If neither a MAP nor an ORDER method is specified, then only comparisons for equality or inequality can be performed. Therefore object instances cannot be ordered. Instances of the same type definition are equal only if each pair of their corresponding attributes is equal. No comparison method must be specified to determine the equality of two ADTs.

Use MAP if you are performing extensive sorting or hash join operations on object instances. MAP is applied once to map the objects to scalar values, and then the database uses the scalars during sorting and merging. A MAP method is more efficient than an ORDER method, which must invoke the method for each object comparison. You must use a MAP method for hash joins. You cannot use an ORDER method because the hash mechanism hashes on the object value.


See Also:

Oracle Database Object-Relational Developer's Guide for more information about object value comparisons

MAP MEMBER

Specifies a MAP member function that returns the relative position of a given instance in the ordering of all instances of the object. A MAP method is called implicitly and induces an ordering of object instances by mapping them to values of a predefined scalar type. PL/SQL uses the ordering to evaluate Boolean expressions and to perform comparisons.

If the argument to the MAP method is null, then the MAP method returns null and the method is not invoked.

An object specification can contain only one MAP method, which must be a function. The result type must be a predefined SQL scalar type, and the MAP method can have no arguments other than the implicit SELF argument.


Note:

If type_name is to be referenced in queries containing sorts (through an ORDER BY, GROUP BY, DISTINCT, or UNION clause) or containing joins, and you want those queries to be parallelized, then you must specify a MAP member function.

A subtype cannot define a new MAP method, but it can override an inherited MAP method.

ORDER MEMBER

Specifies an ORDER member function that takes an instance of an object as an explicit argument and the implicit SELF argument and returns either a negative, zero, or positive integer. The negative, positive, or zero indicates that the implicit SELF argument is less than, equal to, or greater than the explicit argument.

If either argument to the ORDER method is null, then the ORDER method returns null and the method is not invoked.

When instances of the same ADT definition are compared in an ORDER BY clause, the ORDER method map_order_function_spec is invoked.

An object specification can contain only one ORDER method, which must be a function having the return type NUMBER.

A subtype can neither define nor override an ORDER method.

varray_type_def

Creates the type as an ordered set of elements, each of which has the same data type.

Restrictions on varray_type_def You can create a VARRAY type of XMLType or of a LOB type for procedural purposes, for example, in PL/SQL or in view queries. However, database storage of such a varray is not supported, so you cannot create an object table or an column of such a VARRAY type.

nested_table_type_def

Creates a named nested table of type datatype.

Examples

ADT Examples This example shows how the sample type customer_typ was created for the sample Order Entry (oe) schema. A hypothetical name is given to the table so that you can duplicate this example in your test database:

CREATE TYPE customer_typ_demo AS OBJECT
    ( customer_id        NUMBER(6)
    , cust_first_name    VARCHAR2(20)
    , cust_last_name     VARCHAR2(20)
    , cust_address       CUST_ADDRESS_TYP
    , phone_numbers      PHONE_LIST_TYP
    , nls_language       VARCHAR2(3)
    , nls_territory      VARCHAR2(30)
    , credit_limit       NUMBER(9,2)
    , cust_email         VARCHAR2(30)
    , cust_orders        ORDER_LIST_TYP
    ) ;
/

In this example, the data_typ1 ADT is created with one member function prod, which is implemented in the CREATE TYPE BODY statement:

CREATE TYPE data_typ1 AS OBJECT 
   ( year NUMBER, 
     MEMBER FUNCTION prod(invent NUMBER) RETURN NUMBER 
   ); 
/
 
CREATE TYPE BODY data_typ1 IS   
      MEMBER FUNCTION prod (invent NUMBER) RETURN NUMBER IS 
         BEGIN 
             RETURN (year + invent);
         END; 
      END; 
/

Subtype Example This statement shows how the subtype corporate_customer_typ in the sample oe schema was created. It is based on the customer_typ supertype created in the preceding example and adds the account_mgr_id attribute. A hypothetical name is given to the table so that you can duplicate this example in your test database:

CREATE TYPE corporate_customer_typ_demo UNDER customer_typ
    ( account_mgr_id     NUMBER(6)
    );

SQLJ Object Type Example These examples create a SQLJ object type and subtype. The address_t type maps to the Java class Examples.Address. The subtype long_address_t maps to the Java class Examples.LongAddress. The examples specify SQLData as the mechanism used to create the Java instance of these types. Each of the functions in these type specifications has a corresponding implementation in the Java class.


See Also:

Oracle Database Object-Relational Developer's Guide for the Java implementation of the functions in these type specifications

CREATE TYPE address_t AS OBJECT
  EXTERNAL NAME 'Examples.Address' LANGUAGE JAVA 
  USING SQLData(
    street_attr varchar(250) EXTERNAL NAME 'street',
    city_attr varchar(50) EXTERNAL NAME 'city',
    state varchar(50) EXTERNAL NAME 'state',
    zip_code_attr number EXTERNAL NAME 'zipCode',
    STATIC FUNCTION recom_width RETURN NUMBER
      EXTERNAL VARIABLE NAME 'recommendedWidth',
    STATIC FUNCTION create_address RETURN address_t
      EXTERNAL NAME 'create() return Examples.Address',
    STATIC FUNCTION construct RETURN address_t
      EXTERNAL NAME 'create() return Examples.Address',
    STATIC FUNCTION create_address (street VARCHAR, city VARCHAR, 
        state VARCHAR, zip NUMBER) RETURN address_t
      EXTERNAL NAME 'create (java.lang.String, java.lang.String, java.lang.String, int) return Examples.Address',
    STATIC FUNCTION construct (street VARCHAR, city VARCHAR, 
        state VARCHAR, zip NUMBER) RETURN address_t
      EXTERNAL NAME 
        'create (java.lang.String, java.lang.String, java.lang.String, int) return Examples.Address',
    MEMBER FUNCTION to_string RETURN VARCHAR
      EXTERNAL NAME 'tojava.lang.String() return java.lang.String',
    MEMBER FUNCTION strip RETURN SELF AS RESULT 
      EXTERNAL NAME 'removeLeadingBlanks () return Examples.Address'
  ) NOT FINAL;
/

CREATE OR REPLACE TYPE long_address_t
UNDER address_t
EXTERNAL NAME 'Examples.LongAddress' LANGUAGE JAVA 
USING SQLData(
    street2_attr VARCHAR(250) EXTERNAL NAME 'street2',
    country_attr VARCHAR (200) EXTERNAL NAME 'country',
    address_code_attr VARCHAR (50) EXTERNAL NAME 'addrCode',    
    STATIC FUNCTION create_address RETURN long_address_t 
      EXTERNAL NAME 'create() return Examples.LongAddress',
    STATIC FUNCTION  construct (street VARCHAR, city VARCHAR, 
        state VARCHAR, country VARCHAR, addrs_cd VARCHAR) 
      RETURN long_address_t 
      EXTERNAL NAME 
        'create(java.lang.String, java.lang.String,
        java.lang.String, java.lang.String, java.lang.String) 
          return Examples.LongAddress',
    STATIC FUNCTION construct RETURN long_address_t
      EXTERNAL NAME 'Examples.LongAddress() 
        return Examples.LongAddress',
    STATIC FUNCTION create_longaddress (
      street VARCHAR, city VARCHAR, state VARCHAR, country VARCHAR, 
      addrs_cd VARCHAR) return long_address_t
      EXTERNAL NAME 
        'Examples.LongAddress (java.lang.String, java.lang.String,
         java.lang.String, java.lang.String, java.lang.String)
           return Examples.LongAddress',
    MEMBER FUNCTION get_country RETURN VARCHAR
      EXTERNAL NAME 'country_with_code () return java.lang.String'
  );
/

Type Hierarchy Example These statements create a type hierarchy. Type employee_t inherits the name and ssn attributes from type person_t and in addition has department_id and salary attributes. Type part_time_emp_t inherits all of the attributes from employee_t and, through employee_t, those of person_t and in addition has a num_hrs attribute. Type part_time_emp_t is final by default, so no further subtypes can be created under it.

CREATE TYPE person_t AS OBJECT (name VARCHAR2(100), ssn NUMBER) 
   NOT FINAL;
/

CREATE TYPE employee_t UNDER person_t 
   (department_id NUMBER, salary NUMBER) NOT FINAL;
/

CREATE TYPE part_time_emp_t UNDER employee_t (num_hrs NUMBER);
/

You can use type hierarchies to create substitutable tables and tables with substitutable columns.

Varray Type Example This statement shows how the phone_list_typ VARRAY type with five elements in the sample oe schema was created. A hypothetical name is given to the table so that you can duplicate this example in your test database:

CREATE TYPE phone_list_typ_demo AS VARRAY(5) OF VARCHAR2(25);

Nested Table Type Example This example from the sample schema pm creates the table type textdoc_tab of type textdoc_typ:

CREATE TYPE textdoc_typ AS OBJECT
    ( document_typ      VARCHAR2(32)
    , formatted_doc     BLOB
    ) ;

CREATE TYPE textdoc_tab AS TABLE OF textdoc_typ;

Nested Table Type Containing a Varray This example of multilevel collections is a variation of the sample table oe.customers. In this example, the cust_address object column becomes a nested table column with the phone_list_typ varray column embedded in it. The phone_list_typ type was created in "Varray Type Example".

CREATE TYPE cust_address_typ2 AS OBJECT
       ( street_address     VARCHAR2(40)
       , postal_code        VARCHAR2(10)
       , city               VARCHAR2(30)
       , state_province     VARCHAR2(10)
       , country_id         CHAR(2)
       , phone              phone_list_typ_demo
       );

CREATE TYPE cust_nt_address_typ
   AS TABLE OF cust_address_typ2;

Constructor Example This example invokes the system-defined constructor to construct the demo_typ object and insert it into the demo_tab table:

CREATE TYPE demo_typ1 AS OBJECT (a1 NUMBER, a2 NUMBER);

CREATE TABLE demo_tab1 (b1 NUMBER, b2 demo_typ1);

INSERT INTO demo_tab1 VALUES (1, demo_typ1(2,3));

See Also:

Oracle Database Object-Relational Developer's Guide for more information about constructors

Creating a Member Method: Example This example invokes method constructor col.get_square. First the type is created:

CREATE TYPE demo_typ2 AS OBJECT (a1 NUMBER, 
   MEMBER FUNCTION get_square RETURN NUMBER); 

Next a table is created with an ADT column and some data is inserted into the table:

CREATE TABLE demo_tab2(col demo_typ2); 

INSERT INTO demo_tab2 VALUES (demo_typ2(2));

The type body is created to define the member function, and the member method is invoked:

CREATE TYPE BODY demo_typ2 IS
   MEMBER FUNCTION get_square
   RETURN NUMBER
   IS x NUMBER;
   BEGIN
      SELECT c.col.a1*c.col.a1 INTO x
      FROM demo_tab2 c;
      RETURN (x);
   END;
END;
/
 
SELECT t.col.get_square() FROM demo_tab2 t;

T.COL.GET_SQUARE()
------------------
                 4

Unlike function invocations, method invocations require parentheses, even when the methods do not have additional arguments.

Creating a Static Method: Example This example changes the definition of the employee_t type to associate it with the construct_emp function. The example first creates an ADT department_t and then an ADT employee_t containing an attribute of type department_t:

CREATE OR REPLACE TYPE department_t AS OBJECT (
   deptno number(10),
   dname CHAR(30));

CREATE OR REPLACE TYPE employee_t AS OBJECT(
   empid RAW(16),
   ename CHAR(31),
   dept REF department_t,
      STATIC function construct_emp
      (name VARCHAR2, dept REF department_t)
      RETURN employee_t
);

This statement requires this type body statement.

CREATE OR REPLACE TYPE BODY employee_t IS
   STATIC FUNCTION construct_emp
   (name varchar2, dept REF department_t)
   RETURN employee_t IS
      BEGIN
         return employee_t(SYS_GUID(),name,dept);
      END;
END;

Next create an object table and insert into the table:

CREATE TABLE emptab OF employee_t;
INSERT INTO emptab
   VALUES (employee_t.construct_emp('John Smith', NULL));

Related Topics

In this chapter:

In other chapters:


See Also:

Oracle Database Object-Relational Developer's Guide for more information about objects, incomplete types, varrays, and nested tables

PKwu* PKwDOEBPS/constant.htm Constant Declaration

Constant Declaration

A constant holds a value that does not change.

A constant declaration specifies the name, data type, and value of the constant and allocates storage for it. The declaration can also impose the NOT NULL constraint.

Topics

Syntax

constant_declaration ::=

Description of constant_declaration.gif follows

See:

Semantics

constant

Name of the constant that you are declaring.

datatype

Data type for which a variable can be declared with an initial value.

NOT NULL

Imposes the NOT NULL constraint on the constant. For information about this constraint, see "NOT NULL Constraint".

expression

Initial value for the constant. expression must have a data type that is compatible with datatype. When constant_declaration is elaborated, the value of expression is assigned to constant.

PKws$PKwDOEBPS/block.htmkV Block

Block

The block, which groups related declarations and statements, is the basic unit of a PL/SQL source program. It has an optional declarative part, a required executable part, and an optional exception-handling part. Declarations are local to the block and cease to exist when the block completes execution. Blocks can be nested.

An anonymous block is an executable statement.

Topics

Semantics

plsql_block

label

Undeclared identifier, unique for the block.

DECLARE

Starts the declarative part of the block.

declare_section

Contains local declarations, which exist only in the block and its sub-blocks and are not visible to enclosing blocks.

Restrictions on declare_section 

  • A declare_section in create_package, create_package_body, or compound_trigger_block cannot include PRAGMA AUTONOMOUS_TRANSACTION.

  • A declare_section in trigger_body or tps_body cannot declare variables of the data type LONG or LONG RAW.


See Also:


subtype_definition

subtype

Name of the user-defined subtype that you are defining.

base_type

Base type of the subtype that you are defining. base_type can be any scalar or user-defined PL/SQL datatype specifier such as CHAR, DATE, or RECORD.

CHARACTER SET character_set

Specifies the character set for a subtype of a character data type.

Restriction on CHARACTER SET character_set Do not specify this clause if base_type is not a character data type.

NOT NULL

Imposes the NOT NULL constraint on data items declared with this subtype. For information about this constraint, see "NOT NULL Constraint".

constraint

Specifies a constraint for a subtype of a numeric data type.

Restriction on constraint Do not specify constraint if base_type is not a numeric data type.

precision

Specifies the precision for a constrained subtype of a numeric data type.

Restriction on precision Do not specify precision if base_type cannot specify precision.

scale

Specifies the scale for a constrained subtype of a numeric data type.

Restriction on scale Do not specify scale if base_type cannot specify scale.

RANGE low_value .. high_value

Specifies the range for a constrained subtype of a numeric data type. The low_value and high_value must be numeric literals.

Restriction on RANGE high_value .. low_value Specify this clause only if base_type is PLS_INTEGER or a subtype of PLS_INTEGER (either predefined or user-defined). (For a summary of the predefined subtypes of PLS_INTEGER, see Table 3-3. For information about user-defined subtypes with ranges, see "Constrained Subtypes".)

body

BEGIN

Starts the executable part of the block, which contains executable statements.

EXCEPTION

Starts the exception-handling part of the block. When PL/SQL raises an exception, normal execution of the block stops and control transfers to the appropriate exception_handler. After the exception handler completes, execution resumes with the statement following the block. For more information about exception-handling, see Chapter 11, "PL/SQL Error Handling."

exception_handler

See "Exception Handler".

END

Ends the block.

name

The name of the block to which END applies—a label, function name, procedure name, or package name.

statement

label

Undeclared identifier, unique for the statement.

assignment_statement

See "Assignment Statement".

basic_loop_statement

See "Basic LOOP Statement".

case_statement

See "CASE Statement".

close_statement

See "CLOSE Statement".

collection_method_call

Invocation of one of these collection methods, which are procedures:

  • DELETE

  • EXTEND

  • TRIM

For syntax, see "Collection Method Invocation".

continue_statement

See "CONTINUE Statement".

cursor_for_loop_statement

See "Cursor FOR LOOP Statement".

execute_immediate_statement

See "EXECUTE IMMEDIATE Statement".

exit_statement

See "EXIT Statement".

fetch_statement

See "FETCH Statement".

for_loop_statement

See "FOR LOOP Statement".

forall_statement

See "FORALL Statement".

goto_statement

See "GOTO Statement".

if_statement

See "IF Statement".

null_statement

See "NULL Statement".

open_statement

See "OPEN Statement".

open_for_statement

See "OPEN FOR Statement".

pipe_row_statement

See "PIPE ROW Statement".

Restriction on pipe_row_statement This statement can appear only in the body of a pipelined table function; otherwise, PL/SQL raises an exception.

raise_statement

See "RAISE Statement".

return_statement

See "RETURN Statement".

select_into_statement

See "SELECT INTO Statement".

while_loop_statement

See "WHILE LOOP Statement".

procedure_call

procedure

Name of the procedure that you are invoking.

parameter [, parameter ]...

List of actual parameters for the procedure that you are invoking. The data type of each actual parameter must be compatible with the data type of the corresponding formal parameter. The mode of the formal parameter determines what the actual parameter can be:

Formal Parameter ModeActual Parameter
INConstant, initialized variable, literal, or expression
OUTVariable whose data type is not defined as NOT NULL
IN OUTVariable (typically, it is a string buffer or numeric accumulator)

If the procedure specifies a default value for a parameter, you can omit that parameter from the parameter list. If the procedure has no parameters, or specifies a default value for every parameter, you can either omit the parameter list or specify an empty parameter list.

sql_statement

commit_statement

SQL COMMIT statement. For syntax, see Oracle Database SQL Language Reference.

delete_statement

SQL DELETE statement. For syntax, see Oracle Database SQL Language Reference. See also "DELETE Statement Extension".

insert_statement

SQL INSERT statement. For syntax, see Oracle Database SQL Language Reference. See also "INSERT Statement Extension".

lock_table_statement

SQL LOCK TABLE statement. For syntax, see Oracle Database SQL Language Reference.

merge_statement

SQL MERGE statement. For syntax, see Oracle Database SQL Language Reference.

rollback_statement

SQL ROLLBACK statement. For syntax, see Oracle Database SQL Language Reference.

savepoint_statement

SQL SAVEPOINT statement. For syntax, see Oracle Database SQL Language Reference.

set_transaction_statement

SQL SET TRANSACTION statement. For syntax, see Oracle Database SQL Language Reference.

update_statement

SQL UPDATE statement. For syntax, see Oracle Database SQL Language Reference. See also "UPDATE Statement Extensions".

PKpkkPKwDOEBPS/sqlcode_function.htm0 SQLCODE Function

SQLCODE Function

In an exception handler, the SQLCODE function returns the numeric code of the exception being handled. (Outside an exception handler, SQLCODE returns 0.)

For an internally defined exception, the numeric code is the number of the associated Oracle Database error. This number is negative except for the error "no data found", whose numeric code is +100.

For a user-defined exception, the numeric code is either +1 (default) or the error code associated with the exception by the EXCEPTION_INIT pragma.

A SQL statement cannot invoke SQLCODE.

If a function invokes SQLCODE, and you use the RESTRICT_REFERENCES pragma to assert the purity of the function, then you cannot specify the constraints WNPS and RNPS.

Topics

Syntax

sqlcode_function ::=

Description of sqlcode_function.gif follows

Related Topics

In this chapter:

In other chapters:


See Also:

Oracle Database Error Messages Reference for a list of Oracle Database error messages and information about them, including their numbers

PKuLPKwDOEBPS/packages.htm PL/SQL Packages

10 PL/SQL Packages

This chapter explains how to bundle related PL/SQL code and data into a package, whose contents are available to many applications.

Topics


See Also:


What is a Package?

A package is a schema object that groups logically related PL/SQL types, variables, constants, subprograms, cursors, and exceptions. A package is compiled and stored in the database, where many applications can share its contents.

A package always has a specification, which declares the public items that can be referenced from outside the package. For more information about the package specification, see "Package Specification".

If the public items include cursors or subprograms, then the package must also have a body. The body must define queries for public cursors and code for public subprograms. The body can also declare and define private items that cannot be referenced from outside the package, but are necessary for the internal workings of the package. Finally, the body can have an initialization part, whose statements initialize variables and do other one-time setup steps, and an exception-handling part. You can change the body without changing the specification or the references to the public items; therefore, you can think of the package body as a black box. For more information about the package body, see "Package Body".

In either the package specification or package body, you can map a package subprogram to an external Java or C subprogram by using a call specification, which maps the external subprogram name, parameter types, and return type to their SQL counterparts. For details, see "Function Declaration and Definition" and "Procedure Declaration and Definition".

The AUTHID clause of the package specification determines whether the subprograms and cursors in the package run with the privileges of their definer (the default) or invoker, and whether their unqualified references to schema objects are resolved in the schema of the definer or invoker. For more information, see "Invoker's Rights and Definer's Rights (AUTHID Property)".

The ACCESSIBLE BY clause of the package specification lets you specify a white list" of PL/SQL units that can access the package. You use this clause in situations like these:

  • You implement a PL/SQL application as several packages—one package that provides the application programming interface (API) and helper packages to do the work. You want clients to have access to the API, but not to the helper packages. Therefore, you omit the ACCESSIBLE BY clause from the API package specification and include it in each helper package specification, where you specify that only the API package can access the helper package.

  • You create a utility package to provide services to some, but not all, PL/SQL units in the same schema. To restrict use of the package to the intended units, you list them in the ACCESSIBLE BY clause in the package specification.

Reasons to Use Packages

Packages support the development and maintenance of reliable, reusable code with the following features:

  • Modularity

    Packages let you encapsulate logically related types, variables, constants, subprograms, cursors, and exceptions in named PL/SQL modules. You can make each package easy to understand, and make the interfaces between packages simple, clear, and well defined. This practice aids application development.

  • Easier Application Design

    When designing an application, all you need initially is the interface information in the package specifications. You can code and compile specifications without their bodies. Next, you can compile standalone subprograms that reference the packages. You need not fully define the package bodies until you are ready to complete the application.

  • Hidden Implementation Details

    Packages let you share your interface information in the package specification, and hide the implementation details in the package body. Hiding the implementation details in the body has these advantages:

    • You can change the implementation details without affecting the application interface.

    • Application users cannot develop code that depends on implementation details that you might want to change.

  • Added Functionality

    Package public variables and cursors can persist for the life of a session. They can be shared by all subprograms that run in the environment. They let you maintain data across transactions without storing it in the database. (For the situations in which package public variables and cursors do not persist for the life of a session, see "Package State".)

  • Better Performance

    The first time you invoke a package subprogram, Oracle Database loads the whole package into memory. Subsequent invocations of other subprograms in same the package require no disk I/O.

    Packages prevent cascading dependencies and unnecessary recompiling. For example, if you change the body of a package function, Oracle Database does not recompile other subprograms that invoke the function, because these subprograms depend only on the parameters and return value that are declared in the specification.

  • Easier to Grant Roles

    You can grant roles on the package, instead of granting roles on each object in the package.


Note:

You cannot reference host variables from inside a package.

Package Specification

A package specification declares public items. The scope of a public item is the schema of the package. A public item is visible everywhere in the schema. To reference a public item that is in scope but not visible, qualify it with the package name. (For information about scope, visibility, and qualification, see "Scope and Visibility of Identifiers".)

Each public item declaration has all information needed to use the item. For example, suppose that a package specification declares the function factorial this way:

FUNCTION factorial (n INTEGER) RETURN INTEGER; -- returns n!

The declaration shows that factorial needs one argument of type INTEGER and returns a value of type INTEGER, which is invokers must know to invoke factorial. Invokers need not know how factorial is implemented (for example, whether it is iterative or recursive).


Note:

To restrict the use of your package to specified PL/SQL units, include the ACCESSIBLE BY clause in the package specification.

Topics

Appropriate Public Items

Appropriate public items are:

  • Types, variables, constants, subprograms, cursors, and exceptions used by multiple subprograms

    A type defined in a package specification is either a PL/SQL user-defined subtype (described in "User-Defined PL/SQL Subtypes") or a PL/SQL composite type (described in Chapter 5, "PL/SQL Collections and Records").


    Note:

    A PL/SQL composite type defined in a package specification is incompatible with an identically defined local or standalone type (see Example 5-31, Example 5-32, and Example 5-37).

  • Associative array types of standalone subprogram parameters

    You cannot declare an associative array type at schema level. Therefore, to pass an associative array variable as a parameter to a standalone subprogram, you must declare the type of that variable in a package specification. Doing so makes the type available to both the invoked subprogram (which declares a formal parameter of that type) and to the invoking subprogram or anonymous block (which declares a variable of that type). See Example 10-2.

  • Variables that must remain available between subprogram invocations in the same session

  • Subprograms that read and write public variables ("get" and "set" subprograms)

    Provide these subprograms to discourage package users from reading and writing public variables directly.

  • Subprograms that invoke each other

    You need not worry about compilation order for package subprograms, as you must for standalone subprograms that invoke each other.

  • Overloaded subprograms

    Overloaded subprograms are variations of the same subprogram. That is, they have the same name but different formal parameters. For more information about them, see "Overloaded Subprograms".


Note:

You cannot reference remote package public variables, even indirectly. For example, if a subprogram refers to a package public variable, you cannot invoke the subprogram through a database link.

Creating Package Specifications

To create a package specification, use the "CREATE PACKAGE Statement".

In Example 10-1, the specification for the package trans_data declares two public types and three public variables.

Example 10-1 Simple Package Specification

CREATE OR REPLACE PACKAGE trans_data AUTHID DEFINER AS
  TYPE TimeRec IS RECORD (
    minutes SMALLINT,
    hours   SMALLINT);
  TYPE TransRec IS RECORD (
    category VARCHAR2(10),
    account  INT,
    amount   REAL,
    time_of  TimeRec);
  minimum_balance     CONSTANT REAL := 10.00;
  number_processed    INT;
  insufficient_funds  EXCEPTION;
  PRAGMA EXCEPTION_INIT(insufficient_funds, -4097);
END trans_data;
/

In Example 10-2, the specification for the package aa_pkg declares an associative array type, aa_type. Then, the standalone procedure print_aa declares a formal parameter of type aa_type. Next, the anonymous block declares a variable of type aa_type, populates it, and passes it to the procedure print_aa, which prints it.

Example 10-2 Passing Associative Array to Standalone Subprogram

CREATE OR REPLACE PACKAGE aa_pkg AUTHID DEFINER IS
  TYPE aa_type IS TABLE OF INTEGER INDEX BY VARCHAR2(15);
END;
/
CREATE OR REPLACE PROCEDURE print_aa (
  aa aa_pkg.aa_type
) AUTHID DEFINER IS
  i  VARCHAR2(15);
BEGIN
  i := aa.FIRST;
 
  WHILE i IS NOT NULL LOOP
    DBMS_OUTPUT.PUT_LINE (aa(i) || '  ' || i);
    i := aa.NEXT(i);
  END LOOP;
END;
/
DECLARE
  aa_var  aa_pkg.aa_type;
BEGIN
  aa_var('zero') := 0;
  aa_var('one') := 1;
  aa_var('two') := 2;
  print_aa(aa_var);
END;
/

Result:

1  one
2  two
0  zero

Because the package specifications in Example 10-1 and Example 10-2 do not declare cursors or subprograms, the packages trans_data and aa_pkg do not need bodies.

Package Body

If a package specification declares cursors or subprograms, then a package body is required; otherwise, it is optional. The package body and package specification must be in the same schema.

Every cursor or subprogram declaration in the package specification must have a corresponding definition in the package body. The headings of corresponding subprogram declarations and definitions must match word for word, except for white space.

To create a package body, use the "CREATE PACKAGE BODY Statement".

In Example 10-3, the headings of the corresponding subprogram declaration and definition do not match word for word; therefore, PL/SQL raises an exception, even though employees.hire_date%TYPE is DATE.

Example 10-3 Matching Package Specification and Body

CREATE PACKAGE emp_bonus AS
  PROCEDURE calc_bonus (date_hired employees.hire_date%TYPE);
END emp_bonus;
/
CREATE PACKAGE BODY emp_bonus AS
  -- DATE does not match employees.hire_date%TYPE
  PROCEDURE calc_bonus (date_hired DATE) IS
  BEGIN
    DBMS_OUTPUT.PUT_LINE
      ('Employees hired on ' || date_hired || ' get bonus.');
  END;
END emp_bonus;
/

Result:

Warning: Package Body created with compilation errors.

Show errors (in SQL*Plus):

SHOW ERRORS

Result:

Errors for PACKAGE BODY EMP_BONUS:
 
LINE/COL ERROR
-------- -----------------------------------------------------------------
2/13     PLS-00323: subprogram or cursor 'CALC_BONUS' is declared in a
         package specification and must be defined in the package body

Correct problem:

CREATE OR REPLACE PACKAGE BODY emp_bonus AS
  PROCEDURE calc_bonus
    (date_hired employees.hire_date%TYPE) IS
  BEGIN
    DBMS_OUTPUT.PUT_LINE
      ('Employees hired on ' || date_hired || ' get bonus.');
  END;
END emp_bonus;
/

Result:

Package body created.

The cursors and subprograms declared in the package specification and defined in the package body are public items that can be referenced from outside the package. The package body can also declare and define private items that cannot be referenced from outside the package, but are necessary for the internal workings of the package.

Finally, the body can have an initialization part, whose statements initialize public variables and do other one-time setup steps. The initialization part runs only the first time the package is referenced. The initialization part can include an exception handler.

You can change the package body without changing the specification or the references to the public items.

Package Instantiation and Initialization

When a session references a package item, Oracle Database instantiates the package for that session. Every session that references a package has its own instantiation of that package.

When Oracle Database instantiates a package, it initializes it. Initialization includes whichever of the following are applicable:

  • Assigning initial values to public constants

  • Assigning initial values to public variables whose declarations specify them

  • Executing the initialization part of the package body

Package State

The values of the variables, constants, and cursors that a package declares (in either its specification or body) comprise its package state. If a PL/SQL package declares at least one variable, constant, or cursor, then the package is stateful; otherwise, it is stateless.

Each session that references a package item has its own instantiation of that package. If the package is stateful, the instantiation includes its state. The package state persists for the life of a session, except in these situations:

  • The package is SERIALLY_REUSABLE.

    For details, see "SERIALLY_REUSABLE Packages".

  • The package body is recompiled.

    If the body of an instantiated, stateful package is recompiled (either explicitly, with the "ALTER PACKAGE Statement", or implicitly), the next invocation of a subprogram in the package causes Oracle Database to discard the existing package state and raise the exception ORA-04068.

    After PL/SQL raises the exception, a reference to the package causes Oracle Database to re-instantiate the package, which re-initializes it. Therefore, previous changes to the package state are lost. (For information about initialization, see "Package Instantiation and Initialization".)

  • Any of the session's instantiated packages are invalidated and revalidated.

    All of a session's package instantiations (including package states) can be lost if any of the session's instantiated packages are invalidated and revalidated. For information about invalidation and revalidation of schema objects, see Oracle Database Development Guide.

As of Oracle Database 11g Release 2 (11.2.0.2), Oracle Database treats a package as stateless if its state is constant for the life of a session (or longer). This is the case for a package whose items are all compile-time constants.

A compile-time constant is a constant whose value the PL/SQL compiler can determine at compilation time. A constant whose initial value is a literal is always a compile-time constant. A constant whose initial value is not a literal, but which the optimizer reduces to a literal, is also a compile-time constant. Whether the PL/SQL optimizer can reduce a nonliteral expression to a literal depends on optimization level. Therefore, a package that is stateless when compiled at one optimization level might be stateful when compiled at a different optimization level. For information about the optimizer, see "PL/SQL Optimizer".

SERIALLY_REUSABLE Packages

SERIALLY_REUSABLE packages let you design applications that manage memory better for scalability.

If a package is not SERIALLY_REUSABLE, its package state is stored in the user global area (UGA) for each user. Therefore, the amount of UGA memory needed increases linearly with the number of users, limiting scalability. The package state can persist for the life of a session, locking UGA memory until the session ends. In some applications, such as Oracle Office, a typical session lasts several days.

If a package is SERIALLY_REUSABLE, its package state is stored in a work area in a small pool in the system global area (SGA). The package state persists only for the life of a server call. After the server call, the work area returns to the pool. If a subsequent server call references the package, then Oracle Database reuses an instantiation from the pool. Reusing an instantiation re-initializes it; therefore, changes made to the package state in previous server calls are invisible. (For information about initialization, see "Package Instantiation and Initialization".)


Note:

Trying to access a SERIALLY_REUSABLE package from a database trigger, or from a PL/SQL subprogram invoked by a SQL statement, raises an error.

Topics

Creating SERIALLY_REUSABLE Packages

To create a SERIALLY_REUSABLE package, include the SERIALLY_REUSABLE pragma in the package specification and, if it exists, the package body.

Example 10-4 creates two very simple SERIALLY_REUSABLE packages, one with only a specification, and one with both a specification and a body.

Example 10-4 Creating SERIALLY_REUSABLE Packages

-- Create bodiless SERIALLY_REUSABLE package:
 
CREATE OR REPLACE PACKAGE bodiless_pkg AUTHID DEFINER IS
  PRAGMA SERIALLY_REUSABLE;
  n NUMBER := 5;
END;
/
 
-- Create SERIALLY_REUSABLE package with specification and body:
 
CREATE OR REPLACE PACKAGE pkg AUTHID DEFINER IS
  PRAGMA SERIALLY_REUSABLE;
  n NUMBER := 5;
END;
/
 
CREATE OR REPLACE PACKAGE BODY pkg IS
  PRAGMA SERIALLY_REUSABLE;
BEGIN
  n := 5;
END;
/

SERIALLY_REUSABLE Package Work Unit

For a SERIALLY_REUSABLE package, the work unit is a server call. You must use its public variables only within the work unit.


Note:

If you make a mistake and depend on the value of a public variable that was set in a previous work unit, then your program can fail. PL/SQL cannot check for such cases.

In Example 10-5, the bodiless packages pkg and pkg_sr are the same, except that pkg_sr is SERIALLY_REUSABLE and pkg is not. Each package declares public variable n with initial value 5. Then, an anonymous block changes the value of each variable to 10. Next, another anonymous block prints the value of each variable. The value of pkg.n is still 10, because the state of pkg persists for the life of the session. The value of pkg_sr.n is 5, because the state of pkg_sr persists only for the life of the server call.

Example 10-5 Effect of SERIALLY_REUSABLE Pragma

CREATE OR REPLACE PACKAGE pkg IS
  n NUMBER := 5;
END pkg;
/

CREATE OR REPLACE PACKAGE sr_pkg IS
  PRAGMA SERIALLY_REUSABLE;
  n NUMBER := 5;
END sr_pkg;
/

BEGIN
  pkg.n := 10;
  sr_pkg.n := 10;
END;
/

BEGIN
  DBMS_OUTPUT.PUT_LINE('pkg.n: ' || pkg.n);
  DBMS_OUTPUT.PUT_LINE('sr_pkg.n: ' || sr_pkg.n);
END;
/

Result:

pkg.n: 10
sr_pkg.n: 5

After the work unit (server call) of a SERIALLY_REUSABLE package completes, Oracle Database does the following:

  • Closes any open cursors.

  • Frees some nonreusable memory (for example, memory for collection and long VARCHAR2 variables)

  • Returns the package instantiation to the pool of reusable instantiations kept for this package.

Explicit Cursors in SERIALLY_REUSABLE Packages

An explicit cursor in a SERIALLY_REUSABLE package remains open until either you close it or its work unit (server call) ends. To re-open the cursor, you must make a new server call. A server call can be different from a subprogram invocation, as Example 10-6 shows.

In contrast, an explicit cursor in a package that is not SERIALLY_REUSABLE remains open until you either close it or disconnect from the session.

Example 10-6 Cursor in SERIALLY_REUSABLE Package Open at Call Boundary

DROP TABLE people;
CREATE TABLE people (name VARCHAR2(20));
 
INSERT INTO people (name) VALUES ('John Smith');
INSERT INTO people (name) VALUES ('Mary Jones');
INSERT INTO people (name) VALUES ('Joe Brown');
INSERT INTO people (name) VALUES ('Jane White');

CREATE OR REPLACE PACKAGE sr_pkg IS
  PRAGMA SERIALLY_REUSABLE;
  CURSOR c IS SELECT name FROM people;
END sr_pkg;
/
 
CREATE OR REPLACE PROCEDURE fetch_from_cursor IS
  name_  VARCHAR2(200);
BEGIN
  IF sr_pkg.c%ISOPEN THEN
    DBMS_OUTPUT.PUT_LINE('Cursor is open.');
  ELSE
    DBMS_OUTPUT.PUT_LINE('Cursor is closed; opening now.');
    OPEN sr_pkg.c;
  END IF;
 
  FETCH sr_pkg.c INTO name_;
  DBMS_OUTPUT.PUT_LINE('Fetched: ' || name_);
 
  FETCH sr_pkg.c INTO name;
    DBMS_O^9UTPUT.PUT_LINE('Fetched: ' || name_);
  END fetch_from_cursor;
/
 

First call to server:

BEGIN
  fetch_from_cursor;
  fetch_from_cursor;
END;
/

Result:

Cursor is closed; opening now.
Fetched: John Smith
Fetched: Mary Jones
Cursor is open.
Fetched: Joe Brown
Fetched: Jane White
 

New call to server:

BEGIN
  fetch_from_cursor;
  fetch_from_cursor;
END;
/

Result:

Cursor is closed; opening now.
Fetched: John Smith
Fetched: Mary Jones
Cursor is open.
Fetched: Joe Brown
Fetched: Jane White

Package Writing Guidelines

  • Become familiar with the packages that Oracle Database supplies, and avoid writing packages that duplicate their features.

    For more information about the packages that Oracle Database supplies, see Oracle Database PL/SQL Packages and Types Reference.

  • Keep your packages general so that future applications can reuse them.

  • Design and define the package specifications before the package bodies.

  • In package specifications, declare only items that must be visible to invoking programs.

    This practice prevents other developers from building unsafe dependencies on your implementation details and reduces the need for recompilation.

    If you change the package specification, you must recompile any subprograms that invoke the public subprograms of the package. If you change only the package body, you need not recompile those subprograms.

  • Declare public cursors in package specifications and define them in package bodies, as in Example 10-7.

    This practice lets you hide cursors' queries from package users and change them without changing cursor declarations.

  • Assign initial values in the initialization part of the package body instead of in declarations.

    This practice has these advantages:

    • The code for computing the initial values can be more complex and better documented.

    • If computing an initial value raises an exception, the initialization part can handle it with its own exception handler.

  • If you implement a database application as several PL/SQL packages—one package that provides the API and helper packages to do the work, then make the helper packages available only to the API package, as in Example 10-8.

In Example 10-7, the declaration and definition of the cursor c1 are in the specification and body, respectively, of the package emp_stuff. The cursor declaration specifies only the data type of the return value, not the query, which appears in the cursor definition (for complete syntax and semantics, see "Explicit Cursor Declaration and Definition").

Example 10-7 Separating Cursor Declaration and Definition in Package

CREATE PACKAGE emp_stuff AS
  CURSOR c1 RETURN employees%ROWTYPE;  -- Declare cursor
END emp_stuff;
/
CREATE PACKAGE BODY emp_stuff AS
  CURSOR c1 RETURN employees%ROWTYPE IS
    SELECT * FROM employees WHERE salary > 2500;  -- Define cursor
END emp_stuff;
/

Example 10-8 creates an API package and a helper package. Because of the ACCESSIBLE BY clause in the helper package specification, only the API package can access the helper package.

Example 10-8 ACCESSIBLE BY Clause

CREATE OR REPLACE PACKAGE helper
  AUTHID DEFINER
  ACCESSIBLE BY (api)
IS
  PROCEDURE h1;
  PROCEDURE h2;
END;
/
 
CREATE OR REPLACE PACKAGE BODY helper
IS
  PROCEDURE h1 IS
  BEGIN
    DBMS_OUTPUT.PUT_LINE('Helper procedure h1');
  END;
 
  PROCEDURE h2 IS
  BEGIN
    DBMS_OUTPUT.PUT_LINE('Helper procedure h2');
  END;
END;
/
 
CREATE OR REPLACE PACKAGE api
  AUTHID DEFINER
IS
  PROCEDURE p1;
  PROCEDURE p2;
END;
/
 
CREATE OR REPLACE PACKAGE BODY api
IS
  PROCEDURE p1 IS
  BEGIN
    DBMS_OUTPUT.PUT_LINE('API procedure p1');
    helper.h1;
  END;
 
  PROCEDURE p2 IS
  BEGIN
    DBMS_OUTPUT.PUT_LINE('API procedure p2');
    helper.h2;
  END;
END;
/
 

Invoke procedures in API package:

BEGIN
  api.p1;
  api.p2;
END;
/
 

Result:

API procedure p1
Helper procedure h1
API procedure p2
Helper procedure h2

Invoke a procedure in helper package:

BEGIN
  helper.h1;
END;
/
 

Result:

SQL> BEGIN
  2    helper.h1;
  3  END;
  4  /
  helper.h1;
  *
ERROR at line 2:
ORA-06550: line 2, column 3:
PLS-00904: insufficient privilege to access object HELPER
ORA-06550: line 2, column 3:
PL/SQL: Statement ignored

Package Example

Example 10-9 creates a table, log, and a package, emp_admin, and then invokes package subprograms from an anonymous block. The package has both specification and body.

The specification declares a public type, cursor, and exception, and three public subprograms. One public subprogram is overloaded (for information about overloaded subprograms, see "Overloaded Subprograms").

The body declares a private variable, defines the public cursor and subprograms that the specification declares, declares and defines a private function, and has an initialization part.

The initialization part (which runs only the first time the anonymous block references the package) inserts one row into the table log and initializes the private variable number_hired to zero. Every time the package procedure hire_employee is invoked, it updates the private variable number_hired.

Example 10-9 Creating emp_admin Package

-- Log to track changes (not part of package):

DROP TABLE log;
CREATE TABLE log (
  date_of_action  DATE,
  user_id         VARCHAR2(20),
  package_name    VARCHAR2(30)
);

-- Package specification:

CREATE OR REPLACE PACKAGE emp_admin AUTHID DEFINER AS
  -- Declare public type, cursor, and exception:
  TYPE EmpRecTyp IS RECORD (emp_id NUMBER, sal NUMBER);
  CURSOR desc_salary RETURN EmpRecTyp;
  invalid_salary EXCEPTION;

  -- Declare public subprograms:

  FUNCTION hire_employee (
    last_name       VARCHAR2,
    first_name      VARCHAR2,
    email           VARCHAR2,
    phone_number    VARCHAR2,
    job_id          VARCHAR2,
    salary          NUMBER,
    commission_pct  NUMBER,
    manager_id      NUMBER,
    department_id   NUMBER
  ) RETURN NUMBER;

  -- Overload preceding public subprogram:
  PROCEDURE fire_employee (emp_id NUMBER);
  PROCEDURE fire_employee (emp_email VARCHAR2);

  PROCEDURE raise_salary (emp_id NUMBER, amount NUMBER);
  FUNCTION nth_highest_salary (n NUMBER) RETURN EmpRecTyp;
END emp_admin;
/
-- Package body:

CREATE OR REPLACE PACKAGE BODY emp_admin AS
  number_hired  NUMBER;  -- private variable, visible only in this package

  -- Define cursor declared in package specification:

  CURSOR desc_salary RETURN EmpRecTyp IS
    SELECT employee_id, salary
    FROM employees
    ORDER BY salary DESC;

  -- Define subprograms declared in package specification:

  FUNCTION hire_employee (
    last_name       VARCHAR2,
    first_name      VARCHAR2,
    email           VARCHAR2,
    phone_number    VARCHAR2,
    job_id          VARCHAR2,
    salary          NUMBER,
    commission_pct  NUMBER,
    manager_id      NUMBER,
    department_id   NUMBER
  ) RETURN NUMBER
  IS
    new_emp_id NUMBER;
  BEGIN
    new_emp_id := employees_seq.NEXTVAL;
    INSERT INTO employees (
      employee_id,
      last_name,
      first_name,
      email,
      phone_number,
      hire_date,
      job_id,
      salary,
      commission_pct,
      manager_id,
      department_id
    )
    VALUES (
      new_emp_id,
      hire_employee.last_name,
      hire_employee.first_name,
      hire_employee.email,
      hire_employee.phone_number,
      SYSDATE,
      hire_employee.job_id,
      hire_employee.salary,
      hire_employee.commission_pct,
      hire_employee.manager_id,
      hire_employee.department_id
    );
    number_hired := number_hired + 1;
    DBMS_OUTPUT.PUT_LINE('The number of employees hired is ' 
                         || TO_CHAR(number_hired) );   
    RETURN new_emp_id;
  END hire_employee;

  PROCEDURE fire_employee (emp_id NUMBER) IS
  BEGIN
    DELETE FROM employees WHERE employee_id = emp_id;
  END fire_employee;

  PROCEDURE fire_employee (emp_email VARCHAR2) IS
  BEGIN
    DELETE FROM employees WHERE email = emp_email;
  END fire_employee;

  -- Define private function, available only inside package:

  FUNCTION sal_ok (
    jobid VARCHAR2,
    sal NUMBER
  ) RETURN BOOLEAN
  IS
    min_sal NUMBER;
    max_sal NUMBER;
  BEGIN
    SELECT MIN(salary), MAX(salary)
    INTO min_sal, max_sal
    FROM employees
    WHERE job_id = jobid;

    RETURN (sal >= min_sal) AND (sal <= max_sal);
  END sal_ok;

  PROCEDURE raise_salary (
    emp_id NUMBER,
    amount NUMBER
  )
  IS
    sal NUMBER(8,2);
    jobid VARCHAR2(10);
  BEGIN
    SELECT job_id, salary INTO jobid, sal
    FROM employees
    WHERE employee_id = emp_id;

    IF sal_ok(jobid, sal + amount) THEN  -- Invoke private function
      UPDATE employees
      SET salary = salary + amount
      WHERE employee_id = emp_id;
    ELSE
      RAISE invalid_salary;
    END IF;
  EXCEPTION
    WHEN invalid_salary THEN
      DBMS_OUTPUT.PUT_LINE ('The salary is out of the specified range.');
  END raise_salary;

  FUNCTION nth_highest_salary (
    n NUMBER
  ) RETURN EmpRecTyp
  IS
    emp_rec  EmpRecTyp;
  BEGIN
    OPEN desc_salary;
    FOR i IN 1..n LOOP
      FETCH desc_salary INTO emp_rec;
    END LOOP;
    CLOSE desc_salary;
    RETURN emp_rec;
  END nth_highest_salary;

BEGIN  -- initialization part of package body
   INSERT INTO log (date_of_action, user_id, package_name)
   VALUES (SYSDATE, USER, 'EMP_ADMIN');
   number_hired := 0;
END emp_admin;
/
-- Invoke packages subprograms in anonymous block:

DECLARE
  new_emp_id NUMBER(6);
BEGIN
  new_emp_id := emp_admin.hire_employee (
    'Belden',
    'Enrique',
    'EBELDEN',
    '555.111.2222',
    'ST_CLERK',
    2500,
    .1,
    101,
    110
  );
  DBMS_OUTPUT.PUT_LINE ('The employee id is ' || TO_CHAR(new_emp_id));
  emp_admin.raise_salary (new_emp_id, 100);

  DBMS_OUTPUT.PUT_LINE (
    'The 10th highest salary is '||
    TO_CHAR (emp_admin.nth_highest_salary(10).sal) ||
             ', belonging to employee: ' ||
             TO_CHAR (emp_admin.nth_highest_salary(10).emp_id)
  );

  emp_admin.fire_employee(new_emp_id);
  -- You can also delete the newly added employee as follows:
  -- emp_admin.fire_employee('EBELDEN');
END;
/

Result is similar to:

The number of employees hired is 1
The employee id is 210
The 10th highest salary is 11500, belonging to employee: 168

How STANDARD Package Defines the PL/SQL Environment

A package named STANDARD defines the PL/SQL environment. The package specification declares public types, variables, exceptions, subprograms, which are available automatically to PL/SQL programs. For example, package STANDARD declares function ABS, which returns the absolute value of its argument, as follows:

FUNCTION ABS (n NUMBER) RETURN NUMBER;

The contents of package STANDARD are directly visible to applications. You need not qualify references to its contents by prefixing the package name. For example, you might invoke ABS from a database trigger, stored subprogram, Oracle tool, or 3GL application, as follows:

abs_diff := ABS(x - y);

If you declare your own version of ABS, your local declaration overrides the public declaration. You can still invoke the SQL function by specifying its full name:

abs_diff := STANDARD.ABS(x - y);

Most SQL functions are overloaded. For example, package STANDARD contains these declarations:

FUNCTION TO_CHAR (right DATE) RETURN VARCHAR2;
FUNCTION TO_CHAR (left NUMBER) RETURN VARCHAR2;
FUNCTION TO_CHAR (left DATE, right VARCHAR2) RETURN VARCHAR2;
FUNCTION TO_CHAR (left NUMBER, right VARCHAR2) RETURN VARCHAR2;

PL/SQL resolves an invocation of TO_CHAR by matching the number and data types of the formal and actual parameters.

PKr}Kh^PKwD#OEBPS/cursor_for_loop_statement.htms Cursor FOR LOOP Statement

Cursor FOR LOOP Statement

The cursor FOR LOOP statement implicitly declares its loop index as a record variable of the row type that a specified cursor returns, and then opens a cursor. With each iteration, the cursor FOR LOOP statement fetches a row from the result set into the record. When there are no more rows to fetch, the cursor FOR LOOP statement closes the cursor. The cursor also closes if a statement inside the loop transfers control outside the loop or raises an exception.

Topics

Syntax

cursor_for_loop_statement ::=

Description of cursor_for_loop_statement.gif follows

See "statement ::=".

Semantics

record

Name for the loop index that the cursor FOR LOOP statement implicitly declares as a %ROWTYPE record variable of the type that cursor or select_statement returns.

record is local to the cursor FOR LOOP statement. Statements inside the loop can reference record and its fields. They can reference virtual columns only by aliases. Statements outside the loop cannot reference record. After the cursor FOR LOOP statement runs, record is undefined.

cursor

Name of an explicit cursor (not a cursor variable) that is not open when the cursor FOR LOOP is entered.

actual_cursor_parameter

Actual parameter that corresponds to a formal parameter of cursor.

select_statement

SQL SELECT statement (not PL/SQL SELECT INTO statement). For select_statement, PL/SQL declares, opens, fetches from, and closes an implicit cursor. However, because select_statement is not an independent statement, the implicit cursor is internal—you cannot reference it with the name SQL.


See Also:

Oracle Database SQL Language Reference for SELECT statement syntax

label

Label that identifies cursor_for_loop_statement (see "statement ::=" and "label"). CONTINUE, EXIT, and GOTO statements can reference this label.

Labels improve readability, especially when LOOP statements are nested, but only if you ensure that the label in the END LOOP statement matches a label at the beginning of the same LOOP statement (the compiler does not check).

PKxsPKwDOEBPS/openfor_statement.htm&; OPEN FOR Statement

OPEN FOR Statement

The OPEN FOR statement associates a cursor variable with a query, allocates database resources to process the query, identifies the result set, and positions the cursor before the first row of the result set. If the query has a FOR UPDATE clause, then the OPEN FOR statement locks the rows of the result set.

Topics

Syntax

open_for_statement ::=

Description of open_for_statement.gif follows

using_clause ::=

Description of using_clause.gif follows

Semantics

open_for_statement

cursor_variable

Name of a cursor variable. If cursor_variable is the formal parameter of a subprogram, then it must not have a return type. For information about cursor variables as subprogram parameters, see "Cursor Variables as Subprogram Parameters".

:host_cursor_variable

Name of a cursor variable that was declared in a PL/SQL host environment and passed to PL/SQL as a bind variable. Do not put space between the colon (:) and host_cursor_variable.

The data type of a host cursor variable is compatible with the return type of any PL/SQL cursor variable.

select_statement

SQL SELECT statement (not a PL/SQL SELECT INTO statement). Typically, select_statement returns multiple rows.


See:

Oracle Database SQL Language Reference for SELECT statement syntax

dynamic_string

String literal, string variable, or string expression of the data type CHAR, VARCHAR2, or CLOB, which represents a SQL SELECT statement. Typically, dynamic_statement represents a SQL SELECT statement that returns multiple rows.

using_clause

Specifies bind variables, using positional notation.


Note:

If you repeat placeholder names in dynamic_sql_statement, be aware that the way placeholders are associated with bind variables depends on the kind of dynamic SQL statement. For details, see "Repeated Placeholder Names in Dynamic SQL Statements."

Restriction on using_clause Use if and only if select_statement or dynamic_sql_stmt includes placeholders for bind variables.

IN, OUT, IN OUT

Parameter modes of bind variables. An IN bind variable passes its value to the select_statement or dynamic_string. An OUT bind variable stores a value that dynamic_string returns. An IN OUT bind variable passes its initial value to dynamic_string and stores a value that dynamic_string returns. Default: IN.

bind_argument

Expression whose value replaces its corresponding placeholder in select_statement or dynamic_string at run time. You must specify a bind_argument for every placeholder.


Note:

Bind variables can be evaluated in any order. If a program determines order of evaluation, then at the point where the program does so, its behavior is undefined.

Restrictions on bind_argument 

  • bind_argument cannot be an associative array indexed by string.

  • bind_argument cannot be the reserved word NULL.

    To pass the value NULL to the dynamic SQL statement, use an uninitialized variable where you want to use NULL, as in Example 7-7.

PKt&&PKwDOEBPS/overview.htm Overview of PL/SQL

1 Overview of PL/SQL

PL/SQL, the Oracle procedural extension of SQL, is a portable, high-performance transaction-processing language. This chapter explains its advantages and briefly describes its main features and its architecture.

Topics

Advantages of PL/SQL

PL/SQL has these advantages:

Tight Integration with SQL

PL/SQL is tightly integrated with SQL, the most widely used database manipulation language. For example:

  • PL/SQL lets you use all SQL data manipulation, cursor control, and transaction control statements, and all SQL functions, operators, and pseudocolumns.

  • PL/SQL fully supports SQL data types.

    You need not convert between PL/SQL and SQL data types. For example, if your PL/SQL program retrieves a value from a column of the SQL type VARCHAR2, it can store that value in a PL/SQL variable of the type VARCHAR2.

    You can give a PL/SQL data item the data type of a column or row of a database table without explicitly specifying that data type (see "%TYPE Attribute" and "%ROWTYPE Attribute").

  • PL/SQL lets you run a SQL query and process the rows of the result set one at a time (see "Processing a Query Result Set One Row at a Time").

  • PL/SQL functions can be declared and defined in the WITH clauses of SQL SELECT statements (see Oracle Database SQL Language Reference).

PL/SQL supports both static and dynamic SQL. Static SQL is SQL whose full text is known at compile time. Dynamic SQL is SQL whose full text is not known until run time. Dynamic SQL lets you make your applications more flexible and versatile. For more information, see Chapter 6, "PL/SQL Static SQL" and Chapter 7, "PL/SQL Dynamic SQL".

High Performance

PL/SQL lets you send a block of statements to the database, significantly reducing traffic between the application and the database.

Bind Variables

When you embed a SQL INSERT, UPDATE, DELETE, MERGE, or SELECT statement directly in your PL/SQL code, the PL/SQL compiler turns the variables in the WHERE and VALUES clauses into bind variables (for details, see "Resolution of Names in Static SQL Statements"). Oracle Database can reuse these SQL statements each time the same code runs, which improves performance.

PL/SQL does not create bind variables automatically when you use dynamic SQL, but you can use them with dynamic SQL by specifying them explicitly (for details, see "EXECUTE IMMEDIATE Statement").

Subprograms

PL/SQL subprograms are stored in executable form, which can be invoked repeatedly. Because stored subprograms run in the database server, a single invocation over the network can start a large job. This division of work reduces network traffic and improves response times. Stored subprograms are cached and shared among users, which lowers memory requirements and invocation overhead. For more information about subprograms, see "Subprograms".

Optimizer

The PL/SQL compiler has an optimizer that can rearrange code for better performance. For more information about the optimizer, see "PL/SQL Optimizer".

High Productivity

PL/SQL lets you write compact code for manipulating data. Just as a scripting language like PERL can read, transform, and write data in files, PL/SQL can query, transform, and update data in a database.

PL/SQL has many features that save designing and debugging time, and it is the same in all environments. If you learn to use PL/SQL with one Oracle tool, you can transfer your knowledge to other Oracle tools. For example, you can create a PL/SQL block in SQL Developer and then use it in an Oracle Forms trigger. For an overview of PL/SQL features, see "Main Features of PL/SQL".

Portability

You can run PL/SQL applications on any operating system and platform where Oracle Database runs.

Scalability

PL/SQL stored subprograms increase scalability by centralizing application processing on the database server. The shared memory facilities of the shared server let Oracle Database support thousands of concurrent users on a single node. For more information about subprograms, see "Subprograms".

For further scalability, you can use Oracle Connection Manager to multiplex network connections. For information about Oracle Connection Manager, see Oracle Database Net Services Reference.

Manageability

PL/SQL stored subprograms increase manageability because you can maintain only one copy of a subprogram, on the database server, rather than one copy on each client system. Any number of applications can use the subprograms, and you can change the subprograms without affecting the applications that invoke them. For more information about subprograms, see "Subprograms".

Support for Object-Oriented Programming

PL/SQL supports object-oriented programming with "Abstract Data Types".

Main Features of PL/SQL

PL/SQL combines the data-manipulating power of SQL with the processing power of procedural languages.

When you can solve a problem with SQL, you can issue SQL statements from your PL/SQL program, without learning new APIs.

Like other procedural programming languages, PL/SQL lets you declare constants and variables, control program flow, define subprograms, and trap runtime errors.

You can break complex problems into easily understandable subprograms, which you can reuse in multiple applications.

Topics

Error Handling

PL/SQL makes it easy to detect and handle errors. When an error occurs, PL/SQL raises an exception. Normal execution stops and control transfers to the exception-handling part of the PL/SQL block. You do not have to check every operation to ensure that it succeeded, as in a C program. For more information, see Chapter 11, "PL/SQL Error Handling".

Blocks

The basic unit of a PL/SQL source program is the block, which groups related declarations and statements.

A PL/SQL block is defined by the keywords DECLARE, BEGIN, EXCEPTION, and END. These keywords divide the block into a declarative part, an executable part, and an exception-handling part. Only the executable part is required. A block can have a label.

Example 1-1 shows the basic structure of a PL/SQL block. For syntax details, see "Block".

Example 1-1 PL/SQL Block Structure

<< label >> (optional)
DECLARE    -- Declarative part (optional)
  -- Declarations of local types, variables, & subprograms

BEGIN      -- Executable part (required)
  -- Statements (which can use items declared in declarative part)

[EXCEPTION -- Exception-handling part (optional)
  -- Exception handlers for exceptions (errors) raised in executable part]
END;

Declarations are local to the block and cease to exist when the block completes execution, helping to avoid cluttered namespaces for variables and subprograms.

Blocks can be nested: Because a block is an executable statement, it can appear in another block wherever an executable statement is allowed.

You can submit a block to an interactive tool (such as SQL*Plus or Enterprise Manager) or embed it in an Oracle Precompiler or OCI program. The interactive tool or program runs the block one time. The block is not stored in the database, and for that reason, it is called an anonymous block (even if it has a label).

An anonymous block is compiled each time it is loaded into memory, and its compilation has three stages:

  1. Syntax checking: PL/SQL syntax is checked, and a parse tree is generated.

  2. Semantic checking: Type checking and further processing on the parse tree.

  3. Code generation


Note:

An anonymous block is a SQL statement.

Variables and Constants

PL/SQL lets you declare variables and constants, and then use them wherever you can use an expression. As the program runs, the values of variables can change, but the values of constants cannot. For more information, see "Declarations" and "Assigning Values to Variables".

Subprograms

A PL/SQL subprogram is a named PL/SQL block that can be invoked repeatedly. If the subprogram has parameters, their values can differ for each invocation. PL/SQL has two types of subprograms, procedures and functions. A function returns a result. For more information about PL/SQL subprograms, see Chapter 8, "PL/SQL Subprograms."

PL/SQL also lets you invoke external programs written in other languages. For more information, see "External Subprograms".

Packages

A package is a schema object that groups logically related PL/SQL types, variables, constants, subprograms, cursors, and exceptions. A package is compiled and stored in the database, where many applications can share its contents. You can think of a package as an application.

You can write your own packages—for details, see Chapter 10, "PL/SQL Packages." You can also use the many product-specific packages that Oracle Database supplies. For information about these, see Oracle Database PL/SQL Packages and Types Reference.

Triggers

A trigger is a named PL/SQL unit that is stored in the database and run in response to an event that occurs in the database. You can specify the event, whether the trigger fires before or after the event, and whether the trigger runs for each event or for each row affected by the event. For example, you can create a trigger that runs every time an INSERT statement affects the EMPLOYEES table.

For more information about triggers, see Chapter 9, "PL/SQL Triggers."

Input and Output

Most PL/SQL input and output (I/O) is done with SQL statements that store data in database tables or query those tables. For information about SQL statements, see Oracle Database SQL Language Reference.

All other PL/SQL I/O is done with PL/SQL packages that Oracle Database supplies, which Table 1-1 summarizes.

Table 1-1 PL/SQL I/O-Processing Packages

PackageDescriptionMore Information

DBMS_OUTPUT

Lets PL/SQL blocks, subprograms, packages, and triggers display output. Especially useful for displaying PL/SQL debugging information.

Oracle Database PL/SQL Packages and Types Reference


HTF

Has hypertext functions that generate HTML tags (for example, the HTF.ANCHOR function generates the HTML anchor tag <A>).

Oracle Database PL/SQL Packages and Types Reference


HTP

Has hypertext procedures that generate HTML tags.

Oracle Database PL/SQL Packages and Types Reference


DBMS_PIPE

Lets two or more sessions in the same instance communicate.

Oracle Database PL/SQL Packages and Types Reference


UTL_FILE

Lets PL/SQL programs read and write operating system files.

Oracle Database PL/SQL Packages and Types Reference


UTL_HTTP

Lets PL/SQL programs make Hypertext Transfer Protocol (HTTP) callouts, and access data on the Internet over HTTP.

Oracle Database PL/SQL Packages and Types Reference


UTL_SMTP

Sends electronic mails (emails) over Simple Mail Transfer Protocol (SMTP) as specified by RFC821.

Oracle Database PL/SQL Packages and Types Reference



To display output passed to DBMS_OUTPUT, you need another program, such as SQL*Plus. To see DBMS_OUTPUT output with SQL*Plus, you must first issue the SQL*Plus command SET SERVEROUTPUT ON.

Some subprograms in the packages in Table 1-1 can both accept input and display output, but they cannot accept data directly from the keyboard. To accept data directly from the keyboard, use the SQL*Plus commands PROMPT and ACCEPT.


See Also:


Data Abstraction

Data abstraction lets you work with the essential properties of data without being too involved with details. You can design a data structure first, and then design algorithms that manipulate it.

Topics

Cursors

A cursor is a pointer to a private SQL area that stores information about processing a specific SQL statement or PL/SQL SELECT INTO statement. You can use the cursor to retrieve the rows of the result set one at a time. You can use cursor attributes to get information about the state of the cursor—for example, how many rows the statement has affected so far. For more information about cursors, see "Cursors".

Composite Variables

A composite variable has internal components, which you can access individually. You can pass entire composite variables to subprograms as parameters. PL/SQL has two kinds of composite variables, collections and records.

In a collection, the internal components are always of the same data type, and are called elements. You access each element by its unique index. Lists and arrays are classic examples of collections.

In a record, the internal components can be of different data types, and are called fields. You access each field by its name. A record variable can hold a table row, or some columns from a table row.

For more information about composite variables, see Chapter 5, "PL/SQL Collections and Records."

%ROWTYPE Attribute

The %ROWTYPE attribute lets you declare a record that represents either a full or partial row of a database table or view. For every column of the full or partial row, the record has a field with the same name and data type. If the structure of the row changes, then the structure of the record changes accordingly. For more information about %ROWTYPE, see "%ROWTYPE Attribute".

%TYPE Attribute

The %TYPE attribute lets you declare a data item of the same data type as a previously declared variable or column (without knowing what that type is). If the declaration of the referenced item changes, then the declaration of the referencing item changes accordingly. The %TYPE attribute is particularly useful when declaring variables to hold database values. For more information about %TYPE, see "%TYPE Attribute".

Abstract Data Types

An Abstract Data Type (ADT) consists of a data structure and subprograms that manipulate the data. The variables that form the data structure are called attributes. The subprograms that manipulate the attributes are called methods.

ADTs are stored in the database. Instances of ADTs can be stored in tables and used as PL/SQL variables.

ADTs let you reduce complexity by separating a large system into logical components, which you can reuse.

In the static data dictionary view *_OBJECTS, the OBJECT_TYPE of an ADT is TYPE. In the static data dictionary view *_TYPES, the TYPECODE of an ADT is OBJECT.

For more information about ADTs, see "CREATE TYPE Statement".


Note:

ADTs are also called user-defined types and object types.


See Also:

Oracle Database Object-Relational Developer's Guide for information about ADTs (which it calls object types)

Control Statements

Control statements are the most important PL/SQL extension to SQL.

PL/SQL has three categories of control statements:

  • Conditional selection statements, which let you run different statements for different data values.

    For more information, see "Conditional Selection Statements".

  • Loop statements, which let you repeat the same statements with a series of different data values.

    For more information, see "LOOP Statements".

  • Sequential control statements, which allow you to go to a specified, labeled statement, or to do nothing.

    For more information, see "Sequential Control Statements".

Conditional Compilation

Conditional compilation lets you customize the functionality in a PL/SQL application without removing source text. For example, you can:

  • Use new features with the latest database release, and disable them when running the application in an older database release.

  • Activate debugging or tracing statements in the development environment, and hide them when running the application at a production site.

For more information, see "Conditional Compilation".

Processing a Query Result Set One Row at a Time

PL/SQL lets you issue a SQL query and process the rows of the result set one at a time. You can use a basic loop, as in Example 1-2, or you can control the process precisely by using individual statements to run the query, retrieve the results, and finish processing.

Example 1-2 Processing Query Result Rows One at a Time

BEGIN
  FOR someone IN (
    SELECT * FROM employees
    WHERE employee_id < 120
    ORDER BY employee_id
  )
  LOOP
    DB0MS_OUTPUT.PUT_LINE('First name = ' || someone.first_name ||
                         ', Last name = ' || someone.last_name);
  END LOOP;
END;
/

Result:

First name = Steven, Last name = King
First name = Neena, Last name = Kochhar
First name = Lex, Last name = De Haan
First name = Alexander, Last name = Hunold
First name = Bruce, Last name = Ernst
First name = David, Last name = Austin
First name = Valli, Last name = Pataballa
First name = Diana, Last name = Lorentz
First name = Nancy, Last name = Greenberg
First name = Daniel, Last name = Faviet
First name = John, Last name = Chen
First name = Ismael, Last name = Sciarra
First name = Jose Manuel, Last name = Urman
First name = Luis, Last name = Popp
First name = Den, Last name = Raphaely
First name = Alexander, Last name = Khoo
First name = Shelli, Last name = Baida
First name = Sigal, Last name = Tobias
First name = Guy, Last name = Himuro
First name = Karen, Last name = Colmenares

Architecture of PL/SQL

Topics

PL/SQL Engine

The PL/SQL compilation and runtime system is an engine that compiles and runs PL/SQL units. The engine can be installed in the database or in an application development tool, such as Oracle Forms.

In either environment, the PL/SQL engine accepts as input any valid PL/SQL unit. The engine runs procedural statements, but sends SQL statements to the SQL engine in the database, as shown in Figure 1-1.

Figure 1-1 PL/SQL Engine

Description of Figure 1-1 follows

Typically, the database processes PL/SQL units.

When an application development tool processes PL/SQL units, it passes them to its local PL/SQL engine. If a PL/SQL unit contains no SQL statements, the local engine processes the entire PL/SQL unit. This is useful if the application development tool can benefit from conditional and iterative control.

For example, Oracle Forms applications frequently use SQL statements to test the values of field entries and do simple computations. By using PL/SQL instead of SQL, these applications can avoid calls to the database.

PL/SQL Units and Compilation Parameters

A PL/SQL unit is one of these:

  • PL/SQL anonymous block

  • FUNCTION

  • LIBRARY

  • PACKAGE

  • PACKAGE BODY

  • PROCEDURE

  • TRIGGER

  • TYPE

  • TYPE BODY

PL/SQL units are affected by PL/SQL compilation parameters (a category of database initialization parameters). Different PL/SQL units—for example, a package specification and its body—can have different compilation parameter settings.

Table 1-2 summarizes the PL/SQL compilation parameters. To display the values of these parameters for specified or all PL/SQL units, query the static data dictionary view ALL_PLSQL_OBJECT_SETTINGS. For information about this view, see Oracle Database Reference.

Table 1-2 PL/SQL Compilation Parameters

ParameterDescription

PLSCOPE_SETTINGS

Controls the compile-time collection, cross-reference, and storage of PL/SQL source text identifier data. Used by the PL/Scope tool (see Oracle Database Development Guide).

For more information about PLSCOPE_SETTINGS, see Oracle Database Reference.

PLSQL_CCFLAGS

Lets you control conditional compilation of each PL/SQL unit independently.

For more information about PLSQL_CCFLAGS, see "How Conditional Compilation Works" and Oracle Database Reference.

PLSQL_CODE_TYPE

Specifies the compilation mode for PL/SQL units—INTERPRETED (the default) or NATIVE. For information about which mode to use, see "Determining Whether to Use PL/SQL Native Compilation".

If the optimization level (set by PLSQL_OPTIMIZE_LEVEL) is less than 2:

  • The compiler generates interpreted code, regardless of PLSQL_CODE_TYPE.

  • If you specify NATIVE, the compiler warns you that NATIVE was ignored.

For more information about PLSQL_CODE_TYPE, see Oracle Database Reference.

PLSQL_OPTIMIZE_LEVEL

Specifies the optimization level at which to compile PL/SQL units (the higher the level, the more optimizations the compiler tries to make).

PLSQL_OPTIMIZE_LEVEL=1 instructs the PL/SQL compiler to generate and store code for use by the PL/SQL debugger.

For more information about PLSQL_OPTIMIZE_LEVEL, see "PL/SQL Optimizer" and Oracle Database Reference.

PLSQL_WARNINGS

Enables or disables the reporting of warning messages by the PL/SQL compiler, and specifies which warning messages to show as errors.

For more information about PLSQL_WARNINGS, see "Compile-Time Warnings" and Oracle Database Reference.

NLS_LENGTH_SEMANTICS

Lets you create CHAR and VARCHAR2 columns using either byte-length or character-length semantics.

For more information about byte and character length semantics, see "CHAR and VARCHAR2 Variables".

For more information about NLS_LENGTH_SEMANTICS, see Oracle Database Reference.

PERMIT_92_WRAP_FORMAT

Specifies whether the 12.1 PL/SQL compiler can use wrapped packages that were compiled with the 9.2 PL/SQL compiler. The default value is TRUE.

For more information about wrapped packages, see Appendix A, "PL/SQL Source Text Wrapping."

For more information about PERMIT_92_WRAP_FORMAT, see Oracle Database Reference.



Note:

The compilation parameter PLSQL_DEBUG, which specifies whether to compile PL/SQL units for debugging, is deprecated. To compile PL/SQL units for debugging, specify PLSQL_OPTIMIZE_LEVEL=1.

The compile-time values of the parameters in Table 1-2 are stored with the metadata of each stored PL/SQL unit, which means that you can reuse those values when you explicitly recompile the unit. (A stored PL/SQL unit is created with one of the "CREATE [ OR REPLACE ] Statements". An anonymous block is not a stored PL/SQL unit.)

To explicitly recompile a stored PL/SQL unit and reuse its parameter values, you must use an ALTER statement with both the COMPILE clause and the REUSE SETTINGS clause. For more information about REUSE SETTINGS, see "compiler_parameters_clause". (All ALTER statements have this clause. For a list of ALTER statements, see "ALTER Statements".)

PK>PKwDOEBPS/title.htm1 Oracle Database PL/SQL Language Reference, 12c Release 1 (12.1)

Oracle® Database

PL/SQL Language Reference

12c Release 1 (12.1)

E50727-04

July 2014


Oracle Database PL/SQL Language Reference, 12c Release 1 (12.1)

E50727-04

Copyright © 1996, 2014, Oracle and/or its affiliates. All rights reserved.

Primary Author: Sheila Moore

Contributor:  The Oracle Database 12c documentation is dedicated to Mark Townsend, who was an inspiration to all who worked on this release.

Contributors:  D. Alpern, E. Belden, S. Agrawal, H. Baer, S. Castledine, T. Chang, B. Cheng, R. Dani, R. Decker, C. Iyer, A. Kruglikov, S. Kotsovolos, N. Le, W. Li, B. Llewellyn, V. Moore, T. Raney, K. Rich, C. Wetherell, G. Viswanathan, M. Yang

This software and related documentation are provided under a license agreement containing restrictions on use and disclosure and are protected by intellectual property laws. Except as expressly permitted in your license agreement or allowed by law, you may not use, copy, reproduce, translate, broadcast, modify, license, transmit, distribute, exhibit, perform, publish, or display any part, in any form, or by any means. Reverse engineering, disassembly, or decompilation of this software, unless required by law for interoperability, is prohibited.

The information contained herein is subject to change without notice and is not warranted to be error-free. If you find any errors, please report them to us in writing.

If this is software or related documentation that is delivered to the U.S. Government or anyone licensing it on behalf of the U.S. Government, the following notice is applicable:

U.S. GOVERNMENT END USERS: Oracle programs, including any operating system, integrated software, any programs installed on the hardware, and/or documentation, delivered to U.S. Government end users are "commercial computer software" pursuant to the applicable Federal Acquisition Regulation and agency-specific supplemental regulations. As such, use, duplication, disclosure, modification, and adaptation of the programs, including any operating system, integrated software, any programs installed on the hardware, and/or documentation, shall be subject to license terms and license restrictions applicable to the programs. No other rights are granted to the U.S. Government.

This software or hardware is developed for general use in a variety of information management applications. It is not developed or intended for use in any inherently dangerous applications, including applications that may create a risk of personal injury. If you use this software or hardware in dangerous applications, then you shall be responsible to take all appropriate fail-safe, backup, redundancy, and other measures to ensure its safe use. Oracle Corporation and its affiliates disclaim any liability for any damages caused by use of this software or hardware in dangerous applications.

Oracle and Java are registered trademarks of Oracle and/or its affiliates. Other names may be trademarks of their respective owners.

Intel and Intel Xeon are trademarks or registered trademarks of Intel Corporation. All SPARC trademarks are used under license and are trademarks or registered trademarks of SPARC International, Inc. AMD, Opteron, the AMD logo, and the AMD Opteron logo are trademarks or registered trademarks of Advanced Micro Devices. UNIX is a registered trademark of The Open Group.

This software or hardware and documentation may provide access to or information on content, products, and services from third parties. Oracle Corporation and its affiliates are not responsible for and expressly disclaim all warranties of any kind with respect to third-party content, products, and services. Oracle Corporation and its affiliates will not be responsible for any loss, costs, or damages incurred due to your access to or use of third-party content, products, or services.

PK>ǭPKwDOEBPS/null_statement.htm - NULL Statement

NULL Statement

The NULL statement is a ''no-op" (no operation)—it only passes control to the next statement.


Note:

The NULL statement and the BOOLEAN value NULL are not related.

Topics

Syntax

null_statement ::=

Description of null_statement.gif follows

Related Topics

PKk: PKwDOEBPS/alter_function.htm! ALTER FUNCTION Statement

ALTER FUNCTION Statement

The ALTER FUNCTION statement explicitly recompiles a standalone function. Explicit recompilation eliminates the need for implicit runtime recompilation and prevents associated runtime compilation errors and performance overhead.


Note:

This statement does not change the declaration or definition of an existing function. To redeclare or redefine a standalone function, use the "CREATE FUNCTION Statement" with the OR REPLACE clause.

Topics

Prerequisites

If the function is in the SYS schema, you must be connected as SYSDBA. Otherwise, the function must be in your schema or you must have ALTER ANY PROCEDURE system privilege.

Syntax

alter_function ::=

Description of alter_function.gif follows

function_compile_clause ::=

Description of function_compile_clause.gif follows

compiler_parameters_clause ::=

Description of compiler_parameters_clause.gif follows

Semantics

schema

Name of the schema containing the function. Default: your schema.

function_name

Name of the function to be recompiled.

COMPILE

Recompiles the function, whether it is valid or invalid.

First, if any of the objects upon which the function depends are invalid, the database recompiles them.

The database also invalidates any local objects that depend upon the function, such as subprograms that invoke the recompiled function or package bodies that define subprograms that invoke the recompiled function.

If the database recompiles the function successfully, then the function becomes valid. Otherwise, the database returns an error and the function remains invalid.

During recompilation, the database drops all persistent compiler switch settings, retrieves them again from the session, and stores them after compilation. To avoid this process, specify the REUSE SETTINGS clause.

DEBUG

Has the same effect as PLSQL_OPTIMIZE_LEVEL=1—instructs the PL/SQL compiler to generate and store the code for use by the PL/SQL debugger. Oracle recommends using PLSQL_OPTIMIZE_LEVEL=1 instead of DEBUG.

REUSE SETTINGS

Prevents Oracle Database from dropping and reacquiring compiler switch settings. With this clause, Oracle preserves the existing settings and uses them for the recompilation of any parameters for which values are not specified elsewhere in this statement.

compiler_parameters_clause

Specifies a value for a PL/SQL compilation parameter in Table 1-2. The compile-time value of each of these parameters is stored with the metadata of the PL/SQL unit being compiled.

You can specify each parameter only once in each statement. Each setting is valid only for the PL/SQL unit being compiled and does not affect other compilations in this session or system. To affect the entire session or system, you must set a value for the parameter using the ALTER SESSION or ALTER SYSTEM statement.

If you omit any parameter from this clause and you specify REUSE SETTINGS, then if a value was specified for the parameter in an earlier compilation of this PL/SQL unit, the database uses that earlier value. If you omit any parameter and either you do not specify REUSE SETTINGS or no value was specified for the parameter in an earlier compilation, then the database obtains the value for that parameter from the session environment.

{ EDITIONABLE | NONEDITIONABLE }

Specifies whether the function becomes an editioned or noneditioned object if editioning is later enabled for the schema object type FUNCTION in schema. Default: EDITIONABLE. For information about altering editioned and noneditioned objects, see Oracle Database Development Guide.

Example

Recompiling a Function: Example To explicitly recompile the function get_bal owned by the sample user oe, issue this statement:

ALTER FUNCTION oe.get_bal COMPILE;

If the database encounters no compilation errors while recompiling get_bal, then get_bal becomes valid. The database can subsequently run it without recompiling it at run time. If recompiling get_bal results in compilation errors, then the database returns an error, and get_bal remains invalid.

The database also invalidates all objects that depend upon get_bal. If you subsequently reference one of these objects without explicitly recompiling it first, then the database recompiles it implicitly at run time.

PKYh!!PKwDOEBPS/datatypes.htm PL/SQL Data Types

3 PL/SQL Data Types

Every PL/SQL constant, variable, parameter, and function return value has a data type that determines its storage format and its valid values and operations.

This chapter explains scalar data types, which store values with no internal components. For information about composite data types, see Chapter 5, "PL/SQL Collections and Records".

A scalar data type can have subtypes. A subtype is a data type that is a subset of another data type, which is its base type. A subtype has the same valid operations as its base type. A data type and its subtypes comprise a data type family.

PL/SQL predefines many types and subtypes in the package STANDARD and lets you define your own subtypes.

The PL/SQL scalar data types are:

  • The SQL data types

  • BOOLEAN

  • PLS_INTEGER

  • BINARY_INTEGER

  • REF CURSOR, explained in "Cursor Variables"

  • User-defined subtypes

Topics


See Also:


SQL Data Types

The PL/SQL data types include the SQL data types. For information about the SQL data types, see Oracle Database SQL Language Reference—all information there about data types and subtypes, data type comparison rules, data conversion, literals, and format models applies to both SQL and PL/SQL, except as noted here:

Unlike SQL, PL/SQL lets you declare variables, to which the following topics apply:

Different Maximum Sizes

The SQL data types listed in Table 3-1 have different maximum sizes in PL/SQL and SQL.

Table 3-1 Data Types with Different Maximum Sizes in PL/SQL and SQL

Data TypeMaximum Size in PL/SQLMaximum Size in SQL

CHARFoot 1 

32,767 bytes

2,000 bytes

NCHARFootref 1

32,767 bytes

2,000 bytes

RAWFootref 1

32,767 bytes

2,000 bytesFoot 2 

VARCHAR2Footref 1

32,767 bytes

4,000 bytesFootref 2

NVARCHAR2Footref 1

32,767 bytes

4,000 bytesFootref 2

LONGFoot 3 

32,760 bytes

2 gigabytes (GB) - 1

LONG RAWFootref 3

32,760 bytes

2 GB

BLOB

128 terabytes (TB)

(4 GB - 1) * database_block_size

CLOB

128 TB

(4 GB - 1) * database_block_size

NCLOB

128 TB

(4 GB - 1) * database_block_size


Footnote 1 When specifying the maximum size of a value of this data type in PL/SQL, use an integer literal (not a constant or variable) whose value is in the range from 1 through 32,767.

Footnote 2 To eliminate this size difference, follow the instructions in Oracle Database SQL Language Reference.

Footnote 3 Supported only for backward compatibility with existing applications.

Additional PL/SQL Constants for BINARY_FLOAT and BINARY_DOUBLE

The SQL data types BINARY_FLOAT and BINARY_DOUBLE represent single-precision and double-precision IEEE 754-format floating-point numbers, respectively.

BINARY_FLOAT and BINARY_DOUBLE computations do not raise exceptions, so you must check the values that they produce for conditions such as overflow and underflow by comparing them to predefined constants (for examples, see Oracle Database SQL Language Reference). PL/SQL has more of these constants than SQL does.

Table 3-2 lists and describes the predefined PL/SQL constants for BINARY_FLOAT and BINARY_DOUBLE, and identifies those that SQL also defines.

Table 3-2 Predefined PL/SQL BINARY_FLOAT and BINARY_DOUBLE ConstantsFoot 1 

ConstantDescription

BINARY_FLOAT_NANFootref 1

BINARY_FLOAT value for which the condition IS NAN (not a number) is true

BINARY_FLOAT_INFINITYFootref 1

Single-precision positive infinity

BINARY_FLOAT_MAX_NORMAL

Maximum normal BINARY_FLOAT value

BINARY_FLOAT_MIN_NORMAL

Minimum normal BINARY_FLOAT value

BINARY_FLOAT_MAX_SUBNORMAL

Maximum subnormal BINARY_FLOAT value

BINARY_FLOAT_MIN_SUBNORMAL

Minimum subnormal BINARY_FLOAT value

BINARY_DOUBLE_NANFootref 1

BINARY_DOUBLE value for which the condition IS NAN (not a number) is true

BINARY_DOUBLE_INFINITYFootref 1

Double-precision positive infinity

BINARY_DOUBLE_MAX_NORMAL

Maximum normal BINARY_DOUBLE value

BINARY_DOUBLE_MIN_NORMAL

Minimum normal BINARY_DOUBLE value

BINARY_DOUBLE_MAX_SUBNORMAL

Maximum subnormal BINARY_DOUBLE value

BINARY_DOUBLE_MIN_SUBNORMAL

Minimum subnormal BINARY_DOUBLE value


Footnote 1 SQL also predefines this constant.

Additional PL/SQL Subtypes of BINARY_FLOAT and BINARY_DOUBLE

PL/SQL predefines these subtypes:

  • SIMPLE_FLOAT, a subtype of SQL data type BINARY_FLOAT

  • SIMPLE_DOUBLE, a subtype of SQL data type BINARY_DOUBLE

Each subtype has the same range as its base type and has a NOT NULL constraint (explained in "NOT NULL Constraint").

If you know that a variable will never have the value NULL, declare it as SIMPLE_FLOAT or SIMPLE_DOUBLE, rather than BINARY_FLOAT or BINARY_DOUBLE. Without the overhead of checking for nullness, the subtypes provide significantly better performance than their base types. The performance improvement is greater with PLSQL_CODE_TYPE='NATIVE' than with PLSQL_CODE_TYPE='INTERPRETED' (for more information, see "Use Data Types that Use Hardware Arithmetic").

CHAR and VARCHAR2 Variables

Topics

Assigning or Inserting Too-Long Values

If the value that you assign to a character variable is longer than the maximum size of the variable, an error occurs. For example:

DECLARE
  c VARCHAR2(3 CHAR);
BEGIN
  c := 'abc  ';
END;
/

Result:

DECLARE
*
ERROR at line 1:
ORA-06502: PL/SQL: numeric or value error: character string buffer too small
ORA-06512: at line 4

Similarly, if you insert a character variable into a column, and the value of the variable is longer than the defined width of the column, an error occurs. For example:

DROP TABLE t;
CREATE TABLE t (c CHAR(3 CHAR));
 
DECLARE
  s VARCHAR2(5 CHAR) := 'abc  ';
BEGIN
  INSERT INTO t(c) VALUES(s);
END;
/

Result:

BEGIN
*
ERROR at line 1:
ORA-12899: value too large for column "HR"."T"."C" (actual: 5, maximum: 3)
ORA-06512: at line 4

To strip trailing blanks from a character value before assigning it to a variable or inserting it into a column, use the RTRIM function, explained in Oracle Database SQL Language Reference. For example:

DECLARE
  c VARCHAR2(3 CHAR);
BEGIN
  c := RTRIM('abc  ');
  INSERT INTO t(c) VALUES(RTRIM('abc  '));
END;
/

Result:

PL/SQL procedure successfully completed.

Declaring Variables for Multibyte Characters

The maximum size of a CHAR or VARCHAR2 variable is 32,767 bytes, whether you specify the maximum size in characters or bytes. The maximum number of characters in the variable depends on the character set type and sometimes on the characters themselves:

Character Set TypeMaximum Number of Characters
Single-byte character set32,767
n-byte fixed-width multibyte character set (for example, AL16UTF16)FLOOR(32,767/n)
n-byte variable-width multibyte character set with character widths between 1 and n bytes (for example, JA16SJIS or AL32UTF8)Depends on characters themselves—can be anything from 32,767 (for a string containing only 1-byte characters) through FLOOR(32,767/n) (for a string containing only n-byte characters).

When declaring a CHAR or VARCHAR2 variable, to ensure that it can always hold n characters in any multibyte character set, declare its length in characters—that is, CHAR(n CHAR) or VARCHAR2(n CHAR), where n does not exceed FLOOR(32767/4) = 8191.


See Also:

Oracle Database Globalization Support Guide for information about Oracle Database character set support

Differences Between CHAR and VARCHAR2 Data Types

CHAR and VARCHAR2 data types differ in:

Predefined Subtypes

The CHAR data type has one predefined subtype in both PL/SQL and SQL—CHARACTER.

The VARCHAR2 data type has one predefined subtype in both PL/SQL and SQL, VARCHAR, and an additional predefined subtype in PL/SQL, STRING.

Each subtype has the same range of values as its base type.


Note:

In a future PL/SQL release, to accommodate emerging SQL standards, VARCHAR might become a separate data type, no longer synonymous with VARCHAR2.

Blank-Padding

Consider these situations:

  • The value that you assign to a variable is shorter than the maximum size of the variable.

  • The value that you insert into a column is shorter than the defined width of the column.

  • The value that you retrieve from a column into a variable is shorter than the maximum size of the variable.

If the data type of the receiver is CHAR, PL/SQL blank-pads the value to the maximum size. Information about trailing blanks in the original value is lost.

If the data type of the receiver is VARCHAR2, PL/SQL neither blank-pads the value nor strips trailing blanks. Character values are assigned intact, and no information is lost.

In Example 3-1, both the CHAR variable and the VARCHAR2 variable have the maximum size of 10 characters. Each variable receives a five-character value with one trailing blank. The value assigned to the CHAR variable is blank-padded to 10 characters, and you cannot tell that one of the six trailing blanks in the resulting value was in the original value. The value assigned to the VARCHAR2 variable is not changed, and you can see that it has one trailing blank.

Example 3-1 CHAR and VARCHAR2 Blank-Padding Difference

DECLARE
  first_name  CHAR(10 CHAR);
  last_name   VARCHAR2(10 CHAR);
BEGIN
  first_name := 'John ';
  last_name  := 'Chen ';
 
  DBMS_OUTPUT.PUT_LINE('*' || first_name || '*');
  DBMS_OUTPUT.PUT_LINE('*' || last_name || '*');
END;
/

Result:

*John      *
*Chen *
Value Comparisons

The SQL rules for comparing character values apply to PL/SQL character variables. Whenever one or both values in the comparison have the data type VARCHAR2 or NVARCHAR2, nonpadded comparison semantics apply; otherwise, blank-padded semantics apply. For more information, see Oracle Database SQL Language Reference.

LONG and LONG RAW Variables


Note:

Oracle supports the LONG and LONG RAW data types only for backward compatibility with existing applications. For new applications:
  • Instead of LONG, use VARCHAR2(32760), BLOB, CLOB or NCLOB.

  • Instead of LONG RAW, use BLOB.


You can insert any LONG value into a LONG column. You can insert any LONG RAW value into a LONG RAW column. You cannot retrieve a value longer than 32,760 bytes from a LONG or LONG RAW column into a LONG or LONG RAW variable.

You can insert any CHAR or VARCHAR2 value into a LONG column. You cannot retrieve a value longer than 32,767 bytes from a LONG column into a CHAR or VARCHAR2 variable.

You can insert any RAW value into a LONG RAW column. You cannot retrieve a value longer than 32,767 bytes from a LONG RAW column into a RAW variable.


See Also:

"Trigger LONG and LONG RAW Data Type Restrictions" for restrictions on LONG and LONG RAW data types in triggers

ROWID and UROWID Variables

When you retrieve a rowid into a ROWID variable, use the ROWIDTOCHAR function to convert the binary value to a character value. For information about this function, see Oracle Database SQL Language Reference.

To convert the value of a ROWID variable to a rowid, use the CHARTOROWID function, explained in Oracle Database SQL Language Reference. If the value does not represent a valid rowid, PL/SQL raises the predefined exception SYS_INVALID_ROWID.

To retrieve a rowid into a UROWID variable, or to convert the value of a UROWID variable to a rowid, use an assignment statement; conversion is implicit.


Note:

  • UROWID is a more versatile data type than ROWID, because it is compatible with both logical and physical rowids.

  • When you update a row in a table compressed with Hybrid Columnar Compression (HCC), the ROWID of the row changes. HCC, a feature of certain Oracle storage systems, is described in Oracle Database Concepts.



See Also:

Oracle Database PL/SQL Packages and Types Reference for information about the DBMS_ROWID package, whose subprograms let you create and return information about ROWID values (but not UROWID values)

BOOLEAN Data Type

The PL/SQL data type BOOLEAN stores logical values, which are the Boolean values TRUE and FALSE and the value NULL. NULL represents an unknown value.

The syntax for declaring an BOOLEAN variable is:

variable_name BOOLEAN

The only value that you can assign to a BOOLEAN variable is a BOOLEAN expression. For details, see "BOOLEAN Expressions".

Because SQL has no data type equivalent to BOOLEAN, you cannot:

  • Assign a BOOLEAN value to a database table column

  • Select or fetch the value of a database table column into a BOOLEAN variable

  • Use a BOOLEAN value in a SQL function

    (However, a SQL query can invoke a PL/SQL function that has a BOOLEAN parameter, as in Example 3-3.)

  • Use a BOOLEAN expression in a SQL statement, except as an argument to a PL/SQL function invoked in a SQL query, or in a PL/SQL anonymous block.


    Note:

    An argument to a PL/SQL function invoked in a static SQL query cannot be a BOOLEAN literal. The workaround is to assign the literal to a variable and then pass the variable to the function, as in Example 3-3.

You cannot pass a BOOLEAN value to the DBMS_OUTPUT.PUT or DBMS_OUTPUT.PUTLINE subprogram. To print a BOOLEAN value, use an IF or CASE statement to translate it to a character value (for information about these statements, see "Conditional Selection Statements").

In Example 3-2, the procedure accepts a BOOLEAN parameter and uses a CASE statement to print Unknown if the value of the parameter is NULL, Yes if it is TRUE, and No if it is FALSE.

Example 3-2 Printing BOOLEAN Values

CREATE PROCEDURE print_boolean (b BOOLEAN)
AS
BEGIN
  DBMS_OUTPUT.put_line (
    CASE
      WHEN b IS NULL THEN 'Unknown'
      WHEN b THEN 'Yes'
      WHEN NOT b THEN 'No'
    END
  );
END;
/
BEGIN
  print_boolean(TRUE);
  print_boolean(FALSE);
  print_boolean(NULL);
END;
/

Result:

Yes
No
Unknown

See Also:

Example 2-35, which creates a print_boolean procedure that uses an IF statement.

In Example 3-3, a SQL statement invokes a PL/SQL function that has a BOOLEAN parameter.

Example 3-3 SQL Statement Invokes PL/SQL Function with BOOLEAN Parameter

CREATE OR REPLACE FUNCTION f (x BOOLEAN, y PLS_INTEGER)
  RETURN employees.employee_id%TYPE
  AUTHID CURRENT_USER AS
BEGIN
  IF x THEN
    RETURN y;
  ELSE
    RETURN 2*y;
  END IF;
END;
/
 
DECLARE
  name employees.last_name%TYPE;
  b BOOLEAN := TRUE;
BEGIN
  SELECT last_name INTO name
  FROM employees
  WHERE employee_id = f(b, 100);
 
  DBMS_OUTPUT.PUT_LINE(name);
 
  b := FALSE;
 
  SELECT last_name INTO name
  FROM employees
  WHERE employee_id = f(b, 100);
 
  DBMS_OUTPUT.PUT_LINE(name);
END;
/

Result:

King
Whalen

PLS_INTEGER and BINARY_INTEGER Data Types

The PL/SQL data types PLS_INTEGER and BINARY_INTEGER are identical. For simplicity, this document uses PLS_INTEGER to mean both PLS_INTEGER and BINARY_INTEGER.

The PLS_INTEGER data type stores signed integers in the range -2,147,483,648 through 2,147,483,647, represented in 32 bits.

The PLS_INTEGER data type has these advantages over the NUMBER data type and NUMBER subtypes:

  • PLS_INTEGER values require less storage.

  • PLS_INTEGER operations use hardware arithmetic, so they are faster than NUMBER operations, which use library arithmetic.

For efficiency, use PLS_INTEGER values for all calculations in its range.

Topics

Preventing PLS_INTEGER Overflow

A calculation with two PLS_INTEGER values that overflows the PLS_INTEGER range raises an overflow exception, even if you assign the result to a NUMBER data type (as in Example 3-4). For calculations outside the PLS_INTEGER range, use INTEGER, a predefined subtype of the NUMBER data type (as in Example 3-5).

Example 3-4 PLS_INTEGER Calculation Raises Overflow Exception

DECLARE
  p1 PLS_INTEGER := 2147483647;
  p2 PLS_INTEGER := 1;
  n NUMBER;
BEGIN
  n := p1 + p2;
END;
/

Result:

DECLARE
*
ERROR at line 1:
ORA-01426: numeric overflow
ORA-06512: at line 6

Example 3-5 Preventing Example 3-4 Overflow

DECLARE
  p1 PLS_INTEGER := 2147483647;
  p2 INTEGER := 1;
  n NUMBER;
BEGIN
  n := p1 + p2;
END;
/

Result:

PL/SQL procedure successfully completed.

Predefined PLS_INTEGER Subtypes

Table 3-3 lists the predefined subtypes of the PLS_INTEGER data type and describes the data they store.

Table 3-3 Predefined Subtypes of PLS_INTEGER Data Type

Data TypeData Description

NATURAL

Nonnegative PLS_INTEGER value

NATURALN

Nonnegative PLS_INTEGER value with NOT NULL constraintFoot 1 

POSITIVE

Positive PLS_INTEGER value

POSITIVEN

Positive PLS_INTEGER value with NOT NULL constraintFootref 1

SIGNTYPE

PLS_INTEGER value -1, 0, or 1 (useful for programming tri-state logic)

SIMPLE_INTEGER

PLS_INTEGER value with NOT NULL constraint. For more information, see "SIMPLE_INTEGER Subtype of PLS_INTEGER".


Footnote 1 For information about the NOT NULL constraint, see "NOT NULL Constraint".

PLS_INTEGER and its subtypes can be implicitly converted to these data types:

  • CHAR

  • VARCHAR2

  • NUMBER

  • LONG

All of the preceding data types except LONG, and all PLS_INTEGER subtypes, can be implicitly converted to PLS_INTEGER.

A PLS_INTEGER value can be implicitly converted to a PLS_INTEGER subtype only if the value does not violate a constraint of the subtype. For example, casting the PLS_INTEGER value NULL to the SIMPLE_INTEGER subtype raises an exception, as Example 3-6 shows.

Example 3-6 Violating Constraint of SIMPLE_INTEGER Subtype

DECLARE
  a SIMPLE_INTEGER := 1;
  b PLS_INTEGER := NULL;
BEGIN
  a := b;
END;
/

Result:

DECLARE
*
ERROR at line 1:
ORA-06502: PL/SQL: numeric or value error
ORA-06512: at line 5

SIMPLE_INTEGER Subtype of PLS_INTEGER

SIMPLE_INTEGER is a predefined subtype of the PLS_INTEGER data type that has the same range as PLS_INTEGER and has a NOT NULL constraint (explained in "NOT NULL Constraint"). It differs significantly from PLS_INTEGER in its overflow semantics.

If you know that a variable will never have the value NULL or need overflow checking, declare it as SIMPLE_INTEGER rather than PLS_INTEGER. Without the overhead of checking for nullness and overflow, SIMPLE_INTEGER performs significantly better than PLS_INTEGER.

Topics

SIMPLE_INTEGER Overflow Semantics

If and only if all operands in an expression have the data type SIMPLE_INTEGER, PL/SQL uses two's complement arithmetic and ignores overflows. Because overflows are ignored, values can wrap from positive to negative or from negative to positive; for example:

230 + 230 = 0x40000000 + 0x40000000 = 0x80000000 = -231

-231 + -231 = 0x80000000 + 0x80000000 = 0x00000000 = 0

For example, this block runs without errors:

DECLARE
  n SIMPLE_INTEGER := 2147483645;
BEGIN
  FOR j IN 1..4 LOOP
    n := n + 1;
    DBMS_OUTPUT.PUT_LINE(TO_CHAR(n, 'S9999999999'));
  END LOOP;
  FOR j IN 1..4 LOOP
   n := n - 1;
   DBMS_OUTPUT.PUT_LINE(TO_CHAR(n, 'S9999999999'));
  END LOOP;
END;
/

Result:

+2147483646
+2147483647
-2147483648
-2147483647
-2147483648
+2147483647
+2147483646
+2147483645

PL/SQL procedure successfully completed.

Expressions with Both SIMPLE_INTEGER and Other Operands

If an expression has both SIMPLE_INTEGER and other operands, PL/SQL implicitly converts the SIMPLE_INTEGER values to PLS_INTEGER NOT NULL.

The PL/SQL compiler issues a warning when SIMPLE_INTEGER and other values are mixed in a way that might negatively impact performance by inhibiting some optimizations.

Integer Literals in SIMPLE_INTEGER Range

Integer literals in the SIMPLE_INTEGER range have the data type SIMPLE_INTEGER. However, to ensure backward compatibility, when all operands in an arithmetic expression are integer literals, PL/SQL treats the integer literals as if they were cast to PLS_INTEGER.

User-Defined PL/SQL Subtypes

PL/SQL lets you define your own subtypes. The base type can be any scalar or user-defined PL/SQL data type specifier such as CHAR, DATE, or RECORD (including a previously defined user-defined subtype).


Note:

The information in this topic applies to both user-defined subtypes and the predefined subtypes listed in Appendix E, "PL/SQL Predefined Data Types".

Subtypes can:

  • Provide compatibility with ANSI/ISO data types

  • Show the intended use of data items of that type

  • Detect out-of-range values

Topics

Unconstrained Subtypes

An unconstrained subtype has the same set of values as its base type, so it is only another name for the base type. Therefore, unconstrained subtypes of the same base type are interchangeable with each other and with the base type. No data type conversion occurs.

To define an unconstrained subtype, use this syntax:

SUBTYPE subtype_name IS base_type

For information about subtype_name and base_type, see subtype_definition.

An example of an unconstrained subtype, which PL/SQL predefines for compatibility with ANSI, is:

SUBTYPE "DOUBLE PRECISION" IS FLOAT

In Example 3-7, the unconstrained subtypes Balance and Counter show the intended uses of data items of their types.

Example 3-7 User-Defined Unconstrained Subtypes Show Intended Use

DECLARE
  SUBTYPE Balance IS NUMBER;

  checking_account        Balance(6,2);
  savings_account         Balance(8,2);
  certificate_of_deposit  Balance(8,2);
  max_insured  CONSTANT   Balance(8,2) := 250000.00;

  SUBTYPE Counter IS NATURAL;

  accounts     Counter := 1;
  deposits     Counter := 0;
  withdrawals  Counter := 0;
  overdrafts   Counter := 0;

  PROCEDURE deposit (
    account  IN OUT Balance,
    amount   IN     Balance
  ) IS
  BEGIN
    account  := account + amount;
    deposits := deposits + 1;
  END;
  
BEGIN
  NULL;
END;
/

Constrained Subtypes

A constrained subtype has only a subset of the values of its base type.

If the base type lets you specify size, precision and scale, or a range of values, then you can specify them for its subtypes. The subtype definition syntax is:

SUBTYPE subtype_name IS base_type
  { precision [, scale ] | RANGE low_value .. high_value } [ NOT NULL ]

Otherwise, the only constraint that you can put on its subtypes is NOT NULL (described in "NOT NULL Constraint"):

SUBTYPE subtype_name IS base_type [ NOT NULL ]

Note:

The only base types for which you can specify a range of values are PLS_INTEGER and its subtypes (both predefined and user-defined).


See Also:

Syntax diagram "subtype_definition ::=" and semantic description "subtype_definition".

In Example 3-8, the constrained subtype Balance detects out-of-range values.

Example 3-8 User-Defined Constrained Subtype Detects Out-of-Range Values

DECLARE
  SUBTYPE Balance IS NUMBER(8,2);
 
  checking_account  Balance;
  savings_account   Balance;
 
BEGIN
  checking_account := 2000.00;
  savings_account  := 1000000.00;
END;
/

Result:

DECLARE
*
ERROR at line 1:
ORA-06502: PL/SQL: numeric or value error: number precision too large
ORA-06512: at line 9

A constrained subtype can be implicitly converted to its base type, but the base type can be implicitly converted to the constrained subtype only if the value does not violate a constraint of the subtype (see Example 3-6).

A constrained subtype can be implicitly converted to another constrained subtype with the same base type only if the source value does not violate a constraint of the target subtype.

In Example 3-9, the three constrained subtypes have the same base type. The first two subtypes can be implicitly converted to the third subtype, but not to each other.

Example 3-9 Implicit Conversion Between Constrained Subtypes with Same Base Type

DECLARE
  SUBTYPE Digit        IS PLS_INTEGER RANGE 0..9;
  SUBTYPE Double_digit IS PLS_INTEGER RANGE 10..99;
  SUBTYPE Under_100    IS PLS_INTEGER RANGE 0..99;
 
  d   Digit        :=  4;
  dd  Double_digit := 35;
  u   Under_100;
BEGIN
  u := d;   -- Succeeds; Under_100 range includes Digit range
  u := dd;  -- Succeeds; Under_100 range includes Double_digit range
  dd := d;  -- Raises error; Double_digit range does not include Digit range
END;
/

Result:

DECLARE
*
ERROR at line 1:
ORA-06502: PL/SQL: numeric or value error
ORA-06512: at line 12

Subtypes with Base Types in Same Data Type Family

If two subtypes have different base types in the same data type family, then one subtype can be implicitly converted to the other only if the source value does not violate a constraint of the target subtype. (For the predefined PL/SQL data types and subtypes, grouped by data type family, see Appendix E, "PL/SQL Predefined Data Types".)

In Example 3-10, the subtypes Word and Text have different base types in the same data type family. The first assignment statement implicitly converts a Word value to Text. The second assignment statement implicitly converts a Text value to Word. The third assignment statement cannot implicitly convert the Text value to Word, because the value is too long.

Example 3-10 Implicit Conversion Between Subtypes with Base Types in Same Family

DECLARE
  SUBTYPE Word IS CHAR(6);
  SUBTYPE Text IS VARCHAR2(15);
 
  verb       Word := 'run';
  sentence1  Text;
  sentence2  Text := 'Hurry!';
  sentence3  Text := 'See Tom run.';
 
BEGIN
  sentence1 := verb;  -- 3-character value, 15-character limit
  verb := sentence2;  -- 5-character value, 6-character limit
  verb := sentence3;  -- 12-character value, 6-character limit
END;
/

Result:

DECLARE
*
ERROR at line 1:
ORA-06502: PL/SQL: numeric or value error: character string buffer too small
ORA-06512: at line 13
PKSPKwDOEBPS/sqlstatements.htmH SQL Statements for Stored PL/SQL Units

14 SQL Statements for Stored PL/SQL Units

This chapter explains how to use the SQL statements that create, change, and drop stored PL/SQL units.

For instructions for reading the syntax diagrams in this chapter, see Oracle Database SQL Language Reference.

CREATE [ OR REPLACE ] Statements

Each of these SQL statements creates a PL/SQL unit at schema level and stores it in the database:

Each of these CREATE statements has an optional OR REPLACE clause. Specify OR REPLACE to re-create an existing PL/SQL unit—that is, to change its declaration or definition without dropping it, re-creating it, and regranting object privileges previously granted on it. If you redefine a PL/SQL unit, the database recompiles it.


Caution:

A CREATE OR REPLACE statement does not issue a warning before replacing the existing PL/SQL unit.

None of these CREATE statements can appear in a PL/SQL block.

ALTER Statements

To recompile an existing PL/SQL unit without re-creating it (without changing its declaration or definition), use one of these SQL statements:

Reasons to use an ALTER statement are:

  • To explicitly recompile a stored unit that has become invalid, thus eliminating the need for implicit runtime recompilation and preventing associated runtime compilation errors and performance overhead.

  • To recompile a stored unit with different compilation parameters.

    For information about compilation parameters, see "PL/SQL Units and Compilation Parameters".

  • To enable or disable a trigger.

  • To specify the EDITIONABLE or NONEDITIONABLE property of a stored unit whose schema object type is not yet editionable in its schema.

    For information about editioned and noneditioned objects, see Oracle Database Development Guide.

The ALTER TYPE statement has additional uses. For details, see "ALTER TYPE Statement".

DROP Statements

To drop an existing PL/SQL unit from the database, use one of these SQL statements:

PKTJMHPKwD OEBPS/loe.htm List of Examples

List of Examples

PKN-PKwDOEBPS/type_attribute.htmQ %TYPE Attribute

%TYPE Attribute

The %TYPE attribute lets you declare a constant, variable, collection element, record field, or subprogram parameter to be of the same data type as a previously declared variable or column (without knowing what that type is). The item declared with %TYPE is the referencing item, and the previously declared item is the referenced item.

The referencing item inherits the following from the referenced item:

  • Data type and size

  • Constraints (unless the referenced item is a column)

The referencing item does not inherit the initial value of the referenced item.

If the declaration of the referenced item changes, then the declaration of the referencing item changes accordingly.

Topics

Syntax

type_attribute ::=

Description of type_attribute.gif follows

Semantics

collection_variable

Name of a collection variable.

Restriction on collection_variable  In a constant declaration, collection_variable cannot be an associative array variable.

cursor_variable

Name of a cursor variable.

db_table_or_view

Name of a database table or view that is accessible when the declaration is elaborated.

column

Name of a column of db_table_or_view.

object

Name of an instance of an ADT.

record_variable

Name of a record variable.

field

Name of a field of record_variable.

scalar_variable

Name of a scalar variable.

PKtYHVQPKwDOEBPS/nameresolution.htmz} PL/SQL Name Resolution

B PL/SQL Name Resolution

This appendix explains PL/SQL name resolution; that is, how the PL/SQL compiler resolves ambiguous references to identifiers.

An unambiguous identifier reference can become ambiguous if you change identifiers in its compilation unit (that is, if you add, rename, or delete identifiers).


Note:

The AUTHID property of a stored PL/SQL unit affects the name resolution of SQL statements that the unit issues at run time. For more information, see "Invoker's Rights and Definer's Rights (AUTHID Property)".

Topics

Qualified Names and Dot Notation

When one named item belongs to another named item, you can (and sometimes must) qualify the name of the "child" item with the name of the "parent" item, using dot notation. For example:

When referencing ...You must qualify its name with ...Using this syntax ...
Field of a recordName of the recordrecord_name.field_name
Method of a collectionName of the collectioncollection_name.method
Pseudocolumn CURRVALName of a sequencesequence_name.CURRVAL
Pseudocolumn NEXTVALName of a sequencesequence_name.NEXTVAL

If an identifier is declared in a named PL/SQL unit, you can qualify its simple name (the name in its declaration) with the name of the unit (block, subprogram, or package), using this syntax:

unit_name.simple_identifier_name

If the identifier is not visible, then you must qualify its name (see "Scope and Visibility of Identifiers").

If an identifier belongs to another schema, then you must qualify its name with the name of the schema, using this syntax:

schema_name.package_name

A simple name can be qualified with multiple names, as Example B-1 shows.

Example B-1 Qualified Names

CREATE OR REPLACE PACKAGE pkg1 AUTHID DEFINER AS
  m NUMBER;
  TYPE t1 IS RECORD (a NUMBER);
  v1 t1;
  TYPE t2 IS TABLE OF t1 INDEX BY PLS_INTEGER;
  v2 t2; 
  FUNCTION f1 (p1 NUMBER) RETURN t1;
  FUNCTION f2 (q1 NUMBER) RETURN t2;
END pkg1;
/

CREATE OR REPLACE PACKAGE BODY pkg1 AS
  FUNCTION f1 (p1 NUMBER) RETURN t1 IS
    n NUMBER;
  BEGIN
     n := m;             -- Unqualified variable name
     n := pkg1.m;        -- Variable name qualified by package name
     n := pkg1.f1.p1;    -- Parameter name qualified by function name,
                         --  which is qualified by package name
     n := v1.a;          -- Variable name followed by component name
     n := pkg1.v1.a;     -- Variable name qualified by package name
                         --  and followed by component name
     n := v2(10).a;      -- Indexed name followed by component name
     n := f1(10).a;      -- Function invocation followed by component name
     n := f2(10)(10).a;  -- Function invocation followed by indexed name
                         --  and followed by component name
     n := hr.pkg1.f2(10)(10).a;  -- Schema name, package name,
                                 -- function invocation, index, component name
     v1.a := p1;
     RETURN v1;
   END f1;

   FUNCTION f2 (q1 NUMBER) RETURN t2 IS
     v_t1 t1;
     v_t2 t2;
   BEGIN
     v_t1.a := q1;
     v_t2(1) := v_t1;
     RETURN v_t2;
   END f2;
END pkg1;
/

Some examples of possibly ambiguous qualified names are:

  • Field or attribute of a function return value, for example:

    func_name().field_name
    func_name().attribute_name
    
  • Schema object owned by another schema, for example:

    schema_name.table_name
    schema_name.procedure_name()
    schema_name.type_name.member_name()
    
  • Package object owned by another user, for example:

    schema_name.package_name.procedure_name()
    schema_name.package_name.record_name.field_name
    
  • Record containing an ADT, for example:

    record_name.field_name.attribute_name
    record_name.field_name.member_name()
    

Column Name Precedence

If a SQL statement references a name that belongs to both a column and either a local variable or formal parameter, then the column name takes precedence.


Caution:

When a variable or parameter name is interpreted as a column name, data can be deleted, changed, or inserted unintentionally.

In Example B-2, the name last_name belongs to both a local variable and a column (names are not case-sensitive). Therefore, in the WHERE clause, both references to last_name resolve to the column, and all rows are deleted.

Example B-2 Variable Name Interpreted as Column Name Causes Unintended Result

DROP TABLE employees2;
CREATE TABLE employees2 AS
  SELECT LAST_NAME FROM employees;
 
DECLARE
  last_name  VARCHAR2(10) := 'King';
BEGIN
  DELETE FROM employees2 WHERE LAST_NAME = last_name;
  DBMS_OUTPUT.PUT_LINE('Deleted ' || SQL%ROWCOUNT || ' rows.');
END;
/
 

Result:

Deleted 107 rows.

Example B-3 solves the problem in Example B-2 by giving the variable a different name.

Example B-3 Fixing Example B-2 with Different Variable Name

DECLARE
  v_last_name  VARCHAR2(10) := 'King';
BEGIN
  DELETE FROM employees2 WHERE LAST_NAME = v_last_name;
  DBMS_OUTPUT.PUT_LINE('Deleted ' || SQL%ROWCOUNT || ' rows.');
END;
/
 

Result:

Deleted 2 rows.

Example B-4 solves the problem in Example B-2 by labeling the block and qualifying the variable name with the block name.

Example B-4 Fixing Example B-2 with Block Label

<<main>>
DECLARE
  last_name  VARCHAR2(10) := 'King';
BEGIN
  DELETE FROM employees2 WHERE last_name = main.last_name;
  DBMS_OUTPUT.PUT_LINE('Deleted ' || SQL%ROWCOUNT || ' rows.');
END;
/
 

Result:

Deleted 2 rows.

In Example B-5, the function dept_name has a formal parameter and a local variable whose names are those of columns of the table DEPARTMENTS. The parameter and variable name are qualified with the function name to distinguish them from the column names.

Example B-5 Subprogram Name for Name Resolution

DECLARE
  FUNCTION dept_name (department_id IN NUMBER)
    RETURN departments.department_name%TYPE
  IS
    department_name  departments.department_name%TYPE;
  BEGIN
    SELECT department_name INTO dept_name.department_name
      --   ^column              ^local variable
    FROM departments
    WHERE department_id = dept_name.department_id;
    --    ^column         ^formal parameter
    RETURN department_name;
  END dept_name;
BEGIN
  FOR item IN (
    SELECT department_id
    FROM departments
    ORDER BY department_name) LOOP
 
      DBMS_OUTPUT.PUT_LINE ('Department: ' || dept_name(item.department_id));
  END LOOP;
END;
/
 

Result:

Department: Accounting
Department: Administration
Department: Benefits
Department: Construction
Department: Contracting
Department: Control And Credit
Department: Corporate Tax
Department: Executive
Department: Finance
Department: Government Sales
Department: Human Resources
Department: IT
Department: IT Helpdesk
Department: IT Support
Department: Manufacturing
Department: Marketing
Department: NOC
Department: Operations
Department: Payroll
Department: Public Relations
Department: Purchasing
Department: Recruiting
Department: Retail Sales
Department: Sales
Department: Shareholder Services
Department: Shipping
Department: Treasury

Differences Between PL/SQL and SQL Name Resolution Rules

PL/SQL and SQL name resolution rules are very similar. However:

  • PL/SQL rules are less permissive than SQL rules.

    Because most SQL rules are context-sensitive, they recognize as legal more situations than PL/SQL rules do.

  • PL/SQL and SQL resolve qualified names differently.

    For example, when resolving the table name HR.JOBS:

    • PL/SQL searches first for packages, types, tables, and views named HR in the current schema, then for public synonyms, and finally for objects named JOBS in the HR schema.

    • SQL searches first for objects named JOBS in the HR schema, and then for packages, types, tables, and views named HR in the current schema.

To avoid problems caused by the few differences between PL/SQL and SQL name resolution rules, follow the recommendations in "Avoiding Inner Capture in SELECT and DML Statements".


Note:

When the PL/SQL compiler processes a static SQL statement, it sends that statement to the SQL subsystem, which uses SQL rules to resolve names in the statement. For details, see "Resolution of Names in Static SQL Statements".

Resolution of Names in Static SQL Statements

Static SQL is described in Chapter 6, "PL/SQL Static SQL".

When the PL/SQL compiler finds a static SQL statement:

  1. If the statement is a SELECT statement, the PL/SQL compiler removes the INTO clause.

  2. The PL/SQL compiler sends the statement to the SQL subsystem.

  3. The SQL subsystem checks the syntax of the statement.

    If the syntax is incorrect, the compilation of the PL/SQL unit fails. If the syntax is correct, the SQL subsystem determines the names of the tables and tries to resolve the other names in the scope of the SQL statement.

  4. If the SQL subsystem cannot resolve a name in the scope of the SQL statement, then it sends the name back to the PL/SQL compiler. The name is called an escaped identifier.

  5. The PL/SQL compiler tries to resolve the escaped identifier.

    First, the compiler tries to resolve the identifier in the scope of the PL/SQL unit. If that fails, the compiler tries to resolve the identifier in the scope of the schema. If that fails, the compilation of the PL/SQL unit fails.

  6. If the compilation of the PL/SQL unit succeeds, the PL/SQL compiler generates the text of the regular SQL statement that is equivalent to the static SQL statement and stores that text with the generated computer code.

  7. At run time, the PL/SQL runtime system invokes routines that parse, bind, and run the regular SQL statement.

    The bind variables are the escaped identifiers (see step 4).

  8. If the statement is a SELECT statement, the PL/SQL runtime system stores the results in the PL/SQL targets specified in the INTO clause that the PL/SQL compiler removed in step 1.


Note:

Bind variables can be evaluated in any order. If a program determines order of evaluation, then at the point where the program does so, its behavior is undefined.

What is Capture?

When a declaration or definition prevents the compiler from correctly resolving a reference in another scope, the declaration or definition is said to capture the reference. Capture is usually the result of migration or schema evolution.

Topics


Note:

Same-scope and inner capture occur only in SQL scope.

Outer Capture

Outer capture occurs when a name in an inner scope, which had resolved to an item in an inner scope, now resolves to an item in an outer scope. Both PL/SQL and SQL are designed to prevent outer capture; you need not be careful to avoid it.

Same-Scope Capture

Same-scope capture occurs when a column is added to one of two tables used in a join, and the new column has the same name as a column in the other table. When only one table had a column with that name, the name could appear in the join unqualified. Now, to avoid same-scope capture, you must qualify the column name with the appropriate table name, everywhere that the column name appears in the join.

Inner Capture

Inner capture occurs when a name in an inner scope, which had resolved to an item in an outer scope, now either resolves to an item in an inner scope or cannot be resolved. In the first case, the result might change. In the second case, an error occurs.

In Example B-6, a new column captures a reference to an old column with the same name. Before new column col2 is added to table tab2, col2 resolves to tab1.col2; afterward, it resolves to tab2.col2.

Example B-6 Inner Capture of Column Reference

Table tab1 has a column named col2, but table tab2 does not:

DROP TABLE tab1;
CREATE TABLE tab1 (col1 NUMBER, col2 NUMBER);
INSERT INTO tab1 (col1, col2) VALUES (100, 10);

DROP TABLE tab2;
CREATE TABLE tab2 (col1 NUMBER);
INSERT INTO tab2 (col1) VALUES (100);

Therefore, in the inner SELECT statement, the reference to col2 resolves to column tab1.col2:

CREATE OR REPLACE PROCEDURE proc AUTHID DEFINER AS
  CURSOR c1 IS
    SELECT * FROM tab1
    WHERE EXISTS (SELECT * FROM tab2 WHERE col2 = 10);
BEGIN
  OPEN c1;
  CLOSE c1;
END;
/

Add a column named col2 to table tab2:

ALTER TABLE tab2 ADD (col2 NUMBER);

Now procedure proc is invalid. At its next invocation, the database automatically recompiles it, and the reference to col2 in the inner SELECT statement resolves to column tab2.col2.

To avoid inner capture, follow the rules in "Avoiding Inner Capture in SELECT and DML Statements".

Avoiding Inner Capture in SELECT and DML Statements

Avoid inner capture of references in SELECT, SELECT INTO, and DML statements by following these recommendations:

  • Specify a unique alias for each table in the statement.

  • Do not specify a table alias that is the name of a schema that owns an item referenced in the statement.

  • Qualify each column reference in the statement with the appropriate table alias.

In Example B-7, schema hr owns tables tab1 and tab2. Table tab1 has a column named tab2, whose Abstract Data Type (ADT) has attribute a. Table tab2 does not have a column named a. Against recommendation, the query specifies alias hr for table tab1 and references table tab2. Therefore, in the query, the reference hr.tab2.a resolves to table tab1, column tab2, attribute a. Then the example adds column a to table tab2. Now the reference hr.tab2.a in the query resolves to schema hr, table tab2, column a. Column a of table tab2 captures the reference to attribute a in column tab2 of table tab1.

Example B-7 Inner Capture of Attribute Reference

CREATE OR REPLACE TYPE type1 AS OBJECT (a NUMBER);
/
DROP TABLE tab1;
CREATE TABLE tab1 (tab2 type1);
INSERT INTO tab1 (tab2) VALUES (type1(10));

DROP TABLE tab2;
CREATE TABLE tab2 (x NUMBER);
INSERT INTO tab2 (x) VALUES (10);

/* Alias tab1 with same name as schema name,
   a bad practice used here for illustration purpose.
   Note lack of alias in second SELECT statement. */

SELECT * FROM tab1 hr
WHERE EXISTS (SELECT * FROM hr.tab2 WHERE x = hr.tab2.a);

Result:

TAB2(A)
---------------
 
TYPE1(10)
 
1 row selected.

Add a column named a to table tab2 (which belongs to schema hr):

ALTER TABLE tab2 ADD (a NUMBER);

Now, when the query runs, hr.tab2.a resolves to schema hr, table tab2, column a. To avoid this inner capture, apply the recommendations to the query:

SELECT * FROM hr.tab1 p1
WHERE EXISTS (SELECT * FROM hr.tab2 p2 WHERE p2.x = p1.tab2.a);

Topics

Qualifying References to Attributes and Methods

To reference an attribute or method of a table element, you must give the table an alias and use the alias to qualify the reference to the attribute or method.

In Example B-8, table tbl1 has column col1 of data type t1, an ADT with attribute x. The example shows several correct and incorrect references to tbl1.col1.x.

Example B-8 Qualifying ADT Attribute References

CREATE OR REPLACE TYPE t1 AS OBJECT (x NUMBER);
/
DROP TABLE tb1;
CREATE TABLE tb1 (col1 t1); 

The references in the following INSERT statements do not need aliases, because they have no column lists:

BEGIN
  INSERT INTO tb1 VALUES ( t1(10) );
  INSERT INTO tb1 VALUES ( t1(20) );
  INSERT INTO tb1 VALUES ( t1(30) );
END;
/

The following references to the attribute x cause error ORA-00904:

UPDATE tb1 SET col1.x = 10 WHERE col1.x = 20;

UPDATE tb1 SET tb1.col1.x = 10 WHERE tb1.col1.x = 20;

UPDATE hr.tb1 SET hr.tb1.col1.x = 10 WHERE hr.tb1.col1.x = 20;

DELETE FROM tb1 WHERE tb1.col1.x = 10;

The following references to the attribute x, with table aliases, are correct:

UPDATE hr.tb1 t SET t.col1.x = 10 WHERE t.col1.x = 20;

DECLARE
  y NUMBER;
BEGIN
  SELECT t.col1.x INTO y FROM tb1 t WHERE t.col1.x = 30;
END;
/

DELETE FROM tb1 t WHERE t.col1.x = 10;

Qualifying References to Row Expressions

Row expressions must resolve as references to table aliases. A row expression can appear in the SET clause of an UPDATE statement or be the parameter of the SQL function REF or VALUE.

In Example B-9, table ot1 is a standalone nested table of elements of data type t1, an ADT with attribute x. The example shows several correct and incorrect references to row expressions.

Example B-9 Qualifying References to Row Expressions

CREATE OR REPLACE TYPE t1 AS OBJECT (x number);
/
DROP TABLE ot1;
CREATE TABLE ot1 OF t1;

BEGIN
  INSERT INTO ot1 VALUES (t1(10));
  INSERT INTO ot1 VALUES (20);
  INSERT INTO ot1 VALUES (30);
END;
/

The following references cause error ORA-00904:

UPDATE ot1 SET VALUE(ot1.x) = t1(20) WHERE VALUE(ot1.x) = t1(10);

DELETE FROM ot1 WHERE VALUE(ot1) = (t1(10));

The following references, with table aliases, are correct:

UPDATE ot1 o SET o = (t1(20)) WHERE o.x = 10;

DECLARE
  n_ref  REF t1;
BEGIN
  SELECT REF(o) INTO n_ref FROM ot1 o WHERE VALUE(o) = t1(30);
END;
/

DECLARE
  n t1;
BEGIN
  SELECT VALUE(o) INTO n FROM ot1 o WHERE VALUE(o) = t1(30);
END;
/

DECLARE
  n NUMBER;
BEGIN
  SELECT o.x INTO n FROM ot1 o WHERE o.x = 30;
END;
/

DELETE FROM ot1 o WHERE VALUE(o) = (t1(20));
PK 9zzPKwDOEBPS/drop_type.htm4 DROP TYPE Statement

DROP TYPE Statement

The DROP TYPE statement drops the specification and body of an ADT, VARRAY type, or nested table type.

Topics

Prerequisites

The ADT, VARRAY type, or nested table type must be in your schema or you must have the DROP ANY TYPE system privilege.

Syntax

drop_type ::=

Description of drop_type.gif follows

Semantics

schema

Name of the schema containing the type. Default: your schema.

type_name

Name of the object, varray, or nested table type to be dropped. You can drop only types with no type or table dependencies.

If type_name is a supertype, then this statement fails unless you also specify FORCE. If you specify FORCE, then the database invalidates all subtypes depending on this supertype.

If type_name is a statistics type, then this statement fails unless you also specify FORCE. If you specify FORCE, then the database first disassociates all objects that are associated with type_name and then drops type_name.


See Also:


If type_name is an ADT that is associated with a statistics type, then the database first tries to disassociate type_name from the statistics type and then drops type_name. However, if statistics have been collected using the statistics type, then the database cannot disassociate type_name from the statistics type, and this statement fails.

If type_name is an implementation type for an index type, then the index type is marked INVALID.

If type_name has a public synonym defined on it, then the database also drops the synonym.

Unless you specify FORCE, you can drop only types that are standalone schema objects with no dependencies. This is the default behavior.


See Also:

Oracle Database SQL Language Reference for information about the CREATE INDEXTYPE statement

FORCE

Drops the type even if it has dependent database objects. The database marks UNUSED all columns dependent on the type to be dropped, and those columns become inaccessible.


Caution:

Oracle recommends against specifying FORCE to drop object types with dependencies. This operation is not recoverable and might make the data in the dependent tables or columns inaccessible.

VALIDATE

Causes the database to check for stored instances of this type in substitutable columns of any of its supertypes. If no such instances are found, then the database completes the drop operation.

This clause is meaningful only for subtypes. Oracle recommends the use of this option to safely drop subtypes that do not have any explicit type or table dependencies.

Example

Dropping an ADT: Example This statement removes the ADT person_t. See "Type Hierarchy Example" for the example that creates this ADT. Any columns that are dependent on person_t are marked UNUSED and become inaccessible.

DROP TYPE person_t FORCE;
PKfBPKwDOEBPS/procedure.htm7 Procedure Declaration and Definition

Procedure Declaration and Definition

A procedure is a subprogram that performs a specific action. A procedure invocation (or call) is a statement.

Before invoking a procedure, you must declare and define it. You can either declare it first (with procedure_declaration) and then define it later in the same block, subprogram, or package (with procedure_definition) or declare and define it at the same time (with procedure_definition).

A procedure declaration is also called a procedure specification or procedure spec.


Note:

This topic applies to nested procedures. For information about standalone procedures, see "CREATE PROCEDURE Statement". For information about package procedures, see "CREATE PACKAGE Statement".

Topics

Syntax

procedure_declaration ::=

Description of procedure_declaration.gif follows

procedure_heading ::=

Description of procedure_heading.gif follows

See "parameter_declaration ::=".

procedure_definition ::=

Description of procedure_definition.gif follows

See:

Semantics

procedure_declaration

Declares a procedure, but does not define it. The definition must appear later in the same block, subprogram, or package as the declaration.

procedure_heading

procedure

Name of the procedure that you are declaring or defining.

procedure_definition

Either defines a procedure that was declared earlier or both declares and defines a procedure.

declare_section

Declares items that are local to the procedure, can be referenced in body, and cease to exist when the procedure completes execution.

body

Required executable part and optional exception-handling part of the procedure.

call_spec, EXTERNAL

See "call_spec" and "EXTERNAL".

Restriction on call_spec, EXTERNAL These clauses can appear only in a package specification or package body.

PKr3 Z<7PKwD OEBPS/autotransaction_pragma.htm AUTONOMOUS_TRANSACTION Pragma

AUTONOMOUS_TRANSACTION Pragma

The AUTONOMOUS_TRANSACTION pragma marks a routine as autonomous; that is, independent of the main transaction.

In this context, a routine is one of these:

  • Schema-level (not nested) anonymous PL/SQL block

  • Standalone, package, or nested subprogram

  • Method of an ADT

  • Noncompound trigger

Topics

Syntax

autonomous_trans_pragma ::=

Description of autonomous_trans_pragma.gif follows

PKӢaPKwDOEBPS/delete_statement.htm DELETE Statement Extension

DELETE Statement Extension

The PL/SQL extension to the where_clause of the SQL DELETE statement lets you specify a CURRENT OF clause, which restricts the DELETE statement to the current row of the specified cursor. For information about the CURRENT OF clause, see "UPDATE Statement Extensions".


See Also:

Oracle Database SQL Language Reference for the syntax of the SQL DELETE statement

PKCw PKwDOEBPS/collection_method.htmt Collection Method Invocation

Collection Method Invocation

A collection method is a PL/SQL subprogram that either returns information about a collection or operates on a collection.

Topics

Syntax

collection_method_call ::=

Description of collection_method_call.gif follows

Semantics

collection

Name of the collection whose method you are invoking.

COUNT

Function that returns the number of elements in the collection, explained in "COUNT Collection Method".

DELETE

Procedure that deletes elements from the collection, explained in "DELETE Collection Method".

Restriction on DELETE If collection is a varray, you cannot specify indexes with DELETE.

index

Numeric expression whose data type either is PLS_INTEGER or can be implicitly converted to PLS_INTEGER (for information about the latter, see "Predefined PLS_INTEGER Subtypes").

EXISTS

Function that returns TRUE if the indexth element of the collection exists and FALSE otherwise, explained in "EXISTS Collection Method".

EXTEND

Procedure that adds elements to the end of the collection, explained in "EXTEND Collection Method".

Restriction on EXTEND You cannot use EXTEND if collection is an associative array.

FIRST

Function that returns the first index in the collection, explained in "FIRST and LAST Collection Methods".

LAST

Function that returns the last index in the collection, explained in "FIRST and LAST Collection Methods".

LIMIT

Function that returns the maximum number of elements that the collection can have. If the collection has no maximum size, then LIMIT returns NULL. For an example, see "LIMIT Collection Method".

NEXT

Function that returns the index of the succeeding existing element of the collection, if one exists. Otherwise, NEXT returns NULL. For more information, see "PRIOR and NEXT Collection Methods".

PRIOR

Function that returns the index of the preceding existing element of the collection, if one exists. Otherwise, NEXT returns NULL. For more information, see "PRIOR and NEXT Collection Methods".

TRIM

Procedure that deletes elements from the end of a collection, explained in "TRIM Collection Method".

Restriction on TRIM You cannot use TRIM if collection is an associative array.

number

Number of elements to delete from the end of a collection. Default: one.

Related Topics

In this chapter:

In other chapters:

PKTPKwDOEBPS/close_statement.htm  CLOSE Statement

CLOSE Statement

The CLOSE statement closes a named cursor, freeing its resources for reuse.

After closing an explicit cursor, you can reopen it with the OPEN statement. You must close an explicit cursor before reopening it.

After closing a cursor variable, you can reopen it with the OPEN FOR statement. You need not close a cursor variable before reopening it.

Topics

Syntax

close_statement ::=

Description of close_statement.gif follows

Semantics

cursor

Name of an open explicit cursor.

cursor_variable

Name of an open cursor variable.

:host_cursor_variable

Name of a cursor variable declared in a PL/SQL host environment and passed to PL/SQL as a bind variable. Do not put space between the colon (:) and host_cursor_variable.

PKbX % PKwDOEBPS/reservewords.htm;_ PL/SQL Reserved Words and Keywords

D PL/SQL Reserved Words and Keywords

Reserved words (listed in Table D-1) and keywords (listed in Table D-2) are identifiers that have special meaning in PL/SQL. They are case-insensitive. For more information about them, see "Reserved Words and Keywords".


Note:

Some of the words in this appendix are also reserved by SQL. You can display them with the dynamic performance view V$RESERVED_WORDS. For information about this view, see Oracle Database Reference.

Table D-1 PL/SQL Reserved Words

Begins with:Reserved Words

A

ALL, ALTER, AND, ANY, AS, ASC, AT

B

BEGIN, BETWEEN, BY

C

CASE, CHECK, CLUSTERS, CLUSTER, COLAUTH, COLUMNS, COMPRESS, CONNECT, CRASH, CREATE, CURSOR

D

DECLARE, DEFAULT, DESC, DISTINCT, DROP

E

ELSE, END, EXCEPTION, EXCLUSIVE

F

FETCH, FOR, FROM, FUNCTION

G

GOTO, GRANT, GROUP

H

HAVING

I

IDENTIFIED, IF, IN, INDEX, INDEXES, INSERT, INTERSECT, INTO, IS

L

LIKE, LOCK

M

MINUS, MODE

N

NOCOMPRESS, NOT, NOWAIT, NULL

O

OF, ON, OPTION, OR, ORDER, OVERLAPS

P

PROCEDURE, PUBLIC

R

RESOURCE, REVOKE

S

SELECT, SHARE, SIZE, SQL, START, SUBTYPE

T

TABAUTH, TABLE, THEN, TO, TYPE

U

UNION, UNIQUE, UPDATE

V

VALUES, VIEW, VIEWS

W

WHEN, WHERE, WITH


Table D-2 PL/SQL Keywords

Begins with:Keywords

A

A, ADD, ACCESSIBLE, AGENT, AGGREGATE, ARRAY, ATTRIBUTE, AUTHID, AVG

B

BFILE_BASE, BINARY, BLOB_BASE, BLOCK, BODY, BOTH, BOUND, BULK, BYTE

C

C, CALL, CALLING, CASCADE, CHAR, CHAR_BASE, CHARACTER, CHARSET, CHARSETFORM, CHARSETID, CLOB_BASE, CLONE, CLOSE, COLLECT, COMMENT, COMMIT, COMMITTED, COMPILED, CONSTANT, CONSTRUCTOR, CONTEXT, CONTINUE, CONVERT, COUNT, CREDENTIAL, CURRENT, CUSTOMDATUM

D

DANGLING, DATA, DATE, DATE_BASE, DAY, DEFINE, DELETE, DETERMINISTIC, DIRECTORY, DOUBLE, DURATION

E

ELEMENT, ELSIF, EMPTY, ESCAPE, EXCEPT, EXCEPTIONS, EXECUTE, EXISTS, EXIT, EXTERNAL

F

FINAL, FIRST, FIXED, FLOAT, FORALL, FORCE

G

GENERAL

H

HASH, HEAP, HIDDEN, HOUR

I

IMMEDIATE, INCLUDING, INDICATOR, INDICES, INFINITE, INSTANTIABLE, INT, INTERFACE, INTERVAL, INVALIDATE, ISOLATION

J

JAVA

L

LANGUAGE, LARGE, LEADING, LENGTH, LEVEL, LIBRARY, LIKE2, LIKE4, LIKEC, LIMIT, LIMITED, LOCAL, LONG, LOOP

M

MAP, MAX, MAXLEN, MEMBER, MERGE, MIN, MINUTE, MOD, MODIFY, MONTH, MULTISET

N

NAME, NAN, NATIONAL, NATIVE, NCHAR, NEW, NOCOPY, NUMBER_BASE

O

OBJECT, OCICOLL, OCIDATE, OCIDATETIME, OCIDURATION, OCIINTERVAL, OCILOBLOCATOR, OCINUMBER, OCIRAW, OCIREF, OCIREFCURSOR, OCIROWID, OCISTRING, OCITYPE, OLD, ONLY, OPAQUE, OPEN, OPERATOR, ORACLE, ORADATA, ORGANIZATION, ORLANY, ORLVARY, OTHERS, OUT, OVERRIDING

P

PACKAGE, PARALLEL_ENABLE, PARAMETER, PARAMETERS, PARENT, PARTITION, PASCAL, PIPE, PIPELINED, PLUGGABLE, PRAGMA, PRECISION, PRIOR, PRIVATE

R

RAISE, RANGE, RAW, READ, RECORD, REF, REFERENCE, RELIES_ON, REM, REMAINDER, RENAME, RESULT, RESULT_CACHE, RETURN, RETURNING, REVERSE, ROLLBACK, ROW

S

SAMPLE, SAVE, SAVEPOINT, SB1, SB2, SB4, SECOND, SEGMENT, SELF, SEPARATE, SEQUENCE, SERIALIZABLE, SET, SHORT, SIZE_T, SOME, SPARSE, SQLCODE, SQLDATA, SQLNAME, SQLSTATE, STANDARD, STATIC, STDDEV, STORED, STRING, STRUCT, STYLE, SUBMULTISET, SUBPARTITION, SUBSTITUTABLE, SUM, SYNONYM

T

TDO, THE, TIME, TIMESTAMP, TIMEZONE_ABBR, TIMEZONE_HOUR, TIMEZONE_MINUTE, TIMEZONE_REGION, TRAILING, TRANSACTION, TRANSACTIONAL, TRUSTED

U

UB1, UB2, UB4, UNDER, UNPLUG, UNSIGNED, UNTRUSTED, USE, USING

V

VALIST, VALUE, VARIABLE, VARIANCE, VARRAY, VARYING, VOID

W

WHILE, WORK, WRAPPED, WRITE

Y

YEAR

Z

ZONE


PKTv;;PKwDOEBPS/preface.htm"F Preface

Preface

Oracle Database PL/SQL Language Reference describes and explains how to use PL/SQL, the Oracle procedural extension of SQL.

Preface Topics

Audience

Oracle Database PL/SQL Language Reference is intended for anyone who is developing PL/SQL-based applications for either an Oracle Database or an Oracle TimesTen In-Memory Database, including:

  • Programmers

  • Systems analysts

  • Project managers

  • Database administrators

To use this document effectively, you need a working knowledge of:

  • Oracle Database

  • Structured Query Language (SQL)

  • Basic programming concepts such as IF-THEN statements, loops, procedures, and functions

Documentation Accessibility

For information about Oracle's commitment to accessibility, visit the Oracle Accessibility Program website at http://www.oracle.com/pls/topic/lookup?ctx=acc&id=docacc.

Access to Oracle Support

Oracle customers have access to electronic support through My Oracle Support. For information, visit http://www.oracle.com/pls/topic/lookup?ctx=acc&id=info or visit http://www.oracle.com/pls/topic/lookup?ctx=acc&id=trs if you are hearing impaired.

Conventions

This document uses these text conventions:

ConventionMeaning
boldfaceBoldface type indicates graphical user interface elements associated with an action, or terms defined in text or the glossary.
italicItalic type indicates book titles, emphasis, or placeholder variables for which you supply particular values.
monospaceMonospace type indicates commands within a paragraph, URLs, code in examples, text that appears on the screen, or text that you enter.
{A|B|C}Choose either A, B, or C.

Also:

  • *_view means all static data dictionary views whose names end with view. For example, *_ERRORS means ALL_ERRORS, DBA_ERRORS, and USER_ERRORS. For more information about any static data dictionary view, or about static dictionary views in general, see Oracle Database Reference.

  • Table names not qualified with schema names are in the sample schema HR. For information about the sample schemas, see Oracle Database Sample Schemas.

Syntax Descriptions

Syntax descriptions are provided in this book for various SQL, PL/SQL, or other command-line constructs in graphic form or Backus Naur Form (BNF). See Oracle Database SQL Language Reference for information about how to interpret these descriptions.

PK&Ѧƾ""PKwDOEBPS/drop_package.htm7 DROP PACKAGE Statement

DROP PACKAGE Statement

The DROP PACKAGE statement drops a stored package from the database. This statement drops the body and specification of a package.


Note:

Do not use this statement to drop a single object from a package. Instead, re-create the package without the object using the "CREATE PACKAGE Statement" and "CREATE PACKAGE BODY Statement" with the OR REPLACE clause.

Topics

Prerequisites

The package must be in your schema or you must have the DROP ANY PROCEDURE system privilege.

Syntax

drop_package ::=

Description of drop_package.gif follows

Semantics

BODY

Drops only the body of the package. If you omit this clause, then the database drops both the body and specification of the package.

When you drop only the body of a package but not its specification, the database does not invalidate dependent objects. However, you cannot invoke a procedure or stored function declared in the package specification until you re-create the package body.

schema

Name of the schema containing the package. Default: your schema.

package

Name of the package to be dropped.

The database invalidates any local objects that depend on the package specification. If you subsequently reference one of these objects, then the database tries to recompile the object and returns an error if you have not re-created the dropped package.

If any statistics types are associated with the package, then the database disassociates the statistics types with the FORCE clause and drops any user-defined statistics collected with the statistics types.


See Also:


Example

Dropping a Package: Example This statement drops the specification and body of the emp_mgmt package, which was created in "Creating a Package Body: Example", invalidating all objects that depend on the specification:

DROP PACKAGE emp_mgmt; 
PKs%8<7PKwDOEBPS/function.htm9 Function Declaration and Definition

Function Declaration and Definition

A function is a subprogram that returns a value. The data type of the value is the data type of the function. A function invocation (or call) is an expression, whose data type is that of the function.

Before invoking a function, you must declare and define it. You can either declare it first (with function_declaration) and then define it later in the same block, subprogram, or package (with function_definition) or declare and define it at the same time (with function_definition).

A function declaration is also called a function specification or function spec.


Note:

This topic applies to nested functions. For information about standalone functions, see "CREATE FUNCTION Statement". For information about package functions, see "CREATE PACKAGE Statement".

Topics

Syntax

function_declaration ::=

Description of function_declaration.gif follows

function_heading ::=

Description of function_heading.gif follows

See:

function_definition ::=

Description of function_definition.gif follows

See:

relies_on_clause ::=

Description of relies_on_clause.gif follows

Semantics

function_declaration

Declares a function, but does not define it. The definition must appear later in the same block, subprogram, or package as the declaration.

DETERMINISTIC

Tells the optimizer that the function returns the same value whenever it is invoked with the same parameter values (if this is not true, then specifying DETERMINISTIC causes unpredictable results). If the function was invoked previously with the same parameter values, the optimizer can use the previous result instead of invoking the function again. DETERMINISTIC can appear only once in the function.

Do not specify DETERMINISTIC for a function whose result depends on the state of session variables or schema objects, because results might vary across invocations. Instead, consider making the function result-cached (see "Making Result-Cached Functions Handle Session-Specific Settings" and "Making Result-Cached Functions Handle Session-Specific Application Contexts").

Only DETERMINISTIC functions can be invoked from a function-based index or a materialized view that has query-rewrite enabled. For more information and possible limitations of the DETERMINISTIC option, see "CREATE FUNCTION Statement".

It is good programming practice to make functions that fall into these categories DETERMINISTIC:

  • Functions used in a WHERE, ORDER BY, or GROUP BY clause

  • Functions that MAP or ORDER methods of a SQL type

  • Functions that help determine whether or where a row appears in a result set

Restriction on DETERMINISTIC You cannot specify DETERMINISTIC for a nested function.

PIPELINED

Use only with a table function, to specify that it is pipelined. A pipelined table function returns a row to its invoker immediately after processing that row and continues to process rows. To return a row (but not control) to the invoker, the function uses the "PIPE ROW Statement". PIPELINED can appear only once in the function.

Restriction on PIPELINED You cannot specify PIPELINED for a nested function.


Note:

You cannot run a pipelined table function over a database link. The reason is that the return type of a pipelined table function is a SQL user-defined type, which can be used only in a single database (as explained in Oracle Database Object-Relational Developer's Guide). Although the return type of a pipelined table function might appear to be a PL/SQL type, the database actually converts that PL/SQL type to a corresponding SQL user-defined type.

PARALLEL_ENABLE

Enables the function for parallel execution, making it safe for use in slave sessions of parallel DML evaluations. PARALLEL_ENABLE can appear only once in the function.

Restriction on PARALLEL_ENABLE You cannot specify PARALLEL_ENABLE for a nested function.

RESULT_CACHE

Caches the results of the function. RESULT_CACHE can appear only once in the function. For more information, see "PL/SQL Function Result Cache".

Restriction on RESULT_CACHE You cannot specify RESULT_CACHE for a nested function.

function_heading

function

Name of the function that you are declaring or defining.

RETURN datatype

Specifies the data type of the value that the function returns, which can be any PL/SQL data type (see Chapter 3, "PL/SQL Data Types").

Restriction on datatype You cannot constrain this data type (with NOT NULL, for example). If datatype is a constrained subtype, then the returned value does not inherit the constraints of the subtype (see "Formal Parameters of Constrained Subtypes").

function_definition

Either defines a function that was declared earlier or both declares and defines a function.

declare_section

Declares items that are local to the function, can be referenced in body, and cease to exist when the function completes execution.

body

Required executable part and optional exception-handling part of the function. In the executable part, at least one execution path must lead to a RETURN statement; otherwise, a runtime error occurs.

call_spec, EXTERNAL

See "call_spec" and "EXTERNAL".

Restriction on call_spec, EXTERNAL These clauses can appear only in a package specification or package body.

relies_on_clause

Specifies the data sources on which the results of the function depend. Each data_source is the name of either a database table or view.


Note:

  • This clause is deprecated. As of Oracle Database 12c, the database detects all data sources that are queried while a result-cached function is running, and relies_on_clause does nothing.

  • You cannot use relies_on_clause in a function declared in an anonymous block.


PKaa699PKwDOEBPS/collection_variable.htmBl Collection Variable Declaration

Collection Variable Declaration

A collection variable is a composite variable whose internal components, called elements, have the same data type. The value of a collection variable and the values of its elements can change.

You reference an entire collection by its name. You reference a collection element with the syntax collection(index).

PL/SQL has three kinds of collection types:

  • Associative array (formerly called PL/SQL table or index-by table)

  • Variable-size array (varray)

  • Nested table

An associative array can be indexed by either a string type or PLS_INTEGER. Varrays and nested tables are indexed by integers.

You can create a collection variable in either of these ways:

  • Define a collection type and then declare a variable of that type.

  • Use %TYPE to declare a collection variable of the same type as a previously declared collection variable.


Note:

This topic applies to collection types that you define inside a PL/SQL block or package, which differ from standalone collection types that you create with the "CREATE TYPE Statement".

In a PL/SQL block or package, you can define all three collection types. With the CREATE TYPE statement, you can create nested table types and VARRAY types, but not associative array types.


Topics

Syntax

collection_type_definition ::=

Description of collection_type_definition.gif follows

assoc_array_type_def ::=

Description of assoc_array_type_def.gif follows

See:

varray_type_def ::=

Description of varray_type_def.gif follows

See "datatype ::=".

nested_table_type_def ::=

Description of nested_table_type_def.gif follows

datatype ::=

Description of datatype.gif follows

See:

collection_variable_dec ::=

Description of collection_variable_dec.gif follows

See "collection_constructor ::=".

Semantics

collection_type_definition

type

Name of the collection type that you are defining.

assoc_array_type_def

Type definition for an associative array.

Restriction on assoc_array_type_def Can appear only in the declarative part of a block, subprogram, package specification, or package body.

nested_table_type_def

Type definition for a nested table.

varray_type_def

Type definition for a variable-size array.

assoc_array_type_def

datatype

Data type of the elements of the associative array. datatype can be any PL/SQL data type except REF CURSOR.

NOT NULL

Imposes the NOT NULL constraint on every element of the associative array. For information about this constraint, see "NOT NULL Constraint".

{ PLS_INTEGER | BINARY_INTEGER }

Specifies that the data type of the indexes of the associative array is PLS_INTEGER.

{ VARCHAR2 | VARCHAR | STRING } (v_size)

Specifies that the data type of the indexes of the associative array is VARCHAR2 (or its subtype VARCHAR or STRING) with length v_size.

You can populate an element of the associative array with a value of any type that can be converted to VARCHAR2 with the TO_CHAR function (described in Oracle Database SQL Language Reference).


Caution:

Associative arrays indexed by strings can be affected by National Language Support (NLS) parameters. For more information, see "NLS Parameter Values Affect Associative Arrays Indexed by String".

LONG

Specifies that the data type of the indexes of the associative array is LONG, which is equivalent to VARCHAR2(32760).


Note:

Oracle supports LONG only for backward compatibility with existing applications. For new applications, use VARCHAR2(32760).

type_attribute, rowtype_attribute

Specifies that the data type of the indexes of the associative array is a data type specified with either %ROWTYPE or %TYPE. This data type must represent either PLS_INTEGER, BINARY_INTEGER, or VARCHAR2(v_size).

varray_type_def

size_limit

Maximum number of elements that the varray can have. size_limit must be an integer literal in the range from 1 through 2147483647.

datatype

Data type of the varray element. datatype can be any PL/SQL data type except REF CURSOR.

NOT NULL

Imposes the NOT NULL constraint on every element of the varray. For information about this constraint, see "NOT NULL Constraint".

nested_table_type_def

datatype

Data type of the elements of the nested table. datatype can be any PL/SQL data type except REF CURSOR or NCLOB.

If datatype is a scalar type, then the nested table has a single column of that type, called COLUMN_VALUE.

If datatype is an ADT, then the columns of the nested table match the name and attributes of the ADT.

NOT NULL

Imposes the NOT NULL constraint on every element of the nested table. For information about this constraint, see "NOT NULL Constraint".

datatype

collection_type

Name of a user-defined varray or nested table type (not the name of an associative array type).

object_type

Instance of a user-defined type.

record_type

Name of a user-defined type that was defined with the data type specifier RECORD.

ref_cursor_type

Name of a user-defined type that was defined with the data type specifier REF CURSOR.

scalar_datatype

Name of a scalar data type, including any qualifiers for size, precision, and character or byte semantics.

collection_variable_dec

new_collection_var

Name of the collection variable that you are declaring.

assoc_array_type

Name of a previously defined associative array type; the data type of new_collection_var.

varray_type

Name of a previously defined VARRAY type; the data type of new_collection_var.

nested_table_type

Name of a previously defined nested table type; the data type of new_collection_var.

collection_constructor

Collection constructor for the data type of new_collection_var, which provides the initial value of new_collection_var.

collection_var_1

Name of a previously declared collection variable of the same data type as new_collection_var, which provides the initial value of new_collection_var.


Note:

collection_var_1 and new_collection_var must have the same data type, not only elements of the same type.

collection_var_2

Name of a previously declared collection variable.

%TYPE

See "%TYPE Attribute".

PK{BBPKwDOEBPS/continue_statement.htmn CONTINUE Statement

CONTINUE Statement

The CONTINUE statement exits the current iteration of a loop, either conditionally or unconditionally, and transfers control to the next iteration of either the current loop or an enclosing labeled loop.

If a CONTINUE statement exits a cursor FOR loop prematurely (for example, to exit an inner loop and transfer control to the next iteration of an outer loop), the cursor closes (in this context, CONTINUE works like GOTO).


Note:

As of Oracle Database 11g Release 1, CONTINUE is a PL/SQL keyword. If your program invokes a subprogram named CONTINUE, you get a warning.

Restrictions on CONTINUE Statement

  • A CONTINUE statement must be inside a LOOP statement.

  • A CONTINUE statement cannot cross a subprogram or method boundary.

Topics

Syntax

continue_statement ::=

Description of continue_statement.gif follows

See "boolean_expression ::=".

Semantics

label

Name that identifies either the current loop or an enclosing loop (see "Basic LOOP Statement").

Without label, the CONTINUE statement transfers control to the next iteration of the current loop. With label, the CONTINUE statement transfers control to the next iteration of the loop that label identifies.

WHEN boolean_expression

Without this clause, the CONTINUE statement exits the current iteration of the loop unconditionally. With this clause, the CONTINUE statement exits the current iteration of the loop if and only if the value of boolean_expression is TRUE.

PKPKwDOEBPS/index.htm Index

Index

A  B  C  D  E  F  G  H  I  J  K  L  M  N  O  P  Q  R  S  T  U  V  W  Z 

Symbols

$$PLSQL_LINE inquiry directive, 2.10.1.4.1
$$PLSQL_UNIT inquiry directive, 2.10.1.4.1
$$PLSQL_UNIT_OWNER inquiry directive, 2.10.1.4.1
$$PLSQL_UNIT_TYPE inquiry directive, 2.10.1.4.1
% wildcard character, 2.7.5.3
%BULK_EXCEPTIONS cursor attribute, 12.4.1.4
%BULK_ROWCOUNT cursor attribute, 12.4.1.5
%FOUND cursor attribute
for implicit cursor, 6.2.1.2
for named cursor, 6.2.2.7.2
%ISOPEN cursor attribute
for implicit cursor, 6.2.1.1
for named cursor, 6.2.2.7.1
%NOTFOUND cursor attribute
for implicit cursor, 6.2.1.3
for named cursor, 6.2.2.7.3
%ROWCOUNT cursor attribute
for implicit cursor, 6.2.1.4
for named cursor, 6.2.2.7.4
%ROWTYPE attribute, 5.11.4
column alias and, 6.2.2.5
explicit cursor and, 6.2.2.5
invisible columns and, 5.11.4.4
syntax diagram, 13
virtual columns and, 5.11.4.3
%TYPE attribute, 2.3.5
initial value and, 2.3.5
NOT NULL constraint and, 2.3.5
syntax diagram, 13
_ wildcard character, 2.7.5.3

A

Abstract Data Type (ADT), 1.2.8.5
creating, 14
editioned, 14
accent-insensitive comparison, 2.7.5.2.3
ACCESS_INTO_NULL exception, 11.4
ACCESSIBLE BY clause
in package specification, 10.1
in subprogram, 8.2
ADT
See Abstract Data Type (ADT)
aggregate function, 14
in PL/SQL expression, 2.7.8
pipelined table function as, 12.5.6
SQL%NOTFOUND attribute and, 6.2.1.3
alias
column
in cursor FOR LOOP, 6.3.2
in explicit cursor, 6.2.2.5
table
for avoiding inner capture, B.6
for row expression, B.6.2
for table element attribute or method, B.6.1
aliasing (problem)
SELECT BULK COLLECT INTO statement and, 12.4.2.1.1
subprogram parameter, 8.6.4
ALTER FUNCTION statement, 14
ALTER LIBRARY statement, 14
ALTER PACKAGE statement, 14
ALTER PROCEDURE statement, 14
ALTER TRIGGER statement, 14
ALTER TYPE statement, 14
AND operator, 2.7.3
anonymous block, 1.2.2
AUTHID property and, 8.13
ANYDATA data type, 12.5.2
ANYDATASET data type, 12.5.2
ANYTYPE data type, 12.5.2
architecture of PL/SQL, 1.3
array
associative
See associative array
non-PL/SQL, 5.1
assignment of value
to composite variable
collection, 5.6
record, 5.12
to scalar variable, 2.6
assignment statement, 2.6.1
syntax diagram, 13
associative array, 5.2
characteristics of, 5.1
comparisons, 5.8
declaring constant, 5.2.1
FIRST and LAST methods for, 5.9.5.1
in FORALL statement, 13
NLS parameters and, 5.2.2
See also collection
atomic (lexical) unit, 2.2
atomically null collection
See null collection
attribute
%ROWTYPE
See %ROWTYPE attribute
%TYPE
See %TYPE attribute
cursor
See cursor attribute
AUTHID property, 8.13
autonomous routine, 6.7
declaring, 6.7.4
autonomous transaction, 6.7
controlling, 6.7.5
pipelined table function in, 13
autonomous trigger, 6.7.6
AUTONOMOUS_TRANSACTION pragma, 6.7.4
for pipelined table function, 12.5.2
syntax diagram, 13

B

bag data structure, 5.1
base type, 3
basic LOOP statement, 4.2.1
syntax diagram, 13
BETWEEN operator, 2.7.5.4
BINARY_DOUBLE data type
predefined constants for, 3.1.2
subtype of, 3.1.3
tuning code and, 12.3.5.1
BINARY_FLOAT data type
predefined constants for, 3.1.2
subtype of, 3.1.3
tuning code and, 12.3.5.1
BINARY_INTEGER data type
See PLS_INTEGER data type
bind variable
avoiding SQL injection with, 7.4.2.1
placeholder for
See placeholder for bind variable
blank-padding
in assignment, 3.1.4.3.2
in comparison, 3.1.4.3.3
block, 1.2.2
syntax diagram, 13
BOOLEAN data type, 3.2
BOOLEAN expression, 2.7.6
BOOLEAN static expression, 2.10.1.5.2
BOOLEAN variable, 2.6.4
built-in function
See SQL function
bulk binding, 12.4
BULK COLLECT clause, 12.4.2
aliasing and, 12.4.2.1.1
of FETCH statement, 12.4.2.2
of RETURNING INTO clause, 12.4.2.3
FORALL statement and, 12.4.3
of SELECT INTO statement, 12.4.2.1
query result set processing and, 6.3.1.2
that returns no rows, 12.4.2
bulk SQL, 12.4
in compound DML trigger, 9.3.3.3

C

C procedure, invoking, 8.14
cache, function result, 8.11
calculated column
See virtual column
call specification, 8.14
in CREATE FUNCTION statement, 14
in CREATE PROCEDURE statement, 14
in package, 10.1
call stack, AUTHID property and, 8.13
capture, B.5
cascading triggers, 9.11
CASE expression
searched, 2.7.7.2
simple, 2.7.7.1
case sensitivity
character comparison and, 2.7.5.2.3
character literal and, 2.2.3
identifier and, 2.2.2
quoted user-defined identifier, 2.2.2.3.2
keyword and, D
LIKE operator and, 2.7.5.3
reserved word and, D
CASE statement, 4.1
searched, 4.1.5
syntax diagram, 13
simple, 4.1.4
IF THEN ELSIF statement and, 4.1.3
syntax diagram, 13
CASE_NOT_FOUND exception, 11.4
case-insensitive comparison, 2.7.5.2.3
CHAR data type, 3.1.4
CHAR data type family, E
character code, 2.1
character literal, 2.2.3
See also string
character set, 2.1
CLOB data type and comparison operator, 2.7.5
CLOB data type family, E
CLOSE statement, 13
collating sequence, 2.7.5.2.3
collection, 5
as public package item, 5.10
assigning one to another, 5.6
comparing one to another, 5.8
cursor variable and, 13
declaration syntax, 13
empty, 5.1
creating with constructor, 5.5
index
See index collection
internal size of
DELETE method and, 5.9.1
EXTEND method and, 5.9.3
TRIM method and, 5.9.2
multidimensional, 5.7
null, 5.1
assigning to collection variable, 5.6.2
pipelined table function and, 12.5.1
querying
with dynamic SQL, 7.2.2
with static SQL, 6.4.6
retrieving query results into, 12.4.2
types of, 5.1
collection constructor, 5.5
collection method, 5.9
as subprogram parameter, 5.9
invocation syntax, 13
null collection and, 5.9
COLLECTION_IS_NULL exception, 11.4
column alias
in cursor FOR LOOP, 6.3.2
in explicit cursor, 6.2.2.5
comment, 2.2.4
nested, 2.2.4.2
PL/SQL Wrapper utility and, A.3
syntax diagram, 13
COMMIT statement, 6.6.1
FOR UPDATE cursor and, 6.6.6.3
in autonomous transaction, 6.7.5.2
comparison operator, 2.7.5
cursor variable and, 13
compatible data type
for collection variables, 5.6.1
for scalar variables, 2.6
compilation
conditional, 2.10
for native execution, 12.9
interpreted, 12.9.5
compilation parameter, 1.3.2
displaying value of, 2.10.1.4.1
predefined inquiry directive for, 2.10.1.4.1
compiler directive
See pragma
compile-time warning, 11.1
composite data type, 5
composite variable, 5
compound trigger, 9.3.3
computation-intensive code, 12.3.5
concatenation operator (||), 2.7.1
concurrent transactions, 6.7.5.4
condition, SQL multiset, 5.8.3
conditional compilation, 2.10
conditional compilation directive, 2.10.1
error, 2.10.1.3
inquiry, 2.10.1.4
restrictions on, 2.10.4
selection, 2.10.1.2
conditional predicate, 9.3.1
conditional selection statement, 4.1
conditional trigger, 9.1
constant
declaring, 2.3.3
associative array, 5.2.1
record, 5.11.2
syntax diagram, 13
initial value of, 2.3.4
predefined, 3.1.2
static, 2.10.1.5.4
in DBMS_DB_VERSION package, 2.10.1.5.5
constrained subtype, 3.4.2
in performance-critical code, 12.3.5.2
subprogram parameter and, 8.6.1.1
constraint
cursor parameter and, 13
NOT NULL
See NOT NULL constraint
trigger compared to, 9.2
constructor
See collection constructor
context of transaction, 6.7.2
CONTINUE statement, 4.2.4
syntax diagram, 13
CONTINUE WHEN statement, 4.2.5
syntax diagram, 13
control statement, 4
control token, 2.10.1.1
correlated subquery, 6.3.4
correlation name, 9.4
with LONG or LONG RAW column, 9.10.2
See also pseudorecord
COUNT collection method, 5.9.6
CREATE FUNCTION statement, 14
CREATE LIBRARY statement, 14
CREATE PACKAGE statement, 14
CREATE TRIGGER statement, 14
CREATE TYPE BODY statement, 14
CREATE TYPE statement, 14
CREATE_WRAPPED procedure, A.4
crossedition trigger, 9.1
CURRENT OF clause, 6.6.6.2
FOR UPDATE cursor and, 6.6.6.2
ROWID pseudocolumn instead of, 6.6.6.3
CURRVAL pseudocolumn, 6.1.2.1
cursor, 6.2
explicit
See explicit cursor
FOR UPDATE, 6.6.6.2
after COMMIT or ROLLBACK, 6.6.6.3
implicit
See implicit cursor
in SERIALLY_REUSABLE package, 10.7.2
named, 6.2.2
pipelined table function and, 12.5.5
See also explicit cursor and cursor variable
nested, 6.5
cursor attribute
for cursor variable, 6.4.7
for explicit cursor, 6.2.2.7
%FOUND, 6.2.2.7.2
%ISOPEN, 6.2.2.7.1
%NOTFOUND, 6.2.2.7.3
%ROWCOUNT, 6.2.2.7.4
for implicit cursor, 6.2.1
DBMS_SQL package and, 7.3
native dynamic SQL and, 7.2
SQL%BULK_EXCEPTIONS, 12.4.1.4
SQL%BULK_ROWCOUNT, 12.4.1.5
SQL%FOUND, 6.2.1.2
SQL%ISOPEN, 6.2.1.1
SQL%NOTFOUND, 6.2.1.3
SQL%ROWCOUNT, 6.2.1.4
where you can use, 6.2
CURSOR expression, 6.5
passing to pipelined table function, 12.5.6
cursor FOR LOOP statement
query result set processing with, 6.3.2
recursive invocation in, 8.9
syntax diagram, 13
cursor number
converting cursor variable to, 7.3.4
converting to cursor variable, 7.3.3
DBMS_SQL.GET_NEXT_RESULT procedure and, 7.3.2
DBMS_SQL.RETURN_RESULT procedure and, 7.3.1
cursor parameter, 6.2.2.6
cursor specification, 13
cursor variable, 6.4
converting cursor number to, 7.3.3
converting to cursor number, 7.3.4
DBMS_SQL.GET_NEXT_RESULT procedure and, 7.3.2
DBMS_SQL.RETURN_RESULT procedure and, 7.3.1
declaration syntax diagram, 13
CURSOR_ALREADY_OPEN exception, 11.4

D

data abstraction, 1.2.8
data definition language statement
See DDL statement
Data Pump Import and triggers, 9.14
data type
collection
See collection
compatible
for collection variables, 5.6.1
for scalar variables, 2.6
composite, 5
object
See Abstract Data Type (ADT)
of expression, 2.7
predefined, E
RECORD
See record
scalar, 3
SQL, 3.1
user-defined
See Abstract Data Type (ADT)
what it determines, 3
See also subtype
data type conversion, 3.1
implicit
See implicit data type conversion
SQL injection and, 7.4.1.3
data type family, 3
overloaded subprogram and, 8.8
predefined data types grouped by, E
subtypes with base types in same, 3.4.3
database character set, 2.1.1
DATABASE trigger, 9.5.2
DATE data type family, E
DBMS_ASSERT package, 7.4.2.2
DBMS_DB_VERSION package, 2.10.1.5.5
DBMS_DDL package, A.4
DBMS_PARALLEL_EXECUTE package, 12.6
DBMS_PREPROCESSOR package, 2.10.3
DBMS_PROFILE package, 12.8.1
DBMS_SQL package, 7.3
switching to native dynamic SQL from, 7.3
DBMS_SQL.GET_NEXT_RESULT procedure, 7.3.2
DBMS_SQL.RETURN_RESULT procedure, 7.3.1
DBMS_SQL.TO_NUMBER function, 7.3.4
DBMS_SQL.TO_REFCURSOR function, 7.3.3
DBMS_STANDARD package, 2.4
DBMS_TRACE package, 12.8.2
DBMS_WARNING package, 11.1.1
dbmsupgin.sql script, 12.9.5
dbmsupgnv.sql script, 12.9.5
DDL statement
dynamic SQL for, 7
in trigger, 6.7.6
subprogram side effects and, 8.12
deadlock
autonomous transaction and, 6.7.5.4
implicit rollback and, 6.6.4
declaration, 2.3
exception raised in, 11.8.1
default value
of cursor parameter, 6.2.2.6.1
of subprogram parameter, 8.6.5
See also initial value
DEFINE
binding category, 12.4
PL/SQL Wrapper utility and, A.3
definer’s rights unit
See DR unit
DELETE collection method, 5.9.1
COUNT method and, 5.9.6
EXISTS method and, 5.9.4
EXTEND method and, 5.9.3
FIRST method and, 5.9.5
LAST method and, 5.9.5
NEXT method and, 5.9.8
PRIOR method and, 5.9.8
TRIM method and, 5.9.2
DELETE statement
BEFORE statement trigger and, 9.9
PL/SQL extension to, 13
See also DML statement
DELETING conditional predicate, 9.3.1
delimiter, 2.2.1
dense collection, 5.1
Descriptive Intermediate Attributed Notation for Ada (DIANA), C
DETERMINISTIC option, 13
for pipelined table function, 12.5.2
directive
compiler
See pragma
error, 2.10.1.3
inquiry, 2.10.1.4
selection, 2.10.1.2
See also conditional compilation directive
direct-key partitioning, 14, 14
DML statement
avoiding inner capture in, B.6
in FORALL statement, 12.4.1
inside pipelined table function, 12.5.2
on pipelined table function result, 12.5.7
PL/SQL syntax of, 6.1.1
repeating efficiently, 12.4.1
DML trigger, 9.3
dot notation
for collection method, 5.9
for identifier in named PL/SQL unit, 2.4
for pseudocolumn, 6.1.2.1
for record field, 5
name resolution and, B.1
double quotation mark ("), 2.1.1
DR unit
call stack and, 8.13
dynamic SQL and, 8.13
name resolution and, 8.13
privilege checking and, 8.13
SCHEMA trigger and, 9.5.1
static SQL and, 8.13
See also AUTHID property
DROP FUNCTION statement, 14
DROP LIBRARY statement, 14
DROP PACKAGE statement, 14
DROP PROCEDURE statement, 14
DROP TRIGGER statement, 14
DROP TYPE BODY statement, 14
DUP_VAL_ON_INDEX exception, 11.4
dynamic SQL, 7
AUTHID property and, 8.13
native, 7.2
switching to DBMS_SQL package from, 7.3
placeholder for bind variable in
EXECUTE IMMEDIATE statement and, 7.2.1
repeated, 7.2.3
tuning, 12.2

E

editioned Abstract Data Type (ADT), 14
element of collection, 5
embedded SQL
See static SQL
empty collection, 5.1
creating with constructor, 5.5
error directive, 2.10.1.3
error handling, 11
error-reporting function
SQLCODE, 13
SQLERRM, 13
SQL%BULK_EXCEPTIONS and, 12.4.1.4
escape character, 2.7.5.3
escaped identifier, B.4
evaluation order, 2.7.2
events publication, 9.15
evolution of type, 14
exception
handling, 11.2
in FORALL statement, 12.4.1.2
in trigger, 9.8
See also exception handler
internally defined
See internally defined exception
predefined
See predefined exception
raised in cursor FOR LOOP statement, 6.3.2
raised in declaration, 11.8.1
raised in exception handler, 11.8.2
raising explicitly, 11.7
reraising, 11.7.1.3
unhandled, 11.9
in FORALL statement, 12.4.1.2
user-defined
See user-defined exception
exception handler, 11.2
continuing execution after, 11.11
exception raised in, 11.8.2
for NO_DATA_NEEDED, 12.5.8
GOTO statement and, 13
locator variables for, 11.2.2
retrieving error code and message in, 11.10
retrying transaction after, 11.12
syntax diagram, 13
EXCEPTION_INIT pragma, 13
for giving error code to user-defined exception, 11.7.2
for giving name to internally defined exception, 11.3
EXECUTE IMMEDIATE statement, 7.2.1
syntax diagram, 13
EXISTS collection method, 5.9.4
EXIT statement, 4.2.2
syntax diagram, 13
EXIT WHEN statement, 4.2.3
in basic LOOP statement, 4.2.3
syntax diagram, 13
exiting a loop, 4.2
explicit cursor, 6.2.2
declaration syntax diagram, 13
in package
declaring, 10.8
opening and closing, 10.7.3
query result processing with
in FOR LOOP statement, 6.3.2
with OPEN, FETCH, and CLOSE statements, 6.3.3
explicit format model, 7.4.2.3
expression, 2.7
CURSOR, 6.5
passing to pipelined table function, 12.5.6
data type of, 2.7
in explicit cursor, 6.2.2.5
SQL function in PL/SQL, 2.7.8
static, 2.10.1.5
syntax diagram, 13
EXTEND collection method, 5.9.3
external subprogram, 8.14

F

FETCH FIRST clause, 12.4.2.1.2
FETCH statement
across COMMIT, 6.6.6.3
record variable and, 5.12.2.2
syntax diagram, 13
that returns no row, 6.2.2.3
with BULK COLLECT clause, 12.4.2.2
with cursor variable, 6.4.3
with explicit cursor, 6.2.2.3
field of record, 5
FIRST collection method, 5.9.5
FOR LOOP statement, 4.2.6
bounds of, 4.2.6.2
FORALL statement and, 12.4.1
STEP clause and, 4.2.6
syntax diagram, 13
See also cursor FOR LOOP statement
FOR UPDATE cursor, 6.6.6.2
after COMMIT or ROLLBACK, 6.6.6.3
FORALL statement, 12.4.1, 12.4.1
associative array in, 13
bulk binding and, 12.4
BULK COLLECT clause and, 12.4.3
for sparse collection, 12.4.1.1
SQL%BULK_EXCEPTIONS and, 12.4.1.4.1
handling exception raised in
after FORALL completes, 12.4.1.4
immediately, 12.4.1.3
number of rows affected by, 12.4.1.5
syntax diagram, 13
unhandled exception in, 12.4.1.2
format model, 7.4.2.3
forward declaration of subprogram, 8.5
function
aggregate
See aggregate function
built-in
See SQL function
declaration syntax diagram, 13
error-reporting
SQLCODE, 13
SQLERRM, 12.4.1.4
invoking, 8.3
in SQL statement, 8.12
options for, 8.4.1
SQL
See SQL function
structure of, 8.4.1
table
See table function
See also subprogram
function result cache, 8.11
function specification, 13

G

generated column
See virtual column
GET_NEXT_RESULT procedure, 7.3.2
global identifier, 2.5
GOTO statement, 4.3.1
restrictions on, 13
syntax diagram, 13
granting roles to PL/SQL units, 8.13.1

H

hardware arithmetic, 12.3.5.1
hash table, 5.1
hiding PL/SQL source text
See wrapping PL/SQL source text
host variable
bulk-binding, 12.4.4
cursor variable as, 6.4.9
packages and, 10.2

I

identifier, 2.2.2
ambiguous reference to, B
escaped, B.4
global, 2.5
in static SQL, 6.1.1
local, 2.5
reference to, 2.4
scope of, 2.5
user-defined, 2.2.2.3
collecting data about, 12.7
visibility of, 2.5
See also name
IDL, C
IF statement, 4.1
IF THEN form, 4.1.1
IF THEN ELSE form, 4.1.2
IF THEN ELSIF form, 4.1.3
nested IF THEN ELSE statement and, 4.1.3
simple CASE statement and, 4.1.3
nested, 4.1.2
syntax diagram, 13
imp and triggers, 9.14
implicit cursor, 6.2.1
CURSOR expression with, 6.5
declaration syntax, 13
dynamic SQL and, 7.3
query result processing with
with cursor FOR LOOP statement, 6.3.2
with SELECT INTO statement, 6.3.1
implicit data type conversion
minimizing, 12.3.5.3
of subprogram parameter, 8.6.2
causing overload error, 8.8.3
of subtypes
constrained, 3.4.2
unconstrained, 3.4.1
with base types in same family, 3.4.3
implicit ROLLBACK statement, 6.6.4
implicitly returning query results, 7.3.1
Import and triggers, 9.14
IN operator, 2.7.5.5
IN OUT parameter mode, 8.6.3
IN parameter mode, 8.6.3
in-bind, 12.4
independent transaction
See autonomous transaction
index collection, 12.4.1.1
representing subset with, 12.4.1.1
index of collection, 5
index-by table
See associative array
infinite loop, 4.2.1
INFORMATIONAL compile-time warning, 11.1
INHERIT ANY PRIVILEGES privilege, 8.13
INHERIT PRIVILEGES privilege, 8.13
initial value
%TYPE attribute and, 2.3.5
NOT NULL constraint and, 2.3.1
of constant, 2.3.4
of variable
nested table, 5.4
record, 5.11.1
scalar, 2.3.4
varray, 5.3
See also default value
initialization parameter, 1.3.2
INLINE pragma, 12.1.1
syntax diagram, 13
inner capture, B.5.3
avoiding, B.6
input, 1.2.7
inquiry directive, 2.10.1.4
INSERT statement
inserting record with, 5.14
restrictions on, 5.16
PL/SQL extension to, 13
See also DML statement
INSERTING conditional predicate, 9.3.1
INSTEAD OF trigger, 9.1
for CREATE statement, 9.5.3
on DML statement, 9.3.2
compound, 9.3.3.1
for pipelined table function result, 12.5.7
on nested table column, 9.3.2
Interface Definition Language (IDL), C
internally defined exception, 11.3
giving name to, 11.3
raising explicitly, 11.7.1.2
interpreted compilation, 12.9.5
INVALID_CURSOR exception, 11.4
INVALID_NUMBER exception, 11.4
invisible column, 5.11.4.4
invoker’s rights unit
See IR unit
IR unit
call stack and, 8.13
dynamic SQL and, 8.13
granting roles to, 8.13.1
name resolution and, 8.13
privilege checking and, 8.13
static SQL and, 8.13, 8.13.2
template objects for, 8.13.2
See also AUTHID property
IS [NOT] NULL operator, 2.7.5.1
collections and, 5.8.1
isolation level of transaction, 6.7.3

J

Java class method invocation, 8.14

K

key-value pair
See associative array
keywords, 2.2.2.1
list of, D

L

labeled LOOP statement, 4.2.3
LAST collection method, 5.9.5
LEVEL pseudocolumn, 6.1.2
lexical unit, 2.2
library
creating, 14
dropping, 14
explicitly recompiling, 14
library arithmetic, 12.3.5.1
LIKE operator, 2.7.5.3
LIMIT clause, 12.4.2.2.1
LIMIT collection method, 5.9.7
line-continuation character, 2.2.3
literal, 2.2.3
local identifier, 2.5
locator variable, 11.2.2
lock mode, 6.6.6.1
LOCK TABLE statement, 6.6.6.1
locking
overriding default, 6.6.6
result set row, 6.6.6.2
table, 6.6.6.1
logical operator, 2.7.3
logical value, 3.2
LOGIN_DENIED exception, 11.4
LONG data type, 3.1.5
in trigger, 9.10.2
LONG RAW data type, 3.1.5
in trigger, 9.10.2
LOOP statement
exiting, 4.2
kinds of, 4.2
labeled, 4.2, 4.2.3
nested, 4.2.3
optimizing, 12.3.4
LOOP UNTIL structure, 4.2.7

M

MALFORMED_WRAP_INPUT exception, A.4
manageability, 1.1.6
MapReduce workloads, 14, 14
materialized view, trigger and, 14
membership test, 2.7.5.5
Method 4, 7.3
method, collection
See collection method
mixed parameter notation, 8.6.6
mode
lock, 6.6.6.1
subprogram parameter, 8.6.3
multibyte character set
as database character set, 2.1.1
variables for values from, 3.1.4.2
multidimensional collection, 5.7
multiline comment, 2.2.4.2
multiple data transformations, 12.5
multiset condition, 5.8.3
mutating table, 9.10.3
mutating-table error
for function, 8.12
for trigger, 9.10.3

N

name
qualified
See dot notation
qualified remote, 2.4
remote, 2.4
simple, 2.4
See also identifier
name resolution, B
AUTHID property and, 8.13
in static SQL, B.4
PL/SQL and SQL differences, B.3
named cursor, 6.2.2
pipelined table function and, 12.5.5
See also explicit cursor and cursor variable
named parameter notation, 8.6.6
national character set, 2.1.2
native dynamic SQL, 7.2
switching to DBMS_SQL package from, 7.3
native execution, compilation for, 12.9
NATURAL subtype, 3.3.2
NATURALN subtype, 3.3.2
nested comment, 2.2.4.2
nested cursor, 6.5
nested IF statement, 4.1.2
IF THEN ELSIF form and, 4.1.3
nested LOOP statement, 4.2.3
nested record
assignment example, 5.12.1
declaration example, 5.11.3
nested subprogram, 8.2
declaration and definition of, 8.2
forward declaration for, 8.5
nested table, 5.4
assigning null value to, 5.6.2
assigning set operation result to, 5.6.3
characteristics of, 5.1
column in view, trigger on, 9.3.2
comparing to NULL, 5.8.1
comparing two, 5.8.2
correlation names and, 9.4
COUNT method for, 5.9.6.2
FIRST and LAST methods for, 5.9.5.3
returned by function, 12.5.1
SQL multiset conditions and, 5.8.3
See also collection
nested transaction, 6.7
NEW correlation name, 9.4
with LONG or LONG RAW column, 9.10.2
NEXT collection method, 5.9.8
NEXTVAL pseudocolumn, 6.1.2.1
NLS parameters
associative array and, 5.2.2
character comparison and, 2.7.5.2.3
SQL injection and, 7.4.1.3
NO_DATA_FOUND exception, 11.4
NO_DATA_NEEDED exception, 12.5.8
SQLCODE for, 11.4
NOCOPY hint, 13
subprogram parameter aliasing and, 8.6.4.1
tuning subprogram invocation with, 12.3.3
nonpadded comparison semantics, 3.1.4.3.3
no-op (no operation) statement, 4.3.2
NOT NULL constraint, 2.3.1
%TYPE attribute and, 2.3.5
EXTEND method and, 5.9.3
NOT operator, 2.7.3
NOT_LOGGED_ON exception, 11.4
null collection, 5.1
assigning to collection variable, 5.6.2
collection method and, 5.9
NULL statement
syntax diagram, 13
uses for, 4.3.2
null string, 2.2.3
NULL value
assigning to record variable, 5.12.3
comparing to collection
associative array, 5.8
nested table, 5.8.1
varray, 5.8.1
comparison operator and, 2.7.5
concatenation operator and, 2.7.1
for $$PLSQL_UNIT inquiry directive, 2.10.1.4.1
for $$PLSQL_UNIT_OWNER inquiry directive, 2.10.1.4.1
for collection variable, 5.6.2
for subprogram parameter, 8.6.5
for unresolvable inquiry directive, 2.10.1.4.3
in control statement, 2.7.3
IN operator and, 2.7.5.5
in set, 2.7.5.5
in USING clause, 7.2.1
simple CASE expression and, 2.7.7.1
simple CASE statement and, 4.1.4
NUMBER data type family
inefficiency of, 12.3.5.1
members of, E

O

obfuscating PL/SQL source text
See wrapping PL/SQL source text
object type
See Abstract Data Type (ADT)
OBJECT_VALUE pseudocolumn, 9.4.1
OCI
associative array and, 5.2.3
cursor variable and, 6.4.9
OLD correlation name, 9.4
OPEN FOR statement, 13
recursive invocation and, 8.9
OPEN statement, 13
recursive invocation and, 8.9
operation, 2.7.2
operator
comparison, 2.7.5
cursor variable and, 13
logical, 2.7.3
relational, 2.7.5.2
collection and, 5.8
operator precedence, 2.7.2
optimizer
PL/SQL, 12.1
SQL, 12.5.5
OR operator, 2.7.3
Oracle Call Interface (OCI)
associative array and, 5.2.3
cursor variable and, 6.4.9
Oracle RAC environment, result caches in, 8.11.5.6
ORA-n error
See internally defined exception
ordinary user-defined identifier, 2.2.2.3.1
Original Import and triggers, 9.14
OUT parameter mode, 8.6.3
out-bind, 12.4
outer capture, B.5.1
output, 1.2.7
overloaded subprogram, 8.8
INLINE pragma and, 12.1.1

P

package, 10.1
body of
See package body
DBMS_STANDARD, 2.4
explicitly recompiling, 14
features of, 10.2
granting roles to, 8.13.1
guidelines for writing, 10.8
initialization of, 10.5
of static constants, 2.10.1.5.4
private items in, 10.4
product-specific, 10
public items in
See public package item
reasons to use, 10.2
SERIALLY_REUSABLE, 10.7
specification of
See package specification
STANDARD
See STANDARD package
state of, 10.6
supplied by Oracle, 10
wrapping, A
guideline for, A.2
package body, 10.1
creating, 14
dropping, 14
initialization part of, 10.4
assigning initial values in, 10.8
replacing, 14
package specification, 10.1
creating, 14
cursor variable in, 13
dropping, 14
replacing, 14
See also public package item
package subprogram, 8.2
parallel DML
bulk binding and, 12.4
for large table, 12.6
PARALLEL_ENABLE option, 13
for pipelined table function, 12.5.2
for table function, 12.5.1
parameter
compilation
See compilation parameter
explicit cursor, 6.2.2.6
initialization, 1.3.2
subprogram
See subprogram parameter
parameter mode, 8.6.3
PARENT correlation name, 9.4
with LONG or LONG RAW column, 9.10.2
parentheses
nested, 2.7.2
to control evaluation order, 2.7.2
to improve readability, 2.7.2
pattern matching, 2.7.5.3
percent sign (%) wildcard character, 2.7.5.3
PERFORMANCE compile-time warning, 11.1
PIPE ROW statement, 12.5.2
in autonomous routine, 6.7.5.4
PIPELINED option, 12.5.1
where to specify, 12.5.2
pipelined table function, 12.5.1
as aggregate function, 12.5.6
in autonomous transaction, 13
See also table function
placeholder for bind variable
in conditional compilation directive, 2.10.4
in dynamic SQL
EXECUTE IMMEDIATE statement and, 7.2.1
repeated, 7.2.3
in static SQL, 6.1.1
OPEN FOR statement and, 6.4.2
in trigger body, 9.4
PLS_INTEGER data type, 3.3
tuning code and, 12.3.5.1
PLS_INTEGER static expression, 2.10.1.5.1
PL/Scope tool, 12.7
PL/SQL architecture, 1.3
PL/SQL block
See block
PL/SQL engine, 1.3.1, 1.3.1
PL/SQL function result cache, 8.11
PL/SQL language
advantages of, 1.1
high performance of, 1.1.2
high productivity with, 1.1.3
lexical units of, 2.2
limits of, C
main features of, 1.2
manageability and, 1.1.6
portability of, 1.1.4
program limits of, C
scalability of, 1.1.5
SQL integration in, 1.1.1
syntax and semantics, 13
PL/SQL optimizer, 12.1
PL/SQL table
See associative array
PL/SQL unit, 1.3.2
stored
See stored PL/SQL unit
PL/SQL Wrapper utility, A.3
PLSQL_CCFLAGS compilation parameter, 2.10.1.4.2
PLSQL_OPTIMIZE_LEVEL compilation parameter, 12.1
PLSQL_WARNINGS compilation parameter
displaying value of
with ALL_PLSQL_OBJECT_SETTINGS view, 11.1
with DBMS_WARNING subprogram, 11.1.1
setting value of
with ALTER statements, 11.1
with PLSQL_WARNINGS subprogram, 11.1.1
portability, 1.1.4
positional parameter notation, 8.6.6
POSITIVE subtype, 3.3.2
POSITIVEN subtype, 3.3.2
post-processed source text, 2.10.3
pragma, 2.9
AUTONOMOUS_TRANSACTION, 13
for pipelined table function, 12.5.2
EXCEPTION_INIT, 13
INLINE, 12.1.1
syntax diagram, 13
RESTRICT_REFERENCES, 13
SERIALLY_REUSABLE, 13
UDF, 13
precedence, operator, 2.7.2
predefined constant, 3.1.2
predefined data type, E
predefined exception, 11.4
raising explicitly, 11.7.1.2
redeclared, 11.6
predefined inquiry directive, 2.10.1.4.1
predefined subtype, E
preprocessor control token, 2.10.1.1
PRIOR collection method, 5.9.8
privilege checking and AUTHID property, 8.13
procedure
declaration syntax, 13
invoking, 8.3
structure of, 8.4.1
See also subprogram
procedure specification, 13
product-specific package, 10
Profiler API, 12.8.1
profiling and tracing programs, 12.8
program limits, C
PROGRAM_ERROR exception, 11.4
pseudocolumn, 6.1.2
OBJECT_VALUE, 9.4.1
pseudoinstruction
See pragma
pseudorecord, 9.4
See also correlation name
public package item
appropriate, 10.3.1
collection type as, 5.10
cursor variable as, 13
declaring, 10.3
RECORD type as, 5.11.3, 5.11.3
referencing, 10.3
remote variable, 10.3.1
scope of, 10.3
visibility of, 10.3
publishing events, 9.15
purity rules for subprograms, 8.12

Q

qualified name
See dot notation
qualified remote name, 2.4
query
implicitly returning results of, 7.3.1
invoking function in, 12.3.2
processing result set of, 6.3
multiple-row dynamic query, 7.2.2
See also SELECT INTO statement
quotation mark, single or double, 2.1.1
quoted user-defined identifier, 2.2.2.3.2

R

RAISE statement, 11.7.1
syntax diagram, 13
RAISE_APPLICATION_ERROR procedure, 11.7.2
raising exception explicitly, 11.7
range test, 2.7.5.4
read-only transaction, 6.6.5
read-write transaction, 6.6.5
recompiling stored PL/SQL unit, 14
record, 5
as public package item, 5.11.3
assigning value to, 5.12
comparing one to another, 5.13
creating, 5.11
syntax diagram, 13
declaring constant, 5.11.2
nested
See nested record
representing row, 5.11.4
types of, 5.11.3
recursive subprogram, 8.9
result-cached, 8.11.4.2
recursive trigger, 9.9
REF CURSOR
See cursor variable
REF CURSOR type, 6.4.1
relational operator, 2.7.5.2
collection and, 5.8
RELEASE constant, 2.10.1.5.5
remote exception handling
subprograms and, 11.8
triggers and, 9.8
remote name, 2.4
remote public package variable, 10.3.1
remote subprogram
exceptions in, 11.8
invoked by trigger, 9.6
with composite parameter, 5
REPEAT UNTIL structure, 4.2.7
replacing stored PL/SQL unit, 14
reraising exception, 11.7.1.3
reserved preprocessor control token, 2.10.1.1
reserved words
information about, 2.2.2.1
list of, D
RESTRICT_REFERENCES pragma, 13
result cache, 8.11
RESULT_CACHE clause, 8.11.1
RESULT_CACHE option for function, 13, 14
RETURN clause of function, 8.4.1
RETURN INTO clause
See RETURNING INTO clause
RETURN statement, 8.4.2
RETURN_RESULT procedure, 7.3.1
RETURNING INTO clause, 13
BULK COLLECT clause of, 12.4.2.3
FORALL statement and, 12.4.3
returning query results implicitly, 7.3.1
REUSE SETTINGS clause, 1.3.2
ROLLBACK statement, 6.6.2
FOR UPDATE cursor and, 6.6.6.3
implicit, 6.6.4
in autonomous transaction, 6.7.5.2
transparent, 9.9
rowid, 3.1.6
ROWID data type, 3.1.6
ROWID pseudocolumn, 6.1.2
instead of CURRENT OF clause, 6.6.6.3
row-level trigger, 9.3
ROWNUM pseudocolumn
bulk SELECT operation and, 12.4.2.1.2
single-row result set and, 6.3.1.1
ROWTYPE_MISMATCH exception
error code for, 11.4
example of, 11.4
runtime error
See exception

S

same-scope capture, B.5.2
SAMPLE clause, 12.4.2.1.2
SAVEPOINT statement, 6.6.3
in autonomous transaction, 6.7.5.3
scalability
SERIALLY_REUSABLE packages and, 10.7
subprograms and, 1.1.5
scalar data type, 3
scalar variable
assigning value to, 2.6
declaration, 2.3.2
syntax diagram, 13
initial value of, 2.3.4
schema object
See stored PL/SQL unit
SCHEMA trigger, 9.5.1
scope of identifier, 2.5
searched CASE expression, 2.7.7.2
searched CASE statement, 4.1.5
syntax diagram, 13
security mechanism
against SQL injection, 7.4
PL/SQL source text wrapping
benefit of, A
limitations of, A.1
trigger as, 9.2
SELECT FOR UPDATE statement, 6.6.6.2
SELECT INTO statement
assigning values with
to record variable, 5.12.2.1
to scalar variables, 2.6.2
avoiding inner capture in, B.6
query result set processing with, 6.3.1
SQL%NOTFOUND attribute and, 6.2.1.3
SQL%ROWCOUNT attribute and, 6.2.1.4
syntax diagram, 13
with BULK COLLECT clause, 12.4.2.1
See also query
selection directive, 2.10.1.2
selector
in simple CASE expression, 2.7.7.1
in simple CASE statement, 4.1.4
SELF_IS_NULL exception, 11.4
sequence, 6.1.2.1
sequential control statement, 4.3
SERIALLY_REUSABLE package, 10.7
SERIALLY_REUSABLE pragma, 13
session cursor, 6.2
set data structure, 5.1
set membership test, 2.7.5.5
SET TRANSACTION statement, 6.6.5
SEVERE compile-time warning, 11.1
short-circuit evaluation
how it works, 2.7.4
tuning code and, 12.3.7
side effects of subprogram, 8.10
SIGNTYPE subtype, 3.3.2
simple CASE expression, 2.7.7.1
simple CASE statement, 4.1.4
IF THEN ELSIF statement and, 4.1.3
syntax diagram, 13
simple DML trigger, 9.3
simple name, 2.4
SIMPLE_DOUBLE subtype, 3.1.3
tuning code and, 12.3.5.1
SIMPLE_FLOAT subtype, 3.1.3
tuning code and, 12.3.5.1
SIMPLE_INTEGER subtype, 3.3.3
tuning code and, 12.3.5.1
single quotation mark (’), 2.1.1
single-line comment, 2.2.4.1
sparse collection, 5.1
FORALL statement for, 12.4.1.1
SQL%BULK_EXCEPTIONS and, 12.4.1.4.1
traversing, 5.9.8
specification
cursor, 13
function, 13
package
See package specification
procedure, 13
SQL
bulk, 12.4
in compound DML trigger, 9.3.3.3
dynamic
See dynamic SQL
static
See static SQL
SQL cursor
See implicit cursor
SQL data type, 3.1
SQL function
in PL/SQL expression, 2.7.8
tuning and, 12.3.6
SQL injection, 7.4
SQL integration in PL/SQL, 1.1.1
SQL multiset condition, 5.8.3
SQL MULTISET operator, 5.6.3
SQL optimizer, 12.5.5
SQL statement
for stored PL/SQL unit, 14
in trigger, 9.1
invoking collection method in, 5.9
invoking PL/SQL function in, 8.12
tuning, 12.3.1
See also anonymous block
SQL%BULK_EXCEPTIONS cursor attribute, 12.4.1.4
SQL%BULK_ROWCOUNT cursor attribute, 12.4.1.5
SQL%FOUND cursor attribute, 6.2.1.2
SQL%NOTFOUND cursor attribute, 6.2.1.3
SQL%ROWCOUNT cursor attribute, 6.2.1.4
SQL*Loader and triggers, 9.14
SQLCODE function, 13
SQLERRM function, 13
SQL%BULK_EXCEPTIONS and, 12.4.1.4
SQLJ object type, creating, 14
standalone subprogram, 8.2
function
creating, 14
dropping, 14
explicitly recompiling, 14
replacing, 14
procedure
creating, 14
dropping, 14
explicitly recompiling, 14
replacing, 14
STANDARD package
data type defined in
See predefined data type
exception defined in
See predefined exception
how it defines PL/SQL environment, 10.10
listing identifiers defined in, 2.2.2.2
referencing item defined in, 2.4
statement injection, 7.4.1.2
statement modification, 7.4.1.1
statement-level trigger, 9.3
static constant, 2.10.1.5.4
in DBMS_DB_VERSION package, 2.10.1.5.5
static expression, 2.10.1.5
static SQL, 6
AUTHID property and, 8.13
name resolution in, B.4
placeholder for bind variable in, 6.1.1
OPEN FOR statement and, 6.4.2
PL/SQL identifier in, 6.1.1
STORAGE_ERROR exception, 11.4
recursive invocation and, 8.9
store table, 5.4.2
stored PL/SQL unit, 1.3.2
creating, 14
recompiling, 14
replacing, 14
wrapping, A
stored subprogram, 8.2
unhandled exception in, 11.9
wrapping, A
string
null, 2.2.3
zero-length, 2.2.3
See also character literal
STRING subtype, 3.1.4.3.1
strong REF CURSOR type
creating, 6.4.1
FETCH statement and, 6.4.3
subprogram, 8
inlining, 12.1.1
invoked by trigger, 9.6
remote
See remote subprogram
unhandled exception in, 11.9
subprogram invocation
optimization of, 12.1.1
resolution of, 8.7
syntax of, 8.3
tuning, 12.3.3
subprogram parameter, 8.6
collection as, 5.9
composite variable as, 5
CURSOR expression as actual, 6.5
cursor variable as, 6.4.8
optional, 8.6.5
query result as, 6.4.8
required, 8.6.5
subquery
correlated, 6.3.4
result set processing with, 6.3.4
SUBSCRIPT_BEYOND_COUNT exception, 11.4
SUBSCRIPT_OUTSIDE_LIMIT exception, 11.4
subtype, 3
constrained, 3.4.2
subprogram parameter and, 8.6.1.1
of BINARY_DOUBLE data type, 3.1.3
of BINARY_FLOAT data type, 3.1.3
of PLS_INTEGER data type, 3.3.2
predefined, E
unconstrained, 3.4.1
user-defined, 3.4
See also data type
synonym, 2.4
SYS_INVALID_ROWID exception, 11.4
SYS_REFCURSOR type, 6.4.1
system trigger, 9.5

T

table
hash, 5.1
index-by
See associative array
mutating, 9.10.3
nested, 5.4
characteristics of, 5.1
parallel DML for large, 12.6
PL/SQL
See associative array
store, 5.4.2
unordered, 5.1
updating large in parallel, 12.6
table alias
for avoiding inner capture, B.6
for row expression, B.6.2
for table element attribute or method, B.6.1
table function, 12.5.1
pipelined
See pipelined table function
weak cursor variable argument to, 6.4.1
TABLE operator, 6.4.6
TCL statement, 6.1.1
in subprogram invoked by trigger, 9.6
in trigger, 6.7.6
template object, 8.13.2
TIMEOUT_ON_RESOURCE exception, 11.4
timing point
of DML trigger
compound, 9.3.3.1
simple, 9.3
of system trigger, 9.5
trigger firing order and, 9.11
TO_NUMBER function, 7.3.4
TO_REFCURSOR function, 7.3.3
TOO_MANY_ROWS exception, 11.4
Trace API, 12.8.2
trace file, 11
tracing and profiling programs, 12.8
transaction
autonomous, 6.7
pipelined table function in, 13
context of, 6.7.2
ending
with COMMIT statement, 6.6.1
with ROLLBACK statement, 6.6.2
isolation level of, 6.7.3
nested, 6.7
read-only, 6.6.5
read-write, 6.6.5
retrying after handling exception, 11.12
SQL%ROWCOUNT cursor attribute and, 6.2.1.4
visibility of, 6.7.3
Transaction Control Language
See TCL statement
TRANSACTIONS initialization parameter, 6.7.5.4
trigger, 9
as security mechanism, 9.2
AUTHID property and, 8.13
autonomous, 6.7.6
cascading, 9.11
DDL statement in, 6.7.6
hiding implementation details of, A.1
materialized view and, 14
recursive, 9.9
TCL statement in, 6.7.6
TRIM collection method, 5.9.2
tri-state logic, 2.7.3
tuning PL/SQL code, 12
type
See data type
type-compatible data type
for collection variables, 5.6.1
for scalar variables, 2.6

U

UDF pragma, 13
unconstrained subtype, 3.4.1
underscore (_) wildcard character, 2.7.5.3
unhandled exception, 11.9
in FORALL statement, 12.4.1.2
unordered table, 5.1
UPDATE statement
BEFORE statement trigger and, 9.9
PL/SQL extensions to, 13
with values in record, 5.15
restrictions on, 5.16
See also DML statement
UPDATING conditional predicate, 9;.3.1
UROWID data type, 3.1.6
USER_DUMP_DEST initialization parameter, 11
user-defined exception, 11.5
giving error code to, 11.7.2
raising
with RAISE statement, 11.7.1.1
with RAISE_APPLICATION_ERROR procedure, 11.7.2
user-defined identifier, 2.2.2.3
collecting data about, 12.7
user-defined subtype, 3.4
user-defined type
See Abstract Data Type (ADT)
utlrp.sql script, 12.9.5

V

V$RESERVED_WORDS view, D
validation check for avoiding SQL injection, 7.4.2.2
VALUE_ERROR exception, 11.4
VARCHAR subtype, 3.1.4.3.1
VARCHAR2 data type, 3.1.4
VARCHAR2 static expression, 2.10.1.5.3
variable
binding of, 12.4
BOOLEAN, 2.6.4
collection
See collection
composite, 5
cursor
See cursor variable
host
cursor variable as, 6.4.9
packages and, 10.2
in cursor variable query, 6.4.5
in explicit cursor query, 6.2.2.4
locator, 11.2.2
record
See record
remote public package, 10.3.1
scalar
See scalar variable
with undefined value, 6.1.1
variable-size array
See varray
varray, 5.3
assigning null value to, 5.6.2
characteristics of, 5.1
comparing to NULL, 5.8.1
COUNT method for, 5.9.6.1
FIRST and LAST methods for, 5.9.5.2
returned by function, 12.5.1
See also collection
VERSION constant, 2.10.1.5.5
view
AUTHID property and, 8.13
INSTEAD OF trigger and, 14
materialized, trigger and, 14
virtual column
%ROWTYPE attribute and, 5.11.4.3
explicit cursors and, 6.2.2.5
visibility
of identifier, 2.5
of transaction, 6.7.3

W

warning, compile-time, 11.1
weak REF CURSOR type
creating, 6.4.1
FETCH statement and, 6.4.3
WHILE LOOP statement, 4.2.7
syntax diagram, 13
white list
See ACCESSIBLE BY clause
whitespace character
between lexical units, 2.2.5
in character literal, 2.2.3
in database character set, 2.1.1
wildcard character, 2.7.5.3
WRAP function, A.4
wrap utility
See PL/SQL Wrapper utility
wrapping PL/SQL source text, A
inquiry directives and, 2.10.1.4.3

Z

ZERO_DIVIDE exception, 11.4
zero-length string, 2.2.3
PK'VPKwDOEBPS/formal_parameter.htm& Formal Parameter Declaration

Formal Parameter Declaration

A formal parameter declaration can appear in the following:

Topics

Syntax

parameter_declaration ::=

Description of parameter_declaration.gif follows

See:

Semantics

parameter

Name of the formal parameter that you are declaring, which you can reference in the executable part of the subprogram.

IN, OUT, IN OUT

Mode that determines the behavior of the parameter, explained in "Subprogram Parameter Modes". Default: IN.


Note:

Avoid using OUT and IN OUT for function parameters. The purpose of a function is to take zero or more parameters and return a single value. Functions must be free from side effects, which change the values of variables not local to the subprogram.

NOCOPY

Requests that the compiler pass the corresponding actual parameter by reference instead of value (for the difference, see "Subprogram Parameter Passing Methods"). Each time the subprogram is invoked, the optimizer decides, silently, whether to obey or disregard NOCOPY.


Caution:

NOCOPY increases the likelihood of aliasing. For details, see "Subprogram Parameter Aliasing with Parameters Passed by Reference".

The compiler ignores NOCOPY in these cases:

  • The actual parameter must be implicitly converted to the data type of the formal parameter.

  • The actual parameter is the element of a collection.

  • The actual parameter is a scalar variable with the NOT NULL constraint.

  • The actual parameter is a scalar numeric variable with a range, size, scale, or precision constraint.

  • The actual and formal parameters are records, one or both was declared with %ROWTYPE or %TYPE, and constraints on corresponding fields differ.

  • The actual and formal parameters are records, the actual parameter was declared (implicitly) as the index of a cursor FOR LOOP statement, and constraints on corresponding fields differ.

  • The subprogram is invoked through a database link or as an external subprogram.


Note:

The preceding list might change in a subsequent release.

datatype

Data type of the formal parameter that you are declaring. The data type can be a constrained subtype, but cannot include a constraint (for example, NUMBER(2) or VARCHAR2(20).

If datatype is a constrained subtype, the corresponding actual parameter inherits the NOT NULL constraint of the subtype (if it has one), but not the size (see Example 8-10).


Caution:

The data type REF CURSOR increases the likelihood of subprogram parameter aliasing, which can have unintended results. For more information, see "Subprogram Parameter Aliasing with Cursor Variable Parameters".

expression

Default value of the formal parameter that you are declaring. The data type of expression must be compatible with datatype.

If a subprogram invocation does not specify an actual parameter for the formal parameter, then that invocation evaluates expression and assigns its value to the formal parameter.

If a subprogram invocation does specify an actual parameter for the formal parameter, then that invocation assigns the value of the actual parameter to the formal parameter and does not evaluate expression.

PK>&&PKwD&OEBPS/img/alter_collection_clauses.gif GIF87aF:wwwqqqYYYUUUKKK???;;;333 ppphhhfff```XXXJJJHHHDDD@@@<<<888000(((&&&""",F:pH,Ȥrl:ШtJZجv˭xL.'Xhс~xM`"{D0K( "uEK" vI_ LFCC ib"GGE0\( EB+CAg iCP40{#GD ?X D0p%(Sqw>LPq[G}qx$]>p_.}Rԕ/^,+mrga~ܶ"!ӗ4ژ!gmmҦ߿N \'Nq 1j {PфHT-HL4 QN,aa0hh'o,Ñ h#$ NBуL&vkQ薠fkH>]D˟O9YETtM:,vc0 ,nQq=BPy4E}؉ !8b((D&8>BiQd*${ Eb0LyXSrB)Pe(A E%A h&oN40y.nG.NWw) L fAq*FNcċsH M @t? H 1P^F>yuCpz+ *`PF`Tf-!&oQ9v…M-|A`HrV Z)%j&؀0L*3M8I;x1CP+@&io lx$hrLh$dFMi`iGf鏷\_ĵ.18BISM` * xz"oh\ \  ũ%)wOM,{R%%nPt1HU;ek[z:3(p6 Pˑft 4zf$`gTIu (Byj"yIA KPaр "@%b|r?N71?\hkEB.f|T? FmW#4=F[켫(xֳ^w ,C]|vD(KU{ &Hq%al'."VoX;:$i! G]l2p Ԡ ̾`ď$V̕hrQgxPe͈]HZ)AyRq,qͱ\NِQXĹfwab݌2֍;V/͆B‹"~ t&D?"h%;:yN.QNV4}6{ Lk8ѪFkIk׽&lq";PK   PKwDOEBPS/img/alter_procedure.gifYGIF87a[}}}{{{wwwqqqmmmUUUSSS???;;;777333)))'''%%%###!!!vvvppphhhfff```\\\XXXPPPHHHDDD@@@:::888222000...&&&""" ,[+A -- 6Ar@~AlH0Ç#Jt=H@ƌ C*z$|RBW"L 0" yB@y&`HaglԌ9aЈ4p nYmDEY Tp|e\ a }46>];DpWѳ˘^N6QiKv^}bU4$$^DpHXq >⁉|†;_y'gBq6_/q}/\y şy$_@ :l_Ō}Od|`0!W c~0ae8aMz%`zq aw _4w %Wt^q !20p $Y‘m!q$2!҂ Q~5.e p3af@È0lh샦)(W^9z9 RE·(j+!\qάBJWE곙7O c{!w}޽Z{:A m$ȀX6AЦ2T JH4֟jr0N9iq#>@d&+f*Hu /̜A@S0We}f13īK*!Af~n19n }BhY^ P*&8HT +0&֗ItJPV@бX85"X3Wd_u76!6KnW@"'ƃ y h/=$_^t$ mz\v'AJgE֙zip({i[ >f%wLN)zrh= ;lp!2Kk0,"8`[w A.#Yy8UiӃJ)$Z~@9k)P [,6}odi+D &@v}LًPWwTzDFx=(d *  B1HBV6Wam4z" hAv H-9D5'APu' e;rY- ul 25)"x*"P!Z8Dv&< $c^4[6i K!*CFDƲ]x i"x HP(%>3ҖJ#zqLgj6YFsIEN2o2RG:T("*P*` &ϮWJV]1iC#x@CXkΥp59VLGO ,gz JK0 bwĢ4|hd˦6]QB4Jr JH4Y+6iVtc6rq6uN9ѲqgϷ~ Hۉf-:Vzw>cy 6$6ɀ4ڭ{#K2i;nz7(7b7]&ඨ u .uCT;AȖ\ȃJ2a/ 〨h (\>:P9oĔoOnú/ÙssS)WK qp!Ͻw~I@ .NB[wzs+&W9lozWa+ gEn<^`q2! y-tzD(GDf#)PI`:'fh@v2 3 "8$X&x%<*Ck//e"0oB'˴/BEb90$@G#t`~g~0B0B:',oYzLGjyo0uÈz6$tdoZSGua`Qa d6bjP2W8 'gRMॅ4F0spbufzZG<SVA ft4j2 p}h]7?;#I:*G0}PG7;UWrFeThk y<&gI!ԊtaBӅusN :2xY&iစcv DŽau{Vh\r&7 d)tnс76`0d[&6X= 3A%7eD1cc_1'yHAd(k1Zfc 1 m[vY? eC7LIOgXWI7t/]Z85^n gI^9X1HRH'pb!x4E"  y!\[pٜqڔrc 0pw?Rim0(X,9^G&9jiMkev[m'cdXR3`arIC9qQ@Vٝ)ĄpXEWyH"auA陋рГ,IUz96nSTzUU^Z R.zLk&MLzZHJc5K\rcD{3n6j<' TuE,|22+Fǂ0;Ȉ |Ȏ lȔakȁ\ɚ\<) ʤ 9{KɥɰB|Ũ;PKA^YPKwD&OEBPS/img/dynamic_returning_clause.gifO GIF87aD:www[[[YYYUUUKKKGGG???;;;777333 vvvppphhhfffdddXXXJJJHHHDDD@@@>>>222...&&&""" ,D:@pH,Ȥrl:ШtJZجXxxL.l+U ݴ|~|6~g>3k}K%^ ZJD*] *T\RȤɤPYF`,yBbq_%"D_CB,,HΨ Cf;hJ:6(Lp "gw9tDHl^:J͠fnK]}U,j@AAÛQbxN?,n X1%JPdF8XԌ= n((|Di&BB0sA^W3\8UuphlnzPB0,+<f$g8_5bfĢ'I@^a'85!^aJY0]((>6фב}F@ߞ eFEY`gTLUJy)R}}:5$@WV}a(vD6j$ꊖMNTo8֪c'VRLeW|y[@1wQBpRuguyZOCsW)u `41 y͐Σ #qެu- Y:Cd?q{pD]|(vi6LZ%Hb C5Etns|$Gju%v؉"dD.z!k7pHs'1;pK{ݴa^z#ߺH+0`Sq@$\}&R!XPapi Ršif9?p{4`OL)aҀ &%JxT,#!ds0[xwI sR8 8 KӚ&&*:T /PΉX̢8PhSbޖ !EnJpP+H@BY6Q ;t6:-6F;*H ȀtǂFV 万8w`X呲 @Ur*Xe咓I, $H6HBMX= Lf )L2/j8#]jW؀ІfFʗQ&o; Kf*(2R<,#ԲY$SBSS g<@^AHNQ-hҠw?QFȲвuJȦ."N/˯$s@]6K<+ 0-)KZ\2 ecWe5 _a'SKӏ̮] fx7 ld}ZƧ Z) #$\a8_@N<ʜx8 -+)-Z2L=5rwvD!J(цg<bSh=iXNiB|ŠEHR>>888444222000...,,,(((&&&$$$"""  ,HK3?#  5 #?ėøՎ+5C (5C#C5q@1 ;ʹ"¤Xŋ3j8[ΪVQ P^8h֢.a bFFN)yi$y&{Q %u4JJI?1^)̪6u#E>3E_"Z ߿wjWj!wE/ 1gRM{(㮅"PX,3M ^ͺuRuyزjk#:;y!ª `ݢ`[cУK9#3ĺhӼ C7#ca@3sk(n(We#A\"RGtfa'I]1 P0D"+hr!5 hW S77cأd@!6"X 5ّXf eG%Dž ?Bp;I6 r9HH\…UHHQ¦#&(!壐NG}j# h q*pN 0e y)3t 3D!mcvz$aiwnjo_2)" z Np, rXi)BqAfYs˶j-Sui!DbX! 4(ۀI2ƻ//!Cj: +Vݴ3 jĘZ"nˍzg`73 Q/U5'"kDK3C83ٝ(#A&g^H-6^3f߅(08D@dE +Ϩ뻇c6 Uogw@ (MMG+r! 2x⇇K 5RLw=Ėub݅N;z %bt8܅oCXRĂ3Dg "Fa dHQxU0 I*!4+ `;1b 3+[Čw FIX"1l;+ǩ9+ܑ#"!Xye ӑ@"i 8.LDWuZeqTz3Ŝ&Wեȹ:M)@DP8Y=g;q/jz/ XLm q[XC%;S`&bΉ4GsZWl9;#t93(ϏV=Wk[磭N Q_žz|ŖkZGnEw[߱,^^ KįlT%O5t竧~%=z}S~\"6ぁ]UK?؏7!G-ܥ eLh>E8R~\3(|XO1 C{;#F%á3981~x"6d};Zw4q6C)_6.mǂ~6#Q'; @zZ=`KP:P}HG[jl؆3>(_glt1ФB4[cJ8 4 ^gktHOq\e3F/14H+0J.|H` ye6Q&4Jvq<24E("AGH1(xFO"SV} I  MĸT{( -Q/ƁcʨW |M&? C莠Byg.Pݸ .XwHU ƄE#Șꨐ e2*Wqy5]0y%Ցr`z5n(6y)8H H CYd9I4GP KfM94OXY SUU.W` [)mi<'9/ԕh⇓E)Hn v) rYTZ3% 4QI RfYb[&xpD` 1 _vdž ,eIgC 4DaV`yAU"ns)C|Y_HY9x Dr) {󜬁ћju@Ts{q|VEc}) S`E 9 R1l %FD3}HS{P ETf5WVQbr 9$DFX;8Hqx~0AHW$7S#+!O H Ṓh3m"}fZ٤ Y2Vj' oZ AXɒ bH* BtXX'-ߒ* *B:IX-M4Rѕ&ʂz- ;%\s*aHRt)E7 0S;5 RGcꆦS"!(^'e/2b3F3:3\Pîm$-s0"TR+6-+9":#7cFۮŁ*3*Z礠 )͙\`'Dd'hDqTc8C\#5T* 'YqEVS $ A.1:0",5·IK-3 vOmH6PQq=_7aʱu tW D 0۰Lzζ9>1SD؂GH/7Vq+l < ;+Z3Kz^9-FaŬā- .̲[6p&{ks(#\sЂ?Ilzk5M "7c>K$a',?VMaD ]a*) ˱B$j[;5 ljGtxG-Ӫ41G8AƨP?  l"#@c2b*ZG"\3 +l*Bj,+95襐kdyٱArlO*DʷY*U<1l"k:Eľ*"IŠ-l1c-W,+¤GJ`BÓ6ՊƵr0]]C%qnWt܍:%_{S}!T[U,1RǠ!\\,A$) qA%T|F # ;\\k&ҧOK TTRSNY]QʁKAG잕 PRUQ B Ϝ_ ZO΀!,$ςCӈq['  1M%SA2!ϟƘ4 Ǜ]5 G&H:ӧpz ,p,-M ʜ[ HpiwX[ zwY I[3ݹCa=NElO*޸ 0s]+J. P`?41ͣVˏ~-9 XYg- bG $vZ VXZĤׂ>r4~FJoN҂d;-M. 5E3>[D .t}Q%˵yMEc\"U>S~᳍_sp1~m㑉Ŏ趱! ԽҖ@,0~M6TMz]+-莜#..&^%L&oϠ1A 3K // !_}.Cw@hw]Voפ2f"A/).&)cSQN 56=tO"O ZT gIi1o5%ax_T-)IT9ONW> fWSL7@_nD1 pnV 4@ޒ)p#:m ץOQHYvc_ {~U_^{sWH]%qB.] $q&"6X :ѤKc>$O2WiRxmV8}dȖ-ڀJB)!ϨU*OzJƦpIPBQqv(H_]w(XIZWcM<+(e 8@04dbO3(@~5Q*(EW(dBId5(BdN>IdxаXDW&X|D0ĕ#XP+~AJCVOY7~  0֍`ڧߚnfڌ^&i5~^~񘉙Dৣ5oߣ*歧R#cđhHZ@jA (գNұ@{X0kp۫*BkHRK2"CeB8J.&Z"oa*6샴$jtoy%kl\H¾U/!Py*À*]6z,0,IL@NR4RoQ1t)P@0&:\&wLE0d J^ @^K PWܳ7Sh wDokNIp"tK`L;[BBys {ͦL㏰y]@IªҐh*@q>"+$K>Bwn_qnR8KyKɞ + >|VZNf~ԊKn2q|#/p)<Kfu"cA&o] :Zb(.A&aG/>EX)%)a $6'HW% XDOpN>@tVDWP+*N'͠S>tD*3!_LBI40|q,~ [TWm#BC$_!"P% 6itH08 *1C<}*؍=կ!ZcnUbk$C?X²˰'҂yj[ V]lIYtn H4B Zwc fHg,7[z}`kFz?l.RE%nqk Ѣ!\FJ7_ u}h-bӵ8yfBduTAVpRkZD`,{/)Qw?3 Ɩ+[ dۋ+,>Z8iq!of Ô2qqEL[ Y-lxLbk%7ɁrL'珺rh0CM`fo_1dr`|5Y7)is~sYBjiy\-[>Vط9ZHC1-} n8kksc g%*zbS>h}]c5KGF5{H @ |;:^m@d9>aW hHV3F91 X>%G(۵2sy-濡;y#eD:FXϔp B ́[~5kcؓFJUqwh#@{πwKDChQoP0$r8g–^3g҆m`ToE  '<} 8?]Y&ŗmO˹ DkkA@)RL$X;)O#Kv\? x@B*}@'{yǫo2,bܷ/VA >`Dwt{2F4꿗=cYC OV(/ |v?:p2R V&1q B"'KDo2KAoHq!sXhG'hFz diTDyo~=肂8g%{ᆎpEׁ{օ(0؃h6uGXuȊh8'e芳臢?HBtHg9aĨYW[(Ixrc׈٨ȍSeэ(_}hIXX` `i(HhXA XkXT6wU/Z)Ca 9ry@Hj_xL6`!I3l:(V7%.´))0*)+ 9fbkA9\:I;]/ |p[M Ri# Y (HE3S)? Wi[9Y p<|a"DTBp p BY<"#nm t yє^h( 7tt|B' A KI9D4496ovFG,qCD HCBqC C t=(;C+r6)LwII31}]-#?F#zlw v׏mwTgr?(90O G2GGz$žx8ә#P'Ff^%qNcAK? .a ݰС@}J"W?QJِ: V DW2(I=Yg CFvc6Ȯ{}[;GY% (k<;dZI;\^a=8{L:+dhb Բ/ JcBc@0;S=U+d vWr45( T;$U`kIq+0t0mUcw'3J 6!bi)yFk∸$| 7bdj˹H?"{jXԹn ijo;˺ ۺKK˻ »z;bۺ [k>#YH_f883@J +淯 g݋M R p^ YEKDѠ&|nJ#nc,̷Y+28?C?0!q# ~(^[Ip|g޿iV8>V=joh. wոaTN^ *a,PDhr6ąn[nR: D< KXBb#LZՋʮҹl( 1D^=n33N5N 5?? 5ƃéǶ5ЯԕΖ&/#CːNC#3 B0M+\aƸMGQ?|Duw50 ӼG/s ۖgOP];}cއoX&/׿HolJa_ @k;PKLRP1K1PKwDOEBPS/img/constraint.gif_ GIF87a3O}}}wwwqqqYYYUUUKKKGGG???;;;777333---'''!!! ppphhhfff```XXXRRRJJJHHHDDD@@@666222000***&&&""" ,3OpH,Ȥrl:ШtJZجv 8xL. 4E} {rai' 2 xn R8z*`8lo*tJ/* FNpZhJ2K/nb *TLK*dBMG WLO2I/0,2o)\8H'HYKpİG,❈ZCd@b C<V\4DAnTX$"ǟ@Xpyu'IɼFRm)۰Bj d2A{4bP}."躍 f0ki¯/*KPXPmpDIq]r(r,ԓ{2SkQ J1LG`)\20)WQ 3]UN2j%chS#ԴVά$T3SVc͕^(rJ3oMUa3S?_vD2=ݹ/(C̉BmG?WDl6|I3 騧{r8V봫>/ u}8O`v؀V2dԖ"1  |bG +5,`$K#(8jRdWJJ@AZV Ç#JHŋ3jȱǏ CIɓx"0M) r@8 2'N&Q⳨QI<8jtgOM(Jj ZbpJgea>M-pe]CF޿YXh +^iWƐg0yk nh̹ϠCMt ȨLWxp۸sͻߺ&,3^#&cƗk|ASc@Yv7uO +1}P/㿶p- os~:_Ҭ hՈ(@b a2>!BR",'. Gab!+2#+;xH' 4n8cE Ϲ7⅂8d$E^-nyȔh%[jYAw!n>wH ig/!Q lU &@=`^yUncB_A`( (*)0b :ZCti0`w$]U AH):I >@O9+H K鲬*u]-,_YY+{; B9 9XQ &h- P j/;+zWnĮ V UanbDDgPp&"Վ|';ZyL-2 ?(J^H֨ V|0A"x׳St]8x}@`¿FBtLF{P$44̕(L =3c9`da!""@ oPNp:a\>D0O|D&RSK+^D2F'&1["OuFؔo\c7Ԉ8ŎkB01-D 8>zq_A$" C^x<4 'IJZ3 :N22'"fgL*m&2'c&-- BH81,8YJ .TĭH%HPd1Ydb](=aƒi|%8YC .+4YkP\6#IMZ%V/d'T B"a%& PP7w6MI,R h`γ }DH* F(q)oە8Xo-%9Dm<-Oc7 b. 5 n&% P(u @ ꫧ:TF=JYRhTE/JaFbjBQǭ)wjQ Qy嫏IX*Ar׶@(vW Qd1B:f -&v5^ĚW Y?v2vt"d^Q00-5 ccD2pŗ\c6x6ݜK2í l{r2i' ;K8n1m枼s A,p46h݊5f6N,(^q:_ EhKTaAZr.vď5Y,oyF_^{餘9.'Y J6O'˗DaSVo8+&H&z+~A05206;g?FtcM%џ!`TG Y*{HđE]BLs!#福>xf H"VDU$f:%;9DBOz(@%ñ#7&dӆbd8}1xEH8B %7"R<%DQ'ṙ0yfw^"?8y5~y1!B&+' Rp@2s*uW{ "<|?SbXr*3b8e&cS h"Y}INx;U{a7 3*Tk<B1v;!!,+-oVw u_^)rw6hVQB*+*:#H$s iIy0s/PI8UTr<NzYR"8'"!@cP]+1u]"3ZTurY;-`;s0`#hHN8 i=r C&5,>G9w j Tu9%b/5}e%R0B;\Wd9;WW%BΑ/PSA/ ? aRvr?6822"]#]ԇ[U!)^{( sZu 6{p%RTܢ|,2|07Rtc44ՆxU5>5.1g3v4{K! ;BscsTHXD(oa~"4EsSlRbbG)Cb)c#AP9Ef'SIKbOYa @ d:wg~ U@:9|+:e)RjpP@ehW⇙U9iz7fؘf)3 H HNɄ9BRkƸ DQ9mƹY5 `ˉO9bA ir!R0~ ܔy. @ #xALi}~ɟ⟵Y9@ 擛KC Q@ɠ~頴U<љә+M0Gϔr)ZI@G`w R։74in Vt<'N< t4( zR* ])N|iYĘvCCRRՈ}gܱZ FoJzG dku XeZy<9 % *0"\2y5`iy;03Z(0$pϷnHtjڣ*~ڦz8a#G@RڬlRa%vJ ;-hFz(׹.A:f6Z_ D3*!OparV 6fBOABQhF &Ȭ DS@27R"mbФbWP/ӲEID@T|L#3}hHI;ѡ> .@:0 ACh#zD:!h# rrWK@7vA>9O!GfD1LEujdz)A} WF~B#+P收[mK g;%J剛`#V:`M;㹪9+APP /Kk*17&x"Db!껱`# ` iY鼗1sWZr"Oǫ/aXcl}%욕51PgSn4T +}<s["{*lKDc]Ejl(5eŔRWrE$WCb*z(f*ux O4ؙ}"5 f-[ 3BD$µs@A)cdX YBY焥$ՊBƒUmIlyBRO, Q;d U $ 07:w1[8CԨ[[FH/ǕިY57 8~V_K2"&b* T3V@.L6O5%B8n2=h, #}wt栀2g+i]i2vWjb6Y-ے_y/ ZUo5(W@*v`V22{5"}O#^xu|V[/ a"h5ʒI4<`S6,wu҇FTV ^Ȑ\,GU߈0Z]b-9ԧsS<  37:G}:hn[%j)%5薐C8'VΛ7Z"Ijz>~Ÿ}q; @US]yT޵x3_Lڬ4/3TZ v?!׾<=f\(M$͆Ж6֔W1363`0-WVƮۚ0^=Eq ˜+ ~\m5˒5Y`3USL.'o2:ǔॗՒ-Ɖ?1+X>!B9RHd-MI ], A ⒐Bk0P4l#ㆻvKcK ;M6 <$%ٴĦXyO=G06df'+#.)T{BBW=㰑B,# AqIHq;+鉛tKK/AJYnHq筱ui @5{T8qMرw>rҰ@^llL~.otc1u͖D^N{dУNmİ!u>]^d!xK&=᚞~{n鲩?B<^~.kmDJTkb繎-lGK&,s>I.GA$F; r4TB( e:"XӛM_O_qV0On34'#c9u]V/]?Kb P,{PzT5p^/o¤?;qy#ML\^oa8¬8^\Ɯ_= |bbI-|tOWT̖DS{s؇ U>d^y_4[? ,b)) *`\V1Р&1("CӍ݀PPSS"TdXX2hiYp9J X +;K[491<): \Iz{\sc m}}:c3nx~8|^ގ !I `^ "M퓷` Ry#En;zl~B;fR[Q7(8KJګjkڼZ7z1'_p/)yLPr(XTi&Pj6~2کWs}[MPPƊyb LQzi%߯ E; qdRPasTU!Ғ4լ[cK dEA?y W$Ɖ_L8j衭R7$,R0{ jZ:}kՃL6K`),__P!5! IY XDp UB%%X(-e^'łHHbIO@mg߁& DhHã~ƣ(3+c2GMsbylIibܰǀK4oAgoU؞;L \QcvrD;\3J|erԖdifYRͣ|Y_|%i;@igA <,j塺r XWi8TET;2XW[B;,UbBOl8ZkR+6R&yVRkuދC^C&\]s-$创nrC@ҎBuv) ޫx[ ~+^6熲'$8Jp겯^-͎\nWxٚfur۳49zOMq6,ؽcZ~x{KϒџGBX/ܠ>? 5=}3k1Me 0. jp?B% V@>x7!A(P@:c_H/  qD,xH#÷K$",v(0k(#d7Əx 0  &C8Zz=UpuB(rl# HJґ* ScLq}!; O#%(gR9%^ Xr-k( U)h_" e !W4& e҄b XcD3e7)>jL7Yl3[33<'ʹ곃oTc32 fЄ*tј%$J4F@ Gt$%)tJ|h6TѠcF;*(J`? /J{Qya6hNn8ݚ1:P՜8cM ִ*!ѨMYU΅G"$iQO*q5IVt4q-R  \o dPt St*rL++mvZ(a%+[Z )GTӆT%_S ~'_2&ϒ(^c+TԶzSDܫH>WP%Q ki⽂E*KMYTh?OrB„! ~Z{Agݽݷî:8nXɸ##]3jkv @ NW董 mKܼ09dfESLa^֫q9SךJk8hR ? iwm1ȬS7 'T^{O|H 29K+i <3;݁iaPb|k*K%eX(tk1$!$ t1&1cפQ{ðD ءFY_Q 2p:702bd2`bS&' rῺzY(51nXJu&bɺᰅe\x (W!(Vr&jM_M#ϵ=#Wױ<~-0G5bck 0v6kz-R9"%p-8:]>vsf\.X$"5jX}t=6.tlho-q}nǒIhĻ$VvK a7ؘ#K^i[:ZHW"sn8(4eqK  ;}+&}3wՔoz9&~P>ptuJuo1 ڡ[11{3dQr1x5#{Su6P'4Cf \˄[o7^M(V.E cA}Va77u1v ʗX<{g5Lbf3 )M!!5#_?Lj䈱6!D fm[#] ]Ԉ~`*%:!g{O|#&]fl`.FñcF/y27' w,xJ H,r9; 2 >!0봔JQet{/1u0B+t`RW O붉jRg@m$ {s.r}{(] *r)$89KFE铥˺),Ll;|J!|9 I$,' 2&G*-,., G03\($G?9'i 4 :zѿk[ |2M qwJfW0a.U,L[ya<;; ^íC((k@K|.م<ݠW{[ fL9n䕽5`` < 皅?N.r}ʊszQF/lA"r bi~ɘ2 7\JhwV |mSȊE ,w 02g[A^ںHR *-vϊXL/^+kۂ/uŧ H0TMt ҽĵ6[yk| 0!& &N q'x=,Rm"@Q9u/"&@;J,w= P:Lt4xi R}B^pq0vi L!Mn?/&F+áL !SA^QlF5PJf*0 b h52CJm`QyM< wA鸓ٰp']A -e+QAS>wW bEÁbhOB0!FmP @OlBu:3]ɍRdZVAXK ԅQ|*TKr@_S`>T=g  $Z B @y:yJY%WSnP&zMAX!`h5D69 Su0Eo!LJ|`w2t*B^2tXyQQxe'=# V'Omz"K5ʂ*$8y ۂPafnW`pY!Wb%txvj$'v\B1BgyO@l Av19('Gr `B`3 0 HihӒR O-N6E gԾ~œ%>ohL(m^B2:#ps,9Pvna9D!|aP-8ZQ4 <kX(Xցش;Ƈ:[Y- phs͎6>w #Ȁ-n{{^Te(SN+wKBnY;w^\)u"]m$MI3ӄQXg4띾 GXB0&:~cxAȯU~D$b+)qo RܗxrY*{`_OpNESΟ"|$z^csy!/DJ$X?aBӠF P SVħYd{#.l~Ks8 ^%y2*@~(h:\K0 4-`36؄NPR8TXVh6&19p)06PMWxhjl؆J%5[7 ]BuxqQ Ja 1@jUs}io]G1ʅ:y$eRuAT}@#8T R8XxȘʸH 0`͘ڸ؍ň RFݠ>|P}{08 < O]FzpVM0`M@߄ܓh"(t ,  w`e89(D\$6i4 ]B5dЙP6FÓ:iGD @'*坞Ϣ:IJi0-`(##G@ēQE``)8̊V3HYe㫅UZfz]kH- Axl'/ ڷoAq D'O,QjSU o6b2O1bR8!\jݖ(Hɺ "TM 2x0p&'SI<pW'_D38͐PԵsCOT4xhtF%ƏAZ*ƒ-Cr4$h q!U*́v_wo qnmk@ e 3$|8tw^ Y ^Yޏ٦8 |ꅻ 3yaNqgaF7[bPk~d}+/;PK>PKwD%OEBPS/img/constructor_declaration.gif$BGIF87aO{{{wwwsssqqqYYYUUUSSSMMMKKKEEECCC???===;;;777333111---)))'''%%% ppphhhfffddd```\\\ZZZXXXRRRPPPHHHFFFDDD@@@<<<888666222000...(((&&&$$$"""  ,OA DÙ6[ćD9[D HAA #JHSBC 8?zD(H9.:QHBViJ#H#? "eTPV\ʴӏ$D8AURb( ܊Qprzaj}}ʷ_{bD(oPMd "%yY1^Sz}ӿ (s-dͱ+t5D 50=-̓wK^O&\ ]|VYzdȨOr= #4uQ'bى]] #1`/祗R Kq@߄,qU"JH[g[y(#ul2 e-xb!DLE ̠U; Z@HTUlٚmCi$3Y$9ldD4p؜;p#X%ؐVÜ @j '7L1BTUp'{iehmpgIz>b:Dh!O9T@A X!]` ERp\A MA,P[f^mK΍Ȳ6Ȫ\,"罆ȩ߁@@*-rV8;RH(H"JO\rqD!qla"$i lyk<$o&CPxΓK>_s#5`<7# ˈн\h%U]ūO-v/[/ $j;t_>t Qgu 8`Iy+7PM_;u\I {?ed朷O.)'\" 9?"T7^J>엧3"yLkazХ8Dk21s,J?W2^/-3BcOO ѼMY0\%2{Gss s"*I0 ;P؈%:@CR/)"ӱR`3 ja릔y* NFLP8[J▦/? Bx.<l̑A_C[􊳰q*? :j WHHpLWƂ*AU!ǪT2;jխRR @k@ ! VD9ͱc ,ˣEWHXFሉ롚V?alSX Y}6dJu1lZz- c['[g w ~FG~Ը$1! A[$AI!( vKw 3pv! Le\'3>ViWZmn_jayKnqd Op3{$QY. 44ITx!BapGpU*CuNGI '0B\L8α[|Bh|pHNca@f-CضS `\e &+ nLʌ*(x`mBK*K-fNEglے4Clt)qBͧa[V ;IԂlul Q띰esu$mm'Hw CpHRDn]Գ#)Iŭ7Jk vgj$;5O:5p># .N FKJ:=~GNdG>:nXuEZO9 WDh)1I!hhkNxP@n{CvH|.qA0y{^'% Н R&07~Y1uqx,eOQȧ|=Lh~O[Ͼ{OOOϿ8Xx ؀8Xx؁ "8$X&x(*,؂.&z/Xa s '*6؃@Ls[1|>x?:Q@NgGyOXERJ[(A-蚸SEo++kvGI50MЇmVP.&%.V-<no!rQu:KT4p\ VJJū#rp0q p>Z/ kuR$q#;Kr$!5SCX-7/<*+{/s>96p65[lʵYQo_D%G0VqPk}yZVK Iz( SHf/5V_dVi 7Jxs[xYBK >2.Z%!ȉ`nиx;9) JB (} KQ+6: 0w@6@Dм~H:ʲʰ0{^w4 |ےDC:1@07+9H,p) Lz{z > {Q1 E:m3A=" 0K!X‡%)#P#㒐vٌê!S֡xd0٩c<O|^U :ȧZ8q1$/Ĭ >J) @| |.=Smp k<0 ܠa$?H:x:ul? D Ny#J.%wFbJPqv`{d8B0_w,ٴc -@7d[ $j;$nE¡> JѾ-17p e+ LcXX猀Ly6 qF ˞ ˛\+d[.| ,n.  Gn U,q ;Ll1N ̌Îм< +ۦǝ0m!ܼ*pC,@R[Q< +TS W_yVY0trzkYU? ",CY LƝs "?x@`Ԉ3$C1ys )ř|[Kʼno< D >z E ~|x >2+ćfz8@fi|{n:( dM+;/\`޲@X"X2!Cձ/Z@ ?_@$8HXhxaTysjz +;K[k{ Q*# -=M]m}y .>N^n~Z/?O_ m0 <0… :|1ĉ+Z1ƍ;z2ȑ$K<2ʕ,[| 3̙4kڼ3Ν<{ 4СD=4ҥL:} 5ԩTZ5֭\z 6رd˚=6ڵlۺ} 7ܹt}u"' 8 >\ʃ[:n /" l9͜;{ c~5xO,FE8!;h,Qp|Z-Dd-o<;CUEg=s&d==P ]{\cqϭ>?t7n-oA,3x e1_h 0C_  }"~*#J;a9\ s@2Ҩ'Qxwpj 2ރE渣(>vbF' 'Zbq蝐 wAP1nQc&c&*',P̛e=EL\))e䈐f8`HFYI ʞBi}ApgihP:,+7L1IAmpZk 0\ǞkBIj <-ͨj Xz 0qA-@19.}w'm G~بWļsv0`^Dl8`_@k" )")|iDž*2+[̌qв)09D)bB?- 0Au\:s/^B+'8j+,fdbvAŭhMaC@w/b6V1 Yyv,B  Z[h96b1ѡM 瞿?.3:,H p^6׹7sOK۲OO})Fg-ŷR{4+P|"ϾfrKC>d'")[#{t\?혠/tM6?"H0 CP`Zq#nڕLHAj}.|v v*T tyCDBr:OɢL2yT*$)\(;LAEaK'* 6\O xd Ʊ [A I艟T~ &I@оPr,e F0 `3#)HuBc LM@7H!ʑDc-E 73 hJsԬ5lJ@3 \|,hK} ͡btuuEdCsKIE`xcݰg' P 'V$nPLYm(y!D@*ƒ2uּx& ѥ"?'d+QCyDU*@TJ0jjDU{|MKJ S6H+rTu J4Y׺b4iV Rk 1Ѭ.$Z߃S=%kcQV`ne d ~U_Бw<B  S ؖڐm*2ή"X*v|B+Bl/lk[rDX"g7aW)ý[q`#KXrO`St-Ez?b ^n7)ݵw;n d7b"#Um@P]{# bQ= X"ꄑRZ\7a; e$oďw*k_ι,&а"ɏ3&TE"*+ܩZ.EvIt>#ԳW YO`X^cfU 6WmDT) ]l~V?j>rNtY;B 0;#ݎ|QaE,Bր邶urҝu`vj:Q*Z Йz*/JE, _';9ޛJm d[tLw$M†ܢd1;ȣS@3 PA#bkEP,AM0eY){8YùmfFOf p&Q @E݌1rEž}9rQ2n8W(1K>, X?#3wЅI! y?S-3;$@sā3w 6382܉] 6odNjힾeP0(VPh=s{)vUwn|7$\>vv/C=bETF__`mcD~̗>{kFe,″,}g <}6~pfV\հh}3Zp+ EbWgSGSj7V 0 Ubb%*>XA@m&g~<5X&GzKh8VG` C b0_4Wp,8a3 lQTY؃H]\ ba0tl@CY=3!vАQBaͰנ}Xxx d0p V䅊( @$PuBp>Ih#q>m3T$" Z6FY8xX !x|fc|dEȇh 5__,v<T 7# C f5YE$Whc|!S/E2bX0w  x ZCc;5 p9중v !h6#SB^ff e PS-B/Zs"2h;iA={  k"l3['10p&jBBC=$h' 7'%)Js•~)QB@F: x(ƒEH J#L 7$uATARGJY]lV `G1\ujvpv;PK!$$PKwD"OEBPS/img/function_declaration.gifGIF87a}}}wwwqqq[[[UUUSSSOOOKKK???===;;;777333---))) pppjjjhhhfffddd```XXXRRRPPPHHHDDD@@@888222000...***(((&&&""" ,0 "*ȐϧB&% 6>') B *B> @I -(HB8l&G6ʗ0Y(ˑ&*i <_0+*!CT*>ԫXܤׯ`nE(ֳZ۷pʝKݻxMuM{)fS +8łj 2"ʏC ς<7Ҽs*Ѡ+^D[7plmy>ّmA 0\THݶ)A8 i4թcOԚs &8`|~oC^^|Ifү%acݲ'fVV! $ek-X<`CT'o7F(Eƛalt Ap HR4L0$a1bb+k ['[bZ0Syϙ@ MJ f#GdJ9\47sB xy$ 8\ HfPk U'9ɕv\ԜByx0n}권~έ+{놼λ,v%<&?Ww./t3\=!sϊZ>+REo[ƬJ۔l BOo1^>2O{GK_zPJuHzWHJC,}I V#IE&| `3ZK!tr،VJ 8aT<a?UܰL ?dQ4Oh$av( JW1<}hIAKZ A%۹6x.9֌̳+hjU&],Te*aڒ?bf!7╰<,H3f2Zc"D3=3_1i g^T_1!oB+2R_ųƶwpJ<}tj3&t^%\(hR)(+lr4& aѾH٨*ɀe|h+BZU`8]<"$P@Hx 0?fxTpͻ\ع4 " ^*h$6#%̚(1alcSGЉ*d!xm℩D,*AF|%*ƣ1AWx 椈#2 Sp5l.?:3$Fmy0bm>%@D˪"S}zrlI!bh掄[(zάQ'7}i&~\ڽZ1K.8eQ9[D<NbmBd{ 7%TsL:ږ5-mY7}:\ݱm>~nڼmv( [`_8p=|[Ee:]\Vm7O~|Q!Dgq#ܸ x9~Z8yE>s0Ї|Cz]r>0k|4I4}:V>u4Z/;ԫ󶻝-&;g#)t媉;w3/ݺrĠ iIQ"db /wfi5|HxG!Z|(Cu)uBQ.D)uH #9'29.UY Ղ-w"aٗmUC@lѓ8KQ!OF={Il4e|@JG ڠP-ЖAGkڡg_%&i5' :4XI8:<ڣ>3 $7!>؞!2r.1zv>yb'i ABNk"hgbɜJV"BvtJufzR ŒUQ"2"lub"8(*81 -T騲Pb 6a E{8ْ#92bҚÚ *Vr I)O U!`Yڌ: & 0Qꮈ$ &xVg) rqިZQbz @ nAJɀ CG;!;PKsPKwD#OEBPS/img/conditional_predicate.gifn GIF87ahn}}}wwwsssqqqYYYUUUKKK???;;;777333111)))''' ppphhhfff```XXXPPPHHHDDD@@@222000...***&&&$$$""",hn@pH,Ȥrl:ШtJZجvTxL.4m|Ut~ltE*puPTDCB^$(cBa3(^a*D33I\ƻÿl/ EB:3(::GJṙ:}`ɞÇZ+;pG=qo^tiITI Bٝ]a P ?m#yOK)Q暁b$n, 9@Spi@Bǧι&ʝKݻx+_`kp4_V!VDH!ajm?@Ո'``$B@}H68$BBw Ġ*Y"q<f(:d Y,@ Xي҄uĘO62t'Q ǐPFHVq_\vnVyo)Gنh"9)'pjQxRw'{':)}9(x!aelRhZ |#E|H1Sd5O(PDH`d'GSu"pbET e ;k]$j^ez~1QMܶ$CƨI*[^6mTUY""Q7pL< A-K0,0zGgok?+ DTOp -Q!TC1(B86`<ϰM1ٵ< (`r{Fl<BlufmͶJ=EֆAC0x`7-myv9OQ!!(P{EERY䜄x7@B(x W ,B]P>++ե@dƧOa82?K1YzC<4hHd^ )[_a؛G{ÀFCtg?HК$=@,g:1G^h5 &6ڞJ6B^f;L1Ӗ!W 0N$F!XA?$ {@ *`Bx.z" 4=(CJGzq`y\P}+9@ӂ eSf>ӂq )4h Pxȡ=0H@ @Cl >BRbn!BJ%q0 !%['B!WDD%*CE D INIf1^߮fTEr[:4$c7ȪinQD.uI UUzQQ_n|Q>xם- yBӌs*ssEZlks =AaD|F_M"ͪ4X"lD 5 19!VPjÔ{Nuݪ+֥n L!v(6n=ƔAaBpqE_=Xv*#Zָ2kk% }XhX7.AlAkN ! baAN%̄dXVű)X , .=3K8ĭINkN[`pRVc\ZE S׮T AہIErs.a t )ӁINsk=Zٻ0H@d.c$i( ݻ 8P:,rizD7ugv7t LYI!Gxy*%'å,=C13!XCma oӻ0=GH=q,;P:t$Erɕ,S^?n#xNx_M RpАydjn•GW'aN's-b lMI{R|,_H!ת;ǾMl3>H{ߢ>Gd]{żP3F ҟ>Xe[k?wKKVsg^=j)w؋K !gGvX%A(xy0_yI0A yDžЈ8`(8 iЏ# 9R@q9 ِ H%)~x-;PKӑls n PKwDOEBPS/img/exceptions_clause.gifGIF87al.wwwqqqmmmUUUKKKAAA===;;;777333---''' ppphhhfffddd```XXXPPPHHHDDD@@@<<<888222(((&&&""",l.@pH,Ȥrl:ШtJZجvzT!$znێ f`6 8] j{0xiR'"i*fhY0*0 OD'J"~HtJ'IL **'"KM0\gO`]BZD)\s&wC5!TLd{ ^Ǘ0mBK#$D B˧ @s4rq@|dȘX be N#@ R `P0| WA 0Q &5//!h P!*p =<$S#H{;̺3M;DG*lhm| Z"$VЦ=BzUصFp Y/f-~Kg"ɟ,2pIT$8Ԃ,uY  4[noxmo}@ jQ!'F` "fi"{cxaq!qaM+&AM#&N Z/MO8)4/6Ne-Hn&0@Bql#d!9s|J@ cf6裐F wIj)v&CQ,@KNPj5.0ܑǥ?Q\ɭ뮼zos*,:Jd8lہ"i6uGqFD}Qd* {8ó yf!GNq8 "*ꐇەb[ı) |F*-z%oG1 +L P +ljA ?BBLóL٥3E% GS,Da1DF]煘`vņJjLi*Y<؉q6,s4Gq &IPmU4Yt0$Jc 3^ /L]5iy{cQ8 jEJ_>7'`[C`>AѤGJ35d{"@o5̯Ee,G pKqFo߄CT_ ogDU1!X ="萷&o}|q/ BPJ4!e(Rw28ljȗh5hr7 3ռCa·鈐7; sڇ}@^=@{Dh7]+=L*.''Ӝ0.Lchh<` p@f$'II0, @pF0)\&3F08^H̹&ExXd " RU3 /YW%@`IjZ̦6Mlj%H3[gSpf{ s90 l-6ٴ[^_Ȃ:h7ݘwrJ(:H3J(6Fk 8TA&l螴Ksz\GU a&@B X!^4 \1 4s-Ht\t ` n`~`/ BmrA\3V4i 򠡡Hz0zd"\aVUbei [5 h!ANbR;saIsjZY Z0(cW0iQ!vo^ nqPQg+ N `۶3o z^5ضwPwT%_aI2C|H A;PKPf PKwDOEBPS/img/element_spec.gifYGIF87agwwwqqqiii[[[UUUSSSKKK???;;;333111---))) ppphhhfffddd```\\\ZZZXXXRRRPPPHHHFFFDDD@@@<<<888222000,,,&&&""" ,g0(ƣ(Ӌ݅CC;%CfqB*\ȰÇ#ŋ3F<^BI%JZ)d0c즀+Eoϟ@ipS^"C@ӧ(ρXj$}C(|K!3n󪶭ۧ'L`ݻB ߿1ܤ +^̸ǐ#KU ̹M%8PV7iϝc˞\T`bg w^ీģK]K:`zXïFlI Sw4B~> I." FhRgo8[ 6Mtuț $Ph  ($v!:7cQ xh|@w<(H bd"!^,”Vb aH %[4CUJ4" RP& Wn)avIt0K&)Ҧ^p@QT)HW)[<  y>UC`)d*+ApH]("~5Ê6j#XѴ- ΄j+䖻رpkYւ ˦Bbo<(v={i^+VeZD xs ƚhg$߮f(ʋY&@ P816Rm< 0B2iM:xiMJ &k!E='0(M(iӿDߘJ¼Ơܖرa$-%ƁU9o0ǚ%[Ъzp:y[`_7fՋyzT9烜xҕ'+^Ƙ-ܞ{!l-_X M?*؆( 1*׍ . BG[4 Ucn/ʒC)`_]ZEɳPv^۝R[gO<;I 6(? B 7=d=` '&>,q$0>}p"oLF" aB悎8bJL焠X W"d=| =bMKD}H+ψTZ$Cm` q 4qwoژ%0 %"'p #qHP FCaf#(49K0!Δ@"k0*$%GtHr]x%eqr"NV@$$Z#G2 #햾|7re%R`Ju›Afr~l v$Dc Px P\PyX ЁR(aW0`^!B=8s;FeodH3Uh6=U]As=Ёk1ݏtQ"y.!ͦk׸~׵P/ WQ` Q>`nH x rgkXT.5