Wednesday, January 4, 2017

Table Fragmentation in Oracle Database - to get performance benifit

In Oracle schema there are tables which has huge difference in actual size (size from User_segments) and expected size from user_tables (Num_rows*avg_row_length (in bytes)). This all is due to fragmentation in the table or stats for table are not updated into user_tables.

We will discuss:
1) What is Table Fragmentation?
2) How to understand HWM (High Water Mark) in table?
3) What are the reasons to reorganization of table?
4) How to find most fragmented tables?
5) How to reset HWM / remove fragmentation?
6) How to get more performance benefits from most fragmented tables?
7) Demo

1) What is Table Fragmentation?

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.

When rows are not stored contiguously, or if rows are split onto more than one block, performance decreases because these rows require additional block accesses.

Note that table fragmentation is different from file fragmentation. When a lot of DML operations are applied on a table, the table will become fragmented because DML does not release free space from the table below the HWM.(High Water Mark).

2) How to understand HWM (High Water Mark) in table?

HWM is an indicator of USED BLOCKS in the database. Blocks below the high water mark (used blocks) have at least once contained data. This data might have been deleted. Since Oracle knows that blocks beyond the high water mark don't have data, it only reads blocks up to the high water mark when doing a full table scan.

DDL statement always resets the HWM.

3) What are the reasons to reorganization of table?

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.

4) How to find most fragmented tables?

In Oracle schema there are tables which has huge difference in actual size (size from User_segments) and expected size from user_tables (Num_rows*avg_row_length (in bytes)). This all is due to fragmentation in the table or stats for table are not updated into dba_tables.

5) What actions to be taken on most fragmented tables?

Steps to Check and Remove Table Fragmentation:- 

i)  Gather table stats:

To check exact difference in table actual size (dba_segments) and stats size (dba_tables). The difference between these value will report actual fragmentation to DBA. So, We have to have updated stats on the table stored in dba_tables. Check LAST_ANALYZED value for table in dba_tables. If this value is recent you can skip this step. Other wise i would suggest to gather table stats to get updated stats.

exec dbms_stats.gather_table_stats('&schema_name','&table_name');

ii) Check Table size:

Now again check table size using and will find reduced size of the table.

select table_name,bytes/(1024*1024*1024) from dba_table where table_name='&table_name';  -- keep a track to match after fragmentation 

iii) Check for Fragmentation in table:

Below query will show the total size of table with fragmentation, expected without fragmentation and how much % of size we can reclaim after removing table fragmentation. Database Administrator has to provide table_name and schema_name as input to this query.

SQL>
set pages 50000 lines 32767;
select owner,
       table_name,
       round((blocks * 8), 2) || 'kb' "Fragmented size",
       round((num_rows * avg_row_len / 1024), 2) || 'kb' "Actual size",
       round((blocks * 8), 2) - round((num_rows * avg_row_len / 1024), 2) || 'kb',
       ((round((blocks * 8), 2) - round((num_rows * avg_row_len / 1024), 2)) /
       round((blocks * 8), 2)) * 100 - 10 "reclaimable space % "
  from dba_tables
 where table_name = '&table_Name'
   AND OWNER LIKE '&schema_name';
/

Note: This query fetch data from dba_tables, so the accuracy of result depends on dba_table stats.
To find Top 10 fragmentation tables
SQL>
select *
      from (select table_name,
               round((blocks * 8), 2) "size (kb)",
               round((num_rows * avg_row_len / 1024), 2) "actual_data (kb)",
               (round((blocks * 8), 2) -
               round((num_rows * avg_row_len / 1024), 2)) "wasted_space (kb)"
          from dba_tables
         where (round((blocks * 8), 2) >
               round((num_rows * avg_row_len / 1024), 2))
         order by 4 desc)
 WHERE ROWNUM <= 10;

If you find reclaimable space % value more than 20% then we can expect fragmentation in the table.

 Suppose, DBA find 50% reclaimable space by above query, So he can proceed for removing fragmentation.

