TransportScripts und taskFLOW
This commit is contained in:
324
00_DB_SETUP_SINGLE/02_DD_SYS/Transport_Batch.sql
Normal file
324
00_DB_SETUP_SINGLE/02_DD_SYS/Transport_Batch.sql
Normal file
@@ -0,0 +1,324 @@
|
||||
-- Übergeordnete Projekte / Themenkomplexe
|
||||
CREATE TABLE TBDDTransportProjects (
|
||||
ProjectID INT IDENTITY(1,1) PRIMARY KEY,
|
||||
ProjectName NVARCHAR(255) NOT NULL, -- z.B. 'Release_2024_Q1' oder 'Modul_E-Rechnung'
|
||||
ProjectDescription NVARCHAR(MAX),
|
||||
ADDED_WHEN DATETIME DEFAULT GETDATE(),
|
||||
ADDED_WHO NVARCHAR(128) DEFAULT SUSER_SNAME()
|
||||
);
|
||||
|
||||
CREATE TABLE TBDDTransportLog (
|
||||
TransportID INT IDENTITY(1,1),
|
||||
ProjectID INT NOT NULL,
|
||||
TransportBatch NVARCHAR(128),
|
||||
TopicGroup NVARCHAR(255),
|
||||
SourceDatabase NVARCHAR(128), -- 'DD_ECM' oder 'IDB'
|
||||
ObjectName NVARCHAR(128),
|
||||
ObjectType VARCHAR(20),
|
||||
SequenceOrder INT DEFAULT 100,
|
||||
SqlScript NVARCHAR(MAX),
|
||||
ArchiveScript NVARCHAR(MAX),
|
||||
Status_Transport VARCHAR(20) DEFAULT 'Pending',
|
||||
LogMessage NVARCHAR(MAX),
|
||||
ADDED_WHEN DATETIME DEFAULT GETDATE(),
|
||||
Deployed_when DATETIME,
|
||||
CONSTRAINT PK_TBPM_PROFILE_GUID PRIMARY KEY (TransportID),
|
||||
CONSTRAINT FK_TBDDTransportLog_ProjectID FOREIGN KEY (ProjectID) REFERENCES TBDDTransportProjects(ProjectID),
|
||||
);
|
||||
GO
|
||||
CREATE OR ALTER PROCEDURE PRDD_Transport_PackObject
|
||||
@SourceDB SYSNAME, -- 'DD_ECM' oder 'IDB'
|
||||
@ObjectName SYSNAME,
|
||||
@ProjectID INT, -- Neu: Pflichtbezug zum Projekt
|
||||
@TransportBatch NVARCHAR(128) = NULL,
|
||||
@ManualOrder INT = NULL
|
||||
AS
|
||||
BEGIN
|
||||
SET NOCOUNT ON;
|
||||
|
||||
DECLARE @Definition NVARCHAR(MAX);
|
||||
DECLARE @Type VARCHAR(20);
|
||||
DECLARE @Order INT;
|
||||
DECLARE @ParmDefinition NVARCHAR(500) = N'@DefOut NVARCHAR(MAX) OUTPUT, @TypeOut VARCHAR(20) OUTPUT';
|
||||
|
||||
-- Dynamische Abfrage der Quelldatenbank
|
||||
DECLARE @SQL NVARCHAR(MAX) = N'
|
||||
SELECT @DefOut = m.definition, @TypeOut = o.type_desc
|
||||
FROM ' + QUOTENAME(@SourceDB) + '.sys.sql_modules m
|
||||
JOIN ' + QUOTENAME(@SourceDB) + '.sys.objects o ON m.object_id = o.object_id
|
||||
WHERE o.object_id = OBJECT_ID(''' + @SourceDB + '..' + @ObjectName + ''')';
|
||||
|
||||
EXEC sp_executesql @SQL, @ParmDefinition, @DefOut = @Definition OUTPUT, @TypeOut = @Type OUTPUT;
|
||||
|
||||
IF @Definition IS NULL
|
||||
BEGIN
|
||||
RAISERROR('Objekt %s in Datenbank %s nicht gefunden.', 16, 1, @ObjectName, @SourceDB);
|
||||
RETURN;
|
||||
END
|
||||
|
||||
-- Sequenzierung festlegen
|
||||
SET @Order = ISNULL(@ManualOrder,
|
||||
CASE
|
||||
WHEN @Type LIKE '%TABLE%' THEN 10
|
||||
WHEN @Type LIKE '%FUNCTION%' THEN 20
|
||||
WHEN @Type = 'VIEW' THEN 30
|
||||
WHEN @Type = 'SQL_STORED_PROCEDURE' THEN 40
|
||||
ELSE 100 END);
|
||||
|
||||
-- CREATE zu CREATE OR ALTER umwandeln
|
||||
IF LEFT(LTRIM(@Definition), 6) = 'CREATE'
|
||||
SET @Definition = 'CREATE OR ALTER' + SUBSTRING(LTRIM(@Definition), 7, LEN(@Definition));
|
||||
|
||||
INSERT INTO TBDDTransportLog (
|
||||
TransportBatch,
|
||||
ProjectID,
|
||||
SourceDatabase,
|
||||
ObjectName,
|
||||
ObjectType,
|
||||
SequenceOrder,
|
||||
SqlScript)
|
||||
VALUES (
|
||||
ISNULL(@TransportBatch,
|
||||
NEWID()),
|
||||
@ProjectID,
|
||||
@SourceDB,
|
||||
@ObjectName,
|
||||
@Type,
|
||||
@Order,
|
||||
@Definition);
|
||||
|
||||
PRINT 'Objekt ' + @ObjectName + ' aus ' + @SourceDB + ' verpackt.';
|
||||
END;
|
||||
GO
|
||||
|
||||
CREATE OR ALTER PROCEDURE PRDD_DeployProject
|
||||
@ProjectID INT,
|
||||
@TargetLinkedServer NVARCHAR(128)
|
||||
AS
|
||||
BEGIN
|
||||
SET NOCOUNT ON;
|
||||
|
||||
-- Prüfung, ob Projekt existiert
|
||||
IF NOT EXISTS (SELECT 1 FROM TBDDTransportProjects WHERE ProjectID = @ProjectID)
|
||||
BEGIN
|
||||
RAISERROR('Projekt mit ID %d wurde nicht gefunden.', 16, 1, @ProjectID);
|
||||
RETURN;
|
||||
END
|
||||
|
||||
DECLARE @ID INT,
|
||||
@DB NVARCHAR(128),
|
||||
@ObjName NVARCHAR(128),
|
||||
@Script NVARCHAR(MAX),
|
||||
@RemoteSQL NVARCHAR(MAX),
|
||||
@ArchiveSQL NVARCHAR(MAX);
|
||||
|
||||
-- Cursor über ALLE Batches dieses Projekts, strikt nach SequenceOrder
|
||||
-- So werden z.B. erst alle Tabellen (10) beider DBs erstellt, bevor Views (30) kommen.
|
||||
DECLARE ProjectCursor CURSOR FOR
|
||||
SELECT TransportID, SourceDatabase, ObjectName, SqlScript
|
||||
FROM TBDDTransportLog
|
||||
WHERE ProjectID = @ProjectID
|
||||
AND Status_Transport IN ('Pending', 'Error') -- Ermöglicht Wiederholung nach Fehlern
|
||||
ORDER BY SequenceOrder ASC, ADDED_WHEN ASC;
|
||||
|
||||
OPEN ProjectCursor;
|
||||
FETCH NEXT FROM ProjectCursor INTO @ID, @DB, @ObjName, @Script;
|
||||
|
||||
PRINT 'Starte Deployment für Projekt-ID: ' + CAST(@ProjectID AS NVARCHAR(10));
|
||||
PRINT 'Ziel-Server: ' + @TargetLinkedServer;
|
||||
PRINT '---------------------------------------------------------';
|
||||
|
||||
WHILE @@FETCH_STATUS = 0
|
||||
BEGIN
|
||||
BEGIN TRY
|
||||
-- 1. Archivierung des Ist-Zustands auf dem Zielserver
|
||||
-- Wir versuchen die Definition des Objekts zu lesen
|
||||
DECLARE @OldDefinition NVARCHAR(MAX) = NULL;
|
||||
|
||||
-- Dynamischer Befehl um OBJECT_DEFINITION remote auszuführen
|
||||
-- Hinweis: Benötigt RPC Out auf dem Linked Server
|
||||
SET @ArchiveSQL = N'SELECT @out = OBJECT_DEFINITION(OBJECT_ID(N''' + @DB + '..' + @ObjName + '''))';
|
||||
|
||||
BEGIN TRY
|
||||
EXEC (@ArchiveSQL, @out = @OldDefinition OUTPUT) AT [TEST_SERVER]; -- Hier @TargetLinkedServer nutzen
|
||||
END TRY
|
||||
BEGIN CATCH
|
||||
SET @OldDefinition = '-- Objekt existierte vor Deployment nicht';
|
||||
END CATCH
|
||||
|
||||
-- 2. Update der Log-Tabelle mit Archiv-Script
|
||||
UPDATE TBDDTransportLog
|
||||
SET ArchiveScript = @OldDefinition,
|
||||
Status_Transport = 'Deploying'
|
||||
WHERE TransportID = @ID;
|
||||
|
||||
-- 3. Ausführung des neuen Scripts
|
||||
-- Wir wechseln den Kontext auf die Ziel-DB
|
||||
SET @RemoteSQL = N'USE ' + QUOTENAME(@DB) + N'; EXEC(N''' + REPLACE(@Script, '''', '''''') + N''');';
|
||||
|
||||
EXEC (@RemoteSQL) AT [TEST_SERVER];
|
||||
|
||||
-- 4. Erfolg loggen
|
||||
UPDATE TBDDTransportLog
|
||||
SET Status_Transport = 'Deployed',
|
||||
LogMessage = 'Erfolgreich am ' + CONVERT(NVARCHAR(30), GETDATE(), 120)
|
||||
WHERE TransportID = @ID;
|
||||
|
||||
PRINT 'SUCCESS: ' + @DB + '.' + @ObjName;
|
||||
END TRY
|
||||
BEGIN CATCH
|
||||
-- Fehler loggen
|
||||
UPDATE TBDDTransportLog
|
||||
SET Status_Transport = 'Error',
|
||||
LogMessage = ERROR_MESSAGE()
|
||||
WHERE TransportID = @ID;
|
||||
|
||||
PRINT 'ERROR: ' + @DB + '.' + @ObjName + ' - ' + ERROR_MESSAGE();
|
||||
|
||||
-- Strategie-Entscheidung: Abbrechen bei Fehler?
|
||||
-- CLOSE ProjectCursor; DEALLOCATE ProjectCursor; RETURN;
|
||||
END CATCH
|
||||
|
||||
FETCH NEXT FROM ProjectCursor INTO @ID, @DB, @ObjName, @Script;
|
||||
END
|
||||
|
||||
CLOSE ProjectCursor;
|
||||
DEALLOCATE ProjectCursor;
|
||||
|
||||
PRINT '---------------------------------------------------------';
|
||||
PRINT 'Deployment abgeschlossen.';
|
||||
END;
|
||||
GO
|
||||
|
||||
CREATE OR ALTER PROCEDURE PRDD_DeployTransportBatch
|
||||
@TargetLinkedServer NVARCHAR(128),
|
||||
@TransportBatch NVARCHAR(128)
|
||||
AS
|
||||
BEGIN
|
||||
SET NOCOUNT ON;
|
||||
DECLARE @ID INT,
|
||||
@DB NVARCHAR(128),
|
||||
@ObjName NVARCHAR(128),
|
||||
@Script NVARCHAR(MAX),
|
||||
@OldScript NVARCHAR(MAX),
|
||||
@RemoteSQL NVARCHAR(MAX);
|
||||
|
||||
DECLARE DeployCursor CURSOR FOR
|
||||
SELECT TransportID, SourceDatabase, ObjectName, SqlScript
|
||||
FROM TBDDTransportLog
|
||||
WHERE TransportBatch = @TransportBatch AND Status_Transport = 'Pending'
|
||||
ORDER BY SequenceOrder ASC;
|
||||
|
||||
OPEN DeployCursor;
|
||||
FETCH NEXT FROM DeployCursor INTO @ID, @DB, @ObjName, @Script;
|
||||
|
||||
WHILE @@FETCH_STATUS = 0
|
||||
BEGIN
|
||||
BEGIN TRY
|
||||
-- 1. Archivierung: Aktuellen Stand vom Ziel-Server holen
|
||||
-- Wir nutzen OPENQUERY oder EXEC AT, um den Stand remote zu prüfen
|
||||
SET @OldScript = NULL;
|
||||
|
||||
DECLARE @GetArchiveSQL NVARCHAR(MAX) =
|
||||
N'SELECT @out = OBJECT_DEFINITION(OBJECT_ID(N''' + @DB + N'..' + @ObjName + N'''))';
|
||||
|
||||
-- Remote-Abfrage des aktuellen Standes
|
||||
EXEC (@GetArchiveSQL, @out = @OldScript OUTPUT) AT [TEST_SERVER];
|
||||
|
||||
-- Alten Stand in DD_SYS sichern
|
||||
UPDATE TBDDTransportLog
|
||||
SET ArchiveScript = @OldScript
|
||||
WHERE TransportID = @ID;
|
||||
|
||||
-- 2. Deployment: Datenbankkontext setzen und Skript ausführen
|
||||
SET @RemoteSQL = N'USE ' + QUOTENAME(@DB) + N'; EXEC(N''' + REPLACE(@Script, '''', '''''') + N''');';
|
||||
|
||||
EXEC (@RemoteSQL) AT [TEST_SERVER];
|
||||
|
||||
UPDATE TBDDTransportLog SET Status_Transport = 'Deployed', LogMessage = 'Erfolgreich',Deployed_when = GETDATE() WHERE TransportID = @ID;
|
||||
END TRY
|
||||
BEGIN CATCH
|
||||
UPDATE TBDDTransportLog
|
||||
SET Status_Transport = 'Error',
|
||||
LogMessage = N'Fehler in ' + @DB + N'.' + @ObjName + N': ' + ERROR_MESSAGE()
|
||||
WHERE TransportID = @ID;
|
||||
|
||||
-- Optional: Hier BREAK einfügen, wenn der ganze Batch bei Fehler stoppen soll
|
||||
END CATCH
|
||||
|
||||
FETCH NEXT FROM DeployCursor INTO @ID, @DB, @ObjName, @Script;
|
||||
END
|
||||
|
||||
CLOSE DeployCursor;
|
||||
DEALLOCATE DeployCursor;
|
||||
END;
|
||||
GO
|
||||
CREATE OR ALTER PROCEDURE PRDD_Transport_AddManualScript
|
||||
@SourceDB NVARCHAR(128),
|
||||
@ObjectName NVARCHAR(128),
|
||||
@SqlScript NVARCHAR(MAX),
|
||||
@TransportBatch NVARCHAR(128),
|
||||
@SequenceOrder INT = 10, -- Standardmäßig 10 (vor Code-Objekten)
|
||||
@ObjectType NVARCHAR(20) = N'TABLE_ALTER'
|
||||
AS
|
||||
BEGIN
|
||||
SET NOCOUNT ON;
|
||||
|
||||
INSERT INTO TBDDTransportLog (
|
||||
TransportBatch,
|
||||
SourceDatabase,
|
||||
ObjectName,
|
||||
ObjectType,
|
||||
SequenceOrder,
|
||||
SqlScript,
|
||||
Status_Transport
|
||||
)
|
||||
VALUES (
|
||||
@TransportBatch,
|
||||
@SourceDB,
|
||||
@ObjectName,
|
||||
@ObjectType,
|
||||
@SequenceOrder,
|
||||
@SqlScript,
|
||||
N'Pending'
|
||||
);
|
||||
|
||||
PRINT 'Manuelles Skript für ' + @ObjectName + ' zum Batch hinzugefügt.';
|
||||
END;
|
||||
GO
|
||||
CREATE OR ALTER PROCEDURE PRDD_TransportBatch_Rollback
|
||||
@TargetLinkedServer NVARCHAR(128),
|
||||
@BatchID UNIQUEIDENTIFIER
|
||||
AS
|
||||
BEGIN
|
||||
SET NOCOUNT ON;
|
||||
DECLARE @ID INT, @DB NVARCHAR(128), @Script NVARCHAR(MAX), @RemoteSQL NVARCHAR(MAX);
|
||||
|
||||
-- Cursor rückwärts (DESC), um die letzte Änderung zuerst rückgängig zu machen
|
||||
DECLARE RollbackCursor CURSOR FOR
|
||||
SELECT TransportID,SourceDatabase, ArchiveScript
|
||||
FROM TBDDTransportLog
|
||||
WHERE TransportBatch = @BatchID AND Status_Transport = 'Deployed' AND ArchiveScript IS NOT NULL
|
||||
ORDER BY SequenceOrder DESC;
|
||||
|
||||
OPEN RollbackCursor;
|
||||
FETCH NEXT FROM RollbackCursor INTO @ID, @DB, @Script;
|
||||
|
||||
WHILE @@FETCH_STATUS = 0
|
||||
BEGIN
|
||||
BEGIN TRY
|
||||
SET @RemoteSQL = N'USE ' + QUOTENAME(@DB) + N'; ' + @Script;
|
||||
EXEC (@RemoteSQL) AT [MEIN_TEST_SERVER]; -- Dynamischer Servername hier einsetzen
|
||||
PRINT 'Rollback erfolgreich für Objekt in ' + @DB;
|
||||
UPDATE TBDDTransportLog SET Status_Transport = 'ROLLBACK', Deployed_when = NULL WHERE TransportID = @ID;
|
||||
END TRY
|
||||
BEGIN CATCH
|
||||
PRINT 'Fehler beim Rollback in ' + @DB + ': ' + ERROR_MESSAGE();
|
||||
END CATCH
|
||||
|
||||
FETCH NEXT FROM RollbackCursor INTO @ID, @DB, @Script;
|
||||
END
|
||||
|
||||
CLOSE RollbackCursor;
|
||||
DEALLOCATE RollbackCursor;
|
||||
END;
|
||||
Reference in New Issue
Block a user