StandardSQL2000Setup.sql 30.5 KB
Newer Older
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232 233 234 235 236 237 238 239 240 241 242 243 244 245 246 247 248 249 250 251 252 253 254 255 256 257 258 259 260 261 262 263 264 265 266 267 268 269 270 271 272 273 274 275 276 277 278 279 280 281 282 283 284 285 286 287 288 289 290 291 292 293 294 295 296 297 298 299 300 301 302 303 304 305 306 307 308 309 310 311 312 313 314 315 316 317 318 319 320 321 322 323 324 325 326 327 328 329 330 331 332 333 334 335 336 337 338 339 340 341 342 343 344 345 346 347 348 349 350 351 352 353 354 355 356 357 358 359 360 361 362 363 364 365 366 367 368 369 370 371 372 373 374 375 376 377 378 379 380 381 382 383 384 385 386 387 388 389 390 391 392 393 394 395 396 397 398 399 400 401 402 403 404 405 406 407 408 409 410 411 412 413 414 415 416 417 418 419 420 421 422 423 424 425 426 427 428 429 430 431 432 433 434 435 436 437 438 439 440 441 442 443 444 445 446 447 448 449 450 451 452 453 454 455 456 457 458 459 460 461 462 463 464 465 466 467 468 469 470 471 472 473 474 475 476 477 478 479 480 481 482 483 484 485 486 487 488 489 490 491 492 493 494 495 496 497 498 499 500 501 502 503 504 505 506 507 508 509 510 511 512 513 514 515 516 517 518 519 520 521 522 523 524 525 526 527 528 529 530 531 532 533 534 535 536 537 538 539 540 541 542 543 544 545 546 547 548 549 550 551 552 553 554 555 556 557 558 559 560 561 562 563 564 565 566 567 568 569 570 571 572 573 574 575 576 577 578 579 580 581 582 583 584 585 586 587 588 589 590 591 592 593 594 595 596 597 598 599 600 601 602 603 604 605 606 607 608 609 610 611 612 613 614 615 616 617 618 619 620 621 622 623 624 625 626 627 628 629 630 631 632 633 634 635 636 637 638 639 640 641 642 643 644 645 646 647 648 649 650 651 652 653 654 655 656 657 658 659 660 661 662 663 664 665 666 667 668 669 670 671 672 673 674 675 676 677 678 679 680 681 682 683 684 685 686 687 688 689 690 691 692 693 694 695 696 697 698 699 700 701 702 703 704 705 706 707 708 709 710 711 712 713 714 715 716 717 718 719 720 721 722 723 724 725 726 727
/*
Jeffrey Barachko 20040325

This script will create 4 stored procedures (sp_backupAllFull, sp_backupAllLog, sp_index_defrag_all and
sp_dbcc_all_dbs. After that, it will create a Server Admin Operator, next will create the following Jobs:
Backup All Databases 12AM, Backup all Logs Hourly, all-Sat12am-IndexDefrag and General-OnStart. Next it will 
create 2 new alerts, one for Deadlocking and one for Full Database Logs (this alert will kick off the Backup \
Log job) and sets all the alerts to email the Server Admin Operator.

NOTE: All Backups are set to be stored on D:\SQLBackups and jobs stored on D:\JobLogs. If you would like to store them
in a different location please modify this script before Running.

NOTE: For some reason, the Operator Notification does not work correctly with this script. After running, plese modify
each job to enable notification based on whatever method you choose.

20040506  Dave Wentzel  changed dbcc proc so that it skips Loading/Offline/Suspect/etc dbs.



*/

SET QUOTED_IDENTIFIER ON 
GO
SET ANSI_NULLS ON 
GO

if exists (select * from sysobjects where id = object_id('sp_backupAllFull'))
drop proc sp_backupAllFull
go



CREATE PROCEDURE sp_backupAllFull
(@backup_file_location varchar(500) = 'd:\sqlbackups\'
)
AS
BEGIN			--begin procedure
/*
AUTHOR: 		Dave Wentzel
PURPOSE: 		backs up the necessary CABS databases to d:\sqlbackups where the dump files have the name in the form
			<dbname>_yyyymmdd_full.bak.  It then deletes any dump files 4 days old. 
LAST MODIFIED:		20040217
DEVELOPER HISTORY:
Name			Date		Change Notes
-----------------------------------------------------
Dave Wentzel		20011102	Moved log backups to d:\sqllogbackups b/c of BackupExec problems.  
Jeff Barachko		20021028	Moved Full and Log backups to new E:\drive
Jeff Barachko		20040106	Made non-CABS specific
Jeff Barachko		20040217	Added logic to ensure database is not InLoad, InRecovery or ISTruncLog before trying log backup
Dave Wentzel		20040311	parameterized the location of the backup files.  
Dave Wentzel		20040504	backups failing when db is offline, added that param to proc

Additional Information available in Visual SourceSafe.
*/
SET NOCOUNT ON

SELECT 'Beginning full database backups of all databases except tempdb, pubs, northwind, distribution'
SELECT 'Procedure start:  ', getdate()

