브랜드

Impact-Company-Logo-English Black-01-177x54

슈나이더 일렉트릭 코리아 웹사이트에 방문해 주셔서 감사합니다.

슈나이더 일렉트릭 코리아 웹사이트 방문자 분들 모두 환영합니다.
		
오늘 무엇을 도와드릴까요?
SQL Server Disk Space Monitor Alerts
Issue
Need to automate the process to monitor the total disk space and available disk space and send an alert at a
predetermined threshold in order to prevent running out of space and the problems that would be associated.

Product Line
ION Enterprise 6.0.x
StruxureWare Power Monitoring 7.0.x
Power Monitoring Expert 7.x
Power Monitoring Expert 8.x
Power Monitoring Expert 9.x
Power Monitoring Expert 2020
Power Monitoring Expert 2021
Power Monitoring Expert 2022
Power Monitoring Expert 2023
ION EEM

Environment
SQL Server 2005, SQL Server 2008 R2, SQL Server 2012, SQL Server 2014, SQL Server 2016, SQL Server 2017, SQL Server 2019

Cause
Proactive automated system maintenance best practice.

Resolution
*Warning: Irreparable database damage can occur. This procedure should only be performed by users familiar with SQL Server Management Studio. Databases should be backed up prior to performing this procedure.*

The following stored procedure sends an alert when any drive size drops below a set threshold and also
includes an attachment of all the folders and files inside each folder and its size in Bytes in the drive where
we have the space deficiency. Also in the mail, it provides the information about which drive is running low on space.

To implement this:
1) highlight and copy the script below or download the attached file to a desired location
2) launch SQL Server Management Studio either:
- open a new Query window and paste the text copied from below
- select File -> Open,  then locate the downloaded file to open
3) execute the script within the Query window to create the stored procedure
4) create a new scheduled SQL job to execute the stored procedure with your parameters as per the Example contained in the script.
** Further information on how to create and schedule a SQL job can be found within your SQL Server documentation or obtained using the Help within SSMS.

SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
/*----------------------------------------------------------------------------------------------------------
Desc: Send Disk space alert with free space details in each drive
------------------------------------------------------------------------------------------------------------
input: @mailto - recipients list
@mailProfile - DBMail Profile.
@threshold - Threshold Free space in MB below which you need the alert to be sent.
@logfile - Log file to hold the file size details and send it as an attachment.
output: Send Mail
Warnings: None.
------------------------------------------------------------------------------------------------------------
Example: EXEC [DiskSpaceMntr]
@mailProfile = 'SQL_Profile',
@mailto = 'mymailid@mymail.com',
@threshold = 10240,
@logfile = 'D:\DBA\DiskSpaceLog.txt'
------------------------------------------------------------------------------------------------------------*/
/****** Object: Stored Procedure dbo.DiskSpaceMntr******/
CREATE PROCEDURE [dbo].[DiskSpaceMntr]
@mailProfile nvarchar(500),
@mailto nvarchar(4000),
@threshold INT,
@logfile nvarchar(4000)
AS
BEGIN
declare @count int;
declare @tempfspace int;
declare @tempdrive char(1);
declare @mailbody nvarchar(4000);
declare @altflag bit;
declare @sub nvarchar(4000);
declare @cmd nvarchar(4000);
SET @count = 0;
SET @mailbody = '';
SET @cmd = '';
SET NOCOUNT ON
--Create temp table to hold drive-free space info
IF EXISTS(select * from sys.sysobjects where id = object_id('#driveinfo'))
drop table #driveinfo
create table #driveinfo(id int identity(1,1),drive char(1), fspace int)
insert into #driveinfo EXEC master..xp_fixeddrives
--Loop through each drive to check for drive threshold
while (select count(*) from #driveinfo) >= @count
begin
set @tempfspace = (select fspace from #driveinfo where id = @count)
set @tempdrive = (select drive from #driveinfo where id = @count)
--If free space is lower than threshold appends details to mail body and dumps the file size details into the logfile.
if @tempfspace < @threshold
BEGIN
SET @altflag = 1;
SET @mailbody = @mailbody + '
Drive ' + CAST(@tempdrive AS NVARCHAR(10)) + ' has ' + CAST(@tempfspace AS NVARCHAR(10)) + ' MB free
'
SET @cmd = 'dir /s /-c ' + @tempdrive + ':\ > ' + @logfile
EXEC xp_cmdshell @cmd
END
set @count = @count + 1
end
--If at least one drive is below threshold level sends the mail with attachment
IF (@altflag = 1)
BEGIN
SET @sub = 'Monitor Space on ' + CAST(@@SERVERNAME AS NVARCHAR(30))
EXEC msdb.dbo.sp_send_dbmail
@profile_name = @mailProfile,
@recipients= @mailto,
@subject = @sub,
@body = @mailbody,
@file_attachments = @logfile,
@body_format = 'HTML'
END
drop table #driveinfo
set nocount off
END

슈나이더 일렉트릭 Korea

첨부 파일
DiskSpaceAlert.sql [2.87 KB]
자세히 알아보기
제품군
자세히 알아보기
제품군

도움이 필요하신가요?

  • 제품 선택기

    애플리케이션에 적합한 제품과 액세서리를 빠르고 쉽게 찾을 수 있습니다.

  • 견적 받기

    영업 관련하여 온라인으로 문의하시면 전문가가 연락드립니다.

  • 구매처

    해당 지역의 가장 가까운 슈나이더 일렉트릭 대리점을 쉽게 찾을 수 있습니다.

  • 지원 센터

    한 곳에서 모든 요구 사항에 대한 지원 리소스를 찾아보십시오.

  • 제품 문서
  • 소프트웨어 다운로드
  • 제품 선택기
  • 제품 대체 및 교체
  • 지원 및 연락처 센터
  • 영업소 검색
  • 견적 받기
  • 채용
  • 회사 소개
  • 부정 행위 보고
  • 접근성
  • 뉴스룸
  • 투자자
  • Ecostruxure
  • 작업 검색
  • 블로그
  • 개인정보 취급방침
  • 쿠키 공지
  • 사용 약관
  • Change your cookie settings