23 June, 2009

AUTOEXTEND ON Next Size


UPDATE 28-Feb-11 : Apparently, in 11gR1, Bug 8318050 affects the behaviour of Autoextend On datafiles such that the NEXT size specified may not be honoured. See Oracle Support Article#8318050.8

In a CREATE TABLESPACE command, the DATAFILE clause is the Physical Specification component.

In pre- 9i/10g OMF manner, the DATAFILE must be specified. A (initial) filesize must also be specified. However, Autoextend's NEXT size is not mandatory and Oracle can "default". Very unfortunately, the default AUTOEXTEND ON NEXT size is 1 Database block (based on the blocksize of the tablespace).

But if you create your Tablespace using OMF (i.e. where "db_create_file_dest" is configured), then Oracle defaults the initial size to 100MB and *also* defaults the AUTOEXTEND to ON with a of 100MB ! That is much neater.

Why is the default 1 Database block bad ? Because when the datafile is full, Oracle will extend it 1 block at-a-time, making a call to the OS to add 1 block on each occassion. Obviously, even if you are extending a table or index with an Extent of 64KB, Oracle has to make 8 calls to the OS (with a datafile block size of 8KB). That is where you will see "data file init write" waits.

In the example below, the (automatic) datafile for Tablespace AN_OMF_TBS get's created with both the initial and increment at 100MB and AutoExtend ON. However, for Tablespace REGULAR_TBS, I have to specify the initial size for the datafile. If I do not specify AutoExtend, the file is created with AutoExtend OFF. For the third tablespace, called ANOTHER_TBS, when I designate AutoExtend ON but do not specify the incremental size, Oracle defaults it to 1 Oracle Block.



SQL> select tablespace_name, file_name, bytes/1048576 File_Size_MB, autoextensible, increment_by from dba_data_files order by file_id;

TABLESPACE_NAME FILE_NAME FILE_SIZE_MB AUT INCREMENT_BY
--------------- ------------------------------------------------------- ------------ --- ------------
SYSTEM /oracle_fs/Databases/ORT24FS/system01.dbf 590 YES 1,280
UNDOTBS1 /oracle_fs/Databases/ORT24FS/undotbs01.dbf 155 YES 640
SYSAUX /oracle_fs/Databases/ORT24FS/sysaux01.dbf 270 YES 1,280
USERS /oracle_fs/Databases/ORT24FS/users01.dbf 85 YES 160
EXAMPLE /oracle_fs/Databases/ORT24FS/example01.dbf 100 YES 80
TEST_A_TBS /oracle_fs/Databases/ORT24FS/test_a_tbs.dbf 100 NO 0

6 rows selected.

SQL> alter system set db_create_file_dest='/var/tmp';

System altered.

SQL> create tablespace an_omf_tbs;

Tablespace created.

SQL> select tablespace_name, file_name, bytes/1048576 File_Size_MB, autoextensible, increment_by from dba_data_files order by file_id;

TABLESPACE_NAME FILE_NAME FILE_SIZE_MB AUT INCREMENT_BY
--------------- ------------------------------------------------------- ------------ --- ------------
SYSTEM /oracle_fs/Databases/ORT24FS/system01.dbf 590 YES 1,280
UNDOTBS1 /oracle_fs/Databases/ORT24FS/undotbs01.dbf 155 YES 640
SYSAUX /oracle_fs/Databases/ORT24FS/sysaux01.dbf 270 YES 1,280
USERS /oracle_fs/Databases/ORT24FS/users01.dbf 85 YES 160
EXAMPLE /oracle_fs/Databases/ORT24FS/example01.dbf 100 YES 80
TEST_A_TBS /oracle_fs/Databases/ORT24FS/test_a_tbs.dbf 100 NO 0
AN_OMF_TBS /var/tmp/ORT24FS/datafile/o1_mf_an_omf_t_541wgb0c_.dbf 100 YES 12,800

7 rows selected.

