(ref) INSTEAD OF triggers

NON-UPDATABLE Views contain any:
  • One or more Table Joins.
  • A GROUP BY clause.
  • START WITH ...CONNECT BY.
  • DISTINCT.
  • Aggregate function (i.e. SUM, AVG, MIN, MAX, COUNT).
  • Set operators.
  • Derived columns (i.e. concatenated, pseudocolumns, etc).

INSTEAD OF triggers

INSTEAD OF triggers are created on
  • (usually) a non-updatable view
  • a nested table column of a non-updatable view

What?
  • INSTEAD OF trigger cannot be conditional.
  • Is the only way to update a view that is not inherently updatable
  • Is always a row-level trigger
  • Can read :OLD and :NEW, but cannot change them.
  • The timing events (BEFORE and AFTER) is not applicable for INSTEAD OF triggers.
  • INSTEAD OF trigger can fire for all three DML statements (I/U/D).
  • Prior to Oracle8.1.6 INSTEAD OF triggers functionality was included in the Enterprise Edition only.

Why use?
  • Used to intercept DML statements and replace them with alternative code.
  • Useful when application does not need (or should not) see the underlying tables (i.e. for security reasons). In this case:
    1. The application issues DMLs against the view
    2. The INSTEAD OF trigger intercepts and rewrite the DMLs to the underlying tables.
  • Useful also when the system uses object-relational functionality.
  • Updates against complex views may result in "ORA-01776-cannot modify more than one base table through a join view" or "ORA-01779-cannot modify a column which maps to a non key-preserved table"
How?
  • The database fires the INSTEAD OF trigger instead of running the triggering DML statement.
  • The trigger should: (a) determine what operation was intended and (b) perform the appropriate DML operations on the underlying tables.
Creation Syntax:
CREATE [OR REPLACE] TRIGGER trigger_name
 INSTEAD OF {dml_statement }
 ON {object_name | database | schema}
 FOR EACH ROW
 [DISABLE]
 [WHEN (logical_expression)]
 [DECLARE]
  declaration_statements;
BEGIN
  execution_statements;
END [trigger_name];
/
In the example below (taken from here) you:

(1) Create the base tables Custormer and Orders.
(2) Create a view order_info.
(3) Create a INSTEAD OF trigger order_info_insert that translates the DML statement into statements acting on the base tables (Orders and Customers).
(4) Insert data on the order_info view. Check the insertion on the base tables.

(1-2) Create base tables Customer, Orders and view.
SQL> CREATE TABLE customers ( 
     customer_id NUMBER (6)  NOT NULL  PRIMARY KEY, 
     cust_first_name VARCHAR2 (20)  NOT NULL , 
     cust_last_name VARCHAR2 (20)  NOT NULL , 
     cust_address VARCHAR2 (200) , 
     phone_numbers VARCHAR2 (12) , 
     nls_language VARCHAR2 (3) , 
     nls_territory VARCHAR2 (30) , 
     credit_limit NUMBER (9,2) , 
     cust_email VARCHAR2 (30) , 
     account_mgr_id NUMBER (6));

Table created.
SQL> CREATE TABLE orders ( 
     order_id NUMBER (12)  NOT NULL Primary key, 
     order_date TIMESTAMP  NOT NULL , 
     order_mode VARCHAR2 (8) , 
     customer_id NUMBER (6)  NOT NULL , 
     order_status NUMBER (2) , 
     order_total NUMBER (8,2) , 
     sales_rep_id NUMBER (6) , 
     promotion_id NUMBER (6));

Table created.
SQL> 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;

View created.
SQL>

Now, if you try to perform an INSERT in the view order_info, it will fail with an ORA-01779 error:

SQL>INSERT INTO order_info 
    values (345, 'Rogers', 'John', 1250, sysdate, 1);

Error: ORA-01779: "cannot modify a column which maps to a non key-preserved table"
*Cause:    An attempt was made to insert or update columns of a join view which
           map to a non-key-preserved table.
*Action:   Modify the underlying base tables directly.


A Key preserved table means that the row from the base table will appear AT MOST ONCE in the output view on that table. Here one customer clearly may have multiple orders, so customer_id will most probably appear multiple times on order_info.

