create user ..."/>
您好,登錄后才能下訂單哦!
上一篇對觸發(fā)器的一些基本知識有了了解,在這一篇操作進行驗證
before觸發(fā)器
[oracle@test ~]$ sqlplus / as sysdba
SQL> create user trigger_test identified by 123456 ; SQL> grant create session to trigger_test ; SQL> grant create table to trigger_test ; SQL> grant dba to trigger_test ; SQL> grant resource to trigger_test ; SQL> grant create sequence to trigger_test ;
[oracle@test ~]$ sqlplus trigger_test/123456
創(chuàng)建測試表student
SQL> create table student(STUDENT_ID NUMBER(8),name varchar2(15),CREATED_BY VARCHAR2(30) not null,CREATED_DATE DATE not null,MODIFIED_BY VARCHAR2(30) not null,MODIFIED_DATE DATE not null)
創(chuàng)建序列student_id_seq
create sequence student_id_seq minvalue 1 maxvalue 9999999999999999999999999999 start with 100 increment by 1;
SQL> select * from student ; no rows selected SQL> select * from cat ; TABLE_NAME TABLE_TYPE ------------------------------ ----------- STUDENT TABLE STUDENT_ID_SEQ SEQUENCE
create or replace trigger student_before_insert before insert on student for each row declare v_student_id student.student_id%type ; begin select student_id_seq.nextval into v_student_id from dual ; :new.student_id := v_student_id ; :new.created_by := user ; :new.created_date := sysdate ; :new.modified_by := user ; :new.modified_date := sysdate ; end;
SQL> insert into student (name) values ('mjt'); SQL> commit ; SQL> select * from student ; STUDENT_ID NAME CREATED_BY CREATED_DATE ---------- --------------- ------------------------------ ------------------- MODIFIED_BY MODIFIED_DATE ------------------------------ ------------------- 100 mjt TRIGGER_TEST 2015-07-29 20:51:19 TRIGGER_TEST 2015-07-29 20:51:19 SQL> insert into student (name) values ('cxq') ; 1 row created. SQL> select * from student ; STUDENT_ID NAME CREATED_BY CREATED_DATE ---------- --------------- ------------------------------ ------------------- MODIFIED_BY MODIFIED_DATE ------------------------------ ------------------- 100 mjt TRIGGER_TEST 2015-07-29 20:51:19 TRIGGER_TEST 2015-07-29 20:51:19 101 cxq TRIGGER_TEST 2015-07-29 21:00:54 TRIGGER_TEST 2015-07-29 21:00:54
after觸發(fā)器
SQL> create table record(table_name varchar2(30),transaction_name varchar2(10),transaction_user varchar2(30),transaction_date date);
這個表被用來記錄數(shù)據(jù)庫中不同表的信息,如,可以記錄誰從student表中刪除或者更新數(shù)據(jù),以及記錄時間。
下面的觸發(fā)器針對對student表的更新或者刪除操作,在此之后進行觸發(fā)
create or replace trigger student_aud after update or delete on student declare v_type varchar2(10); begin if updating then v_type := 'UPDATE'; elsif deleting then v_type := 'DELETE'; end if; update trigger_test.record set transaction_user = user, transaction_date = sysdate where table_name = 'student' and transaction_name = v_type; if sql%notfound then insert into trigger_test.record values ('student', v_type, user, sysdate); end if; end;
SQL> select * from record ; no rows selected SQL> select * from student ; STUDENT_ID NAME CREATED_BY CREATED_DATE ---------- --------------- ------------------------------ ------------------- MODIFIED_BY MODIFIED_DATE ------------------------------ ------------------- 100 mjt TRIGGER_TEST 2015-07-29 20:51:19 TRIGGER_TEST 2015-07-29 20:51:19 101 cxq TRIGGER_TEST 2015-07-29 21:00:54 TRIGGER_TEST 2015-07-29 21:00:54 SQL> update student set name = 'somebody' where name = 'mjt' ; 1 row updated. SQL> commit ; Commit complete. SQL> select * from student ; STUDENT_ID NAME CREATED_BY CREATED_DATE ---------- --------------- ------------------------------ ------------------- MODIFIED_BY MODIFIED_DATE ------------------------------ ------------------- 100 somebody TRIGGER_TEST 2015-07-29 20:51:19 TRIGGER_TEST 2015-07-29 20:51:19 101 cxq TRIGGER_TEST 2015-07-29 21:00:54 TRIGGER_TEST 2015-07-29 21:00:54 SQL> select * from record ; TABLE_NAME TRANSACTIO TRANSACTION_USER ------------------------------ ---------- ------------------------------ TRANSACTION_DATE ------------------- student UPDATE TRIGGER_TEST 2015-07-29 21:50:46 SQL> delete student where name = 'somebody' ; 1 row deleted. SQL> commit ; Commit complete. SQL> select * from student ; STUDENT_ID NAME CREATED_BY CREATED_DATE ---------- --------------- ------------------------------ ------------------- MODIFIED_BY MODIFIED_DATE ------------------------------ ------------------- 101 cxq TRIGGER_TEST 2015-07-29 21:00:54 TRIGGER_TEST 2015-07-29 21:00:54 SQL> select * from record ; TABLE_NAME TRANSACTIO TRANSACTION_USER ------------------------------ ---------- ------------------------------ TRANSACTION_DATE ------------------- student UPDATE TRIGGER_TEST 2015-07-29 21:50:46 student DELETE TRIGGER_TEST 2015-07-29 21:56:08 SQL> alter trigger student_aud disable ; Trigger altered. SQL> update student set name = 'mjt' where name = 'cxq'; 1 row updated. SQL> commit ; Commit complete. SQL> select * from student ; STUDENT_ID NAME CREATED_BY CREATED_DATE ---------- --------------- ------------------------------ ------------------- MODIFIED_BY MODIFIED_DATE ------------------------------ ------------------- 101 mjt TRIGGER_TEST 2015-07-29 21:00:54 TRIGGER_TEST 2015-07-29 21:00:54 SQL> select * from record ; TABLE_NAME TRANSACTIO TRANSACTION_USER ------------------------------ ---------- ------------------------------ TRANSACTION_DATE ------------------- student UPDATE TRIGGER_TEST 2015-07-29 21:50:46 student DELETE TRIGGER_TEST 2015-07-29 21:56:08
禁用觸發(fā)器之后,在student表上的update操作不再觸發(fā)產(chǎn)生記錄到record表
對應啟用
SQL> alter trigger student_aud enable ; Trigger altered.
3.自治事務
自治事務是由其他事務(通常被稱為主事務)發(fā)起的獨立事務,自治事務也許會執(zhí)行多個dml語句,并且提交或者回滾,而不會提交或者回滾主事務執(zhí)行的dml語句。
假如希望即使主事務失敗,仍舊能夠記錄審計數(shù)據(jù),這種情況下,主事務是面向
表的update或者delete,需要定義可以獨立于主事務進行提交的自治事務。
定義主事務,需要使用autonomous_transaction編譯指令在語句塊的聲明部分
declare pragma autonomous_transaction commit ; create or replace trigger student_aud after update or delete on student declare v_type varchar2(10); pragma autonomous_transaction ; begin if updating then v_type := 'UPDATE'; elsif deleting then v_type := 'DELETE'; end if; update trigger_test.record set transaction_user = user, transaction_date = sysdate where table_name = 'student' and transaction_name = v_type; if sql%notfound then insert into trigger_test.record values ('student', v_type, user, sysdate); end if; commit ; end;
如果當前更新或者刪除表student中的內(nèi)容,無論成功或者失敗,都會在record表中記錄當前的操作。不足的是,record表中最多只能記錄兩條數(shù)據(jù),只是當前最新操作的時間以及操作者。
免責聲明:本站發(fā)布的內(nèi)容(圖片、視頻和文字)以原創(chuàng)、轉(zhuǎn)載和分享為主,文章觀點不代表本網(wǎng)站立場,如果涉及侵權請聯(lián)系站長郵箱:is@yisu.com進行舉報,并提供相關證據(jù),一經(jīng)查實,將立刻刪除涉嫌侵權內(nèi)容。