SQL> create tablespace REGULAR_TBS datafile '/oracle_fs/Databases/ORT24FS/regular_tbs.dbf';
create tablespace REGULAR_TBS datafile '/oracle_fs/Databases/ORT24FS/regular_tbs.dbf'
*
ERROR at line 1:
ORA-01119: error in creating database file '/oracle_fs/Databases/ORT24FS/regular_tbs.dbf'
ORA-17610: file '/oracle_fs/Databases/ORT24FS/regular_tbs.dbf' does not exist and no size specified
ORA-27037: unable to obtain file status
Linux-x86_64 Error: 2: No such file or directory
Additional information: 3


SQL> create tablespace REGULAR_TBS datafile '/oracle_fs/Databases/ORT24FS/regular_tbs.dbf' size 100M;

Tablespace created.

SQL> select tablespace_name, file_name, bytes/1048576 File_Size_MB, autoextensible, increment_by from dba_data_files order by file_id;

TABLESPACE_NAME FILE_NAME FILE_SIZE_MB AUT INCREMENT_BY
--------------- ------------------------------------------------------- ------------ --- ------------
SYSTEM /oracle_fs/Databases/ORT24FS/system01.dbf 590 YES 1,280
UNDOTBS1 /oracle_fs/Databases/ORT24FS/undotbs01.dbf 155 YES 640
SYSAUX /oracle_fs/Databases/ORT24FS/sysaux01.dbf 270 YES 1,280
USERS /oracle_fs/Databases/ORT24FS/users01.dbf 85 YES 160
EXAMPLE /oracle_fs/Databases/ORT24FS/example01.dbf 100 YES 80
TEST_A_TBS /oracle_fs/Databases/ORT24FS/test_a_tbs.dbf 100 NO 0
AN_OMF_TBS /var/tmp/ORT24FS/datafile/o1_mf_an_omf_t_541wgb0c_.dbf 100 YES 12,800
REGULAR_TBS /oracle_fs/Databases/ORT24FS/regular_tbs.dbf 100 NO 0

8 rows selected.

SQL> create tablespace ANOTHER_TBS datafile '/oracle_fs/Databases/ORT24FS/another_tbs.dbf' size 100M autoextend on ;

Tablespace created.

SQL> select tablespace_name, file_name, bytes/1048576 File_Size_MB, autoextensible, increment_by from dba_data_files order by file_id;

TABLESPACE_NAME FILE_NAME FILE_SIZE_MB AUT INCREMENT_BY
--------------- ------------------------------------------------------- ------------ --- ------------
SYSTEM /oracle_fs/Databases/ORT24FS/system01.dbf 590 YES 1,280
UNDOTBS1 /oracle_fs/Databases/ORT24FS/undotbs01.dbf 155 YES 640
SYSAUX /oracle_fs/Databases/ORT24FS/sysaux01.dbf 270 YES 1,280
USERS /oracle_fs/Databases/ORT24FS/users01.dbf 85 YES 160
EXAMPLE /oracle_fs/Databases/ORT24FS/example01.dbf 100 YES 80
TEST_A_TBS /oracle_fs/Databases/ORT24FS/test_a_tbs.dbf 100 NO 0
AN_OMF_TBS /var/tmp/ORT24FS/datafile/o1_mf_an_omf_t_541wgb0c_.dbf 100 YES 12,800
REGULAR_TBS /oracle_fs/Databases/ORT24FS/regular_tbs.dbf 100 NO 0
ANOTHER_TBS /oracle_fs/Databases/ORT24FS/another_tbs.dbf 100 YES 1

9 rows selected.

SQL>


You would be well-adviced to remember that when you create or add a non-OMF datafile, you should specify the Increment size with the AutoExtend ON. Else, you might suffer the overheads of Oracle having to make multiple calls to the OS whenever extending the datafile (imagine extending a datafile 1 block at each call for an extent of 64MB !)


SQL> create tablespace LAST_TBS datafile '/oracle_fs/Databases/ORT24FS/last_tbs.dbf' size 100M autoextend on next 100M;

