--创建表并开启数据库内归档特性
SQL>grant select on dba_objects to c##andy container=all;
SQL> conn c##andy/andy
Connected.
SQL>create table ida as select object_name,object_id from dba_objects where 1=2;
SQL>insert into ida select object_name,object_id from dba_objects order by object_id fetch first 10 percent rows only;
7281 rows created.
SQL> alter table ida ROW ARCHIVAL; 或者在建表的时候指定 create table (XXX) ROWARCHIVAL;
Table altered.
--检查表内容
SQL>SELECT COUNT(*) FROM ida;
COUNT(*)
----------
7281
SQL> desc ida;
Name Null? Type
----------------------------------------- -------- ----------------------------
OBJECT_NAME VARCHAR2(128)
OBJECT_ID NUMBER
开启数据库内归档特性将会引起表另外增加一个叫做“ORA_ARCHIVE_STATE”系统隐藏列。
SQL>
COL column_name FORMAT A20;
COL data_type FORMAT A20;
SELECT column_id,
column_name,
data_type,
data_length,
hidden_column
FROM user_tab_cols
WHERE table_name = 'IDA'
ORDER BY column_id;
COLUMN_ID COLUMN_NAME DATA_TYPE DATA_LENGTH HID
---------- -------------------- -------------------- ----------- ---
1 OBJECT_NAME VARCHAR2 128 NO
2 OBJECT_ID NUMBER 22 NO
SYS_NC00003$ RAW 126 YES
ORA_ARCHIVE_STATEVARCHAR2 4000 YES
默认的,该列的每行被填充为‘0’。
SQL>
COL ora_archive_state FORMAT A20;
SELECT ora_archive_state,COUNT(*)
FROM ida
GROUP BY ora_archive_state
ORDER BY ora_archive_state;
ORA_ARCHIVE_STATE COUNT(*)
-------------------- ----------
0 7281
2. 归档(删除)的行
并非删除不需要的行,而是把ORA_ARCHIVE_STATE系统隐藏列的值更改为‘1’。这将导致应用看不到这些行。
SQL>
UPDATE ida
SET ora_archive_state ='1'
WHERE object_id>7000;
284 rows updated.
SQL>COMMIT;
SQL>SELECT COUNT(*) FROM ida;
COUNT(*)
----------
6997 > 已经出现隐藏列了
3. 显示归档行
通过将ROW_ARCHIVAL_VISIBILITY设置为ALL,可以使得这些隐藏行对会话可见。将该参数设置回ACTIVE可以再次使这些行不可见。
--使归档的行可见
SQL>ALTER SESSION SET ROW ARCHIVAL VISIBILITY = ALL;
SQL>SELECT COUNT(*) FROM ida;
COUNT(*)
----------
7281 > 隐藏行对会话可见
--使归档行再次不可见
SQL>ALTER SESSION SET ROW ARCHIVAL VISIBILITY = ACTIVE;
SQL>SELECT COUNT(*) FROM ida;
COUNT(*)
----------
6997 > 隐藏行对会话不可见
--禁用并重新开启数据库内归档特性
SQL>ALTER TABLE ida NO ROW ARCHIVAL;
SQL>ALTER TABLE ida ROW ARCHIVAL;