或者是試試看 undocumented 的「擴充預存程序(extended stored procedure)」:xp_fixeddrives。
以下為使用 xp_fixeddrives 的範例:
EXEC xp_fixeddrives
可以觀察到 xp_fixeddrives 回傳本機磁碟的可用空間,以 MB 為顯示單位。
接下來,筆者提供整合了「作業(Job)」與「警示(Alert)」的範例。
功能說明:
1. 使用「作業」,設定所需要執行的 T-SQL 陳述式,排程執行偵測作業。
2. 設定磁碟可用空間的臨界值,低於臨界值時,發出錯誤訊息,觸發「警示」。
在本範例中,觸發的是嚴重層級 17 的錯誤。
關於要執行偵測判斷的 T-SQL 陳述式,請參考以下的範例程式碼1:
SET NOCOUNT ON USE master GO DECLARE @msg nvarchar(256) , @dr varchar(256) DECLARE @fs TABLE (drive char(1), MB_Free int) DECLARE @ds TABLE(drive char(1)) INSERT @fs EXEC xp_fixeddrives INSERT @ds SELECT drive FROM @fs WHERE MB_Free<10240 -- 設定磁碟的臨界值(MB),在本範例中,設定為 10 GB IF EXISTS(SELECT * FROM @ds) BEGIN DECLARE @rs varchar(256) SET @rs='' SELECT @rs=@rs+drive+',' FROM @ds SELECT @dr=SUBSTRING(@rs, 1,DATALENGTH(@rs)-1) SET @msg =N'磁碟:'+@dr+N' 的可用空間低於臨界值' RAISERROR (@msg, 17,1) WITH LOG END
在範例程式碼1中,是針對本機每個磁碟都設定為相同的臨界值。 若你需要分別對各個磁碟,設定所需的臨界值,請參考以下的範例程式碼2:
SET NOCOUNT ON USE master GO DECLARE @msg nvarchar(256) , @dr varchar(256) DECLARE @fs TABLE (drive char(1), MB_Free int) DECLARE @ds TABLE(drive char(1)) INSERT @fs EXEC xp_fixeddrives INSERT @ds SELECT drive FROM @fs WHERE drive='C' AND MB_Free<10240 -- 設定磁碟C的臨界值(MB) INSERT @ds SELECT drive FROM @fs WHERE drive='D' AND MB_Free<10240 -- 設定磁碟D的臨界值(MB) INSERT @ds SELECT drive FROM @fs WHERE drive='E' AND MB_Free<10240 -- 設定磁碟E的臨界值(MB) INSERT @ds SELECT drive FROM @fs WHERE drive='F' AND MB_Free<10240 -- 設定磁碟F的臨界值(MB) IF EXISTS(SELECT * FROM @ds) BEGIN DECLARE @rs varchar(256) SET @rs='' SELECT @rs=@rs+drive+',' FROM @ds SELECT @dr=SUBSTRING(@rs, 1,DATALENGTH(@rs)-1) SET @msg =N'磁碟:'+@dr+N' 的可用空間低於臨界值' RAISERROR (@msg, 17,1) WITH LOG END在此感謝 Will 熱情提供。
以下的範例程式碼,其功能為: 將上述的磁碟可用空間判斷功能,包裝為「作業」,並且設定每 30 分鐘自動執行一次。
USE [msdb] GO /****** Object: Job [jb_偵測磁碟的可用空間] Script Date: 05/27/2010 20:54:15 ******/ IF EXISTS (SELECT job_id FROM msdb.dbo.sysjobs_view WHERE name = N'jb_偵測磁碟的可用空間') EXEC msdb.dbo.sp_delete_job @job_name=N'jb_偵測磁碟的可用空間', @delete_unused_schedule=1 GO USE [msdb] GO /****** Object: Job [jb_偵測磁碟的可用空間] Script Date: 05/27/2010 20:54:15 ******/ BEGIN TRANSACTION DECLARE @ReturnCode INT SELECT @ReturnCode = 0 /****** Object: JobCategory [[Uncategorized (Local)]]] Script Date: 05/27/2010 20:54:15 ******/ IF NOT EXISTS (SELECT name FROM msdb.dbo.syscategories WHERE name=N'[Uncategorized (Local)]' AND category_class=1) BEGIN EXEC @ReturnCode = msdb.dbo.sp_add_category @class=N'JOB', @type=N'LOCAL', @name=N'[Uncategorized (Local)]' IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback END DECLARE @jobId BINARY(16) EXEC @ReturnCode = msdb.dbo.sp_add_job @job_name=N'jb_偵測磁碟的可用空間', @enabled=1, @notify_level_eventlog=0, @notify_level_email=0, @notify_level_netsend=0, @notify_level_page=0, @delete_level=0, @description=N'沒有可用的描述。', @category_name=N'[Uncategorized (Local)]', @owner_login_name=N'sa', @job_id = @jobId OUTPUT IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback /****** Object: Step [st_偵測磁碟可用空間] Script Date: 05/27/2010 20:54:15 ******/ EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'st_偵測磁碟可用空間', @step_id=1, @cmdexec_success_code=0, @on_success_action=1, @on_success_step_id=0, @on_fail_action=2, @on_fail_step_id=0, @retry_attempts=0, @retry_interval=0, @os_run_priority=0, @subsystem=N'TSQL', @command=N'SET NOCOUNT ON USE master GO DECLARE @msg nvarchar(256) , @dr varchar(256) DECLARE @fs TABLE (drive char(1), MB_Free int) DECLARE @ds TABLE(drive char(1)) INSERT @fs EXEC xp_fixeddrives INSERT @ds SELECT drive FROM @fs WHERE drive=''C'' AND MB_Free<10240 -- 設定磁碟C的臨界值(MB) INSERT @ds SELECT drive FROM @fs WHERE drive=''D'' AND MB_Free<10240 -- 設定磁碟D的臨界值(MB) INSERT @ds SELECT drive FROM @fs WHERE drive=''E'' AND MB_Free<10240 -- 設定磁碟E的臨界值(MB) INSERT @ds SELECT drive FROM @fs WHERE drive=''F'' AND MB_Free<10240 -- 設定磁碟F的臨界值(MB) IF EXISTS(SELECT * FROM @ds) BEGIN DECLARE @rs varchar(256) SET @rs='''' SELECT @rs=@rs+drive+'','' FROM @ds SELECT @dr=SUBSTRING(@rs, 1,DATALENGTH(@rs)-1) SET @msg =N''磁碟:''+@dr+N'' 的可用空間低於臨界值'' RAISERROR (@msg, 17,1) WITH LOG END', @database_name=N'master', @flags=0 IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback EXEC @ReturnCode = msdb.dbo.sp_update_job @job_id = @jobId, @start_step_id = 1 IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback EXEC @ReturnCode = msdb.dbo.sp_add_jobschedule @job_id=@jobId, @name=N'sch1_每30分鐘執行一次', @enabled=1, @freq_type=4, @freq_interval=1, @freq_subday_type=4, @freq_subday_interval=30, @freq_relative_interval=0, @freq_recurrence_factor=0, @active_start_date=20100527, @active_end_date=99991231, @active_start_time=0, @active_end_time=235959, @schedule_uid=N'a32cb358-f75a-41ce-9ede-0f6556e1e299' IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback EXEC @ReturnCode = msdb.dbo.sp_add_jobserver @job_id = @jobId, @server_name = N'(local)' IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback COMMIT TRANSACTION GOTO EndSave QuitWithRollback: IF (@@TRANCOUNT > 0) ROLLBACK TRANSACTION EndSave: GO
參考資料:
設定「警示(Alerts)」來回應所發生的錯誤,以「錯誤嚴重性(Error Severities)」為例 http://sharedderrick.blogspot.com/2010/04/alertserror-severities.html
Using xp_fixeddrives to Monitor Free Space
http://www.databasejournal.com/features/mssql/article.php/3080501/Using-xpfixeddrives-to-Monitor-Free-Space.htm
沒有留言:
張貼留言