Oracle数据库truncate作用与DBA_OBJECTS区别的测试总结
Oracle数据库truncate作用与DBA_OBJECTS区别的测试总结
创建xtdwtest表
create table xtdwtest as select * from dba_objects
SQL> select object_id,data_object_id from dba_objects where object_name='XTDWTEST';
OBJECT_ID DATA_OBJECT_ID
---------- --------------
59436 59436
Execution Plan
----------------------------------------------------------
Plan hash value: 1440243298
-----------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
-----------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 3 | 276 | 18 (0)| 00:00:01 |
| 1 | VIEW | DBA_OBJECTS | 3 | 276 | 18 (0)| 00:00:01 |
| 2 | UNION-ALL | | | | | |
|* 3 | FILTER | | | | | |
| 4 | NESTED LOOPS | | 2 | 162 | 17 (0)| 00:00:01 |
| 5 | TABLE ACCESS BY INDEX ROWID| OBJ$ | 2 | 156 | 16 (0)| 00:00:01 |
|* 6 | INDEX SKIP SCAN | I_OBJ2 | 2 | | 14 (0)| 00:00:01 |
| 7 | TABLE ACCESS CLUSTER | USER$ | 1 | 3 | 1 (0)| 00:00:01 |
|* 8 | INDEX UNIQUE SCAN | I_USER# | 1 | | 0 (0)| 00:00:01 |
|* 9 | TABLE ACCESS BY INDEX ROWID | IND$ | 1 | 8 | 2 (0)| 00:00:01 |
|* 10 | INDEX UNIQUE SCAN | I_IND1 | 1 | | 1 (0)| 00:00:01 |
| 11 | NESTED LOOPS | | 1 | 82 | 1 (0)| 00:00:01 |
|* 12 | INDEX SKIP SCAN | I_LINK1 | 1 | 79 | 0 (0)| 00:00:01 |
| 13 | TABLE ACCESS CLUSTER | USER$ | 1 | 3 | 1 (0)| 00:00:01 |
|* 14 | INDEX UNIQUE SCAN | I_USER# | 1 | | 0 (0)| 00:00:01 |
-----------------------------------------------------------------------------------------------
SQL> truncate table xtdwtest;
Table truncated.
SQL> select object_id,data_object_id from dba_objects where object_name='XTDWTEST';
OBJECT_ID DATA_OBJECT_ID
---------- --------------
59436 59437
其中OBJ#/OBJECT_ID可以被看作是对象的逻辑号(类似序列号一样分配),应序号一旦分配之后就不会发生改变其中DATAOBJ#/DATA_OBJECT_ID则是和物理存储关联的编号,通常认为是对象的物理号,这个编号会随着对象物理存储结构的改变而发生改变。
obj#与dataobj#说明:
obj# number not null, /* object number */
/* DO NOT CREATE INDEX ON DATAOBJ# AS IT WILL BE UPDATED IN A SPACE
* TRANSACTION DURING TRUNCATE */
dataobj# number, /* data layer object number */
以上实际上也暗示了TRUNCATE作为DDL可以快速回收空间的本质,在执行TRUNCATE操作时,数据库只简单地回收空间,将空间标记为可用(并不会在数据块上真正删除数据),同时将对象的数据对象重新定位,完成空间回收。