DEFERRED_SEGMENT_CREATION 参数相关说明

联系:手机(13429648788)  QQ(107644445)

链接:https://www.orasos.com/deferred_segment_creation-%e5%8f%82%e6%95%b0%e7%9b%b8%e5%85%b3%e8%af%b4%e6%98%8e.html

标题:DEFERRED_SEGMENT_CREATION 参数相关说明

作者:惜分飞©版权所有[文章允许转载,但必须以链接方式注明源地址,否则追究法律责任.]

DEFERRED_SEGMENT_CREATION specifies the semantics of deferred segment creation. If set to true, then segments for tables and their dependent objects (LOBs, indexes) will not be created until the first row is inserted into the table.
这句话的意思是 DEFERRED_SEGMENT_CREATION 参数的作用是:创建表的时候延迟创建这个表相关的segment(包括lobs,indexes),直到第一次插入数据的时候才创建segment.补充说明:DEFERRED_SEGMENT_CREATION 参数从11.2.0.1引进,默认值为true;如果要使其恢复老版本功能,设置该参数为false.

DEFERRED_SEGMENT_CREATION默认值

SQL> select * from v$version;

BANNER
--------------------------------------------------------------------------------
Oracle Database 11g Enterprise Edition Release 11.2.0.3.0 - Production
PL/SQL Release 11.2.0.3.0 - Production
CORE    11.2.0.3.0      Production
TNS for Linux: Version 11.2.0.3.0 - Production
NLSRTL Version 11.2.0.3.0 - Production

SQL> select to_char(sysdate,'yyyy-mm-dd hh24:mi:ss') "WWW.XIFENFEI.COM" FROM DUAL;

WWW.XIFENFEI.COM
--------------------------------------
2012-06-01 05:31:03

SQL> show parameter DEFERRED_SEGMENT_CREATION;

NAME                                 TYPE       VALUE
------------------------------------ ---------- --------
deferred_segment_creation            boolean    TRUE

DEFERRED_SEGMENT_CREATION效果验证

SQL> create table t_xifenfei (id number,name varchar2(30));

Table created.

SQL> create index ind_t_xifenfei on t_xifenfei(id);

Index created.

SQL> select segment_name,segment_type from dba_segments where
  2   segment_name in('T_XIFENFEI','IND_T_XIFENFEI') AND OWNER='CHF';

no rows selected
--未创建segment

SQL> INSERT INTO T_XIFENFEI VALUES(1,'WWW.XIFENFEI.COM');

1 row created.

SQL> commit;

Commit complete.

SQL> select segment_name,segment_type from dba_segments where 
  2  segment_name in('T_XIFENFEI','IND_T_XIFENFEI') AND OWNER='CHF';

SEGMENT_NAME         SEGMENT_TYPE
-------------------- ------------------------------------
IND_T_XIFENFEI       INDEX
T_XIFENFEI           TABLE
--创建segment

SQL> alter session set deferred_segment_creation=false;

Session altered.

SQL> create table t_xifenfei_2 (id number,name varchar2(30));

Table created.

SQL> select segment_name,segment_type from dba_segments where segment_name='T_XIFENFEI_2';

SEGMENT_NAME         SEGMENT_TYPE
-------------------- ------------------------------------
T_XIFENFEI_2         TABLE
--创建segment

问题1(朋友疑惑为什么它没有给相关表空间分配配额但是创建表成功)

SQL> create user xifenfei identified by xifenfei default tablespace users;

User created.

SQL> grant connect,resource to xifenfei;

Grant succeeded.

SQL> revoke unlimited tablespace from xifenfei;

Revoke succeeded.

SQL> alter user xifenfei quota unlimited on users;

User altered.

SQL> conn xifenfei/xifenfei
Connected.
SQL> create table t_xifenfei (id number,name varchar2(30)) tablespace system;

Table created.
--在system表空间无配额,但是创建表成功

SQL> insert into t_xifenfei values(1,'www.orasos.com');
insert into t_xifenfei values(1,'www.orasos.com')
            *
ERROR at line 1:
ORA-01950: no privileges on tablespace 'SYSTEM'
--插入数据库失败,因为在system上创建segment失败


SQL> alter session set deferred_segment_creation=false;

Session altered.

SQL> create table t_xifenfei_2 (id number,name varchar2(30)) tablespace system;
create table t_xifenfei_2 (id number,name varchar2(30)) tablespace system
*
ERROR at line 1:
ORA-01950: no privileges on tablespace 'SYSTEM'
--deferred_segment_creation设置为false后,创建表直接失败

问题2(exp未导segment不存在表)
该问题帮朋友解决过.因为暂时无11.2.0.1版本数据库,直接摘录MOS

In 11.2 the deferred storage segment feature is enabled by default. 
Conventional export (exp) silently skips tables with deferred segment
creation if no segment has yet been created. ie: If the table does
not yet contain any rows. In some cases "exp" will report EXP-11 for 
the table.
 
eg:
 create table t(c1 int) tablespace sysaux;
 select segment_created from user_tables where table_name='T';
  SEG
  ---
  NO
 
 Table level export:
   exp scott/tiger file=/tmp/scott.dmp tables=t
   ^
   EXP-11 SCOTT.T does not exist
 
 Schema level export:
   exp scott/tiger file=/tmp/scott.dmp owner=scott statistics=none
   ^
   Export completes successfully but silently does not export
   table "T".
 
Rediscovery Notes:
  Tables that may be affected by this can be found thus:
    select owner, table_name from dba_tables 
     where segment_created='NO';
 
  EXP-11 on export for tables with no data.
  Tables missing after exp/imp
 
Workaround
  Re-create the missing table at the export site from DDL.
  (the table did not contain rows otherwise it would have
   had a segment created for it)

In 11.2 the deferred storage segment feature is enabled by default. 
Conventional export (exp) silently skips tables with deferred segment
creation if no segment has yet been created. ie: If the table does
not yet contain any rows. In some cases "exp" will report EXP-11 for 
the table.
 
eg:
 create table t(c1 int) tablespace sysaux;
 select segment_created from user_tables where table_name='T';
  SEG
  ---
  NO
 
 Table level export:
   exp scott/tiger file=/tmp/scott.dmp tables=t
   ^
   EXP-11 SCOTT.T does not exist
 
 Schema level export:
   exp scott/tiger file=/tmp/scott.dmp owner=scott statistics=none
   ^
   Export completes successfully but silently does not export
   table "T".
 
Rediscovery Notes:
  Tables that may be affected by this can be found thus:
    select owner, table_name from dba_tables 
     where segment_created='NO';
 
  EXP-11 on export for tables with no data.
  Tables missing after exp/imp
 
Workaround
  Re-create the missing table at the export site from DDL.
  (the table did not contain rows otherwise it would have
   had a segment created for it)
 
This issue is fixed in	
•12.1 (Future Release) 
•11.2.0.2 (Server Patch Set)