Tablespace created.

SQL> select tablespace_name, file_name, bytes/1048576 File_Size_MB, autoextensible, increment_by from dba_data_files order by file_id;

TABLESPACE_NAME FILE_NAME FILE_SIZE_MB AUT INCREMENT_BY
--------------- ------------------------------------------------------- ------------ --- ------------
SYSTEM /oracle_fs/Databases/ORT24FS/system01.dbf 590 YES 1,280
UNDOTBS1 /oracle_fs/Databases/ORT24FS/undotbs01.dbf 155 YES 640
SYSAUX /oracle_fs/Databases/ORT24FS/sysaux01.dbf 270 YES 1,280
USERS /oracle_fs/Databases/ORT24FS/users01.dbf 85 YES 160
EXAMPLE /oracle_fs/Databases/ORT24FS/example01.dbf 100 YES 80
TEST_A_TBS /oracle_fs/Databases/ORT24FS/test_a_tbs.dbf 100 NO 0
AN_OMF_TBS /var/tmp/ORT24FS/datafile/o1_mf_an_omf_t_541wgb0c_.dbf 100 YES 12,800
REGULAR_TBS /oracle_fs/Databases/ORT24FS/regular_tbs.dbf 100 NO 0
ANOTHER_TBS /oracle_fs/Databases/ORT24FS/another_tbs.dbf 100 YES 1
LAST_TBS /oracle_fs/Databases/ORT24FS/last_tbs.dbf 100 YES 12,800

10 rows selected.

SQL>

Tablespace LAST_TBS's datafile is created with a meaningful Increment for AutoExtend.

.
.
.

11 comments:

Pascal said...

Hi Hemant;
Is this assumption correct?

If I specify autoextend on,and omit next clause (not OMF).

Oracle would extend the datafile by the size of extent (for UNIFORM size)
and for autoallocate what ever size come up as per autoallocate algorithm.
and it never extents 1block,1block,etc..

Hemant K Chitale said...

Pascal,
This is something you could test for yourself.

Hemant K Chitale

Pascal said...

Hi Hemant;

Someone in Otn forum told me that,
it will extend 1 block, 1block and
thus it has negative impact on performance.

Someother person told me that oracle is clever, will never extend 1 block,1 block,etc...
Instead of this,the event in my previous post will occur.

I am in dilemma. What do u think?

Hemant K Chitale said...

I am not in a dilemma.

Ths conversation is OVER.

Eric said...

Hi Hemant;
I just read some docs and did some tests,
I notice that,
When we omit next clause and specify autoextend on (not omf)

Oracle would not make lots of one block increases - it would figure out "hey, I need 1mb of space - I better grow by 1mb - in 1 block units"

Correct me if I am wrong

Hemant K Chitale said...

Eric,

I haven't tested this myself. But I do believe that you are right. Oracle should be intelligent enough to make a single multiblock request to extend a datafile -- this behaviour could vary by version, platform and the size of the extent required.
The fact is that it seems that the default is still supposed to be 1 block, but since AutoExtend was introduced way back in 7.3 (or 7.2 ?), I am sure Oracle has fixed the behaviour to improve on the default.

EVIL said...

Hi Hemant, sorry to mention this but.. If you are providing a suggestion or answer in your blog, people tend to ask questions. Even I get lots of doubts in your explaination but really taken back on the way you have replied to Pascal and Eric. :):)

Hemant K Chitale said...

Evil,
You are too quick to judge. You haven't seen the manner of other questions I had received earlier. You haven't seen the many other answers I have provided in other posts.

Hemant

Mannji said...

Hi

can we use increment by parameter in auto extend on its overcome the default 1 block size extend?

Hemant K Chitale said...

Mannji,

Use ALTER DATABASE DATAFILE '...' AUTOEXTEND ON NEXT 100M ; -- to change the autoextend to 100MB

valiantvimal said...

Thanks Hemant..Your Article is helpful.