About This Blog

.net & SQL Samples, programming tips and tricks, performance tips, guidelines, and best practices

Thursday 12 January 2012

Fragmented Index – Rebuild or Reorganize ?

Introduction
In past, many times I have written on Fragmentation of Indexes and how to Defrag them. You can find some related articles at -
After this, many of my readers have queried me for-
  1. What is the basic difference between ReBuild & ReOrganizing an Index?
  2. When to use what?
So, today I will address these two specific queries and also show a handy TSQL which could be used to remove Index fragmentation.
ReBuilding Index means the Index will be ReBuild from scratch using the same definition of its creation. It is same as using DBCC DBREINDEX. Please note that for new development do no use DBCC DBREINDEX as its deprecated from SQL Server 2005 onwards. It is generally preferred to rebuild OFFLINE. However, rebuild could be done ONLINE by specifying appropriate options.
ReOrganizing Index means the data at the Index leaf will be re-organized and the fragments will be removed to the max possible extent. It is same as using DBCC INDEXDEFRAG. Please note that for new development do no use DBCC INDEXDEFRAG as its deprecated from SQL Server 2005 onwards. ReOrganizing an Index is an ONLINE process.
When to use what – As per Microsoft, the recommendations are as under -
If Avg. Fragmentation < 5%, no action is required
else if 5% < Avg. Fragmentation <= 30%, reorganization is required
else if Avg. Fragmentation > 30%, rebuild is required
So, based on the above recommendations, the below TSQL could be used to serve the purpose -
USE DBName
GO
 
DECLARE @tsql NVARCHAR(MAX)  
DECLARE @fillfactor INT
 
SET @fillfactor = 70 
 
DECLARE @FragmentedIndexs TABLE (IndexID INT,
                                 IndexName VARCHAR(100),
                                 ObjectName VARCHAR(100),
                                 AvgFragmentationInPercent DECIMAL(6,2),
                                 FragmentCount INT,
                                 AvgFragmentSizeInPage DECIMAL(6,2),
                                 IndexDepth INT)
 
--Insert the Details for Fragmented Indexes.
INSERT INTO @FragmentedIndexs
SELECT 
  PS.index_id,
  QUOTENAME(I.name) Name,
  QUOTENAME(DB_NAME()) +'.'+ QUOTENAME(OBJECT_SCHEMA_NAME(I.[object_id])) + '.' + QUOTENAME(OBJECT_NAME(I.[object_id])) ObjectName,
  PS.avg_fragmentation_in_percent,
  PS.fragment_count,
  PS.avg_fragment_size_in_pages,
  PS.index_depth
FROM 
  sys.dm_db_index_physical_stats (DB_ID(), NULL ,NULL, NULL, NULL) AS PS
INNER JOIN sys.indexes AS I 
  ON PS.[object_id]= I.[object_id]
  AND PS.index_id = I.index_id
WHERE
  PS.avg_fragmentation_in_percent > 5  
ORDER BY 
  PS.avg_fragmentation_in_percent DESC
 
--Select the details.
SELECT * FROM @FragmentedIndexs
 
--Prepare the Query to REORGANIZE the Indexes
SET @tsql = ''
 
SELECT @tsql = 
  STUFF(( SELECT DISTINCT 
           ';' + 'ALTER INDEX ' + FI.IndexName + ' ON ' + FI.ObjectName + ' REORGANIZE '
          FROM 
           @FragmentedIndexs FI
          WHERE
            FI.AvgFragmentationInPercent <= 30
          FOR XML PATH('')), 1,1,'')
  
SELECT @tsql
PRINT 'REORGANIZING START'
EXEC sp_executesql @tsql 
PRINT 'REORGANIZING END'
 
--Prepare the Query to REBUILD the Indexes
SET @tsql = ''
 