5) How to reset HWM / remove fragmentation?

We have three options to reorganize fragmented tables:

1. Alter table move (to another tablespace, or same tablespace) and rebuild indexes:- 
   (Depends upon the free space available in the tablespace)  
2. Export and import the table:- (difficult to implement in production environment)
3. Shrink command (from Oracle 10g onwards)
   (Shrink command is only applicable for tables which are tablespace with auto segment space management)

Here, I am following Options 1 and 3 option by keeping table availability in mind. 

Option: 1 

Alter table move (to another tablespace, or same tablespace) and rebuild indexes:-
Collect status of all the indexes on the table:-

We will record Index status at one place, So that we get back them after completion of this exercise,  

SQL> select index_name,status from dba_indexes 
where table_name like '&table_name';

Move table in to same or new tablespace:
---------------------------------------
In this step we will move fragmented table to same tablespace or from one tablespace to another tablespace to reclaim fragmented space. Find Current size of you table from dba_segments and check if same or any other tablespace has same free space available. So, that we can move this table to same or new tablespace.

Steps to Move table in to same tablespace:

-----------------------------------------
alter table <table_name> move;   ------> Move to same tablespace

OR

Steps to Move table in to new tablespace:
----------------------------------------
alter table <table_name> enable row movement;
alter table <table_name> move tablespace <new_tablespace_name>;

Now, get back table to old tablespaces using below command

alter table table_name move tablespace old_tablespace_name;

Now,Rebuild all indexes:
-----------------------
We need to rebuild all the indexes on the table because of move command all the index goes into unusable state.

SQL> select status,index_name from dba_indexes where table_name = '&table_name';

STATUS INDEX_NAME
-------- ------------------------------
UNUSABLE INDEX_NAME                            -------> Here, value in status field may be valid or unusable.

SQL> alter index <INDEX_NAME> rebuild online;  -------> Use this command for each index
Index altered.

SQL> select status,index_name from dba_indexes where table_name = '&table_name';

STATUS INDEX_NAME
-------- ------------------------------
VALID INDEX_NAME                               -------> Here, value in status field must be valid.

After completing these steps, table statistics must be gathered.

Option: 2 Export and import the table:-

Click here to read from my posts

Option: 3 Shrink command (from Oracle 10g onwards):-
------------------------------------------

Shrink command: 
--------------
Its a new 10g feature to shrink (reorg) the tables (almost) online which can be used with automatic segment space 
management.

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 <table_name> enable row movement;
Table altered.

There are 2 ways of using this command.

1. Rearrange rows and reset the HWM:
-----------------------------------
Part 1: Rearrange (All DML's can happen during this time)

SQL> alter table <table_name> shrink space compact;
Table altered.

Part 2: Reset HWM (No DML can happen. but this is fairly quick, infact goes unnoticed.)

SQL> alter table <table_name> shrink space;
Table altered.

2. Directly reset the HWM:
-------------------------
(Both rearrange and restting HWM happens in one statement)
SQL> alter table <table_name> shrink space; 
Table altered.

Advantages over the conventional methods are:
--------------------------------------------
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.

After completing these steps, table statistics must be gathered.

6) How to get more performance benefits from most fragmented tables?

After doing above steps, you must gather statistics to tell optimizer to create best execution plan for better performance during query execution. Here I have given some auto sampling method to gather stats. Most of cases I got performance benefits when I did auto sampling method.

Gather table stats:
------------------
SQL> exec dbms_stats.gather_table_stats('&owner_name','&table_name');
PL/SQL procedure successfully completed.
OR
SQL> exec dbms_stats.gather_table_stats('&owner_name', '&table_name', estimate_percent => dbms_stats.auto_sample_size);
OR 
SQL> exec dbms_stats.gather_table_stats(ownname=>'&owner_name',
tabname=>'&table_name',estimate_percent => 100, cascade=>true, method_opt=>'for all columns size AUTO'); 

