Automate drive space monitoring for all production servers

  • Comments posted to this topic are about the item Automate drive space monitoring for all production servers

    ----------------------------------------------------------------------------------------------------------------------------------------------------
    Roshan Joe

    Jeff Moden -Forum Etiquette: How to post data/code on a forum to get the best help[/url]

  • Here is a simple script that allows you to avoid populating a table with servers. I'd suggest using reporting services to email results to your end users.

    /*

    ** This table holds the drive space data

    */

    create table serverdrivespace

    (

    name sysname

    , drive sysname

    , mbfree nvarchar(255)

    )

    /*

    ** This script populates the serverdrivespace table

    */

    truncate table serverdrivespace

    create table #servers

    (

    name sysname not null

    , network_name sysname null

    , status nvarchar(255) not null

    , id int not null

    , collation_name sysname null

    , connect_timeout int not null

    , query_timeout int not null

    )

    create table #drivespace

    (

    drive sysname

    , mbfree nvarchar(255)

    )

    declare server_cursor cursor for

    select name from #servers

    where status like '%rpc,%'

    begin try

    insert into #servers

    exec sp_helpserver

    declare @name sysname

    open server_cursor

    fetch next from server_cursor into @name

    declare @sql nvarchar(4000)

    while @@fetch_status = 0

    begin

    set @sql = 'exec [' + @name + '].master.dbo.xp_fixeddrives'

    print @sql

    truncate table #drivespace

    insert into #drivespace

    exec sp_executesql @sql

    insert into serverdrivespace

    select @name as servername, *

    from #drivespace

    fetch next from server_cursor into @name

    end

    close server_cursor

    end try

    begin catch

    SELECT

    ERROR_NUMBER() AS ErrorNumber

    ,ERROR_SEVERITY() AS ErrorSeverity

    ,ERROR_STATE() AS ErrorState

    ,ERROR_PROCEDURE() AS ErrorProcedure

    ,ERROR_LINE() AS ErrorLine

    ,ERROR_MESSAGE() AS ErrorMessage;

    end catch

    select * from serverdrivespace

    deallocate server_cursor

    drop table #drivespace

    drop table #servers

    An upgrade to this would be an SSIS package that uses WMI to get drive information from remote servers. You could monitor the entire network this way instead of limiting yourself to just SQL Servers.

  • Thanks pklotka. But I would stick to the table. It gives me control over which all servers to check among my long list of linked servers. Thank you for the suggestion.

    ----------------------------------------------------------------------------------------------------------------------------------------------------
    Roshan Joe

    Jeff Moden -Forum Etiquette: How to post data/code on a forum to get the best help[/url]

  • joeroshan (6/13/2009)


    ,,the table. It gives me control over which all servers to check among my long list of linked servers.

    Not sure how efficient & advisable it is to link many servers.

    Being conservative, I run a small sp as part of each nightly backup/maint plan on each SQL server I administer. It writes the free space into a small cummulative table in the Master db, which I can then retrieve with an external application every morning.

    Table:

    CREATE TABLE [dbo].[tblStatsDisk](

    [ID] [int] IDENTITY(1,1) NOT NULL,

    [DiskTimeStamp] [datetime] NULL,

    [Drive] [char](1) NULL,

    [FreeDisk] [bigint] NULL

    Maint Plan SP:

    USE MASTER

    -- Description: Poll free disk space on each drive immediately after the backup

    -- =============================================

    ALTER PROCEDURE [dbo].[GetDiskFree]

    AS

    /* TEST HARNESS

    exec [dbo].[GetDiskFree]

    select * from dbo.tblStatsDisk

    */

    BEGIN

    SET NOCOUNT ON;

    INSERT into dbo.tblStatsDisk (drive, FreeDisk)

    EXEC master.dbo.xp_fixeddrives

    -- this command creates the rows (one for each drive) with NULL date, srv... fields

    -- the columns must allow NULL especially disktimestamp

    UPDATE master.dbo.tblStatsDisk

    SET DiskTimeStamp = (GETDATE())

    where disktimestamp is null

    END

    ----

    How you collect and centralise this later is another story ... but you start small with a modular approach then build an application that combines this with some DB size stats collected from the backup DMV routines.

    HTH

  • If I still had the code available, I would share...

    We had a dilapidated 200 box that would not delete the old backup files on an external drive... Needless to say it would fill up and we would puke on a regular basis if someone did not manually traverse Win Explorer and delete the old backups.

    After learning about the xp_FixedDrives procedure (here, by the way), I created a sproc ( triggered by an agent job firing hourly) that would check our drive and if we got below a comfortable free space level, it would automatically email the network administrator.

    After we had some baseline data we were able to track our average usage on an hourly and daily basis. As more and better data came in, the procedure was altered so that if it was predicted to drop below the comfort zone before the next working shift, it would let the admin know before the end of the working day. This saved many early morning messages telling us that the backup dropped us below our established comfort zone

    Another element that this brought to the table was the ability to track the variations in daily usage. We are primarily a web design and host company, so peoples working schedules can be seen minutely when looking at the various file sizes... No surprises then when a blizzard closes 95% of businesses that the logs increased in size

    Director of Transmogrification Services
  • I'm looking for a script to monitor non fixed drives like mount points. Any idea?

    Thanks! Aldo

  • Good post , however,it is triggering mails for only one linked server in server list table. I would require disk space availability on all servers in server list table. Did any one simulate of execute the code ??? Apreciate your help.

  • Thanks for the script.

Viewing 8 posts - 1 through 7 (of 7 total)

You must be logged in to reply to this topic. Login to reply