DECLARE 
	@datestring varchar(100)			--holds a converted date string for the backup process
	,@dbname	 varchar(100)			--holds the current db name in the cursor loop
	,@cmd varchar(1000)				--holds the backup command to be executed
	
SELECT @datestring = convert(varchar(100), getdate(),112)   --gives me yyyymmdd

--perform the backup on each database via a cursor loop, creating the full and log devices as you go
DECLARE CurBackups CURSOR STATIC READ_ONLY FOR
	SELECT name 
	FROM sysdatabases WHERE name NOT IN ('tempdb','pubs','northwind', 'distribution')
	AND databasepropertyex(name,'IsInStandby') = 0
	AND databasepropertyex(name, 'Status') = 'ONLINE'
OPEN CurBackups
FETCH NEXT FROM CurBackups INTO @dbname
WHILE (@@FETCH_STATUS = 0)
BEGIN
	SELECT 'Backing up ' + @dbname + '...'
	--gives me BACKUP DATABASE DATABASENAME TO DISK = 'd:\sqlbackups\20010119_databasename_full.bak' WITH INIT
	SELECT @cmd = 'BACKUP DATABASE [' + @dbname + '] TO DISK = ''' + @backup_file_location + @datestring + '_' + @dbname + '_full.bak'' WITH INIT'
	SELECT @cmd
	EXEC (@cmd)
	IF (@@error <>0)
	BEGIN
		RAISERROR ('Error occurred during backup process.', 16, 1) WITH LOG
    		RETURN 1
    	END
	SELECT 'Done backing up database ' + @dbname + '!'
	IF (@dbname) NOT IN ('master','model','msdb')
	BEGIN
	IF (databaseproperty(@dbname,'IsInLoad') = 0 AND databaseproperty(@dbname,'IsInRecovery') = 0 AND databaseproperty(@dbname,'IsTruncLog') = 0)
		BEGIN
			SELECT 'Performing log backup for ' + @dbname + '...'
			--gives me BACKUP LOG databasename TO DISK = 'd:\sqlbackups\20010119_databasename_log.bak' WITH INIT
			SELECT @cmd = 'BACKUP LOG [' + @dbname + '] TO DISK = ''' + @backup_file_location + @datestring + '_' + @dbname + '_log.bak'' WITH INIT'
			SELECT @cmd
			EXEC (@cmd)
			IF (@@error <>0)
			BEGIN
				RAISERROR ('Error occurred during log backup process.', 16, 1) WITH LOG
	 	   		RETURN 1
			END
			SELECT 'Done backing up log ' + @dbname + '!'
	END
	ELSE
		BEGIN
		SELECT @dbname + ' is in recovery, in loading process, or is in trunc log on chkpt mode, so the logs for it are not being backed up.'
		END	
	END
	FETCH NEXT FROM CurBackups INTO @dbname
END
CLOSE CurBackups
DEALLOCATE CurBackups

--clear out any dump files 3 days old, sqlbackups
SELECT 'Clearing out any dump files from 3 days ago from \sqlbackups and \sqllogbackups...'
SELECT @datestring = convert(varchar(100), getdate() - 4, 112)  --gives me yyyymmdd for 4 days ago
SELECT @cmd = 'del ' + @backup_file_location + @datestring + '*.*'
SELECT @cmd
EXEC master..xp_cmdshell @cmd



SELECT 'Procedure end:  ', getdate()
END				--end procedure
GO
SET QUOTED_IDENTIFIER OFF 
GO
SET ANSI_NULLS ON 
GO

SET QUOTED_IDENTIFIER ON 
GO
SET ANSI_NULLS ON 
GO

if exists (select * from sysobjects where id = object_id ('sp_backupAllLog'))
	drop proc sp_backupAllLog
go


CREATE PROCEDURE sp_backupAllLog
(@backup_file_location varchar(500) = 'd:\sqlbackups\'
)
AS

BEGIN			--begin procedure
/*
AUTHOR: 		Dave Wentzel
PURPOSE: 		backs up log files to D:\sqlbackups
LAST MODIFIED:		20011102
DEVELOPER HISTORY
Name			Date			Change Notes
------------------------------------------------------------
Dave Wentzel		20011102		moved log backups to sqllogbackups b/c of BackupExec issues
Jeff Barachko		20021028		moved log backups to new E:\drive
Jeff Barachko		20030501		changed proc to backup to 6 log.baks instead of 1
Jeff Barachko		20040106		changed proc back to 1 file instead of six and made non-CABS specific
Dave Wentzel		20040311		parameterized the location for the dump files. 
Dave Wentzel		20040721		proc failing on suspect dbs.  Added a line to check for status of online.  
Additional Information available in Visual SourceSafe.
*/

SET NOCOUNT ON

SELECT 'Beginning log backups of all databases except tempdb, pubs, northwind, master, model, msdb, and distribution'
SELECT 'Procedure start:  ', getdate()

