RE: locally managed autoallocate (was: Separate Indexes and Data)

2003-10-02 Thread Niall Litchfield
  -Original Message-
  From: Jesse, Rich
  Sent: Wednesday, October 01, 2003 9:49 AM
  To: Multiple recipients of list ORACLE-L
  Subject: RE: locally managed autoallocate (was: Separate Indexes and
  Data)
  
  Theoritically, perhaps, but what if an existing table needs
  to auto-extend
  at 1M and all that's left in the table is 16 (or whatever) 
 
 (blush)  Obviously, that's supposed to say left in the tableSPACE.

9.0.1 'unable to allocate extent'

C:\Documents and Settings\Niallsqlplus niall/niall

SQL*Plus: Release 9.2.0.1.0 - Production on Thu Oct 2 21:59:45 2003

Copyright (c) 1982, 2002, Oracle Corporation.  All rights reserved.


Connected to:
Oracle9i Enterprise Edition Release 9.2.0.1.0 - Production
With the Partitioning, OLAP and Oracle Data Mining options
JServer Release 9.2.0.1.0 - Production

SQL create tablespace test_auto
  2  datafile 'c:\oracle\oradata\home9i\test_auto.dbf' size 1152k
  3  extent management local;

Tablespace created.

SQL create table t1(n number,charcol char(200))
  2  tablespace test_auto
  3  ;

Table created.

SQL select count(*) from dba_extents where segment_name='T1';

  COUNT(*)
--
 1

SQL begin
  2  for i in 1..14 loop
  3  execute immediate 'alter table t1 allocate extent';
  4  end loop;
  5  end;
  6  /

PL/SQL procedure successfully completed.

SQL analyze table t1 compute statistics;

Table analyzed.

SQL select count(*) from dba_extents where segment_name='T1';

  COUNT(*)
--
15

SQL alter table t1 allocate extent;

Table altered.

SQL select count(*) from dba_extents where segment_name='T1';

  COUNT(*)
--
16

SQL alter table t1 allocate extent;
alter table t1 allocate extent
*
ERROR at line 1:
ORA-01653: unable to extend table NIALL.T1 by 128 in tablespace
TEST_AUTO


SQL select bytes from dba_free_space where tablespace_name='TEST_AUTO';

 BYTES
--
 65536

SQL create table tX(n number,charcol char(200))
  2  tablespace test_auto;

Table created.


Niall 

-- 
Please see the official ORACLE-L FAQ: http://www.orafaq.net
-- 
Author: Niall Litchfield
  INET: [EMAIL PROTECTED]

Fat City Network Services-- 858-538-5051 http://www.fatcity.com
San Diego, California-- Mailing list and web hosting services
-
To REMOVE yourself from this mailing list, send an E-Mail message
to: [EMAIL PROTECTED] (note EXACT spelling of 'ListGuru') and in
the message BODY, include a line containing: UNSUB ORACLE-L
(or the name of mailing list you want to be removed from).  You may
also send the HELP command for other information (like subscribing).


RE: locally managed autoallocate (was: Separate Indexes and Data)

2003-10-02 Thread Jesse, Rich
Well, sort of.  If I had a 9i DB to play with, I'd try this myself...

1)  Create an SMT.
2)  Create 50 tables in that TS.
3)  Drop every even table just created.
4)  Extend one of the remaining tables until you can't.

Depending on the size of the TS created and the blocksize, you could have a
situation where there's enough freespace in the TS, but not contiguous.
Thus, fragmentation.

Granted, this is isn't a typical case, but over a year or two, I could see
it happening here.

Maybe I'll install 9iR2 at home tonite to try this...sigh


Rich