So, if you issue an INSERT against order_info, how can the database decide what to do with it?
Should it insert into orders AND customers? Only into orders? Or only into customers?

Well, you need to write an instead of trigger to intercept the DML against the trigger and issue DMLs against the base table(s) according to your business rules..

In this example, the trigger will split the INSERT coming from the application and insert on each table accordingly:


(3) Create a INSTEAD OF trigger order_info_insert that translates the DML statement into statements acting on the base tables (Orders and Customers).
SQL> 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, order_status)
 VALUES (:new.order_id, :new.order_date, :new.customer_id, :new.order_status);
EXCEPTION
 WHEN duplicate_info THEN
   raise_application_error (
     num=> -20107,
     msg=> 'Duplicate customer or order ID');
END order_info_insert;
/
Trigger created.
SQL>

(4) Insert data on the order_info view. Check the insertion on the base tables.
SQL> INSERT into order_info 
 (Customer_id, cust_last_name, cust_first_name, order_id, order_date, order_status)
VALUES
 (1, 'Smith', 'John', 2500, '13-AUG-09', 0);
1 rows inserted.


SQL> Select Customer_id, cust_last_name, cust_first_name from customers;

CUSTOMER_ID  CUST_FIRST_NAME  CUST_LAST_NAME       
------------ ---------------- ----------------- 
           1 John             Smith 

SQL> Select order_id, order_date, order_status from orders;

ORDER_ID    ORDER_DATE                              ORDER_STATUS
---------- ---------------------------------------- ------------------------
     2500  13-AUG-09 12.00.00.000000 AM             0

SQL>

INSTEAD OF triggers on Nested Table Column of View


Nested Table Column of View (?)

You can create a view that has a nested table as one of its columns.
Now if you want to be able to update such a view, you need a instead of trigger.
It will intercept the object-relational INSERT and translate it to one that inserts into the base table.



(1) To create a view with a nested table as one of its columns you can:

(a) create the object type for the elements of the nested table. In this case, the type nte captures attributes of employees.

CREATE OR REPLACE TYPE nte AUTHID DEFINER IS
 OBJECT (
   emp_id   number(6),
   lastname varchar2(25),
   job      varchar2(10),
   sal      number(8,2));


(b) create the object table type. Here it will define a table of objects of the type nte.

CREATE OR REPLACE TYPE emp_list_ IS TABLE OF nte;

(c) Now you define the view containing the nested table in one of its columns (emplist).

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, i.salary
                  FROM employees e
                  WHERE e.department_id = d.department_id) 
                  AS emp_list_
                 ) emplist
  FROM departments d; 

(d) You can select the contents of emplist, and compare with a direct select of the base table:

SQL> select emplist from dept_view where department_id=10;

