如何同时对多个表或列操作
通过使用这个存储过程,你就可以方便的对数据库中具有一定规则的或者全部表,对这里的字段进行各种操作,具体看示例!
CREATE PROCEDURE SP_execSQLonDB (@TABLENAME VARCHAR(50), --表名条件 @COLUMNNAME VARCHAR(50), --字段条件 @SQL NVARCHAR(4000), --执行的SQL @INCLUDE_NTI CHAR(1) = 'N') --是否包含Text,NText,Image数据类型 AS BEGIN --Variable Declaration --变量定义 DECLARE @strSQL NVARCHAR(4000) DECLARE @SQL2 NVARCHAR(4000) DECLARE @sTableName VARCHAR(200) DECLARE @sColumnName VARCHAR(200)
DECLARE @SQLTemp NVARCHAR(4000)
--Check whether to include TEXT, NTEXT, IMAGE data types --检查是否需要包含 Text,NText,Image数据类型 SET @INCLUDE_NTI = UPPER(LTRIM(RTRIM(@INCLUDE_NTI))) IF @INCLUDE_NTI NOT IN ('N', 'Y') SET @INCLUDE_NTI = 'N'
--Construct a cursor to get the list of Table/Column Names according to the @TABLENAME and @COLUMNNAME parameters. --创建一个游标来读取表名和列名的列表,这里列表由参数@TABLENAME 和 @COLUMNNAME 决定 SET @strSQL = N'DECLARE TabColCursor CURSOR FOR SELECT RTRIM(LTRIM(SU.name)) + ''.'' + LTRIM(RTRIM(SO.name)), SC.name FROM sysobjects SO INNER JOIN syscolumns SC ON SO.id = SC.id INNER JOIN sysusers SU ON SO.uid = SU.uid WHERE SO.xtype = ''U'' '
--Filter out Text/NText/Image data types if it is not included --假如不包含Text/NText/Image数据类型,把他们过滤掉 IF @INCLUDE_NTI = 'N' --In SysColumns sytem table XTYPE column corresponds to Column Data Type SET @strSQL = @strSQL + ' AND SC.xtype NOT IN (35, 99, 34) '
--Add the TABLE(S) name i.e. filter if it is supplied --假如有提供表名参数,把它写入过滤条件中 IF @TABLENAME IS NOT NULL AND ltrim(rtrim(@TABLENAME)) <> '' BEGIN SET @TABLENAME = REPLACE(@TABLENAME, ', ', ',') SET @strSQL = @strSQL + ' AND (SO.name LIKE ''' + REPLACE(@TABLENAME, ',', ''' OR SO.name LIKE ''') + ''')' SET @SQLTemp= ' AND (SO.name LIKE ''' + REPLACE(@TABLENAME, ',', ''' OR SO.name LIKE ''') + ''')' END
--Add the COLUMN(S) name i.e. filter if it is supplied --假如有提供列名参数,把它写入过滤条件中 IF @COLUMNNAME IS NOT NULL AND ltrim(rtrim(@COLUMNNAME)) <> '' BEGIN SET @COLUMNNAME = REPLACE(@COLUMNNAME, ', ', ',') SET @strSQL = @strSQL + ' AND (SC.name LIKE ''' + REPLACE(@COLUMNNAME, ',', ''' OR SC.name LIKE ''') + ''')' END
--Execute the constructed "Cursor Declaration" string --执行定义游标的SQL语句 EXECUTE sp_executesql @strSQL IF @@ERROR > 0 BEGIN PRINT 'Error while declaring the Cursor. Please check out the parameters supplied to the Procedure' RETURN -1 END
--Database Transaction. --标记一个显式本地事务的起始点 BEGIN TRANSACTION gDatabaseTrans
--Open the cursor --打开游标 OPEN TabColCursor
--Fetch te Table, Column names to variables --用游标取出标名、列名对应到参数 FETCH NEXT FROM TabColCursor INTO @sTableName, @sColumnName
--Execute the SQL statement supplied in @SQL parameter on every row of Cursor's data --对于每一行游标取出的数据,执行由@SQL参数传进来的SQL语句 WHILE @@FETCH_STATUS = 0 BEGIN --Construct SQL2 to Execute supplied @SQL --by replacing @TABLENAME, @COLUMNNAME with running Table Name, Column Name of Cursor's data --用游标取出的表名列名来替换@SQL中的@TABLENAME, @COLUMNNAME来构造SQL2 SET @SQL2 = @SQL SET @SQL2 = REPLACE(@SQL2, '@TABLENAME', @sTableName) SET @SQL2 = REPLACE(@SQL2, '@COLUMNNAME', @sColumnName)
--Execute the constructed SQL2 --执行SQL2 EXECUTE sp_executesql @SQL2 --Check for errors --检查错误 IF @@ERROR <> 0 BEGIN --On Error, Destroy objects, Rollback transaction --Return -1 as UNSUCCESSFUL flag --如果发生错误,删除游标,回滚 --返回错误标记 -1 PRINT 'Error occurred' DEALLOCATE TabColCursor ROLLBACK TRANSACTION gDatabaseTrans RETURN -1 END
--Process Next Row of Cursor --进行下一行数据 FETCH NEXT FROM TabColCursor INTO @sTableName,@sColumnName END
--Destroy CURSOR object --删除游标 DEALLOCATE TabColCursor
--Procedure executed properly. Commit the Transaction. --Return 0 as SUCCESSFUL flag --成功完成存储过程,成功结束事务 --返回成功标记 0 COMMIT TRANSACTION gDatabaseTrans RETURN 0 END
使用例子
1、这个例子在NORTHWIND数据库上执行 把所有表中列名包含Name的列中,把以“Ltd.”结尾的列替换成“LIMITED”。 用 SELECT * FROM Suppliers检查运行结果!
EXEC SP_execSQLonDB '', --没有表名条件,针对所有表 '%Name%', --列名条件,列名包含“Name”字符串 'UPDATE @TABLENAME SET @COLUMNNAME = REPLACE(@COLUMNNAME,''Ltd.'',''LIMITED'') WHERE @COLUMNNAME LIKE ''%Ltd.''', --UPDATE 语句 'N' --不包含NTEXT,TEXT,IMAGE数据类型
2、这个例子也在NORTHWIND数据库上执行 统计所有表中列名包含Name的列的值是“QUICK-Stop”的数量 create table ##TMP1 (table_name varchar(200),column_name varchar(200),rou_count int) exec SP_execSQLonDB '', '%Name%', 'DECLARE @iCount as int SELECT @iCount=COUNT(1) FROM @TABLENAME WHERE @COLUMNNAME = ''QUICK-Stop'' IF @iCount >0 INSERT INTO ##TMP1 SELECT ''@TABLENAME'',''@COLUMNNAME'',@iCount', 'N' select * from ##TMP1
3、这个例子自己理解 针对所有以“EMPLOYEE”开头的表,以“DEPT”开头的字段执行存储过程。 EXEC SP_execSQLonDB 'EMPLOYEE%', 'DEPT%', 'EXEC USP_DeptStates ''@TABLENAME'',''@COLUMNNAME''', 'N'
4、还是自己理解 对@TABLENAME @COLUMNNAME参数给于多个值! EXEC SP_execSQLonDB 'EMPLOYEE%,PF%', 'SALARY,%AMOUNT%', 'EXEC USP_EMPLOYEE_PF ', 'N'

|