SELECT @tsql = 
  STUFF(( SELECT DISTINCT 
           ';' + 'ALTER INDEX ' + FI.IndexName + ' ON ' + FI.ObjectName + ' REBUILD WITH (FILLFACTOR = ' + CONVERT(VARCHAR(3),@fillfactor) + ') '
          FROM 
           @FragmentedIndexs FI
          WHERE
            FI.AvgFragmentationInPercent > 30
          FOR XML PATH('')), 1,1,'')
  
SELECT @tsql
PRINT 'REBUILD START'
EXEC sp_executesql @tsql
PRINT 'REBUILD END'

Conclusion

To keep the indexes in proper shape, a timely defragmentation is necessary. When to defragment has got no THUMB RULE, it depends on the environment. However, the above script could be scheduled as per ones need to make sure that the indexes gets defragmented when need.

Friday 6 January 2012

Managing Timeouts while using System.Transactions in .Net

Problem
While working with System.Transactions in .net 2.0 or higher versions, we often come across a situation where we need to execute some long running processes inside Transactions and our process gets aborted after few seconds. This demands for some long running transactions. So, lets see how this can be achieved -
  • Setting the CommandTimeout for the Command object – Command object is used to execute raw TSQL/ Stored procedures though .net. This object has got a getter/setter property CommandTimeout which holds the wait time before terminating the attempt to execute the command. By default, the value is 30 seconds. So, a long running process will certainly get aborted after 30 seconds. In order to extend it over this time, we can set an appropriate timeout value. We need to set it to 0 (zero) to set it to infinite. For more information, please refer this msdn article.
  • Next important factor in this sequence is setting the timeout value for the TransactionScope. The TransactionScope class has got an overloaded constructor, where we can specify the timeout TimeSpan
    TimeSpan timeout = TimeSpan.FromSeconds(30);
    using(TransactionScope scope = new 8 TransactionScope(TransactionScopeOption.Required, timeout))
    {...}
or we can also make use of the TransactionOptions.Timeout property and set its value.

TransactionOptions options = new TransactionOptions();
options.IsolationLevel = IsolationLevel.ReadCommitted;
options.Timeout = TransactionManager.DefaultTimeout;
 
using(TransactionScope scope = new 8 TransactionScope(TransactionScopeOption.Required, options))
{...}

By default, the value is 60 seconds. We can an appropriate value for this property or can also set it to infinite the same way as we did for the command object. We need to set it to 0 (zero) to set it to infinite.
This is the point where most of the developers think they are done after setting the timeout values for the command & the transaction objects. But this is not 100% correct. It holds true only to a time limit of 10 minutes. If you want your transaction to continue after that, setting only the above two values is not the solution. And here comes into play the TransactionManager settings.

TransactionManager sits on top of Transaction & Command. The default timeout value of TransactionManager is 10 minutes and it is defined in the machine.config file. The main problem in re-setting this value is -
  1. It can not be changed programmatically.
  2. And due to Point 1, we have to make manual changes in the machine.config file. This results in a machine wide change; i.e. all the applications running on that box will be affected by this change. So, one needs to take utmost care in doing so and should properly assess the consequences before attempting this change.
Please note that we can not specify the machinesettings in our own configuration file. But we need to actually add/change the machinesettings\timeout in the machine.config file. Below shows a timeout of 30 minutes after manual change.

<configuration>
 <system.transactions>
  <machineSettings maxTimeout="00:30:00" />
 </system.transactions>
</configuration>

Conclusion
The timeout of a transaction is decided by MIN(TransactionManager Timeout value, Transaction timeout value, command timeout value); i.e. a minimum value of these 3 settings is the deciding factor.

References
  1. http://social.msdn.microsoft.com/forums/en-US/windowstransactionsprogramming/thread/250b40b9-0838-4142-a8ff-d9d26690083b/
  2. http://social.msdn.microsoft.com/Forums/en-US/windowstransactionsprogramming/thread/7863f7e5-ec86-4f77-90e2-dc212ff099a2/