mssql-jobs-by-fsaver

This commit is contained in:
Pavel Muhortov 2024-05-19 13:07:32 +03:00
parent 18eb681898
commit 86c1efe4cf

View File

@ -2,10 +2,74 @@
Collection for database management systems
* [`mssql-jobs-by-fsaver`](https://git.hmp.today/pavel.muhortov/dbms#mssql-jobs-by-fsaver)
* [`mysqldump-wrapper.sh`](https://git.hmp.today/pavel.muhortov/dbms#mysqldump-wrapper-sh)
____
## `mssql-jobs-by-fsaver`
**Description:**
> running Microsoft SQL Server agent jobs by Effector Saver with handling of executing time and errors
**Dependencies:**
>
> * [SQL Server](https://www.microsoft.com/en-us/sql-server) (tested version 2022 on [Windows Server 2022](https://learn.microsoft.com/en-us/windows-server/get-started/whats-new-in-windows-server-2022))
> * [SQL Server Management Studio](https://learn.microsoft.com/en-us/sql/ssms) (tested version 19.1 on [Windows Server 2022](https://learn.microsoft.com/en-us/windows-server/get-started/whats-new-in-windows-server-2022))
> * [Effector Saver](https://mixbackup.com/) (tested version 4.11 on [Windows Server 2022](https://learn.microsoft.com/en-us/windows-server/get-started/whats-new-in-windows-server-2022))
### Create maintenance plan with subplan name
>
> example maintanence plane name: `Daily-Database_Name`
> example subplan name: `Backup`
Microsoft SQL Server Management Studio -> Management -> Maintenance Plans -> New Maintenance Plan -> Name: `Daily-Database_Name` -> Subplan properties -> Name: `Backup`
### Check auto made agent job and its name
Microsoft SQL Server Management Studio -> SQL Server Agent -> Jobs -> `Daily-Database_Name.Backup`
### Create Effector Saver task
Effector Saver -> Tasks -> Add task -> Other tasks -> Commands -> Name: Daily-Database_Name -> Main preferences -> Add command
Name:
```text
Daily-Database_Name.Backup
```
Command type:
```text
SQL script
```
Command text:
```sql
SET NOCOUNT ON
DECLARE @jobNM NVARCHAR(MAX) = 'Daily-Database_Name.Backup',
@jobID UNIQUEIDENTIFIER,
@maxID INT
SELECT @jobID = job_id FROM msdb..sysjobs WHERE name = @jobNM
SELECT @maxID = MAX(instance_id) FROM msdb..sysjobhistory WHERE job_id = @jobID AND step_id = 0
SET @maxID = COALESCE(@maxID, -1)
EXEC msdb..sp_start_job @job_id = @jobID
WHILE (SELECT MAX(instance_id) FROM msdb..sysjobhistory WHERE job_id = @jobID AND step_id = 0) = @maxID
WAITFOR DELAY '00:00:01'
SELECT @maxID = MAX(instance_id) FROM msdb..sysjobhistory WHERE job_id = @jobID AND step_id = 0
IF (SELECT run_status FROM msdb..sysjobhistory WHERE instance_id = @maxID) = 0
RAISERROR (N'#ERROR# Microsoft SQL Server Job finished with error', 16, 1) WITH NOWAIT
```
____
## `mysqldump-wrapper.sh`
**Description:**