EMPLIST(EMP_ID, LASTNAME, JOB, SAL)
-----------------------------------------------
EMP_LIST_(NTE(200, 'Whalen', 'AD_ASST', 4400)


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

EMPLOYEE_ID LAST_NAME		      JOB_ID	     SALARY
----------- ------------------------- ---------- ----------
200 Whalen		      AD_ASST	       4400

(e) Now, if you try to insert directly into the dept_view, you'll receive an ORA-25015.

SQL> INSERT into table (
                        select d.emplist
                        from dept_view d
                        where department_id = 10
     ) 
     VALUES (1001, 'Glenn', 'AC_MGR', 10000);

SQL Error: ORA-25015: cannot perform DML on this nested table view column
*Cause:    DML cannot be performed on a nested table view column except through
an INSTEAD OF trigger
*Action:   Create an INSTEAD OF trigger over the nested table view column
and then perform the DML.

(f) So you need an INSTEAD OF 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
  -- Intercept the insert into the nested table.
  -- Translate it to an insert into the base table.
  INSERT INTO employees (
              employee_id, last_name, email, hire_date, job_id, salary, department_id)
  VALUES (
     :Employee.emp_id,
     :Employee.lastname,
     :Employee..lastname || '@company.com', 
     SYSDATE,
     :Employee.job,
     :Employee.sal,
     :Department.department_id);
END;


(g) Now you if repeat the insert statement, the trigger will fire and perform the insert in the base table employees:

SQL> INSERT into table (
                        select d.emplist
                        from dept_view d
                        where department_id = 10
     ) 
     VALUES (1001, 'Glenn', 'AC_MGR', 10000);

1 rows inserted.

(h) You can check the results by querying the dept_view view and employees table:

SQL> select emplist from dept_view where department_id = 10;

EMPLIST(EMP_ID, LASTNAME, JOB, SAL)
--------------------------------------------------------------------------------
EMP_LIST_(NTE(200, 'Whalen', 'AD_ASST', 4400), NTE(1001, 'Glenn', 'AC_MGR', 10000))


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

EMPLOYEE_ID LAST_NAME		      JOB_ID	     SALARY
----------- ------------------------- ---------- ----------
	200 Whalen		      AD_ASST	       4400
       1001 Glenn		      AC_MGR	      10000

2 rows selected.



(ref) Trigger on Object Table

You can create triggers on object tables. In this case, the trigger can reference the pseudocolumn OBJECT_VALUE.
In the example below you:

(1) Create an OBJECT_TYPE to define a table.
(2) Create an OBJECT TABLE obj_employee
(3) Insert data on obj_employee
(4) Create a table emp_hist for logging updates to obj_employee
(5) Create a trigger emp_obj_trg.
  • The trigger will execute for each row of obj_employee affected by a DML statement.
  • The old and new values of the object emp in obj_employee will be written in emp_history.
  • The old and new values are :OLD.OBJECT_VALUE and :NEW.OBJECT_VALUE


(1-3) Create OBJECT_TYPE, OBJECT TABLE and Insert data.

SQL> CREATE or REPLACE TYPE EmployeeType AS OBJECT (
  Id             number,
  first_name     varchar2(15),
  last_name      varchar2(15),
  hire_date      date,
  salary         number(8,2)
  );

Type created.
SQL> CREATE TABLE obj_employee OF EmployeeType;

Table created.
SQL> INSERT INTO obj_employee VALUES (
    EmployeeType(1, 'John', 'Martic', '02-AUG-03', 95000))
1 row created.

SQL> INSERT INTO obj_employee VALUES (
    EmployeeType(2, 'Mary', 'Kempft', '02-JUL-99', 98000)))
1 row created.

SQL> INSERT INTO obj_employee VALUES (
    EmployeeType(3, 'Greg', 'Bloom', '02-AUG-09', 55000))
1 row created.

SQL> commit;
Commit complete.

SQL> select * from obj_employee;

    ID FIRST_NAME      LAST_NAME       HIRE_DATE    SALARY
------ --------------- --------------- ------------ ----------
     1 John            Martic          02-AUG-03         95000
     2 Mary            Kempft          02-JUL-99         98000
     3 Greg            Bloom           02-AUG-09         55000



(4) Create history table emp_hist:
SQL> CREATE TABLE emp_hist 
  (dt          date,
   username    varchar2(20),
   old_obj_emp EmployeeType,
   new_obj_emp EmployeeType);

table created.
SQL>

Compare emp_hist and obj_employee:

  • obj_employee is an object table. Each of its rows is an object of the type EmployeeType
  • emp_hist is a traditional table. Two of its columns are objects of the type EmployeeType
(?) How is the translation/mapping OO-Relational done?
SQL> desc obj_employee
 Name               Null?  Type
 ------------------ ------ ------------------
 ID                         NUMBER
 FIRST_NAME                 VARCHAR2(15)
 LAST_NAME                  VARCHAR2(15)
 HIRE_DATE                  DATE
 SALARY                     NUMBER(8,2)

SQL> desc emp_hist
 Name               Null?  Type
 ------------------ ------ ------------------
 DT                        DATE
 USERNAME                  VARCHAR2(20)
 OLD_OBJ_EMP               EMPLOYEETYPE
 NEW_OBJ_EMP               EMPLOYEETYPE


(5) Create a trigger emp_obj_trg.
  • The trigger will execute for each row of obj_employee affected by a DML statement.
  • The old and new values of the object emp in obj_employee will be written in emp_history.
  • The old and new values are :OLD.OBJECT_VALUE and :NEW.OBJECT_VALUE

SQL> CREATE OR REPLACE TRIGGER emp_obj_trg
 AFTER UPDATE on obj_employee
 FOR EACH ROW