Rich Jesse   System/Database Administrator
[EMAIL PROTECTED]  Quad/Tech Inc, Sussex, WI USA


 -Original Message-
 From: Niall Litchfield [mailto:[EMAIL PROTECTED]
 Sent: Thursday, October 02, 2003 5:10 PM
 To: Multiple recipients of list ORACLE-L
 Subject: RE: locally managed autoallocate (was: Separate Indexes and
 Data)
 
 
   -Original Message-
   From: Jesse, Rich
   Sent: Wednesday, October 01, 2003 9:49 AM
   To: Multiple recipients of list ORACLE-L
   Subject: RE: locally managed autoallocate (was: Separate 
 Indexes and
   Data)
   
   Theoritically, perhaps, but what if an existing table needs
   to auto-extend
   at 1M and all that's left in the table is 16 (or whatever) 
  
  (blush)  Obviously, that's supposed to say left in the tableSPACE.
 
 9.0.1 'unable to allocate extent'
 
 C:\Documents and Settings\Niallsqlplus niall/niall
 
 SQL*Plus: Release 9.2.0.1.0 - Production on Thu Oct 2 21:59:45 2003
 
 Copyright (c) 1982, 2002, Oracle Corporation.  All rights reserved.
 
 
 Connected to:
 Oracle9i Enterprise Edition Release 9.2.0.1.0 - Production
 With the Partitioning, OLAP and Oracle Data Mining options
 JServer Release 9.2.0.1.0 - Production
 
 SQL create tablespace test_auto
   2  datafile 'c:\oracle\oradata\home9i\test_auto.dbf' size 1152k
   3  extent management local;
 
 Tablespace created.
 
 SQL create table t1(n number,charcol char(200))
   2  tablespace test_auto
   3  ;
 
 Table created.
 
 SQL select count(*) from dba_extents where segment_name='T1';
 
   COUNT(*)
 --
  1

 
[snip]
-- 
Please see the official ORACLE-L FAQ: http://www.orafaq.net
-- 
Author: Jesse, Rich
  INET: [EMAIL PROTECTED]

Fat City Network Services-- 858-538-5051 http://www.fatcity.com
San Diego, California-- Mailing list and web hosting services
-
To REMOVE yourself from this mailing list, send an E-Mail message
to: [EMAIL PROTECTED] (note EXACT spelling of 'ListGuru') and in
the message BODY, include a line containing: UNSUB ORACLE-L
(or the name of mailing list you want to be removed from).  You may
also send the HELP command for other information (like subscribing).


RE: locally managed autoallocate (was: Separate Indexes and Data)

2003-10-01 Thread Jesse, Rich
 -Original Message-
 From: Jacques Kilchoer [mailto:[EMAIL PROTECTED]
 Sent: Tuesday, September 30, 2003 7:34 PM
 To: Multiple recipients of list ORACLE-L
 Subject: locally managed autoallocate (was: Separate Indexes and Data)
 
 
  Ive read the book. PCTINCREASE is basically set to 100% so 
  the extent sizes double. Thats 'basically' how it works. I 
  have seen some posts on dejanews saying it doesnt necessarily 
  work this way and some people are finding large extent sizes 
  with just a few extents and when tables are dropped this is 
  leading to fragmentation. It hasnt happened to me, but the 
  posts on dejanews were from some pretty good posters. So Im 
  playing conservative. We also had one of the contributors 
  here mention issues. 
 
 
 I think Jonathan Lewis has explained the algorithm before, 
 but it's also something that we have investigated here.
 The algorithm (ignoring some details) is:
 There will be 4 extent sizes used, 64K, 1M, 8M, 64M
 As long as object allocation is 1M or less, 64K extent sizes are used,
 When object allocation is between 1M and 64M, 1M extent sizes 
 are used.
 When object allocation is between 64M and 1G, 8M extent sizes 
 are used.
 When object allocation is more than 1G, 64M extent sizes are used.
 
 However, when you initially create the object, the extents 
 are determined by figuring out the space allocated to the 
 newly created object taking into account the INITIAL, NEXT, 
 PCTINCREASE, MINEXTENTS storage parameters. So the object 
 might start off with 1M extents instead of starting off with 
 64K extents. The algorithm is similar to the one outlined 
 above but it is more complicated. The NEXT and PCTINCREASE 
 seem to be ignored after the object is created.
 e.g.
 create table ... tablespace locally_managed_autoallocate
   storage (initial 1M next 512K minextents 15 pctincrease 0) ... ;
 Initial allocation will be 1M + (15 - 1) * 512K = 8M
 When you create the table, you will see eight extents, each 
 of one megabyte.
 
 There are additional wrinkles, but I don't think the 
 algorithm has bugs.
 
 I don't think that there really is fragmentation in the 
 sense that an unused extent will remain unused forever. All 
 extents will be in one of the 4 sizes mentioned above, and 
 all are subject to reuse at some point.

Theoritically, perhaps, but what if an existing table needs to auto-extend
at 1M and all that's left in the table is 16 (or whatever) 64K chunks.  I
still maintain that system-managed tablespaces are barely better than DMTs
-- fragmentation is still potentially a problem and needs to be monitored.

On the flip-side, LMT segments need to be watched too in case they are
growing beyond the design of the TS (e.g. more than 1024 or how ever many
extents).  I'd much rather deal with the latter because it's much less
likely to happen unexpectedly in our environment.

Rich

Rich Jesse   System/Database Administrator
[EMAIL PROTECTED]  Quad/Tech Inc, Sussex, WI USA
-- 
Please see the official ORACLE-L FAQ: http://www.orafaq.net
-- 
Author: Jesse, Rich
  INET: [EMAIL PROTECTED]

Fat City Network Services-- 858-538-5051 http://www.fatcity.com
San Diego, California-- Mailing list and web hosting services
-
To REMOVE yourself from this mailing list, send an E-Mail message
to: [EMAIL PROTECTED] (note EXACT spelling of 'ListGuru') and in
the message BODY, include a line containing: UNSUB ORACLE-L
(or the name of mailing list you want to be removed from).  You may
also send the HELP command for other information (like subscribing).


RE: locally managed autoallocate (was: Separate Indexes and Data)

2003-10-01 Thread Jesse, Rich
 -Original Message-
 From: Jesse, Rich 
 Sent: Wednesday, October 01, 2003 9:49 AM
 To: Multiple recipients of list ORACLE-L
 Subject: RE: locally managed autoallocate (was: Separate Indexes and
 Data)
 
 Theoritically, perhaps, but what if an existing table needs 
 to auto-extend
 at 1M and all that's left in the table is 16 (or whatever) 

(blush)  Obviously, that's supposed to say left in the tableSPACE.

 64K chunks.  I
 still maintain that system-managed tablespaces are barely 
 better than DMTs
 -- fragmentation is still potentially a problem and needs to 
 be monitored.
 
 On the flip-side, LMT segments need to be watched too in case they are
 growing beyond the design of the TS (e.g. more than 1024 or 
 how ever many
 extents).  I'd much rather deal with the latter because it's much less
 likely to happen unexpectedly in our environment.
 
 Rich

Rich

Rich Jesse   System/Database Administrator
[EMAIL PROTECTED]  Quad/Tech Inc, Sussex, WI USA
-- 
Please see the official ORACLE-L FAQ: http://www.orafaq.net
-- 
Author: Jesse, Rich
  INET: [EMAIL PROTECTED]

Fat City Network Services-- 858-538-5051 http://www.fatcity.com
San Diego, California-- Mailing list and web hosting services
-
To REMOVE yourself from this mailing list, send an E-Mail message
to: [EMAIL PROTECTED] (note EXACT spelling of 'ListGuru') and in
the message BODY, include a line containing: UNSUB ORACLE-L
(or the name of mailing list you want to be removed from).  You may
also send the HELP command for other information (like subscribing).


locally managed autoallocate (was: Separate Indexes and Data)

2003-09-30 Thread Jacques Kilchoer
 Ive read the book. PCTINCREASE is basically set to 100% so 
 the extent sizes double. Thats 'basically' how it works. I 
 have seen some posts on dejanews saying it doesnt necessarily 
 work this way and some people are finding large extent sizes 
 with just a few extents and when tables are dropped this is 
 leading to fragmentation. It hasnt happened to me, but the 
 posts on dejanews were from some pretty good posters. So Im 
 playing conservative. We also had one of the contributors 
 here mention issues. 


I think Jonathan Lewis has explained the algorithm before, but it's also something 
that we have investigated here.
The algorithm (ignoring some details) is:
There will be 4 extent sizes used, 64K, 1M, 8M, 64M
As long as object allocation is 1M or less, 64K extent sizes are used,
When object allocation is between 1M and 64M, 1M extent sizes are used.
When object allocation is between 64M and 1G, 8M extent sizes are used.
When object allocation is more than 1G, 64M extent sizes are used.

However, when you initially create the object, the extents are determined by figuring 
out the space allocated to the newly created object taking into account the INITIAL, 
NEXT, PCTINCREASE, MINEXTENTS storage parameters. So the object might start off with 
1M extents instead of starting off with 64K extents. The algorithm is similar to the 
one outlined above but it is more complicated. The NEXT and PCTINCREASE seem to be 
ignored after the object is created.
e.g.
create table ... tablespace locally_managed_autoallocate
  storage (initial 1M next 512K minextents 15 pctincrease 0) ... ;
Initial allocation will be 1M + (15 - 1) * 512K = 8M
When you create the table, you will see eight extents, each of one megabyte.

There are additional wrinkles, but I don't think the algorithm has bugs.

I don't think that there really is fragmentation in the sense that an unused extent 
will remain unused forever. All extents will be in one of the 4 sizes mentioned above, 
and all are subject to reuse at some point.
-- 
Please see the official ORACLE-L FAQ: http://www.orafaq.net
-- 
Author: Jacques Kilchoer
  INET: [EMAIL PROTECTED]

Fat City Network Services-- 858-538-5051 http://www.fatcity.com
San Diego, California-- Mailing list and web hosting services
-
To REMOVE yourself from this mailing list, send an E-Mail message
to: [EMAIL PROTECTED] (note EXACT spelling of 'ListGuru') and in
the message BODY, include a line containing: UNSUB ORACLE-L
(or the name of mailing list you want to be removed from).  You may
also send the HELP command for other information (like subscribing).


Re: locally managed autoallocate (was: Separate Indexes and Data)

2003-09-30 Thread Mladen Gogala
Yes, and there is one thing to add:
If you do not specify INTIAL, the extent allocation starts with  5 blocks for
the intial  extent. For 8k, it's 40k, but  in an autoallocating LMT extent  
cannot be smaller then 64k, so it is the amount of the space allocated.	The  
interesting question is: what happens with blocksize-16k? Will there be 64k
or two extents of 64k, i.e. 128k?
Here is the answer:

SQL create tablespace test1
 2  datafile '/data/oradata/data/test101.dbf' size 64M reuse
 3  autoextend on next 64m maxsize 513M
 4  extent management local autoallocate
 5  segment space management auto
 6  blocksize 16k
 7  /
Tablespace created.

SQL create table a (a number) tablespace test1;

Table created.

SQL select owner,segment_name,extent_id,blocks
 2  from dba_extents
 3  where segment_name='A'and tablespace_name='TEST1'
 4  and owner=user
 5  /
OWNER  SEGMENT_NA  EXTENT_ID BLOCKS
-- -- -- --
OPS$MGOGALAA   0 64
16k*64=1M. That means that oracle will allocate a full megabyte for the  
initial extent. It cannot take 64k, because it's smaller then 5*16k
(that number of 5 blocks is hardwired into the RDBMS since time immemorial)
and it cannot take two extents because that would, in turn, mean that the  
initial extent is smaller then 5 blocks. Therefore, it takes 1M. Jonathan  
Lewis was right. Here is one tecnique for optimizing the disk consumption in
such cases:

SQL drop tablespace test1 including contents and datafiles;

Tablespace dropped.

SQL



On 2003.09.30 20:34, Jacques Kilchoer wrote:
 Ive read the book. PCTINCREASE is basically set to 100% so
 the extent sizes double. Thats 'basically' how it works. I
 have seen some posts on dejanews saying it doesnt necessarily
 work this way and some people are finding large extent sizes
 with just a few extents and when tables are dropped this is
 leading to fragmentation. It hasnt happened to me, but the
 posts on dejanews were from some pretty good posters. So Im
 playing conservative. We also had one of the contributors
 here mention issues.
I think Jonathan Lewis has explained the algorithm before, but it's also
something that we have investigated here.
The algorithm (ignoring some details) is:
There will be 4 extent sizes used, 64K, 1M, 8M, 64M
As long as object allocation is 1M or less, 64K extent sizes are used,
When object allocation is between 1M and 64M, 1M extent sizes are used.
When object allocation is between 64M and 1G, 8M extent sizes are used.
When object allocation is more than 1G, 64M extent sizes are used.
However, when you initially create the object, the extents are determined by
figuring out the space allocated to the newly created object taking into
account the INITIAL, NEXT, PCTINCREASE, MINEXTENTS storage parameters. So  
the
object might start off with 1M extents instead of starting off with 64K
extents. The algorithm is similar to the one outlined above but it is more
complicated. The NEXT and PCTINCREASE seem to be ignored after the object is
created.
e.g.
create table ... tablespace locally_managed_autoallocate
  storage (initial 1M next 512K minextents 15 pctincrease 0) ... ;
Initial allocation will be 1M + (15 - 1) * 512K = 8M
When you create the table, you will see eight extents, each of one megabyte.

There are additional wrinkles, but I don't think the algorithm has bugs.

I don't think that there really is fragmentation in the sense that an
unused extent will remain unused forever. All extents will be in one of the  
4
sizes mentioned above, and all are subject to reuse at some point.
--
Please see the official ORACLE-L FAQ: http://www.orafaq.net
--
Author: Jacques Kilchoer
  INET: [EMAIL PROTECTED]

Fat City Network Services-- 858-538-5051 http://www.fatcity.com
San Diego, California-- Mailing list and web hosting services
-
To REMOVE yourself from this mailing list, send an E-Mail message
to: [EMAIL PROTECTED] (note EXACT spelling of 'ListGuru') and in
the message BODY, include a line containing: UNSUB ORACLE-L
(or the name of mailing list you want to be removed from).  You may
also send the HELP command for other information (like subscribing).
--
Mladen Gogala
Oracle DBA
--
Please see the official ORACLE-L FAQ: http://www.orafaq.net
--
Author: Mladen Gogala
 INET: [EMAIL PROTECTED]
Fat City Network Services-- 858-538-5051 http://www.fatcity.com
San Diego, California-- Mailing list and web hosting services
-
To REMOVE yourself from this mailing list, send an E-Mail message
to: [EMAIL PROTECTED] (note EXACT spelling of 'ListGuru') and in
the message BODY, include a line containing: UNSUB ORACLE-L
(or the name of mailing list you want to be removed from).  You may
also send the HELP command for other information (like subscribing).