验证ORA_CLIENT_IP_ADDRESS只在系统触发器中有效
ORA_CLIENT_IP_ADDRESS函数的功能是以VARCHAR2类型返回客户端IP地址,一般只用在系统触发器中,其实它也只在系统触发器中有效.
经常看到有人说使用ORA_CLIENT_IP_ADDRESS获得的IP为空,大概也是这个原因造成的.
这里采用DDL触发器和系统触发器做对比.
首先准备实验用的表及两个触发器对象(一个DDL触发器,一个系统触发器)
[sql]
--建立记录表
23:37:15 SYS@orcl> create table t01(id number,nn varchar2(40));
Elapsed: 00:00:00.05
--建立系统触发器
23:37:53 SYS@orcl> create or replace trigger ORA_TEST
23:38:16 2 after logon ON database
23:38:16 3 BEGIN
23:38:16 4 dbms_output.put_line(ORA_LOGIN_USER||'IP:'||NVL(ORA_CLIENT_IP_ADDRESS,'AA'));
23:38:16 5 insert into t01 select nvl(max(id),0)+1,ORA_LOGIN_USER||'[system Trigger]IP:'||NVL(ORA_CLIENT_IP_ADDRESS,'AA') from t01;
23:38:16 6 end;
23:38:17 7 /
Elapsed: 00:00:00.05
--建立DDL触发器
23:38:19 SYS@orcl> create or replace trigger ORA_TEST_ddl
23:38:38 2 after ddl ON database
23:38:38 3 BEGIN
23:38:38 4 dbms_output.put_line(ORA_LOGIN_USER||'IP:'||NVL(ORA_CLIENT_IP_ADDRESS,'AA'));
23:38:38 5 insert into t01 select nvl(max(id),0)+1,ORA_LOGIN_USER||'[DDL Trigger]IP:'||NVL(ORA_CLIENT_IP_ADDRESS,'AA') from t01;
23:38:38 6 end;
23:38:38 7 /
Elapsed: 00:00:00.11
其易做图别加了ORA_LOGIN_USER来标识登录的用户,以及DDL Trigger和system Trigger字串来标识触发的是哪个触发器.
[sql]
--先测试系统触发器,发现dbms_output.put_line没有输出
00:06:11 @orcl> conn cry/cry
Connected.
00:09:28 CRY@orcl> conn scott/tiger
Connected.
00:09:37 SCOTT@orcl> conn sys/ as sysdba
Connected.
此时的表t01为
[sql]
00:09:40 SYS@orcl> select * from t01;
ID NN
---------- ----------------------------------------
1 CRY[system Trigger]IP:192.168.123.102
2 SCOTT[system Trigger]IP:192.168.123.102
3 SYS[system Trigger]IP:192.168.123.102
Elapsed: 00:00:00.02
从表t01中发现ORA_CLIENT_IP_ADDRESS函数在系统触发器中有效,并且成功的返回了IP地址.
(PS:还可以看出在系统触发器中dbms_output.put_line失效了,没有输出任何东西)
[sql]
--再测试DDL触发器,发现dbms_output.put_line有输出
00:10:11 @orcl> conn cry/cry
Connected.
00:11:17 CRY@orcl> create table cry01(id number);
CRYIP:AA
Elapsed: 00:00:00.07
00:11:47 CRY@orcl> conn scott/tiger
Connected.
00:12:00 SCOTT@orcl> create table scott01(id number);
SCOTTIP:AA
Elapsed: 00:00:00.05
00:12:20 @orcl> conn sys/ as sysdba
Connected.
00:12:23 SYS@orcl> create table sys01(id number);
SYSIP:AA
Elapsed: 00:00:00.04
注意带AA的都是dbms_output.put_line输出的,这说明在DDL触发器中dbms_output.put_line是有效的.
此时的T01记录表为:
[sql]
00:12:33 SYS@orcl> select * from t01;
ID NN
---------- ----------------------------------------
1 CRY[system Trigger]IP:192.168.123.102
2 SCOTT[system Trigger]IP:192.168.123.102
3 SYS[system Trigger]IP:192.168.123.102
4 CRY[system Trigger]IP:192.168.123.102
5 CRY[DDL Trigger]IP:AA
6 SCOTT[system Trigger]IP:192.168.123.102
7 SCOTT[DDL Trigger]IP:AA
8 SYS[system Trigger]IP:192.168.123.102
9 SYS[DDL Trigger]IP:AA
Elapsed: 00:00:00.02
其中ID为1、2、3为上面登录三个用户时触发的系统触发器记录,第4条记录对应测试DDL触发器时登录的cry用户(登录触发了系统触发器)
第5条记录测试cry用户创建表cry01时触发的DDL触发器记录(此时我们可以发现ORA_CLIENT_IP_ADDRESS已经返回为空了,并将空转换为了字符'AA',可以去前面看DDL触发器的定义),
继续往下看发现只要是DDL Trigger的都没有记录IP,也就是ORA_CLIENT_IP_ADDRESS返回的IP为空了,而明显的system Trigger都有IP.
[sql]
00:18:26 SYS@orcl> SELECT ORA_CLIENT_IP_ADDRESS FROM DUAL;
ORA_CLIENT_IP_ADDRESS
----------------------------------------------------------
<null>
Elapsed: 00:00:00.02
ORA_CLIENT_IP_ADDRESS虽然是函数,但是直接调用也是为空的
----
综上说明ORA_CLIENT_IP_ADDRESS函数只在系统触发器中起作用。