Oracle FAQ | Your Portal to the Oracle Knowledge Grid |
![]() |
![]() |
Home -> Community -> Mailing Lists -> Oracle-L -> RE: PCTUSED - when is block added to freelist?
The MetaLink note didn't seem to make it clear, at least not to me.
I ran the following test which initially filled 7 blocks. Adding one more row as seen in the test, causes additional blocks to be added with the current PCTFREE and PCTUSED settings.
set echo on
drop table fb;
create table fb(
mydata varchar2(100)
)
tablespace system
pctused 20
pctfree 80
storage( initial 8k next 8k pctincrease 0 )
/
begin
analyze table fb compute statistics;
select blocks, empty_blocks
from user_tables
where table_name = 'FB'
/
insert into fb(mydata)
values(rpad('',100,'X'));
commit;
analyze table fb compute statistics;
select blocks, empty_blocks
from user_tables
where table_name = 'FB'
/
set echo off
Here are the results:
09:32:23 rsysdevdb.radisys.com - jkstill_at_dv01 SQL> drop table fb;
Table dropped.
09:32:23 rsysdevdb.radisys.com - jkstill_at_dv01 SQL>
09:32:23 rsysdevdb.radisys.com - jkstill_at_dv01 SQL> -- create in SYSTEM
tablespace, as it is
09:32:23 rsysdevdb.radisys.com - jkstill_at_dv01 SQL> -- the only dictionary
managed TBS in the DB
09:32:23 rsysdevdb.radisys.com - jkstill_at_dv01 SQL> 09:32:23 rsysdevdb.radisys.com - jkstill_at_dv01 SQL> create table fb( 09:32:23 2 mydata varchar2(100) 09:32:23 3 ) 09:32:23 4 tablespace system 09:32:23 5 pctused 20 09:32:23 6 pctfree 80 09:32:23 7 storage( initial 8k next 8k pctincrease 0 ) 09:32:23 8 /
Table created.
09:32:23 rsysdevdb.radisys.com - jkstill_at_dv01 SQL> 09:32:23 rsysdevdb.radisys.com - jkstill_at_dv01 SQL> begin 09:32:23 2 -- maximum rows that will fit in initial blocks 09:32:23 3 for r in 1..1029 09:32:23 4 loop 09:32:23 5 insert into fb(mydata) 09:32:23 6 values(rpad('',100,'X')); 09:32:23 7 end loop; 09:32:23 8 commit; 09:32:23 9 end; 09:32:23 10 /
PL/SQL procedure successfully completed.
09:32:23 rsysdevdb.radisys.com - jkstill_at_dv01 SQL> 09:32:23 rsysdevdb.radisys.com - jkstill_at_dv01 SQL> analyze table fb compute statistics;
Table analyzed.
09:32:23 rsysdevdb.radisys.com - jkstill_at_dv01 SQL> 09:32:23 rsysdevdb.radisys.com - jkstill_at_dv01 SQL> select blocks, empty_blocks
09:32:23 2 from user_tables 09:32:23 3 where table_name = 'FB' 09:32:23 4 / BLOCKS EMPTY BLOCKS ----------- ------------ 7 0
1 row selected.
09:32:23 rsysdevdb.radisys.com - jkstill_at_dv01 SQL> 09:32:23 rsysdevdb.radisys.com - jkstill_at_dv01 SQL> 09:32:23 rsysdevdb.radisys.com - jkstill_at_dv01 SQL> insert into fb(mydata) 09:32:23 2 values(rpad('',100,'X'));
1 row created.
09:32:23 rsysdevdb.radisys.com - jkstill_at_dv01 SQL> commit;
Commit complete.
09:32:23 rsysdevdb.radisys.com - jkstill_at_dv01 SQL> 09:32:23 rsysdevdb.radisys.com - jkstill_at_dv01 SQL> analyze table fb compute statistics;
Table analyzed.
09:32:23 rsysdevdb.radisys.com - jkstill_at_dv01 SQL> 09:32:23 rsysdevdb.radisys.com - jkstill_at_dv01 SQL> select blocks, empty_blocks
09:32:23 2 from user_tables 09:32:23 3 where table_name = 'FB' 09:32:23 4 / BLOCKS EMPTY BLOCKS ----------- ------------ 12 3
1 row selected.
09:32:23 rsysdevdb.radisys.com - jkstill_at_dv01 SQL> 09:32:23 rsysdevdb.radisys.com - jkstill_at_dv01 SQL> set echo off
I next added the following line just before the final row is inserted:
alter table fb pctused 80 pctfree 20;
No new blocks were added this time, suggesting that the blocks were put on
the
freelist at the time of INSERT. A more thorough explanation requires
running a
trace, but this was enough for me.
09:34:49 rsysdevdb.radisys.com - jkstill_at_dv01 SQL> @fb2 09:34:50 rsysdevdb.radisys.com - jkstill_at_dv01 SQL> 09:34:50 rsysdevdb.radisys.com - jkstill_at_dv01 SQL> drop table fb;
Table dropped.
09:34:50 rsysdevdb.radisys.com - jkstill_at_dv01 SQL>
09:34:50 rsysdevdb.radisys.com - jkstill_at_dv01 SQL> -- create in SYSTEM
tablespace, as it is
09:34:50 rsysdevdb.radisys.com - jkstill_at_dv01 SQL> -- the only dictionary
managed TBS in the DB
09:34:50 rsysdevdb.radisys.com - jkstill_at_dv01 SQL> 09:34:50 rsysdevdb.radisys.com - jkstill_at_dv01 SQL> create table fb( 09:34:50 2 mydata varchar2(100) 09:34:50 3 ) 09:34:50 4 tablespace system 09:34:50 5 pctused 20 09:34:50 6 pctfree 80 09:34:50 7 storage( initial 8k next 8k pctincrease 0 ) 09:34:50 8 /
Table created.
09:34:50 rsysdevdb.radisys.com - jkstill_at_dv01 SQL> 09:34:50 rsysdevdb.radisys.com - jkstill_at_dv01 SQL> begin 09:34:50 2 -- maximum rows that will fit in initial blocks 09:34:50 3 for r in 1..1029 09:34:50 4 loop 09:34:50 5 insert into fb(mydata) 09:34:50 6 values(rpad('',100,'X')); 09:34:50 7 end loop; 09:34:50 8 commit; 09:34:50 9 end; 09:34:50 10 /
PL/SQL procedure successfully completed.
09:34:50 rsysdevdb.radisys.com - jkstill_at_dv01 SQL> 09:34:50 rsysdevdb.radisys.com - jkstill_at_dv01 SQL> analyze table fb compute statistics;
Table analyzed.
09:34:50 rsysdevdb.radisys.com - jkstill_at_dv01 SQL> 09:34:50 rsysdevdb.radisys.com - jkstill_at_dv01 SQL> select blocks, empty_blocks
09:34:50 2 from user_tables 09:34:50 3 where table_name = 'FB' 09:34:50 4 / BLOCKS EMPTY BLOCKS ----------- ------------ 7 0
1 row selected.
09:34:50 rsysdevdb.radisys.com - jkstill_at_dv01 SQL> 09:34:50 rsysdevdb.radisys.com - jkstill_at_dv01 SQL> 09:34:50 rsysdevdb.radisys.com - jkstill_at_dv01 SQL> alter table fb pctused80 pctfree 20;
Table altered.
09:34:50 rsysdevdb.radisys.com - jkstill_at_dv01 SQL> 09:34:50 rsysdevdb.radisys.com - jkstill_at_dv01 SQL> insert into fb(mydata) 09:34:50 2 values(rpad('',100,'X'));
1 row created.
09:34:50 rsysdevdb.radisys.com - jkstill_at_dv01 SQL> commit;
Commit complete.
09:34:50 rsysdevdb.radisys.com - jkstill_at_dv01 SQL> 09:34:50 rsysdevdb.radisys.com - jkstill_at_dv01 SQL> analyze table fb compute statistics;
Table analyzed.
09:34:50 rsysdevdb.radisys.com - jkstill_at_dv01 SQL> 09:34:50 rsysdevdb.radisys.com - jkstill_at_dv01 SQL> select blocks, empty_blocks
09:34:50 2 from user_tables 09:34:50 3 where table_name = 'FB' 09:34:50 4 / BLOCKS EMPTY BLOCKS ----------- ------------ 7 0
1 row selected.
09:34:50 rsysdevdb.radisys.com - jkstill_at_dv01 SQL> 09:34:50 rsysdevdb.radisys.com - jkstill_at_dv01 SQL> set echo off
Rick_Cale_at_teamhealth.com
Sent by: root_at_fatcity.com
09/04/2002 09:33 AM
Please respond to ORACLE-L
To: Multiple recipients of list ORACLE-L <ORACLE-L_at_fatcity.com> cc: Subject: RE: PCTUSED - when is block added to freelist?
See Note: 1029850.6 on MetaLink for more details but here is algorithm
used
for freelist
A block is put on free list if the free space in the block is greater than the space reserved by PCTFREE. Blockslinked in a free list are
futureupdates or inserts.
A block is unlinked from a free list if the free space in the block is not enough to allow a new row insert, and if the percentage of the used space remainsabove PCTUSED.
A block is relinked to a free list ifafter DELETE or UPDATE
fallsbelow PCTUSED.
Each time a block is added to a free list, it is linked at the head of the chain.
Rick
"Miller, Jay" <JayMiller_at_TDWater To: Multiple recipients of list ORACLE-L <ORACLE-L_at_fatcity.com> house.com> cc: Sent by: Subject: RE: PCTUSED - when is block added to freelist? root_at_fatcity.com 09/04/2002 11:03 AM Please respond to ORACLE-L
Yes, that's what I intended to ask :).
Thanks, Jared.
Jay
-----Original Message-----
Sent: Tuesday, September 03, 2002 9:18 PM
To: Multiple recipients of list ORACLE-L
If I understand Jay's question correctly, what he's asking is not how PCTUSED and PCTFREE work, but "what action or actions trigger Oracle to put a block back on the freelist after changing PCTUSED to a higher value?"
Is that correct Jay?
Jared
On Tuesday 03 September 2002 15:38, Miller, Jay wrote: > I have one huge table (takes up about 30% of the total database storage) > which has a monthly batch deletion of old data. I had PCTFREE and PCTUSED
> set to the defaults of 10 and 40 respectively. > > I occurred to me that I could probably free up a lot more space by > increasing the PCTUSED so that more blocks would be available to bewritten
> here). > > So my question is, if I just raise the PCTUSED from 40 to, say, 75 would > all blocks that fall into the 40-75 range become available for inserts?Or
> is it only after their next update or delete? > > Different sections of the docs seem to imply different things. The docs > say: > > A lower PCTUSED reduces processing costs incurred during UPDATE andDELETE
> statements for moving a block to the free list when the block has fallen > below that percentage of usage. > > This seems to imply that it won't be moved to the freelist until adelete
> or update is done that affects that block. > > > But they also say: > > A higher PCTUSED increases processing cost during INSERTs and UPDATEs. > > This seems to imply that when it's looking to do the insert it mightfind
> that it can insert to a block. > > > Anyway, why would a lower PCTUSED reduce processing costs during aDELETE
> but a higher PCTUSED wouldn't increase processing costs during a DELETE. > That makes no sense. I'm befuddled. > > > TIA, > Jay Miller
-- Please see the official ORACLE-L FAQ: http://www.orafaq.com -- Author: Jared Still INET: jkstill_at_cybcon.com Fat City Network Services -- (858) 538-5051 FAX: (858) 538-5051 San Diego, California -- Public Internet access / Mailing Lists -------------------------------------------------------------------- To REMOVE yourself from this mailing list, send an E-Mail message to: ListGuru_at_fatcity.com (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). -- Please see the official ORACLE-L FAQ: http://www.orafaq.com -- Author: Miller, Jay INET: JayMiller_at_TDWaterhouse.com Fat City Network Services -- (858) 538-5051 FAX: (858) 538-5051 San Diego, California -- Public Internet access / Mailing Lists -------------------------------------------------------------------- To REMOVE yourself from this mailing list, send an E-Mail message to: ListGuru_at_fatcity.com (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).Received on Wed Sep 04 2002 - 15:59:25 CDT
--
Please see the official ORACLE-L FAQ: http://www.orafaq.com
--
Author: INET: Rick_Cale_at_teamhealth.com Fat City Network Services -- (858) 538-5051 FAX: (858) 538-5051 San Diego, California -- Public Internet access / Mailing Lists -------------------------------------------------------------------- To REMOVE yourself from this mailing list, send an E-Mail message to: ListGuru_at_fatcity.com (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).
--
Please see the official ORACLE-L FAQ: http://www.orafaq.com
--
Author: INET: Jared.Still_at_radisys.com Fat City Network Services -- (858) 538-5051 FAX: (858) 538-5051 San Diego, California -- Public Internet access / Mailing Lists -------------------------------------------------------------------- To REMOVE yourself from this mailing list, send an E-Mail message to: ListGuru_at_fatcity.com (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).
![]() |
![]() |