SQL Server Maintenance Solution SP doesn't seem to work as expected

  • Hi,

    I'm trying to figure out how to use this IndexOptimize SP I got from http://ola.hallengren.com/ to run against just a single table's indexes.

    When I run the following query:

    SELECT * FROM sys.dm_db_index_physical_stats (DB_ID(N'database_name'), OBJECT_ID(N'dbo.table_name'), NULL, NULL , 'DETAILED');

    I get this as the result both before and after running the IndexOptimize job:

    http://cl.ly/image/472J160R1y2n

    Here is what I'm trying to run:

    EXECUTE dbo.IndexOptimize

    @databases = 'database_name',

    @Indexes = 'database_name.dbo.table_name',

    @FragmentationLow = NULL,

    @FragmentationMedium = 'INDEX_REORGANIZE,INDEX_REBUILD_ONLINE',

    @FragmentationHigh = 'INDEX_REBUILD_ONLINE',

    @FragmentationLevel1 = 5,

    @FragmentationLevel2 = 30

    Here's the output:

    Here you go:

    DateTime: 2012-10-22 16:52:59

    Server: SQL2005-STAGE

    Version: 9.00.5000.00

    Edition: Standard Edition (64-bit)

    Procedure: [master].[dbo].[IndexOptimize]

    Parameters: @databases = '%database_name%', @FragmentationLow = NULL, @FragmentationMedium = 'INDEX_REORGANIZE,INDEX_REBUILD_ONLINE', @FragmentationHigh = 'INDEX_REBUILD_ONLINE', @FragmentationLevel1 = 5, @FragmentationLevel2 = 30, @PageCountLevel = 1000, @SortInTempdb = 'N', @MaxDOP = NULL, @FillFactor = NULL, @PadIndex = NULL, @LOBCompaction = 'Y', @UpdateStatistics = NULL, @OnlyModifiedStatistics = 'N', @StatisticsSample = NULL, @StatisticsResample = 'N', @PartitionLevel = 'N', @TimeLimit = NULL, @Indexes = '%database_name.dbo.table_name%', @Delay = NULL, @LogToTable = 'N', @Execute = 'Y'

    Source: http://ola.hallengren.com<http://ola.hallengren.com/&gt;

    DateTime: 2012-10-22 16:52:59

    Database: [database_name]

    Status: ONLINE

    Standby: No

    Updateability: READ_WRITE

    User access: MULTI_USER

    Is accessible: Yes

    Recovery model: FULL

    DateTime: 2012-10-22 16:55:10

    The query completes, but it doesn't seem to make a difference to the table's indexes. Am I missing something?

  • How big are the indexes and how fragmented? Small indexes won't usually benefit from defragmentation, so SQL Server will often just ignore you if you ask it to defrag them. It's a "feature" that lots of DBAs run into.

    - Gus "GSquared", RSVP, OODA, MAP, NMVP, FAQ, SAT, SQL, DNA, RNA, UOI, IOU, AM, PM, AD, BC, BCE, USA, UN, CF, ROFL, LOL, ETC
    Property of The Thread

    "Nobody knows the age of the human race, but everyone agrees it's old enough to know better." - Anon

  • The stats I ran against the table are in a screen shot I have available here:

    The table is about 10GB and the fragmentation to me looks significant enough unless I'm reading it wrong.

  • What version and edition are you running? (Do a SELECT @@VERSION.)

    Could you script out the table and post that?

  • Default the parameter for high fragmentation is set like this:

    @FragmentationHigh = 'INDEX_REBUILD_ONLINE,INDEX_REBUILD_OFFLINE'

    This means that it will rebuild an index online if that is possible. If that is not possible, it will rebuild the index offline.

    Here it has been set like this:

    @FragmentationHigh = 'INDEX_REBUILD_ONLINE'

    This means that it will rebuild an index online if that is possible. If that is not possible, it will skip the index. As you have Standard Edition it will not be able to rebuild the index online and the index will therefore be skipped.

    So you need to change the parameter to allow for offline rebuilds or upgrade to Enterprise Edition.

    Ola Hallengren

    http://ola.hallengren.com

Viewing 5 posts - 1 through 4 (of 4 total)

You must be logged in to reply to this topic. Login to reply