BEGIN
 DBMS_OUTPUT.PUT_LINE('Logging Update');
 INSERT INTO emp_hist (dt, username, old_obj_emp, new_obj_emp)
 VALUES (sysdate, user, :OLD.OBJECT_VALUE, :NEW.OBJECT_VALUE);
END emp_obj_trg;

Trigger created.
SQL> 

SQL> set serveroutput on 
SQL> update obj_employee set salary=salary*1.10 where id=1;
Logging Update

1 row updated.

SQL> update obj_employee set salary=salary*.98;
Logging Update
Logging Update
Logging Update

3 rows updated.


(6) Check the audit table (using implicit cursor):

SQL> set serveroutput on
SQL> BEGIN
 for j in (select * from emp_hist) loop
  dbms_output.put_line (
   'Date: ' || j.dt ||'-- User '|| j.username);
   DBMS_OUTPUT.PUT_LINE(
   '(old rec)-- ID:'|| j.old_obj_emp.id || '-- OLD SALARY: '|| j.old_obj_emp.salary);
  DBMS_OUTPUT.PUT_LINE(
   '(new rec)-- ID:'|| j.new_obj_emp.id || '-- NEW SALARY: '|| j.new_obj_emp.salary);
 end loop;
end;
/

Date: 22-AUG-11-- User FHAT
(old rec)-- ID:1-- OLD SALARY: 95000
(new rec)-- ID:1-- NEW SALARY: 104500
Date: 22-AUG-11-- User FHAT
(old rec)-- ID:1-- OLD SALARY: 104500
(new rec)-- ID:1-- NEW SALARY: 102410
Date: 22-AUG-11-- User FHAT
(old rec)-- ID:2-- OLD SALARY: 98000
(new rec)-- ID:2-- NEW SALARY: 96040
Date: 22-AUG-11-- User FHAT
(old rec)-- ID:3-- OLD SALARY: 55000
(new rec)-- ID:3-- NEW SALARY: 53900

PL/SQL procedure successfully completed.
SQL>








(17) On Triggers



Introduction
  • Named PL/SQL unit. Can be enabled or disabled, but cannot be explicitly invoked.
  • Trigger is created on or defined on the item (to which it will be "attached"): table, view, schema or database.
  • Firing criteria is based on a triggering event (DML, DDL, System) and on a timing specification (before, after, instead of). A conditional clause (WHEN) may also be used to further specify the triggering rules.
  • Triggers do not accept arguments.
  • Triggers can be written in PL/SQL or JAVA.
  • Starting on Oracle 11g, triggers can now be created in the disabled state.

