Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase 1234»»»

Monitoring Disk Space and Sending Alerts with TSQL Expand / Collapse
Author
Message
Posted Sunday, August 10, 2003 12:00 AM
Valued Member

Valued MemberValued MemberValued MemberValued MemberValued MemberValued MemberValued MemberValued Member

Group: General Forum Members
Last Login: Friday, January 18, 2013 11:03 AM
Points: 55, Visits: 60
Comments posted to this topic are about the content posted at http://www.sqlservercentral.com/columnists/hji/monitoringdiskspaceandsendingalertswithtsql.asp


Post #15135
Posted Thursday, January 08, 2004 10:54 AM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Monday, October 28, 2013 12:26 PM
Points: 17, Visits: 2

Previously it was giving error because i didn't have SQL Mail in Support Services.

Now it works fine for me. This is perfect.

Thanks

 




Post #94147
Posted Thursday, September 13, 2007 11:49 PM
SSC-Enthusiastic

SSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-EnthusiasticSSC-Enthusiastic

Group: General Forum Members
Last Login: Wednesday, March 11, 2009 7:15 AM
Points: 129, Visits: 12

Haidong Ji,

Try the next script (no e-mail part attached but it schoudn't be that difficult to add it);

CREATE PROCEDURE [dbo].[sp_diskspace] AS
/*
Displays the free space,free space percentage
plus total drive size for a server
*/
SET NOCOUNT ON

DECLARE @hr int
DECLARE
@fso int
DECLARE
@drive char(1)
DECLARE @odrive int
DECLARE
@TotalSize varchar(20)
DECLARE @MB bigint ; SET @MB = 1048576

CREATE TABLE #drives (
drive char(1) PRIMARY KEY,
FreeSpace int NULL,
TotalSize int NULL)

INSERT #drives(drive,FreeSpace) EXEC master.dbo.xp_fixeddrives

EXEC @hr=sp_OACreate 'Scripting.FileSystemObject',@fso OUT

IF @hr <> 0 EXEC sp_OAGetErrorInfo @fso

DECLARE dcur CURSOR LOCAL FAST_FORWARD
FOR
SELECT drive from #drives
ORDER by drive

OPEN dcur
FETCH NEXT FROM dcur INTO @drive
WHILE @@FETCH_STATUS=0
BEGIN

EXEC @hr = sp_OAMethod @fso,'GetDrive', @odrive OUT, @drive

IF @hr <> 0 EXEC sp_OAGetErrorInfo @fso

EXEC @hr = sp_OAGetProperty @odrive,'TotalSize', @TotalSize OUT

IF @hr <> 0 EXEC sp_OAGetErrorInfo @odrive

UPDATE #drives
SET TotalSize=@TotalSize/@MB
WHERE drive=@drive

FETCH NEXT FROM dcur INTO @drive
END
CLOSE
dcur
DEALLOCATE dcur

EXEC @hr=sp_OADestroy @fso

IF @hr <> 0 EXEC sp_OAGetErrorInfo @fso

SELECT drive,
FreeSpace as 'Free(MB)',
TotalSize as 'Total(MB)',
CAST((FreeSpace/(TotalSize*1.0))*100.0 as int) as 'Free(%)'
FROM #drives
ORDER BY drive

DROP TABLE #drives

RETURN

8888888888888888888888888888888888888888888888888888888888888888888

Select the outcome from all your serers (using a databaselink) into a local "gathering-table"

create table Disk_Capp (Servername varchar(40), Volume varchar(5),FreeMb int, TotalMb int, FreePCT integer, date datetime, runnum integer)

--The @runnum is a counter for each time you execute this script to keep track on history in the DISK_CAPP table

