-- 检查表是否存在,不存在则创建 IF NOT EXISTS (SELECT * FROM sys.tables WHERE name = 'LostIndexCreationList') BEGIN CREATE TABLE LostIndexCreationList ( TableName NVARCHAR(128), ColumnName NVARCHAR(128) ); END -- 修正版全库ID字段索引创建脚本 BEGIN TRY --BEGIN TRANSACTION; -- 创建临时表存储需要创建索引的表和字段 CREATE TABLE #IndexCreationList ( TableName NVARCHAR(128), ColumnName NVARCHAR(128) ); -- 找出所有需要创建索引的字段 INSERT INTO #IndexCreationList SELECT t.name AS TableName, c.name AS ColumnName FROM sys.tables t JOIN sys.columns c ON t.object_id = c.object_id WHERE c.name LIKE '%ID' AND t.name NOT LIKE 'tmp%' AND t.name NOT IN ( 't_EpDataSourceInfo' ) AND t.is_ms_shipped = 0 AND NOT EXISTS ( SELECT 1 FROM sys.indexes i JOIN sys.index_columns ic ON i.object_id = ic.object_id AND i.index_id = ic.index_id WHERE i.object_id = t.object_id AND ic.column_id = c.column_id AND i.name = 'IX_' + t.name + '_' + c.name ); SELECT * FROM #IndexCreationList; DECLARE @sql NVARCHAR(MAX) = ''; DECLARE @tableName NVARCHAR(128), @columnName NVARCHAR(128),@rows int=0; DECLARE cur CURSOR FOR SELECT TableName, ColumnName FROM #IndexCreationList; OPEN cur; FETCH NEXT FROM cur INTO @tableName, @columnName; WHILE @@FETCH_STATUS = 0 BEGIN BEGIN TRY -- 动态生成索引创建语句 set @rows =@rows +1; SET @sql = 'CREATE INDEX IX_' + @tableName + '_' + @columnName + ' ON ' + QUOTENAME(@tableName) + '(' + QUOTENAME(@columnName) + ');'; -- 执行语句 PRINT CONVERT(NVARCHAR(100),@rows) +' Executing: ' + @sql; EXEC sp_executesql @sql; END TRY BEGIN CATCH -- 捕获错误并记录 INSERT INTO dbo.LostIndexCreationList ( TableName, ColumnName ) VALUES ( @tableName, -- TableName - nvarchar(128) @columnName -- ColumnName - nvarchar(128) ) PRINT 'Error occurred while creating index IX_' + @tableName + '_' + @columnName + ': ' + ERROR_MESSAGE(); END CATCH; FETCH NEXT FROM cur INTO @tableName, @columnName; END; CLOSE cur; DEALLOCATE cur; ---- 动态生成并执行创建索引的SQL --DECLARE @sql NVARCHAR(MAX) = ''; --SELECT @sql = @sql + -- 'CREATE INDEX IX_' + TableName + '_' + ColumnName + -- ' ON ' + QUOTENAME(TableName) + '(' + QUOTENAME(ColumnName) + ');' + CHAR(13) --FROM #IndexCreationList; --IF LEN(@sql) > 0 --BEGIN -- EXEC sp_executesql @sql; -- PRINT '成功创建 ' + CAST(@@ROWCOUNT AS NVARCHAR(10)) + ' 个索引'; --END --ELSE --BEGIN -- PRINT '没有需要创建的索引,所有ID字段索引已存在'; --END -- 验证结果 SELECT t.name AS 表名, i.name AS 索引名称, c.name AS 字段名 FROM sys.tables t JOIN sys.indexes i ON t.object_id = i.object_id JOIN sys.index_columns ic ON i.object_id = ic.object_id AND i.index_id = ic.index_id JOIN sys.columns c ON ic.object_id = c.object_id AND ic.column_id = c.column_id WHERE i.name LIKE 'IX_%_%ID' ORDER BY t.name, i.name; DROP TABLE #IndexCreationList; --COMMIT TRANSACTION; END TRY BEGIN CATCH IF @@TRANCOUNT > 0 ROLLBACK TRANSACTION; PRINT '错误发生: ' + ERROR_MESSAGE(); PRINT '错误行号: ' + CAST(ERROR_LINE() AS NVARCHAR(10)); END CATCH;