Commit 5967f772 authored by dwentzel's avatar dwentzel

added PostRestoreSteps

parent 184915ec
IF OBJECT_ID('dbo.PostRestoreSteps') IS NOT NULL
DROP PROCEDURE dbo.PostRestoreSteps;
GO
CREATE PROCEDURE dbo.PostRestoreSteps
AS
BEGIN
/*
Performs a series of steps "post restore" of a db to ensure it is setup correctly.
See also:
http://www.davewentzel.com/content/post-restore-process
--turns off autoclose and autoshrink if enabled.
--sets compat mode to 100 (SQL 2008). this is needed for MERGE statement for instance.
--sets TRUSTWORTHY and DB_CHAINING
--sets the db owner to sa
--enables Service Broker (see http://git.davewentzel.com/dwentzel/servicebrokercode/blob/master/ServiceBrokerEnable.sql)
--syncs logins and passwords.
Feel free to add or change anything you like to match your requirements. Some other suggestions are:
--setting up/ensuring proper database hygiene SQL Agent jobs are in place (backup/update stats/reorg)
--enabling the CLR
--re-enabling custom events
--optionally removing "sensitive" data
--changing other "environment" data that you persist in your db
*/
declare @exec_str varchar(2000)
declare @db varchar(2000)
SELECT @db = db_name()
--Set various db options
SELECT @exec_str = 'ALTER DATABASE ' + quotename(@db) + ' SET AUTO_CLOSE OFF'
PRINT @exec_str
EXEC (@exec_str)
SELECT @exec_str = 'ALTER DATABASE ' + quotename(@db) + ' SET AUTO_SHRINK OFF'
PRINT @exec_str
EXEC (@exec_str)
SELECT @exec_str = 'ALTER DATABASE ' + quotename(@db) + ' SET COMPATIBILITY_LEVEL = 100'
PRINT @exec_str
EXEC (@exec_str)
SELECT @exec_str = 'ALTER DATABASE ' + quotename(@db) + ' SET TRUSTWORTHY ON'
PRINT @exec_str
EXEC (@exec_str)
SELECT @exec_str = 'ALTER DATABASE ' + quotename(@db) + ' SET DB_CHAINING ON'
PRINT @exec_str
EXEC (@exec_str)
--Check/set db owner.
if (
select suser_sname(owner_sid) as db_owner
from sys.databases
WHERE name = db_name()
) <> 'sa'
BEGIN
SELECT @exec_str = 'ALTER AUTHORIZATION ON DATABASE::' + @db + ' TO SA;'
PRINT @exec_str
EXEC (@exec_str)
END;
--synch logins/users
Declare @BadUser varchar (100)
Declare @FixUser varchar (100)
DECLARE BadUsers_cursor INSENSITIVE CURSOR FOR
select u.name
from sysusers u, master.dbo.syslogins l
where u.name = l.name collate SQL_Latin1_General_CP1_CI_AS
and u.sid <> l.sid
-- and u.sid = l.sid (test for the good ones)
Open BadUsers_cursor
FETCH NEXT FROM BadUsers_cursor INTO @BadUser
WHILE (@@FETCH_STATUS <> -1)
Begin
Select @FixUser = 'sp_change_users_login ''Update_One'', ''' + ltrim(@BadUser) + ''', ''' + ltrim(@BadUser) + ''''
Print @FixUser --(to print commands)
Exec (@FixUser)
FETCH NEXT FROM BadUsers_cursor INTO @BadUser
End
CLOSE BadUsers_cursor
DEALLOCATE BadUsers_cursor
IF EXISTS (select * from sysobjects WHERE object_id = object_id('ServiceBrokerEnable'))
BEGIN
EXEC ServiceBrokerEnable
END;
END
GO
......@@ -26,4 +26,8 @@ sysjobhistoryPurge : http://www.davewentzel.com/content/blocking-and-contention-
provides natively. Also, the purge is "smart" and will not cause blocking and concurrency
problems on instances with many, frequent SQL Agent jobs. Includes tsqlt unit tests.
PostRestoreSteps.sql : http://www.davewentzel.com/content/post-restore-process. Train your staff to always run
this proc as part of their environment build and db restore process and you'll ensure
your environment (database at least) is always configured properly.
Please see my other public repos at http://git.davewentzel.com
Markdown is supported
0% or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment