Last active
March 22, 2016 13:52
-
-
Save NoahDragon/88c33e54e7a685e54542 to your computer and use it in GitHub Desktop.
SQL Server Index Operations.
This file contains hidden or bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
-- | |
-- Disabled indexes. | |
-- | |
select | |
sys.objects.name, | |
sys.indexes.name | |
from sys.indexes | |
inner join sys.objects on sys.objects.object_id = sys.indexes.object_id | |
where sys.indexes.is_disabled = 1 | |
order by | |
sys.objects.name, | |
sys.indexes.name | |
-- | |
-- The include columns on index. | |
-- | |
SELECT | |
IndexName = i.Name, | |
ColName = c.Name | |
FROM | |
sys.indexes i | |
INNER JOIN | |
sys.index_columns ic ON ic.object_id = i.object_id AND ic.index_id = i.index_id | |
INNER JOIN | |
sys.columns c ON c.object_id = ic.object_id AND c.column_id = ic.column_id | |
WHERE | |
ic.is_included_column = 1 | |
AND i.object_id = OBJECT_ID('whwork') | |
-- | |
-- Index fragment and statistic | |
-- | |
-- Statistic | |
Declare @tableName VARCHAR(512), @count int, @sql Nvarchar(max) | |
SET @tableName = 'brnprices' | |
SET @sql = N'select @count = count(1) from '+ @tableName | |
exec sp_executesql @sql, N'@count int OUTPUT', @count = @count OUTPUT | |
SELECT 'Statistic', | |
@count AS TableRowCount, | |
1.00 * 100 * sysInx2.rowmodctr / ISNULL(NULLIF(@count, 0), 1), | |
100 * (sysInx2.rowmodctr / ISNULL(NULLIF(@count, 0), 1)), | |
sysInx2.rowmodctr, | |
sysobj.name, | |
sysInx2.name, | |
* | |
FROM sys.sysindexes sysInx2 WITH (NOLOCK) | |
inner join sys.objects sysObj WITH (NOLOCK) | |
on sysInx2.id = sysObj.object_id | |
WHERE OBJECT_ID(@tableName) = sysInx2.id | |
--- Index | |
SELECT 'Index', | |
@count AS TableRowCount, | |
OBJECT_NAME(inxStat.object_id) AS TableName, | |
sysInx.name AS IndexName, | |
inxStat.avg_fragmentation_in_percent AS FragPercent, | |
inxStat.avg_fragment_size_in_pages AS FragSizeInPages, | |
inxstat.page_count | |
FROM sys.dm_db_index_physical_stats ( DB_ID(), OBJECT_ID(@tableName), NULL, NULL, 'SAMPLED' ) AS inxStat | |
INNER JOIN sys.indexes AS sysInx WITH (NOLOCK) | |
ON inxStat.object_id = sysInx.object_id | |
AND inxStat.index_id = sysInx.index_id | |
INNER JOIN sys.objects AS sysObj WITH (NOLOCK) | |
ON sysInx.object_id = sysObj.object_id | |
AND sysObj.schema_id = SCHEMA_ID('dbo') | |
WHERE (inxStat.database_id = DB_ID() | |
AND OBJECT_NAME(inxStat.object_id) = @tableName | |
AND inxStat.index_id <> 0) | |
-------- Following criteria are used to deciede if indexes are needed to rebuild --------------------- | |
AND inxStat.page_count > 500 | |
AND (inxStat.avg_fragmentation_in_percent > 30 OR | |
inxStat.avg_fragment_size_in_pages < 8) | |
-- | |
-- Rebuild/Disable Indexes | |
-- | |
ALTER INDEX ALL ON purchordlines | |
--DISABLE | |
REBUILD |
Sign up for free
to join this conversation on GitHub.
Already have an account?
Sign in to comment