Archive for November, 2018
Logging Triggers
Oracle Logging Trigger Results
This article demonstrates how you can write log files from triggers on different tables to the same logging table. This approach leverages Oracle’s object types and column substitutability features. It also eliminates the requirement to create a unique logging table for each logging trigger. The trick to accomplishing this requires mastering two skills.
The first skill requires you to learn how to create user-defined types (UDTs) and subtypes. The UDT stores the elements common to all logging data, and the UDT subtype stores the unique column values of individual tables. The second skill requires you to learn how to create a logging table that uses a base UDT as a column type, and to learn how to insert new data into and query subtype data from a UDT subtype.
You will learn both skills in this article. If you’re new to database triggers and Oracle’s object types, I’d recommend you check out my earlier “Critical and Non-critical Triggers” and “Object Types and Column Substitutability” articles.
The article works through the steps in four parts. You create:
- Five tables and sequences, and one UDT base type and two subtypes that map to the specific tables
- A reusable autonomous stored procedure
- Two data manipulation language (DML) triggers
- A test case with standalone PL/SQL blocks that query the data
This article uses small headers to organize the parts. After creating and testing the parts, there are some observations and suggestions at the end of the article.
Creating Tables, Sequences, and Types
You create five tables because of foreign key dependencies. The application_user table supports the use of who-audit columns. Who-audit columns document the user who creates and last updates every row of data. Who-audit columns must link to an access control list (ACL), which are typically a list of user names and their encrypted password keys.
The following creates the ACL table and sequence:
SQL> CREATE TABLE application_user 2 ( application_user_id NUMBER CONSTRAINT app_user_pk PRIMARY KEY 3 , application_user_name VARCHAR2(30) CONSTRAINT app_user_nn1 NOT NULL 4 , created_by NUMBER CONSTRAINT app_user_nn2 NOT NULL 5 , creation_date DATE CONSTRAINT app_user_nn3 NOT NULL 6 , last_updated_by NUMBER CONSTRAINT app_user_nn4 NOT NULL 7 , last_update_date DATE CONSTRAINT app_user_nn5 NOT NULL 8 , CONSTRAINT app_user_fk1 FOREIGN KEY(created_by) 9 REFERENCES application_user(app_user_id) 10 , CONSTRAINT app_user_fk2 FOREIGN KEY(last_updated_by) 11 REFERENCES application_user(app_user_id)); SQL> CREATE SEQUENCE application_user_seq; |
After you create the application_user
table and application_user_seq
sequence, you need to insert one row. The row let’s you validate the created_by
and last_updated_by
who-audit columns.
The following creates the mpaa
table and mpaa_seq
sequence:
SQL> CREATE TABLE mpaa 2 ( mpaa_id NUMBER CONSTRAINT mpaa_pk PRIMARY KEY 3 , rating_code VARCHAR2(5) CONSTRAINT mpaa_nn1 NOT NULL 4 , rating_name VARCHAR2(30) CONSTRAINT mpaa_nn2 NOT NULL 5 , rating_desc VARCHAR2(180) CONSTRAINT mpaa_nn3 NOT NULL 6 , created_by NUMBER CONSTRAINT mpaa_nn4 NOT NULL 7 , creation_date DATE CONSTRAINT mpaa_nn5 NOT NULL 8 , last_updated_by NUMBER CONSTRAINT mpaa_nn6 NOT NULL 9 , last_update_date DATE CONSTRAINT mpaa_nn7 NOT NULL 10 , CONSTRAINT mpaa_fk1 FOREIGN KEY(created_by) 11 REFERENCES application_user(application_user_id) 12 , CONSTRAINT mpaa_fk2 FOREIGN KEY(last_updated_by) 13 REFERENCES application_user(application_user_id)); SQL> CREATE SEQUENCE mpaa_seq; |
The mpaa
table supports film
ratings for the film
table. The film
table’s mpaa_id
column holds foreign key values that reference the mpaa
table. The film
and employee
tables are the principle testing tables for the stored procedure, triggers, and trigger event logging.
The following creates the film
table and film_seq
sequence:
SQL> CREATE TABLE film 2 ( film_id NUMBER CONSTRAINT film_pk PRIMARY KEY 3 , film_name VARCHAR2(40) CONSTRAINT film_nn1 NOT NULL 4 , release_date DATE CONSTRAINT film_nn2 NOT NULL 5 , mpaa_id NUMBER CONSTRAINT film_nn3 NOT NULL 6 , created_by NUMBER CONSTRAINT film_nn4 NOT NULL 7 , creation_date DATE CONSTRAINT film_nn5 NOT NULL 8 , last_updated_by NUMBER CONSTRAINT film_nn6 NOT NULL 9 , last_update_date DATE CONSTRAINT film_nn7 NOT NULL 10 , CONSTRAINT film_fk1 FOREIGN KEY(created_by) 11 REFERENCES application_user(application_user_id) 12 , CONSTRAINT film_fk2 FOREIGN KEY(last_updated_by) 13 REFERENCES application_user(application_user_id) 14 , CONSTRAINT film_fk3 FOREIGN KEY (mpaa_id) 15 REFERENCES mpaa (mpaa_id)); SQL> CREATE SEQUENCE film_seq; |
The following creates the employee
table and employee_seq
sequence:
SQL> CREATE TABLE employee 2 ( employee_id NUMBER 3 , employee_number VARCHAR2(10) 4 , first_name VARCHAR2(20) CONSTRAINT employee_nn1 NOT NULL 5 , middle_name VARCHAR2(20) 6 , last_name VARCHAR2(20) CONSTRAINT employee_nn2 NOT NULL 7 , created_by NUMBER CONSTRAINT employee_nn3 NOT NULL 8 , creation_date DATE CONSTRAINT employee_nn5 NOT NULL 9 , last_updated_by NUMBER CONSTRAINT employee_nn6 NOT NULL 10 , last_update_date DATE CONSTRAINT employee_nn7 NOT NULL 11 , CONSTRAINT employee_pk PRIMARY KEY (employee_id) 12 , CONSTRAINT employee_fk1 FOREIGN KEY (created_by) 13 REFERENCES application_user (application_user_id) 14 , CONSTRAINT employee_fk2 FOREIGN KEY (last_updated_by) 15 REFERENCES application_user (application_user_id)); SQL> DROP SEQUENCE employee_seq; |
You should populate some data in the application_user
, mpaa
, film
, and employee
tables. This testing ensures the interdependencies work.
Before you create the trigger_log
table, you need to create three UDTs. The base_t
object type requires you create a base_t
object type and implement a base_t
object body.
The following creates the base_t
object type:
SQL> CREATE OR REPLACE 2 TYPE base_t IS OBJECT 3 ( oname VARCHAR2(30) 4 , CONSTRUCTOR FUNCTION base_t 5 RETURN SELF AS RESULT 6 , MEMBER FUNCTION get_oname RETURN VARCHAR2 7 , MEMBER PROCEDURE set_oname (oname VARCHAR2) 8 , MEMBER FUNCTION to_string RETURN VARCHAR2) 9 INSTANTIABLE NOT FINAL; 10 / |
The following creates the base_t
object body:
SQL> CREATE OR REPLACE 2 TYPE BODY base_t IS 3 /* A default constructor w/o formal parameters. */ 4 CONSTRUCTOR FUNCTION base_t 5 RETURN SELF AS RESULT IS 6 BEGIN 7 self.oname := 'BASE_T'; 8 RETURN; 9 END; 10 /* An accessor, or getter, method. */ 11 MEMBER FUNCTION get_oname RETURN VARCHAR2 IS 12 BEGIN 13 RETURN self.oname; 14 END get_oname; 15 /* A mutator, or setter, method. */ 16 MEMBER PROCEDURE set_oname 17 ( oname VARCHAR2 ) IS 18 BEGIN 19 self.oname := oname; 20 END set_oname; 21 /* A to_string conversion method. */ 22 MEMBER FUNCTION to_string RETURN VARCHAR2 IS 23 BEGIN 24 RETURN self.oname; 25 END to_string; 26 END; 27 / |
Lines 4 through 9 implements a no-argument constructor that automatically assigns a literal value to the oname
field on line 7. This type of constructor lets you create an instance of the base_t
object type without providing an oname
. Lines 11 through 14 implements a getter for the oname
field, and lines 16 through 20 implements a setter for the oname
field.
Lines 22 through 26 implements a to_string
function that prints the oname
field value. The to_string
function also provides a convenient way to test the object type of object instance stored in tables, as you will see later in this article.
You can now create the UDT subtypes for the employee
and film
tables. The base_t
name represents the base type or a super type. The subtypes for the employee
and film
tables use the more conventional _obj
suffix.
The following creates the employee_obj
UDT subtype:
SQL> CREATE OR REPLACE 2 TYPE employee_obj UNDER base_t 3 ( employee_id NUMBER 4 , employee_number VARCHAR2(10) 5 , first_name VARCHAR2(20) 6 , middle_name VARCHAR2(20) 7 , last_name VARCHAR2(20) 8 , created_by NUMBER 9 , creation_date DATE 10 , last_updated_by NUMBER 11 , last_update_date DATE); 12 / |
The following creates the film_obj
UDT subtype:
SQL> CREATE OR REPLACE 2 TYPE film_obj UNDER base_t 3 ( film_id NUMBER 4 , film_name VARCHAR2(40) 5 , release_date DATE 6 , mpaa_id NUMBER 7 , created_by NUMBER 8 , creation_date DATE 9 , last_updated_by NUMBER 10 , last_update_date DATE); 11 / |
After creating the base_t
UDT and the employee_obj
and film_obj
subtypes, you can create the trigger_log
table. The following creates the trigger_log
table and trigger_log_s
sequence:
SQL> CREATE TABLE trigger_log 2 ( trigger_log_id NUMBER 3 , table_name VARCHAR2(30) 4 , trigger_event VARCHAR2(6) 5 , transaction_status VARCHAR2(9) 6 , old_instance BASE_T 7 , new_instance BASE_T ); |
The surrogate key for the table is the trigger_log_id
column. The composite key of the table_name
, trigger_event
, and transaction_status columns define the natural key for table. The old_instance and new_instance columns hold respectively the values for any table before and after the DML event.
Autonomous Procedure
You have a 32,000-byte limit on the size of database triggers. Also, you have a limit on the scope of database triggers. A database trigger must run in the same context as the DML event, which means a trigger can’t write a log file when it raises an exception. You can write a log file when the trigger raises an exception by calling a procedure that runs as an anonymous transaction.
The following implements anonymous-transaction procedure:
SQL> CREATE OR REPLACE 2 PROCEDURE log_trigger_result 3 ( pv_table_name VARCHAR2 4 , pv_trigger_event VARCHAR2 5 , pv_transaction_status VARCHAR2 6 , pv_old_instance BASE_T 7 , pv_new_instance BASE_T ) IS 8 9 /* Set precompiler directive to run in a separate context. */ 10 PRAGMA AUTONOMOUS_TRANSACTION; 11 BEGIN 12 /* Write to the log table. */ 13 INSERT INTO trigger_log 14 ( trigger_log_id 15 , table_name 16 , trigger_event 17 , transaction_status 18 , old_instance 19 , new_instance ) 20 VALUES 21 ( trigger_log_s.NEXTVAL 22 , pv_table_name 23 , pv_trigger_event 24 , pv_transaction_status 25 , pv_old_instance 26 , pv_new_instance ); 27 28 /* Commit the autonmous transaction. */ 29 COMMIT; 30 END log_trigger_result; 31 / |
Lines 6 and 7 uses a base_t UDT as a parameter type, which means it accepts a base_t
type or any subtype. Line 10 set a pre-compiler directive that enables the log_trigger_result
procedure to run in an independent thread of execution.
Autonomous Procedure
The INSERT
statement designates two base_t
columns on lines 18 and 19, and then it passes the two base_t
parameters in the VALUES
clause. Line 29 commits the record into the trigger_log
table.
The following implements an INSERT
or UPDATE
event trigger on the employee table:
SQL> CREATE OR REPLACE TRIGGER employee_t1 2 BEFORE INSERT OR UPDATE OF last_name ON employee 3 FOR EACH ROW 4 WHEN (REGEXP_LIKE(NEW.last_name,' ')) 5 DECLARE 6 /* DML event label. */ 7 lv_employee_event VARCHAR2(6); 8 lv_transaction_status VARCHAR2(9) := 'REJECTED'; 9 10 /* Declare exception. */ 11 e EXCEPTION; 12 PRAGMA EXCEPTION_INIT(e,-20001); 13 BEGIN 14 /* Check for an event and assign event value. */ 15 IF INSERTING THEN 16 /* Check for a empty image_id primary key column value, 17 and assign the next sequence value when it is missing. */ 18 IF :NEW.employee_id IS NULL THEN 19 SELECT employee_seq.NEXTVAL 20 INTO :NEW.employee_id 21 FROM dual; 22 END IF; 23 :NEW.last_name := REGEXP_REPLACE(:NEW.last_name,' ','-',1,1); 24 lv_transaction_status := 'PROCESSED'; 25 lv_employee_event := 'INSERT'; 26 ELSE 27 lv_employee_event := 'UPDATE'; 28 END IF; 29 30 /* Log the details captured by an insert or update. */ 31 log_trigger_result 32 ( pv_table_name => 'EMPLOYEE' 33 , pv_trigger_event => lv_employee_event 34 , pv_transaction_status => lv_transaction_status 35 , pv_new_instance => 36 employee_obj( 37 oname => 'EMPLOYEE_OBJ' 38 , employee_id => :old.employee_id 39 , employee_number => :old.employee_number 40 , first_name => :old.first_name 41 , middle_name => :old.middle_name 42 , last_name => :old.last_name 43 , created_by => :old.created_by 44 , creation_date => :old.creation_date 45 , last_updated_by => :old.last_updated_by 46 , last_update_date => :old.last_update_date ) 47 , pv_old_instance => 48 employee_obj( 49 oname => 'EMPLOYEE_OBJ' 50 , employee_id => :NEW.employee_id 51 , employee_number => :NEW.employee_number 52 , first_name => :NEW.first_name 53 , middle_name => :NEW.middle_name 54 , last_name => :NEW.last_name 55 , created_by => :NEW.created_by 56 , creation_date => :NEW.creation_date 57 , last_updated_by => :NEW.last_updated_by 58 , last_update_date => :NEW.last_update_date )); 59 60 /* Throw exception. */ 61 IF UPDATING THEN 62 RAISE_APPLICATION_ERROR(-20001 63 ,'No two-part last names without a hyphen.'); 64 END IF; 65 66 EXCEPTION 67 /* Capture an exception. */ 68 WHEN e THEN 69 ROLLBACK; 70 dbms_output.put_line('[Trigger Event: '||lv_employee_event||']'); 71 dbms_output.put_line(SQLERRM); 72 WHEN OTHERS THEN 73 dbms_output.put_line(SQLERRM); 74 END; 75 / |
Line 8 sets the lv_transaction_status
to REJECTED
by default. Line 15 checks for an INSERT
statement as the triggering event. It sets the lv_transaction_status
to PROCESSED
and sets the lv_employee_event
to INSERT
on lines 24 and 25. An UPDATE
statement sets the lv_employee_event
variable to UPDATE
on line 27.
Lines 35 through 46 create an instance of the employee_obj
as the old part of the INSERT
statement. It should always be a null value for an INSERT
statement. Lines 47 through 58 create an instance of the employee_obj
as the new part of the INSERT
statement.
The following implements an INSERT
or UPDATE
event trigger on the film table:
SQL> CREATE OR REPLACE TRIGGER film_t1 2 BEFORE INSERT OR UPDATE OF film_name ON film 3 FOR EACH ROW 4 DECLARE 5 /* DML event label. */ 6 lv_trigger_event VARCHAR2(6); 7 lv_transaction_status VARCHAR2(9) := 'REJECTED'; 8 9 /* Declare exception. */ 10 e EXCEPTION; 11 PRAGMA EXCEPTION_INIT(e,-20001); 12 BEGIN 13 /* Check for an event and assign event value. */ 14 IF INSERTING THEN 15 /* Check for a empty image_id primary key column value, 16 and assign the next sequence value when it is missing. */ 17 IF :NEW.film_id IS NULL THEN 18 SELECT film_seq.NEXTVAL 19 INTO :NEW.film_id 20 FROM dual; 21 END IF; 22 lv_trigger_event := 'INSERT'; 23 lv_transaction_status := 'PROCESSED'; 24 ELSIF UPDATING THEN 25 lv_trigger_event := 'UPDATE'; 26 END IF; 27 28 /* Log the details captured by an insert or update. */ 29 log_trigger_result 30 ( pv_table_name => 'FILM' 31 , pv_trigger_event => lv_trigger_event 32 , pv_transaction_status => lv_transaction_status 33 , pv_new_instance => 34 film_obj( 35 oname => 'FILM_OBJ' 36 , film_id => :old.film_id 37 , film_name => :old.film_name 38 , release_date => :old.release_date 39 , mpaa_id => :old.mpaa_id 40 , created_by => :old.created_by 41 , creation_date => :old.creation_date 42 , last_updated_by => :old.last_updated_by 43 , last_update_date => :old.last_update_date ) 44 , pv_old_instance => 45 film_obj( 46 oname => 'FILM_OBJ' 47 , film_id => :NEW.film_id 48 , film_name => :NEW.film_name 49 , release_date => :NEW.release_date 50 , mpaa_id => :NEW.mpaa_id 51 , created_by => :NEW.created_by 52 , creation_date => :NEW.creation_date 53 , last_updated_by => :NEW.last_updated_by 54 , last_update_date => :NEW.last_update_date )); 55 56 /* Throw exception. */ 57 IF UPDATING THEN 58 RAISE_APPLICATION_ERROR(-20001,'Film names not updateable.'); 59 END IF; 60 61 EXCEPTION 62 /* Capture an exception. */ 63 WHEN e THEN 64 ROLLBACK; 65 dbms_output.put_line('[Trigger Event: '||lv_trigger_event||']'); 66 dbms_output.put_line(SQLERRM); 67 WHEN OTHERS THEN 68 dbms_output.put_line(SQLERRM); 69 END; 70 / |
The film_t1
trigger does much the same thing as the employee_t1
trigger. The difference occurs in the INSERT
statement. The film_t1
trigger constructs an old and new film_obj
instances to the autonomous procedure.
You use INSERT
and UPDATE
statements as test cases for the complete model. The INSERT
statement would look like the following:
SQL> INSERT INTO employee 2 ( employee_id 3 , employee_number 4 , first_name 5 , last_name 6 , created_by 7 , creation_date 8 , last_updated_by 9 , last_update_date ) 10 VALUES 11 ( employee_seq.NEXTVAL 12 ,'B98765-678' 13 ,'Catherine' 14 ,'Zeta Jones' 15 , 1 16 , TRUNC(SYSDATE) 17 , 1 18 , TRUNC(SYSDATE)); |
The INSERT
statements should complete without error, but the UPDATE
statement should raise an error. You can use the following UPDATE
statement:
SQL> UPDATE employee 2 SET employee_number = 'B98765-678' 3 , first_name = 'Catherine' 4 , last_name = 'Zeta Jones' 5 , created_by = 1 6 , creation_date = TRUNC(SYSDATE) 7 , last_updated_by = 1 8 , last_update_date = TRUNC(SYSDATE) 9 WHERE first_name = 'Catherine' 10 AND middle_name IS NULL 11 AND last_name = 'Zeta-Jones'; |
It throws the following exception:
UPDATE employee * ERROR at line 1: ORA-04092: cannot ROLLBACK in a trigger ORA-06512: at "STUDENT.EMPLOYEE_T1", line 64 ORA-20001: No two-part last names without a hyphen. ORA-04088: error during execution of trigger 'STUDENT.EMPLOYEE_T1' |
An INSERT
statement lets you test the film table, and UPDATE
statement lets you test the film table. The film_t
allows the INSERT
statement but raises an exception with an UPDATE
statement.
Query Data with Standalone PL/SQL
You have the ability to query the results with PL/SQL. The following anonymous block lets you print the results of the trigger architecture for employee_obj
records.
SQL> DECLARE 2 /* Declare a cursor with subcursors. */ 3 CURSOR c IS 4 SELECT trigger_log_id 5 , table_name 6 , trigger_event 7 , transaction_status 8 , TREAT(new_instance AS employee_obj) 9 , TREAT(old_instance AS employee_obj) 10 FROM trigger_log 11 WHERE table_name = 'EMPLOYEE'; 12 13 /* Declare scalar variables. */ 14 lv_trigger_log_id NUMBER; 15 lv_table_name VARCHAR2(30); 16 lv_trigger_event VARCHAR2(6); 17 lv_transaction_status VARCHAR2(9); 18 19 /* Declare UDT variables. */ 20 lv_old_record EMPLOYEE_OBJ; 21 lv_new_record EMPLOYEE_OBJ; 22 23 BEGIN 24 /* Open base cursor and fetch records until none are found. */ 25 OPEN c; 26 LOOP 27 FETCH c 28 INTO lv_trigger_log_id 29 , lv_table_name 30 , lv_trigger_event 31 , lv_transaction_status 32 , lv_old_record 33 , lv_new_record; 34 EXIT WHEN c%NOTFOUND; 35 36 dbms_output.put_line('========================================'); 37 dbms_output.put_line('Trigger_Log_ID [Row] : ' 38 || lv_trigger_log_id); 39 dbms_output.put_line('Table_Name [Row] : ' 40 || lv_table_name); 41 dbms_output.put_line('Table_Name [Row] : ' 42 || lv_trigger_event); 43 dbms_output.put_line('Transaction [Row] : ' 44 || lv_transaction_status); 45 dbms_output.put_line( 46 '----------------------------------------'); 47 dbms_output.put_line('OName [Old] : ' 48 || lv_old_record.oname); 49 dbms_output.put_line('Employee_ID [Old] : ' 50 || lv_old_record.employee_id); 51 dbms_output.put_line('Employee_Number [Old] : ' 52 || lv_old_record.employee_number); 53 dbms_output.put_line('First_Name [Old] : ' 54 || lv_old_record.first_name); 55 dbms_output.put_line('Middle_Name [Old] : ' 56 || lv_old_record.middle_name); 57 dbms_output.put_line('Last_Name [Old] : ' 58 || lv_old_record.last_name); 59 dbms_output.put_line( 60 '----------------------------------------'); 61 dbms_output.put_line('OName [New] : ' 62 || lv_new_record.oname); 63 dbms_output.put_line('Employee_ID [New] : ' 64 || lv_new_record.employee_id); 65 dbms_output.put_line('Employee_Number [New] : ' 66 || lv_new_record.employee_number); 67 dbms_output.put_line('First_Name [New] : ' 68 || lv_new_record.first_name); 69 dbms_output.put_line('Middle_Name [New] : ' 70 || lv_new_record.middle_name); 71 dbms_output.put_line('Last_Name [New] : ' 72 || lv_new_record.last_name); 73 END LOOP; 74 CLOSE c; 75 76 /* Print the close the set. */ 77 dbms_output.put_line( 78 '========================================'); 79 END; 80 / |
The cursor on lines 4 through 11 includes a key trick for reading the object types on lines 8 and 9. The TREAT
function instructs the query to instantiate the base_t
column as an employee_obj subtype.
You access the object instance on lines 47 through 58 by referring to the lv_new_record
variable. You access the individual field element with a dot notation. The same approach lets you access the lv_old_record
variable’s contents.
It generates the following output from the employee
table:
======================================== Trigger_Log_ID [ROW] : 1 Table_Name [ROW] : EMPLOYEE Table_Name [ROW] : INSERT TRANSACTION [ROW] : PROCESSED ---------------------------------------- OName [Old] : EMPLOYEE_OBJ Employee_ID [Old] : Employee_Number [Old] : First_Name [Old] : Middle_Name [Old] : Last_Name [Old] : ---------------------------------------- OName [NEW] : EMPLOYEE_OBJ Employee_ID [NEW] : 1 Employee_Number [NEW] : B98765-678 First_Name [NEW] : Catherine Middle_Name [NEW] : Last_Name [NEW] : Zeta-Jones ======================================== Trigger_Log_ID [ROW] : 2 Table_Name [ROW] : EMPLOYEE Table_Name [ROW] : UPDATE TRANSACTION [ROW] : REJECTED ---------------------------------------- OName [Old] : EMPLOYEE_OBJ Employee_ID [Old] : 1 Employee_Number [Old] : B98765-678 First_Name [Old] : Catherine Middle_Name [Old] : Last_Name [Old] : Zeta-Jones ---------------------------------------- OName [NEW] : EMPLOYEE_OBJ Employee_ID [NEW] : 1 Employee_Number [NEW] : B98765-678 First_Name [NEW] : Catherine Middle_Name [NEW] : Last_Name [NEW] : Zeta Jones ======================================== |
This article has shown you how to create a framework for the writing trigger results from multiple tables into a single logging table. It’s also shown you how to leverage column substitutability with the base_t
type column.
While this example has shown you to query with an anonymous block, you should really use an object table function. You would develop one object table function for each different type of output.
Critical Triggers
Oracle Critical and Non-critical Triggers
This article demonstrates how you can write critical and non-critical row-level triggers. You may ask yourself, what are critical and non-critical triggers? That’s a great question. A critical trigger stops processing and raises an exception within the scope of an Application Programming Interface (API). An API is typically a series of end-user forms that help you solve business problems. A non-critical trigger either allows users to perform undesired behavior or it automatically fixes undesired behavior by preventing it. Non-critical triggers may log events but they don’t typically raise exceptions to the API.
Next, you’re probably asking yourself if critical and non-critical triggers are important. That’s also a great question. The answer is they’re very important and a key part of any database-centric application software solution.
If you’re new to database triggers, you can read the DML Trigger Basic article on this site to get an introduction. By way of review, you can write database triggers against DDL or DML statements. DML triggers can be either statement-level or row-level triggers.
The difference between a statement-level and row-level trigger is simple. A statement-level trigger runs once for any INSERT
, UPDATE
, or DELETE
statement, which means you can’t inspect the specific rows that a DML statement affects. A row-level trigger runs once for each row affected by an INSERT
, UPDATE
, or DELETE
statement.
Row-level database triggers give us the most granular (fancy word for detailed) view of transactions in your application. They’re also the best suited to logging changes happening with your data. The examples in this article will use DML row-level database triggers.
Business Logic
The article creates some tables for the examples, and the tables use traditional Oracle sequences and triggers. That’s because using sequences and triggers is the closest to how Oracle APEX creates tables. Many readers are familiar with how APEX works. After we create the tables, sequences, and basic automatic numbering database triggers, you will learn how to create non-critical triggers. The last section shows you how to create critical triggers.
It’s helpful to have a basic business problem when you work with so many moving parts. I chose a business problem that should be familiar to most people. The example uses a human resource professional. A human resource professional creates new employees when they join a company. Company policy sometimes dictates the convention for personal names. For example, they may restrict multipart last names. That means when you want to enter a multipart last name; they replace the whitespace with a hyphen.
The example business case requires that all last names must have hyphens. This means that the company disallows multipart last names. While this may seem old fashioned, it’s a simple business process to model, and it lets you see how to work with non-critical and critical database triggers.
So, here are our two use cases:
Non-critical Use Case
A human resource professional may try to enter a multipart last name with whitespace between parts. The entry may be intentional or simply a mistake. Assuming a positive mental attitude, you should assume the human resource profession doesn’t understand the policy. That means our triggers shouldn’t raise an exception when initially entering a value. The insert trigger should only log the attempt to enter non-conforming data. Initial entries, like this, are made through INSERT
statements.
Critical Use Case
What the same human resource professional does when they notice that they weren’t able to enter a multipart last name becomes important. A critical trigger becomes necessary when the human resource professional tries to change a hyphenated name into a multipart name. The API uses an UPDATE
statement to change an existing value with a new value. There is no use case when the human resource professional accepts the change to a hyphenated name.
The following steps you through how you create a framework for the non-critical and critical triggers. The framework uses three tables.
Framework
The non-critical trigger only uses two of those tables. The non-critical trigger is an INSERT
trigger and the critical trigger is an UPDATE
trigger. The application_user
table will contain information about our authorized users; and the employee
table will be the target for our non-critical and critical triggers.
The following creates the application_user
table with this statement:
SQL> CREATE TABLE application_user 2 ( application_user_id NUMBER 3 , application_user_name VARCHAR2(30) CONSTRAINT application_user_nn1 NOT NULL 4 , created_by NUMBER CONSTRAINT application_user_nn2 NOT NULL 5 , creation_date DATE CONSTRAINT application_user_nn3 NOT NULL 6 , last_updated_by NUMBER CONSTRAINT application_user_nn4 NOT NULL 7 , last_update_date DATE CONSTRAINT application_user_nn5 NOT NULL 8 , CONSTRAINT application_user_pk PRIMARY KEY (application_user_id) 9 , CONSTRAINT application_user_fk1 FOREIGN KEY (created_by) 10 REFERENCES application_user (application_user_id) 11 , CONSTRAINT application_user_fk2 FOREIGN KEY (last_updated_by) 12 REFERENCES application_user (application_user_id)); |
The application_user_seq
supports a surrogate key for the application_user
table. You create it with the following statement:
SQL> CREATE OR REPLACE TRIGGER application_user_t1 2 BEFORE INSERT ON application_user 3 FOR EACH ROW 4 BEGIN 5 /* Check for a empty image_id primary key column value, 6 and assign the next sequence value when it is missing. */ 7 IF :NEW.application_user_id IS NULL THEN 8 SELECT application_user_seq.NEXTVAL 9 INTO :NEW.application_user_id 10 FROM dual; 11 END IF; 12 END; 13 / |
You will need at least one row in the application_user
table to test the non-critical and critical triggers. The following insert a single row into the application_user
table:
SQL> INSERT INTO application_user 2 ( application_user_name 3 , created_by 4 , creation_date 5 , last_updated_by 6 , last_update_date) 7 VALUES 8 ('Database Administrator' 9 , 1 10 , TRUNC(SYSDATE) 11 , 1 12 , TRUNC(SYSDATE)); |
The next statement creates the employee
table:
SQL> CREATE TABLE employee 2 ( employee_id NUMBER 3 , employee_number VARCHAR2(10) 4 , first_name VARCHAR2(20) CONSTRAINT employee_nn1 NOT NULL 5 , middle_name VARCHAR2(20) 6 , last_name VARCHAR2(20) CONSTRAINT employee_nn2 NOT NULL 7 , created_by NUMBER CONSTRAINT employee_nn3 NOT NULL 8 , creation_date DATE CONSTRAINT employee_nn5 NOT NULL 9 , last_updated_by NUMBER CONSTRAINT employee_nn6 NOT NULL 10 , last_update_date DATE CONSTRAINT employee_nn7 NOT NULL 11 , CONSTRAINT employee_pk PRIMARY KEY (employee_id) 12 , CONSTRAINT employee_fk1 FOREIGN KEY (created_by) 13 REFERENCES application_user (application_user_id) 14 , CONSTRAINT employee_fk2 FOREIGN KEY (last_updated_by) 15 REFERENCES application_user (application_user_id)); |
You create the employee_seq
sequence with this statement:
SQL> CREATE SEQUENCE employee_seq; |
Next, you create a trigger to generate sequence values like you did for the application_user
table:
SQL> CREATE OR REPLACE TRIGGER employee_t1 2 BEFORE INSERT ON employee 3 FOR EACH ROW 4 BEGIN 5 /* Check for a empty image_id primary key column value, 6 and assign the next sequence value when it is missing. */ 7 IF :NEW.employee_id IS NULL THEN 8 SELECT employee_seq.NEXTVAL 9 INTO :NEW.employee_id 10 FROM dual; 11 END IF; 12 END; 13 / |
You have created the two tables for our non-critical trigger. The next section relies on the framework and integrates with it.
Non-critical Trigger
Before you create the logging trigger, you should test the concept of replacing a whitespace in a multipart last name with a hyphenated name. The following INSERT
trigger fixes user input by replacing the whitespace with a hyphen. It doesn’t log the entry and some times you won’t log results for this type of trigger.
You create the employee_t2
trigger with the following:
SQL> CREATE OR REPLACE TRIGGER employee_t2 2 BEFORE INSERT ON employee 3 FOR EACH ROW 4 FOLLOWS employee_t1 5 WHEN (REGEXP_LIKE(NEW.last_name,' ')) 6 BEGIN 7 /* Substitute a dash for the white space. */ 8 :NEW.last_name := REGEXP_REPLACE(:NEW.last_name,' ','-',1,1); 9 END; 10 / |
Line 4 designates that employee_t2
executes after employee_t1
, which is the purpose of the FOLLOWS
command. Line 8 uses the REGEXP_REPLACE
function to find and replace the first instance of a whitespace with a hyphen.
After creating the employee_t2
trigger, you can test it by using an INSERT
statement like this:
SQL> INSERT INTO employee 2 ( employee_number 3 , first_name 4 , last_name 5 , created_by 6 , creation_date 7 , last_updated_by 8 , last_update_date ) 9 VALUES 10 ('B12345-678' 11 ,'Sandy' 12 ,'Johnston Smith' 13 , 1 14 , TRUNC(SYSDATE) 15 , 1 16 , TRUNC(SYSDATE)); |
You can verify that the employee_t1
trigger prevented the entry of a multipart last name with the following query:
SQL> COLUMN employee_id FORMAT 9999 HEADING "Employee|ID #" SQL> COLUMN employee_number FORMAT A10 HEADING "Employee|Number" SQL> COLUMN first_name FORMAT A20 HEADING "First Name" SQL> COLUMN last_name FORMAT A20 HEADING "Last Name" SQL> SELECT employee_id 2 , employee_number 3 , first_name 4 , last_name 5 FROM employee; |
It returns:
Employee Employee ID # Number First Name Last Name -------- ---------- -------------------- -------------------- 1 B12345-678 Sandy Johnston-Smith |
As you see from the results, the last name is hyphenated. If we accept another use case for the UPDATE
statement, we may treat updates like you treat inserts.
An INSERT
trigger doesn’t guarantee the user can’t change the hyphenated last name into a multipart last name. The application user can always change the value by using an UPDATE
statement. That’s why there must be an UPDATE
trigger.
The first element of a our
SQL> CREATE OR REPLACE TRIGGER employee_t3 2 BEFORE UPDATE OF last_name ON employee 3 FOR EACH ROW 4 WHEN (REGEXP_LIKE(NEW.last_name,' ')) 5 BEGIN 6 /* Substitute a dash for the white space. */ 7 :NEW.last_name := REGEXP_REPLACE(:NEW.last_name,' ','-',1,1); 8 END; 9 / |
Line 2 guarantees that the UPDATE
trigger only runs when an UPDATE
statement changes the last_name
column of the employee
table. An UPDATE
statement like the following causes the trigger to run (technically, the jargon is “fire”):
SQL> UPDATE employee 2 SET last_name = 'Johnston Smith' 3 WHERE employee_number = 'B12345-678'; |
Having shown you how to create the non-critical INSERT
and UPDATE
triggers, I’ll now show you how to create the following employee_log table. This is where you can store the results from INSERT
, UPDATE
, and DELETE
triggers. All columns are nullable (or optional) columns except the sequence generated employee_log_id
column. The columns are optional because an INSERT
statement never has an old set of values, and a DELETE
statement never has a new set of values. Only the UPDATE
statement provides old and new values inside a trigger.
The following creates the employee_log
table:
SQL> CREATE TABLE employee_log 2 ( employee_log_id NUMBER 3 , employee_event VARCHAR2(6) 4 , old_employee_id NUMBER 5 , old_employee_number VARCHAR2(10) 6 , old_first_name VARCHAR2(20) 7 , old_middle_name VARCHAR2(20) 8 , old_last_name VARCHAR2(20) 9 , old_created_by NUMBER 10 , old_creation_date DATE 11 , old_last_updated_by NUMBER 12 , old_last_update_date DATE 13 , new_employee_id NUMBER 14 , new_employee_number VARCHAR2(10) 15 , new_first_name VARCHAR2(20) 16 , new_middle_name VARCHAR2(20) 17 , new_last_name VARCHAR2(20) 18 , new_created_by NUMBER 19 , new_creation_date DATE 20 , new_last_updated_by NUMBER 21 , new_last_update_date DATE 22 , CONSTRAINT employee_log_pk PRIMARY KEY (employee_log_id)); |
You should create the employee_log_seq
sequence, like
SQL> CREATE SEQUENCE employee_log_seq; |
Then, you should add an employee_log_t1
trigger to generate the sequence value automatically. The trigger follows the pattern of the prior two triggers for the application_user
and employee
tables.
You create the employee_log_seq
trigger with the following syntax:
SQL> CREATE OR REPLACE TRIGGER employee_log_t1 2 BEFORE INSERT ON employee_log 3 FOR EACH ROW 4 BEGIN 5 /* Check for a empty image_id primary key column value, 6 and assign the next sequence value when it is missing. */ 7 IF :NEW.employee_log_id IS NULL THEN 8 SELECT employee_log_seq.NEXTVAL 9 INTO :NEW.employee_log_id 10 FROM dual; 11 END IF; 12 END; 13 / |
The logging table is the first step. After creating the logging table, you need to create a standalone log_invalid_employee
procedure. The following code creates the procedure. This procedure only runs in the current transaction context, and later another version shows you how to implement it in an autonomous transaction context.
SQL> CREATE OR REPLACE 2 PROCEDURE log_invalid_employee 3 ( pv_employee_event VARCHAR2 4 , pv_old_employee_id NUMBER 5 , pv_old_employee_number VARCHAR2 6 , pv_old_first_name VARCHAR2 7 , pv_old_last_name VARCHAR2 8 , pv_old_created_by NUMBER 9 , pv_old_creation_date DATE 10 , pv_old_last_updated_by NUMBER 11 , pv_old_last_update_date DATE 12 , pv_new_employee_id NUMBER 13 , pv_new_employee_number VARCHAR2 14 , pv_new_first_name VARCHAR2 15 , pv_new_last_name VARCHAR2 16 , pv_new_created_by NUMBER 17 , pv_new_creation_date DATE 18 , pv_new_last_updated_by NUMBER 19 , pv_new_last_update_date DATE) IS 20 BEGIN 21 /* Write to the log table. */ 22 INSERT INTO employee_log 23 ( employee_event 24 , old_employee_id 25 , old_employee_number 26 , old_first_name 27 , old_last_name 28 , old_created_by 29 , old_creation_date 30 , old_last_updated_by 31 , old_last_update_date 32 , new_employee_id 33 , new_employee_number 34 , new_first_name 35 , new_last_name 36 , new_created_by 37 , new_creation_date 38 , new_last_updated_by 39 , new_last_update_date ) 40 VALUES 41 ( pv_employee_event 42 , pv_old_employee_id 43 , pv_old_employee_number 44 , pv_old_first_name 45 , pv_old_last_name 46 , pv_old_created_by 47 , pv_old_creation_date 48 , pv_old_last_updated_by 49 , pv_old_last_update_date 50 , pv_new_employee_id 51 , pv_new_employee_number 52 , pv_new_first_name 53 , pv_new_last_name 54 , pv_new_created_by 55 , pv_new_creation_date 56 , pv_new_last_updated_by 57 , pv_new_last_update_date ); 58 END log_invalid_employee; 59 / |
With the logging table and procedure, you can now rework the INSERT
and UPDATE
triggers into a single trigger. The new trigger fires when an INSERT
or an UPDATE
statement affects the employee
table. That means you can log the data from both events.
If you created employee_t1
, employee_t2
and employee_t3
triggers, you need to drop employee_t2
and employee_t3
triggers before creating the new trigger. The previous employee_t3
trigger will cause incorrect behaviors because it is incompatible with the new employee_t1
trigger.
The new employee_t1
trigger is:
SQL> CREATE OR REPLACE TRIGGER employee_t1 2 BEFORE INSERT OR UPDATE OF last_name ON employee 3 FOR EACH ROW 4 WHEN (REGEXP_LIKE(NEW.last_name,' ')) 5 DECLARE 6 /* DML event label. */ 7 lv_employee_event VARCHAR2(6); 8 BEGIN 9 /* Check for an event and assign event value. */ 10 IF INSERTING THEN 11 /* Check for a empty image_id primary key column value, 12 and assign the next sequence value when it is missing. */ 13 IF :NEW.employee_id IS NULL THEN 14 SELECT employee_seq.NEXTVAL 15 INTO :NEW.employee_id 16 FROM dual; 17 END IF; 18 lv_employee_event := 'INSERT'; 19 ELSE 20 lv_employee_event := 'UPDATE'; 21 END IF; 22 23 /* Log the details captured by an insert or update. */ 24 log_invalid_employee 25 ( pv_employee_event => lv_employee_event 26 , pv_old_employee_id => :old.employee_id 27 , pv_old_employee_number => :old.employee_number 28 , pv_old_first_name => :old.first_name 29 , pv_old_last_name => :old.last_name 30 , pv_old_created_by => :old.created_by 31 , pv_old_creation_date => :old.creation_date 32 , pv_old_last_updated_by => :old.last_updated_by 33 , pv_old_last_update_date => :old.last_update_date 34 , pv_new_employee_id => :NEW.employee_id 35 , pv_new_employee_number => :NEW.employee_number 36 , pv_new_first_name => :NEW.first_name 37 , pv_new_last_name => :NEW.last_name 38 , pv_new_created_by => :NEW.created_by 39 , pv_new_creation_date => :NEW.creation_date 40 , pv_new_last_updated_by => :NEW.last_updated_by 41 , pv_new_last_update_date => :NEW.last_update_date ); 42 43 /* Substitute a dash for the white space. */ 44 :NEW.last_name := REGEXP_REPLACE(:NEW.last_name,' ','-',1,1); 45 END; 46 / |
This non-critical trigger checks whether the event is an INSERT
statement on line 10. The trigger generates a sequence value when an INSERT
statement fires the trigger. Then, the trigger sets a local variable with the INSERT
string. It assigns an UPDATE
string when an UPDATE
statement fires the trigger.
After the event detection logic, the trigger calls the log_invalid_employee
procedure on line 24. Line 44 changes the multipart last name into a hyphenated last name.
This part of the article has shown you how to create and manage non-critical triggers.
Critical Trigger
This part of the article shows you how to create and manage critical triggers. The key difference is that critical triggers stop the transaction that fires the trigger. This has significant impact on how you design and implement the log_invalid_employee
procedure.
You need to modify the log_invalid_employee
procedure so that it supports autonomous transactions. That requires adding a PRAGMA
precompiler directive in the declaration block and a COMMIT
statement after the INSERT
statement.
The following shows you the changes required in the log_invalid_employee
procedure:
SQL> CREATE OR REPLACE 2 PROCEDURE log_invalid_employee 3 ( pv_employee_event VARCHAR2 4 , pv_old_employee_id NUMBER ... 21 /* Set precompiler directive to run in a separate context. */ 22 PRAGMA AUTONOMOUS_TRANSACTION; 23 BEGIN ... 62 /* Commit the autonmous transaction. */ 63 COMMIT; 64 END log_invalid_employee; 65 / |
Line 22 holds the autonomous transaction PRAGMA
, and line 63 holds the COMMIT
statement. Both of these are required when you want to enable a trigger to both log data and raise an exception that terminates the transaction.
Next, you need to rework the employee_t1
trigger by adding content to the declaration and execution blocks, and by adding an exception block. The declaration block requires you to declare an exception variable and create a PRAGMA precompiler directive. The exception block requires you to add a conditional block at the end of the execution block. You also need to add an exception block to manage a raised exception.
The following shows you the changes required for the employee_t1
trigger:
SQL> CREATE OR REPLACE TRIGGER employee_t1 2 BEFORE INSERT OR UPDATE OF last_name ON employee 3 FOR EACH ROW 4 WHEN (REGEXP_LIKE(NEW.last_name,' ')) 5 DECLARE ... 9 /* Declare exception. */ 10 e EXCEPTION; 11 PRAGMA EXCEPTION_INIT(e,-20001); 12 BEGIN ... 47 /* Re-check for an event and assign event value. */ 48 IF INSERTING THEN 49 /* Substitute a dash for the white space. */ 50 :NEW.last_name := REGEXP_REPLACE(:NEW.last_name,' ','-',1,1); 51 ELSE 52 /* Throw exception. */ 53 RAISE_APPLICATION_ERROR(-20001,'No two-part last names without a hyphen.'); 54 END IF; 55 EXCEPTION 56 /* Capture an exception. */ 57 WHEN e THEN 58 ROLLBACK; 59 dbms_output.put_line('[Trigger Event: '||lv_employee_event||']'); 60 dbms_output.put_line(SQLERRM); 61 WHEN OTHERS THEN 62 dbms_output.put_line(SQLERRM); 63 END; 64 / |
Line 10 declares a local exception variable. Line 11 declares the PRAGMA
precompiler directive. Lines 47 through 54 implements the conditional logic for writing a hyphenated last name for an INSERT
statement, and the logic for raising an exception for an UPDATE
statement.
An INSERT
statement causes the database trigger to write to the employee_log logging table. An UPDATE statement causes the database trigger to write to the logging table and throw an exception.
The test case for a critical event trigger uses an UPDATE
statement, as shown:
SQL> UPDATE employee 2 SET last_name = 'Zeta Jones' 3 WHERE employee_number = 'B98765-678'; |
The first thing you see is a thrown exception, like
[Trigger Event: UPDATE] ORA-20001: No two-part last names without a hyphen. |
After you see the thrown exception, you can run the following query to see what has been written to the exception_log
table:
SQL> COLUMN employee_log_id FORMAT 9999 HEADING "Empl|Log|ID #" SQL> COLUMN old_employee_id FORMAT 9999 HEADING "Empl|ID #" SQL> COLUMN old_name FORMAT A25 HEADING "Old Name" SQL> COLUMN new_employee_id FORMAT 9999 HEADING "Empl|ID #" SQL> COLUMN new_name FORMAT A25 HEADING "New Name" SQL> SELECT employee_log_id 2 , old_employee_id 3 , DECODE( old_last_name || ', '|| old_first_name,', ',NULL 4 , old_last_name || ', '|| old_first_name) AS "old_name" 5 , new_employee_id 6 , DECODE( new_last_name || ', '|| new_first_name,', ',NULL 7 , new_last_name || ', '|| new_first_name) AS "new_name" 8 FROM employee_log; |
It displays:
Empl Log Empl Empl ID # ID # Old Name ID # New Name ----- ----- ------------------------- ----- ------------------------- 1 2 Evert Lloyd, Chris 2 2 Evert-Lloyd, Chris 2 Evert Lloyd, Chris 3 3 Zeta Jones, Catherine 4 3 Zeta-Jones, Catherine 3 Zeta Jones, Catherine |
The ultimate test of these is that while there were many attempts at entering a multipart last name, none of them succeeds. You can query the last_name
column from the employee
table to verify that, like
SQL> SELECT last_name 2 FROM employee; |
It should show you the three rows that you’ve inserted and updated through this article. You should see:
Last Name ------------------------- Johnston-Smith Evert-Lloyd Zeta-Jones |
Through this article you should have learned how to create non-critical and critical triggers. These techniques are important when you manage transactions against business rules that can’t be supported by ordinary database constraints.
Oracle Trigger Basics
Oracle Trigger Basics
Once you master the basics of inserting, updating, and deleting data from the database, you typically learn about database triggers. Database triggers are coding elements that let you manage events beyond the limit of database constraints.
Before you can appreciate the power of database triggers, you need to understand what database constraints can and can’t do. Then, together we’ll explore how you can implement database triggers.
Database constraints let you manage events. A primary key constraint guarantees a column or a set of columns are unique and not null. A foreign key constraint guarantees a column only contains a value or set of values found in the primary key. A not null constraint makes a column mandatory when you insert or update a row in a table. A unique constraint guarantees a column or set of columns only exist in one row of a table. A check constraint guarantees a column’s value must comply with a set of rules defined with a row of data.
Database constraints do have limits. For example, a foreign key constraint doesn’t guarantee the right foreign key value because it only guarantees a foreign key value is a valid value in a list of possible values. That means it’s possible to insert or update a foreign key column or set of columns with an incorrect foreign key value. Only a database trigger can guarantee the insert or update of a correct foreign key value. The database trigger verifies the correct behavior by validating conditions before an insert or update.
While a unique constraint guarantees uniqueness and a check constraint guarantees compliance against a set of rules in a row, only a database trigger can guarantee the maximum number of like rows in a table that comply with a rule. Also, there is no constraint that manages inserts, updates, and deletes with dependencies on data in other tables.
A Data Manipulation Language (DML) trigger lets you manage these shortfalls and more. You have two options when implementing DML triggers. One implements a statement trigger and the other implements a row-level trigger. A statement-level trigger runs once for any and all rows affected by an INSERT
, UPDATE
, or DELETE
statement. A row-level trigger runs once for each row affected by an INSERT
, UPDATE
, or DELETE
statement.
Both of these triggers have two components – a trigger and a trigger body. The trigger defines what event to manage and the trigger body implements the logic that manages the event.
Statement-Level Triggers
You should create two tables to work with statement-level triggers. The first is the avenger table and the second is the avenger_log table. Your inserts, updates, and deletes to the avenger table act as events that fire triggers. Statement-level triggers can be defined to run before or after INSERT
, UPDATE
, and DELETE
statements. Statement-level triggers are narrowly scoped events and they log message data to the avenger_log
table.
This is the definition of the avenger table:
SQL> CREATE TABLE avenger 2 ( avenger_id NUMBER 3 , avenger_name VARCHAR2(30) 4 , first_name VARCHAR2(20) 5 , last_name VARCHAR2(20)); |
This is the definition of the avenger_log
table:
SQL> CREATE TABLE avenger_log 2 ( avenger_log_id NUMBER 3 , trigger_name VARCHAR2(30) 4 , trigger_timing VARCHAR2(6) 5 , trigger_event VARCHAR2(6) 6 , trigger_type VARCHAR2(12)); |
The following avenger_t1
creates a BEFORE INSERT
statement trigger:
SQL> CREATE OR REPLACE TRIGGER avenger_t1 2 BEFORE INSERT ON avenger 3 DECLARE 4 /* Declare local trigger-scope variables. */ 5 lv_sequence_id NUMBER := avenger_log_s.NEXTVAL; 6 lv_trigger_name VARCHAR2(30) := 'AVENGER_T1'; 7 lv_trigger_event VARCHAR2(6) := 'INSERT'; 8 lv_trigger_type VARCHAR2(12) := 'STATEMENT'; 9 lv_trigger_timing VARCHAR2(6) := 'BEFORE'; 10 BEGIN 11 /* Log event into the avenger_log table. */ 12 INSERT INTO avenger_log 13 ( avenger_log_id 14 , trigger_name 15 , trigger_event 16 , trigger_type 17 , trigger_timing ) 18 VALUES 19 ( lv_sequence_id 20 , lv_trigger_name 21 , lv_trigger_event 22 , lv_trigger_type 23 , lv_trigger_timing ); 24 END avenger_t1; 25 / |
Lines 1 and 2 declare the trigger. Lines 3 through 24 implements an anonymous PL/SQL block as the trigger’s body, and line 25 executes the trigger. Lines 6 through 9 store literal values for the trigger’s name, event, type, and timing. The trigger uses these literal values when logging events to the avenger_log
table.
You access the data catalog information about triggers in the DBA_
, ALL_
, and USER_TRIGGERS
views in a non-containerized database. Triggers also exist in those views for containerized databases (CDB). CDBs have an additional CDB_TRIGGERS
view that stores triggers. The trigger body is stored in the TRIGGER_BODY
column of those views in a LONG
column.
You can create an AFTER STATEMENT
trigger by simply changing the first two lines or the trigger declaration, as follows:
SQL> CREATE OR REPLACE TRIGGER avenger_t1 2 AFTER INSERT ON avenger |
Then, you need to change values of the string literals on lines 6, 7, and 9 as follows:
6 lv_trigger_name VARCHAR2(30) := 'AVENGER_T2'; 7 lv_trigger_event VARCHAR2(6) := 'INSERT'; 8 lv_trigger_type VARCHAR2(12) := 'STATEMENT'; 9 lv_trigger_timing VARCHAR2(6) := 'AFTER'; |
Compiling the database triggers, let’s insert a row into the avenger
table, like this:
SQL> INSERT INTO avenger 2 VALUES 3 ( avenger_s.NEXTVAL 4 ,'Captain America' 5 ,'Steven' 6 ,'Rogers'); |
Then, you can query the avenger_log
table, like this:
SQL> COLUMN avenger_log_id FORMAT 999 HEADING "Avenger|Log ID #" SQL> COLUMN trigger_name FORMAT A12 HEADING "Trigger|Name" SQL> COLUMN trigger_timing FORMAT A7 HEADING "Trigger|Timing" SQL> COLUMN trigger_event FORMAT A7 HEADING "Trigger|Event" SQL> COLUMN trigger_type FORMAT A12 HEADING "Trigger|Type" SQL> SELECT * FROM avenger_log; |
It returns two rows – one row from the avenger_t1
trigger and the other from the avenger_t2
trigger:
Avenger TRIGGER TRIGGER TRIGGER TRIGGER LOG ID # Name TIMING Event TYPE -------- ------------ ------- ------- ---------- 1 AVENGER_T2 AFTER INSERT STATEMENT 2 AVENGER_T1 BEFORE INSERT STATEMENT |
Both of the triggers use the avenger_log_s1
sequence. You may notice that the AFTER STATEMENT
trigger ran before the BEFORE STATEMENT
trigger. That shows you that triggers aren’t sequenced by default, even when you think that the timing event should sequence them.
Oracle lets you sequence triggers by using the FOLLOWS
clause when you define database triggers. The following modifies the avenger_t2
by adding a FOLLOWS
clause on line 3, and it uses ellipses to shorten the example:
SQL> CREATE OR REPLACE TRIGGER avenger_t2 2 BEFORE INSERT ON avenger 3 FOLLOWS avenger_t1 4 DECLARE … 11 BEGIN … 25 END avenger_t2; 26 / |
The testing script drops and creates the avenger_log
table before creating fresh copies of the avenger_t1
and avenger_t2
triggers. The script lets you re-query the avenger_log
table without the baggage of the previous two rows.
Like before, it returns two rows – one row from the avenger_t1
trigger and the other from the avenger_t2
trigger:
Avenger TRIGGER TRIGGER TRIGGER TRIGGER LOG ID # Name TIMING Event TYPE -------- ------------ ------- ------- ----------- 1 AVENGER_T1 BEFORE INSERT STATEMENT 2 AVENGER_T2 AFTER INSERT STATEMENT |
You should note that the BEFORE STATEMENT
trigger now runs before the AFTER STATEMENT
trigger. The FOLLOWS
clause lets you guarantee the order of trigger execution.
As you can see, statement-level triggers don’t give us the ability to see, change, or log the before and after values of data. You can do that with row-level triggers.
Row-Level Triggers
Row-level triggers let you see the initial column values you add into a table with an INSERT
statement. Row-level triggers let you see existing column values and the column values provided by an UPDATE
statement. The DELETE
statement only provides the existing column values to a trigger because it removes the row from the database. Inside the row-level trigger you can change new values based on rules that you put in code inside the database trigger.
The avenger_log
table requires major changes to support a row-level database trigger because it needs to store the old and new values of a table’s data column. Data columns hold values that describe an instance of the table. A data column or set of data columns should also define a unique key that makes each row unique in a table.
After engineering a table, you should also add a surrogate key column. A surrogate (stand-in) key column contains a value generated from a sequence, and a surrogate key is generally unrelated to the subject of a table. You use the natural key to find a unique row in a table, and you copy the surrogate key value when you want a foreign key to link another row with the row identified by the surrogate key.
Both the surrogate key column and natural key (one or more columns) should both identify unique rows. That means for every surrogate key there should be a natural key.
The data columns in the avenger table are the avenger_name
, first_name
, and last_name
columns. You should define an old
and new
column for each of the data columns when you create a logging table.
This defines the new avenger_log
table:
SQL> CREATE TABLE avenger_log 2 ( avenger_log_id NUMBER 3 , trigger_name VARCHAR2(30) 4 , trigger_timing VARCHAR2(6) 5 , trigger_event VARCHAR2(6) 6 , trigger_type VARCHAR2(12) 7 , old_avenger_name VARCHAR2(20) 8 , old_first_name VARCHAR2(20) 9 , old_last_name VARCHAR2(20) 10 , new_avenger_name VARCHAR2(20) 11 , new_first_name VARCHAR2(20) 12 , new_last_name VARCHAR2(20)); |
The first row-level database trigger you create runs when an INSERT
statement adds a new row to the avenger
table. The code exists below:
SQL> CREATE OR REPLACE TRIGGER avenger_t3 2 BEFORE INSERT ON avenger 3 FOR EACH ROW 4 DECLARE 5 /* Declare local trigger-scope variables. */ 6 lv_sequence_id NUMBER := avenger_log_s.NEXTVAL; 7 lv_trigger_name VARCHAR2(30) := 'AVENGER_T3'; 8 lv_trigger_event VARCHAR2(6) := 'INSERT'; 9 lv_trigger_type VARCHAR2(12) := 'FOR EACH ROW'; 10 lv_trigger_timing VARCHAR2(6) := 'BEFORE'; 11 BEGIN 12 /* Log event into the avenger_log table. */ 13 INSERT INTO avenger_log 14 ( avenger_log_id 15 , trigger_name 16 , trigger_event 17 , trigger_type 18 , trigger_timing 19 , old_avenger_name 20 , old_first_name 21 , old_last_name 22 , new_avenger_name 23 , new_first_name 24 , new_last_name ) 25 VALUES 26 ( lv_sequence_id 27 , lv_trigger_name 28 , lv_trigger_event 29 , lv_trigger_type 30 , lv_trigger_timing 31 , :old.avenger_name 32 , :old.first_name 33 , :old.last_name 34 , :NEW.avenger_name 35 , :NEW.first_name 36 , :NEW.last_name ); 37 END avenger_t3; 38 / |
Line 3 declares the avenger_t3
trigger as a row-level trigger. Lines 31 through 36 inserts the old and new values from the row of the avenger
table when the INSERT
statement runs with the following three values:
SQL> INSERT INTO avenger 2 VALUES 3 ( avenger_s.NEXTVAL 4 ,'Capt. America' 5 ,'Steven' 6 ,'Rogers'); |
Since the script drops and recreates the avenger
and avenger_log
tables and drops the avenger_t1
and avenger_t2
statement-level triggers, you can write a query to return only the test row. The following anonymous PL/SQL block let’s you print the old
and new
column values next to one another. The program helps make the row-level trigger’s ability to see before and after values clear.
SQL> SET SERVEROUTPUT ON SIZE UNLIMITED SQL> BEGIN 2 FOR i IN (SELECT * FROM avenger_log) LOOP 3 dbms_output.put_line( 4 'Trigger Name [' 5 || i.trigger_name||']'); 6 dbms_output.put_line( 7 'Trigger Event [' 8 || i.trigger_event||']'); 9 dbms_output.put_line( 10 'Trigger Type [' 11 || i.trigger_type||']'); 12 dbms_output.put_line( 13 'Trigger Timing [' 14 || i.trigger_timing||']'); 15 dbms_output.put_line( 16 'Avenger Name [' 17 || i.old_avenger_name||'][' 18 || i.new_avenger_name||']'); 19 dbms_output.put_line( 20 'First Name [' 21 || i.old_first_name||'][' 22 || i.new_first_name||']'); 23 dbms_output.put_line( 24 'Last Name [' 25 || i.old_last_name||'][' 26 || i.new_last_name||']'); 27 END LOOP; 28 END; 29 / |
This anonymous block prints the following from the avenger_log
table:
TRIGGER Name [AVENGER_T3] TRIGGER Event [INSERT] TRIGGER TYPE [FOR EACH ROW] TRIGGER TIMING [BEFORE] Avenger Name [][Capt. America] FIRST Name [][Steven] LAST Name [][Rogers] |
This has demonstrated how you write a row-level trigger against an INSERT
event. You should note that the old
values for the avenger_name
, first_name
, and last_name
are null values between the square brackets. Next, you should examine how to write a row-level trigger against more than one type of event.
The Oracle Database lets you write individual triggers for INSERT
, UPDATE
, or DELETE
statement, or a single trigger to manage INSERT
, UPDATE
, and DELETE
events. The following modifies the avenger_t3
trigger so that it works for an INSERT
, UPDATE
, and DELETE
events:
SQL> CREATE OR REPLACE TRIGGER avenger_t3 2 BEFORE INSERT OR UPDATE OR DELETE ON avenger 3 FOR EACH ROW |
Line 2 of the previous trigger is where we change the avenger_t3
trigger to also work with UPDATE
and DELETE
events. Then, we need to change one other line and then add a small IF
-block to the trigger.
Line 8 of the original trigger assigns a default value to the lv_trigger_event
variable, but you need to remove the value assignment. The modified line looks like this:
8 lv_trigger_event VARCHAR2(6); |
You also need to add an IF
-block that manages Data Manipulation Language (DML) event functions. The IF
-block should be the first thing in the execution block of the trigger body, and it should implement this logic:
11 BEGIN 12 /* Evaluate and assign event for logging. */ 13 IF INSERTING THEN lv_trigger_event := 'INSERT'; 14 ELSIF UPDATING THEN lv_trigger_event := 'UPDATE'; 15 ELSIF DELETING THEN lv_trigger_event := 'DELETE'; 16 END IF; ... |
The INSERTING
event function on line 13 occurs when an INSERT
statement activates the trigger. The UPDATING
and DELETING
event functions on lines 14 and 15 occur when a respective UPDATE
or DELETE
statement activity fires a trigger.
The following UPDATE
statement now creates an event that the avenger_t3
trigger is monitoring:
SQL> UPDATE avenger 2 SET avenger_name = 'Captain America' 3 WHERE avenger_name = 'Capt. America'; |
Next, let’s test a DELETE
statement with the following:
SQL> DELETE 2 FROM avenger 3 WHERE avenger_name = 'Captain America'; |
The following anonymous block program lets you see the log values inserted into the avenger_log
table from the INSERT
, UPDATE
, and DELETE
statement triggers:
SQL> SET SERVEROUTPUT ON SIZE UNLIMITED SQL> BEGIN 2 FOR i IN (SELECT * FROM avenger_log) LOOP 3 dbms_output.put_line( 4 'Row Number [' 5 || i.avenger_log_id ||'][' 6 || i.trigger_event ||']'); 7 dbms_output.put_line( 8 'Avenger Name [' 9 || i.old_avenger_name ||'][' 10 || i.new_avenger_name ||']'); 11 dbms_output.put_line( 12 'First Name [' 13 || i.old_first_name ||'][' 14 || i.new_first_name ||']'); 15 dbms_output.put_line( 16 'Last Name [' 17 || i.old_last_name ||'][' 18 || i.new_last_name ||']'); 19 END LOOP; 20 END; 21 / |
The anonymous block returns the following:
Row Number [1][INSERT] Avenger Name [][Capt. America] First Name [][Steven] Last Name [][Rogers] Row Number [2][UPDATE] Avenger Name [Capt. America][Captain America] First Name [Steven][Steven] Last Name [Rogers][Rogers] Row Number [3][DELETE] Avenger Name [Captain America][] First Name [Steven][] Last Name [Rogers][] |
You should notice the old
values for the INSERT
event are missing because there isn’t a row before running the INSERT
statement. Likewise, you should notice the new values for the DELETE
event are missing because there isn’t a row after running a DELETE
statement. Only the UPDATE
event has both an old
and new
value because the row exists before and after any change. The old
values hold the row’s values before the UPDATE
statement and the new
values hold the row’s values after the UPDATE
statement.
Column Substitutability
Object Types and Column Substitutability
This article shows you how to use extend parent (or superclass) objects. You extend parent classes when you implement specialized behaviors (or methods) in subtypes. That’s because SQL statements can’t work with specialized methods when a table’s column stores subclasses in a superclass column type.
Substitutability is the process of storing subtypes in a super type column. It is a powerful feature of the Oracle database. The “type evolution” feature of the Oracle Database 12c release makes it more important because it makes it more flexible. The flexibility occurs because Oracle lets you evolve parent classes.
You evolve parent classes when you implement MEMBER
functions or procedures, and you want to access them for all substitutable column values. That’s necessary because you need to define the MEMBER
function or procedure in the column’s base object type. Prior to Oracle Database 12c, you couldn’t change (evolve) a base type. If you’re new to the idea of object types and subtypes, you may want to check out my earlier “Object Types and Subtypes” article.
Before discussing the complexity of creating and evolving object types to support column substitutability, let’s create a base_t object type. The base_t object type will become our root node object type. A root node object type is our most general object type. A root node is also the topmost node of an inverted tree of object types. All subtypes of the root node become child nodes, and child nodes without their own children are at the bottom of the tree and they’re leaf nodes.
The following creates the base_t object type. It is similar to object types that I use in related articles to keep ideas consistent and simple across the articles. This version of the base_t object doesn’t try to maintain an internal unique identifier because the table maintains it as a surrogate key.
SQL> CREATE OR REPLACE 2 TYPE base_t IS OBJECT 3 ( oname VARCHAR2(30) 4 , CONSTRUCTOR FUNCTION base_t 5 RETURN SELF AS RESULT 6 , MEMBER FUNCTION get_oname RETURN VARCHAR2 7 , MEMBER PROCEDURE set_oname (oname VARCHAR2) 8 , MEMBER FUNCTION to_string RETURN VARCHAR2) 9 INSTANTIABLE NOT FINAL; 10 / |
The oname attribute on line two holds the name of the object type. Lines 4 and 5 define the default constructor, which has no formal parameters. Line 6 defines an accessor method, or getter, and line 7 defines a mutator, or setter. Line 8 defines a traditional to_string
method that lets you print the contents of the object type.
Next, let’s implement the base_t
object type’s body:
SQL> CREATE OR REPLACE 2 TYPE BODY base_t IS 3 /* A default constructor w/o formal parameters. */ 4 CONSTRUCTOR FUNCTION base_t 5 RETURN SELF AS RESULT IS 6 BEGIN 7 self.oname := 'BASE_T'; 8 RETURN; 9 END; 10 /* An accessor, or getter, method. */ 11 MEMBER FUNCTION get_oname RETURN VARCHAR2 IS 12 BEGIN 13 RETURN self.oname; 14 END get_oname; 15 /* A mutator, or setter, method. */ 16 MEMBER PROCEDURE set_oname 17 ( oname VARCHAR2 ) IS 18 BEGIN 19 self.oname := oname; 20 END set_oname; 21 /* A to_string conversion method. */ 22 MEMBER FUNCTION to_string RETURN VARCHAR2 IS 23 BEGIN 24 RETURN '['||self.oname||']'; 25 END to_string; 26 END; 27 / |
Line 7 assigns a literal value to the oname attribute. Line 24 returns the value of the oname
attribute for the instance. The remainder of the object type is generic. You can read about the generic features in my “Object Types and Bodies Basics” and about accessor and mutator methods in my “Object Types with Getters and Setters” articles.
Let’s define and implement a hobbit_t
subtype of our base_t
object type. The hobbit_t
object type is:
SQL> CREATE OR REPLACE TYPE hobbit_t UNDER base_t 2 ( genus VARCHAR2(20) 3 , name VARCHAR2(20) 4 , CONSTRUCTOR FUNCTION hobbit_t 5 ( genus VARCHAR2 6 , name VARCHAR2) RETURN SELF AS RESULT 7 , MEMBER FUNCTION get_genus RETURN VARCHAR2 8 , MEMBER FUNCTION get_name RETURN VARCHAR2 9 , MEMBER PROCEDURE set_genus (genus VARCHAR2) 10 , MEMBER PROCEDURE set_name (name VARCHAR2) 11 , OVERRIDING MEMBER FUNCTION to_string RETURN VARCHAR2) 12 INSTANTIABLE NOT FINAL; 13 / |
Lines 2 and 3 add two new genus and name attributes to the hobbit_t
subtype. The hobbit_t subtype also inherits the oname attribute from its parent base_t
type. Lines 7 and 8 define two getters and lines 9 and 10 define two setters, which support the genus and name attributes of the hobbit_t
subtype. The hobbit_t
object type’s getter and setters are unique to the subtype. They are also a specialization of the base_t
object type. As such, these getters and setters are inaccessible to instances of the base_t
object type. Line 11 defines an overriding to_string
function for the base_t
type’s to_string
function.
The following implements the hobbit_t
object body:
SQL> CREATE OR REPLACE TYPE BODY hobbit_t IS 2 /* A default constructor with two formal parameters. */ 3 CONSTRUCTOR FUNCTION hobbit_t 4 ( genus VARCHAR2 5 , name VARCHAR2 ) 6 RETURN SELF AS RESULT IS 7 BEGIN 8 self.oname := 'HOBBIT_T'; 9 self.name := name; 10 self.genus := genus; 11 RETURN; 12 END; 13 /* An accessor, or getter, method. */ 14 MEMBER FUNCTION get_genus RETURN VARCHAR2 IS 15 BEGIN 16 RETURN self.genus; 17 END get_genus; 18 /* An accessor, or getter, method. */ 19 MEMBER FUNCTION get_name RETURN VARCHAR2 IS 20 BEGIN 21 RETURN self.name; 22 END get_name; 23 /* A mutator, or setter, method. */ 24 MEMBER PROCEDURE set_genus 25 ( genus VARCHAR2 ) IS 26 BEGIN 27 self.genus := genus; 28 END set_genus; 29 /* A mutator, or setter, method. */ 30 MEMBER PROCEDURE set_name 31 ( name VARCHAR2 ) IS 32 BEGIN 33 self.name := name; 34 END set_name; 35 /* A to_string conversion method. */ 36 OVERRIDING MEMBER FUNCTION to_string RETURN VARCHAR2 IS 37 BEGIN 38 /* Uses general invocation on parent to_string 39 function. */ 40 RETURN (self AS base_t).to_string 41 || '['||self.genus||']['||self.name||']'; 42 END to_string; 43 END; 44 / |
Lines 4 and 5 list the parameters for the hobbit_t constructor. Line 8 assigns a literal value to the oname attribute of the base_t
object type. Lines 9 and 10 assign the formal parameters to the genus and name attributes of the hobbit_t
subtype. Line 40 uses a general invocation statement to call the base_t
’s to_string
function.
You can now create a table that has a substitutable column that uses the base_t
parent object type. The Oracle database assumes object type columns are substitutable at all levels, unless you turn off a column’s substitutability.
The following creates a tolkien
table, and it has only two columns. One column has a NUMBER data type and the other has a user-defined object type. The base_t
object type column is substitutable at all levels:
SQL> CREATE TABLE tolkien 2 ( tolkien_id NUMBER 3 , character BASE_T ); |
You create a tolkien_s
sequence for the unique tolkien_id
column with the following:
SQL> CREATE SEQUENCE tolkien_s START WITH 1001; |
You can insert one base_t
and two hobbit_t
object types with the following INSERT
statements:
SQL> INSERT INTO tolkien VALUES 2 ( tolkien_s.NEXTVAL, base_t() ); SQL> INSERT INTO tolkien VALUES 2 ( tolkien_s.NEXTVAL, hobbit_t('HOBBIT','Bilbo') ); SQL> INSERT INTO tolkien VALUES 2 ( tolkien_s.NEXTVAL, hobbit_t('HOBBIT','Frodo') ); |
The following simple query shows you the unique identifier in the tolkien_id
column and collapsed object types in the character column of the tolkien
table:
SQL> COLUMN character FORMAT A40 SQL> SELECT tolkien_id 2 , character 3 FROM tolkien; |
It should display the following:
TOLKIEN_ID CHARACTER(ONAME) ---------- ---------------------------------------- 1001 BASE_T('BASE_T') 1002 HOBBIT_T('HOBBIT_T', 'HOBBIT', 'Bilbo') 1003 HOBBIT_T('HOBBIT_T', 'HOBBIT', 'Frodo') |
Oracle always stores object instances as collapsed object instances in tables. You need to use the TREAT
function in SQL to read instances of an object type.
The TREAT
function lets you place in memory an instance of an object type. The TREAT
function requires that you designate the type of object instance. If you want the TREAT
function to work with all rows of the table, you designate the column’s object type as the base (or superclass) type. Designating a subtype to work like a parent, grandparent, or any antecedent type is a form of casting. Though casting in this case is actually dynamic dispatch.
Dynamic dispatch lets you pass any subtype as a parent or antecedent type. Dynamic dispatch inspects the object and treats it as a unique object.
The following query uses the TREAT
function to read the parent and any subtype of the parent object type:
SQL> COLUMN to_string FORMAT A40 SQL> SELECT tolkien_id 2 , TREAT(character AS BASE_T).to_string() AS to_string 3 FROM tolkien; |
It prints the oname attribute for base_t
instances and the oname
, genus
, and name
attributes for hobbit_t
instances, like
TOLKIEN_ID TO_STRING ---------- --------------------------- 1001 [BASE_T] 1002 [BASE_T] 1003 [HOBBIT_T][HOBBIT][Bilbo] 1004 [HOBBIT_T][HOBBIT][Frodo] |
The TREAT
function manages dynamic dispatch but requires any specialized method of a subtype to exist in the parent or antecedent type to which it is cast. Any query can cast to the root or an intermediate parent subtype. The TREAT
function raises an exception when you don’t have an equivalent method stub (definition) in the parent or antecedent type.
For example, let’s modify the previous query and change the method call on line 2 from the to_string function to the get_name
function. The new query is:
SQL> COLUMN to_string FORMAT A40 SQL> SELECT tolkien_id 2 , TREAT(character AS BASE_T).get_name() AS get_name 3 FROM tolkien; |
It fails with the following error:
, TREAT(character AS BASE_T).get_name() AS get_name * ERROR at line 2: ORA-00904: "STUDENT"."BASE_T"."GET_NAME": invalid identifier |
The reason for the failure is interesting. It occurs because the get_name
function is only part of the hobbit_t
subtype and can’t be found as an identifier inside the base_t
object type. PL/SQL identifiers are: reserved or key words; predefined identifiers; quoted identifiers; user-identifiers; and user-defined variables, subroutine, and data or object type names.
You can access the MEMBER
functions or procedures (method) of a subtype when you cast to a parent type provided you meet two conditions. First, you must implement the MEMBER
method in the subtype. Second, you must define the same MEMBER
method in the parent type.
Accessing a subtype MEMBER
method differs from general invocation. General invocation occurs when you call a MEMBER
method from a parent or antecedent type from a subtype’s OVERRIDING MEMBER
method. Oracle doesn’t explain how you call a subtype’s method from a parent or antecedent type but there is a close corollary – packages.
For example, you can only call a package function or procedure from another PL/SQL block when you’ve defined it in the package specification. This means you need to implement a stub for the get_name
function inside the base_t
object type because it acts as the specification.
You add a get_name
function to the base_t
object type in the next example:
SQL> CREATE OR REPLACE 2 TYPE base_t IS OBJECT 3 ( oname VARCHAR2(30) 4 , CONSTRUCTOR FUNCTION base_t 5 RETURN SELF AS RESULT 6 , MEMBER FUNCTION get_name RETURN VARCHAR2 7 , MEMBER FUNCTION get_oname RETURN VARCHAR2 8 , MEMBER PROCEDURE set_oname (oname VARCHAR2) 9 , MEMBER FUNCTION to_string RETURN VARCHAR2) 10 INSTANTIABLE NOT FINAL; 11 / |
Line 6 adds the get_name
function to the base_t
object type. The following shows you how to implement get_name
function stub in the object type body:
SQL> CREATE OR REPLACE 2 TYPE BODY base_t IS 3 CONSTRUCTOR FUNCTION base_t 4 RETURN SELF AS RESULT IS 5 BEGIN 6 self.oname := 'BASE_T'; 7 RETURN; 8 END; 9 MEMBER FUNCTION get_name RETURN VARCHAR2 IS 10 BEGIN 11 RETURN NULL; 12 END get_name; 13 MEMBER FUNCTION get_oname RETURN VARCHAR2 IS 14 BEGIN 15 RETURN self.oname; 16 END get_oname; 17 MEMBER PROCEDURE set_oname 18 ( oname VARCHAR2 ) IS 19 BEGIN 20 self.oname := oname; 21 END set_oname; 22 MEMBER FUNCTION to_string RETURN VARCHAR2 IS 23 BEGIN 24 RETURN '['||self.oname||']'; 25 END to_string; 26 END; 27 / |
Lines 9 through 12 implement the get_name
function stub. You should note that it returns a null value because the name attribute doesn’t exist in the root node (base_t
) object type.
The change to the hobbit_t
object type is simpler. All you need to do is add the OVERRIDING
keyword before the get_name
member function in the hobbit_t
object type and body. With that change, you can successfully run the following query:
SQL> COLUMN get_name FORMAT A20 SQL> SELECT tolkien_id 2 , TREAT(character AS BASE_T).get_name() AS get_name 3 FROM tolkien; |
It now works and prints:
TOLKIEN_ID GET_NAME ---------- -------------------- 1001 1002 Bilbo 1003 Frodo |
This article showed you how to extend parent object types. It also showed you how to modify parent types to support generalized calls with the TREAT
function. Together these principles show you how to leverage substitutability on columns.
Types & Subtypes
Object Types and Subtypes
This article teaches you how to use subtypes or subclasses. You can define an object type with or without dependencies. Object types can have two types of dependencies. The simplest case occurs when you define an object attribute with an object type instead of a data type. The more complex case occurs when you define an object subtype because it inherits the behavior of the base object type. The base object type is a superclass and a parent class. The subtype is a subclass and a child class.
The ability to capture various result sets is a key use case for object types and subtypes. That’s because you can define a table’s column with the object type, and then you can store in that column the object type or any of its subtypes.
A base object type should contain a unique identifier and an object name. The Object Types & Bodies Basic article explains the best practice for unique identifiers. It suggests that you populate the unique ID value with a no argument constructor function. The object name attribute should hold the object type name.
I’d like to suggest we consider base_t
as the name of our superclass. You can define a base_t
object type like this:
SQL> CREATE OR REPLACE 2 TYPE base_t IS OBJECT 3 ( obj_id NUMBER 4 , obj_name VARCHAR2(30) 5 , CONSTRUCTOR FUNCTION base_t RETURN SELF AS RESULT 6 , MEMBER FUNCTION to_string RETURN VARCHAR2) 7 INSTANTIABLE NOT FINAL; 8 / |
Line 2 and 3 define two attributes. They are the unique identifier, or ID, and the object. The no argument constructor function assigns values to the obj_id
and obj_name
attributes. It assigns the base_t_s
sequence value to the obj_id
attribute and it assigns a string literal to the obj_name
attribute. The to_string member function returns a concatenated string of the obj_id
and obj_name
values. The return value of the to_string
function is what you want to disclose about the contents of an object type.
Line 7 declares the class as instantiable and not final. You can create an instance of a class when its instantiable, and you can create subtypes of a type when it’s NOT FINAL
.
You need to create the base_t_s
sequence before we can compile the base_t
object body. The following statement creates the base_t_s
sequence as a set of values starting at 1:
SQL> CREATE SEQUENCE base_t_s; |
The object body for the base_t
object type is:
SQL> CREATE OR REPLACE 2 TYPE BODY base_t IS 3 4 /* Default constructor. */ 5 CONSTRUCTOR FUNCTION base_t RETURN SELF AS RESULT IS 6 BEGIN 7 /* Assign a sequence value and string literal 8 to the instance. */ 9 self.obj_id := base_t_s.NEXTVAL; 10 self.obj_name := 'BASE_T'; 11 RETURN; 12 END; 13 14 /* A text output function. */ 15 MEMBER FUNCTION to_string RETURN VARCHAR2 IS 16 BEGIN 17 RETURN 'UID#: ['||obj_id||']'||CHR(10) 18 || 'Type: ['||obj_name||']'; 19 END; 20 / |
Line 9 assigns a base_t_s
sequence value to the obj_id
attribute, which serves as a unique identifier. Line 10 assigns a string literal to the obj_name
attribute. The obj_name
attribute identifies the object type. Line 17 and 18 prints the contents of the base_t
object type as a two-row string.
You can test the construction of the base_t
object type with this query:
SQL> SELECT base_t() FROM dual; |
It displays:
BASE_T()(OBJ_ID, OBJ_NAME) ---------------------------- BASE_T(1, 'BASE_T') |
Alternatively, you can test the to_string
member function with the TREAT
function, like:
SQL> SELECT TREAT(base_t() AS base_t).to_string() AS "Text" 2 FROM dual; |
It displays:
Text ---------------- UID#: [2] Type: [BASE_T] |
Alternatively, you can test to_string
member function with an anonymous block (by enabling SERVEROUTPUT
):
SQL> SET SERVEROUTPUT ON SIZE UNLIMITED SQL> BEGIN 2 dbms_output.put_line(base_t().to_string); 3 END; 4 / |
It displays:
Text ---------------- UID#: [2] Type: [BASE_T] |
There’s another way to query the object instance with a query. While I don’t think it’s effective for this situation, you should know how the syntax works. It requires that you create a collection of the base_t
object type, which you can do with this syntax:
SQL> CREATE OR REPLACE 2 TYPE base_t_tab IS TABLE OF base_t; 3 / |
It displays:
Text ---------------- UID#: [2] Type: [BASE_T] |
You can query the base_t
object type from inside a collection by using the CAST
and COLLECT
functions. The COLLECT
function puts a single object instance into a base_t_tab
collection. The CAST
function puts the generic collection into a specific collection.
The syntax to perform this operation is:
SQL> COLUMN obj_id FORMAT 9999 SQL> COLUMN obj_name FORMAT A20 SQL> SELECT * 2 FROM TABLE(SELECT CAST(COLLECT(base_t()) AS base_t_tab) 3 FROM dual); |
Assuming the base_t_s
sequence holds a current value of 3, the query returns:
OBJ_ID OBJ_NAME ------ -------------------- 5 BASE_T |
This type of query isn’t too useful in day-to-day programming. It’s more of a corner use case for testing an object type with a sequence value. While you expect an obj_id
value of 4, the query returns a value of 5. Somewhere in the execution Oracle appears to call the sequence twice.
The COLLECT
and TREAT
functions increment the value of sequence when you put them inside object types. So, you shouldn’t use a sequence as a unique identifier inside an object type. I plan to cover the better approach in subsequent article.
Now that you have a solid base_t
object, let’s create a hobbit_t
subtype. The hobbit_t subtype adds one attribute to the two attributes in the base_t
object type.
The following declares the hobbit_t
object type as a subtype and overrides the to_string
member function:
SQL> CREATE OR REPLACE 2 TYPE hobbit_t UNDER base_t 3 ( hobbit_name VARCHAR2(30) 4 , CONSTRUCTOR FUNCTION hobbit_t 5 ( hobbit_name VARCHAR2 ) RETURN SELF AS RESULT 6 , OVERRIDING MEMBER FUNCTION to_string RETURN VARCHAR2) 7 INSTANTIABLE NOT FINAL; 8 / |
Assuming the base_t_s
sequence holds a current value of 3, the query returns:
OBJ_ID OBJ_NAME ------ -------------------- 5 BASE_T |
Line 2 declares the hobbit_t
subtype as UNDER
the base_t
object type. There isn’t a no argument constructor that mirrors the parent base_t
object type. You also can’t call the parent type’s constructor like they do in Java.
Line 4 and 5 declare a single argument constructor. The hobbit_t
object type’s constructor assigns values to the obj_id
and obj_name
attributes. More or less it performs the same function as its parent’s constructor. Then, the constructor assigns the parameter value to the hobbit_name
attribute of the hobbit_t
object type.
Line 6 declares an overriding to_string
member function. The overriding to_string
member function replaces the behavior of our parent class. It provides the subclass with its own a specialized behavior.
You implement the hobbit_t
object type like this:
SQL> CREATE OR REPLACE 2 TYPE BODY hobbit_t IS 3 4 /* One argument constructor. */ 5 CONSTRUCTOR FUNCTION hobbit_t 6 ( hobbit_name VARCHAR2 ) RETURN SELF AS RESULT IS 7 BEGIN 8 /* Assign a sequence value and string literal 9 to the instance. */ 10 self.obj_id := base_t_s.NEXTVAL; 11 self.obj_name := 'HOBBIT_T'; 12 13 /* Assign a parameter to the subtype only attribute. */ 14 self.hobbit_name := hobbit_name; 15 RETURN; 16 END; 17 18 /* An output function. */ 19 OVERRIDING MEMBER FUNCTION to_string RETURN VARCHAR2 IS 20 BEGIN 21 RETURN (self AS base_t).to_string||CHR(10) 22 || 'Name: ['||hobbit_name||']'; 23 END; 24 END; 25 / |
Lines 10 assigns a sequence value to the obj_id
attribute. Line 11 assigns a string literal to the obj_name
attribute. Line 14 assigns the parameter value of the constructor to the hobbit_name
attribute of the hobbit_t
subtype. Line 21 is more complex than a simple assignment.
Line 21 contains a “generalized invocation” of the base_t
object. A generalized invocation calls a parent or super class method. PL/SQL member functions or procedures are methods. Line 21 calls the base_t
type’s to_string
function. This way, the overriding to_string
function returns a specialized result. It returns the result from the parent class and the value of its own hobbit_name
attribute.
You can test the generalized invocation with the following query:
SQL> SELECT 2 TREAT( 3 hobbit_t('Bilbo') AS hobbit_t).to_string() AS "Text" 4 FROM dual; |
The query prints:
Text ----------------------- UID#: [1] Type: [HOBBIT_T] Name: [Bilbo] |
Together we’ve explored of how you create types and subtypes. You’ve learned a type is a generalization or superclass, and a subtype is a specialization or subclass. You’ve also learned how to create both a generalization and specialization. At this point, you may ask, “Why should I bother with subtypes?”
The benefit of subtypes is dynamic dispatch. Dynamic dispatch is the process of selecting an object type from an inverted tree of object types. The topmost object type is the root node or most generalized version of an object type. The bottom most object type is a leaf node or the most specialized version of an object type. All nodes between the root node and leaf nodes are simply nodes. Nodes become more specialized as you step down the hierarchy from the root node.
The process of selecting an object type from an inverted tree is polymorphism. Polymorphism means your program specifies the most general node at compile time. Then, the program accepts the root node or any subordinate nodes at runtime. Moreover, dynamic dispatch is like writing a function or procedure to do many things.
Another form of dynamic dispatch occurs when you overload a function or procedure in a PL/SQL package. Calls to overloaded functions or procedure choose which version to run based on the data types of the call parameters.
The key difference between overloading and selecting object types is simple. The first deals with choosing between different data types or object types. The second deals with choosing between object types in the same node tree.
You have two choices to demonstrate dynamic dispatch. One would use a SQL table or varray collection and the other would use column substitutability. Creating a table that uses substitutability seems the easiest approach.
The following creates a table of the base_t
object type:
SQL> CREATE TABLE dynamic 2 ( character_type BASE_T ); |
You can now insert a base_t
object type or any of the base_t
subtypes. The base_t_s
sequence is reset for the test case INSERT
statements:
SQL> INSERT INTO dynamic VALUES (base_t()); SQL> INSERT INTO dynamic VALUES (hobbit_t('Bilbo Baggins')); SQL> INSERT INTO dynamic VALUES (hobbit_t('Peregrin Took')); |
The following query uses a CASE
statement to identify whether the column returns a base_t
or hobbit_t
object type:
SQL> SELECT 2 CASE 3 WHEN TREAT(character_type AS hobbit_t) IS NOT NULL THEN 4 TREAT(character_type AS hobbit_t).to_string() 5 ELSE 6 TREAT(character_type AS base_t).to_string() 7 END AS "Text" 8 FROM dynamic; |
The query returns the following:
Text ----------------------- UID#: [3] Type: [BASE_T] UID#: [7] Type: [HOBBIT_T] Name: [Bilbo Baggins] UID#: [13] Type: [HOBBIT_T] Name: [Peregrin Took] |
The result set shows you that the character_type
column holds different types of the base_t
object type. It should also show you how you may store different result logs from DML row level triggers in a single table. Another article, I hope to write soon.
The unique identifier appears to increment three times with the first INSERT
statement and five times with subsequent inserts. Actually, each INSERT
statement increments the sequence five times. A debug statement would show you that it assigns the third call to the .NEXTVAL
pseudo column value to the obj_id
value. This is true for both the base_t
and hobbit_t
object type, and any other derived subtypes.
This article has shown you how to implement object types and subtypes. It also has explained how dynamic dispatch works and it provides a working example of dynamic dispatch leveraging column substitutability.
Type Getters & Setters
Object Types with Getters and Setters
This article is for you when you know the basics about how you work Oracle’s object types. It teaches you how to write effective getters, setters, comparators, and static methods. Please read my Object Types & Bodies Basic article if you’re not sure how to work with object types.
Getters access an object instance and return values from an instance variable. Along with getters, you have setters. Setters let you assign a new value to an instance variable. Formally, getters are accessor methods and setters are mutator methods. PL/SQL implements getters as functions and setters as procedures. After all a PL/SQL procedure is like a function that returns a void data type in Java.
The Object Types & Bodies Basic article introduces a people_obj
object type. This article extends the behavior of the people_obj
type. Extends is a funny word because it can have different meanings in object-oriented programming. Here, extends means to add functionality.
The first things we’ll add are getters and setters for all the attributes of the object instance. We need to add them to the object type and body because Oracle implements objects like it does packages. The object type defines the published functions and procedures. The object body implements the published functions and procedures.
Here’s the new people_obj
type with getters and setters:
SQL> CREATE OR REPLACE 2 TYPE people_obj IS OBJECT 3 ( people_id NUMBER 4 , first_name VARCHAR2(20) 5 , middle_name VARCHAR2(20) 6 , last_name VARCHAR2(20) 7 , CONSTRUCTOR FUNCTION people_obj RETURN SELF AS RESULT 8 , CONSTRUCTOR FUNCTION people_obj 9 ( first_name VARCHAR2 10 , middle_name VARCHAR2 DEFAULT NULL 11 , last_name VARCHAR2 ) RETURN SELF AS RESULT 12 , MEMBER FUNCTION get_people_id RETURN NUMBER 13 , MEMBER FUNCTION get_first_name RETURN VARCHAR2 14 , MEMBER FUNCTION get_middle_name RETURN VARCHAR2 15 , MEMBER FUNCTION get_last_name RETURN VARCHAR2 16 , MEMBER PROCEDURE set_first_name (pv_first_name VARCHAR2) 17 , MEMBER PROCEDURE set_middle_name (pv_first_name VARCHAR2) 18 , MEMBER PROCEDURE set_last_name (pv_first_name VARCHAR2)) 19 INSTANTIABLE NOT FINAL; 20 / |
The new getters and setters are on lines 12 through 18. The closing parenthesis for the list of attributes, functions, and procedures moves from line 11 to line 18. While there are four attributes in the people_obj
type and four getters for those attributes, there are only three setters. The reason for the difference is simple. The people_id
attribute is a unique identifier. You should never change the value of a unique identifier.
Next, lets implement the object body. I’m opting to show the complete object body because some readers may not check out the earlier article. Here’s the people_obj
body:
SQL> CREATE OR REPLACE 2 TYPE BODY people_obj IS 3 4 /* Default constructor. */ 5 CONSTRUCTOR FUNCTION people_obj RETURN SELF AS RESULT IS 6 7 /* Set a counter variable using a sequence. */ 8 lv_people_obj_s NUMBER := people_obj_s.NEXTVAL; 9 10 BEGIN 11 /* Assign a sequence value to the instance. */ 12 self.people_id := lv_people_obj_s; 13 14 /* Return a constructed instance. */ 15 RETURN; 16 END people_obj; 17 18 /* Override constructor. */ 19 CONSTRUCTOR FUNCTION people_obj 20 ( first_name VARCHAR2 21 , middle_name VARCHAR2 DEFAULT NULL 22 , last_name VARCHAR2 ) RETURN SELF AS RESULT IS 23 24 /* Create a empty default instance. */ 25 people PEOPLE_OBJ := people_obj(); 26 27 BEGIN 28 /* Create the instance with the default constructor. */ 29 people.first_name := first_name; 30 people.middle_name := middle_name; 31 people.last_name := last_name; 32 33 /* Assign a local instance this instance. */ 34 self := people; 35 36 /* Return the current instance. */ 37 RETURN; 38 END people_obj; 39 40 /* Get people ID attribute. */ 41 MEMBER FUNCTION get_people_id RETURN NUMBER IS 42 BEGIN 43 RETURN self.people_id; 44 END get_people_id; 45 46 /* Get first name attribute. */ 47 MEMBER FUNCTION get_first_name RETURN VARCHAR2 IS 48 BEGIN 49 RETURN self.first_name; 50 END get_first_name; 51 52 /* Get middle name attribute. */ 53 MEMBER FUNCTION get_middle_name RETURN VARCHAR2 IS 54 BEGIN 55 RETURN self.middle_name; 56 END get_middle_name; 57 58 /* Get last name attribute. */ 59 MEMBER FUNCTION get_last_name RETURN VARCHAR2 IS 60 BEGIN 61 RETURN self.last_name; 62 END get_last_name; 63 64 /* Set first name attribute. */ 65 MEMBER PROCEDURE set_first_name 66 ( pv_first_name VARCHAR2 ) IS 67 BEGIN 68 self.first_name := pv_first_name; 69 END set_first_name; 70 71 /* Set middle name attribute. */ 72 MEMBER PROCEDURE set_middle_name 73 ( pv_middle_name VARCHAR2 ) IS 74 BEGIN 75 self.middle_name := pv_middle_name; 76 END set_middle_name; 77 78 /* Set last name attribute. */ 79 MEMBER PROCEDURE set_last_name 80 ( pv_last_name VARCHAR2 ) IS 81 BEGIN 82 self.last_name := pv_last_name; 83 END set_last_name; 84 END; 85 / |
The get_people_id
member function on lines 41-44 returns the unique identifier for the object instance. The get_first_name
member function on lines 47-50 returns the first_name
attribute. The get_middle_name
member function on lines 53-56 returns the middle_name
attribute. The get_last_name
member function on lines 59-62 returns the last_name
attribute. Each of these getters returns an instance attribute. The self reserved word identifies the current instance of the object type.
The set_first_name
member procedure on lines 65-69 assigns a value to the first_name
attribute. The set_middle_name
procedure on lines 72-76 assigns a value to the middle_name
attribute. The set_last_name
member procedures on lines 79-83 assigns a value to the last_name
attribute. The constructor functions create instances of the people_obj
and return them to the calling scope. Each of these setters assigns a value to an instance attribute.
Comparative functions are limited to the MAP
and ORDER
member functions. The MAP
function only works with the CHAR
, DATE
, NUMBER
, or VARCHAR2
data type. You could implement a MAP
function against the last_name attribute but not the collection of the three variable length strings. You would implement an ORDER
member function to compare the collection of strings.
You can define an equals MAP
function in the people_obj
object type like:
SQL> CREATE OR REPLACE 2 TYPE people_obj IS OBJECT 3 ( people_id NUMBER ... 19 , MAP MEMBER FUNCTION equals RETURN VARCHAR2) 20 INSTANTIABLE NOT FINAL; 21 / |
After creating the people_obj
object type, you can implement the following MAP
function:
SQL> CREATE OR REPLACE 2 TYPE BODY people_obj IS ... 85 /* Implement an equals MAP function. */ 86 MAP MEMBER FUNCTION equals RETURN VARCHAR2 IS 87 BEGIN 88 RETURN self.last_name; 89 END equals; 90 91 END; 92 / |
The MAP
function is inadequate when you compare multiple attributes. You can implement an ORDER MEMBER
function with the following syntax in the people_obj
object type.
SQL> CREATE OR REPLACE 2 TYPE people_obj IS OBJECT 3 ( people_id NUMBER ... 19 , ORDER MEMBER FUNCTION equals 20 (pv_people PEOPLE_OBJ) RETURN NUMBER) 21 INSTANTIABLE NOT FINAL; 22 / |
The ORDER
function is more complete than the MAP
function. You can implement a last name, first name, and middle name ORDER
function as follows:
SQL> CREATE OR REPLACE 2 TYPE BODY people_obj IS ... 85 /* Implement an equals MAP function. */ 86 ORDER MEMBER FUNCTION equals 87 (pv_people PEOPLE_OBJ) RETURN NUMBER IS 88 BEGIN 89 IF NVL(self.last_name,'A') > NVL(pv_people.last_name,'A') THEN 90 RETURN 1; 91 ELSIF NVL(self.last_name,'A') = NVL(pv_people.last_name,'A') AND 92 NVL(self.first_name,'A') > NVL(pv_people.first_name,'A') THEN 93 RETURN 1; 94 ELSIF NVL(self.last_name,'A') = NVL(pv_people.last_name,'A') AND 95 NVL(self.first_name,'A') = NVL(pv_people.first_name,'A') AND 96 NVL(self.middle_name,'A') > NVL(pv_people.middle_name,'A') THEN 97 RETURN 1; 98 ELSE 99 RETURN 0; 100 END IF; 101 END equals; 102 END; 103 / |
The equals ORDER
function on lines 86 through 101 checks for a three conditions. First, it checks whether the instance’s last_name is greater than the parameter object’s last_name
. Second, it checks whether the last names are equal and the instance’s first_name is greater than the parameter object’s first_name
. Finally, it checks whether the last and first names are equal and the middle_name
is greater than the parameter object’s middle_name
value.
Unfortunately, it’s hard to test this comparison without adding a to_string
function. The to_string function prints the formatted name. You can add the to_string
function to the object type like so:
SQL> CREATE OR REPLACE 2 TYPE people_obj IS OBJECT 3 ( people_id NUMBER ... 19 , MAP MEMBER FUNCTION equals RETURN VARCHAR2 21 , MEMBER FUNCTION to_string RETURN VARCHAR2) 20 INSTANTIABLE NOT FINAL; 21 / |
Line 21 shows the declaration of the to_string
function, and the following code snippet shows you the implementation of the to_string
function:
SQL> CREATE OR REPLACE 2 TYPE BODY people_obj IS ... 103 /* Create a to_string function. */ 104 MEMBER FUNCTION to_string RETURN VARCHAR2 IS 105 BEGIN 106 RETURN self.last_name || ', ' || self.first_name || ' ' || 107 self.middle_name; 108 END to_string; 109 110 END; 111 / |
After assembling all the parts, we can test whether the ORDER
comparative function works. The following anonymous block program declares a people_list
collection that holds instances of the people_obj
object type.
SQL> DECLARE 2 /* Declare an object type. */ 3 TYPE people_list IS TABLE OF people_obj; 4 5 /* Declare three object types. */ 6 lv_obj1 PEOPLE_OBJ := people_obj('Fred',NULL,'Maher'); 7 lv_obj2 PEOPLE_OBJ := people_obj('John',NULL,'Fedele'); 8 lv_obj3 PEOPLE_OBJ := people_obj('James',NULL,'Fedele'); 9 lv_obj4 PEOPLE_OBJ := people_obj('James','Xavier','Fedele'); 10 11 /* Declare a list of the object type. */ 12 lv_objs PEOPLE_LIST := people_list( lv_obj1, lv_obj2 13 , lv_obj3, lv_obj4); 14 15 /* Swap A and B. */ 16 PROCEDURE swap 17 ( a IN OUT PEOPLE_OBJ 18 , b IN OUT PEOPLE_OBJ ) IS 19 /* Declare a third variable. */ 20 c PEOPLE_OBJ; 21 BEGIN 22 /* Swap values. */ 23 c := b; 24 b := a; 25 a := c; 26 END swap; 27 28 BEGIN 29 /* Nested loop comparison. */ 30 FOR i IN 1..lv_objs.COUNT LOOP 31 FOR j IN 1..lv_objs.COUNT LOOP 32 IF lv_objs(i).equals(lv_objs(j)) = 0 THEN 33 swap(lv_objs(i), lv_objs(j)); 34 END IF; 35 END LOOP; 36 END LOOP; 37 38 /* Print the reordered list. */ 39 FOR i IN 1..lv_objs.COUNT LOOP 40 dbms_output.put_line(lv_objs(i).to_string()); 41 END LOOP; 42 END; 43 / |
The people_obj
instances on lines 6 through 9 are out of order in the starting collection. The local swap procedure reorders them on lines 30 through 36. You would see the following output from the preceding anonymous block:
Fedele, James Fedele, James Xavier Fedele, John Maher, Fred |
All of our work in this paper so far shows you how to work with implementing functions and procedures in instances of object types. PL/SQL object types support MEMBER
functions and procedures to work with object instances. PL/SQL object types also support STATIC
functions and procedures. You use STATIC
functions and procedures when you want to write and call a module in an object type that works like a function or procedure in a package.
You can call a STATIC
function or procedure without creating an instance of an object. Creating an instance of the object type is a key use of STATIC
functions. This approach is very much like how Oracle implements temporary BLOB
and CLOB
columns.
Here’s the snippet of additional code required in the people_obj
object type:
SQL> CREATE OR REPLACE 2 TYPE people_obj IS OBJECT 3 ( people_id NUMBER ... 21 , MEMBER FUNCTION to_string RETURN VARCHAR2 22 , STATIC FUNCTION get_people_obj 23 ( pv_people_id NUMBER) RETURN people_obj) 20 INSTANTIABLE NOT FINAL; 21 / |
The get_people_obj
function is a STATIC
function and it takes a single number to return a name. It accomplishes this by using a parameterized cursor. You would implement the get_people_obj
function like so:
SQL> CREATE OR REPLACE 2 TYPE BODY people_obj IS ... 109 /* Create a get_people_obj function. */ 110 STATIC FUNCTION get_people_obj 111 ( pv_people_id NUMBER ) RETURN PEOPLE_OBJ IS 112 113 /* Implement a cursor. */ 114 CURSOR get_people_obj 115 ( cv_people_id NUMBER ) IS 116 SELECT first_name 117 , middle_name 118 , last_name 119 FROM contact 120 WHERE contact_id = cv_people_id; 121 122 /* Create a cursor variable. */ 123 lv_contact get_people_obj%ROWTYPE; 124 125 /* Create a temporary instance of people_obj. */ 126 lv_people_obj PEOPLE_OBJ; 127 BEGIN 128 /* Open, fetch and close cursor. */ 129 OPEN get_people_obj(pv_people_id); 130 FETCH get_people_obj INTO lv_contact; 131 lv_people_obj := people_obj( first_name => lv_contact.first_name 132 , middle_name => lv_contact.middle_name 133 , last_name => lv_contact.last_name); 134 CLOSE get_people_obj; 135 RETURN lv_people_obj; 136 END get_people_obj; 137 138 END; 139 / |
The get_people_obj
function takes a single numeric parameter. The numeric parameter passes the primary key value for the contact table. Then, the STATIC
function returns an instance of the people_obj
object type. It accomplishes that feat by using the numeric value as a lookup key in the contact
table, as you can see in the get_people_obj cursor on lines 114 through 120. The STATIC
method opens, fetches a single row, and closes on lines 129 through 135.
Now you can call the get_people_obj
function in a query and return an instance of people_obj
. You can also use the to_string
method to view the output, as follows:
SQL> SELECT people_obj.get_people_obj(1003).to_string() 2 FROM dual; |
It prints:
PEOPLE_OBJ.GET_PEOPLE_OBJ(1003).TO_STRING() --------------------------------------------- Vizquel, Oscar |
This article has shown you how to write effective getters, setters, comparators, and static methods. It also has shown how to test and work with Oracle object types and bodies.
Type & Body Basics
Object Types and Bodies Basics
Oracle Database 10g gave us a new way to write PL/SQL – object types. Object types are different from standard PL/SQL functions, procedures, and packages. While you can pin packages in memory, object types go one step further. You can instantiate them, which means you can start them, assign values to their variables, and put them into your PGA’s memory. Object types provide you with new challenges writing programs in the Oracle database.
Oracle Database 12c makes using object types simpler. That’s because Oracle Database 12c supports type evolution. Type evolution lets you change an object type when it has dependents. An object type’s dependents can be a table, another object type, function, procedure, or package. Oracle Database 12c also lets you white list the callers of an object type.
You define object types with variables and methods, like you define packages. Object type methods are either functions or procedures. You can implement object type functions and procedures as instance or static methods. An instance method works on the object type’s variable, whereas, static methods work like ordinary functions and procedures. That means static methods can’t access object type variables.
You learn how to define and implement basic object types and bodies in this article. This article shows you how to use and deploy objects and shows you how to implement the specialized CONSTRUCTOR
functions.
The following declares a basic people_obj
object type:
SQL> CREATE OR REPLACE 2 TYPE people_obj IS OBJECT 3 ( people_id NUMBER 4 , first_name VARCHAR2(20) 5 , middle_name VARCHAR2(20) 6 , last_name VARCHAR2(20)); 7 / |
The CREATE OR REPLACE
is SQL syntax creates an object type, like you would create a PL/SQL function, procedure, or package. Lines 2 through 6 declare a four element people_obj
object type, and the semicolon on line 6 acts as a statement terminator. The forward slash on line 7 executes the CREATE TYPE
statement.
To most developers the foregoing syntax appears to declare a record data structure. There’s more to it than that. The CREATE TYPE
syntax also creates an implicit constructor function. You can call the people_obj constructor with a list of parameter that matches both the list of element names and their data types. The call syntax supports both named and positional notation.
You can test the people_obj
object type with the following anonymous block:
SQL> DECLARE 2 people PEOPLE_OBJ := people_obj(1,'John','Paul','Jones'); 3 BEGIN 4 dbms_output.put_line( people.first_name || ' ' 5 ||people.middle_name || ' ' 6 ||people.last_name); 7 END; 8 / |
Line 2 declares a variable of the object type with positional notation, and then it assigns an instance of the people_obj
object type. On the right side of the assignment operator, a call to the constructor function creates an instance of the people_obj object type. Object construction has the highest order of precedence, which means it always creates the people_obj
instance first.
Lines 4 through 6 print the values of the first, middle, and last name elements. These values are the instance values held by the peoplevariable. It prints:
John Paul Jones |
The following example shows you how to call the default people_obj constructor with named notation:
SQL> DECLARE 2 people PEOPLE_OBJ := people_obj( first_name => 'John' 3 , middle_name => 'Paul' 4 , last_name => 'Jones' 5 , people_id => 2); 6 BEGIN ... 10 END; 11 / |
The named notation on lines 2 through 5 let us vary the order of the object attributes. Oracle raises the following exception if you pare the list of call parameters by removing one of them.
PLS-00306: wrong number or types of arguments in call to 'PEOPLE_OBJ' |
You can add one or more override constructor functions to the people_obj
object type. The first override constructor example has two call parameters, and they are the first_name
and last_name
parameters.
SQL> CREATE OR REPLACE 2 TYPE people_obj IS OBJECT 3 ( people_id NUMBER 4 , first_name VARCHAR2(20) 5 , middle_name VARCHAR2(20) 6 , last_name VARCHAR2(20) 7 , CONSTRUCTOR FUNCTION people_obj 8 ( first_name VARCHAR2 9 , last_name VARCHAR2 ) RETURN SELF AS RESULT) 10 INSTANTIABLE NOT FINAL; 11 / |
Lines 7 through 9 declare the override constructor function. This override constructor function doesn’t provide a value for the people_id
attribute. The concept of an object having a unique identifier, or ID, is part of good object-oriented design practices.
An Oracle sequence can help us guarantee the unique ID. You can create a people_obj_s
sequence for the people_obj with the following syntax:
SQL> CREATE SEQUENCE people_obj_s; |
You can use the people_obj_s
sequence in the override constructor to generate the unique ID. The following code implements the modified people_obj
object type:
SQL> CREATE OR REPLACE 2 TYPE BODY people_obj IS 3 CONSTRUCTOR FUNCTION people_obj 4 ( first_name VARCHAR2 5 , last_name VARCHAR2 ) RETURN SELF AS RESULT IS 6 7 /* Set a counter variable using a sequence. */ 8 lv_people_obj_s NUMBER := people_obj_s.NEXTVAL; 9 10 BEGIN 11 /* Create the instance with the default constructor. */ 12 self := people_obj( people_id => lv_people_obj_s 13 , first_name => first_name 14 , middle_name => NULL 15 , last_name => last_name ); 16 /* Return the current instance. */ 17 RETURN; 18 END people_obj; 19 END; 20 / |
Line 8 declares a local lv_people_obj_s
variable, and it assigns the next value from the people_obj_s
sequence. The local variable is necessary because you can’t put a call to the .NEXTVAL
pseudo column inside a call to an object type constructor function.
The self key word on line 12 represents the instance of an object. You call the default constructor on lines 12 through 15. The default constructor takes a local variable, two parameter values, and a null value.
You can test the new people_obj
with the following anonymous block:
SQL> DECLARE 2 people PEOPLE_OBJ := people_obj( first_name => 'John' 3 , last_name => 'Jones'); 4 BEGIN 5 dbms_output.put_line( '['|| people.people_id ||'] ' 6 ||'['|| people.first_name ||'] ' 7 ||'['|| people.middle_name ||'] ' 8 ||'['|| people.last_name ||']'); 9 END; 10 / |
It prints
[1] [John] [] [Jones] |
Clearly, the handling of the middle_name
attribute is suboptimal. Actually, it’s more or less a joke. However, it does give us an opportunity to show how to handle optional parameters in a constructor function.
You would change the people_obj
object type by adding a parameter to the override constructor function, like
SQL> CREATE OR REPLACE 2 TYPE people_obj IS OBJECT 3 ( people_id NUMBER 4 , first_name VARCHAR2(20) 5 , middle_name VARCHAR2(20) 6 , last_name VARCHAR2(20) 7 , CONSTRUCTOR FUNCTION people_obj 8 ( first_name VARCHAR2 9 , middle_name VARCHAR2 DEFAULT NULL 10 , last_name VARCHAR2 ) RETURN SELF AS RESULT) 11 INSTANTIABLE NOT FINAL; 12 / |
There are only two changes to the implementation of the people_obj
object body. One changes the list of parameters in the constructor function. The other replaces the null assignment with a parameter value from the overriding constructor function.
Here’s the implementation of the new people_obj
object body:
SQL> CREATE OR REPLACE 2 TYPE BODY people_obj IS 3 CONSTRUCTOR FUNCTION people_obj 4 ( first_name VARCHAR2 5 , middle_name VARCHAR2 DEFAULT NULL 6 , last_name VARCHAR2 ) RETURN SELF AS RESULT IS 7 8 /* Set a counter variable using a sequence. */ 9 lv_people_obj_s NUMBER := people_obj_s.NEXTVAL; 10 11 BEGIN 12 /* Create the instance with the default constructor. */ 13 self := people_obj( people_id => lv_people_obj_s 14 , first_name => first_name 15 , middle_name => middle_name 16 , last_name => last_name ); 17 /* Return the current instance. */ 18 RETURN; 19 END people_obj; 20 END; 21 / |
Line 5 specifies the middle_name parameter as an optional parameter. The optional parameter in the middle of the list can present a problem when you make call to it with positional notation. A call with named notation on the other hand works without a hitch. Line 15 replaces the null value with the middle_name parameter from the constructor function.
You can test the modified people_obj
with the following anonymous block:
SQL> DECLARE 2 people PEOPLE_OBJ := people_obj( first_name => 'John' 3 , last_name => 'Jones'); 4 5 BEGIN 6 dbms_output.put_line( '['|| people.people_id ||'] ' 7 ||'['|| people.first_name ||'] ' 8 ||'['|| people.middle_name ||'] ' 9 ||'['|| people.last_name ||']'); 10 END; 11 / |
It prints
[1] [John] [] [Jones] |
If you modify the constructor call on lines 2 through 4, as follows:
2 people PEOPLE_OBJ := people_obj( first_name => 'James' 3 , middle_name => 'Wilson' 4 , last_name => 'Jones'); |
It prints
[1] [John] [Wilson] [Jones] |
There are still several problems with the current people_obj
object type. The largest shortfall is that there’s no traditional default constructor. In many object-oriented language, a default constructor is a null argument constructor. A null argument constructor let’s you position logic that all other constructors can leverage.
A sequence value is an example of logic that you can share across constructor functions. The following version of the people_obj
object type declares a standard no argument constructor function:
SQL> CREATE OR REPLACE 2 TYPE people_obj IS OBJECT 3 ( people_id NUMBER 4 , first_name VARCHAR2(20) 5 , middle_name VARCHAR2(20) 6 , last_name VARCHAR2(20) 7 , CONSTRUCTOR FUNCTION people_obj RETURN SELF AS RESULT 8 , CONSTRUCTOR FUNCTION people_obj 9 ( first_name VARCHAR2 10 , middle_name VARCHAR2 DEFAULT NULL 11 , last_name VARCHAR2 ) RETURN SELF AS RESULT) 12 INSTANTIABLE NOT FINAL; 13 / |
Line 7 holds the declaration of a no argument constructor. The following people_obj
object type implements a no argument constructor. The object body also makes access to the sequence a feature available to all overriding constructors.
SQL> CREATE OR REPLACE 2 TYPE BODY people_obj IS 3 4 /* Default constructor. */ 5 CONSTRUCTOR FUNCTION people_obj RETURN SELF AS RESULT IS 6 7 /* Set a counter variable using a sequence. */ 8 lv_people_obj_s NUMBER := people_obj_s.NEXTVAL; 9 10 BEGIN 11 /* Assign a sequence value to the instance. */ 12 self.people_id := lv_people_obj_s; 13 14 /* Return a constructed instance. */ 15 RETURN; 16 END; 17 18 /* Override constructor. */ 19 CONSTRUCTOR FUNCTION people_obj 20 ( first_name VARCHAR2 21 , middle_name VARCHAR2 DEFAULT NULL 22 , last_name VARCHAR2 ) RETURN SELF AS RESULT IS 23 24 /* Create a empty default instance. */ 25 people PEOPLE_OBJ := people_obj(); 26 27 BEGIN 28 /* Create the instance with the default constructor. */ 29 people.first_name := first_name; 30 people.middle_name := middle_name; 31 people.last_name := last_name; 32 33 /* Assign a local instance this instance. */ 34 self := people; 35 36 /* Return the current instance. */ 37 RETURN; 38 END people_obj; 39 END; 40 / |
The implementation of the no argument constructor is on lines 5 through 16. It uses the .NEXTVAL
pseudo column to secure the next sequence value as a unique ID. Then, the constructor function returns a uniquely identified but otherwise empty object instance.
Line 25 creates a people_obj
instance inside the declaration block of the overriding constructor. Inside the execution block, the overriding parameters are assigned to the attributes of the local instance. Ultimately, the local instance is assigned to the current instance and returned to any caller of the overriding constructor.
You call the modified overriding function with the following anonymous block:
SQL> DECLARE 2 people PEOPLE_OBJ := people_obj( first_name => 'Samuel' 3 , middle_name => 'Langhorne' 4 , last_name => 'Clemens'); 5 BEGIN 6 dbms_output.put_line( '['|| people.people_id ||'] ' 7 ||'['|| people.first_name ||'] ' 8 ||'['|| people.middle_name ||'] ' 9 ||'['|| people.last_name ||']'); 10 END; 11 / |
It prints
[3] [Samuel] [Langhorne] [Clemens] |
This article has shown you how to define and implement basic object types and bodies. It also has shown you how to work with default, no argument, and overriding constructor functions.
Preprocessing External Tables
A question that comes up now and again is there a way in Oracle Database 11g Express Edition to mimic some behavior in the Oracle Standard or Enterprise editions. Many of these questions arise because developers want to migrate a behavior they’ve implemented in Java to the Express Edition. Sometimes the answer is no but many times the answer is yes. The yes answers come with a how.
This article answers the question: “How can I read an operating systems’ file directory with out an embedded Java Virtual Machine (JVM)?” These developers have read or implemented logic like that found in my earlier “Using DBMS_JAVA
to Read External Files” article. The answer is simple. You need to use a preprocessing script inside an external table. That’s what you will learn in this article, but if you’re not familiar with external tables you should read this other “External Tables” article.
External tables let you access plain text files with SQL*Loader or Oracle’s proprietary Data Pump files. You typically create external tables with Oracle Data Pump when you’re moving large data sets between database instances.
External tables use Oracle’s virtual directories. An Oracle virtual directory is an internal reference in the data dictionary. A virtual directory maps a unique directory name to a physical directory on the local operating system. Virtual directories were simple before Oracle Database 12c gave us the multitenant architecture. In a multitenant database there are two types of virtual directories. One services the schemas of the Container Database (CDB) and it’s in the CDB’s SYS
schema. The other services the schemas of a Pluggable Database (PDB) and it’s in the ADMIN
schema for the PDB.
You can create a CDB virtual database as SYSTEM
user with the following syntax in Windows:
SQL> CREATE DIRECTORY upload AS 'C:\Data\Upload'; |
or, like this in Linux or Unix:
SQL> CREATE DIRECTORY upload AS '/u01/app/oracle'; |
There are some subtle differences between these two statements. Windows directories or folders start with a logical drive letter, like C:\
, D:\, and so forth. Linux and Unix directories start with a mount point like /u01.
As you can read in the “External Tables” article, you need to change the ownership of external files and directories to the oracle user and, default, oracle user’s default dba group. Likewise, you should change the privilege of the containing directory to 755 (owner has read, write, and execute privileges; and group and others have read and execute privileges.
The balance of this article is broken into two pieces configuring a working external table with preprocessing and troubleshooting cartridge errors.
External Tables with Preprocessing Example
There are xxx database steps to creating this example. The first database step requires you create three virtual directories. The syntax for the three statements is:
SQL> CREATE DIRECTORY upload AS '/u01/app/oracle/upload'; SQL> CREATE DIRECTORY LOG AS '/u01/app/oracle/log'; SQL> CREATE DIRECTORY preproc AS '/u01/app/oracle/preproc'; |
The upload
directory hosts the files you want to discover for upload. The log
directory hosts the log files for the external tables. The preproc
directory hosts the executable program, which generates a list of files currently in the upload
directory.
After creating the virtual directories or before creating them, you should create the physical directories in the Linux operating system. The virtual directories can only point to something when it actually exists. Moreover, they work like Oracle’s synonyms that point to other objects in the database. The physical files need to be in a directory tree that is navigable by the oracle user and the oracle user and it’s default primary dba group needs to own them.
You can use the following command to change ownership when you’re the root
user:
# chown –R oracle:dba /u01/app/oracle |
The second database step requires that you grant privileges on the virtual directories to the student
user. You can do that with the following syntax:
SQL> GRANT read ON DIRECTORY upload; SQL> GRANT read, WRITE ON DIRECTORY LOG; SQL> GRANT read, EXECUTE ON DIRECTORY preproc; |
The upload
directory requires read-only privileges. The log
directory requires read and write privileges. The read privileges let it find files and the write privilege lets it append to log files when they already exist. The preproc
directory requires read and execute privileges. The read privilege is the same as that explained earlier. The execute privilege lets you run the preprocessing program file.
The third database step requires creating an external file with preprocessing. The following script creates the sample table:
SQL> CREATE TABLE directory_list 2 ( file_name VARCHAR2(60)) 3 ORGANIZATION EXTERNAL 4 ( TYPE oracle_loader 5 DEFAULT DIRECTORY preproc 6 ACCESS PARAMETERS 7 ( RECORDS DELIMITED BY NEWLINE CHARACTERSET US7ASCII 8 PREPROCESSOR preproc:'list2dir.sh' 9 BADFILE 'LOG':'dir.bad' 10 DISCARDFILE 'LOG':'dir.dis' 11 LOGFILE 'LOG':'dir.log' 12 FIELDS TERMINATED BY ',' 13 OPTIONALLY ENCLOSED BY "'" 14 MISSING FIELD VALUES ARE NULL) 15 LOCATION ('list2dir.sh')) 16 REJECT LIMIT UNLIMITED; |
Line 5 designates the default directory as preproc because the location of the executable file should be in the preproc directory. Line 8 designates that there is a preprocessing step, and it identifies the virtual directory and physical file name inside single quotes. Line 15 identifies the source file for the external table, which is an executable program.
Next, you need to create the bash
file to get and return a directory list. Before you write that file, you need to understand that preprocessing script files don’t inherit a $PATH
environment variable from Oracle.
That probably means you might have tried to create a simple bash
shell command like the following in a list2dir.sh
file.
ls /u01/app/oracle/upload | find . -type f | ls *csv | sed -e 's/\.\///' |
When you test this file by calling it from SQL, like this:
SQL> SELECT * FROM directory_list; |
It raises the following exception stack:
SELECT * FROM directory_list * ERROR AT line 1: ORA-29913: error IN executing ODCIEXTTABLEFETCH callout ORA-29400: data cartridge error KUP-04095: preprocessor command /u01/app/oracle/preprocess/list2dir.sh encountered error "/u01/app/oracle/preprocess/list2dir.sh: line 1: ls: No such file or directory |
The reason isn’t immediately clear to some developers. The significant error is:
ls: No such file or directory |
The error message indicates that a call through Oracle’s OCI call interface cannot find the location of the ls
program. That occurs because there is no $PATH
variable set a list of values that points to the /usr/bin
directory where you find the ls
program. You need to prepend /usr/bin before the ls
, find
, and sed
programs.
/usr/bin/ls /u01/app/oracle/upload | /usr/bin/find . -type f | /usr/bin/ls *csv | /usr/bin/sed -e 's/\.\///' |
Create a list2dir.sh
file in the /u01/app/oracle/preproc
directory with the preceding command line. Then, make sure oracle is the owner with a primary dba
group and the privileges are 755 on the file. The command to set the privileges is:
# chmod –R 755 /u01/app/oracle/preproc.sh |
Having completed that Linux operating system step you should probably put some files in the upload directory. You can create empty files with the touch command at the linux command line for this example.
The fourth database step lets you query the external table, which runs the preprocessing program and returns its results as values in the table:
SQL> CREATE * FROM directory_list; |
It should return something like this:
FILE_NAME ------------------------------ character.csv transaction_upload2.csv transaction_upload.csv |
As always, this is written to help those solve problems.
External Tables
Oracle Database 9i introduced external tables. You can create external tables to load plain text files by using Oracle SQL*Loader. Alternatively, you can create external tables that load and unload files by using Oracle Data Pump. This article demonstrates both techniques.
You choose external tables that use Oracle SQL*Loader when you want to import plain text files. There are three types of plain text files. They are comma-separated value (CSV), tab-separated value (TSV), and position specific text files.
External tables that use Oracle Data Pump don’t work with plain text files. They work with an Oracle proprietary format. That means you load source files previously created by an Oracle Data Pump export. You typically create external tables with Oracle Data Pump when you’re moving large data sets between database instances.
External tables use Oracle’s virtual directories. An Oracle virtual directory is an internal reference in the data dictionary. A virtual directory maps a unique directory name to a physical directory on the local operating system. Virtual directories were simple before Oracle Database 12c gave us the multitenant architecture. In a multitenant database there are two types of virtual directories. One services the schemas of the Container Database (CDB) and it’s in the CDB’s SYS
schema. The other services the schemas of a Pluggable Database (PDB) and it’s in the ADMIN
schema for the PDB.
You can create a CDB virtual directory as SYSTEM
user with the following syntax in Windows:
SQL> CREATE DIRECTORY upload AS 'C:\Data\Upload'; |
or, like this in Linux or Unix:
SQL> CREATE DIRECTORY upload AS '/u01/app/oracle'; |
There are some subtle differences between these two statements. Windows directories or folders start with a logical drive letter, like C:\
, D:\
, and so forth. Linux and Unix directories start with a mount point like /u01
.
One of the subtle differences is directory and file ownership. You can change ownership for a directory in Windows as the Administrator account. The change makes the directory publically accessible, and that’s probably fine for a test database. After such a change, the Oracle user can find the external file even when parent directories aren’t navigable. Although, a production database on Windows would requires more skill at setting and restricting file permissions.
Linux and Unix directories require that the oracle user can navigate the tree from the mount point to the target physical directory. Also, you must designate the ownership of external files as the same as the Oracle Database user. Assuming a standard install of the Oracle Database 11g XE instance, you would issue the following shell command as the root
user to change file ownership and access privileges:
# chown –R oracle:dba /u01/app/oracle/upload # chmod –R 755 /u01/app/oracle/upload |
After you create the virtual directory, you must grant privileges or a role to the user that defines the external table. While data and log files should be separated, this example assumes they co-exist in the same directory.
The following statement grants read privilege for the data file and write privileges for the log files to a CDB user. You should run this statement as the system
user.
SQL> GRANT read, WRITE ON DIRECTORY upload TO c##importer; |
or, like this in non-multitenant database or PDB user:
SQL> GRANT read, WRITE ON DIRECTORY upload TO importer; |
The last preparation steps require a plain text file in the physical directory. Let’s create a CSV file of key Avenger characters, and name it the avenger.csv
file.
The avenger.csv file holds the following values:
1,'Anthony','Stark','Iron Man' 2,'Thor','Odinson','God of Thunder' 3,'Steven','Rogers','Captain America' 4,'Bruce','Banner','Hulk' 5,'Clinton','Barton','Hawkeye' 6,'Natasha','Romanoff','Black Widow' |
You create the external table after creating the virtual directory, granting read and write privileges on the virtual directory, and creating an external physical file. The syntax for the CREATE TABLE
statement of an external table is very similar to the syntax of an ordinary table. The difference between the two types of tables is a clause. An internal table has a STORAGE
clause, while an external table has an ORGANIZATION EXTERNAL
clause.
The following creates the avenger table as an external table:
SQL> CREATE TABLE avenger 2 ( avenger_id NUMBER 3 , first_name VARCHAR2(20) 4 , last_name VARCHAR2(20) 5 , character_name VARCHAR2(20)) 6 ORGANIZATION EXTERNAL 7 ( TYPE oracle_loader 8 DEFAULT DIRECTORY upload 9 ACCESS PARAMETERS 10 ( RECORDS DELIMITED BY NEWLINE CHARACTERSET US7ASCII 11 BADFILE 'UPLOAD':'avenger.bad' 12 DISCARDFILE 'UPLOAD':'avenger.dis' 13 LOGFILE 'UPLOAD':'avenger.log' 14 FIELDS TERMINATED BY ',' 15 OPTIONALLY ENCLOSED BY "'" 16 MISSING FIELD VALUES ARE NULL) 17 LOCATION ('avenger.csv')) 18 REJECT LIMIT UNLIMITED; |
Lines 1 through 5 create the columns of the avenger table. Lines 6 through 17 contain the ORGANIZATION EXTERNAL
clause. Line 7 designates the external table as managed by the Oracle SQL*Loader utility. Line 8 sets the default virtual directory. Lines 11 through 12 set the bad, discard, and log file location. The bad and discard files keep all that can’t be read. The log file keeps all rows read by a query against the avenger table.
You also have the option of making all reads automatic parallel. You simply add a PARALLEL
clause, like this:
19 PARALLEL; |
A simple query with SQL*Plus formatting lets us test whether the avenger table works. The query to display all columns of all rows is:
SQL> COLUMN first_name FORMAT A10 SQL> COLUMN last_name FORMAT A10 SQL> COLUMN character_name FORMAT A15 SQL> SELECT * FROM avenger; |
Yields the following formatted output:
AVENGER_ID FIRST_NAME LAST_NAME CHARACTER_NAME ---------- ---------- ---------- --------------- 1 Anthony Stark Iron Man 2 Thor Odinson God of Thunder 3 Steven Rogers Captain America 4 Bruce Banner Hulk 5 Clinton Barton Hawkeye 6 Natasha Romanoff Black Widow 6 rows selected. |
It’s possible to redefine the avenger table to use either relative or fixed positional columns. You change the ACCESS PARAMETERS
clause on lines 9 through 16 to make this change.
The following ACCESS PARAMETERS
clause runs across lines 9 through 19 and creates relative position definition:
9 ACCESS PARAMETERS 10 ( RECORDS DELIMITED BY NEWLINE CHARACTERSET US7ASCII 11 BADFILE 'UPLOAD':'avenger.bad' 12 DISCARDFILE 'UPLOAD':'avenger.dis' 13 LOGFILE 'UPLOAD':'avenger.log' 14 FIELDS 15 MISSING FIELD VALUES ARE NULL 16 ( avenger_id CHAR(4) 17 , first_name CHAR(20) 18 , last_name CHAR(20) 19 , character_name CHAR(4))) |
You can change from the relative position, to a fixed position by changing lines 16 through 19. The change for fixed length strings is:
16 ( avenger_id POSITION 1:4 17 , first_name POSITION 5:24 18 , last_name POSITION 25:44 19 , character_name POSITION 45:64)) |
Having worked with the Oracle SQL*Loader version of external tables, lets create one that uses Oracle Data Pump. Assuming we keep the same data structure, drop the avenger table, and create a catalog managed avenger_internal
table.
This statement creates the avenger_internal
table:
SQL> CREATE TABLE avenger_internal 2 ( avenger_id NUMBER 3 , first_name VARCHAR2(20) 4 , last_name VARCHAR2(20) 5 , character_name VARCHAR2(20)); |
To avoid writing six INSERT
statements, you can write one INSERT
statement with a query against the SQL*Loader avenger table. The syntax for that INSERT
statement is:
SQL> INSERT INTO avenger_internal 2 SELECT * FROM avenger; |
With an internally managed table, you create an avenger_export
table that uses Oracle Data Pump like this:
SQL> CREATE TABLE avenger_export 2 ORGANIZATION EXTERNAL 3 ( TYPE oracle_datapump 4 DEFAULT DIRECTORY upload 5 LOCATION ('avenger_export.dmp')) AS 6 SELECT avenger_id 7 , first_name 8 , last_name 9 , character_name 10 FROM avenger_internal; |
The CREATE TABLE
statement exports data to the avenger_export.dmp
file immediately. You must drop and recreate the avenger_export
table to get a fresh extract of the avenger_internal
table’s data. You must also remove the previous avenger_export.dmp
file before you try to recreate the avenger_export
table.
You raise the following error when you fail to remove the previous export file:
CREATE TABLE avenger_export * ERROR AT line 1: ORA-29913: error IN executing ODCIEXTTABLEOPEN callout ORA-29400: data cartridge error KUP-11012: FILE avenger_export.dmp IN /u01/... already EXISTS |
This is a simple example with only four columns. You might think you can use the SELECT *
as the SELECT
-list of the query on lines 6 through 10. If you’re running Oracle Database 12c, you can use the shorter syntax, but if you’re running Oracle Database 11g you can’t. If you attempt it in an Oracle Database 11g instance, the CREATE TABLE
statement returns the following error:
ERROR at line 6:
ORA-30656: COLUMN TYPE NOT supported ON external organized TABLE |
You create an avenger_import table with another twist on this now familiar Oracle SQL syntax. The CREATE TABLE
statement is:
SQL> CREATE TABLE avenger_import 2 ( avenger_id NUMBER 3 , first_name VARCHAR2(20) 4 , last_name VARCHAR2(20) 5 , character_name VARCHAR2(20)) 6 ORGANIZATION EXTERNAL 7 ( TYPE oracle_datapump 8 DEFAULT DIRECTORY up2load 9 LOCATION ('avenger_export.dmp')); |
Like the export process, the import process happens immediately when the CREATE TABLE
statement runs. A query against the avenger_import table would show you the original six rows we started with in the plain text files.
This article has introduced Oracle external tables. It has shown you how to import plain text files with SQL*Loader. It has also shown you how to export files from tables.