Disable all non-clustered indexes
Build a table variable with the indexes and table names. Use a loop to iterate over them, and execute a dynamic SQL statement for each of them.
declare @Indexes table
(
Num int identity(1,1) primary key clustered,
TableName nvarchar(255),
IndexName nvarchar(255)
)
INSERT INTO @Indexes
(
TableName,
IndexName
)
SELECT sys.objects.name tableName,
sys.indexes.name indexName
FROM sys.indexes
JOIN sys.objects ON sys.indexes.object_id = sys.objects.object_id
WHERE sys.indexes.type_desc = 'NONCLUSTERED'
AND sys.objects.type_desc = 'USER_TABLE'
DECLARE @Max INT
SET @Max = @@ROWCOUNT
SELECT @Max as 'max'
SELECT * FROM @Indexes
DECLARE @I INT
SET @I = 1
DECLARE @TblName NVARCHAR(255), @IdxName NVARCHAR(255)
DECLARE @SQL NVARCHAR(MAX)
WHILE @I <= @Max
BEGIN
SELECT @TblName = TableName, @IdxName = IndexName FROM @Indexes WHERE Num = @I
SELECT @SQL = N'ALTER INDEX ' + @IdxName + N' ON ' + @TblName + ' DISABLE;'
EXEC sp_sqlexec @SQL
SET @I = @I + 1
END
You can build the queries into a select statement, like so:
DECLARE @sql AS VARCHAR(MAX)='';
SELECT @sql = @sql +
'ALTER INDEX ' + sys.indexes.name + ' ON ' + sys.objects.name + ' DISABLE;' +CHAR(13)+CHAR(10)
FROM
sys.indexes
JOIN
sys.objects
ON sys.indexes.object_id = sys.objects.object_id
WHERE sys.indexes.type_desc = 'NONCLUSTERED'
AND sys.objects.type_desc = 'USER_TABLE';
EXEC(@sql);
Chars 13 and 10 are the line-feed/carriage-returns, so you can check the output by replacing EXEC
with PRINT
, and it will be more readable.