Commit 62c8ee7e authored by dwentzel's avatar dwentzel
Browse files

moving DBA-in-a-Box from unversioned drupal to git

parent 3c4a05df
/*
given a full database .bak file, generates a restore script to restore the db properly
is coded to work specifically with DBA-in-a-box scripts
exec sp_backupAllFull 'c:\sqlbackups\'
exec sp_backupAllLog 'c:\sqlbackups\'
change variables below
then run on any sql server pointing to the local folder with the .bak files
*/
USE master;
GO
SET NOCOUNT ON
DECLARE @dbName sysname
DECLARE @BackupFile VARCHAR(5000) , @PathOnly varchar(5000)
SELECT @BackupFile = 'C:\DATA\DebbySCO_201006041207.bak'
DECLARE @cmd NVARCHAR(500)
DECLARE @fileList TABLE (backupFile NVARCHAR(255))
DECLARE @lastFullBackup NVARCHAR(500)
DECLARE @lastDiffBackup NVARCHAR(500)
DECLARE @dbExists bit
DECLARE @Position int
SELECT @PathOnly = substring(@BackupFile,1,len(@BackupFile) - CHARINDEX('\',REVERSE(@BackupFile),1)+1)
--PRINT '--@PathOnly: ' + @PathOnly
SELECT @dbName = SUBSTRING (@BackupFile,(LEN(@PathOnly)+10),2000)
SELECT @dbName = SUBSTRING (@dbName,1,len(@dbName)-9)
PRINT '--restore scripts for ' + @BackupFile
PRINT '--for database: ' + quotename(@dbName)
PRINT '--these statements assume you are overwriting the existing db, are not changing the dbname,'
PRINT '--and are restoring to the most recent available log records'
PRINT '--you will likely need to change this script to fit your needs'
IF OBJECT_ID('tempdb..#DUMMYfiles') IS NOT NULL
BEGIN
drop table #DUMMYfiles
END;
CREATE TABLE #DUMMYfiles
(LogicalName nvarchar(128)
,PhysicalName nvarchar(260)
,[Type] char(1)
,FileGroupName nvarchar(128)
,Size numeric(20,0)
,MaxSize numeric(20,0)
,FileID bigint
,CreateLSN numeric(25,0)
,DropLSN numeric(25,0)
,UniqueID uniqueidentifier
,ReadOnlyLSN numeric(25,0)
,ReadWriteLSN numeric(25,0)
,BackupSizeInBytes bigint
,SourceBlockSize int
,FileGroupID int
,LogGroupGUID uniqueidentifier
,DifferentialBaseLSN numeric(25,0)
,DifferentialBaseGUID uniqueidentifier
,IsReadOnly bit
,IsPresent bit
,TDEThumbprint varbinary(32)
)
SELECT @cmd = 'RESTORE FILELISTONLY FROM DISK = ''' + @BackupFile + ''''
INSERT INTO #DUMMYFiles EXEC (@cmd)
IF EXISTS (select * from sys.databases WHERE name = @dbName)
BEGIN
SELECT @dbExists = 1
END
ELSE
BEGIN
SELECT @dbExists = 0
END;
IF @dbExists = 1
BEGIN
PRINT '--Step 1: backing up the log tail if possible to folder/setting database offline'
PRINT 'BACKUP LOG ' + quotename(@dbName) + ' TO DISK = ''' + @PathOnly + @dbname + '_logtail.bak'''
PRINT 'ALTER DATABASE ' + quotename(@dbName) + ' SET OFFLINE WITH ROLLBACK IMMEDIATE;'
END;
ELSE
BEGIN
PRINT '--Step 1: restoring to non-existent db, no work to do'
END;
PRINT '--Step 2: restoring db full backup, but not recovering'
PRINT 'RESTORE DATABASE ' + quotename(@dbName) + ' FROM DISK = ''' + @BackupFile + ''''
PRINT ' WITH '
DECLARE dave CURSOR FOR
SELECT ' MOVE ''' + LogicalName + ''' TO ''' + PhysicalName + ''','
FROM #DUMMYFiles
ORDER BY Type
OPEN dave
FETCH NEXT FROM dave INTO @cmd
WHILE (@@FETCH_STATUS = 0)
BEGIN
PRINT @cmd
FETCH NEXT FROM dave INTO @cmd
END
CLOSE dave
DEALLOCATE dave
PRINT ' NORECOVERY, REPLACE;'
PRINT '--Step 3: restoring log chain if possible'
IF OBJECT_ID('tempdb..#DUMMYHeader') IS NOT NULL
BEGIN
drop table #DUMMYHeader
END;
CREATE TABLE #DUMMYHeader
(BackupName nvarchar(128)
,BackupDescription nvarchar(255)
,BackupType smallint
,ExpirationDate datetime
,Compressed bit
,Position smallint
,DeviceType tinyint
,UserName nvarchar(128)
,ServerName nvarchar(128)
,DatabaseName nvarchar(128)
,DatabaseVersion int
,DatabaseCreationDate datetime
,BackupSize numeric(20,0)
,FirstLSN numeric(25,0)
,LastLSN numeric(25,0)
,CheckpointLSN numeric(25,0)
,DatabaseBackupLSN numeric(25,0)
,BackupStartDate datetime
,BackupFinishDate datetime
,SortOrder smallint
,CodePage smallint
,UnicodeLocaleId int
,UnicodeComparisonStyle int
,CompatibilityLevel tinyint
,SoftwareVendorID int
,SoftwareVersionMajor int
,SoftwareVersionMinor int
,SoftwareVersionBuild int
,MachineName nvarchar(128)
,Flags int
,BindingID uniqueidentifier
,RecoveryForkID uniqueidentifier
,Collation nvarchar(128)
,FamilyGUID uniqueidentifier
,HasBulkLoggedData bit
,IsSnapshot bit
,IsReadOnly bit
,IsSingleUser bit
,HasBackupChecksums bit
,IsDamaged bit
,BeginsLogChain bit
,HasIncompleteMetaData bit
,IsForceOffline bit
,IsCopyOnly bit
,FirstRecoveryForkID uniqueidentifier
,ForkPointLSN numeric(25,0)
,RecoveryModel nvarchar(60)
,DifferentialBaseLSN numeric(25,0)
,DifferentialBaseGUID uniqueidentifier
,BackupTypeDescription nvarchar(60)
,BackupSetGUID uniqueidentifier
,CompressedBackupSize bigint
);
SELECT @cmd = 'RESTORE HEADERONLY FROM DISK = ''' + replace(@BackupFile,'_full.','_log.') + ''''
INSERT INTO #DUMMYHeader EXEC (@cmd)
--select * from #DUMMYHeader
DECLARE dave CURSOR FOR
SELECT Position FROM #DUMMYHeader ORDER BY Position
OPEN dave
FETCH NEXT FROM dave INTO @Position
WHILE (@@FETCH_STATUS = 0)
BEGIN
PRINT 'RESTORE LOG ' + quotename(@dbName) + ' FROM DISK = ''' + replace(@BackupFile,'_full.','_log.') + ''''
PRINT ' WITH NORECOVERY, FILE = ' + convert(varchar(5),@Position) + ','
PRINT ' STOPAT = ''' + convert(varchar(200),getdate()) + ''';'
FETCH NEXT FROM dave INTO @Position
END
CLOSE dave
DEALLOCATE dave
PRINT '--Step 4: tail of the log restore'
PRINT 'RESTORE LOG ' + quotename(@dbName) + ' FROM DISK = ''' + @PathOnly + @dbname + '_logtail.bak'''
PRINT ' WITH NORECOVERY,'
PRINT ' STOPAT = ''' + convert(varchar(200),getdate()) + ''';'
PRINT '--Step 5: recover db and bring online'
PRINT 'RESTORE DATABASE ' + quotename(@dbName) + ' WITH RECOVERY;'
--finally, some cleanup steps after any restore.
PRINT 'ALTER DATABASE ' + quotename(@dbName) + ' SET ONLINE;'
PRINT 'ALTER DATABASE ' + quotename(@dbName) + ' SET MULTI_USER;'
PRINT '--Step 6: sync logins/users...this only needs to be run if the backup is being restored to a different server'
PRINT '--this will sync logins if possible, else create a new sql login with a password = user account name'
declare dave cursor for
select 'exec sp_change_users_login auto_fix, ' + CHAR(39) + name + CHAR(39) + ', NULL, '
+ CHAR(39) + name + CHAR(39)
+ CHAR(13) + CHAR(10)+ 'Go'
from sys.sysusers
where islogin = 1 and issqluser =1 and hasdbaccess = 1 and sid > 0x01
OPEN dave
FETCH NEXT FROM dave INTO @cmd
WHILE (@@FETCH_STATUS = 0)
BEGIN
PRINT @cmd
FETCH NEXT FROM dave INTO @cmd
END
CLOSE dave
DEALLOCATE dave
copied from http://www.davewentzel.com/content/dba-box-scripts
There are some changes I haven't gotten around to implementing in the last 10+ years.
Someday...
we delete files from the sqlbackups folder using DOS dir after constructing the date parameters in TSQL. This is wrong...if the agent wasn't running on a given day then those backups never get deleted. Proper way is to use FORFILES in DOS.
This command *should* delete files where the file modified date property is older than 3 days.
FORFILES /p d:\sqlbackups /s /m *.bak /d -3 /c "CMD/C del /Q /F @FILE"
This needs to be tested.
\ No newline at end of file
use msdb
go
if exists (select * from dbo.sysobjects where id = object_id(N'[dbo].[SQLIndexDefragAll]') and OBJECTPROPERTY(id, N'IsProcedure') = 1)
drop procedure [dbo].[SQLIndexDefragAll]
GO
SET QUOTED_IDENTIFIER ON
GO
SET ANSI_NULLS ON
GO
/**************************************************************************************
Purpose : The Purpose of this Stored Procedure is to detect the SQL server version and call the appropriate stored procedure to defrag Indexes in user databases.
Date Created : May 17, 2006
Modification History:
Date Who What
============= =============== ====================================
*/
CREATE PROCEDURE dbo.SQLIndexDefragAll
@dbName VARCHAR(80)=NULL,
@TableName VARCHAR(100)=NULL,
@Frag Float = 10.0
AS SET NOCOUNT ON
DECLARE @Version VARCHAR(255)
SELECT @Version=CASE
WHEN CHARINDEX ('8.00',@@version)>0 then 'SQL Server 2000'
WHEN CHARINDEX ('9.00',@@version)>0 then 'SQL Server 2005'
ELSE 'UnKnown'
END
IF @Version='SQL Server 2000'
BEGIN
EXEC SQLIndexDefragAll_SQL2000
@dbName=@dbName,
@TableName=@TableName,
@maxFrag=@Frag
END
IF @Version='SQL Server 2005'
BEGIN
EXEC SQLIndexDefragAll_SQL2005
@dbName=@dbName,
@TableName=@TableName,
@Frag=@Frag
END
GO
SET QUOTED_IDENTIFIER OFF
GO
SET ANSI_NULLS ON
GO
USE MSDB
GO
if exists (select * from dbo.sysobjects where id = object_id(N'[dbo].[SQLIndexDefragAll_SQL2000]') and OBJECTPROPERTY(id, N'IsProcedure') = 1)
drop procedure [dbo].[SQLIndexDefragAll_SQL2000]
GO
SET QUOTED_IDENTIFIER ON
GO
SET ANSI_NULLS OFF
GO
/**************************************************************************************
Purpose : The Purpose of this Stored Procedure is to defrag Indexes in SQL 2005 user databases.
Date Created : May 17, 2006
Modification History:
Date Who What
============= =============== ====================================
*/
CREATE PROCEDURE dbo.SQLIndexDefragAll_SQL2000
@DBName VARCHAR(80)=NULL,
@TableName VARCHAR(100)=NULL,
@maxfrag DECIMAL =10.0
AS
SET NOCOUNT ON
DECLARE @objectid INT
DECLARE @indexid INT
DECLARE @indexname VARCHAR(255)
DECLARE @StrSQL NVARCHAR(2000)
DECLARE @execstr NVARCHAR(2000)
DECLARE @OutputMessage NVARCHAR(2000)
DECLARE @schmaName NVARCHAR(80)
DECLARE @frag DECIMAL
DECLARE @tblName VARCHAR(100)
DECLARE @OuterLoop INT
DECLARE @InnerLoop INT
DECLARE @InnerLoop2 INT
DECLARE @sDbname VARCHAR(80)
DECLARE @SQLCommand varchar(2000)
DECLARE @rc int
DECLARE @LSrc int
DECLARE @SQLrc int
DECLARE @DatabaseName VARCHAR(50)
DECLARE @ErrorText varchar(200)
DECLARE @Errormessage VARCHAR(400)
--Create the table
if exists (select * from dbo.sysobjects where id = object_id(N'[dbo].[SQLIndexDefragCommands]') and OBJECTPROPERTY(id, N'IsUserTable') = 1)
drop table [dbo].[SQLIndexDefragCommands]
CREATE TABLE [dbo].[SQLIndexDefragCommands] (
[DBName] [varchar] (80) COLLATE SQL_Latin1_General_CP1_CI_AS NULL ,
[DefragCommand] [varchar] (2000) COLLATE SQL_Latin1_General_CP1_CI_AS NULL ,
[Process] [int] NULL
) ON [PRIMARY]
--Another table to store table names.
CREATE TABLE #TableList (Tabname VARCHAR(80))
--Create a table to store databaseNames.
CREATE TABLE #TempDBList
(DBName VARCHAR(80),
Process INT DEFAULT 0
)
--Create a Temp table to store
-- the table Names
CREATE TABLE #TempTableList
(DatabaseName VARCHAR(80),
SchemaName VARCHAR(80),
TableName VARCHAR(80),
Process INT DEFAULT 0
)
--Create table name to store indexes
CREATE TABLE #fraglist
(DatabaseName VARCHAR(80),
ObjectName [char] (255) COLLATE SQL_Latin1_General_CP1_CI_AS NULL ,
ObjectId int NULL ,
IndexName char (255) COLLATE SQL_Latin1_General_CP1_CI_AS NULL ,
IndexId int NULL ,
Lvl int NULL ,
CountPages int NULL ,
CountRows int NULL ,
MinRecSize int NULL ,
MaxRecSize int NULL ,
AvgRecSize int NULL ,
ForRecCount int NULL ,
Extents int NULL ,
ExtentSwitches int NULL ,
AvgFreeBytes int NULL ,
AvgPageDensity int NULL ,
ScanDensity decimal(18, 0) NULL ,
BestCount int NULL ,
ActualCount int NULL ,
LogicalFrag decimal(18, 0) NULL ,
ExtentFrag decimal(18, 0) NULL ,
Status INT DEFAULT 0
)
--Check If dbname is passed as null and a table is passed.
--Raise an error in that situation.
SET @ErrorMessage='Reindexing Requires a Database Name.In order to reindex single or multiple tables'+CHAR(13)+CHAR(10)
+'both the database and table names must be passed.'
IF (@DBNAME IS NULL AND @TableName IS NOT NULL)
BEGIN
RAISERROR (@Errormessage,16,1)
RETURN
END
--Section I. Prepare the commands for the IndexDefrag.
IF @DBName IS NULL
BEGIN
INSERT INTO #TempDBList(DBName)
SELECT [NAME] AS DBName FROM master.dbo.sysdatabases AS A
WHERE [NAME] NOT IN ('master','msdb','tempdb','Adventureworks','model','pubs')
AND status &512 = 0
AND isnull(databaseproperty(a.name,'isReadOnly'),0) = 0
AND isnull(databaseproperty(a.name,'isOffline'),0) = 0
AND isnull(databaseproperty(a.name,'IsSuspect'),0) = 0
AND isnull(databaseproperty(a.name,'IsShutDown'),0) = 0
AND isnull(databaseproperty(a.name,'IsNotRecovered'),0) = 0
AND isnull(databaseproperty(a.name,'IsInStandBy'),0) = 0
AND isnull(databaseproperty(a.name,'IsInRecovery'),0) = 0
AND isnull(databaseproperty(a.name,'IsInLoad'),0) = 0
AND isnull(databaseproperty(a.name,'IsEmergencyMode'),0) = 0
AND isnull(databaseproperty(a.name,'IsDetached'),0) = 0
AND NOT EXISTS (SELECT B.[NAME]
FROM msdb..SQLDBIndexDefragExclusions b
WHERE A.[NAME] = b.[NAME])
ORDER BY [Name] ASC
END
ELSE
BEGIN
INSERT INTO #TempDBList(DBName)
SELECT [NAME] AS DBName FROM master.dbo.sysdatabases AS A
WHERE [NAME] NOT IN ('master','msdb','tempdb','Adventureworks','model','pubs')
AND status &512 = 0
AND isnull(databaseproperty(a.name,'isReadOnly'),0) = 0
AND isnull(databaseproperty(a.name,'isOffline'),0) = 0
AND isnull(databaseproperty(a.name,'IsSuspect'),0) = 0
AND isnull(databaseproperty(a.name,'IsShutDown'),0) = 0
AND isnull(databaseproperty(a.name,'IsNotRecovered'),0) = 0
AND isnull(databaseproperty(a.name,'IsInStandBy'),0) = 0
AND isnull(databaseproperty(a.name,'IsInRecovery'),0) = 0
AND isnull(databaseproperty(a.name,'IsInLoad'),0) = 0
AND isnull(databaseproperty(a.name,'IsEmergencyMode'),0) = 0
AND isnull(databaseproperty(a.name,'IsDetached'),0) = 0
AND [Name]=@DBName
END
--Loop over the databases
DECLARE DBCursor CURSOR
FOR SELECT DBNAME
FROM #TempDbList
WHERE Process=0
OPEN DBCursor
FETCH NEXT FROM DBCursor INTO @sDbname
--Save the fetch status to a variable
SELECT @OuterLoop = @@FETCH_STATUS
WHILE @OuterLoop = 0
BEGIN
SELECT @StrSQL = N'SELECT ' +''''+ @sDbName +'''' +'AS DatabaseName, ' + 'QUOTENAME(''dbo'') As SchemaName, QUOTENAME([NAME]) As TableName FROM ' + @sDbName +'.'+'dbo.sysobjects where type = ''U'' and uid = 1 AND [NAME] NOT LIKE ''dt%'''
INSERT INTO #TempTableList
(DatabaseName,
SchemaName,
TableName)
EXEC sp_executesql @StrSQL
IF @TableName IS NULL
BEGIN
DECLARE TableCursor CURSOR FOR
SELECT DatabaseName,
SchemaName,
TableName
FROM #TempTableList
WHERE Process=0
ORDER BY TableName ASC
END
ELSE
BEGIN
INSERT INTO #TableList (Tabname)
SELECT TABLENAME
FROM dbo.fnCSV_To_Table(@TableName)
DECLARE TableCursor CURSOR
FOR SELECT DatabaseName,
SchemaName,
TableName
FROM #TempTableList
WHERE TableName IN
(SELECT QUOTENAME(TabName) FROM #TableList)
ORDER BY TableName ASC
END
OPEN TableCursor
FETCH NEXT FROM TableCursor INTO @sdbName,@schmaName,@tblName
--Save fetch status into local variable
SELECT @InnerLoop = @@FETCH_STATUS
WHILE @InnerLoop = 0
BEGIN
SELECT @StrSQL = N'USE ' + quotename(@sDbname, '[') + N'; DBCC SHOWCONTIG('''+ @schmaName + '.' + @tblName +''') WITH TABLERESULTS,ALL_INDEXES, NO_INFOMSGS;'
INSERT INTO SQLIndexDefragCommands (DBName,DefragCommand)
VALUES (@sdbName,@StrSQL)
UPDATE #TempTableList
SET Process = 1
WHERE DatabaseName = @sDbname
AND Process=0
FETCH NEXT FROM TableCursor INTO @sdbName,@schmaName,@tblName
SELECT @InnerLoop = @@FETCH_STATUS
END
CLOSE TableCursor
DEALLOCATE TableCursor
--Update the processed database status
UPDATE #TempDbList
SET Process = 1
WHERE DBName = @sDbname
AND Process=0
FETCH NEXT FROM DBCursor into @sDbname
SELECT @OuterLoop = @@FETCH_STATUS
END
CLOSE DBCursor
DEALLOCATE DBCursor
--Section II. Get the commands from the IndexDefrag table and execute them.
DECLARE SQLCommand_Cursor CURSOR
FOR
select DBName,DefragCommand
from msdb.dbo.SQLIndexDefragCommands
order by DBName ASC
OPEN SQLCommand_Cursor
FETCH NEXT FROM SQLCommand_Cursor
INTO @DBName
,@SQLCommand
WHILE (@@FETCH_STATUS <> -1)
BEGIN
IF (@@FETCH_STATUS <> -2)