This is an upgrade to a script I wrote a long time ago. It's handy when you find a system whose master database is somehow full of user objects. (I know that none of us ever make that mistake...)
The biggest improvement is that this script now only generates DROP statement, it doesn't execute them. You have to do that yourself, and you should be sure to back up your master database (you do that on a regular basis anyway, right?), and be darn sure to read all the comments, and of course examine the generated T-SQL code, before executing it. Use at your own risk!
------------------------------------------------------------------------------- -- Drops all user objects that have been accidentally created in 'master'. -- This script erases everything in the master database that is not Microsoft- -- shipped. HOWEVER, be careful: some user objects BELONG in the master -- database (database triggers, security objects, for example). Backing up the -- master database first would be a prudent step. Use at your own risk. -- NOTE: This script only generates the T-SQL code required. You have to copy -- it and do the actual execution yourself. You may have to run this script -- several times due to dependencies; you may also get error messages about -- objects that cannot be found, also due to dependencies. ------------------------------------------------------------------------------- USE master DECLARE @Sql NVARCHAR(MAX) SET @Sql = '' DECLARE @ObjectName sysname SET @ObjectName = '' DECLARE @ConstraintName sysname SET @ConstraintName = '' DECLARE @TableName sysname SET @TableName = '' DECLARE @TypeDesc NVARCHAR(4000) SET @TypeDesc = '' DECLARE @Type NVARCHAR(1024) SET @Type = '' DECLARE @Score INT SET @Score = 0 DECLARE @ObjectID INT SET @ObjectID = 0 DECLARE @ENumber INT DECLARE @ESeverity INT DECLARE @EState INT DECLARE @EProcedure NVARCHAR(126) DECLARE @ELine INT DECLARE @EMessageRecv NVARCHAR(2048) DECLARE @EMessageSent NVARCHAR(440) RAISERROR('-- Execute this code only *AFTER* you have examined it throughly!', 10, 1) WITH NOWAIT RAISERROR('USE master', 10, 1) WITH NOWAIT ------------------------------------------------------------------------------- -- Most objects follow this pattern. ------------------------------------------------------------------------------- DECLARE cur CURSOR DYNAMIC FOR SELECT name, type_desc FROM sys.objects WHERE is_ms_shipped = 0 ORDER BY type_desc, name OPEN cur FETCH FIRST FROM cur INTO @ObjectName, @TypeDesc WHILE @@FETCH_STATUS = 0 BEGIN BEGIN TRY IF @TypeDesc = 'VIEW' BEGIN SET @Sql = 'DROP VIEW ' + QUOTENAME(@ObjectName) RAISERROR('%s', 10, 1, @Sql) WITH NOWAIT END ELSE IF @TypeDesc NOT LIKE '%_CONSTRAINT' ESCAPE '$' BEGIN SET @Type = REVERSE(@TypeDesc) SET @Score = CHARINDEX('_', @Type) SET @Type = SUBSTRING(@Type, 0, @Score) SET @Type = REVERSE(@Type) SET @Sql = 'DROP ' + @Type + ' ' + QUOTENAME(@ObjectName) RAISERROR('%s', 10, 1, @Sql) WITH NOWAIT END END TRY BEGIN CATCH SET @ENumber = ISNULL(ERROR_NUMBER(), -1) SET @ESeverity = ISNULL(ERROR_SEVERITY(), -1) SET @EState = ISNULL(ERROR_STATE(), 0) IF @EState = 0 SET @EState = 42 SET @EProcedure = ISNULL(ERROR_PROCEDURE(), N'{N/A}') SET @ELine = ISNULL(ERROR_LINE(), -1) SET @EMessageRecv = ISNULL(ERROR_MESSAGE(), N'') SET @EMessageSent = N'' IF ERROR_PROCEDURE() IS NOT NULL SET @EMessageSent = N'Error %d, Level %d, State %d, Procedure %s, Line %d, Message: ' SET @EMessageSent = @EMessageSent + ERROR_MESSAGE() RAISERROR(@EMessageSent, 10 /* @ESeverity */ , @EState, @ENumber, @ESeverity, @EState, @EProcedure, @ELine) WITH LOG END CATCH FETCH NEXT FROM cur INTO @ObjectName, @TypeDesc END CLOSE cur DEALLOCATE cur ------------------------------------------------------------------------------- -- Constraints are the only exception to the pattern above. ------------------------------------------------------------------------------- DECLARE cur CURSOR DYNAMIC FOR SELECT name, type_desc, OBJECT_NAME(parent_object_id) FROM sys.objects WHERE is_ms_shipped = 0 AND type_desc LIKE '%_CONSTRAINT' ESCAPE '$' ORDER BY type_desc, name OPEN cur FETCH FIRST FROM cur INTO @ConstraintName, @TypeDesc, @TableName WHILE @@FETCH_STATUS = 0 BEGIN BEGIN TRY SET @Sql = 'ALTER TABLE ' + QUOTENAME(@TableName) + ' DROP CONSTRAINT ' + QUOTENAME(@ConstraintName) RAISERROR('%s', 10, 1, @Sql) WITH NOWAIT END TRY BEGIN CATCH SET @ENumber = ISNULL(ERROR_NUMBER(), -1) SET @ESeverity = ISNULL(ERROR_SEVERITY(), -1) SET @EState = ISNULL(ERROR_STATE(), 0) IF @EState = 0 SET @EState = 42 SET @EProcedure = ISNULL(ERROR_PROCEDURE(), N'{N/A}') SET @ELine = ISNULL(ERROR_LINE(), -1) SET @EMessageRecv = ISNULL(ERROR_MESSAGE(), N'') SET @EMessageSent = N'' IF ERROR_PROCEDURE() IS NOT NULL SET @EMessageSent = N'Error %d, Level %d, State %d, Procedure %s, Line %d, Message: ' SET @EMessageSent = @EMessageSent + ERROR_MESSAGE() RAISERROR(@EMessageSent, 10 /* @ESeverity */ , @EState, @ENumber, @ESeverity, @EState, @EProcedure, @ELine) WITH LOG END CATCH FETCH NEXT FROM cur INTO @ConstraintName, @TypeDesc, @TableName END CLOSE cur DEALLOCATE cur ------------------------------------------------------------------------------- -- Done. ------------------------------------------------------------------------------- RAISERROR('-- Execute this code only *AFTER* you have examined it throughly!', 10, 1) WITH NOWAIT
7 comments:
Hi
Nice script, im going to try it out on a couple of older instances that had too many owners along the way.
Will have to change it to support different schema though.
Good stuff, had to use this today...
Very nice, saved me some clicks... :-)
Good stuff, had to use this today...
Exactly what I needed, thanks a lot
Great script, helped me a lot!
Thanks, this worked great!
Post a Comment