–- For entire schema
EXECUTE DBMS_STATS.GATHER_SCHEMA_STATS('&schema_name',DBMS_STATS.AUTO_SAMPLE_SIZE);

Check Table size:
-----------------
Now again check table size using and will find reduced size of the table.

SQL> select table_name,bytes/(1024*1024*1024) from dba_table where table_name='&table_name';

Now match with your earlier track, You must have some benefits. Sure performance will improve.

7) Demonstration:

Here I ll show you one demo activity. But when you will do, you first complete in your pre-prod database and collect performance statistics before and after. Then based on benefit, you can plan for production.

Demo:
1) Take all invalid objects counts for whole database as wel as applied schema

select count(1) from dba_objects where status='INVALID' -- 2386

select count(1) from dba_objects where status='INVALID' and owner='CUSTOMER' -- 0

2) Take Top list ( preferably 10) of tables for fragmenation

select *
  from (select table_name,
               round((blocks * 8), 2) "size (kb)",
               round((num_rows * avg_row_len / 1024), 2) "actual_data (kb)",
               (round((blocks * 8), 2) -
               round((num_rows * avg_row_len / 1024), 2)) "wasted_space (kb)"
          from dba_tables
         where (round((blocks * 8), 2) >
               round((num_rows * avg_row_len / 1024), 2))
         order by 4 desc)
 WHERE ROWNUM <= 10;

Output:

TABLE_NAME                      size (kb) actual_data (kb) wasted_space (kb)
------------------------------ ---------- ---------------- -----------------
CUSTOMER_SERVICES_DTLS       12382432      10341757.49       2040674.51
PKG_ACTUAL_AVAILABLE           7291976       5736686.1         1555289.9
PROCESSED_TRAN                  1601072       367932.44         1233139.56
PROCESSED_CUURENCY              1314672       145479.1          1169192.9
ACTUAL_SERVICES_DTLS            7452568       6332113.25        1120454.75
SERVICEREQUESTDETAILS           3037840       1932758.36        1105081.64
PKG_RESULTREPORTDTLS            1436632       440030.4          996601.6
BATCH_TXN_SERIALITEM            2621128       1820127.37        801000.63
CUSTOMER_BILLDETAILS            233616        1451156.52        782459.48


10 rows selected

-- Find size
SQL> select segment_name, bytes/(1024*1024*1024) "Size GB" from
  2  dba_segments where segment_name='CUSTOMER_SERVICES_DTLS';
  

SEGMENT_NAME                           Size GB
-------------------------------------- ----------
CUSTOMER_SERVICES_DTLS             11.828125

SQL> 

3) Take one sample table. Here we ll take "CUSTOMER_SERVICES_DTLS". Find the owner.

SQL>
select owner,table_name,tablespace_name,num_rows,blocks
from dba_tables where table_name='CUSTOMER_SERVICES_DTLS';

output:

OWNER      TABLE_NAME                     TABLESPACE_NAME    NUM_ROWS     BLOCKS
---------------------------- ------------------------------ ---------- ----------
CUSTOMER      CUSTOMER_SERVICES_DTLS     CUSTOMER              74055662    1542825

4) Do below activities for safe purpose:

a) Take DDL

-- Create table
create table CUSTOMER.CUSTOMER_SERVICES_DTLS
(
 xxxxxx
) tablespace CUSTOMER;
--Create/Recreate indexes 
create index CUSTOMER.INDX_TXNID on CUSTOMER.CUSTOMER_SERVICES_DTLS (TXNID)
  tablespace CUSTOMER;
create index CUSTOMER.INDX_SYSTEMUPDATEDDATE on CUSTOMER.CUSTOMER_SERVICES_DTLS (SYSTEMUPDATEDDATE)
  tablespace CUSTOMER;

b) take logical backup using expdp:

expdp directory=data_pump dumpfile=CUSTOMER_SERVICES_DTLS.dmp logfile=CUSTOMER_SERVICES_DTLS.log tables=CUSTOMER.CUSTOMER_SERVICES_DTLS exclude=statistics

SQL> 

5) Verify all index status

SQL> select index_name,status
  2  from dba_indexes where table_name='CUSTOMER_SERVICES_DTLS';

INDEX_NAME                     STATUS
------------------------------ --------
INDX_TXNID             VALID
INDX_SYSTEMUPDATEDDATE          VALID

SQL> 

6) Now move the table:
SQL> connect / as sysdba
SQL> set timing on;
SQL> alter table CUSTOMER.CUSTOMER_SERVICES_DTLS move;

Table altered.

Elapsed: 00:11:12.18
SQL> 

(Note: Based of table size, more archivelogs will be generated. You must have sufficient space on required tablespace/ datafile, including TEMP tablespace)

7) Now again verify these:
a) No. of records
SQL> select count(rowid) from CUSTOMER.CUSTOMER_SERVICES_DTLS;

COUNT(ROWID)
------------
    74055662

SQL> 

b) Index statistics

SQL> select index_name,status
  2  from dba_indexes where table_name='CUSTOMER_SERVICES_DTLS';

INDEX_NAME                     STATUS
------------------------------ --------
INDX_TXNID             UNUSABLE
INDX_SYSTEMUPDATEDDATE          UNUSABLE

SQL> 

Here Indexes are "Unusable" status. So these must be rebuild.

8) Rebuild the Indexes

SQL> alter index CUSTOMER.INDX_TXNID rebuild online;

Index altered.
SQL> alter index CUSTOMER.INDX_SYSTEMUPDATEDDATE rebuild online;

Index altered.
SQL> 

Now check the index stats

SQL> select index_name,status from dba_indexes where table_name='CUSTOMER_SERVICES_DTLS';
INDEX_NAME                     STATUS
------------------------------ --------
INDX_TXNID             VALID
INDX_SYSTEMUPDATEDDATE          VALID

SQL> 

Now all are valid.

9) Now Chek no. of rows and blocks

SQL>
select owner,table_name,tablespace_name,num_rows,blocks
from dba_tables where table_name='CUSTOMER_SERVICES_DTLS';

output:

OWNER      TABLE_NAME                     TABLESPACE_NAME    NUM_ROWS     BLOCKS
---------------------------- ------------------------------ ---------- ----------
CUSTOMER      CUSTOMER_SERVICES_DTLS     CUSTOMER              74055662    151033

See here no. of blocks reduced.

10) Now Gather table stats:

SQL> exec dbms_stats.gather_table_stats(ownname=>'CUSTOMER',tabname=>'CUSTOMER_SERVICES_DTLS',estimate_percent => 100, cascade=>true, method_opt=>'for all columns size AUTO'); 


11) Check Table size:

Now again check table size using and will find reduced size of the table.

SQL> 
SQL> select segment_name, bytes/(1024*1024*1024) "Size GB" from
  2  dba_segments where segment_name='CUSTOMER_SERVICES_DTLS';
  

SEGMENT_NAME                           Size GB
-------------------------------------- ----------
CUSTOMER_SERVICES_DTLS             10.02131

SQL> 


Here table size reduced also.

12) Now crosscheck all valid/ invalid object counts and match. You can release your database if you have taken downtime.


Issues may come during the above activity:

SQL> alter table CUSTOMER.CUSTOMER_SERVICES_DTLS move; 
alter table CUSTOMER.CUSTOMER_SERVICES_DTLS move
*
ERROR at line 1:
ORA-01652: unable to extend temp segment by 8192 in tablespace CUSTOMER


i.e., you don't have sufficient space on required tablespace and temp tablespace also.

So add more datafiles and tempfles if your datafiles and tempfile reached 32G.


No comments:

Post a Comment