Atlanta Custom Software Development 

 
   Search        Code/Page
 

User Login
Email

Password

 

Forgot the Password?
Services
» Web Development
» Maintenance
» Data Integration/BI
» Information Management
Programming
  Database
Automation
OS/Networking
Graphics
Links
Tools
» Regular Expr Tester
» Free Tools

Monitoring Hard Drive Space

Total Hit ( 2911)

Rate this article:     Poor     Excellent 

 Submit Your Question/Comment about this article

Rating


 


This script monitors available disk space for the specified drive. If a drive name is not specified in @drivename parameter the usp_dba_diskspace_monitor stored procedure will check all drives against a space limit (MB) passed through @spacelimit parameter. If available disk space is less then @spacelimit an alert gets raised and sent to an operator.

A schedules job '# DBA - Monitor Disk Space' allows you to automate the monitoring. The run schedule can be modified according to DBA's requirements.

The diskspace_monitor.sql script consist of:

create a new message
create a new alert
stored procedure 'usp_dba_diskspace_monitor'
scheduled job

Click here to copy the following block
-- Script to monitor available disk space
--
-- Replace string <operator_name> with the operator name
-- Replace string <dbname> with the database name where the 'usp_dba_diskspace_monitor'
-- stored procedure will be created
-- Replace <drive> with the drive name. If not specified, all physical drives will be monitored against
-- the same space limit specified by @spacelimit parameter
-- Replace <spacelimit_MB> with the proper value. This value is used to check the available space left.
-- It is passed to @spacelimit parameter. If the available disk space is less then @spacelimit the alert gets
-- sent to an operator.
-- Job schedule can be modified according to your requirements.
--
-- add message
EXEC sp_addmessage @msgnum = 60001, @severity = 16,
      @msgtext = N'Free space on drive %s is less then specified limit of %d MB. Available space is %d MB.',
      @lang = 'us_english'
   go

-- create alert
IF (EXISTS (SELECT name FROM msdb.dbo.sysalerts WHERE name = N'Free disk space reached specified limit'))
    ---- Delete the alert with the same name.
     EXECUTE msdb.dbo.sp_delete_alert @name = N'Free disk space reached specified limit'
   BEGIN
   EXECUTE msdb.dbo.sp_add_alert @name = N'Free disk space reached specified limit',
   @message_id = 60001,
   @severity = 0, @enabled = 1, @delay_between_responses = 0, @include_event_description_in = 5,
   @category_name = N'[Uncategorized]'

   EXECUTE msdb.dbo.sp_add_notification @alert_name = N'Free disk space reached specified limit',
   @operator_name = N'<operator_name>', @notification_method = 1
   END
   go

-- create stored procedure

use <dbname>
go

if exists (select * from sysobjects where id = object_id(N'[dbo].[usp_dba_diskspace_monitor]') and OBJECTPROPERTY(id, N'IsProcedure') = 1)
drop procedure [dbo].[usp_dba_diskspace_monitor]
GO
create procedure usp_dba_diskspace_monitor @drivename varchar(5) = NULL, @spacelimit int as
BEGIN
   DECLARE @drive varchar(5)
   DECLARE @MB_free int
   DECLARE @msg varchar(255)

   SET nocount on

   create table #diskspace
   (drive varchar(5) not null,
   MB_free int not null)

   insert into #diskspace
   exec master..xp_fixeddrives

   IF @drivename is NULL
   BEGIN
       DECLARE drive_curs CURSOR FOR
           select drive, MB_free
           from #diskspace
       
       OPEN drive_curs
       FETCH NEXT FROM drive_curs INTO @drive, @MB_free

       WHILE @@FETCH_STATUS = 0
       BEGIN
           IF @MB_free < @spacelimit
           BEGIN
               RAISERROR(60001, 16, 1, @drive, @spacelimit, @MB_free) with log
               select @msg = 'Drive ' + RTRIM(@drive) +
                   ': Free disk space reached specified limit'
               print ' '
               print @msg
               print ' '
           END    
           ELSE
           BEGIN
               select @msg = 'Drive ' + RTRIM(@drive) +
                   ': There is plenty of available disk space'    
               print ' '
               print @msg
               print ' '
           END
       
           FETCH NEXT FROM drive_curs INTO @drive, @MB_free
       END
   
       close drive_curs
       deallocate drive_curs
   END
   ELSE    -- drivename is not null
   BEGIN
       select @drive = drive, @MB_free = MB_free
       from #diskspace
       where drive = @drivename

       IF @@ROWCOUNT = 0
       BEGIN
           select @msg = 'Could not find information for drive ' + @drivename
           return 1
       END
       
       IF @MB_free < @spacelimit
       BEGIN
           RAISERROR(60001, 16, 1, @drive, @spacelimit, @MB_free) with log
           select @msg = 'Drive ' + RTRIM(@drive) +
               ': Free disk space reached specified limit'
           print ' '
           print @msg
           print ' '
       END    
       ELSE
       BEGIN
           select @msg = 'Drive ' + RTRIM(@drive) +
               ': There is plenty of available disk space'    
           print ' '
           print @msg
           print ' '
       END
   END

   drop table #diskspace
END

go


-- create a job to execute the usp_dba_diskspace_monitor procedure
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'# DBA - Monitor Disk 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 ''# DBA - Monitor Disk 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'# DBA - Monitor Disk Space'
  SELECT @JobID = NULL
 END

BEGIN

 -- Add the job
 EXECUTE @ReturnCode = msdb.dbo.sp_add_job @job_id = @JobID OUTPUT , @job_name = N'# DBA - Monitor Disk 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'step1',
 @command = N'exec usp_dba_diskspace_monitor @drivename = ''<drive>'', @spacelimit = <spacelimit_MB>', @database_name = N'<dbname>',
 @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'', @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'Monitor disk space', @enabled = 1, @freq_type = 4, @active_start_date = 20000605, @active_start_time = 230000, @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


Submitted By : Nayan Patel  (Member Since : 5/26/2004 12:23:06 PM)

Job Description : He is the moderator of this site and currently working as an independent consultant. He works with VB.net/ASP.net, SQL Server and other MS technologies. He is MCSD.net, MCDBA and MCSE. In his free time he likes to watch funny movies and doing oil painting.
View all (893) submissions by this author  (Birth Date : 7/14/1981 )


Home   |  Comment   |  Contact Us   |  Privacy Policy   |  Terms & Conditions   |  BlogsZappySys

© 2008 BinaryWorld LLC. All rights reserved.