Para este job rodar corretamente necessitamos que ( EXEC sp_configure 'xp_cmdshell',1 ),
Neste exemplo assumimos que já esteja habilitado caso sua arquitetura seja padrão desligado o que é recomendável, você pode habilitar no copor doo job e em seguida desabilitá-lo ( EXEC sp_configure 'xp_cmdshell',0 ),
exemplo completo :
- Para permitir que as opções avançadas de ser mudado. EXEC sp_configure 'show advanced options', 1; GO - Para atualizar o valor atualmente configurado para opções avançadas. RECONFIGURE; GO - Para ativar o recurso. EXEC sp_configure 'xp_cmdshell', 1; GO - Para atualizar o valor atualmente configurado para esta função. RECONFIGURE; GO
--FONTE : https://msdn.microsoft.com/en-us/library/ms190693.aspx
AGORA VAMOS AO SCRIPT
USE [msdb]
GO
/****** Object: Job [Auditoria_discos] Script Date: 06/24/2015 11:39:35 ******/
BEGIN TRANSACTION
DECLARE @ReturnCode INT
SELECT @ReturnCode = 0
/****** Object: JobCategory [[Uncategorized (Local)]]] Script Date: 06/24/2015 11:39:35 ******/
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'Auditoria_discos',
@enabled=1,
@notify_level_eventlog=0,
@notify_level_email=0,
@notify_level_netsend=0,
@notify_level_page=0,
@delete_level=0,
@description=N'No description available.',
@category_name=N'[Uncategorized (Local)]',
@owner_login_name=N'<< SEU USUARIO >>', @job_id = @jobId OUTPUT
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback
/****** Object: Step [Auditoria_discos] Script Date: 06/24/2015 11:39:35 ******/
EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'Auditoria_discos',
@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'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
INSERT INTO [<<<<< SEU SERVIDOR>>>>>>>].[Control_Data_Base].[dbo].[espaco_discos]
([server],[drive],[freespace],[totalsize],[percentfree],[date_check])
SELECT @@SERVERNAME as servido,
drive,
FreeSpace as ''Livre(MB)'',
TotalSize as ''Total(MB)'',
CAST((FreeSpace/(TotalSize*1.0))*100.0 as int) as ''Livre(%)'' ,
GETDATE()
FROM #drives
ORDER BY drive
DROP TABLE #drives
RETURN
GO
-- Confesso que parte do código peguei na internet, só não lembro aonde.',
@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'Auditoria_discos',
@enabled=1,
@freq_type=4,
@freq_interval=1,
@freq_subday_type=1,
@freq_subday_interval=0,
@freq_relative_interval=0,
@freq_recurrence_factor=0,
@active_start_date=20150416,
@active_end_date=99991231,
@active_start_time=71500,
@active_end_time=235959,
@schedule_uid=N'11b64e2a-cd4a-42b1-8959-e3db1723c7d6'
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