在处理一些已经提交的数据时,因为提交的时间超过了可以闪回的时间,所以采用了LOGMNR来处理。在处理的过程中,很多人都会发现得到的SQL语句中,包含了空列的情况。
例子:
SQL> CONN SYS@YTK102 AS SYSDBA输入口令: 已连接。
SQL> ALTER SESSION SET NLS_DATE_FORMAT = 'YYYY-MM-DD HH24:MI:SS';
会话已更改。
SQL> SELECT GROUP#, FIRST_TIME FROM V$LOG;
GROUP# FIRST_TIME
---------- -------------------
1 2008-01-18 22:35:57
2 2008-01-20 18:58:37
3 2008-01-16 23:56:50
SQL> SELECT MEMBER FROM V$LOGFILE WHERE GROUP# = 2;
MEMBER
-------------------------------
E:ORACLEORADATAYTK102REDO02.LOG
SQL> ALTER SYSTEM SWITCH LOGFILE;
系统已更改。
SQL> EXEC DBMS_LOGMNR.ADD_LOGFILE('E:ORACLEORADATAYTK102REDO02.LOG', DBMS_LOGMNR.NEW)
PL/SQL 过程已成功完成。
SQL> EXEC DBMS_LOGMNR.START_LOGMNR(OPTIONS => DBMS_LOGMNR.DICT_FROM_ONLINE_CATALOG)
PL/SQL 过程已成功完成。
SQL> SELECT SQL_UNDO FROM V$LOGMNR_CONTENTS
2 WHERE SEG_NAME = 'T_LOGMNR';
SQL_UNDO
--------------------------------------------------------------------------
insert into "YANGTK"."T_LOGMNR"("ID","NAME","") values ('1','A',NULL);
insert into "YANGTK"."T_LOGMNR"("ID","NAME","") values ('2','B',NULL);
insert into "YANGTK"."T_LOGMNR"("ID","NAME","") values ('3','C',NULL); |
在此部分可以看到T_LOGMNR表后面跟了一个空的列,而这个列的值也是NULL。
检查表结构:
SQL> DESC YANGTK.T_LOGMNR
名称 是否为空? 类型
------------------------- -------- ----------------
ID NOT NULL NUMBER
NAME VARCHAR2(30)
SQL> SELECT TABLE_NAME, COLUMN_NAME FROM DBA_TAB_COLUMNS
2 WHERE TABLE_NAME = 'T_LOGMNR'
3 AND OWNER = 'YANGTK';
TABLE_NAME COLUMN_NAME
------------------------------ ---------------------
T_LOGMNR ID
T_LOGMNR NAME |
从数据字典中找不到这个空列的信息,直接查询COL$表:
SQL> SELECT OBJECT_ID FROM DBA_OBJECTS
2 WHERE OBJECT_NAME = 'T_LOGMNR'
3 AND OWNER = 'YANGTK';
OBJECT_ID
----------
53636
SQL> SELECT NAME FROM COL$ WHERE OBJ# = 53636;
NAME
------------------------------
ID
NAME
SYS_NC00003$ |
从COL$中可以看到这个隐藏列了,检查隐藏列:
SQL> SELECT NAME, DEFAULT$ FROM COL$ WHERE OBJ# = 53636;
NAME DEFAULT$
------------------------------ -----------------------
ID
NAME
SYS_NC00003$ DECODE("ID",1,"NAME"||'1',"NAME"||'2') |
现在已经可以看出这个列是一个基于基础列的函数表达式,对比函数索引列:
SQL> SELECT INDEX_NAME, INDEX_TYPE, UNIQUENESS FROM DBA_INDEXES
2 WHERE TABLE_NAME = 'T_LOGMNR'
3 AND TABLE_OWNER = 'YANGTK';
INDEX_NAME INDEX_TYPE UNIQUENES
------------------- ---------------- ---------
SYS_C005983 NORMAL UNIQUE
IND_T_LOGMNR_NAME FUNCTION-BASED NORMAL NONUNIQUE
SQL> SELECT COLUMN_EXPRESSION FROM DBA_IND_EXPRESSIONS
2 WHERE TABLE_NAME = 'T_LOGMNR'
3 AND TABLE_OWNER = 'YANGTK'
4 AND INDEX_NAME = 'IND_T_LOGMNR_NAME';
COLUMN_EXPRESSION
------------------------------------------------
DECODE("ID",1,"NAME"||'1',"NAME"||'2') |
至此,我们可以看到,这个隐藏列就是函数索引产生的 |