暂无图片
暂无图片
暂无图片
暂无图片
暂无图片

Oracle中审计删除(DELETE)操作的触发器

原创 eygle 2011-01-12
1074
帮朋友写的一个简单审计删除操作的触发器,供参考。
首先是授权:

SQL> connect / as sysdba
Connected.

SQL> grant select on v_$sql to eygle;

Grant succeeded.

SQL> grant select on v_$session to eygle;

Grant succeeded.
创建测试表及审计表:

SQL> connect eygle/eygle
Connected.
SQL> create table eygle as select user_id,username from dba_users;

Table created.

SQL> desc eygle
 Name                                      Null?    Type
 ----------------------------------------- -------- ----------------------------
 USER_ID                                   NOT NULL NUMBER
 USERNAME                                  NOT NULL VARCHAR2(30)

SQL> create table eygle_delete_audit
  2  (user_id number,username varchar2(30),deleteby varchar2(30),deldate date,ipaddress varchar2(50),sqltext clob);

Table created.
创建如下触发器:
CREATE OR REPLACE TRIGGER eygle_after_delete
    AFTER DELETE
        ON eygle
        FOR EACH ROW
BEGIN

INSERT INTO eygle_delete_audit
SELECT :old.user_id,:old.username,user,sysdate,SYS_CONTEXT ('userenv', 'ip_address')
,q.sql_text
FROM v$sql q, v$session s
WHERE s.audsid = (SELECT USERENV ('SESSIONID') FROM DUAL)
AND s.sql_id = q.sql_id;

END;
/
测试删除操作:

SQL> connect eygle/eygle@rac1
Connected.
SQL> delete from eygle where user_id=46;

1 row deleted.

SQL> commit;

Commit complete.

SQL> truncate table eygle_delete_audit;

Table truncated.

SQL> delete from eygle where user_id=0;

1 row deleted.

SQL> commit;

Commit complete.

SQL> select * from eygle_delete_audit;

   USER_ID USERNAME                       DELETEBY
---------- ------------------------------ ------------------------------
DELDATE      IPADDRESS
------------ --------------------------------------------------
SQLTEXT
--------------------------------------------------------------------------------
         0 SYS                            EYGLE
12-JAN-11    172.16.3.248
delete from eygle where user_id=0

能够成功记录删除信息及SQL,不知是否有其他问题,请建议!



「喜欢这篇文章,您的关注和赞赏是给作者最好的鼓励」
关注作者
【版权声明】本文为墨天轮用户原创内容,转载时必须标注文章的来源(墨天轮),文章链接,文章作者等基本信息,否则作者和墨天轮有权追究责任。如果您发现墨天轮中有涉嫌抄袭或者侵权的内容,欢迎发送邮件至:contact@modb.pro进行举报,并提供相关证据,一经查实,墨天轮将立刻删除相关内容。

评论