Created
September 3, 2022 18:36
-
-
Save possebon/847a8afb1a40cf0b29bb149a54df1745 to your computer and use it in GitHub Desktop.
This file contains hidden or bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
USE [msdb] | |
GO | |
/****** Object: Job [SQL Audit Logs to S3] Script Date: 9/3/2022 3:33:46 PM ******/ | |
BEGIN TRANSACTION | |
DECLARE @ReturnCode INT | |
SELECT @ReturnCode = 0 | |
/****** Object: JobCategory [Database Maintenance] Script Date: 9/3/2022 3:33:46 PM ******/ | |
IF NOT EXISTS (SELECT name FROM msdb.dbo.syscategories WHERE name=N'Database Maintenance' AND category_class=1) | |
BEGIN | |
EXEC @ReturnCode = msdb.dbo.sp_add_category @class=N'JOB', @type=N'LOCAL', @name=N'Database Maintenance' | |
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback | |
END | |
DECLARE @jobId BINARY(16) | |
EXEC @ReturnCode = msdb.dbo.sp_add_job @job_name=N'SQL Audit Logs to S3', | |
@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'Database Maintenance', | |
@owner_login_name=N'SMARTBANK\maa-terceiro', @job_id = @jobId OUTPUT | |
IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback | |
/****** Object: Step [Move SQL Audit Log files to S3 bucket] Script Date: 9/3/2022 3:33:46 PM ******/ | |
EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'Move SQL Audit Log files to S3 bucket', | |
@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'PowerShell', | |
@command=N'$path=''F:\SQL Audit'' | |
$server = $env:COMPUTERNAME | |
$s3Bucket = ''hmg-sqlserver-backup'' | |
$region = ''us-east-2'' | |
Get-ChildItem -File -Path $path | Sort-Object -Property LastAccessTime | |
$audit_files = Get-ChildItem -File -Path $path | Sort-Object -Property LastAccessTime | |
if ($audit_files.Length -gt 2) | |
{ | |
$counter = 1 | |
foreach ($audit_file in $audit_files) { | |
if ($counter -lt ($audit_files.Length) - 1) { | |
$destination = ''Audit Logs/'' + $audit_file.Name | |
Write-S3Object -BucketName $s3Bucket -File $audit_file.FullName -Region $region -Key $destination | |
Remove-Item -Path $audit_file.FullName -Force | |
} | |
$counter++ | |
} | |
} | |
', | |
@database_name=N'master', | |
@flags=48 | |
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'Every 15 minutes', | |
@enabled=1, | |
@freq_type=4, | |
@freq_interval=1, | |
@freq_subday_type=4, | |
@freq_subday_interval=15, | |
@freq_relative_interval=0, | |
@freq_recurrence_factor=0, | |
@active_start_date=20220321, | |
@active_end_date=99991231, | |
@active_start_time=0, | |
@active_end_time=235959, | |
@schedule_uid=N'b07dbd69-4e23-4bd7-9354-e1f4090f62e4' | |
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 | |
Sign up for free
to join this conversation on GitHub.
Already have an account?
Sign in to comment