What is PL/SQL and what is it used for?
SQL is a declarative language that allows database programmers to write a SQL declaration and hand it to the database for execution. As such, SQL cannot be used to execute procedural code with conditional, iterative and sequential statements. To overcome this limitation, PL/SQL was created.
PL/SQL is Oracle's Procedural Language extension to SQL. PL/SQL's language syntax, structure and data types are similar to that of Ada. Some of the statements provided by PL/SQL:
Conditional Control Statements:
- IF ... THEN ... ELSIF ... THEN ... ELSE ... END IF;
- CASE ... WHEN ... THEN ... ELSE ... END CASE;
Iterative Statements:
- LOOP ... END LOOP;
- WHILE ... LOOP ... END LOOP;
- FOR ... IN [REVERSE] ... LOOP ... END LOOP;
Sequential Control Statements:
- GOTO ...;
- NULL;
The PL/SQL language includes object oriented programming techniques such as encapsulation, function overloading, information hiding (all but inheritance).
PL/SQL is commonly used to write data-centric programs to manipulate data in an Oracle database.
Example PL/SQL blocks:
/* Remember to SET SERVEROUTPUT ON to see the output */
BEGIN
DBMS_OUTPUT.PUT_LINE('Hello World');
END;
/
BEGIN
-- A PL/SQL cursor
FOR cursor1 IN (SELECT * FROM table1) -- This is an embedded SQL statement
LOOP
DBMS_OUTPUT.PUT_LINE('Column 1 = ' || cursor1.column1 ||
', Column 2 = ' || cursor1.column2);
END LOOP;
END;
/
What is the difference between SQL and PL/SQL?
Both SQL and PL/SQL are languages used to access data within Oracle databases.
SQL is a limited language that allows you to directly interact with the database. You can write queries (SELECT), manipulate objects (DDL) and data (DML) with SQL. However, SQL doesn't include all the things that normal programming languages have, such as loops and IF...THEN...ELSE statements.
PL/SQL is a normal programming language that includes all the features of most other programming languages. But, it has one thing that other programming languages don't have: the ability to easily integrate with SQL.
Some of the differences:
- SQL is executed one statement at a time. PL/SQL is executed as a block of code.
- SQL tells the database what to do (declarative), not how to do it. In contrast, PL/SQL tell the database how to do things (procedural).
- SQL is used to code queries, DML and DDL statements. PL/SQL is used to code program blocks, triggers, functions, procedures and packages.
- You can embed SQL in a PL/SQL program, but you cannot embed PL/SQL within a SQL statement.
Should one use PL/SQL or Java to code procedures and triggers?
Both PL/SQL and Java can be used to create Oracle stored procedures and triggers. This often leads to questions like "Which of the two is the best?" and "Will Oracle ever desupport PL/SQL in favour of Java?".
Many Oracle applications are based on PL/SQL and it would be difficult of Oracle to ever desupport PL/SQL. In fact, all indications are that PL/SQL still has a bright future ahead of it. Many enhancements are still being made to PL/SQL. For example, Oracle 9i supports native compilation of PL/SQL code to binaries. Not to mention the numerous PL/SQL enhancements made in Oracle 10g and 11g.
PL/SQL and Java appeal to different people in different job roles. The following table briefly describes the similarities and difference between these two language environments:
PL/SQL:
- Can be used to create Oracle packages, procedures and triggers
- Data centric and tightly integrated into the database
- Proprietary to Oracle and difficult to port to other database systems
- Data manipulation is slightly faster in PL/SQL than in Java
- PL/SQL is a traditional procedural programming language
Java:
- Can be used to create Oracle packages, procedures and triggers
- Open standard, not proprietary to Oracle
- Incurs some data conversion overhead between the Database and Java type
- Java is an Object Orientated language, and modules are structured into classes
- Java can be used to produce complete applications
PS: Starting with Oracle 10g, .NET procedures can also be stored within the database (Windows only). Nevertheless, unlike PL/SQL and JAVA, .NET code is not usable on non-Windows systems.
PS: In earlier releases of Oracle it was better to put as much code as possible in procedures rather than triggers. At that stage procedures executed faster than triggers as triggers had to be re-compiled every time before executed (unless cached). In more recent releases both triggers and procedures are compiled when created (stored p-code) and one can add as much code as one likes in either procedures or triggers. However, it is still considered a best practice to put as much of your program logic as possible into packages, rather than triggers.
How can one see if somebody modified any code?
The source code for stored procedures, functions and packages are stored in the Oracle Data Dictionary. One can detect code changes by looking at the TIMESTAMP and LAST_DDL_TIME column in the USER_OBJECTS dictionary view. Example:
SELECT OBJECT_NAME,
TO_CHAR(CREATED, 'DD-Mon-RR HH24:MI') CREATE_TIME,
TO_CHAR(LAST_DDL_TIME, 'DD-Mon-RR HH24:MI') MOD_TIME,
STATUS
FROM USER_OBJECTS
WHERE LAST_DDL_TIME > '&CHECK_FROM_DATE';
Note: If you recompile an object, the LAST_DDL_TIME column is updated, but the TIMESTAMP column is not updated. If you modified the code, both the TIMESTAMP and LAST_DDL_TIME columns are updated.
How can one search PL/SQL code for a string/ key value?
The following query is handy if you want to know where certain tables, columns and expressions are referenced in your PL/SQL source code.
SELECT type, name, line
FROM user_source
WHERE UPPER(text) LIKE UPPER('%&KEYWORD%');
If you run the above query from SQL*Plus, enter the string you are searching for when prompted for KEYWORD. If not, replace &KEYWORD with the string you are searching for.
How does one keep a history of PL/SQL code changes?
One can build a history of PL/SQL code changes by setting up an AFTER CREATE schema (or database) level trigger (available from Oracle 8.1.7). This will allow you to easily revert to previous code should someone make any catastrophic changes. Look at this example:
CREATE TABLE SOURCE_HIST -- Create history table
AS SELECT SYSDATE CHANGE_DATE, ALL_SOURCE.*
FROM ALL_SOURCE WHERE 1=2;
CREATE OR REPLACE TRIGGER change_hist -- Store code in hist table
AFTER CREATE ON SCOTT.SCHEMA -- Change SCOTT to your schema name
DECLARE
BEGIN
IF ORA_DICT_OBJ_TYPE in ('PROCEDURE', 'FUNCTION',
'PACKAGE', 'PACKAGE BODY',
'TYPE', 'TYPE BODY')
THEN
-- Store old code in SOURCE_HIST table
INSERT INTO SOURCE_HIST
SELECT sysdate, all_source.* FROM ALL_SOURCE
WHERE TYPE = ORA_DICT_OBJ_TYPE -- DICTIONARY_OBJ_TYPE IN 8i
AND NAME = ORA_DICT_OBJ_NAME; -- DICTIONARY_OBJ_NAME IN 8i
END IF;
EXCEPTION
WHEN OTHERS THEN
raise_application_error(-20000, SQLERRM);
END;
/
show errors
A better approach is to create an external CVS or SVN repository for the scripts that install the PL/SQL code. The canonical version of what's in the database must match the latest CVS/SVN version or else someone would be cheating.
How can I protect my PL/SQL source code?
Oracle provides a binary wrapper utility that can be used to scramble PL/SQL source code. This utility was introduced in Oracle7.2 (PL/SQL V2.2) and is located in the ORACLE_HOME/bin directory.
The utility use human-readable PL/SQL source code as input, and writes out portable binary object code (somewhat larger than the original). The binary code can be distributed without fear of exposing your proprietary algorithms and methods. Oracle will still understand and know how to execute the code. Just be careful, there is no "decode" command available. So, don't lose your source!
The syntax is:
wrap iname=myscript.pls oname=xxxx.plb
Please note: there is no legal way to unwrap a *.plb binary file. You are supposed to backup and keep your *.pls source files after wrapping them. However it is possible for skilled hackers to unwrap your wrapped Oracle PL/SQL code.
How can I know which stored PL/SQL code is wrapped?
The following query gives the list of all wrapped PL/SQL code:
select owner, name, type
from dba_source
where line = 1
and instr(text, ' wrapped'||chr(10))+instr(text, ' wrapped '||chr(10)) > 0
order by 1, 2, 3
/
Can one print to the screen from PL/SQL?
One can use the DBMS_OUTPUT package to write information to an output buffer. This buffer can be displayed on the screen from SQL*Plus if you issue the SET SERVEROUTPUT ON; command. For example:
set serveroutput on
begin
dbms_output.put_line('Look Ma, I can print from PL/SQL!!!');
end;
/
DBMS_OUTPUT is useful for debugging PL/SQL programs. However, if you print too much, the output buffer will overflow. In that case, set the buffer size to a larger value, eg.: set serveroutput on size 200000
If you forget to set serveroutput on type SET SERVEROUTPUT ON once you remember, and then EXEC NULL;. If you haven't cleared the DBMS_OUTPUT buffer with the disable or enable procedure, SQL*Plus will display the entire contents of the buffer when it executes this dummy PL/SQL block.
To display an empty line, it is better to use new_line procedure than put_line with an empty string.
Can one read/write files from PL/SQL?
The UTL_FILE database package can be used to read and write operating system files.
A DBA user needs to grant you access to read from/ write to a specific directory before using this package. Here is an example:
CONNECT / AS SYSDBA
CREATE OR REPLACE DIRECTORY mydir AS '/tmp';
GRANT read, write ON DIRECTORY mydir TO scott;
Provide user access to the UTL_FILE package (created by catproc.sql):
GRANT EXECUTE ON UTL_FILE TO scott;
Copy and paste these examples to get you started:
Write File
DECLARE
fHandler UTL_FILE.FILE_TYPE;
BEGIN
fHandler := UTL_FILE.FOPEN('MYDIR', 'myfile', 'w');
UTL_FILE.PUTF(fHandler, 'Look ma, Im writing to a file!!!\n');
UTL_FILE.FCLOSE(fHandler);
EXCEPTION
WHEN utl_file.invalid_path THEN
raise_application_error(-20000, 'Invalid path. Create directory or set UTL_FILE_DIR.');
END;
/
Read File
DECLARE
fHandler UTL_FILE.FILE_TYPE;
buf varchar2(4000);
BEGIN
fHandler := UTL_FILE.FOPEN('MYDIR', 'myfile', 'r');
UTL_FILE.GET_LINE(fHandler, buf);
dbms_output.put_line('DATA FROM FILE: '||buf);
UTL_FILE.FCLOSE(fHandler);
EXCEPTION
WHEN utl_file.invalid_path THEN
raise_application_error(-20000, 'Invalid path. Create directory or set UTL_FILE_DIR.');
END;
/
NOTE: UTL_FILE was introduced with Oracle 7.3. Before Oracle 7.3 the only means of writing a file was to use DBMS_OUTPUT with the SQL*Plus SPOOL command.
Can one call DDL statements from PL/SQL?
One can call DDL statements like CREATE, DROP, TRUNCATE, etc. from PL/SQL by using the "EXECUTE IMMEDIATE" statement (native SQL). Examples:
begin
EXECUTE IMMEDIATE 'CREATE TABLE X(A DATE)';
end;
begin execute Immediate 'TRUNCATE TABLE emp'; end;
DECLARE
var VARCHAR2(100);
BEGIN
var := 'CREATE TABLE temp1(col1 NUMBER(2))';
EXECUTE IMMEDIATE var;
END;
NOTE: The DDL statement in quotes should not be terminated with a semicolon.
Users running Oracle versions below Oracle 8i can look at the DBMS_SQL package (see FAQ about Dynamic SQL).
Can one use dynamic SQL statements from PL/SQL?
Starting from Oracle8i one can use the "EXECUTE IMMEDIATE" statement to execute dynamic SQL and PL/SQL statements (statements created at run-time). Look at these examples. Note that the statements within quotes are NOT semicolon terminated:
EXECUTE IMMEDIATE 'CREATE TABLE x (a NUMBER)';
-- Using bind variables...'
sql_stmt := 'INSERT INTO dept VALUES (:1, :2, :3)';
EXECUTE IMMEDIATE sql_stmt USING dept_id, dept_name, location;
-- Returning a cursor...
sql_stmt := 'SELECT * FROM emp WHERE empno = :id';
EXECUTE IMMEDIATE sql_stmt INTO emp_rec USING emp_id;
One can also use the older DBMS_SQL package (V2.1 and above) to execute dynamic statements. Look at these examples:
CREATE OR REPLACE PROCEDURE DYNSQL AS
cur integer;
rc integer;
BEGIN
cur := DBMS_SQL.OPEN_CURSOR;
DBMS_SQL.PARSE(cur, 'CREATE TABLE X (Y DATE)', DBMS_SQL.NATIVE);
rc := DBMS_SQL.EXECUTE(cur);
DBMS_SQL.CLOSE_CURSOR(cur);
END;
/
More complex DBMS_SQL example using bind variables:
CREATE OR REPLACE PROCEDURE DEPARTMENTS(NO IN DEPT.DEPTNO%TYPE) AS
v_cursor integer;
v_dname char(20);
v_rows integer;
BEGIN
v_cursor := DBMS_SQL.OPEN_CURSOR;
DBMS_SQL.PARSE(v_cursor, 'select dname from dept where deptno > :x', DBMS_SQL.V7);
DBMS_SQL.BIND_VARIABLE(v_cursor, ':x', no);
DBMS_SQL.DEFINE_COLUMN_CHAR(v_cursor, 1, v_dname, 20);
v_rows := DBMS_SQL.EXECUTE(v_cursor);
loop
if DBMS_SQL.FETCH_ROWS(v_cursor) = 0 then
exit;
end if;
DBMS_SQL.COLUMN_VALUE_CHAR(v_cursor, 1, v_dname);
DBMS_OUTPUT.PUT_LINE('Deptartment name: '||v_dname);
end loop;
DBMS_SQL.CLOSE_CURSOR(v_cursor);
EXCEPTION
when others then
DBMS_SQL.CLOSE_CURSOR(v_cursor);
raise_application_error(-20000, 'Unknown Exception Raised: '||sqlcode||' '||sqlerrm);
END;
/
What is the difference between %TYPE and %ROWTYPE?
Both %TYPE and %ROWTYPE are used to define variables in PL/SQL as it is defined within the database. If the datatype or precision of a column changes, the program automatically picks up the new definition from the database without having to make any code changes.
The %TYPE and %ROWTYPE constructs provide data independence, reduces maintenance costs, and allows programs to adapt as the database changes to meet new business needs.
%TYPE
%TYPE is used to declare a field with the same type as that of a specified table's column. Example:
DECLARE
v_EmpName emp.ename%TYPE;
BEGIN
SELECT ename INTO v_EmpName FROM emp WHERE ROWNUM = 1;
DBMS_OUTPUT.PUT_LINE('Name = ' || v_EmpName);
END;
/
%ROWTYPE
%ROWTYPE is used to declare a record with the same types as found in the specified database table, view or cursor. Examples:
DECLARE
v_emp emp%ROWTYPE;
BEGIN
v_emp.empno := 10;
v_emp.ename := 'XXXXXXX';
END;
/
How does one get the value of a sequence into a PL/SQL variable?
Starting with 11g you can directly do the following:
i := sq_sequence.NEXTVAL;
On the previous versions you have to use embedded SQL statements to obtain sequence values:
select sq_sequence.NEXTVAL into :i from dual;
Can one execute an operating system command from PL/SQL?
There is no direct way to execute operating system commands from PL/SQL. PL/SQL doesn't have a "host" command, as with SQL*Plus, that allows users to call OS commands. Nevertheless, the following workarounds can be used:
Database Pipes
Write an external program (using one of the precompiler languages, OCI or Perl with Oracle access modules) to act as a listener on a database pipe (SYS.DBMS_PIPE). Your PL/SQL program then put requests to run commands in the pipe, the listener picks it up and run the requests. Results are passed back on a different database pipe. For a Pro*C example, see chapter 8 of the Oracle Application Developers Guide.
CREATE OR REPLACE FUNCTION host_command( cmd IN VARCHAR2 )
RETURN INTEGER IS
status NUMBER;
errormsg VARCHAR2(80);
pipe_name VARCHAR2(30);
BEGIN
pipe_name := 'HOST_PIPE';
dbms_pipe.pack_message( cmd );
status := dbms_pipe.send_message(pipe_name);
RETURN status;
END;
/
External Procedure Listeners:
From Oracle 8 one can call external 3GL code in a dynamically linked library (DLL or shared object). One can write a library in C/ C++ to do whatever is required. Defining this C/C++ function to PL/SQL makes it executable. Look at this External Procedure example.
DBMS_SCHEDULER
In Oracle 10g and above, one can execute OS commands via the DBMS_SCHEDULER package. Look at this example:
BEGIN
dbms_scheduler.create_job(job_name => 'myjob',
job_type => 'executable',
job_action => '/app/oracle/x.sh',
enabled => TRUE,
auto_drop => TRUE);
END;
/
exec dbms_scheduler.run_job('myjob');
How does one loop through tables in PL/SQL?
One can make use of cursors to loop through data within tables. Look at the following nested loops code example.
DECLARE
CURSOR dept_cur IS
SELECT deptno
FROM dept
ORDER BY deptno;
-- Employee cursor all employees for a dept number
CURSOR emp_cur (v_dept_no DEPT.DEPTNO%TYPE) IS
SELECT ename
FROM emp
WHERE deptno = v_dept_no;
BEGIN
FOR dept_rec IN dept_cur LOOP
dbms_output.put_line('Employees in Department '||TO_CHAR(dept_rec.deptno));
FOR emp_rec in emp_cur(dept_rec.deptno) LOOP
dbms_output.put_line('...Employee is '||emp_rec.ename);
END LOOP;
END LOOP;
END;
/
How often should one COMMIT in a PL/SQL loop? / What is the best commit strategy?
Contrary to popular belief, one should COMMIT less frequently within a PL/SQL loop to prevent ORA-1555 (Snapshot too old) errors. The higher the frequency of commit, the sooner the extents in the undo/ rollback segments will be cleared for new transactions, causing ORA-1555 errors.
To fix this problem one can easily rewrite code like this:
FOR records IN my_cursor LOOP
...do some stuff...
COMMIT;
END LOOP;
COMMIT;
... to ...
FOR records IN my_cursor LOOP
...do some stuff...
i := i+1;
IF mod(i, 10000) = 0 THEN -- Commit every 10000 records
COMMIT;
END IF;
END LOOP;
COMMIT;
If you still get ORA-1555 errors, contact your DBA to increase the undo/ rollback segments.
NOTE: Although fetching across COMMITs work with Oracle, is not supported by the ANSI standard.
Issuing frequent commits is bad, bad, BAD! It’s the WORST thing you can do… just don’t do it! In the following example I will create around 7 million rows and then attempt to update a portion of them serially. In addition, I will issue a commit every thousandth row.
Example 1.1: Creating a somewhat large table
SQL> create table big_employee_table
2 as
3 select rownum as eid
4 , e.*
5 from hr.employees e
6 , dba_objects do;
Table created.
Elapsed: 00:00:12.23
SQL> select count(*)
2 from big_employee_table;
COUNT(*)
----------
7838713
Elapsed: 00:00:08.11
Before I go on, notice that Oracle’s “Create Table As” (CTAS) method blazed thru table creation. That’s 7.84 Million rows in 12.23 seconds. Sometimes, this is the very best method of updating large data sets. The following block updates 100,000 rows, serially, committing every 1000 rows:
Example 1.2: Updating serially
SQL> declare
2 cursor c is
3 select *
4 from big_employee_table
5 where rownum <= 100000;
6 begin
7 for r in c loop
8 update big_employee_table
9 set salary = salary * 1.03
10 where eid = r.eid;
11
12 if mod ( r.eid, 1000 ) = 0 then
13 commit;
14 end if;
15 end loop;
16 end;
17 /
Observe that the update took more time than I have patience for ;). At 20 minutes I killed the session. It is painfully slow and should never be done. Moreover, it chewed up an entire CPU core for the duration. If you’re only updating a few rows, why do it in PL/SQL at all? I like Tom Kyte’s approach (paraphrasing):
1. Do it in SQL.
2. If SQL can’t do it, do it in PL/SQL.
3. If PL/SQL can’t do it, do it in Java.
4. If Java can’t do it ask yourself if it needs to be done.
The following block does the same work in bulk:
Example 1.3: Updating in bulk and committing at the end
SQL> declare
2 type obj_rowid is table of rowid
3 index by pls_integer;
4
5 lr_rowid obj_rowid;
6 lr_salary dbms_sql.number_table;
7
8 cursor c is
9 select rowid rid
10 , salary
11 from big_employee_table
12 where rownum <= 100000;
13 begin
14 open c;
15 loop
16 fetch c bulk collect
17 into lr_rowid
18 , lr_salary
19 limit 500;
20
21 for a in 1 .. lr_rowid.count loop
22 lr_salary ( a ) := lr_salary ( a ) * 1.03;
23 end loop;
24
25 forall b in 1 .. lr_rowid.count
26 update big_employee_table
27 set salary = lr_salary ( b )
28 where rowid in ( lr_rowid ( b ));
29
30 exit when c%notfound;
31 end loop;
32 close c;
33 commit; -- there! not in the loop
34 exception
35 when others then
36 rollback;
37 dbms_output.put_line ( sqlerrm );
38 end;
39 /
PL/SQL procedure successfully completed.
Elapsed: 00:00:02.11
SQL>
Notice that the update completed in 2 seconds! I’ve seen faster but my two-gerbil sandbox machine doesn’t have the power that our newer servers do. The point is that the update was incredibly fast and chewed up only 10% of one core. So, in answer to the question of “how often should I commit?” I say don’t until you absolutely have to.
I can SELECT from SQL*Plus but not from PL/SQL. What is wrong?
PL/SQL respect object privileges given directly to the user, but does not observe privileges given through roles. The consequence is that a SQL statement can work in SQL*Plus, but will give an error in PL/SQL. Choose one of the following solutions:
- Grant direct access on the tables to your user. Do not use roles!
GRANT select ON scott.emp TO my_user;
- Define your procedures with invoker rights (Oracle 8i and higher);
create or replace procedure proc1
authid current_user is
begin
...
- Move all the tables to one user/schema.
What is a mutating and constraining table?
"Mutating" means "changing". A mutating table is a table that is currently being modified by an update, delete, or insert statement. When a trigger tries to reference a table that is in state of flux (being changed), it is considered "mutating" and raises an error since Oracle should not return data that has not yet reached its final state.
Another way this error can occur is if the trigger has statements to change the primary, foreign or unique key columns of the table off which it fires. If you must have triggers on tables that have referential constraints, the workaround is to enforce the referential integrity through triggers as well.
There are several restrictions in Oracle regarding triggers:
- A row-level trigger cannot query or modify a mutating table. (Of course, NEW and OLD still can be accessed by the trigger).
- A statement-level trigger cannot query or modify a mutating table if the trigger is fired as the result of a CASCADE delete.
- Etc.
Can one pass an object/table as an argument to a remote procedure?
The only way to reference an object type between databases is via a database link. Note that it is not enough to just use "similar" type definitions. Look at this example:
-- Database A: receives a PL/SQL table from database B
CREATE OR REPLACE PROCEDURE pcalled(TabX DBMS_SQL.VARCHAR2S) IS
BEGIN
-- do something with TabX from database B
null;
END;
/
-- Database B: sends a PL/SQL table to database A
CREATE OR REPLACE PROCEDURE pcalling IS
TabX DBMS_SQL.VARCHAR2S@DBLINK2;
BEGIN
pcalled@DBLINK2(TabX);
END;
/
What is the difference between stored procedures and functions?
- Functions MUST return a value, procedures don't need to.
- You can have DML (insert,update, delete) statements in a function. But, you cannot call such a function in a SQL query. (However an autonomous transaction function can.)
- You cannot call a procedure in a SQL query.
Is there a PL/SQL Engine in SQL*Plus?
No. Unlike Oracle Forms, SQL*Plus does not have an embedded PL/SQL engine. Thus, all your PL/SQL code is sent directly to the database engine for execution. This makes it much more efficient as SQL statements are not stripped off and sent to the database individually.
Is there a limit on the size of a PL/SQL block?
Yes, the max size is not an explicit byte limit, but related to the parse tree that is created when you compile the code. You can run the following select statement to query the size of an existing package or procedure:
SQL> select * from dba_object_size where name = 'procedure_name';
What are the PL/SQL compiler limits for block, record, subquery and label nesting?
The following limits apply:
Level of Block Nesting: 255
Level of Record Nesting: 32
Level of Subquery Nesting: 254
Level of Label Nesting: 98
Level of Record Nesting: 32
Level of Subquery Nesting: 254
Level of Label Nesting: 98
Can one COMMIT/ ROLLBACK from within a trigger?
A commit inside a trigger would defeat the basic definition of an atomic transaction (see ACID). Trigger logic is by definition an extension of the original DML operation. Changes made within triggers should thus be committed or rolled back as part of the transaction in which they execute. For this reason, triggers are NOT allowed to execute COMMIT or ROLLBACK statements (with the exception of autonomous triggers). Here is an example of what will happen when they do:
SQL> CREATE TABLE tab1 (col1 NUMBER);
Table created.
SQL> CREATE TABLE log (timestamp DATE, operation VARCHAR2(2000));
Table created.
SQL> CREATE TRIGGER tab1_trig
2 AFTER insert ON tab1
3 BEGIN
4 INSERT INTO log VALUES (SYSDATE, 'Insert on TAB1');
5 COMMIT;
6 END;
7 /
Trigger created.
SQL> INSERT INTO tab1 VALUES (1);
INSERT INTO tab1 VALUES (1)
*
ERROR at line 1:
ORA-04092: cannot COMMIT in a trigger
ORA-06512: at "SCOTT.TAB1_TRIG", line 3
ORA-04088: error during execution of trigger 'SCOTT.TAB1_TRIG'
Autonomous transactions:
As workaround, one can use autonomous transactions. Autonomous transactions execute separate from the current transaction.
Unlike regular triggers, autonomous triggers can contain COMMIT and ROLLBACK statements. Example:
SQL> CREATE OR REPLACE TRIGGER tab1_trig
2 AFTER insert ON tab1
3 DECLARE
4 PRAGMA AUTONOMOUS_TRANSACTION;
5 BEGIN
6 INSERT INTO log VALUES (SYSDATE, 'Insert on TAB1');
7 COMMIT; -- only allowed in autonomous triggers
8 END;
9 /
Trigger created.
SQL> INSERT INTO tab1 VALUES (1);
1 row created.
Note that with the above example will insert and commit log entries - even if the main transaction is rolled-back!
Remember that an "autonomous_transaction" procedure/function/trigger is a whole transaction in itself and so it must end with a commit or a rollback statement.
No comments:
Post a Comment