Triggers: what for?
Customization of database management; centralization of some business or validation rules; logging and audit.
  • Overcome the mutating-table error.
  • Maintain referential integrity between parent and child.
  • Generate calculated column values
  • Log events (connections, user actions, table updates, etc)
  • 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
  • Enforce complex security authorizations: (i.e. 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
  • Control the behavior of DDL statements, as by altering, creating, or renaming objects
  • when they change data in a view>
  • Audit information of system access and behavior by creating transparent logs
(but, however, nonetheless, take heed:),
  • if the trigger code turns out to be very(?) long, you will more likely have better performance using a stored procedure instead. In fact, a trigger cannot be larger than 32Kb (because stored on LONG column). If you need to write something longer, use a stored procedure instead.
  • You can’t control the sequence of or synchronize calls to triggers, and this can present problems if you rely too heavily on triggers
  • A trigger can call a SQL statement that in turn fires another trigger: The number of cascading triggers is limited to 32, after which an exception is thrown. (11g and earlier)

Triggers: How much is too much?
  • DML statements on tables with DML Triggers are likely to have decreased perform.
  • You may choose to disable triggers before loading data. Of course the cost to this is the work you'll have to perform latter what the disabled triggers did not do.
  • If the task is complex, you may spread it across multiple triggers. However, this will make it maintenance more difficult, since it is likely to make the entire process harder to follow later.
  • Triggers may get disabled by accident: For example, DDLs on objects touched by a trigger may render it unusable. If you don't catch this, you may end up with missing/corrupt data.


Five types of Triggers
DDL Triggers
  • On CREATE, ALTER, DROP
  • Useful to control or monitor DDL statements.
  • An instead-of create table trigger allow for:
    • Ensuring that table creation meets development standards (i.e. proper storage or partitioning clauses.
    • Monitor poor programming practices (i.e. programs create and drop temporary tables rather than use Oracle collections. Temporary tables can fragmentdisk space and degrade database performance over time.
DML Triggers
  • Statement-level or row-level
  • Audit, check, save, and replace values before they are changed.
  • Automatic numbering of numeric primary keys (through row-level trigger).
Compound Triggers
  • Act as statement- and row-level triggers.
  • Lets you capture information at four timing points:
    (a) before the firing statement;
    (b) before each row change from the firing statement;
    (c) after each row change from the firing statement; and
    (d) after the firing statement.
  • Audit, check, save, and replace values before they are changed when you need to take action at both the statement and row event levels.
Instead-of Triggers
  • Enable you to stop performance of a DML statement and redirect the DML statement.
  • Often used to manage how you write to non-updatable views: They apply business rules and directly insert,update, or delete rows in tables that define updatable views.
  • Alternatively, they insert, update, or delete rows in tables unrelated to the view.
System Database event Triggers
  • Fire when a system activity occurs in the database (i.e. logon and logoff).
  • Useful for auditing information of system access. (You can track system events and map them to users).


Constraints
  • Apply to OLD and NEW data.
  • Easier to write and less error-prone.
Triggers
  • Apply only to NEW data.
  • Can enforce complex business rules.
  • Enforce ref integrity on distributed databases.


Using DML triggers

Using Compound triggers (11g only)

Using triggers on object tables
You can create triggers on object tables. In this case, the trigger can reference the pseudocolumn OBJECT_VALUE. Check an example here.

Using INSTEAD OF triggers

INSTEAD OF triggers are created on views. This allow DML statements to be issued against non-updatable views. Check an example here.

Privileges required to use Triggers

- CREATE TRIGGER: For your own objects.
- CREATE ANY TRIGGER + ALTER ANY TABLE.
- EXECUTE:to fire triggers on other schemas

Trigger Design Guidelines
  • 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.
  • 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.
  • 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. 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.
  • Use DATABASE triggers judiciously. They fire every time any database user initiates a triggering event.
  • Only committed triggers fire. A trigger is committed, implicitly, after the CREATE TRIGGER statement that creates it succeeds.

Trigger Restrictions
  • Maximum Trigger Size
    • Max 32Kb. If needed, you can move code into functions, procedures or packages. In this case, the code could also be reused. stored modules can also be wrapped.
    • 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
  • DCL and DDL Restrictions
    • Only an autonomous trigger can run TCL or DDL statements
    • Nonsystem trigger bodies can’t contain DDL statements. They also can’t contain Transaction Control Language (TCL) commands, like ROLLBACK, SAVEPOINT,or COMMIT.
    • A trigger cannot invoke a subprogram that runs transaction control statements, because the subprogram runs in the context of the trigger body.
    • If you declare a trigger as autonomous, nonsystem trigger bodies can contain Data Control Language commands because they don’t alter the transaction scope.
    • To enable a trigger to work outside the scope of a triggering statement you use include in its DECLARE block: PRAGMA AUTONOMOUS_TRANSACTION;
    • A larger problem with SQL statements exists with remote transactions. If you call a remote
      schema-level function or procedure from a trigger body, it is possible that you may encounter a
      timestamp or signature mismatch. A mismatch invalidates the trigger and causes the triggering
      SQL statement to fail.
  • LONG and LONG RAW Datatypes
    • The LONG and LONG RAW datatypes are legacy components. Migrate out of them.
    • A trigger cannot declare a variable of the LONG or LONG RAW data type.
    • You may, however, insert into a LONG or LONG RAW column when the value can be converted CHAR or VARCHAR2.
    • Row-level triggers cannot use a :new,:old or parent with a LONG or LONG RAW column.
  • Triggers will fail if try to access a mutating table.
  • Oracle 11g has relaxed some mutating table restrictions

Triggers and data transfers
These utilities may fire triggers:
SQL*LOoader (sqlldr), Data Pump Import (impdp) and Original import (imp)
SQL*Loader (sqlldr):
- During a SQL*Loader conventional load, INSERT triggers fire.
- Before a SQL*Loader direct load, triggers are disabled.
Data Pump Import (impdp):
- 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.
Original Import (imp):
- 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:
- 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.