I ran into an issue at a customer site where certain triggers were disabled in the database where they should be enabled. It appeared that an update script, that is run every night, first disables all triggers on a couple of tables. Then does what it needs to do, without the overhead of the trigger code. and then, when it’s done, it enables all triggers again.
If the update code fails for whatever reason, then the re-enabling of the triggers is not performed, leaving the triggers in disabled state on the database, which can cause problems in everyday use. What you would actually want is a situation where you can disable the triggers, but just for the current session. Any other session should have the triggers enabled at all times. Unfortunately Oracle doesn’t support this kind of enabling/disabling of triggers. We do however have access to all the possibilities of PL/SQL in triggers so we can build a solution to this problem ourselves.
I have come up with a semaphore package which allows me to set and clear a flag or semaphore which I can then check in the trigger code and then, depending on the value of this semaphore execute or skip the code in the trigger. I have also used the knowledge I posted here about a boolean that’s really an integer.
The package:
CREATE OR REPLACE PACKAGE bar_semaphore
IS
— Author : Patrick Barel
— Public function and procedure declarations
FUNCTION sem_emp
RETURN BOOLEAN;
PROCEDURE set_sem_emp;
PROCEDURE clr_sem_emp;
END bar_semaphore;
CREATE OR REPLACE PACKAGE BODY bar_semaphore
IS
— Private variable declarations
g_emp PLS_INTEGER;
— Function and procedure implementations
PROCEDURE MINVALUE(
p_variable_in_out IN OUT PLS_INTEGER
, p_min_value_in IN PLS_INTEGER DEFAULT 0 )
IS
BEGIN
IF p_variable_in_out < p_min_value_in THEN
p_variable_in_out := p_min_value_in;
END IF;
END MINVALUE;
PROCEDURE initialization
IS
BEGIN
g_emp := 0;
END initialization;
FUNCTION sem_emp
RETURN BOOLEAN
IS
BEGIN
RETURN( g_emp > 0 );
END sem_emp;
PROCEDURE set_sem_emp
IS
BEGIN
g_emp := g_emp + 1;
END set_sem_emp;
PROCEDURE clr_sem_emp
IS
BEGIN
g_emp := g_emp – 1;
MINVALUE( g_emp, 0 );
END clr_sem_emp;
BEGIN
initialization;
END bar_semaphore;
The triggers:
CREATE OR REPLACE TRIGGER tr_emp_bri
BEFORE INSERT
ON emp
FOR EACH ROW
DECLARE
— local variables here
BEGIN
IF NOT( bar_semaphore.sem_emp ) THEN
IF :NEW.ename IS NULL THEN
:NEW.ename := ‘<EMPTY>’;
END IF;
END IF;
END tr_emp_bri;
CREATE OR REPLACE TRIGGER tr_emp_bru
BEFORE UPDATE
ON emp
FOR EACH ROW
DECLARE
— local variables here
BEGIN
IF NOT( bar_semaphore.sem_emp ) THEN
IF :NEW.ename IS NULL THEN
:NEW.ename := ‘<EMPTY>’;
END IF;
END IF;
END tr_emp_bru;
The script:
clear screen
set serveroutput on
select * from emp;
update emp set ename = null where empno = 7934;
select * from emp;
rollback;
select * from emp;
exec bar_semaphore.set_sem_emp;
update emp set ename = null where empno = 7934;
select * from emp;
rollback;
exec bar_semaphore.clr_sem_emp;
update emp set ename = null where empno = 7934;
select * from emp;
rollback;
select * from emp;
exec bar_semaphore.set_sem_emp;
update emp set ename = null where empno = 7934;
select * from emp;
rollback;
connect scott/tiger
select * from emp;
update emp set ename = null where empno = 7934;
select * from emp;
The output of the script shows that when a new session is connected and the semaphore is set in the other session, disabling the triggers, this has no influence on the currently connected session. It is as if the semaphore is never set and the triggers function as normal. This way the triggers can be turned off for certain scripts, or pieces of code, that don’t want to be bothered by the code in the trigger, while other session still have this code in place and still have it turned on.
You can either choose to have a single semaphore in a package, or a single semaphore for every table or even a semaphores for different functions in the code. This way execution can be turned off and on exactly the way you want it.
Check the cross post at blog.bar-solutions.com for some nice comments by other developers.
Perhaps I misunderstand the problem but why not simply disable all required triggers, run the update code and enable them again, regardless the outcome of the update script???
Hi Patrick, you could also add the check for NOT(bar_semaphore.sem_emp) into the WHERE clause of the trigger. That might make it even faster. But to be honest, I haven’t tested that.
Patrick
On a second thought, your “solution” did not actually disable the trigger at all. Even if a trigger body with only “null;” in it will incur much more overhead than without the trigger at all. If your customer wants the triggers to be re-enabled, regardless of the status of overnight job, then the update script should re-enable the triggers and send an error that the job failed.
MINVALUE???
Ever heard of a function called LEAST?