DECLARE 
	@datestring varchar(100)			--holds a converted date string for the backup process
	,@dbname	 varchar(100)			--holds the current db name in the cursor loop
	,@cmd varchar(1000)				--holds the backup command to be executed
	
SELECT @datestring = convert(varchar(100), getdate(),112)   --gives me yyyymmdd

--run the tran log backups
DECLARE CurBackups CURSOR STATIC READ_ONLY FOR
	SELECT name 
	FROM sysdatabases WHERE name NOT IN ('tempdb','pubs','northwind','distribution','master','model','msdb')
OPEN CurBackups
FETCH FIRST FROM CurBackups INTO @dbname
WHILE (@@FETCH_STATUS = 0)
BEGIN
	--added 20010531, Dave Wentzel, check to be sure database is not in recovery mode, loading, or trunc. log on chkpt mode.  If so, skip it.  
	IF (databaseproperty(@dbname,'IsInLoad') = 0 AND databaseproperty(@dbname,'IsInRecovery') = 0 AND databaseproperty(@dbname,'IsTruncLog') = 0) AND databasepropertyex(@dbname, 'Status') = 'ONLINE'
	BEGIN
		SELECT 'Performing log backup for ' + @dbname + '...'
		--gives me BACKUP LOG databasename TO DISK = 'd:\backups\20010119_databasename_log.bak' WITH NOINIT
		SELECT @cmd = 'BACKUP LOG [' + @dbname + '] TO DISK = ''' + @backup_file_location + @datestring + '_' + @dbname + '_log.bak'' WITH NOINIT'
		SELECT @cmd
		EXEC (@cmd)
		IF (@@error <>0)
		BEGIN
			RAISERROR ('Error occurred during log backup process.', 16, 1) WITH LOG
	 		RETURN 1
		END
		SELECT 'Done backing up log ' + @dbname + '!'
	END
	ELSE
	BEGIN
		SELECT @dbname + ' is in recovery, in loading process, or is in trunc log on chkpt mode, so the logs for it are not being backed up.'
	END	
	FETCH NEXT FROM CurBackups INTO @dbname
END
CLOSE CurBackups
DEALLOCATE CurBackups
SELECT 'Procedure end:  ', getdate()
END				--end procedure
GO
SET QUOTED_IDENTIFIER OFF 
GO
SET ANSI_NULLS ON 
GO

SET QUOTED_IDENTIFIER OFF 
GO
SET ANSI_NULLS ON 
GO
USE master 
go

if exists (select * from sysobjects where id = object_id('sp_dbcc_all_dbs'))
	drop proc sp_dbcc_all_dbs
go

