-------------------------------------------------------------------------------- -- SQL Server & Azure SQL Managed Instance - Query Performance Insights -- SQL Agent that periodically collects the QPI statistics. -- Author: Jovan Popovic -------------------------------------------------------------------------------- DECLARE @database sysname = <'put the name of the database where QPI procedures are placed'>; DECLARE @job_name sysname; SET @job_name = @database + N'-snapshot-qpi-stats'; /****** Object: Job [snapshot-qpi-stats] Script Date: 10/5/2018 7:52:13 AM ******/ BEGIN TRANSACTION DECLARE @ReturnCode INT SELECT @ReturnCode = 0 /****** Object: JobCategory [[Uncategorized (Local)]] Script Date: 10/5/2018 7:52:13 AM ******/ 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=@job_name, @enabled=1, @notify_level_eventlog=0, @notify_level_email=0, @notify_level_netsend=0, @notify_level_page=0, @delete_level=0, @description=N'Takes the snapshots of QPI file and wait statistics. Requires QPI library to be installed on the target database.', @category_name=N'[Uncategorized (Local)]', @job_id = @jobId OUTPUT IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback /****** Object: Step [snapshot-file-stats] Script Date: 10/5/2018 7:52:13 AM ******/ EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'snapshot-file-stats', @step_id=1, @cmdexec_success_code=0, @on_success_action=3, @on_success_step_id=0, @on_fail_action=3, @on_fail_step_id=0, @retry_attempts=2, @retry_interval=0, @os_run_priority=0, @subsystem=N'TSQL', @command=N'EXEC qpi.snapshot_file_stats', @database_name= @database, @flags=0 IF (@@ERROR <> 0 OR @ReturnCode <> 0) GOTO QuitWithRollback /****** Object: Step [snapshot-wait-stats] Script Date: 10/5/2018 7:52:14 AM ******/ EXEC @ReturnCode = msdb.dbo.sp_add_jobstep @job_id=@jobId, @step_name=N'snapshot-wait-stats', @step_id=2, @cmdexec_success_code=0, @on_success_action=1, @on_success_step_id=0, @on_fail_action=2, @on_fail_step_id=0, @retry_attempts=3, @retry_interval=0, @os_run_priority=0, @subsystem=N'TSQL', @command=N'EXEC qpi.snapshot_wait_stats;', @database_name=@database, @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'qpi-stats-collection-interval', @enabled=1, @freq_type=4, @freq_interval=1, @freq_subday_type=4, @freq_subday_interval=5, @freq_relative_interval=0, @freq_recurrence_factor=0, @active_start_date=20181005, @active_end_date=99991231, @active_start_time=0, @active_end_time=235959, @schedule_uid=N'b2abc5d7-7574-4994-aadf-105bd5fccbce' 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