SET @Query ='INSERT Disk_Capp SELECT '''+@servername+''',*,cast(getdate() as varchar(20)),'+cast(@runnum as varchar(10))+' FROM OPENQUERY( [DBA_'+@servername+'],''SET FMTONLY OFF;EXEC master.dbo.sp_diskspace'')'
exec ( @Query )

8888888888888888888888888888888888888888888888888888888888888888888

Mention that the you are authorized to use the SP_OAxxxxx procedures (open and close using the DBlinks 1 and 0 )

SET @Query_c1 ='declare @var1 varchar(3000)
set @var1 = ''EXEC [DBA_'
+@servername+'].master.dbo.sp_configure ''show advanced options'',1 go reconfigure go''
exec (@var1)'
exec (@Query_c1)

SET @Query_c2 ='declare @var2 varchar(3000)
set @var2 = ''EXEC [DBA_'
+@servername+'].master.dbo.sp_configure ''Ole Automation Procedure'',1 go reconfigure go''
exec (@var2)'

exec (@Query_c2)

 8888888888888888888888888888888888888888888888888888888888888888888

Hope you (or someone else) can use it. . .

GKramer
The Netherlands

 

Post #399181
Posted Friday, September 14, 2007 1:18 AM
SSC Veteran

SSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC VeteranSSC Veteran

Group: General Forum Members
Last Login: Wednesday, September 18, 2013 2:20 AM
Points: 216, Visits: 169
Thank you Haidong Ji for your script.
And what a very interesting twist to the tale that Guus Kramer added!, very cool and useful!
Post #399190
Posted Friday, September 14, 2007 5:56 AM


UDP Broadcaster

UDP BroadcasterUDP BroadcasterUDP BroadcasterUDP BroadcasterUDP BroadcasterUDP BroadcasterUDP BroadcasterUDP Broadcaster

Group: General Forum Members
Last Login: Wednesday, January 02, 2013 12:15 PM
Points: 1,443, Visits: 711

Thank you Haidong!

I know I've used this one, or some variation of it before in the past, it's very useful!

Post #399251
Posted Friday, September 14, 2007 6:43 AM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Monday, April 21, 2014 2:55 PM
Points: 24, Visits: 246

It is good to know more than one way to do that.   My question is why this is better than using performance monitor and its alert to do the same thing.  Isn't it lesser work or resources by using performance monitor to track disk space and send alert?

 

Post #399280
Posted Friday, September 14, 2007 6:48 AM


UDP Broadcaster

UDP BroadcasterUDP BroadcasterUDP BroadcasterUDP BroadcasterUDP BroadcasterUDP BroadcasterUDP BroadcasterUDP Broadcaster

Group: General Forum Members
Last Login: Wednesday, January 02, 2013 12:15 PM
Points: 1,443, Visits: 711
I actually used this one in conjunction with xp_SMTP_sendmail can't remember the xact SProc name, but it's an add-in sproc, and it was quick and didn't add much load to the server.
Post #399283
Posted Friday, September 14, 2007 6:50 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Wednesday, February 06, 2008 12:08 PM
Points: 1, Visits: 3

In our environment, we have RAID drives that allow unlimited growth.  The only issue with that is that the DBA group doesn't set our databases to auto grow, so sometimes we hit the space limit set up for the particular database, even if we have plenty of disk space available.

Is there a way to write a stored proc to monitor & send an alert on the allocated disk space for a particular database??  That would be really useful for us.

Thanks!




Post #399284
Posted Friday, September 14, 2007 7:47 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Monday, November 26, 2007 8:06 AM
Points: 4, Visits: 2
Love the article, but the presentation is the pits! I eventually copy/pasted the article in a text editor with word-wrap...
Post #399303
Posted Friday, September 14, 2007 7:57 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Sunday, April 20, 2014 7:43 PM
Points: 4, Visits: 229

There have been many articles on this subject and all them rely on xp_fixeddrives to report total and free disk space.  This works well in smaller environments but in much larger environments, especially those including a SAN, this approach will fall short.  Most larger organizations, ones which hire Sr. Level DBAs are moving towards Mount Points on the Windows Servers.  The lack of drive letters, the need to spread multi-terabyte databases over dozens of filegroups, failover and DR environment integration, all facilitate the need for a different approach to space consideration and how to address the disk space.

WMI and many other tools in our SQL bag of tricks, fail to recoginize mountpoints in the environment.  If you xp_fixeddrives or even a WMIC query to look a drive which has a mount point with a terabyte of dataspace, all that is returned in the available space on the local disks.  This is really not going to help you and trust me, it looks "strange" on a report which you show 1.1 terabytes of data on a 17 Gb disk with 16 Gb Free. 

There are ways to gather this information in C#, such as walking the directory tree, and adding the functionality through an extended stored procedure  but then you have to roll that out to all the servers and in secure/large environment, that is not always an easy or well received task. 

The other factor to consider is support for the developed solution.  Writing C# is great for many add-ons but not all DBAs are comfortable with creating, maintaining and/or deploying C# applications or SQL stored procedures/functions.  

The lack of this particular functionality (ability easily and accurately determine available/used disk space) and other similar functionaility is concerning and leaves many DBAs, who want to maintian a TSQL codebase, even if it uses COM XPs, at the mercy fo the monitoring software vendors out there.  Since CHKDSK can return the correct information on drives which have Mount Points, which is what I currently use to gather space information for TSQL by parsing the output, then I feel Microsoft should have updated the xp_fixeddrives routine to report the correct information or at least provided and documented a way of gathering that information.  Especiallys since SQL Server is by far the greatest benefactor of utilizing mount points to store the large amounts of data the want to boast the capability of being able to address.

This article and the use of the email system is well thought out and helpful but not as much in larger SQL farms which managing the data environment is even more critical.  I would also suggest adding a table in your database to store sent alerts (emails) and build in the functionality of storing the messages as part of the routine.  This will allow someone to do historical reporting and analysis of the alerts, this one and others, which have been sent out over a period of time without being dependent on reviewing the emails through a mail server and its client or through a mail interface.

Bob Wright

Sr. DBA/.NET Architect/SQL Architect

  

Post #399307
« Prev Topic | Next Topic »

Add to briefcase 1234»»»

Permissions Expand / Collapse