CREATE PROCEDURE sp_dbcc_all_dbs
AS
/*
Name:		sp_dbcc_all_dbs
Author:		Dave Wentzel
Create Date:	11/6/2000
Purpose:	Runs dbcc checkdb (with no_infomsgs) on each database (or you can specify
		the dbs at the appropriate location below) on your server.  
Known Bugs:	None
History:	None
*/
SET NOCOUNT ON 
SET QUOTED_IDENTIFIER OFF
SELECT getdate()
DECLARE @db varchar(1000)
--declare a cursor to cycle through all dbs except those listed in parens
DECLARE dbcc_cursor CURSOR FORWARD_ONLY READ_ONLY FOR
	SELECT 'DBCC CHECKDB (''' + name +''') WITH NO_INFOMSGS'
	FROM sysdatabases 
	WHERE name NOT IN ('tempdb','pubs','Northwind')
	AND databasepropertyex(name,'IsInStandby') = 0
	AND databasepropertyex(name, 'Status') = 'ONLINE'
	AND databasepropertyex(name, 'Updateability') = 'READ_WRITE'
	ORDER BY name
OPEN dbcc_cursor
FETCH NEXT FROM dbcc_cursor INTO @db
WHILE (@@FETCH_STATUS = 0)
BEGIN
	SELECT @db
	SELECT ' ' 
	SELECT ' ' 
	EXEC (@db)
	FETCH NEXT FROM dbcc_cursor INTO @db
END
CLOSE dbcc_cursor
DEALLOCATE dbcc_cursor
SELECT getdate()
SELECT 'Done!'
GO
SET QUOTED_IDENTIFIER OFF 
GO
SET ANSI_NULLS ON 
GO





CREATE PROC sp_index_defrag_all
AS
BEGIN     --procedure
/*
Name:		sp_index_defrag_all
Author:		Dave Wentzel
Create Date:	20031216
Purpose:	Runs DBCC INDEXDEFRAG for any index found to be above 10% fragmented on the server.  Then runs UPDATE statistics 
		for every table in every database.  Database exception list is inline.  
Known Bugs:	sp_msforeachdb has a 2000 execstring limit.  Because of this the string is not commented properly because I'm very near
		the limit.  Be careful if this procedure needs to be modified in the future.  
		when excluding databases the exclusion check is done TWICE in the code below.  
History:	
		Procedure was rewritten due to collation conflicts when the server is in one collation and the db in another.  
		This procedure builds an execstring
		that uses ? as a replacement parameter for sp_msforeachdb.  This gets around the collation issues.  SHOWCONTIG is executed and a table is built
		so we don't defrag things needless which blows up the transaction logs.  
Developer	Change Date		Notes
------------------------------------------------------------------------------
Dave Wentzel	20040202		Split work into two msforeachdb calls due to 2000 character limit.  
					Added code to check status of db before doing work, (dont run on readonly dbs).  
					Changed code for indexdefrag because it wasnt pulling table owner info properly, not sure why.  

*/
SET NOCOUNT ON 
SET QUOTED_IDENTIFIER OFF
SET ARITHABORT ON
DECLARE @db nvarchar(100)		--holds the name of the database
	,@SQLStr nvarchar(2000)		--used for sp_executesql string execution
	,@param nvarchar(500)		--used for sp_executesql parameter declaration


--first, perform DBCC INDEXDEFRAG
EXEC sp_MSforeachdb 'declare @db varchar(100) select @db = ''[?]''
IF (ltrim(rtrim(@db)) not in (''[master]'',''[model]'',''[msdb]'', ''[tempdb]'')) 
begin  
IF databasepropertyex(''?'',''IsInStandby'') = 0  AND databasepropertyex(''?'',''Status'') = ''ONLINE'' AND databasepropertyex(''?'',''Updateability'') = ''READ_WRITE''
begin  
SELECT ''Running INDEXDEFRAG for ?''

DECLARE @tb NVARCHAR(128),@execstr NVARCHAR(2000),@idx nvarchar(128),@frag DECIMAL, @maxfrag DECIMAL, @sch nvarchar(50)

SELECT @maxfrag = 10

CREATE TABLE #fraglist (ObjectName CHAR (255), ObjectId INT,IndexName CHAR (255), IndexId INT,Lvl INT,CountPages INT,
   CountRows INT,MinRecSize INT,MaxRecSize INT,AvgRecSize INT,ForRecCount INT,Extents INT,ExtentSwitches INT,
   AvgFreeBytes INT,AvgPageDensity INT, ScanDensity DECIMAL,BestCount INT,ActualCount INT,LogicalFrag DECIMAL,
   ExtentFrag DECIMAL)

INSERT INTO #fraglist EXEC (''USE [?] DBCC SHOWCONTIG WITH FAST, TABLERESULTS, ALL_INDEXES, NO_INFOMSGS'')

DECLARE indexes CURSOR FOR
SELECT quotename(t.table_schema + ''.'' + so.name) , quotename(si.name)
FROM #fraglist f
JOIN [?]..sysobjects so
ON so.id = f.ObjectId
JOIN [?]..sysindexes si 
ON so.id = si.id
AND f.IndexId = si.indid
JOIN [?].INFORMATION_SCHEMA.TABLES t
ON so.name = t.TABLE_NAME
WHERE f.LogicalFrag >= @maxfrag AND so.type = ''U'' AND si.indid <> 0 AND si.indid <> 255
ORDER BY so.name, si.name
OPEN indexes
FETCH NEXT FROM indexes INTO @tb, @idx
WHILE (@@FETCH_STATUS = 0)
BEGIN
SELECT @execstr = N''DBCC INDEXDEFRAG ([?],'' + RTRIM(@tb) + '','' + RTRIM(@idx) + '')''
SELECT @execstr
EXEC (@execstr)
FETCH NEXT FROM indexes INTO @tb, @idx
END
CLOSE indexes
DEALLOCATE indexes

DROP TABLE #fraglist

end  
end  
'

--now perform UPDATE STATISTICS

EXEC sp_MSforeachdb 'declare @db varchar(100) select @db = ''[?]''
IF (ltrim(rtrim(@db)) not in (''[master]'',''[model]'',''[msdb]'', ''[tempdb]'')) 
begin  --db check
IF databasepropertyex(''?'',''IsInStandby'') = 0  AND databasepropertyex(''?'',''Status'') = ''ONLINE'' AND databasepropertyex(''?'',''Updateability'') = ''READ_WRITE''
begin  --db online
SELECT ''Running UPDATE STATS for ?''
DECLARE @tb NVARCHAR(128),@execstr NVARCHAR(2000),@sch nvarchar(50)

DECLARE tbl CURSOR FOR
SELECT  quotename(TABLE_NAME), quotename(TABLE_SCHEMA)
FROM [?].INFORMATION_SCHEMA.TABLES
WHERE TABLE_TYPE = ''BASE TABLE''
OPEN tbl
FETCH NEXT FROM tbl INTO @tb, @sch
WHILE (@@fetch_status = 0)
BEGIN

SELECT @execstr = N''UPDATE STATISTICS [?].'' + @sch + ''.'' + @tb 
SELECT @execstr
EXEC (@execstr)
FETCH NEXT FROM tbl INTO @tb, @sch
END
CLOSE tbl
DEALLOCATE tbl
end  --db online
end  --db check
'

END  --procedure
GO
SET QUOTED_IDENTIFIER OFF 
GO
SET ANSI_NULLS ON 
GO


-- Script generated on 3/24/2004 4:11 PM
-- By: sa
-- Server: USATRAME0374\INSTANCEA

IF (EXISTS (SELECT name FROM msdb.dbo.sysoperators WHERE name = N'Server Admins'))
 ---- Delete operator with the same name.
  EXECUTE msdb.dbo.sp_delete_operator @name = N'Server Admins' 
BEGIN 
EXECUTE msdb.dbo.sp_add_operator @name = N'Server Admins', @enabled = 1, @email_address = N'USPhiladelphiaSVSQLAdmins@deloitte.com', @category_name = N'[Uncategorized]', @weekday_pager_start_time = 80000, @weekday_pager_end_time = 180000, @saturday_pager_start_time = 80000, @saturday_pager_end_time = 180000, @sunday_pager_start_time = 80000, @sunday_pager_end_time = 180000, @pager_days = 62
END
 
go

-- Script generated on 3/24/2004 4:14 PM
-- By: sa
-- Server: USATRAME0374\INSTANCEA

BEGIN TRANSACTION            
  DECLARE @JobID BINARY(16)  
  DECLARE @ReturnCode INT    
  SELECT @ReturnCode = 0     
IF (SELECT COUNT(*) FROM msdb.dbo.syscategories WHERE name = N'[General Maintenance]') < 1 
  EXECUTE msdb.dbo.sp_add_category @name = N'[General Maintenance]'

  -- Delete the job with the same name (if it exists)
  SELECT @JobID = job_id     
  FROM   msdb.dbo.sysjobs    
  WHERE (name = N'all-Sat12am-IndexDefrag')       
  IF (@JobID IS NOT NULL)    
  BEGIN  
  -- Check if the job is a multi-server job  
  IF (EXISTS (SELECT  * 
              FROM    msdb.dbo.sysjobservers 
              WHERE   (job_id = @JobID) AND (server_id <> 0))) 
  BEGIN 
    -- There is, so abort the script 
    RAISERROR (N'Unable to import job ''all-Sat12am-IndexDefrag'' since there is already a multi-server job with this name.', 16, 1) 
    GOTO QuitWithRollback  
  END 
  ELSE 
    -- Delete the [local] job 
    EXECUTE msdb.dbo.sp_delete_job @job_name = N'all-Sat12am-IndexDefrag' 
    SELECT @JobID = NULL
  END 

BEGIN 

  -- Add the job
  EXECUTE @ReturnCode = msdb.dbo.sp_add_job @job_id = @JobID OUTPUT , @job_name = N'all-Sat11pm-IndexDefrag', @owner_login_name = N'sa', @description = N'No description available.', @category_name = N'[General Maintenance]', @enabled = 1, @notify_level_email = 3, @notify_level_page = 0, @notify_level_netsend = 0, @notify_level_eventlog = 2, @delete_level= 0, @notify_email_operator_name = N'Server Admins'
  IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback 

  -- Add the job steps
  EXECUTE @ReturnCode = msdb.dbo.sp_add_jobstep @job_id = @JobID, @step_id = 1, @step_name = N'sp_index_defrag_all', @command = N'sp_index_defrag_all', @database_name = N'master', @server = N'', @database_user_name = N'', @subsystem = N'TSQL', @cmdexec_success_code = 0, @flags = 0, @retry_attempts = 0, @retry_interval = 1, @output_file_name = N'D:\Joblogs\sp_index_defrag_all.out', @on_success_step_id = 0, @on_success_action = 1, @on_fail_step_id = 0, @on_fail_action = 2
  IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback 
  EXECUTE @ReturnCode = msdb.dbo.sp_update_job @job_id = @JobID, @start_step_id = 1 

  IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback 

  -- Add the job schedules
  EXECUTE @ReturnCode = msdb.dbo.sp_add_jobschedule @job_id = @JobID, @name = N'Sat Night', @enabled = 1, @freq_type = 8, @active_start_date = 20031229, @active_start_time = 230000, @freq_interval = 64, @freq_subday_type = 1, @freq_subday_interval = 0, @freq_relative_interval = 0, @freq_recurrence_factor = 1, @active_end_date = 99991231, @active_end_time = 235959
  IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback 

  -- Add the Target Servers
  EXECUTE @ReturnCode = msdb.dbo.sp_add_jobserver @job_id = @JobID, @server_name = N'(local)' 
  IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback 

END
COMMIT TRANSACTION          
GOTO   EndSave              
QuitWithRollback:
  IF (@@TRANCOUNT > 0) ROLLBACK TRANSACTION 
EndSave: 

 go
 
-- Script generated on 3/24/2004 4:24 PM
-- By: sa
-- Server: USATRAME0374\INSTANCEA

BEGIN TRANSACTION            
  DECLARE @JobID BINARY(16)  
  DECLARE @ReturnCode INT    
  SELECT @ReturnCode = 0     
IF (SELECT COUNT(*) FROM msdb.dbo.syscategories WHERE name = N'Database Maintenance') < 1 
  EXECUTE msdb.dbo.sp_add_category @name = N'Database Maintenance'

  -- Delete the job with the same name (if it exists)
  SELECT @JobID = job_id     
  FROM   msdb.dbo.sysjobs    
  WHERE (name = N'Backup All Databases 12AM')       
  IF (@JobID IS NOT NULL)    
  BEGIN  
  -- Check if the job is a multi-server job  
  IF (EXISTS (SELECT  * 
              FROM    msdb.dbo.sysjobservers 
              WHERE   (job_id = @JobID) AND (server_id <> 0))) 
  BEGIN 
    -- There is, so abort the script 
    RAISERROR (N'Unable to import job ''Backup All Databases 12AM'' since there is already a multi-server job with this name.', 16, 1) 
    GOTO QuitWithRollback  
  END 
  ELSE 
    -- Delete the [local] job 
    EXECUTE msdb.dbo.sp_delete_job @job_name = N'Backup All Databases 12AM' 
    SELECT @JobID = NULL
  END 

BEGIN 

  -- Add the job
  EXECUTE @ReturnCode = msdb.dbo.sp_add_job @job_id = @JobID OUTPUT , @job_name = N'Backup All Databases 12AM', @owner_login_name = N'sa', @description = N'No description available.', @category_name = N'Database Maintenance', @enabled = 1, @notify_level_email = 2, @notify_level_page = 0, @notify_level_netsend = 0, @notify_level_eventlog = 2, @delete_level= 0, @notify_email_operator_name = N'Server Admins'
  IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback 

  -- Add the job steps
  EXECUTE @ReturnCode = msdb.dbo.sp_add_jobstep @job_id = @JobID, @step_id = 1, @step_name = N'DBCC All Databases', @command = N'sp_dbcc_all_dbs', @database_name = N'master', @server = N'', @database_user_name = N'', @subsystem = N'TSQL', @cmdexec_success_code = 0, @flags = 0, @retry_attempts = 0, @retry_interval = 1, @output_file_name = N'D:\Joblogs\Backup all Databases 12AM.out', @on_success_step_id = 0, @on_success_action = 3, @on_fail_step_id = 0, @on_fail_action = 2
  IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback 
  EXECUTE @ReturnCode = msdb.dbo.sp_add_jobstep @job_id = @JobID, @step_id = 2, @step_name = N'Backup All', @command = N'exec sp_backupAllFull', @database_name = N'master', @server = N'', @database_user_name = N'', @subsystem = N'TSQL', @cmdexec_success_code = 0, @flags = 2, @retry_attempts = 0, @retry_interval = 1, @output_file_name = N'D:\Joblogs\Backup all Databases 12AM.out', @on_success_step_id = 0, @on_success_action = 1, @on_fail_step_id = 0, @on_fail_action = 2
  IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback 
  EXECUTE @ReturnCode = msdb.dbo.sp_update_job @job_id = @JobID, @start_step_id = 1 

  IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback 

  -- Add the job schedules
  EXECUTE @ReturnCode = msdb.dbo.sp_add_jobschedule @job_id = @JobID, @name = N'Daily at 12AM', @enabled = 1, @freq_type = 4, @active_start_date = 20040106, @active_start_time = 0, @freq_interval = 1, @freq_subday_type = 1, @freq_subday_interval = 0, @freq_relative_interval = 0, @freq_recurrence_factor = 0, @active_end_date = 99991231, @active_end_time = 235959
  IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback 

  -- Add the Target Servers
  EXECUTE @ReturnCode = msdb.dbo.sp_add_jobserver @job_id = @JobID, @server_name = N'(local)' 
  IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback 

END
COMMIT TRANSACTION          
GOTO   EndSave              
QuitWithRollback:
  IF (@@TRANCOUNT > 0) ROLLBACK TRANSACTION 
EndSave: 


 go

-- Script generated on 3/24/2004 4:25 PM
-- By: sa
-- Server: USATRAME0374\INSTANCEA

BEGIN TRANSACTION            
  DECLARE @JobID BINARY(16)  
  DECLARE @ReturnCode INT    
  SELECT @ReturnCode = 0     
IF (SELECT COUNT(*) FROM msdb.dbo.syscategories WHERE name = N'Database Maintenance') < 1 
  EXECUTE msdb.dbo.sp_add_category @name = N'Database Maintenance'

  -- Delete the job with the same name (if it exists)
  SELECT @JobID = job_id     
  FROM   msdb.dbo.sysjobs    
  WHERE (name = N'Backup all Logs Hourly')       
  IF (@JobID IS NOT NULL)    
  BEGIN  
  -- Check if the job is a multi-server job  
  IF (EXISTS (SELECT  * 
              FROM    msdb.dbo.sysjobservers 
              WHERE   (job_id = @JobID) AND (server_id <> 0))) 
  BEGIN 
    -- There is, so abort the script 
    RAISERROR (N'Unable to import job ''Backup all Logs Hourly'' since there is already a multi-server job with this name.', 16, 1) 
    GOTO QuitWithRollback  
  END 
  ELSE 
    -- Delete the [local] job 
    EXECUTE msdb.dbo.sp_delete_job @job_name = N'Backup all Logs Hourly' 
    SELECT @JobID = NULL
  END 

BEGIN 

  -- Add the job
  EXECUTE @ReturnCode = msdb.dbo.sp_add_job @job_id = @JobID OUTPUT , @job_name = N'Backup all Logs Hourly', @owner_login_name = N'sa', @description = N'No description available.', @category_name = N'Database Maintenance', @enabled = 1, @notify_level_email = 2, @notify_level_page = 0, @notify_level_netsend = 0, @notify_level_eventlog = 2, @delete_level= 0, @notify_email_operator_name = N'Server Admins'
  IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback 

  -- Add the job steps
  EXECUTE @ReturnCode = msdb.dbo.sp_add_jobstep @job_id = @JobID, @step_id = 1, @step_name = N'Backup Log', @command = N'exec sp_backupAllLog', @database_name = N'master', @server = N'', @database_user_name = N'', @subsystem = N'TSQL', @cmdexec_success_code = 0, @flags = 0, @retry_attempts = 3, @retry_interval = 1, @output_file_name = N'D:\Joblogs\Backup all Logs Hourly.out', @on_success_step_id = 0, @on_success_action = 1, @on_fail_step_id = 0, @on_fail_action = 2
  IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback 
  EXECUTE @ReturnCode = msdb.dbo.sp_update_job @job_id = @JobID, @start_step_id = 1 

  IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback 

  -- Add the job schedules
  EXECUTE @ReturnCode = msdb.dbo.sp_add_jobschedule @job_id = @JobID, @name = N'Hourly', @enabled = 1, @freq_type = 4, @active_start_date = 20040106, @active_start_time = 10000, @freq_interval = 1, @freq_subday_type = 8, @freq_subday_interval = 1, @freq_relative_interval = 0, @freq_recurrence_factor = 0, @active_end_date = 99991231, @active_end_time = 235959
  IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback 

  -- Add the Target Servers
  EXECUTE @ReturnCode = msdb.dbo.sp_add_jobserver @job_id = @JobID, @server_name = N'(local)' 
  IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback 

END
COMMIT TRANSACTION          
GOTO   EndSave              
QuitWithRollback:
  IF (@@TRANCOUNT > 0) ROLLBACK TRANSACTION 
EndSave: 


 go

-- Script generated on 3/24/2004 4:25 PM
-- By: sa
-- Server: USATRAME0374\INSTANCEA

BEGIN TRANSACTION            
  DECLARE @JobID BINARY(16)  
  DECLARE @ReturnCode INT    
  SELECT @ReturnCode = 0     
IF (SELECT COUNT(*) FROM msdb.dbo.syscategories WHERE name = N'[General Maintenance]') < 1 
  EXECUTE msdb.dbo.sp_add_category @name = N'[General Maintenance]'

  -- Delete the job with the same name (if it exists)
  SELECT @JobID = job_id     
  FROM   msdb.dbo.sysjobs    
  WHERE (name = N'General-OnStart')       
  IF (@JobID IS NOT NULL)    
  BEGIN  
  -- Check if the job is a multi-server job  
  IF (EXISTS (SELECT  * 
              FROM    msdb.dbo.sysjobservers 
              WHERE   (job_id = @JobID) AND (server_id <> 0))) 
  BEGIN 
    -- There is, so abort the script 
    RAISERROR (N'Unable to import job ''General-OnStart'' since there is already a multi-server job with this name.', 16, 1) 
    GOTO QuitWithRollback  
  END 
  ELSE 
    -- Delete the [local] job 
    EXECUTE msdb.dbo.sp_delete_job @job_name = N'General-OnStart' 
    SELECT @JobID = NULL
  END 

BEGIN 

  -- Add the job
  EXECUTE @ReturnCode = msdb.dbo.sp_add_job @job_id = @JobID OUTPUT , @job_name = N'General-OnStart', @owner_login_name = N'sa', @description = N'This job captures the most recent 100 SQL statements sent to the server before an error of Severity 17 or higher occurs.  Output is saved at \mssql7\log\blackbox.trc.  File can be examined with Profiler.', @category_name = N'[General Maintenance]', @enabled = 1, @notify_level_email = 3, @notify_level_page = 0, @notify_level_netsend = 0, @notify_level_eventlog = 2, @delete_level= 0, @notify_email_operator_name = N'Server Admins'
  IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback 

  -- Add the job steps
  EXECUTE @ReturnCode = msdb.dbo.sp_add_jobstep @job_id = @JobID, @step_id = 1, @step_name = N'Nothing', @command = N'select getdate()', @database_name = N'master', @server = N'', @database_user_name = N'', @subsystem = N'TSQL', @cmdexec_success_code = 0, @flags = 0, @retry_attempts = 0, @retry_interval = 1, @output_file_name = N'D:\Joblogs\General-OnStart.out', @on_success_step_id = 0, @on_success_action = 1, @on_fail_step_id = 0, @on_fail_action = 2
  IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback 
  EXECUTE @ReturnCode = msdb.dbo.sp_update_job @job_id = @JobID, @start_step_id = 1 

  IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback 

  -- Add the job schedules
  EXECUTE @ReturnCode = msdb.dbo.sp_add_jobschedule @job_id = @JobID, @name = N'OnStart', @enabled = 1, @freq_type = 64
  IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback 

  -- Add the Target Servers
  EXECUTE @ReturnCode = msdb.dbo.sp_add_jobserver @job_id = @JobID, @server_name = N'(local)' 
  IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback 

END
COMMIT TRANSACTION          
GOTO   EndSave              
QuitWithRollback:
  IF (@@TRANCOUNT > 0) ROLLBACK TRANSACTION 
EndSave: 


 go

-- Script generated on 3/24/2004 4:12 PM
-- By: sa
-- Server: USATRAME0374\INSTANCEA

IF (EXISTS (SELECT name FROM msdb.dbo.sysalerts WHERE name = N'Any Full Transaction Log'))
 ---- Delete the alert with the same name.
  EXECUTE msdb.dbo.sp_delete_alert @name = N'Any Full Transaction Log' 
BEGIN 
EXECUTE msdb.dbo.sp_add_alert @name = N'Any Full Transaction Log', @message_id = 9002, @severity = 0, @enabled = 1, @delay_between_responses = 600, @include_event_description_in = 7, @job_name = N'Backup all Logs Hourly', @category_name = N'[Uncategorized]'

EXECUTE msdb.dbo.sp_add_notification @alert_name = N'Any Full Transaction Log', @operator_name = N'Server Admins', @notification_method = 1

END
 go

-- Script generated on 3/24/2004 4:14 PM
-- By: sa
-- Server: USATRAME0374\INSTANCEA

IF (EXISTS (SELECT name FROM msdb.dbo.sysalerts WHERE name = N'DeadLock'))
 ---- Delete the alert with the same name.
  EXECUTE msdb.dbo.sp_delete_alert @name = N'DeadLock' 
BEGIN 
EXECUTE msdb.dbo.sp_add_alert @name = N'DeadLock', @message_id = 1205, @severity = 0, @enabled = 1, @delay_between_responses = 0, @include_event_description_in = 5, @category_name = N'[Uncategorized]'
END
 go
EXEC sp_altermessage 1205, with_log, true
go
-- Script generated on 3/24/2004 11:27 AM
-- By: sa
-- Server: USATRAME0374\INSTANCEA

-- Script generated on 3/24/2004 11:29 AM
-- By: sa
-- Server: USATRAME0374\INSTANCEA

IF (EXISTS (SELECT name FROM msdb.dbo.sysoperators WHERE name = N'Server Admins'))
 ---- Delete operator with the same name.
  EXECUTE msdb.dbo.sp_delete_operator @name = N'Server Admins' 
BEGIN 
EXECUTE msdb.dbo.sp_add_operator @name = N'Server Admins', @enabled = 1, @email_address = N'USPhiladelphiaSVSQLAdmins@deloitte.com', @category_name = N'[Uncategorized]', @weekday_pager_start_time = 80000, @weekday_pager_end_time = 180000, @saturday_pager_start_time = 80000, @saturday_pager_end_time = 180000, @sunday_pager_start_time = 80000, @sunday_pager_end_time = 180000, @pager_days = 62


EXECUTE msdb.dbo.sp_add_notification @alert_name = N'DeadLock', @operator_name = N'Server Admins', @notification_method = 1

EXECUTE msdb.dbo.sp_add_notification @alert_name = N'Demo: Sev. 19 Errors', @operator_name = N'Server Admins', @notification_method = 1


EXECUTE msdb.dbo.sp_add_notification @alert_name = N'Demo: Sev. 20 Errors', @operator_name = N'Server Admins', @notification_method = 1


EXECUTE msdb.dbo.sp_add_notification @alert_name = N'Demo: Sev. 21 Errors', @operator_name = N'Server Admins', @notification_method = 1


EXECUTE msdb.dbo.sp_add_notification @alert_name = N'Demo: Sev. 22 Errors', @operator_name = N'Server Admins', @notification_method = 1


EXECUTE msdb.dbo.sp_add_notification @alert_name = N'Demo: Sev. 23 Errors', @operator_name = N'Server Admins', @notification_method = 1


EXECUTE msdb.dbo.sp_add_notification @alert_name = N'Demo: Sev. 24 Errors', @operator_name = N'Server Admins', @notification_method = 1


EXECUTE msdb.dbo.sp_add_notification @alert_name = N'Demo: Sev. 25 Errors', @operator_name = N'Server Admins', @notification_method = 1


EXECUTE msdb.dbo.sp_add_notification @alert_name = N'Any Full Transaction Log', @operator_name = N'Server Admins', @notification_method = 1

END
go