DATABASE REINDEXING JOB FAILS

  • Executing the query "ALTER INDEX [IX_NAME failed with the following error: "The index "IX_NAME" (partition 1) on table "tablename" cannot be reorganized because page level locking is disabled.". Possible failure reasons: Problems with the query, "ResultSet" property not set correctly, parameters not set correctly, or connection not established correctly.

    please hep with error below.

    how do i check for the status of page level locking?

    Can i enable page level locking in multiple tables in one go? How?

  • THE-FHA (12/6/2011)


    Executing the query "ALTER INDEX [IX_NAME failed with the following error: "The index "IX_NAME" (partition 1) on table "tablename" cannot be reorganized because page level locking is disabled.". Possible failure reasons: Problems with the query, "ResultSet" property not set correctly, parameters not set correctly, or connection not established correctly.

    please hep with error below.

    how do i check for the status of page level locking?

    Can i enable page level locking in multiple tables in one go? How?

    You need to add SET (ALLOW_PAGE_LOCKS = ON) in your ALTER INDEX code.


    Sujeet Singh

  • hi,

    i am currently trying to get a script which will do that for multiple databases.

  • THE-FHA (12/6/2011)


    hi,

    i am currently trying to get a script which will do that for multiple databases.

    You can use below script (available on msdn here) to identify the fragmented indexes in current database & then automatically reorganize/rebuild them.

    -- Ensure a USE <databasename> statement has been executed first.

    SET NOCOUNT ON;

    DECLARE @objectid int;

    DECLARE @indexid int;

    DECLARE @partitioncount bigint;

    DECLARE @schemaname nvarchar(130);

    DECLARE @objectname nvarchar(130);

    DECLARE @indexname nvarchar(130);

    DECLARE @partitionnum bigint;

    DECLARE @partitions bigint;

    DECLARE @frag float;

    DECLARE @command nvarchar(4000);

    -- Conditionally select tables and indexes from the sys.dm_db_index_physical_stats function

    -- and convert object and index IDs to names.

    SELECT

    object_id AS objectid,

    index_id AS indexid,

    partition_number AS partitionnum,

    avg_fragmentation_in_percent AS frag

    INTO #work_to_do

    FROM sys.dm_db_index_physical_stats (DB_ID(), NULL, NULL , NULL, 'LIMITED')

    WHERE avg_fragmentation_in_percent > 10.0 AND index_id > 0;

    -- Declare the cursor for the list of partitions to be processed.

    DECLARE partitions CURSOR FOR SELECT * FROM #work_to_do;

    -- Open the cursor.

    OPEN partitions;

    -- Loop through the partitions.

    WHILE (1=1)

    BEGIN;

    FETCH NEXT

    FROM partitions

    INTO @objectid, @indexid, @partitionnum, @frag;

    IF @@FETCH_STATUS < 0 BREAK;

    SELECT @objectname = QUOTENAME(o.name), @schemaname = QUOTENAME(s.name)

    FROM sys.objects AS o

    JOIN sys.schemas as s ON s.schema_id = o.schema_id

    WHERE o.object_id = @objectid;

    SELECT @indexname = QUOTENAME(name)

    FROM sys.indexes

    WHERE object_id = @objectid AND index_id = @indexid;

    SELECT @partitioncount = count (*)

    FROM sys.partitions

    WHERE object_id = @objectid AND index_id = @indexid;

    -- 30 is an arbitrary decision point at which to switch between reorganizing and rebuilding.

    IF @frag < 30.0

    SET @command = N'ALTER INDEX ' + @indexname + N' ON ' + @schemaname + N'.' + @objectname + N' REORGANIZE';

    IF @frag >= 30.0

    SET @command = N'ALTER INDEX ' + @indexname + N' ON ' + @schemaname + N'.' + @objectname + N' REBUILD';

    IF @partitioncount > 1

    SET @command = @command + N' PARTITION=' + CAST(@partitionnum AS nvarchar(10));

    EXEC (@command);

    PRINT N'Executed: ' + @command;

    END;

    -- Close and deallocate the cursor.

    CLOSE partitions;

    DEALLOCATE partitions;

    -- Drop the temporary table.

    DROP TABLE #work_to_do;

    GO

    P.S. You need to modify the above script a little bit to contain "SET (ALLOW_PAGE_LOCKS = ON)" with ALTER INDEX statement.


    Sujeet Singh

  • I run the following to set page lock on for every index in every database on a server:

    exec master..sp_MSForeachdb 'USE [?]

    if ((select is_read_only from sys.databases where name=db_name())=0)

    begin

    SET NOCOUNT ON

    DECLARE @DBName nvarchar(400), @INName nvarchar(400)

    DECLARE @ODBName nvarchar(400), @OINName nvarchar(400)

    Declare @execstr nvarchar(4000)

    --PRINT ''----------------''

    DECLARE Index_cursor CURSOR FOR

    Select A.Name as InName,ob.Name as DBName from sys.indexes A

    left outer join sys.objects ob on ob.object_id=A.Object_id

    where is_disabled=0 and allow_page_locks=0 and ob.type=''U''

    -- Select only allow_page_locks 0 and User Tables

    OPEN Index_cursor

    FETCH NEXT FROM Index_cursor

    INTO @INName, @DBName

    WHILE @@FETCH_STATUS = 0

    BEGIN

    PRINT @DBName +'' '' + @INName

    --PRINT @INName

    SET @ODBName = ltrim(rtrim(@DBName))

    SET @OINName = ltrim(rtrim(@INName))

    SELECT @execstr = ''ALTER INDEX [''+@OINName+ ''] ON ''+

    @ODBName+'' SET (ALLOW_PAGE_LOCKS = ON)'';

    select db_name(), @execstr

    EXEC (@execstr);

    FETCH NEXT FROM Index_cursor

    INTO @INName, @DBName

    END

    CLOSE Index_cursor

    DEALLOCATE Index_cursor

    end'

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

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