What should be the size of UNDO tablespace? Generally this question is vaguely answered saying that sizing comes with experience (of DBA) or looking at load on server or sometimes even by the number of ORA-1555 or out of space errors.
This paper is to help DBA’s in calculating the size of UNDO tablespace by using a simple formula.
While designing an application, generally it is tough to know about the number of transactions and subsequently number of rows changed per second.
So I suggest having a “big undo tablespace” to start with and based on load, after doing some calculations and resize your UNDO tablespace.
In my case one of the applications was going to production (live), and I had no idea that how many transactions will happen against this database. All what I was told that there will be optimum (transactional) activity on this database. The word “optimum” itself is vague.
So I started with UNDO tablespace with size of 2GB and datafiles with autoextend “on” .
Note:
In production, you must be very careful in using this (autoextend on) as the space may grow to inifinity very fast. So my advice is either dont use this option, or use with "maxsize" or continuously monitor space (which is tough).
I month later, I noticed the activity from V$undostat.
Here is the step by step approach:
Step 1: Longest running query.
SQL> select max(maxquerylen) from v$undostat;
MAX(MAXQUERYLEN)
----------------
1793
This gives you ideal value for UNDO_RETENTION. To be on the safer size you should add few more seconds to get the right value. So in my case, the size of undo retention should be say 2000 secs.
Step 2: Size of UNDO tablespace.
Size of UNDO needed = UNDO_RETENTION x [UNDO block Generation per sec x DB_BLOCK_SIZE] + Overhead(30xDB_BLOCK_SIZE)
Out of these we know UNDO_RETENTION and DB_BLOCK_SIZE
All we need is to find out “UNDO Blocks per second”
Which can be easily fetched from v$undostat
SQL> SELECT (SUM(undoblks))/ SUM ((end_time - begin_time) * 24*60*60) "UPS"
2 FROM v$undostat;
UPS
------------------------------
8.11985583
V$undostat stores data for every 10 mins and begin/end times are start/end time of those intervals. We multiplied it with 24*60*60 because the difference between two dates will be in days and to get to seconds, we need it to multiply with 24hrs*60mins*60secs
So now we have all the values needed.
Undo size needed = [8.12 x 2000 x 8192] + [30 x 8192] = 133283840 bytes = 127.11 MB
Showing posts with label Space management. Show all posts
Showing posts with label Space management. Show all posts
Thursday, February 15, 2007
Wednesday, February 7, 2007
Identify and fix table fragmentation in Oracle 10g - how?
Table fragmentation – when?
If a table is only subject to inserts, there will not be any fragmentation.
Fragmentation comes with when we update/delete data in table.
The space which gets freed up during non-insert DML operations is not immediately re-used (or sometimes, may not get reuse ever at all). This leaves behind holes in table which results in table fragmentation.
To understand it more clearly, we need to be clear on how oracle manages space for tables.
“High water mark” of table actually defines the border line between (ever) used and unused (never) space. While performing full table scan, Oracle will always read the data up to HWM. And if there is lot of free space with-in HWM, that is read too, and hence degrading the performance of FTS.
Now lets see how to identify HWM, unused (never used) space and free space (used but deleted/updated) and then take a call whether the concerned table is candidate for a reorganization or not.
SQL> create table test as select * from dba_tables; -- Create a table
Table created.
SQL> analyze table test compute statistics; -- Analyze it
Table analyzed.
SQL> select blocks "Ever Used", empty_blocks "Never Used", num_rows "Total rows"
2 from user_tables where table_name='TEST'; -- The number of blocks used/free
Ever Used Never Used Total rows
---------- ---------- ----------
49 6 1680
SQL> delete from test where owner='SYS'; --- Im deleting almost half the number of rows.
764 rows deleted.
SQL> commit;
Commit complete.
SQL> analyze table test compute statistics; -- Analyze it again
Table analyzed.
SQL> select blocks "Ever Used", empty_blocks "Never Used", num_rows "Total rows"
2 from user_tables where table_name='TEST'; -- No difference in blocks usage
Ever Used Never Used Total rows
---------- ---------- ----------
49 6 916
PL/SQL procedure successfully completed.
Even though you deleted almost half the rows, the above shows that table HWM is up to 49 blocks, and to perform any FTS, Oracle will go up to 49 blocks to search the data. If your application is so-written that there are many FTS on this table, you may consider, reorganizing this table.
Reasons to reorganization
a) Slower response time (from that table)
b) High number of chained (actually migrated) rows.
c) Table has grown many folds and the old space is not getting reused.
Note: Index based queries may not get that much benefited by reorg as compared to queries which does Full table scan.
How to reorganize?
Before Oracle 10g, there were mainly 2 ways to do the reorganization of the table
a) Export, drop, and import.
b) Alter tablemove (to another tablespace, or same tablespace).
Oracle 10g provides us a new way of reorganizing the data.
Shrink command: This command is only applicable for tables which are tablespace with auto segment space management.
Before using this command, you should have row movement enabled.
SQL> alter table test enable row movement;
Table altered.
There are 2 ways of using this command.
1. Break in two parts: In first part rearrange rows and in second part reset the HWM.
Part 1: Rearrange (All DML's can happen during this time)
SQL> alter table test shrink space compact;
Table altered.
Part 2: Reset HWM (No DML can happen. but this is fairly quick, infact goes unnoticed.)
SQL> alter table sa shrink space;
Table altered.
2. Do it in one go:
SQL> alter table sa shrink space; (Both rearrange and restting HWM happens in one statement)
Table altered.
Few advantages over the conventional methods
1. Unlike "alter table move ..", indexes are not in UNUSABLE state. After shrink command, indexes are updated also.
2. Its an online operation, So you dont need downtime to do this reorg.
3. It doesnot require any extra space for the process to complete.
Conclusion
Its a new 10g feature to shrink (reorg) the tables (almost) online which can be used with automatic segment space management.
If a table is only subject to inserts, there will not be any fragmentation.
Fragmentation comes with when we update/delete data in table.
The space which gets freed up during non-insert DML operations is not immediately re-used (or sometimes, may not get reuse ever at all). This leaves behind holes in table which results in table fragmentation.
To understand it more clearly, we need to be clear on how oracle manages space for tables.
“High water mark” of table actually defines the border line between (ever) used and unused (never) space. While performing full table scan, Oracle will always read the data up to HWM. And if there is lot of free space with-in HWM, that is read too, and hence degrading the performance of FTS.
Now lets see how to identify HWM, unused (never used) space and free space (used but deleted/updated) and then take a call whether the concerned table is candidate for a reorganization or not.
SQL> create table test as select * from dba_tables; -- Create a table
Table created.
SQL> analyze table test compute statistics; -- Analyze it
Table analyzed.
SQL> select blocks "Ever Used", empty_blocks "Never Used", num_rows "Total rows"
2 from user_tables where table_name='TEST'; -- The number of blocks used/free
Ever Used Never Used Total rows
---------- ---------- ----------
49 6 1680
SQL> delete from test where owner='SYS'; --- Im deleting almost half the number of rows.
764 rows deleted.
SQL> commit;
Commit complete.
SQL> analyze table test compute statistics; -- Analyze it again
Table analyzed.
SQL> select blocks "Ever Used", empty_blocks "Never Used", num_rows "Total rows"
2 from user_tables where table_name='TEST'; -- No difference in blocks usage
Ever Used Never Used Total rows
---------- ---------- ----------
49 6 916
PL/SQL procedure successfully completed.
Even though you deleted almost half the rows, the above shows that table HWM is up to 49 blocks, and to perform any FTS, Oracle will go up to 49 blocks to search the data. If your application is so-written that there are many FTS on this table, you may consider, reorganizing this table.
Reasons to reorganization
a) Slower response time (from that table)
b) High number of chained (actually migrated) rows.
c) Table has grown many folds and the old space is not getting reused.
Note: Index based queries may not get that much benefited by reorg as compared to queries which does Full table scan.
How to reorganize?
Before Oracle 10g, there were mainly 2 ways to do the reorganization of the table
a) Export, drop, and import.
b) Alter table
Oracle 10g provides us a new way of reorganizing the data.
Shrink command: This command is only applicable for tables which are tablespace with auto segment space management.
Before using this command, you should have row movement enabled.
SQL> alter table test enable row movement;
Table altered.
There are 2 ways of using this command.
1. Break in two parts: In first part rearrange rows and in second part reset the HWM.
Part 1: Rearrange (All DML's can happen during this time)
SQL> alter table test shrink space compact;
Table altered.
Part 2: Reset HWM (No DML can happen. but this is fairly quick, infact goes unnoticed.)
SQL> alter table sa shrink space;
Table altered.
2. Do it in one go:
SQL> alter table sa shrink space; (Both rearrange and restting HWM happens in one statement)
Table altered.
Few advantages over the conventional methods
1. Unlike "alter table move ..", indexes are not in UNUSABLE state. After shrink command, indexes are updated also.
2. Its an online operation, So you dont need downtime to do this reorg.
3. It doesnot require any extra space for the process to complete.
Conclusion
Its a new 10g feature to shrink (reorg) the tables (almost) online which can be used with automatic segment space management.
Subscribe to:
Posts (Atom)