/* script contents: stored procedure - SpaceUsedByFileGroupInsert stored procedure - SpaceUsedByFileGroupLowFree SQLAgent job - */ use admin GO SET QUOTED_IDENTIFIER OFF GO SET ANSI_NULLS ON GO if exists (select * from dbo.sysobjects where id = object_id(N'[dbo].[SpaceUsedByFileGroupInsert]') and OBJECTPROPERTY(id, N'IsProcedure') = 1) drop procedure [dbo].[SpaceUsedByFileGroupInsert] GO CREATE PROCEDURE [dbo].[SpaceUsedByFileGroupInsert] @Server varchar(128) , @Database varchar(128) , @FileGroup varchar(128) , @FileName varchar(128) , @File int , @Path varchar(128) , @IsPrimaryFile bit , @Size int , @SizeInKB float , @SpaceAvailableInMB int , @FileGrowth int , @FileGrowthType int , @MaximumSize int AS /******************************************************************************************************* * admin.dbo.SpaceUsedByFileGroupInsert * Creator: Bill Wunder * * Description: Add a row to the SpaceUsedHistory table * Notes: creates table that holds DMO DBFILE properties * if table does not already exist * * Usage: EXECUTE admin.dbo.SpaceUsedByFileGroupInsert , admin , 1 , 'test' , 'c:\temp\test.txt' , 1 , 1 , 1 , 1 , 1 , 1 , '%' , 1 * * * Modifications: * Developer Name Date Brief Description * ------------------ -------- ------------------------------------------------------------ * ********************************************************************************************************/ --------------------------------------------- -- declare variables --------------------------------------------- --------------------------------------------- -- create temp tables --------------------------------------------- --------------------------------------------- -- set session variables --------------------------------------------- SET NOCOUNT ON --------------------------------------------- -- body of stored procedure --------------------------------------------- if object_id('dbo.SpaceUsedHistory','U') is null create table dbo.SpaceUsedHistory ([Server] varchar(128) , [Database] varchar(128) , [FileGroup] varchar(128) , [FileName] varchar(128) , [File] int , [Path] varchar(128) , [IsPrimaryFile] bit , [Size] int , [SizeInKB] float , [SpaceAvailableInMB] int , [FileGrowth] int , [FileGrowthInKB] float , [FileGrowthType] int , [MaximumSize] int , [RecCreatedDt] datetime constraint dft_SpaceUsedHistory__RecCreatedDt default getdate() , [RecCreatedUser] varchar(128) constraint dft_SpaceUsedHistory__RecCreatedUser default suser_sname() , constraint pk_SpaceUsedHistory__RecCreatedDt__Server__Database__FileGroup__FileName primary key ([RecCreatedDt], [Server], [Database], [FileGroup], [FileName])) insert dbo.SpaceUsedHistory ([Server] , [Database] , [FileGroup] , [FileName] , [File] , [Path] , [IsPrimaryFile] , [Size] , [SizeInKB] , [SpaceAvailableInMB] , [FileGrowth] , [FileGrowthInKB] , [FileGrowthType] , [MaximumSize]) values (@Server , @Database , @FileGroup , @FileName , @File , @Path , @IsPrimaryFile , @Size , @SizeInKB , @SpaceAvailableInMB , case when @FileGrowthType = 0 then null else @FileGrowth end , case when @FileGrowthType = 0 then @FileGrowth else null end , @FileGrowthType , @MaximumSize) RETURN GO SET QUOTED_IDENTIFIER OFF GO SET ANSI_NULLS ON GO use admin GO SET QUOTED_IDENTIFIER OFF GO SET ANSI_NULLS ON GO if exists (select * from dbo.sysobjects where id = object_id(N'[dbo].[SpaceUsedByFileGroupLowFree]') and OBJECTPROPERTY(id, N'IsProcedure') = 1) drop procedure [dbo].[SpaceUsedByFileGroupLowFree] GO CREATE PROCEDURE [dbo].[SpaceUsedByFileGroupLowFree] @recipients varchar(100) = 'DBOps@wallst.com', @server varchar(128) = null AS /******************************************************************************************************* * admin.dbo.SpaceUsedByFileGroupLowFree * Creator: Bill Wunder * * Description: send email of files where available bytes getting low * Notes: * * Usage: EXECUTE admin.dbo.SpaceUsedByFileGroupLowFree @recipients = 'bill.wunder@wallst.com' * * * Modifications: * Developer Name Date Brief Description * ------------------ -------- ------------------------------------------------------------ * ********************************************************************************************************/ --------------------------------------------- -- declare variables --------------------------------------------- declare @subject varchar(100), @SQLStr nvarchar(4000) --------------------------------------------- -- create temp tables --------------------------------------------- --------------------------------------------- -- set session variables --------------------------------------------- SET NOCOUNT ON --------------------------------------------- -- body of stored procedure --------------------------------------------- if @server is null set @server = @@servername set @subject = 'Database Data Files with low avaiable free space on ' + @server set @SQLStr = 'set nocount on select cast([Database] as varchar(20)) [Database] , cast([FileName] as varchar(30)) [File] , [Size] [Size MB] , [SpaceAvailableInMB] [Available] from admin.dbo.SpaceUsedHistory s where Size > 16 and server = ''' + @server + ''' and RecCreatedDt = (select max(RecCreatedDt) from admin.dbo.SpaceUsedHistory where Server = s.Server and [Database] = s.[Database] and [FileName] = s.[FileName]) and SpaceAvailableInMB * 1024 < case when FileGrowthType = 0 then .2*(FileGrowthInKB) when FileGrowthType = 1 then .2*(SizeInKB*(FileGrowth*.01)) end' if exists (select 1 from admin.dbo.SpaceUsedHistory s where Size > 16 and server = @server and RecCreatedDt = (select max(RecCreatedDt) from admin.dbo.SpaceUsedHistory where Server = s.Server and [Database] = s.[Database] and [FileName] = s.[FileName]) and SpaceAvailableInMB * 1024 < case when FileGrowthType = 0 then .2*(FileGrowthInKB) when FileGrowthType = 1 then .2*(SizeInKB*(FileGrowth*.01)) end) exec sysmon.dbo.safe_sendmail @recipients = @recipients , @subject = @subject , @query = @SQLStr RETURN GO SET QUOTED_IDENTIFIER OFF GO SET ANSI_NULLS ON GO -- SQLAgent job Monitor Free Space -- replace "" with the correct full path to the dts package file "Monitor Free Space.dts" BEGIN TRANSACTION DECLARE @JobID BINARY(16) DECLARE @ReturnCode INT SELECT @ReturnCode = 0 IF (SELECT COUNT(*) FROM msdb.dbo.syscategories WHERE name = N'[Uncategorized (Local)]') < 1 EXECUTE msdb.dbo.sp_add_category @name = N'[Uncategorized (Local)]' -- Delete the job with the same name (if it exists) SELECT @JobID = job_id FROM msdb.dbo.sysjobs WHERE (name = N'Monitor Free Space') 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 ''Monitor Free Space'' 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'Monitor Free Space' SELECT @JobID = NULL END BEGIN -- Add the job EXECUTE @ReturnCode = msdb.dbo.sp_add_job @job_id = @JobID OUTPUT , @job_name = N'Monitor Free Space', @owner_login_name = N'sa', @description = N'No description available.', @category_name = N'[Uncategorized (Local)]', @enabled = 1, @notify_level_email = 0, @notify_level_page = 0, @notify_level_netsend = 0, @notify_level_eventlog = 2, @delete_level= 0 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'step 1', @command = N'dtsrun /F"\\\Monitor Free Space.dts" /N"Monitor Free Space" /A"SQL Server:8=[SRVR]" /A"Log to SQL Server:8=[SRVR]"', @database_name = N'', @server = N'', @database_user_name = N'', @subsystem = N'CmdExec', @cmdexec_success_code = 0, @flags = 0, @retry_attempts = 0, @retry_interval = 1, @output_file_name = N'', @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'5PM', @enabled = 1, @freq_type = 4, @active_start_date = 20020823, @active_start_time = 170000, @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: