--DROP TABLE TBMigrationLog CREATE TABLE TBMigrationLog ( MigrationID INTEGER NOT NULL, ScriptName VARCHAR(255) NOT NULL, ExecutedWhen DATETIME NOT NULL, ExecutedWho VARCHAR(50) NOT NULL, ExecState VARCHAR(50), ErrorMessage VARCHAR(500), CONSTRAINT PK_TBMigrationLog PRIMARY KEY (MigrationID) ) GO --DROP TABLE TBMigrationScripts CREATE TABLE TBMigrationScripts ( MigrationID INTEGER IDENTITY(1,1), ScriptName VARCHAR(255) NOT NULL, ScriptDescription VARCHAR(255), ScriptPath_Command NVARCHAR(MAX), IsActive BIT NOT NULL DEFAULT 0, AddedWhen DATETIME NOT NULL DEFAULT GETDATE() CONSTRAINT PK_TBMigrationScripts PRIMARY KEY (MigrationID) ) GO INSERT INTO TBMigrationScripts (ScriptName, ScriptDescription, ScriptPath_Command, IsActive) VALUES ('007', 'FILE', 'E:\TreeSizeFree\1.9.8.1.sql', 1); --CREATE PROCEDURE ExecuteMigrations --AS BEGIN DECLARE @MigrationID INT, @ScriptName VARCHAR(255), @ScriptPath_Command NVARCHAR(MAX), @SQL NVARCHAR(MAX),@ScriptDescription VARCHAR(20); DECLARE MigrationCursor CURSOR FOR SELECT MS.MigrationID, MS.ScriptName, ScriptPath_Command,MS.ScriptDescription FROM TBMigrationScripts MS LEFT JOIN TBMigrationLog ML ON MS.MigrationID = ML.MigrationID WHERE ML.MigrationID IS NULL AND MS.IsActive = 1 ORDER BY MS.MigrationID; OPEN MigrationCursor; FETCH NEXT FROM MigrationCursor INTO @MigrationID, @ScriptName, @ScriptPath_Command,@ScriptDescription; WHILE @@FETCH_STATUS = 0 BEGIN BEGIN TRY -- Lies das SQL-Skript aus der Datei IF @ScriptDescription = 'FILE' BEGIN DECLARE @DynamicSQL NVARCHAR(500), @FileContent NVARCHAR(MAX); SET @DynamicSQL = 'SELECT @FileContentOut = BulkColumn FROM OPENROWSET(BULK ''' + @ScriptPath_Command + ''', SINGLE_CLOB) AS FileContent'; EXEC sp_executesql @DynamicSQL, N'@FileContentOut NVARCHAR(MAX) OUTPUT', @FileContent OUTPUT; SET @SQL = @FileContent; PRINT '==============================' PRINT @SQL PRINT '==============================' END ELSE SET @SQL = @ScriptPath_Command; -- Führe das Skript aus PRINT 'EXECUTING - MIGRATION SKRIPT [' + @ScriptName + '] ...' EXEC sp_executesql @SQL; PRINT '########################################' PRINT 'EXECUTION SUCCESSFUL!' PRINT '########################################' -- Erfolgreiche Migration protokollieren INSERT INTO TBMigrationLog (MigrationID, ScriptName, ExecutedWhen, ExecutedWho, ExecState) VALUES (@MigrationID, @ScriptName, GETDATE(), SYSTEM_USER, 'Success'); END TRY BEGIN CATCH DECLARE @ERR VARCHAR(1500) = ERROR_MESSAGE(); PRINT @ERR -- Fehler protokollieren INSERT INTO TBMigrationLog (MigrationID, ScriptName, ExecutedWhen, ExecutedWho, ExecState, ErrorMessage) VALUES (@MigrationID, @ScriptName, GETDATE(), 'XXXX', 'Failed', @ERR); BREAK; END CATCH; PRINT '' FETCH NEXT FROM MigrationCursor INTO @MigrationID, @ScriptName, @ScriptPath_Command,@ScriptDescription; END; CLOSE MigrationCursor; DEALLOCATE MigrationCursor; END;