USE [DD_SYS] GO SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO SET ANSI_WARNINGS ON GO SET ANSI_PADDING ON GO -- [PRDD_SYNC_DATABASE] -- ================================================================= -- Schema- und optionale Daten-Synchronisation zwischen zwei bestehenden Datenbanken -- Fokus: programmierbare Objekte, Schemata, Tabellen (additiv), Keys, FKs, Indizes, Synonyme -- Optionale Datenabgleiche pro Tabelle (nur bei Abweichungen) -- Minimum requirement: MS SQL Server 2016 -- -- Returns: INT Value - 0 = Everything worked well, 1 = Error -- ================================================================= -- NICHT UNTERSTÜTZT / NOT SUPPORTED (in dieser Version): -- - Extended Properties (sp_addextendedproperty) -- - Service Broker Objects (Queues, Services, Contracts) -- - User-Defined Types (CREATE TYPE) -- - Full-Text Indexes (CREATE FULLTEXT INDEX) -- - XML Schema Collections (CREATE XML SCHEMA COLLECTION) -- - User-Defined Statistics (CREATE STATISTICS) -- - Columnstore Indexes (type 5,6 - nur Clustered/Nonclustered werden synchronisiert) -- - Partitions und Partition Schemes -- - Change Data Capture (CDC) -- - Change Tracking -- - CLR Assemblies, CLR Functions, CLR Procedures (CREATE ASSEMBLY) -- - Encrypted Objects (WITH ENCRYPTION) -- ================================================================= -- GEPLANTE FEATURES / PLANNED FEATURES (Future): -- - @pBATCHSIZE: Batch-basiertes MERGE für große Tabellen (Parameter validiert, Implementierung ausstehend) -- ================================================================= -- Copyright (c) 2025 by Digital Data GmbH -- -- Digital Data GmbH • Ludwig-Rinn-Strasse 16 • D-35452 Heuchelheim -- Tel.: 0641/202360 • E-Mail: info-flow@digitaldata.works -- ================================================================= -- Creation Date / Author: 24.12.2025 / MK -- Version Date / Editor: 29.12.2025 / MK -- Version Number: 0.6.4 (Final) -- ================================================================= -- History: -- 29.12.2025 / MK - v0.6.4: Bugfix: Views+Functions+Procedures robust (case-insensitive, whitespace, placeholder) -- 29.12.2025 / MK - v0.6.3: Code Review: 34 Punkte behoben (CRITICAL, HIGH, MEDIUM, LOW) -- 29.12.2025 / MK - v0.6.2: Validation auch bei @EXECUTE=0 (DRY-RUN/Preview) -- 29.12.2025 / MK - v0.6.1: OBJECT DETAILS nur bei @DEBUG=1 (weniger Output) -- 29.12.2025 / MK - v0.6.0: Views/Procedures/Functions use CREATE OR ALTER (no more DROP required) -- 29.12.2025 / MK - v0.5.9: Cycle Detection for Views/Functions Dependency CTEs -- 29.12.2025 / MK - v0.5.8: Code Review Fixes + Bidirectional Mismatch Report -- 29.12.2025 / MK - v0.5.7: Feature: @pDROPEXISTING Parameter zur Steuerung von DROP-Statements -- 29.12.2025 / MK - v0.5.6: Bugfix: DROP Phases sort before CREATE, Comprehensive Collation-Fix -- 29.12.2025 / MK - v0.5.4: Feature: @pUSETRANSACTION Parameter, Transaction Safety-Net -- 29.12.2025 / MK - v0.5.3: Code Review: 23-Punkte-Plan (Security, Performance, Validation) -- 29.12.2025 / MK - v0.5.2: Feature: Collation-Check, Temp-Tables mit Server-Collation -- 29.12.2025 / MK - v0.5.1: Bugfix: Temp-Tabellen dynamisch mit Quell-DB Collation -- 29.12.2025 / MK - v0.5.0: Feature: DROP + CREATE for programmable objects -- 29.12.2025 / MK - v0.4.x: Diverse Bugfixes und Code Reviews -- 28.12.2025 / MK - v0.3.x: Collation-Fixes, Cursors LOCAL, Stats -- 24.12.2025 / MK - v0.2.0: IncludeData-Option, Logging-Tabelle, Hash-Vergleich -- ================================================================= CREATE OR ALTER PROCEDURE [dbo].[PRDD_SYNC_DATABASE] ( @pSOURCEDATABASE NVARCHAR(128) = NULL, -- Quell-Datenbank (Referenz). Schema- und Datenvergleich-Basis. Nicht NULL erforderlich. @pTARGETDATABASE NVARCHAR(128) = NULL, -- Ziel-Datenbank (zu aktualisieren). Erhält alle Schema- und Datenänderungen. Nicht NULL erforderlich. @pEXECUTE BIT = 1, -- Ausführungsmodus: 1 = Änderungen ausführen, 0 = Nur Plan ausgeben/Test (Dry-Run) @pEXCLUDEOBJECTS NVARCHAR(MAX) = NULL, -- Optionale Objekt-Ausschlüsse. Komma-getrennt. Unterstützt Wildcards (*). Beispiel: 'test*,temp_*' @pSYNCOBJECTS NVARCHAR(500) = 'ALL', -- Objekttypen für Sync. 'ALL' oder kommasepariert: SCHEMAS,TABLES/TABS,VIEWS,PROCEDURES/PROCS,FUNCTIONS/FUNCS,TRIGGERS,INDEXES,SYNONYMS,SEQUENCES @pLOGLEVEL NVARCHAR(25) = 'INFO', -- Log-Schwellenwert: 'INFO' = alle, 'WARN' = Warnungen+Fehler, 'ERROR' = nur Fehler, NULL = kein Logging @pDEBUG BIT = 0, -- Debug-Modus: 1 = ausführliche Ausgabe (SQL-Statements, Hashes), 0 = minimal @pINCLUDEDATA BIT = 0, -- Daten-Synchronisation: 0 = nur Schema, 1 = Schema + Daten mit Hash-Vergleich @pDELETEMISSING BIT = 0, -- Lösch-Strategie für Target-Daten: 0 = behalten, 1 = fehlende Zeilen im Target löschen @pSYNCSECURITY BIT = 0, -- Sicherheitssync: 1 = Benutzer/Rollen/Grants synchronisieren, 0 = überspringen (Standard) @pVALIDATION_MODE NVARCHAR(20) = 'NONE', -- Validierungsmodus: 'NONE' = keine, 'SCHEMA' = nur Schema, 'DATA' = nur Daten, 'ALL' = beides @pBATCHSIZE INT = 10000, -- [FUTURE] Batch-Größe für Data-Sync (validiert, aber noch nicht implementiert) @pUSETRANSACTION BIT = 0, -- Transaction-Modus: 1 = atomare Ausfuehrung mit Rollback bei Fehler, 0 = ohne Transaction @pDROPEXISTING BIT = 0 -- DROP-Strategie fuer programm. Objekte (Views/Triggers/Functions/Procs): 1 = DROP vor CREATE, 0 = nur CREATE OR ALTER (Standard) ) AS BEGIN --===============================================-- Set session options --================================================-- SET NOCOUNT ON; SET XACT_ABORT ON; ---------------------------------------------------------------------------------------------------------------------------- --=========================================-- Define constants --========================================-- DECLARE @CONST_MIN_BATCHSIZE INT = 100, @CONST_MAX_BATCHSIZE INT = 1000000, @CONST_DEFAULT_BATCHSIZE INT = 10000, @CONST_MAX_EXCLUDES INT = 1000; -- Maximum number of exclude patterns (overflow protection, 1000 is sufficient for most use cases without memory impact) ---------------------------------------------------------------------------------------------------------------------------- --=========================================-- Parameter copies (avoid sniffing) --========================================-- DECLARE @SOURCEDATABASE SYSNAME = NULLIF(LTRIM(RTRIM(@pSOURCEDATABASE)), N''), @TARGETDATABASE SYSNAME = NULLIF(LTRIM(RTRIM(@pTARGETDATABASE)), N''), @EXECUTE BIT = ISNULL(@pEXECUTE, 0), @LOGLEVEL NVARCHAR(25) = CASE WHEN @pLOGLEVEL IS NULL THEN NULL ELSE UPPER(LTRIM(RTRIM(@pLOGLEVEL))) END, @DEBUG BIT = ISNULL(@pDEBUG, 0), @EXCLUDEOBJECTS NVARCHAR(MAX) = CASE WHEN @pEXCLUDEOBJECTS IS NULL THEN NULL ELSE LTRIM(RTRIM(@pEXCLUDEOBJECTS)) END, @SYNCOBJECTS NVARCHAR(500) = CASE WHEN @pSYNCOBJECTS IS NULL THEN N'ALL' ELSE UPPER(LTRIM(RTRIM(@pSYNCOBJECTS))) END, @INCLUDEDATA BIT = ISNULL(@pINCLUDEDATA, 0), @DELETEMISSING BIT = ISNULL(@pDELETEMISSING, 0), @SYNCSECURITY BIT = ISNULL(@pSYNCSECURITY, 0), @VALIDATION_MODE NVARCHAR(20) = CASE WHEN @pVALIDATION_MODE IS NULL THEN 'NONE' ELSE UPPER(LTRIM(RTRIM(@pVALIDATION_MODE))) END, @BATCHSIZE INT = NULL, -- Wird nach Konstanten-Definition gesetzt @USETRANSACTION BIT = ISNULL(@pUSETRANSACTION, 0), @DROPEXISTING BIT = ISNULL(@pDROPEXISTING, 0); -- Object type flags for granular control (derived from @SYNCOBJECTS) DECLARE @SYNC_SCHEMAS BIT = 0, @SYNC_TABLES BIT = 0, @SYNC_VIEWS BIT = 0, @SYNC_PROCEDURES BIT = 0, @SYNC_FUNCTIONS BIT = 0, @SYNC_TRIGGERS BIT = 0, @SYNC_INDEXES BIT = 0, @SYNC_SYNONYMS BIT = 0, @SYNC_SEQUENCES BIT = 0; -- Parse @SYNCOBJECTS and set flags (with delimiter check to avoid partial string matches) DECLARE @SYNCOBJECTS_PADDED NVARCHAR(510) = N',' + REPLACE(@SYNCOBJECTS, N' ', N'') + N','; IF @SYNCOBJECTS = N'ALL' OR @SYNCOBJECTS = N'' OR @SYNCOBJECTS IS NULL BEGIN -- ALL: Enable all object types SET @SYNC_SCHEMAS = 1; SET @SYNC_TABLES = 1; SET @SYNC_VIEWS = 1; SET @SYNC_PROCEDURES = 1; SET @SYNC_FUNCTIONS = 1; SET @SYNC_TRIGGERS = 1; SET @SYNC_INDEXES = 1; SET @SYNC_SYNONYMS = 1; SET @SYNC_SEQUENCES = 1; END ELSE BEGIN -- Individual object types from comma-separated list (with delimiter check) IF CHARINDEX(N',SCHEMAS,', @SYNCOBJECTS_PADDED) > 0 SET @SYNC_SCHEMAS = 1; IF CHARINDEX(N',TABLES,', @SYNCOBJECTS_PADDED) > 0 OR CHARINDEX(N',TABS,', @SYNCOBJECTS_PADDED) > 0 SET @SYNC_TABLES = 1; IF CHARINDEX(N',VIEWS,', @SYNCOBJECTS_PADDED) > 0 SET @SYNC_VIEWS = 1; IF CHARINDEX(N',PROCEDURES,', @SYNCOBJECTS_PADDED) > 0 OR CHARINDEX(N',PROCS,', @SYNCOBJECTS_PADDED) > 0 SET @SYNC_PROCEDURES = 1; IF CHARINDEX(N',FUNCTIONS,', @SYNCOBJECTS_PADDED) > 0 OR CHARINDEX(N',FUNCS,', @SYNCOBJECTS_PADDED) > 0 SET @SYNC_FUNCTIONS = 1; IF CHARINDEX(N',TRIGGERS,', @SYNCOBJECTS_PADDED) > 0 SET @SYNC_TRIGGERS = 1; IF CHARINDEX(N',INDEXES,', @SYNCOBJECTS_PADDED) > 0 SET @SYNC_INDEXES = 1; IF CHARINDEX(N',SYNONYMS,', @SYNCOBJECTS_PADDED) > 0 SET @SYNC_SYNONYMS = 1; IF CHARINDEX(N',SEQUENCES,', @SYNCOBJECTS_PADDED) > 0 SET @SYNC_SEQUENCES = 1; -- Warning if no object types recognized IF @SYNC_SCHEMAS = 0 AND @SYNC_TABLES = 0 AND @SYNC_VIEWS = 0 AND @SYNC_PROCEDURES = 0 AND @SYNC_FUNCTIONS = 0 AND @SYNC_TRIGGERS = 0 AND @SYNC_INDEXES = 0 AND @SYNC_SYNONYMS = 0 AND @SYNC_SEQUENCES = 0 BEGIN PRINT '[WARN] No valid object types recognized in @pSYNCOBJECTS: ' + @SYNCOBJECTS; PRINT '[WARN] Valid values: ALL, SCHEMAS, TABLES/TABS, VIEWS, PROCEDURES/PROCS, FUNCTIONS/FUNCS, TRIGGERS, INDEXES, SYNONYMS, SEQUENCES'; END; END; -- BATCHSIZE mit Konstanten validieren (#1, #18) SET @BATCHSIZE = CASE WHEN @pBATCHSIZE IS NULL OR @pBATCHSIZE < 0 THEN @CONST_DEFAULT_BATCHSIZE WHEN @pBATCHSIZE > 0 AND @pBATCHSIZE < @CONST_MIN_BATCHSIZE THEN @CONST_MIN_BATCHSIZE WHEN @pBATCHSIZE > @CONST_MAX_BATCHSIZE THEN @CONST_MAX_BATCHSIZE ELSE @pBATCHSIZE END; -- Warning if BATCHSIZE was automatically adjusted IF @BATCHSIZE <> ISNULL(@pBATCHSIZE, @CONST_DEFAULT_BATCHSIZE) BEGIN PRINT '[WARN] @pBATCHSIZE adjusted from ' + CONVERT(NVARCHAR(10), ISNULL(@pBATCHSIZE, -1)) + ' to ' + CONVERT(NVARCHAR(10), @BATCHSIZE); END; -- Validate VALIDATION_MODE and set to default if invalid IF @VALIDATION_MODE NOT IN (N'NONE', N'SCHEMA', N'DATA', N'ALL') BEGIN PRINT '[WARN] Invalid @pVALIDATION_MODE value, defaulting to NONE'; SET @VALIDATION_MODE = N'NONE'; END; --=================================================-- Declare runtime variables --==========================================-- DECLARE @MY_PROCEDURE_NAME NVARCHAR(128) = OBJECT_NAME(@@PROCID); DECLARE @PRODUCTVERSION sql_variant, @PRODUCTMAINVERSION INT, @PRODUCTLEVEL sql_variant, @PRODUCTEDITION sql_variant, @SERVERNAME sql_variant, @COMPUTERNETBIOS sql_variant, @MACHINENAME sql_variant, @INSTANCENAME sql_variant, @MYSESSIONID NVARCHAR(50) = CONVERT(NVARCHAR(50),@@SPID), @PLACEHOLDERSOURCEDBQUOTED NVARCHAR(32) = N'{#SOURCEDB_Q#}', @PLACEHOLDERTARGETDBQUOTED NVARCHAR(32) = N'{#TARGETDB_Q#}', @PLACEHOLDERSOURCEDB NVARCHAR(32) = N'{#SOURCEDB#}', @PLACEHOLDERTARGETDB NVARCHAR(32) = N'{#TARGETDB#}', @PLACEHOLDERCOLLATION NVARCHAR(32) = N'{#COLLATION#}', @PLACEHOLDERTARGETCOLLATION NVARCHAR(32) = N'{#TARGET_COLLATION_NAME#}', @PLACEHOLDERSOURCECOLLATIONNAME NVARCHAR(32) = N'{#SOURCECOLLATION_NAME#}', @PLACEHOLDERTARGETCOLLATIONNAME NVARCHAR(32) = N'{#TARGETCOLLATION_NAME#}', @PLACEHOLDERDROPEXISTING NVARCHAR(32) = N'{#DROPEXISTING_FILTER#}', @DROPEXISTING_FILTER NVARCHAR(20) = CASE WHEN @DROPEXISTING = 1 THEN N'' ELSE N'AND 1=0' END, @SOURCEDATABASEQUOTED NVARCHAR(260) = QUOTENAME(@SOURCEDATABASE), @TARGETDATABASEQUOTED NVARCHAR(260) = QUOTENAME(@TARGETDATABASE), @SOURCECOLLATION NVARCHAR(128) = NULL, @TARGETCOLLATION NVARCHAR(128) = NULL, @SERVERCOLLATION NVARCHAR(128) = NULL, @COMPARECOLLATION NVARCHAR(200) = NULL, @DYNAMICSQL NVARCHAR(MAX) = NULL, @SERVERINFOMSG NVARCHAR(MAX) = NULL, @DELCLAUSE NVARCHAR(100) = NULL, @STEP INT = NULL, @PHASE NVARCHAR(50) = NULL, @COMMAND NVARCHAR(MAX) = NULL, @SEVERITY NVARCHAR(10) = 'INFO', @ERRMSG NVARCHAR(MAX) = NULL, @VALIDATION_PASSED BIT = 1, @VALIDATION_ERRORS INT = 0, @VALIDATION_WARNINGS INT = 0, @VALIDATION_SQL NVARCHAR(MAX) = NULL, @VALIDATION_CURSOR_SQL NVARCHAR(MAX) = NULL, @VALIDATION_SOURCE_COUNT INT = 0, @VALIDATION_TARGET_COUNT INT = 0, @VALIDATION_SOURCE_ROWS BIGINT = 0, @VALIDATION_TARGET_ROWS BIGINT = 0, @VALIDATION_SCHEMA_NAME NVARCHAR(128) = NULL, @VALIDATION_TABLE_NAME NVARCHAR(128) = NULL, @RETURN_STATUS INT = 0, @RETURN_STATUS_TEXT NVARCHAR(MAX) = N'START PROCEDURE [' + @MY_PROCEDURE_NAME + N'] @ ' + CONVERT(NVARCHAR(50),GETDATE(),120), -- Error output variables (used in execution loop) @ERRPOS INT = 1, @ERRCHUNK INT = 4000; ---------------------------------------------------------------------------------------------------------------------------- --=================================================-- Output parameters --================================================-- PRINT '===================================================================================================='; PRINT @RETURN_STATUS_TEXT; PRINT ''; PRINT 'PARAMETER01 - @pSOURCEDATABASE: ' + ISNULL(@SOURCEDATABASE,''); PRINT 'PARAMETER02 - @pTARGETDATABASE: ' + ISNULL(@TARGETDATABASE,''); PRINT 'PARAMETER03 - @pEXECUTE: ' + CONVERT(NVARCHAR(1),@EXECUTE); PRINT 'PARAMETER04 - @pEXCLUDEOBJECTS: ' + ISNULL(@EXCLUDEOBJECTS,''); PRINT 'PARAMETER05 - @pSYNCOBJECTS: ' + ISNULL(@SYNCOBJECTS,''); PRINT 'PARAMETER06 - @pLOGLEVEL: ' + ISNULL(@LOGLEVEL,''); PRINT 'PARAMETER07 - @pDEBUG: ' + CONVERT(NVARCHAR(1),@DEBUG); PRINT 'PARAMETER08 - @pINCLUDEDATA: ' + CONVERT(NVARCHAR(1),@INCLUDEDATA); PRINT 'PARAMETER09 - @pDELETEMISSING: ' + CONVERT(NVARCHAR(1),@DELETEMISSING); PRINT 'PARAMETER10 - @pSYNCSECURITY: ' + CONVERT(NVARCHAR(1),@SYNCSECURITY); PRINT 'PARAMETER11 - @pVALIDATION_MODE: ' + ISNULL(@VALIDATION_MODE,''); PRINT 'PARAMETER12 - @pBATCHSIZE: ' + CONVERT(NVARCHAR(10),@BATCHSIZE); PRINT 'PARAMETER13 - @pUSETRANSACTION: ' + CONVERT(NVARCHAR(1),@USETRANSACTION); PRINT 'PARAMETER14 - @pDROPEXISTING: ' + CONVERT(NVARCHAR(1),@DROPEXISTING); PRINT ''; ---------------------------------------------------------------------------------------------------------------------------- --=================================================-- Get server infos --==================================================-- SELECT @PRODUCTVERSION = SERVERPROPERTY('productversion'), @PRODUCTLEVEL = SERVERPROPERTY ('productlevel'), @PRODUCTEDITION = SERVERPROPERTY ('edition'); SELECT @MACHINENAME = SERVERPROPERTY('MachineName'), @INSTANCENAME = SERVERPROPERTY('InstanceName'); SELECT @SERVERNAME = SERVERPROPERTY('ServerName'); SELECT @COMPUTERNETBIOS = SERVERPROPERTY('ComputerNamePhysicalNetBIOS'); SET @PRODUCTMAINVERSION = ISNULL(LEFT(CONVERT(NVARCHAR(100),@PRODUCTVERSION), CHARINDEX('.', CONVERT(NVARCHAR(100),@PRODUCTVERSION)) - 1),0); -- SQL Server 2016+ required (version 13+) for STRING_SPLIT, HASHBYTES SHA2_256, etc. IF @PRODUCTMAINVERSION < 13 BEGIN RAISERROR('SQL Server 2016 or higher required (current version: %d)', 16, 1, @PRODUCTMAINVERSION); RETURN 1; END; -- Get Collations: Server, Source and Target (not DD_SYS!) SELECT @SERVERCOLLATION = CONVERT(NVARCHAR(128), SERVERPROPERTY('Collation')); DECLARE @COLLATION_SQL NVARCHAR(1000); SET @COLLATION_SQL = N'USE ' + @SOURCEDATABASEQUOTED + N'; SELECT @col = CONVERT(NVARCHAR(128), DATABASEPROPERTYEX(DB_NAME(), ''Collation''))'; EXEC sys.sp_executesql @COLLATION_SQL, N'@col NVARCHAR(128) OUTPUT', @SOURCECOLLATION OUTPUT; SET @COLLATION_SQL = N'USE ' + @TARGETDATABASEQUOTED + N'; SELECT @col = CONVERT(NVARCHAR(128), DATABASEPROPERTYEX(DB_NAME(), ''Collation''))'; EXEC sys.sp_executesql @COLLATION_SQL, N'@col NVARCHAR(128) OUTPUT', @TARGETCOLLATION OUTPUT; -- COMPARISONS: Use Source collation for cross-database object name comparisons -- NEW OBJECTS: Use Target collation for new columns (Target-DB defines collation) SET @COMPARECOLLATION = N' COLLATE ' + ISNULL(@SOURCECOLLATION, ISNULL(@SERVERCOLLATION, N'Latin1_General_CI_AS')); PRINT 'Informations about this Server:'; PRINT '@MYSESSIONID: ' + CONVERT(NVARCHAR(100),@MYSESSIONID); PRINT '@SERVERNAME: ' + CONVERT(NVARCHAR(100),@SERVERNAME); PRINT '@COMPUTERNETBIOS: ' + CONVERT(NVARCHAR(100),@COMPUTERNETBIOS); PRINT '@MACHINENAME: ' + CONVERT(NVARCHAR(100),@MACHINENAME); PRINT '@INSTANCENAME: ' + ISNULL(CONVERT(NVARCHAR(100),@INSTANCENAME), N''); PRINT '@PRODUCTVERSION: ' + CONVERT(NVARCHAR(100),@PRODUCTVERSION); PRINT '@PRODUCTMAINVERSION: ' + CONVERT(NVARCHAR(100),@PRODUCTMAINVERSION); PRINT '@PRODUCTLEVEL: ' + CONVERT(NVARCHAR(100),@PRODUCTLEVEL); PRINT '@PRODUCTEDITION: ' + CONVERT(NVARCHAR(100),@PRODUCTEDITION); PRINT ''; PRINT 'Collation Information:'; PRINT '@SERVERCOLLATION: ' + ISNULL(@SERVERCOLLATION, N''); PRINT '@SOURCECOLLATION: ' + ISNULL(@SOURCECOLLATION, N''); PRINT '@TARGETCOLLATION: ' + ISNULL(@TARGETCOLLATION, N'') + N' (used for new columns)'; PRINT '@COMPARECOLLATION: ' + ISNULL(@COMPARECOLLATION, N'') + N' (for object name comparisons)'; ---------------------------------------------------------------------------------------------------------------------------- --=================================================-- Logging-Tabelle im aktuellen Kontext sicherstellen --================================================-- IF @LOGLEVEL IS NOT NULL BEGIN IF EXISTS (SELECT * FROM [INFORMATION_SCHEMA].[TABLES] WHERE [TABLE_NAME] = N'TBDD_SYNC_DATABASE_LOG') BEGIN PRINT '[INFO] Log table already exists'; END ELSE BEGIN PRINT '[INFO] Log table does not exists, trying to create...'; CREATE TABLE [dbo].[TBDD_SYNC_DATABASE_LOG]( [LOG_ID] BIGINT IDENTITY(1,1) NOT NULL, [LOG_LEVEL] NVARCHAR(10) NOT NULL, [MESSAGE1] NVARCHAR(MAX) NULL, [MESSAGE2] NVARCHAR(MAX) NULL, [MESSAGE3] NVARCHAR(MAX) NULL, [ADDED_WHO] SYSNAME NOT NULL CONSTRAINT [DF_TBDD_SYNC_DATABASE_LOG_ADDED_WHO] DEFAULT (SUSER_SNAME()), [ADDED_WHEN] DATETIME2(0) NOT NULL CONSTRAINT [DF_TBDD_SYNC_DATABASE_LOG_ADDED_WHEN] DEFAULT (GETDATE()), CONSTRAINT [PK_TBDD_SYNC_DATABASE_LOG_LOGID] PRIMARY KEY CLUSTERED ( [LOG_ID] ASC ) WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, DATA_COMPRESSION = PAGE) ON [PRIMARY] ) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]; END; END ELSE BEGIN PRINT ''; PRINT '[WARN] Skipping Logging to log table!'; END; ----------------------------------------------------------------------------------------------------------------------------- --=================================================-- Log server infos to table --================================================-- IF @LOGLEVEL IS NOT NULL BEGIN SET @SERVERINFOMSG = N'ServerInfo: ServerName=' + CONVERT(NVARCHAR(100),@SERVERNAME) + N'; ComputerNetBIOS=' + CONVERT(NVARCHAR(100),@COMPUTERNETBIOS) + N'; Machine=' + CONVERT(NVARCHAR(100),@MACHINENAME) + N'; Instance=' + ISNULL(CONVERT(NVARCHAR(100),@INSTANCENAME),N'') + N'; Version=' + CONVERT(NVARCHAR(100),@PRODUCTVERSION) + N'; MainVersion=' + CONVERT(NVARCHAR(100),@PRODUCTMAINVERSION) + N'; Level=' + CONVERT(NVARCHAR(100),@PRODUCTLEVEL) + N'; Edition=' + CONVERT(NVARCHAR(100),@PRODUCTEDITION) + N'; SessionID=' + CONVERT(NVARCHAR(100),@MYSESSIONID); --================================================-- Log server info to table --=================================================-- IF (UPPER(@LOGLEVEL) IN (N'INFO',N'WARN',N'ERROR')) BEGIN INSERT INTO [TBDD_SYNC_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [ADDED_WHO], [ADDED_WHEN]) VALUES ('INFO', '00-Server', CONVERT(NVARCHAR(MAX),@SERVERNAME), @SERVERINFOMSG, @MY_PROCEDURE_NAME, GETDATE()); END; ----------------------------------------------------------------------------------------------------------------------------- END; ----------------------------------------------------------------------------------------------------------------------------- IF @SOURCEDATABASE IS NULL OR DB_ID(@SOURCEDATABASE) IS NULL BEGIN RAISERROR('Source database invalid/missing',16,1); RETURN 1; END; IF @TARGETDATABASE IS NULL OR DB_ID(@TARGETDATABASE) IS NULL BEGIN RAISERROR('Target database must exist',16,1); RETURN 1; END; IF @SOURCEDATABASE = @TARGETDATABASE BEGIN RAISERROR('Source and target must differ',16,1); RETURN 1; END; -- Check if databases are online (uses state instead of state_desc for performance) IF EXISTS (SELECT 1 FROM sys.databases WHERE name = @SOURCEDATABASE AND state <> 0) BEGIN RAISERROR('Source database is not online (state <> 0)',16,1); RETURN 1; END; IF EXISTS (SELECT 1 FROM sys.databases WHERE name = @TARGETDATABASE AND state <> 0) BEGIN RAISERROR('Target database is not online (state <> 0)',16,1); RETURN 1; END; IF @DEBUG = 1 PRINT '[DEBUG] Validating @LOGLEVEL: ' + ISNULL(@LOGLEVEL, ''); IF @LOGLEVEL IS NOT NULL AND UPPER(@LOGLEVEL) NOT IN (N'INFO',N'WARN',N'ERROR') BEGIN RAISERROR('Invalid @pLOGLEVEL',16,1); RETURN 1; END; IF @DEBUG = 1 PRINT '[DEBUG] Validating @VALIDATION_MODE: ' + ISNULL(@VALIDATION_MODE, ''); -- VALIDATION_MODE is already validated in line 101-104 and set to default -- @SYNCOBJECTS Info-Ausgabe PRINT '[INFO] Object types to sync: ' + @SYNCOBJECTS; PRINT '[INFO] Sync flags: SCHEMAS=' + CONVERT(NVARCHAR(1), @SYNC_SCHEMAS) + ', TABLES=' + CONVERT(NVARCHAR(1), @SYNC_TABLES) + ', VIEWS=' + CONVERT(NVARCHAR(1), @SYNC_VIEWS) + ', PROCEDURES=' + CONVERT(NVARCHAR(1), @SYNC_PROCEDURES) + ', FUNCTIONS=' + CONVERT(NVARCHAR(1), @SYNC_FUNCTIONS) + ', TRIGGERS=' + CONVERT(NVARCHAR(1), @SYNC_TRIGGERS) + ', INDEXES=' + CONVERT(NVARCHAR(1), @SYNC_INDEXES) + ', SYNONYMS=' + CONVERT(NVARCHAR(1), @SYNC_SYNONYMS) + ', SEQUENCES=' + CONVERT(NVARCHAR(1), @SYNC_SEQUENCES); -- Warnings for potentially problematic combinations IF @SYNC_INDEXES = 1 AND @SYNC_TABLES = 0 BEGIN PRINT '[WARN] INDEXES enabled without TABLES - indexes may reference non-existing tables'; END; IF @SYNC_VIEWS = 1 AND @SYNC_TABLES = 0 BEGIN PRINT '[WARN] VIEWS enabled without TABLES - views may reference non-existing tables'; END; IF @SYNC_TRIGGERS = 1 AND @SYNC_TABLES = 0 BEGIN PRINT '[WARN] TRIGGERS enabled without TABLES - triggers may reference non-existing tables'; END; IF @VALIDATION_MODE IN (N'DATA', N'ALL') AND @SYNC_TABLES = 0 BEGIN PRINT '[WARN] Data validation requested but TABLES sync is disabled'; END; IF @INCLUDEDATA = 1 AND @SYNC_TABLES = 0 BEGIN PRINT '[WARN] @pINCLUDEDATA=1 but TABLES sync is disabled - data sync will be limited'; END; IF @DEBUG = 1 PRINT '[DEBUG] All validations passed'; -- Security #17: Extended permission check for DDL operations IF @EXECUTE = 1 BEGIN IF HAS_PERMS_BY_NAME(@TARGETDATABASE, 'DATABASE', 'ALTER') = 0 BEGIN RAISERROR('Insufficient permissions: ALTER permission required on target database',16,1); RETURN 1; END; IF HAS_PERMS_BY_NAME(@TARGETDATABASE, 'DATABASE', 'CREATE TABLE') = 0 BEGIN RAISERROR('Insufficient permissions: CREATE TABLE permission required on target database',16,1); RETURN 1; END; IF HAS_PERMS_BY_NAME(@SOURCEDATABASE, 'DATABASE', 'VIEW DEFINITION') = 0 BEGIN RAISERROR('Insufficient permissions: VIEW DEFINITION permission required on source database',16,1); RETURN 1; END; END; IF @DEBUG = 1 PRINT '[DEBUG] Permissions validated'; --===============================================-- Log result to table --=================================================-- IF @DEBUG = 1 PRINT '[DEBUG] Logging to table...'; IF UPPER(@LOGLEVEL) IN (N'INFO',N'WARN',N'ERROR') BEGIN INSERT INTO [TBDD_SYNC_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [ADDED_WHO], [ADDED_WHEN]) VALUES ('INFO', '01-Validation', 'Parametern validiert', 'Source: '+@SOURCEDATABASE+', Target: '+@TARGETDATABASE, @MY_PROCEDURE_NAME, GETDATE()); END; IF @DEBUG = 1 PRINT '[DEBUG] Log entry created successfully'; ----------------------------------------------------------------------------------------------------------------------------- -- Prepare excludes IF @DEBUG = 1 PRINT '[DEBUG] Creating excludes temp table...'; -- Create temp table with SERVER collation (use COLLATE in queries) -- Line removed CREATE TABLE #TBDD_SYNC_DATABASE_EXCLUDEDOBJECTS(Pattern NVARCHAR(256) NOT NULL, IsWildcard BIT NOT NULL DEFAULT 0); CREATE NONCLUSTERED INDEX IX_Pattern ON #TBDD_SYNC_DATABASE_EXCLUDEDOBJECTS(Pattern, IsWildcard); CREATE NONCLUSTERED INDEX IX_IsWildcard_Pattern ON #TBDD_SYNC_DATABASE_EXCLUDEDOBJECTS(IsWildcard, Pattern); -- #7: Performance-Index IF @DEBUG = 1 PRINT '[DEBUG] Excludes temp table created'; IF @EXCLUDEOBJECTS IS NOT NULL BEGIN IF @DEBUG = 1 PRINT '[DEBUG] Processing EXCLUDEOBJECTS...'; INSERT INTO #TBDD_SYNC_DATABASE_EXCLUDEDOBJECTS(Pattern, IsWildcard) SELECT TOP (@CONST_MAX_EXCLUDES) -- Limit to max patterns (overflow protection) REPLACE(LTRIM(RTRIM(value)), N'*', N'%'), CASE WHEN value LIKE '%*%' THEN 1 ELSE 0 END FROM STRING_SPLIT(@EXCLUDEOBJECTS, N',') WHERE LTRIM(RTRIM(value))<>N''; DECLARE @INSERTED_EXCLUDES INT = @@ROWCOUNT; IF @DEBUG = 1 PRINT '[DEBUG] EXCLUDEOBJECTS processed, count: ' + CONVERT(NVARCHAR(10), @INSERTED_EXCLUDES); -- Warning if limit reached IF @INSERTED_EXCLUDES >= @CONST_MAX_EXCLUDES BEGIN PRINT '[WARN] EXCLUDEOBJECTS limit reached (' + CONVERT(NVARCHAR(10), @CONST_MAX_EXCLUDES) + '). Additional patterns ignored!'; END; END; --===============================================-- Log result to table --=================================================-- IF @DEBUG = 1 PRINT '[DEBUG] Counting excludes...'; DECLARE @EXCLUDECOUNT INT = (SELECT COUNT(*) FROM #TBDD_SYNC_DATABASE_EXCLUDEDOBJECTS); IF (UPPER(@LOGLEVEL) IN (N'INFO',N'WARN',N'ERROR')) BEGIN INSERT INTO [TBDD_SYNC_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [ADDED_WHO], [ADDED_WHEN]) VALUES ('INFO', '02-Preparation', 'Temp-Tabellen erstellt', 'Excludes: '+CONVERT(NVARCHAR(10),@EXCLUDECOUNT), @MY_PROCEDURE_NAME, GETDATE()); END; ----------------------------------------------------------------------------------------------------------------------------- -- Commands temp table erstellen (Phase with server collation) -- Line removed CREATE TABLE #TBDD_SYNC_DATABASE_COMMANDS(Step INT IDENTITY(1,1) NOT NULL, Phase NVARCHAR(50) NOT NULL, Command NVARCHAR(MAX) NOT NULL, CONSTRAINT PK_Commands PRIMARY KEY CLUSTERED (Step)); CREATE NONCLUSTERED INDEX IX_Phase ON #TBDD_SYNC_DATABASE_COMMANDS(Phase) INCLUDE(Step); IF @DEBUG = 1 PRINT '[DEBUG] Commands temp table created'; --=================================================-- Security Sync (optional) --==================================================-- IF @DEBUG = 1 PRINT '[DEBUG] Checking @SYNCSECURITY: ' + CONVERT(NVARCHAR(1), @SYNCSECURITY); IF @SYNCSECURITY = 1 BEGIN IF @DEBUG = 1 PRINT '[DEBUG] Security sync is enabled'; --===============================================-- Log result to table --=================================================-- IF (UPPER(@LOGLEVEL) IN (N'INFO',N'WARN',N'ERROR')) BEGIN INSERT INTO [TBDD_SYNC_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [ADDED_WHO], [ADDED_WHEN]) VALUES ('INFO', '03-Security', 'Security-Sync aktiviert', 'Sync Rollen, Benutzer, Grants', @MY_PROCEDURE_NAME, GETDATE()); END; ----------------------------------------------------------------------------------------------------------------------------- -- Rollen anlegen SET @DYNAMICSQL = N' INSERT INTO #TBDD_SYNC_DATABASE_COMMANDS(Phase, Command) SELECT * FROM ( SELECT N''01-Security-Roles'', N''USE {#TARGETDB_Q#}; IF NOT EXISTS (SELECT 1 FROM sys.database_principals WHERE name=N'''''' + REPLACE(r.name, '''''''', '''''''''''') + N'''''' AND type=''''R'''') CREATE ROLE ''+QUOTENAME(r.name)+N'';'' FROM {#SOURCEDB_Q#}.sys.database_principals r WHERE r.type=''R'' AND ISNULL(r.is_fixed_role,0)=0 AND r.name{#COLLATION#} NOT IN (N''public'')) AS X(Phase, Command) WHERE X.Command IS NOT NULL AND LEN(X.Command)>0;' SET @DYNAMICSQL = REPLACE(REPLACE(REPLACE(@DYNAMICSQL, @PLACEHOLDERSOURCEDBQUOTED, @SOURCEDATABASEQUOTED), @PLACEHOLDERTARGETDBQUOTED, @TARGETDATABASEQUOTED), @PLACEHOLDERCOLLATION, @COMPARECOLLATION); BEGIN TRY EXEC sys.sp_executesql @DYNAMICSQL; IF @DEBUG = 1 PRINT '[DEBUG] Security-Roles commands built successfully'; END TRY BEGIN CATCH PRINT '[ERROR] Failed to build Security-Roles commands!'; PRINT '[ERROR] Error Message: ' + ERROR_MESSAGE(); PRINT '[ERROR] Dynamic SQL (first 8000 chars):'; PRINT SUBSTRING(@DYNAMICSQL, 1, 8000); IF LEN(@DYNAMICSQL) > 8000 PRINT '[ERROR] (continued): ' + SUBSTRING(@DYNAMICSQL, 8001, 8000); THROW; END CATCH; -- Benutzer anlegen (nur wenn Login existiert) SET @DYNAMICSQL = N' INSERT INTO #TBDD_SYNC_DATABASE_COMMANDS(Phase, Command) SELECT * FROM ( SELECT N''01-Security-Users'', N''USE {#TARGETDB_Q#}; IF (EXISTS (SELECT 1 FROM sys.server_principals WHERE name=N'''''' + REPLACE(dp.name, '''''''', '''''''''''') + N'''''' ) AND NOT EXISTS (SELECT 1 FROM sys.database_principals WHERE name=N'''''' + REPLACE(dp.name, '''''''', '''''''''''') + N'''''' )) BEGIN CREATE USER ''+QUOTENAME(dp.name)+N'' FOR LOGIN ''+QUOTENAME(dp.name)+N'' WITH DEFAULT_SCHEMA='' + QUOTENAME(ISNULL(dp.default_schema_name,N''dbo'')) + N''; END'' FROM {#SOURCEDB_Q#}.sys.database_principals dp WHERE dp.type IN (''S'',''U'') AND dp.name{#COLLATION#} NOT IN (N''dbo'',N''guest'',N''INFORMATION_SCHEMA'',N''sys'',N''public'')) AS X(Phase, Command) WHERE X.Command IS NOT NULL AND LEN(X.Command)>0;'; SET @DYNAMICSQL = REPLACE(REPLACE(REPLACE(@DYNAMICSQL, @PLACEHOLDERSOURCEDBQUOTED, @SOURCEDATABASEQUOTED), @PLACEHOLDERTARGETDBQUOTED, @TARGETDATABASEQUOTED), @PLACEHOLDERCOLLATION, @COMPARECOLLATION); BEGIN TRY EXEC sys.sp_executesql @DYNAMICSQL; IF @DEBUG = 1 PRINT '[DEBUG] Security-Users commands built successfully'; END TRY BEGIN CATCH PRINT '[ERROR] Failed to build Security-Users commands!'; PRINT '[ERROR] Error Message: ' + ERROR_MESSAGE(); PRINT '[ERROR] Dynamic SQL (first 8000 chars):'; PRINT SUBSTRING(@DYNAMICSQL, 1, 8000); IF LEN(@DYNAMICSQL) > 8000 PRINT '[ERROR] (continued): ' + SUBSTRING(@DYNAMICSQL, 8001, 8000); THROW; END CATCH; -- Rollenmitgliedschaften angleichen SET @DYNAMICSQL = N' INSERT INTO #TBDD_SYNC_DATABASE_COMMANDS(Phase, Command) SELECT * FROM ( SELECT N''01-Security-RoleMembers'', N''USE {#TARGETDB_Q#}; IF (EXISTS (SELECT 1 FROM sys.database_principals WHERE name=N'''''' + REPLACE(r.name, '''''''', '''''''''''') + N'''''' AND type=''''R'''') AND EXISTS (SELECT 1 FROM sys.database_principals WHERE name=N'''''' + REPLACE(m.name, '''''''', '''''''''''') + N'''''' ) AND NOT EXISTS (SELECT 1 FROM sys.database_role_members drm JOIN sys.database_principals rp ON rp.principal_id=drm.role_principal_id JOIN sys.database_principals mp ON mp.principal_id=drm.member_principal_id WHERE rp.name=N'''''' + REPLACE(r.name, '''''''', '''''''''''') + N'''''' AND mp.name=N'''''' + REPLACE(m.name, '''''''', '''''''''''') + N'''''' )) BEGIN ALTER ROLE ''+QUOTENAME(r.name)+N'' ADD MEMBER ''+QUOTENAME(m.name)+N''; END'' FROM {#SOURCEDB_Q#}.sys.database_role_members drm JOIN {#SOURCEDB_Q#}.sys.database_principals r ON r.principal_id=drm.role_principal_id JOIN {#SOURCEDB_Q#}.sys.database_principals m ON m.principal_id=drm.member_principal_id WHERE r.name{#COLLATION#} NOT IN (N''public'') AND m.name{#COLLATION#} NOT IN (N''dbo'',N''guest'',N''INFORMATION_SCHEMA'',N''sys'',N''public'')) AS X(Phase, Command) WHERE X.Command IS NOT NULL AND LEN(X.Command)>0;'; SET @DYNAMICSQL = REPLACE(REPLACE(REPLACE(@DYNAMICSQL, @PLACEHOLDERSOURCEDBQUOTED, @SOURCEDATABASEQUOTED), @PLACEHOLDERTARGETDBQUOTED, @TARGETDATABASEQUOTED), @PLACEHOLDERCOLLATION, @COMPARECOLLATION); BEGIN TRY EXEC sys.sp_executesql @DYNAMICSQL; IF @DEBUG = 1 PRINT '[DEBUG] Security-RoleMembers commands built successfully'; END TRY BEGIN CATCH PRINT '[ERROR] Failed to build Security-RoleMembers commands!'; PRINT '[ERROR] Error Message: ' + ERROR_MESSAGE(); PRINT '[ERROR] Dynamic SQL (first 8000 chars):'; PRINT SUBSTRING(@DYNAMICSQL, 1, 8000); IF LEN(@DYNAMICSQL) > 8000 PRINT '[ERROR] (continued): ' + SUBSTRING(@DYNAMICSQL, 8001, 8000); THROW; END CATCH; -- Database-/Schema-/Objekt-/Spalten-Grants (GRANT/DENY) nur wenn im Target nicht vorhanden oder anderes state SET @DYNAMICSQL = N' INSERT INTO #TBDD_SYNC_DATABASE_COMMANDS(Phase, Command) SELECT N''01-Security-Grants'', N''USE {#TARGETDB_Q#}; '' + CASE dp.state_desc WHEN ''DENY'' THEN N''DENY '' WHEN ''GRANT_WITH_GRANT_OPTION'' THEN N''GRANT '' ELSE N''GRANT '' END + dp.permission_name + CASE dp.class WHEN 0 THEN N'' TO ''+QUOTENAME(pr.name) WHEN 3 THEN N'' ON SCHEMA::''+QUOTENAME(s.name)+N'' TO ''+QUOTENAME(pr.name) WHEN 4 THEN N'' ON OBJECT::''+QUOTENAME(sc.name)+N''.''{#COLLATION#}+QUOTENAME(obj.name)+N'' (''+QUOTENAME(col.name)+N'') TO ''+QUOTENAME(pr.name) ELSE N'' ON ''+QUOTENAME(sc.name)+N''.''{#COLLATION#}+QUOTENAME(obj.name)+N'' TO ''+QUOTENAME(pr.name) END + CASE WHEN dp.state_desc=''GRANT_WITH_GRANT_OPTION'' THEN N'' WITH GRANT OPTION'' ELSE N'''' END + N'';'' FROM {#SOURCEDB_Q#}.sys.database_permissions dp JOIN {#SOURCEDB_Q#}.sys.database_principals pr ON pr.principal_id=dp.grantee_principal_id LEFT JOIN {#SOURCEDB_Q#}.sys.objects obj ON obj.object_id=dp.major_id LEFT JOIN {#SOURCEDB_Q#}.sys.schemas sc ON sc.schema_id=obj.schema_id LEFT JOIN {#SOURCEDB_Q#}.sys.schemas s ON s.schema_id=dp.major_id AND dp.class=3 LEFT JOIN {#SOURCEDB_Q#}.sys.columns col ON col.object_id=dp.major_id AND dp.class=4 AND col.column_id=dp.minor_id LEFT JOIN {#TARGETDB_Q#}.sys.database_principals tpr ON tpr.name{#COLLATION#}=pr.name{#COLLATION#} LEFT JOIN {#TARGETDB_Q#}.sys.schemas tsc ON tsc.name{#COLLATION#}=sc.name{#COLLATION#} LEFT JOIN {#TARGETDB_Q#}.sys.objects tobj ON tobj.name{#COLLATION#}=obj.name{#COLLATION#} AND tobj.schema_id=tsc.schema_id LEFT JOIN {#TARGETDB_Q#}.sys.columns tcol ON tcol.object_id=tobj.object_id AND tcol.name{#COLLATION#}=col.name{#COLLATION#} LEFT JOIN {#TARGETDB_Q#}.sys.database_permissions tdp ON tdp.grantee_principal_id=tpr.principal_id AND tdp.permission_name{#COLLATION#}=dp.permission_name{#COLLATION#} AND tdp.class=dp.class AND ISNULL(tdp.state_desc,N''''){#COLLATION#}=ISNULL(dp.state_desc,N''''){#COLLATION#} AND ( (dp.class=0 AND tdp.major_id=0) OR (dp.class=3 AND tdp.major_id=tsc.schema_id) OR (dp.class=1 AND tdp.major_id=tobj.object_id) OR (dp.class=4 AND tdp.major_id=tobj.object_id AND tdp.minor_id=tcol.column_id) ) WHERE pr.name{#COLLATION#} NOT IN (N''dbo'',N''guest'',N''INFORMATION_SCHEMA'',N''sys'',N''public'') AND dp.permission_name NOT IN (N''CONTROL'') AND dp.state_desc IN (''GRANT'',''GRANT_WITH_GRANT_OPTION'',''DENY'') AND tdp.major_id IS NULL;'; SET @DYNAMICSQL = REPLACE(REPLACE(REPLACE(@DYNAMICSQL, @PLACEHOLDERSOURCEDBQUOTED, @SOURCEDATABASEQUOTED), @PLACEHOLDERTARGETDBQUOTED, @TARGETDATABASEQUOTED), @PLACEHOLDERCOLLATION, @COMPARECOLLATION); IF @DEBUG=1 BEGIN DECLARE @DbgPos INT = 1, @DbgChunk INT = 4000; PRINT '===== DEBUG Security-Grants DynamicSql (length: ' + CONVERT(NVARCHAR(10), LEN(@DYNAMICSQL)) + '):'; WHILE @DbgPos <= LEN(@DYNAMICSQL) BEGIN PRINT SUBSTRING(@DYNAMICSQL, @DbgPos, @DbgChunk); SET @DbgPos = @DbgPos + @DbgChunk; END; END; BEGIN TRY EXEC sys.sp_executesql @DYNAMICSQL; IF @DEBUG = 1 PRINT '[DEBUG] Security-Grants commands built successfully'; END TRY BEGIN CATCH PRINT '[ERROR] Failed to build Security-Grants commands!'; PRINT '[ERROR] Error Message: ' + ERROR_MESSAGE(); PRINT '[ERROR] Dynamic SQL (first 8000 chars):'; PRINT SUBSTRING(@DYNAMICSQL, 1, 8000); IF LEN(@DYNAMICSQL) > 8000 PRINT '[ERROR] (continued): ' + SUBSTRING(@DYNAMICSQL, 8001, 8000); THROW; END CATCH; END; ----------------------------------------------------------------------------------------------------------------------------- --=================================================-- Schemas (nur anlegen wenn fehlend) --================================================-- IF @SYNC_SCHEMAS = 1 BEGIN IF @DEBUG = 1 PRINT '[DEBUG] Building Schemas commands...'; SET @DYNAMICSQL = N' INSERT INTO #TBDD_SYNC_DATABASE_COMMANDS(Phase, Command) SELECT N''02-Schemas'', N''USE {#TARGETDB_Q#}; IF NOT EXISTS (SELECT 1 FROM sys.schemas WHERE name = N'''''' + REPLACE(s.name, '''''''', '''''''''''') + N'''''' ) BEGIN EXEC(N''''CREATE SCHEMA '' + QUOTENAME(s.name) + N'';''''); END;'' FROM {#SOURCEDB_Q#}.sys.schemas s WHERE s.name{#COLLATION#} NOT IN (N''sys'',N''INFORMATION_SCHEMA'',N''dbo'',N''guest'',N''db_owner'',N''db_accessadmin'',N''db_securityadmin'',N''db_ddladmin'',N''db_backupoperator'',N''db_datareader'',N''db_datawriter'',N''db_denydatareader'',N''db_denydatawriter'') AND NOT EXISTS (SELECT 1 FROM #TBDD_SYNC_DATABASE_EXCLUDEDOBJECTS ex WHERE (ex.IsWildcard=1 AND s.name{#COLLATION#} LIKE ex.Pattern{#COLLATION#}) OR (ex.IsWildcard=0 AND s.name{#COLLATION#}=ex.Pattern{#COLLATION#}));'; SET @DYNAMICSQL = REPLACE(REPLACE(REPLACE(@DYNAMICSQL, @PLACEHOLDERSOURCEDBQUOTED, @SOURCEDATABASEQUOTED), @PLACEHOLDERTARGETDBQUOTED, @TARGETDATABASEQUOTED), @PLACEHOLDERCOLLATION, @COMPARECOLLATION); BEGIN TRY EXEC sys.sp_executesql @DYNAMICSQL; IF @DEBUG = 1 PRINT '[DEBUG] Schemas commands built successfully'; END TRY BEGIN CATCH PRINT '[ERROR] Failed to build Schemas commands!'; PRINT '[ERROR] Error Message: ' + ERROR_MESSAGE(); PRINT '[ERROR] Dynamic SQL (first 8000 chars):'; PRINT SUBSTRING(@DYNAMICSQL, 1, 8000); IF LEN(@DYNAMICSQL) > 8000 PRINT '[ERROR] (continued): ' + SUBSTRING(@DYNAMICSQL, 8001, 8000); THROW; END CATCH; END ELSE PRINT '[INFO] Skipping Schemas (disabled by @pSYNCOBJECTS)'; ----------------------------------------------------------------------------------------------------------------------------- --=================================================-- Tables anlegen (fehlend) --================================================-- IF @SYNC_TABLES = 1 BEGIN IF @DEBUG = 1 PRINT '[DEBUG] Building Tables commands...'; SET @DYNAMICSQL = N' INSERT INTO #TBDD_SYNC_DATABASE_COMMANDS(Phase, Command) SELECT N''03-Tables'', CASE WHEN tgt.object_id IS NULL THEN N''USE {#TARGETDB_Q#}; CREATE TABLE '' + QUOTENAME(sc.name) + N''.'' + QUOTENAME(t.name) + N''('' + STUFF(( SELECT N'','' + CHAR(10) + N'' '' + CASE WHEN c.is_computed = 1 THEN QUOTENAME(c.name) + N'' AS '' + cc.definition + CASE WHEN cc.is_persisted=1 THEN N'' PERSISTED'' ELSE N'''' END ELSE QUOTENAME(c.name) + N'' '' + CASE WHEN ty.is_user_defined=1 THEN QUOTENAME(tys.name) + N''.'' + QUOTENAME(ty.name) WHEN ty.name{#COLLATION#} IN (N''varchar'',N''char'',N''varbinary'',N''binary'') THEN ty.name + N''('' + CASE WHEN c.max_length=-1 THEN N''max'' ELSE CONVERT(nvarchar(10), c.max_length) END + N'')'' WHEN ty.name{#COLLATION#} IN (N''nvarchar'',N''nchar'') THEN ty.name + N''('' + CASE WHEN c.max_length=-1 THEN N''max'' ELSE CONVERT(nvarchar(10), c.max_length/2) END + N'')'' WHEN ty.name{#COLLATION#} IN (N''decimal'',N''numeric'') THEN ty.name + N''('' + CONVERT(nvarchar(10), c.precision) + N'','' + CONVERT(nvarchar(10), c.scale) + N'')'' WHEN ty.name{#COLLATION#} IN (N''datetime2'',N''datetimeoffset'',N''time'') THEN ty.name + N''('' + CONVERT(nvarchar(10), c.scale) + N'')'' ELSE ty.name END + CASE WHEN ty.is_user_defined=0 AND ty.name{#COLLATION#} IN (N''char'',N''varchar'',N''nchar'',N''nvarchar'',N''text'',N''ntext'') THEN N'' COLLATE {#TARGET_COLLATION_NAME#}'' ELSE N'''' END + CASE WHEN ic.object_id IS NOT NULL THEN N'' IDENTITY('' + CONVERT(nvarchar(30), ic.seed_value) + N'','' + CONVERT(nvarchar(30), ic.increment_value) + N'')'' ELSE N'''' END + CASE WHEN c.is_nullable=1 THEN N'' NULL'' ELSE N'' NOT NULL'' END END FROM {#SOURCEDB_Q#}.sys.columns c LEFT JOIN {#SOURCEDB_Q#}.sys.identity_columns ic ON ic.object_id=c.object_id AND ic.column_id=c.column_id LEFT JOIN {#SOURCEDB_Q#}.sys.computed_columns cc ON cc.object_id=c.object_id AND cc.column_id=c.column_id JOIN {#SOURCEDB_Q#}.sys.types ty ON ty.user_type_id=c.user_type_id LEFT JOIN {#SOURCEDB_Q#}.sys.schemas tys ON tys.schema_id=ty.schema_id WHERE c.object_id=t.object_id ORDER BY c.column_id FOR XML PATH(''''), TYPE).value(''.'', ''nvarchar(max)''),1,2,N'''') + N'' );'' ELSE N''-- Table structure differs: '' + QUOTENAME(sc.name) + N''.'' + QUOTENAME(t.name) + N'' (manual review required)'' END FROM {#SOURCEDB_Q#}.sys.tables t JOIN {#SOURCEDB_Q#}.sys.schemas sc ON sc.schema_id=t.schema_id LEFT JOIN {#TARGETDB_Q#}.sys.schemas tsc ON tsc.name{#COLLATION#}=sc.name{#COLLATION#} LEFT JOIN {#TARGETDB_Q#}.sys.tables tt ON tt.name{#COLLATION#}=t.name{#COLLATION#} AND tt.schema_id = tsc.schema_id LEFT JOIN {#TARGETDB_Q#}.sys.objects tgt ON tgt.object_id = tt.object_id WHERE sc.name{#COLLATION#}<>N''sys''{#COLLATION#} AND t.is_ms_shipped=0 AND NOT EXISTS (SELECT 1 FROM #TBDD_SYNC_DATABASE_EXCLUDEDOBJECTS ex WHERE (ex.IsWildcard=1 AND (t.name{#COLLATION#} LIKE ex.Pattern{#COLLATION#} OR (sc.name + N''.'' + t.name){#COLLATION#} LIKE ex.Pattern{#COLLATION#})) OR (ex.IsWildcard=0 AND (t.name{#COLLATION#}=ex.Pattern{#COLLATION#} OR (sc.name + N''.'' + t.name){#COLLATION#}=ex.Pattern{#COLLATION#})));'; SET @DYNAMICSQL = REPLACE(REPLACE(REPLACE(@DYNAMICSQL, @PLACEHOLDERSOURCEDBQUOTED, @SOURCEDATABASEQUOTED), @PLACEHOLDERTARGETDBQUOTED, @TARGETDATABASEQUOTED), @PLACEHOLDERCOLLATION, @COMPARECOLLATION); SET @DYNAMICSQL = REPLACE(REPLACE(@DYNAMICSQL, @PLACEHOLDERSOURCEDB, @SOURCEDATABASE), @PLACEHOLDERTARGETDB, @TARGETDATABASE); SET @DYNAMICSQL = REPLACE(@DYNAMICSQL, @PLACEHOLDERTARGETCOLLATION, @TARGETCOLLATION); BEGIN TRY EXEC sys.sp_executesql @DYNAMICSQL; IF @DEBUG = 1 PRINT '[DEBUG] Tables commands executed successfully'; END TRY BEGIN CATCH PRINT '[ERROR] Failed to execute Tables command!'; PRINT '[ERROR] Error Message: ' + ERROR_MESSAGE(); PRINT '[ERROR] Error Line: ' + CONVERT(NVARCHAR(10), ERROR_LINE()); PRINT '[ERROR] Dynamic SQL (first 8000 chars):'; PRINT SUBSTRING(@DYNAMICSQL, 1, 8000); IF LEN(@DYNAMICSQL) > 8000 BEGIN PRINT '[ERROR] Dynamic SQL (continuation):'; PRINT SUBSTRING(@DYNAMICSQL, 8001, 8000); END; THROW; END CATCH; ----------------------------------------------------------------------------------------------------------------------------- --=================================================-- Tabellen-ALTER: fehlende Spalten anlegen --================================================-- SET @DYNAMICSQL = N' INSERT INTO #TBDD_SYNC_DATABASE_COMMANDS(Phase, Command) SELECT N''03-Table-AddColumns'', N''USE {#TARGETDB_Q#}; ALTER TABLE ''+QUOTENAME(sc.name)+N''.''{#COLLATION#}+QUOTENAME(t.name)+N'' ADD ''+ CASE WHEN c.is_computed=1 THEN QUOTENAME(c.name) + N'' AS '' + cc.definition + CASE WHEN cc.is_persisted=1 THEN N'' PERSISTED'' ELSE N'''' END ELSE QUOTENAME(c.name) + N'' '' + CASE WHEN ty.is_user_defined=1 THEN QUOTENAME(tys.name) + N''.'' + QUOTENAME(ty.name) WHEN ty.name{#COLLATION#} IN (N''varchar'',N''char'',N''varbinary'',N''binary'') THEN ty.name + N''('' + CASE WHEN c.max_length=-1 THEN N''max'' ELSE CONVERT(nvarchar(10), c.max_length) END + N'')'' WHEN ty.name{#COLLATION#} IN (N''nvarchar'',N''nchar'') THEN ty.name + N''('' + CASE WHEN c.max_length=-1 THEN N''max'' ELSE CONVERT(nvarchar(10), c.max_length/2) END + N'')'' WHEN ty.name{#COLLATION#} IN (N''decimal'',N''numeric'') THEN ty.name + N''('' + CONVERT(nvarchar(10), c.precision) + N'','' + CONVERT(nvarchar(10), c.scale) + N'')'' WHEN ty.name{#COLLATION#} IN (N''datetime2'',N''datetimeoffset'',N''time'') THEN ty.name + N''('' + CONVERT(nvarchar(10), c.scale) + N'')'' ELSE ty.name END + CASE WHEN ty.is_user_defined=0 AND ty.name{#COLLATION#} IN (N''char'',N''varchar'',N''nchar'',N''nvarchar'',N''text'',N''ntext'') THEN N'' COLLATE {#TARGET_COLLATION_NAME#}'' ELSE N'''' END + CASE WHEN c.is_sparse=1 THEN N'' SPARSE'' ELSE N'''' END + CASE WHEN ic.object_id IS NOT NULL THEN N'' IDENTITY('' + CONVERT(nvarchar(30), ic.seed_value) + N'','' + CONVERT(nvarchar(30), ic.increment_value) + N'')'' ELSE N'''' END + CASE WHEN c.is_nullable=1 THEN N'' NULL'' ELSE N'' NOT NULL'' END END FROM {#SOURCEDB_Q#}.sys.tables t JOIN {#SOURCEDB_Q#}.sys.schemas sc ON sc.schema_id=t.schema_id JOIN {#SOURCEDB_Q#}.sys.columns c ON c.object_id=t.object_id LEFT JOIN {#SOURCEDB_Q#}.sys.identity_columns ic ON ic.object_id=c.object_id AND ic.column_id=c.column_id LEFT JOIN {#SOURCEDB_Q#}.sys.computed_columns cc ON cc.object_id=c.object_id AND cc.column_id=c.column_id JOIN {#SOURCEDB_Q#}.sys.types ty ON ty.user_type_id=c.user_type_id LEFT JOIN {#SOURCEDB_Q#}.sys.schemas tys ON tys.schema_id=ty.schema_id LEFT JOIN {#TARGETDB_Q#}.sys.schemas tsc ON tsc.name{#COLLATION#}=sc.name{#COLLATION#} LEFT JOIN {#TARGETDB_Q#}.sys.tables tt ON tt.name{#COLLATION#}=t.name{#COLLATION#} AND tt.schema_id=tsc.schema_id LEFT JOIN {#TARGETDB_Q#}.sys.columns tc ON tc.object_id=tt.object_id AND tc.name{#COLLATION#}=c.name{#COLLATION#} WHERE sc.name{#COLLATION#}<>N''sys''{#COLLATION#} AND t.is_ms_shipped=0 AND tt.object_id IS NOT NULL -- Target table must exist AND tc.object_id IS NULL -- Column must not exist AND NOT EXISTS (SELECT 1 FROM #TBDD_SYNC_DATABASE_EXCLUDEDOBJECTS ex WHERE (ex.IsWildcard=1 AND (t.name{#COLLATION#} LIKE ex.Pattern{#COLLATION#} OR (sc.name{#COLLATION#}+N''.''{#COLLATION#}+t.name{#COLLATION#}) LIKE ex.Pattern{#COLLATION#})) OR (ex.IsWildcard=0 AND (t.name{#COLLATION#}=ex.Pattern{#COLLATION#} OR (sc.name{#COLLATION#}+N''.''{#COLLATION#}+t.name{#COLLATION#})=ex.Pattern{#COLLATION#})));'; SET @DYNAMICSQL = REPLACE(REPLACE(REPLACE(@DYNAMICSQL, @PLACEHOLDERSOURCEDBQUOTED, @SOURCEDATABASEQUOTED), @PLACEHOLDERTARGETDBQUOTED, @TARGETDATABASEQUOTED), @PLACEHOLDERCOLLATION, @COMPARECOLLATION); SET @DYNAMICSQL = REPLACE(REPLACE(@DYNAMICSQL, @PLACEHOLDERSOURCEDB, @SOURCEDATABASE), @PLACEHOLDERTARGETDB, @TARGETDATABASE); SET @DYNAMICSQL = REPLACE(@DYNAMICSQL, @PLACEHOLDERTARGETCOLLATION, @TARGETCOLLATION); BEGIN TRY EXEC sys.sp_executesql @DYNAMICSQL; IF @DEBUG = 1 PRINT '[DEBUG] Table-AddColumns commands executed successfully'; END TRY BEGIN CATCH PRINT '[ERROR] Failed to execute Table-AddColumns command!'; PRINT '[ERROR] Error Message: ' + ERROR_MESSAGE(); PRINT '[ERROR] Dynamic SQL (first 8000 chars):'; PRINT SUBSTRING(@DYNAMICSQL, 1, 8000); THROW; END CATCH; ----------------------------------------------------------------------------------------------------------------------------- --=================================================-- Table ALTER: Modify columns (Type/Nullability/Collation/Sparse) --================================================-- SET @DYNAMICSQL = N' INSERT INTO #TBDD_SYNC_DATABASE_COMMANDS(Phase, Command) SELECT N''03-Table-AlterColumns'', N''USE {#TARGETDB_Q#}; ALTER TABLE ''+QUOTENAME(sc.name)+N''.''{#COLLATION#}+QUOTENAME(t.name)+N'' ALTER COLUMN ''+ QUOTENAME(c.name) + N'' ''+ CASE WHEN ty.is_user_defined=1 THEN QUOTENAME(tys.name) + N''.'' + QUOTENAME(ty.name) WHEN ty.name{#COLLATION#} IN (N''varchar'',N''char'',N''varbinary'',N''binary'') THEN ty.name + N''('' + CASE WHEN c.max_length=-1 THEN N''max'' ELSE CONVERT(nvarchar(10), c.max_length) END + N'')'' WHEN ty.name{#COLLATION#} IN (N''nvarchar'',N''nchar'') THEN ty.name + N''('' + CASE WHEN c.max_length=-1 THEN N''max'' ELSE CONVERT(nvarchar(10), c.max_length/2) END + N'')'' WHEN ty.name{#COLLATION#} IN (N''decimal'',N''numeric'') THEN ty.name + N''('' + CONVERT(nvarchar(10), c.precision) + N'','' + CONVERT(nvarchar(10), c.scale) + N'')'' WHEN ty.name{#COLLATION#} IN (N''datetime2'',N''datetimeoffset'',N''time'') THEN ty.name + N''('' + CONVERT(nvarchar(10), c.scale) + N'')'' ELSE ty.name END + CASE WHEN ty.is_user_defined=0 AND ty.name{#COLLATION#} IN (N''char'',N''varchar'',N''nchar'',N''nvarchar'',N''text'',N''ntext'') THEN N'' COLLATE {#TARGET_COLLATION_NAME#}'' ELSE N'''' END + CASE WHEN c.is_sparse=1 THEN N'' SPARSE'' ELSE N'''' END + CASE WHEN c.is_nullable=1 THEN N'' NULL'' ELSE N'' NOT NULL'' END FROM {#SOURCEDB_Q#}.sys.tables t JOIN {#SOURCEDB_Q#}.sys.schemas sc ON sc.schema_id=t.schema_id JOIN {#SOURCEDB_Q#}.sys.columns c ON c.object_id=t.object_id JOIN {#SOURCEDB_Q#}.sys.types ty ON ty.user_type_id=c.user_type_id LEFT JOIN {#SOURCEDB_Q#}.sys.schemas tys ON tys.schema_id=ty.schema_id LEFT JOIN {#SOURCEDB_Q#}.sys.identity_columns ic_src ON ic_src.object_id=c.object_id AND ic_src.column_id=c.column_id LEFT JOIN {#TARGETDB_Q#}.sys.schemas tsc ON tsc.name{#COLLATION#}=sc.name{#COLLATION#} LEFT JOIN {#TARGETDB_Q#}.sys.tables tt ON tt.name{#COLLATION#}=t.name{#COLLATION#} AND tt.schema_id=tsc.schema_id LEFT JOIN {#TARGETDB_Q#}.sys.columns tc ON tc.object_id=tt.object_id AND tc.name{#COLLATION#}=c.name{#COLLATION#} LEFT JOIN {#TARGETDB_Q#}.sys.types tty ON tty.user_type_id=tc.user_type_id WHERE sc.name{#COLLATION#}<>N''sys''{#COLLATION#} AND t.is_ms_shipped=0 AND c.is_computed=0 AND tc.object_id IS NOT NULL AND ic_src.object_id IS NULL AND ( c.is_nullable<>tc.is_nullable OR c.is_sparse<>tc.is_sparse OR c.max_length<>tc.max_length OR c.precision<>tc.precision OR c.scale<>tc.scale OR ty.name{#COLLATION#}<>tty.name{#COLLATION#} OR ty.is_user_defined<>tty.is_user_defined ) AND NOT EXISTS (SELECT 1 FROM #TBDD_SYNC_DATABASE_EXCLUDEDOBJECTS ex WHERE (ex.IsWildcard=1 AND (t.name{#COLLATION#} LIKE ex.Pattern{#COLLATION#} OR (sc.name{#COLLATION#}+N''.''{#COLLATION#}+t.name{#COLLATION#}) LIKE ex.Pattern{#COLLATION#})) OR (ex.IsWildcard=0 AND (t.name{#COLLATION#}=ex.Pattern{#COLLATION#} OR (sc.name{#COLLATION#}+N''.''{#COLLATION#}+t.name{#COLLATION#})=ex.Pattern{#COLLATION#})));'; SET @DYNAMICSQL = REPLACE(REPLACE(REPLACE(@DYNAMICSQL, @PLACEHOLDERSOURCEDBQUOTED, @SOURCEDATABASEQUOTED), @PLACEHOLDERTARGETDBQUOTED, @TARGETDATABASEQUOTED), @PLACEHOLDERCOLLATION, @COMPARECOLLATION); SET @DYNAMICSQL = REPLACE(REPLACE(@DYNAMICSQL, @PLACEHOLDERSOURCEDB, @SOURCEDATABASE), @PLACEHOLDERTARGETDB, @TARGETDATABASE); SET @DYNAMICSQL = REPLACE(@DYNAMICSQL, @PLACEHOLDERTARGETCOLLATION, @TARGETCOLLATION); BEGIN TRY EXEC sys.sp_executesql @DYNAMICSQL; IF @DEBUG = 1 PRINT '[DEBUG] Table-AlterColumns commands executed successfully'; END TRY BEGIN CATCH PRINT '[ERROR] Failed to execute Table-AlterColumns command!'; PRINT '[ERROR] Error Message: ' + ERROR_MESSAGE(); PRINT '[ERROR] Dynamic SQL (first 8000 chars):'; PRINT SUBSTRING(@DYNAMICSQL, 1, 8000); IF LEN(@DYNAMICSQL) > 8000 PRINT '[ERROR] (continued): ' + SUBSTRING(@DYNAMICSQL, 8001, 8000); THROW; END CATCH; ----------------------------------------------------------------------------------------------------------------------------- --=================================================-- Tabellen-ALTER: Default Constraints synchronisieren --================================================-- SET @DYNAMICSQL = N' INSERT INTO #TBDD_SYNC_DATABASE_COMMANDS(Phase, Command) SELECT N''03-Table-Defaults'', N''USE {#TARGETDB_Q#}; '' + CASE WHEN tgtDC.object_id IS NOT NULL THEN N''ALTER TABLE ''+QUOTENAME(sc.name)+N''.''{#COLLATION#}+QUOTENAME(t.name)+N'' DROP CONSTRAINT ''+QUOTENAME(tgtDC.name)+N''; '' ELSE N'''' END + CASE WHEN srcdc.name IS NOT NULL THEN N''ALTER TABLE ''+QUOTENAME(sc.name)+N''.''{#COLLATION#}+QUOTENAME(t.name)+N'' ADD CONSTRAINT ''+QUOTENAME(srcdc.name)+N'' DEFAULT ''+ISNULL(srcdc.definition,N'''')+N'' FOR ''+QUOTENAME(c.name)+N'';'' ELSE N'''' END FROM {#SOURCEDB_Q#}.sys.tables t JOIN {#SOURCEDB_Q#}.sys.schemas sc ON sc.schema_id=t.schema_id JOIN {#SOURCEDB_Q#}.sys.columns c ON c.object_id=t.object_id LEFT JOIN {#SOURCEDB_Q#}.sys.default_constraints srcdc ON srcdc.parent_object_id=c.object_id AND srcdc.parent_column_id=c.column_id LEFT JOIN {#TARGETDB_Q#}.sys.schemas tsc ON tsc.name{#COLLATION#}=sc.name{#COLLATION#} LEFT JOIN {#TARGETDB_Q#}.sys.tables tt ON tt.name{#COLLATION#}=t.name{#COLLATION#} AND tt.schema_id=tsc.schema_id LEFT JOIN {#TARGETDB_Q#}.sys.columns tc ON tc.object_id=tt.object_id AND tc.name{#COLLATION#}=c.name{#COLLATION#} LEFT JOIN {#TARGETDB_Q#}.sys.default_constraints tgtDC ON tgtDC.parent_object_id=tc.object_id AND tgtDC.parent_column_id=tc.column_id WHERE sc.name{#COLLATION#}<>N''sys''{#COLLATION#} AND t.is_ms_shipped=0 AND c.is_computed=0 AND tc.object_id IS NOT NULL AND ( (srcdc.definition IS NOT NULL AND (tgtDC.definition IS NULL OR tgtDC.definition{#COLLATION#}<>srcdc.definition{#COLLATION#})) OR (srcdc.definition IS NULL AND tgtDC.definition IS NOT NULL) ) AND NOT EXISTS (SELECT 1 FROM #TBDD_SYNC_DATABASE_EXCLUDEDOBJECTS ex WHERE (ex.IsWildcard=1 AND (t.name{#COLLATION#} LIKE ex.Pattern{#COLLATION#} OR (sc.name{#COLLATION#}+N''.''{#COLLATION#}+t.name{#COLLATION#}) LIKE ex.Pattern{#COLLATION#})) OR (ex.IsWildcard=0 AND (t.name{#COLLATION#}=ex.Pattern{#COLLATION#} OR (sc.name{#COLLATION#}+N''.''{#COLLATION#}+t.name{#COLLATION#})=ex.Pattern{#COLLATION#})));'; SET @DYNAMICSQL = REPLACE(REPLACE(REPLACE(@DYNAMICSQL, @PLACEHOLDERSOURCEDBQUOTED, @SOURCEDATABASEQUOTED), @PLACEHOLDERTARGETDBQUOTED, @TARGETDATABASEQUOTED), @PLACEHOLDERCOLLATION, @COMPARECOLLATION); SET @DYNAMICSQL = REPLACE(REPLACE(@DYNAMICSQL, @PLACEHOLDERSOURCEDB, @SOURCEDATABASE), @PLACEHOLDERTARGETDB, @TARGETDATABASE); BEGIN TRY EXEC sys.sp_executesql @DYNAMICSQL; IF @DEBUG = 1 PRINT '[DEBUG] Table-Defaults commands executed successfully'; END TRY BEGIN CATCH PRINT '[ERROR] Failed to execute Table-Defaults command!'; PRINT '[ERROR] Error Message: ' + ERROR_MESSAGE(); PRINT '[ERROR] Dynamic SQL (first 8000 chars):'; PRINT SUBSTRING(@DYNAMICSQL, 1, 8000); IF LEN(@DYNAMICSQL) > 8000 PRINT '[ERROR] (continued): ' + SUBSTRING(@DYNAMICSQL, 8001, 8000); THROW; END CATCH; ----------------------------------------------------------------------------------------------------------------------------- --=================================================-- Tabellen-ALTER: Check Constraints synchronisieren --================================================-- SET @DYNAMICSQL = N' INSERT INTO #TBDD_SYNC_DATABASE_COMMANDS(Phase, Command) SELECT N''03-Table-Checks'', N''USE {#TARGETDB_Q#}; '' + CASE WHEN tgtck.object_id IS NOT NULL THEN N''ALTER TABLE ''+QUOTENAME(sc.name)+N''.''{#COLLATION#}+QUOTENAME(t.name)+N'' DROP CONSTRAINT ''+QUOTENAME(tgtck.name)+N''; '' ELSE N'''' END + N''ALTER TABLE ''+QUOTENAME(sc.name)+N''.''{#COLLATION#}+QUOTENAME(t.name)+N'' WITH CHECK ADD CONSTRAINT ''+QUOTENAME(ck.name)+N'' CHECK ''+ISNULL(ck.definition,N'''') FROM {#SOURCEDB_Q#}.sys.check_constraints ck JOIN {#SOURCEDB_Q#}.sys.tables t ON t.object_id=ck.parent_object_id JOIN {#SOURCEDB_Q#}.sys.schemas sc ON sc.schema_id=t.schema_id LEFT JOIN {#TARGETDB_Q#}.sys.schemas tsc ON tsc.name{#COLLATION#}=sc.name{#COLLATION#} LEFT JOIN {#TARGETDB_Q#}.sys.tables tt ON tt.name{#COLLATION#}=t.name{#COLLATION#} AND tt.schema_id=tsc.schema_id LEFT JOIN {#TARGETDB_Q#}.sys.check_constraints tgtck ON tgtck.parent_object_id=tt.object_id AND tgtck.name{#COLLATION#}=ck.name{#COLLATION#} WHERE sc.name{#COLLATION#}<>N''sys''{#COLLATION#} AND t.is_ms_shipped=0 AND (tgtck.object_id IS NULL OR tgtck.definition{#COLLATION#}<>ck.definition{#COLLATION#}) AND NOT EXISTS (SELECT 1 FROM #TBDD_SYNC_DATABASE_EXCLUDEDOBJECTS ex WHERE (ex.IsWildcard=1 AND (t.name{#COLLATION#} LIKE ex.Pattern{#COLLATION#} OR (sc.name{#COLLATION#}+N''.''{#COLLATION#}+t.name{#COLLATION#}) LIKE ex.Pattern{#COLLATION#})) OR (ex.IsWildcard=0 AND (t.name{#COLLATION#}=ex.Pattern{#COLLATION#} OR (sc.name{#COLLATION#}+N''.''{#COLLATION#}+t.name{#COLLATION#})=ex.Pattern{#COLLATION#})));'; SET @DYNAMICSQL = REPLACE(REPLACE(REPLACE(@DYNAMICSQL, @PLACEHOLDERSOURCEDBQUOTED, @SOURCEDATABASEQUOTED), @PLACEHOLDERTARGETDBQUOTED, @TARGETDATABASEQUOTED), @PLACEHOLDERCOLLATION, @COMPARECOLLATION); SET @DYNAMICSQL = REPLACE(REPLACE(@DYNAMICSQL, @PLACEHOLDERSOURCEDB, @SOURCEDATABASE), @PLACEHOLDERTARGETDB, @TARGETDATABASE); BEGIN TRY EXEC sys.sp_executesql @DYNAMICSQL; IF @DEBUG = 1 PRINT '[DEBUG] Table-Checks commands executed successfully'; END TRY BEGIN CATCH PRINT '[ERROR] Failed to execute Table-Checks command!'; PRINT '[ERROR] Error Message: ' + ERROR_MESSAGE(); PRINT '[ERROR] Dynamic SQL (first 8000 chars):'; PRINT SUBSTRING(@DYNAMICSQL, 1, 8000); IF LEN(@DYNAMICSQL) > 8000 PRINT '[ERROR] (continued): ' + SUBSTRING(@DYNAMICSQL, 8001, 8000); THROW; END CATCH; ----------------------------------------------------------------------------------------------------------------------------- --=================================================-- Tabellen-ALTER: Unique Constraints synchronisieren --================================================-- SET @DYNAMICSQL = N' INSERT INTO #TBDD_SYNC_DATABASE_COMMANDS(Phase, Command) SELECT * FROM ( SELECT N''03-Table-Unique'', N''USE {#TARGETDB_Q#}; '' + CASE WHEN tgtuq.object_id IS NOT NULL THEN N''ALTER TABLE ''+QUOTENAME(sc.name)+N''.''{#COLLATION#}+QUOTENAME(t.name)+N'' DROP CONSTRAINT ''+QUOTENAME(tgtuq.name)+N''; '' ELSE N'''' END + N''ALTER TABLE ''+QUOTENAME(sc.name)+N''.''{#COLLATION#}+QUOTENAME(t.name)+N'' ADD CONSTRAINT ''+QUOTENAME(uq.name)+N'' UNIQUE '' + CASE WHEN i.type=1 THEN N''CLUSTERED '' ELSE N''NONCLUSTERED '' END + N''(''+STUFF((SELECT '',''{#COLLATION#}+QUOTENAME(cs.name) FROM {#SOURCEDB_Q#}.sys.index_columns ic JOIN {#SOURCEDB_Q#}.sys.columns cs ON cs.object_id=ic.object_id AND cs.column_id=ic.column_id WHERE ic.object_id=i.object_id AND ic.index_id=i.index_id ORDER BY ic.key_ordinal FOR XML PATH(''''), TYPE).value(''.'',''nvarchar(max)''),1,1,N'''')+N'')'' FROM {#SOURCEDB_Q#}.sys.key_constraints uq JOIN {#SOURCEDB_Q#}.sys.tables t ON t.object_id=uq.parent_object_id JOIN {#SOURCEDB_Q#}.sys.schemas sc ON sc.schema_id=t.schema_id JOIN {#SOURCEDB_Q#}.sys.indexes i ON i.object_id=uq.parent_object_id AND i.index_id=uq.unique_index_id LEFT JOIN {#TARGETDB_Q#}.sys.schemas tsc ON tsc.name{#COLLATION#}=sc.name{#COLLATION#} LEFT JOIN {#TARGETDB_Q#}.sys.tables tt ON tt.name{#COLLATION#}=t.name{#COLLATION#} AND tt.schema_id=tsc.schema_id LEFT JOIN {#TARGETDB_Q#}.sys.key_constraints tgtuq ON tgtuq.parent_object_id=tt.object_id AND tgtuq.name{#COLLATION#}=uq.name{#COLLATION#} AND tgtuq.type{#COLLATION#}=''UQ''{#COLLATION#} OUTER APPLY ( SELECT HASHBYTES(''SHA2_256'', (SELECT cs.name{#COLLATION#}, ic.key_ordinal FROM {#SOURCEDB_Q#}.sys.index_columns ic JOIN {#SOURCEDB_Q#}.sys.columns cs ON cs.object_id=ic.object_id AND cs.column_id=ic.column_id WHERE ic.object_id=i.object_id AND ic.index_id=i.index_id ORDER BY ic.key_ordinal FOR XML PATH(''''), TYPE).value(''.'',''nvarchar(max)''){#COLLATION#}) AS src_hash ) hsrc OUTER APPLY ( SELECT HASHBYTES(''SHA2_256'', (SELECT cs.name{#COLLATION#}, ic.key_ordinal FROM {#TARGETDB_Q#}.sys.index_columns ic JOIN {#TARGETDB_Q#}.sys.columns cs ON cs.object_id=ic.object_id AND cs.column_id=ic.column_id WHERE ic.object_id=tgtuq.parent_object_id AND ic.index_id=tgtuq.unique_index_id ORDER BY ic.key_ordinal FOR XML PATH(''''), TYPE).value(''.'',''nvarchar(max)''){#COLLATION#}) AS tgt_hash ) htgt WHERE uq.type{#COLLATION#}=''UQ''{#COLLATION#} AND sc.name{#COLLATION#}<>N''sys''{#COLLATION#} AND (tgtuq.object_id IS NULL OR hsrc.src_hash<>htgt.tgt_hash) AND NOT EXISTS (SELECT 1 FROM #TBDD_SYNC_DATABASE_EXCLUDEDOBJECTS ex WHERE (ex.IsWildcard=1 AND (t.name{#COLLATION#} LIKE ex.Pattern{#COLLATION#} OR (sc.name{#COLLATION#}+N''.''{#COLLATION#}+t.name{#COLLATION#}) LIKE ex.Pattern{#COLLATION#})) OR (ex.IsWildcard=0 AND (t.name{#COLLATION#}=ex.Pattern{#COLLATION#} OR (sc.name{#COLLATION#}+N''.''{#COLLATION#}+t.name{#COLLATION#})=ex.Pattern{#COLLATION#}))) ) AS X(Phase, Command) WHERE X.Command IS NOT NULL AND LEN(X.Command)>0;'; SET @DYNAMICSQL = REPLACE(REPLACE(REPLACE(@DYNAMICSQL, @PLACEHOLDERSOURCEDBQUOTED, @SOURCEDATABASEQUOTED), @PLACEHOLDERTARGETDBQUOTED, @TARGETDATABASEQUOTED), @PLACEHOLDERCOLLATION, @COMPARECOLLATION); SET @DYNAMICSQL = REPLACE(REPLACE(@DYNAMICSQL, @PLACEHOLDERSOURCEDB, @SOURCEDATABASE), @PLACEHOLDERTARGETDB, @TARGETDATABASE); BEGIN TRY EXEC sys.sp_executesql @DYNAMICSQL; IF @DEBUG = 1 PRINT '[DEBUG] Table-Unique commands built successfully'; END TRY BEGIN CATCH PRINT '[ERROR] Failed to build Table-Unique commands!'; PRINT '[ERROR] Error Message: ' + ERROR_MESSAGE(); PRINT '[ERROR] Dynamic SQL (first 8000 chars):'; PRINT SUBSTRING(@DYNAMICSQL, 1, 8000); IF LEN(@DYNAMICSQL) > 8000 PRINT '[ERROR] (continued): ' + SUBSTRING(@DYNAMICSQL, 8001, 8000); THROW; END CATCH; END ELSE PRINT '[INFO] Skipping Tables (disabled by @pSYNCOBJECTS)'; ----------------------------------------------------------------------------------------------------------------------------- --=================================================-- Foreign Keys vor PK-Anpassung droppen (Target referenziert PK-Tabellen) --================================================-- IF @SYNC_TABLES = 1 BEGIN -- FK-Drop for PK belongs to TABLES SET @DYNAMICSQL = N' INSERT INTO #TBDD_SYNC_DATABASE_COMMANDS(Phase, Command) SELECT * FROM ( SELECT N''04-FK-DropForPK'', N''USE {#TARGETDB_Q#}; ALTER TABLE ''+QUOTENAME(ts.name)+N''.''{#COLLATION#}+QUOTENAME(tt.name)+N'' DROP CONSTRAINT ''+QUOTENAME(tfk.name)+N'';'' FROM {#SOURCEDB_Q#}.sys.key_constraints pk JOIN {#SOURCEDB_Q#}.sys.tables st ON st.object_id=pk.parent_object_id JOIN {#SOURCEDB_Q#}.sys.schemas ss ON ss.schema_id=st.schema_id JOIN {#TARGETDB_Q#}.sys.schemas ts ON ts.name{#COLLATION#}=ss.name{#COLLATION#} JOIN {#TARGETDB_Q#}.sys.tables tt ON tt.name{#COLLATION#}=st.name{#COLLATION#} AND tt.schema_id=ts.schema_id JOIN {#TARGETDB_Q#}.sys.foreign_keys tfk ON tfk.referenced_object_id=tt.object_id WHERE pk.type{#COLLATION#}=''PK''{#COLLATION#} AND ss.name{#COLLATION#}<>N''sys''{#COLLATION#} AND NOT EXISTS (SELECT 1 FROM #TBDD_SYNC_DATABASE_EXCLUDEDOBJECTS ex WHERE (ex.IsWildcard=1 AND (st.name{#COLLATION#} LIKE ex.Pattern{#COLLATION#} OR (ss.name{#COLLATION#}+N''.''{#COLLATION#}+st.name{#COLLATION#}) LIKE ex.Pattern{#COLLATION#})) OR (ex.IsWildcard=0 AND (st.name{#COLLATION#}=ex.Pattern{#COLLATION#} OR (ss.name{#COLLATION#}+N''.''{#COLLATION#}+st.name{#COLLATION#})=ex.Pattern{#COLLATION#}))) ) AS X(Phase, Command) WHERE X.Command IS NOT NULL AND LEN(X.Command)>0;'; SET @DYNAMICSQL = REPLACE(REPLACE(REPLACE(@DYNAMICSQL, @PLACEHOLDERSOURCEDBQUOTED, @SOURCEDATABASEQUOTED), @PLACEHOLDERTARGETDBQUOTED, @TARGETDATABASEQUOTED), @PLACEHOLDERCOLLATION, @COMPARECOLLATION); BEGIN TRY EXEC sys.sp_executesql @DYNAMICSQL; IF @DEBUG = 1 PRINT '[DEBUG] FK-DropForPK commands built successfully'; END TRY BEGIN CATCH PRINT '[ERROR] Failed to build FK-DropForPK commands!'; PRINT '[ERROR] Error Message: ' + ERROR_MESSAGE(); PRINT '[ERROR] Dynamic SQL (first 8000 chars):'; PRINT SUBSTRING(@DYNAMICSQL, 1, 8000); IF LEN(@DYNAMICSQL) > 8000 PRINT '[ERROR] (continued): ' + SUBSTRING(@DYNAMICSQL, 8001, 8000); THROW; END CATCH; END ELSE PRINT '[INFO] Skipping FK-DropForPK (disabled by @pSYNCOBJECTS)'; --=================================================-- Primary Keys (Drop/Create bei Abweichungen) --================================================-- IF @SYNC_TABLES = 1 BEGIN -- Primary Keys belongs to TABLES SET @DYNAMICSQL = N' INSERT INTO #TBDD_SYNC_DATABASE_COMMANDS(Phase, Command) SELECT * FROM ( SELECT N''05-PrimaryKeys'', N''USE {#TARGETDB_Q#}; '' + CASE WHEN tp.object_id IS NOT NULL THEN N''ALTER TABLE ''+QUOTENAME(sc.name)+N''.''{#COLLATION#}+QUOTENAME(t.name)+'' DROP CONSTRAINT ''+QUOTENAME(tp.name)+''; '' ELSE N'''' END + N''ALTER TABLE ''+QUOTENAME(sc.name)+N''.''{#COLLATION#}+QUOTENAME(t.name)+'' ADD CONSTRAINT ''+QUOTENAME(pk.name)+'' PRIMARY KEY '' + CASE WHEN i.type=1 THEN N''CLUSTERED '' ELSE N''NONCLUSTERED '' END + N''('' + STUFF((SELECT '',''{#COLLATION#}+QUOTENAME(cs.name) FROM {#SOURCEDB_Q#}.sys.index_columns ic JOIN {#SOURCEDB_Q#}.sys.columns cs ON cs.object_id=ic.object_id AND cs.column_id=ic.column_id WHERE ic.object_id=i.object_id AND ic.index_id=i.index_id ORDER BY ic.key_ordinal FOR XML PATH(''''), TYPE).value(''.'',''nvarchar(max)''),1,1,N'''') + N'')'' FROM {#SOURCEDB_Q#}.sys.key_constraints pk JOIN {#SOURCEDB_Q#}.sys.tables t ON t.object_id=pk.parent_object_id JOIN {#SOURCEDB_Q#}.sys.schemas sc ON sc.schema_id=t.schema_id JOIN {#SOURCEDB_Q#}.sys.indexes i ON i.object_id=pk.parent_object_id AND i.index_id=pk.unique_index_id OUTER APPLY ( SELECT tp.object_id, tp.name, tp.unique_index_id FROM {#TARGETDB_Q#}.sys.key_constraints tp JOIN {#TARGETDB_Q#}.sys.tables tt ON tt.object_id=tp.parent_object_id JOIN {#TARGETDB_Q#}.sys.schemas tsc ON tsc.schema_id=tt.schema_id WHERE tp.type{#COLLATION#}=''PK''{#COLLATION#} AND tsc.name{#COLLATION#}=sc.name{#COLLATION#} AND tt.name{#COLLATION#}=t.name{#COLLATION#} ) tp OUTER APPLY ( SELECT HASHBYTES(''SHA2_256'', (SELECT cs.name{#COLLATION#}, ic.key_ordinal FROM {#SOURCEDB_Q#}.sys.index_columns ic JOIN {#SOURCEDB_Q#}.sys.columns cs ON cs.object_id=ic.object_id AND cs.column_id=ic.column_id WHERE ic.object_id=i.object_id AND ic.index_id=i.index_id ORDER BY ic.key_ordinal FOR XML PATH(''''), TYPE).value(''.'',''nvarchar(max)''){#COLLATION#}) AS src_hash ) hsrc OUTER APPLY ( SELECT HASHBYTES(''SHA2_256'', (SELECT cs.name{#COLLATION#}, ic.key_ordinal FROM {#TARGETDB_Q#}.sys.index_columns ic JOIN {#TARGETDB_Q#}.sys.columns cs ON cs.object_id=ic.object_id AND cs.column_id=ic.column_id WHERE ic.object_id=tp.object_id AND ic.index_id=tp.unique_index_id ORDER BY ic.key_ordinal FOR XML PATH(''''), TYPE).value(''.'',''nvarchar(max)''){#COLLATION#}) AS tgt_hash ) htgt WHERE pk.type{#COLLATION#}=''PK''{#COLLATION#} AND sc.name{#COLLATION#}<>N''sys''{#COLLATION#} AND (tp.object_id IS NULL OR hsrc.src_hash<>htgt.tgt_hash) AND NOT EXISTS (SELECT 1 FROM #TBDD_SYNC_DATABASE_EXCLUDEDOBJECTS ex WHERE (ex.IsWildcard=1 AND (t.name{#COLLATION#} LIKE ex.Pattern{#COLLATION#} OR (sc.name{#COLLATION#}+N''.''{#COLLATION#}+t.name{#COLLATION#}) LIKE ex.Pattern{#COLLATION#})) OR (ex.IsWildcard=0 AND (t.name{#COLLATION#}=ex.Pattern{#COLLATION#} OR (sc.name{#COLLATION#}+N''.''{#COLLATION#}+t.name{#COLLATION#})=ex.Pattern{#COLLATION#}))) ) AS X(Phase, Command) WHERE X.Command IS NOT NULL AND LEN(X.Command)>0;'; SET @DYNAMICSQL = REPLACE(REPLACE(REPLACE(@DYNAMICSQL, @PLACEHOLDERSOURCEDBQUOTED, @SOURCEDATABASEQUOTED), @PLACEHOLDERTARGETDBQUOTED, @TARGETDATABASEQUOTED), @PLACEHOLDERCOLLATION, @COMPARECOLLATION); SET @DYNAMICSQL = REPLACE(REPLACE(@DYNAMICSQL, @PLACEHOLDERSOURCEDB, @SOURCEDATABASE), @PLACEHOLDERTARGETDB, @TARGETDATABASE); BEGIN TRY EXEC sys.sp_executesql @DYNAMICSQL; IF @DEBUG = 1 PRINT '[DEBUG] PrimaryKeys commands built successfully'; END TRY BEGIN CATCH PRINT '[ERROR] Failed to build PrimaryKeys commands!'; PRINT '[ERROR] Error Message: ' + ERROR_MESSAGE(); PRINT '[ERROR] Dynamic SQL (first 8000 chars):'; PRINT SUBSTRING(@DYNAMICSQL, 1, 8000); IF LEN(@DYNAMICSQL) > 8000 PRINT '[ERROR] (continued): ' + SUBSTRING(@DYNAMICSQL, 8001, 8000); THROW; END CATCH; END ELSE PRINT '[INFO] Skipping Primary Keys (disabled by @pSYNCOBJECTS)'; ----------------------------------------------------------------------------------------------------------------------------- --=================================================-- Foreign Keys (fehlend oder abweichend -> Drop/Create) --================================================-- IF @SYNC_TABLES = 1 BEGIN -- Foreign Keys belongs to TABLES SET @DYNAMICSQL = N' INSERT INTO #TBDD_SYNC_DATABASE_COMMANDS(Phase, Command) SELECT * FROM ( SELECT N''06-ForeignKeys'', N''USE {#TARGETDB_Q#}; '' + CASE WHEN tfk.object_id IS NOT NULL THEN N''ALTER TABLE ''+QUOTENAME(ts.name)+N''.''{#COLLATION#}+QUOTENAME(t.name)+N'' DROP CONSTRAINT ''+QUOTENAME(tfk.name)+N''; '' ELSE N'''' END + N''ALTER TABLE ''+QUOTENAME(ts.name)+N''.''{#COLLATION#}+QUOTENAME(t.name)+ N'' WITH CHECK ADD CONSTRAINT ''+QUOTENAME(fk.name)+N'' FOREIGN KEY (''+ STUFF((SELECT '',''{#COLLATION#}+QUOTENAME(c.name) FROM {#SOURCEDB_Q#}.sys.foreign_key_columns fkc JOIN {#SOURCEDB_Q#}.sys.columns c ON c.object_id=fkc.parent_object_id AND c.column_id=fkc.parent_column_id WHERE fkc.constraint_object_id=fk.object_id ORDER BY fkc.constraint_column_id FOR XML PATH(''''), TYPE).value(''.'',''nvarchar(max)''),1,1,N'''') + N'') REFERENCES ''+ QUOTENAME(rs.name)+N''.''{#COLLATION#}+QUOTENAME(rt.name)+N''(''+ STUFF((SELECT '',''{#COLLATION#}+QUOTENAME(rc.name) FROM {#SOURCEDB_Q#}.sys.foreign_key_columns fkc JOIN {#SOURCEDB_Q#}.sys.columns rc ON rc.object_id=fkc.referenced_object_id AND rc.column_id=fkc.referenced_column_id WHERE fkc.constraint_object_id=fk.object_id ORDER BY fkc.constraint_column_id FOR XML PATH(''''), TYPE).value(''.'',''nvarchar(max)''),1,1,N'''') + N'')'' + CASE WHEN fk.delete_referential_action=1 THEN N'' ON DELETE CASCADE'' WHEN fk.delete_referential_action=2 THEN N'' ON DELETE SET NULL'' WHEN fk.delete_referential_action=3 THEN N'' ON DELETE SET DEFAULT'' ELSE N'''' END + CASE WHEN fk.update_referential_action=1 THEN N'' ON UPDATE CASCADE'' WHEN fk.update_referential_action=2 THEN N'' ON UPDATE SET NULL'' WHEN fk.update_referential_action=3 THEN N'' ON UPDATE SET DEFAULT'' ELSE N'''' END + CASE WHEN fk.is_not_for_replication=1 THEN N'' NOT FOR REPLICATION'' ELSE N'''' END + N'';'' FROM {#SOURCEDB_Q#}.sys.foreign_keys fk JOIN {#SOURCEDB_Q#}.sys.tables t ON t.object_id=fk.parent_object_id JOIN {#SOURCEDB_Q#}.sys.tables rt ON rt.object_id=fk.referenced_object_id JOIN {#SOURCEDB_Q#}.sys.schemas ts ON ts.schema_id=t.schema_id JOIN {#SOURCEDB_Q#}.sys.schemas rs ON rs.schema_id=rt.schema_id LEFT JOIN {#TARGETDB_Q#}.sys.schemas tts ON tts.name{#COLLATION#}=ts.name{#COLLATION#} LEFT JOIN {#TARGETDB_Q#}.sys.tables tt ON tt.name{#COLLATION#}=t.name{#COLLATION#} AND tt.schema_id=tts.schema_id LEFT JOIN {#TARGETDB_Q#}.sys.foreign_keys tfk ON tfk.name{#COLLATION#}=fk.name{#COLLATION#} AND tfk.parent_object_id=ISNULL(tt.object_id, -1) OUTER APPLY ( SELECT HASHBYTES(''SHA2_256'', (SELECT fkc.constraint_column_id, pc.name{#COLLATION#}, rc.name{#COLLATION#}, fk.delete_referential_action, fk.update_referential_action, fk.is_not_for_replication FROM {#SOURCEDB_Q#}.sys.foreign_key_columns fkc JOIN {#SOURCEDB_Q#}.sys.columns pc ON pc.object_id=fkc.parent_object_id AND pc.column_id=fkc.parent_column_id JOIN {#SOURCEDB_Q#}.sys.columns rc ON rc.object_id=fkc.referenced_object_id AND rc.column_id=fkc.referenced_column_id WHERE fkc.constraint_object_id=fk.object_id ORDER BY fkc.constraint_column_id FOR XML PATH(''''), TYPE).value(''.'',''nvarchar(max)''){#COLLATION#}) AS src_hash ) hsrc OUTER APPLY ( SELECT HASHBYTES(''SHA2_256'', (SELECT fkc.constraint_column_id, pc.name{#COLLATION#}, rc.name{#COLLATION#}, tfk.delete_referential_action, tfk.update_referential_action, tfk.is_not_for_replication FROM {#TARGETDB_Q#}.sys.foreign_key_columns fkc JOIN {#TARGETDB_Q#}.sys.columns pc ON pc.object_id=fkc.parent_object_id AND pc.column_id=fkc.parent_column_id JOIN {#TARGETDB_Q#}.sys.columns rc ON rc.object_id=fkc.referenced_object_id AND rc.column_id=fkc.referenced_column_id WHERE fkc.constraint_object_id=tfk.object_id ORDER BY fkc.constraint_column_id FOR XML PATH(''''), TYPE).value(''.'',''nvarchar(max)''){#COLLATION#}) AS tgt_hash ) htgt WHERE fk.is_ms_shipped=0 AND ts.name{#COLLATION#}<>N''sys''{#COLLATION#} AND (tfk.object_id IS NULL OR hsrc.src_hash<>htgt.tgt_hash) AND NOT EXISTS (SELECT 1 FROM #TBDD_SYNC_DATABASE_EXCLUDEDOBJECTS ex WHERE (ex.IsWildcard=1 AND (t.name{#COLLATION#} LIKE ex.Pattern{#COLLATION#} OR (ts.name{#COLLATION#}+N''.''{#COLLATION#}+t.name{#COLLATION#}) LIKE ex.Pattern{#COLLATION#})) OR (ex.IsWildcard=0 AND (t.name{#COLLATION#}=ex.Pattern{#COLLATION#} OR (ts.name{#COLLATION#}+N''.''{#COLLATION#}+t.name{#COLLATION#})=ex.Pattern{#COLLATION#}))) ) AS X(Phase, Command) WHERE X.Command IS NOT NULL AND LEN(X.Command)>0;'; SET @DYNAMICSQL = REPLACE(REPLACE(REPLACE(@DYNAMICSQL, @PLACEHOLDERSOURCEDBQUOTED, @SOURCEDATABASEQUOTED), @PLACEHOLDERTARGETDBQUOTED, @TARGETDATABASEQUOTED), @PLACEHOLDERCOLLATION, @COMPARECOLLATION); BEGIN TRY EXEC sys.sp_executesql @DYNAMICSQL; IF @DEBUG = 1 PRINT '[DEBUG] ForeignKeys commands built successfully'; END TRY BEGIN CATCH PRINT '[ERROR] Failed to build ForeignKeys commands!'; PRINT '[ERROR] Error Message: ' + ERROR_MESSAGE(); PRINT '[ERROR] Dynamic SQL (first 8000 chars):'; PRINT SUBSTRING(@DYNAMICSQL, 1, 8000); IF LEN(@DYNAMICSQL) > 8000 PRINT '[ERROR] (continued): ' + SUBSTRING(@DYNAMICSQL, 8001, 8000); THROW; END CATCH; END ELSE PRINT '[INFO] Skipping Foreign Keys (disabled by @pSYNCOBJECTS)'; ----------------------------------------------------------------------------------------------------------------------------- --=================================================-- Indexe (NC/Clustered) fehlend oder abweichend -> Drop/Create --================================================-- IF @SYNC_INDEXES = 1 BEGIN SET @DYNAMICSQL = N' INSERT INTO #TBDD_SYNC_DATABASE_COMMANDS(Phase, Command) SELECT * FROM ( SELECT N''07-Indexes'', N''USE {#TARGETDB_Q#}; '' + CASE WHEN ti.index_id IS NOT NULL THEN N''DROP INDEX ''+QUOTENAME(i.name)+N'' ON ''+QUOTENAME(s.name)+N''.''{#COLLATION#}+QUOTENAME(t.name)+N''; '' ELSE N'''' END + N''CREATE '' + CASE WHEN i.is_unique=1 THEN N''UNIQUE '' ELSE N'''' END + CASE WHEN i.type=1 THEN N''CLUSTERED '' WHEN i.type=2 THEN N''NONCLUSTERED '' ELSE N'''' END + N''INDEX '' + QUOTENAME(i.name) + N'' ON '' + QUOTENAME(s.name)+N''.''{#COLLATION#}+QUOTENAME(t.name)+N''(''+ STUFF((SELECT '',''{#COLLATION#}+QUOTENAME(c.name) + CASE WHEN ic.is_descending_key=1 THEN N'' DESC'' ELSE N'''' END FROM {#SOURCEDB_Q#}.sys.index_columns ic JOIN {#SOURCEDB_Q#}.sys.columns c ON c.object_id=ic.object_id AND c.column_id=ic.column_id WHERE ic.object_id=i.object_id AND ic.index_id=i.index_id AND ic.is_included_column=0 ORDER BY ic.key_ordinal FOR XML PATH(''''), TYPE).value(''.'',''nvarchar(max)''),1,1,N'''') + N'')'' + CASE WHEN EXISTS (SELECT 1 FROM {#SOURCEDB_Q#}.sys.index_columns ic WHERE ic.object_id=i.object_id AND ic.index_id=i.index_id AND ic.is_included_column=1) THEN N'' INCLUDE(''+STUFF((SELECT '',''{#COLLATION#}+QUOTENAME(c.name) FROM {#SOURCEDB_Q#}.sys.index_columns ic JOIN {#SOURCEDB_Q#}.sys.columns c ON c.object_id=ic.object_id AND c.column_id=ic.column_id WHERE ic.object_id=i.object_id AND ic.index_id=i.index_id AND ic.is_included_column=1 ORDER BY ic.index_column_id FOR XML PATH(''''), TYPE).value(''.'',''nvarchar(max)''),1,1,N'''')+N'')'' ELSE N'''' END + N'' WITH (PAD_INDEX = ''+CASE WHEN i.is_padded=1 THEN N''ON'' ELSE N''OFF'' END+ N'', ALLOW_ROW_LOCKS = ''+CASE WHEN i.allow_row_locks=1 THEN N''ON'' ELSE N''OFF'' END+ N'', ALLOW_PAGE_LOCKS = ''+CASE WHEN i.allow_page_locks=1 THEN N''ON'' ELSE N''OFF'' END+ N'', IGNORE_DUP_KEY = ''+CASE WHEN i.ignore_dup_key=1 THEN N''ON'' ELSE N''OFF'' END+ N'', FILLFACTOR = ''+CONVERT(nvarchar(3), CASE WHEN i.fill_factor=0 THEN 100 ELSE i.fill_factor END)+N'')'' + CASE WHEN i.has_filter=1 THEN N'' WHERE ''+ISNULL(i.filter_definition,N'''') ELSE N'''' END FROM {#SOURCEDB_Q#}.sys.indexes i JOIN {#SOURCEDB_Q#}.sys.tables t ON t.object_id=i.object_id JOIN {#SOURCEDB_Q#}.sys.schemas s ON s.schema_id=t.schema_id LEFT JOIN {#TARGETDB_Q#}.sys.schemas ts ON ts.name{#COLLATION#}=s.name{#COLLATION#} LEFT JOIN {#TARGETDB_Q#}.sys.tables tt ON tt.schema_id=ts.schema_id AND tt.name{#COLLATION#}=t.name{#COLLATION#} LEFT JOIN {#TARGETDB_Q#}.sys.indexes ti ON ti.object_id=tt.object_id AND ti.name{#COLLATION#}=i.name{#COLLATION#} OUTER APPLY ( SELECT HASHBYTES(''SHA2_256'', (SELECT ic.key_ordinal, ic.is_included_column, ic.is_descending_key, c.name{#COLLATION#}, i.has_filter, i.filter_definition{#COLLATION#}, i.is_padded, i.allow_row_locks, i.allow_page_locks, i.ignore_dup_key, i.fill_factor FROM {#SOURCEDB_Q#}.sys.index_columns ic JOIN {#SOURCEDB_Q#}.sys.columns c ON c.object_id=ic.object_id AND c.column_id=ic.column_id WHERE ic.object_id=i.object_id AND ic.index_id=i.index_id ORDER BY ic.index_column_id FOR XML PATH(''''), TYPE).value(''.'',''nvarchar(max)''){#COLLATION#}) AS src_hash, i.is_unique AS src_unique, i.type AS src_type ) hsrc OUTER APPLY ( SELECT HASHBYTES(''SHA2_256'', (SELECT ic.key_ordinal, ic.is_included_column, ic.is_descending_key, c.name{#COLLATION#}, ti.has_filter, ti.filter_definition{#COLLATION#}, ti.is_padded, ti.allow_row_locks, ti.allow_page_locks, ti.ignore_dup_key, ti.fill_factor FROM {#TARGETDB_Q#}.sys.index_columns ic JOIN {#TARGETDB_Q#}.sys.columns c ON c.object_id=ic.object_id AND c.column_id=ic.column_id WHERE ic.object_id=tt.object_id AND ic.index_id=ti.index_id ORDER BY ic.index_column_id FOR XML PATH(''''), TYPE).value(''.'',''nvarchar(max)''){#COLLATION#}) AS tgt_hash, ti.is_unique AS tgt_unique, ti.type AS tgt_type ) htgt WHERE i.is_primary_key=0 AND i.is_unique_constraint=0 AND i.is_hypothetical=0 AND i.type IN (1,2) AND t.is_ms_shipped=0 AND s.name{#COLLATION#}<>N''sys''{#COLLATION#} AND (ti.index_id IS NULL OR hsrc.src_hash<>htgt.tgt_hash OR hsrc.src_unique<>htgt.tgt_unique OR hsrc.src_type<>htgt.tgt_type) AND NOT EXISTS (SELECT 1 FROM #TBDD_SYNC_DATABASE_EXCLUDEDOBJECTS ex WHERE (ex.IsWildcard=1 AND (t.name{#COLLATION#} LIKE ex.Pattern{#COLLATION#} OR (s.name{#COLLATION#}+N''.''{#COLLATION#}+t.name{#COLLATION#}) LIKE ex.Pattern{#COLLATION#})) OR (ex.IsWildcard=0 AND (t.name{#COLLATION#}=ex.Pattern{#COLLATION#} OR (s.name{#COLLATION#}+N''.''{#COLLATION#}+t.name{#COLLATION#})=ex.Pattern{#COLLATION#}))) ) AS X(Phase, Command) WHERE X.Command IS NOT NULL AND LEN(X.Command)>0;'; SET @DYNAMICSQL = REPLACE(REPLACE(REPLACE(@DYNAMICSQL, @PLACEHOLDERSOURCEDBQUOTED, @SOURCEDATABASEQUOTED), @PLACEHOLDERTARGETDBQUOTED, @TARGETDATABASEQUOTED), @PLACEHOLDERCOLLATION, @COMPARECOLLATION); BEGIN TRY EXEC sys.sp_executesql @DYNAMICSQL; IF @DEBUG = 1 PRINT '[DEBUG] Index commands built successfully'; END TRY BEGIN CATCH PRINT '[ERROR] Failed to build Index commands!'; PRINT '[ERROR] Error Message: ' + ERROR_MESSAGE(); PRINT '[ERROR] Dynamic SQL (first 8000 chars):'; PRINT SUBSTRING(@DYNAMICSQL, 1, 8000); IF LEN(@DYNAMICSQL) > 8000 PRINT '[ERROR] (continued): ' + SUBSTRING(@DYNAMICSQL, 8001, 8000); THROW; END CATCH; END ELSE PRINT '[INFO] Skipping Indexes (disabled by @pSYNCOBJECTS)'; ----------------------------------------------------------------------------------------------------------------------------- --=================================================-- Programmierbare Objekte (Triggers/Views/Functions/Procedures) --================================================-- -- Triggers (table-level) IF @SYNC_TRIGGERS = 1 BEGIN SET @DYNAMICSQL = N' INSERT INTO #TBDD_SYNC_DATABASE_COMMANDS(Phase, Command) SELECT * FROM ( -- First: Generate DROP statements for existing triggers that will be recreated SELECT N''10A-Triggers-Drop'', N''EXEC {#TARGETDB_Q#}.sys.sp_executesql N''''DROP TRIGGER '' + QUOTENAME(ts.name) + N''.'' + QUOTENAME(ttr.name) + N'''''';'' FROM {#SOURCEDB_Q#}.sys.triggers tr JOIN {#SOURCEDB_Q#}.sys.objects o ON o.object_id=tr.object_id JOIN {#SOURCEDB_Q#}.sys.sql_modules m ON m.object_id=tr.object_id JOIN {#SOURCEDB_Q#}.sys.schemas s ON s.schema_id=o.schema_id JOIN {#SOURCEDB_Q#}.sys.tables pt ON pt.object_id=tr.parent_id JOIN {#SOURCEDB_Q#}.sys.schemas ps ON ps.schema_id=pt.schema_id JOIN {#TARGETDB_Q#}.sys.triggers ttr ON 1=1 JOIN {#TARGETDB_Q#}.sys.objects tobj ON tobj.object_id=ttr.object_id JOIN {#TARGETDB_Q#}.sys.sql_modules tgtm ON tgtm.object_id=ttr.object_id JOIN {#TARGETDB_Q#}.sys.schemas ts ON ts.schema_id=tobj.schema_id AND ts.name{#COLLATION#}=s.name{#COLLATION#} AND ttr.name{#COLLATION#}=tr.name{#COLLATION#} CROSS APPLY (SELECT HASHBYTES(''SHA2_256'', REPLACE(REPLACE(CAST(m.definition AS NVARCHAR(max)){#COLLATION#}, N''[''+ N''{#SOURCEDB#}'' +N'']'', N''[''+ N''{#TARGETDB#}'' +N'']''), N''{#SOURCEDB#}''+N''.'', N''{#TARGETDB#}''+N''.'')) AS src_hash, HASHBYTES(''SHA2_256'', CAST(tgtm.definition AS NVARCHAR(max)){#COLLATION#}) AS tgt_hash) hcmp WHERE s.name{#COLLATION#}<>N''sys''{#COLLATION#} AND tr.parent_id IS NOT NULL AND m.definition IS NOT NULL AND (N''{#SOURCECOLLATION_NAME#}'' COLLATE Latin1_General_CI_AS<>N''{#TARGETCOLLATION_NAME#}'' COLLATE Latin1_General_CI_AS OR hcmp.src_hash<>hcmp.tgt_hash) AND NOT EXISTS (SELECT 1 FROM #TBDD_SYNC_DATABASE_EXCLUDEDOBJECTS ex WHERE (ex.IsWildcard=1 AND (pt.name{#COLLATION#} LIKE ex.Pattern{#COLLATION#} OR (ps.name{#COLLATION#}+N''.''{#COLLATION#}+pt.name{#COLLATION#}) LIKE ex.Pattern{#COLLATION#})) OR (ex.IsWildcard=0 AND (pt.name{#COLLATION#}=ex.Pattern{#COLLATION#} OR (ps.name{#COLLATION#}+N''.''{#COLLATION#}+pt.name{#COLLATION#})=ex.Pattern{#COLLATION#})) OR (ex.IsWildcard=1 AND (tr.name{#COLLATION#} LIKE ex.Pattern{#COLLATION#} OR (s.name{#COLLATION#}+N''.''{#COLLATION#}+tr.name{#COLLATION#}) LIKE ex.Pattern{#COLLATION#})) OR (ex.IsWildcard=0 AND (tr.name{#COLLATION#}=ex.Pattern{#COLLATION#} OR (s.name{#COLLATION#}+N''.''{#COLLATION#}+tr.name{#COLLATION#})=ex.Pattern{#COLLATION#}))){#DROPEXISTING_FILTER#} UNION ALL -- Second: Generate CREATE statements for all triggers SELECT N''10B-Triggers'', N''EXEC {#TARGETDB_Q#}.sys.sp_executesql N'''''' + REPLACE( REPLACE( REPLACE( -- First normalize spaces (8->1, 4->1, 2->1 twice for 3+ spaces), then replace CREATE/ALTER REPLACE(REPLACE( REPLACE(REPLACE(REPLACE(REPLACE(CAST(m.definition AS NVARCHAR(max)){#COLLATION#}, N'' '', N'' ''), N'' '', N'' ''), N'' '', N'' ''), N'' '', N'' ''), N''ALTER TRIGGER'', N''CREATE TRIGGER''), N''CREATE OR ALTER TRIGGER'', N''CREATE TRIGGER''), N''[''+ N''{#SOURCEDB#}'' +N'']'', N''[''+ N''{#TARGETDB#}'' +N'']''), N''{#SOURCEDB#}''+N''.'', N''{#TARGETDB#}''+N''.''), CHAR(39), CHAR(39)+CHAR(39)) + '''''';'' FROM {#SOURCEDB_Q#}.sys.triggers tr JOIN {#SOURCEDB_Q#}.sys.objects o ON o.object_id=tr.object_id JOIN {#SOURCEDB_Q#}.sys.sql_modules m ON m.object_id=tr.object_id JOIN {#SOURCEDB_Q#}.sys.schemas s ON s.schema_id=o.schema_id JOIN {#SOURCEDB_Q#}.sys.tables pt ON pt.object_id=tr.parent_id JOIN {#SOURCEDB_Q#}.sys.schemas ps ON ps.schema_id=pt.schema_id CROSS APPLY (SELECT HASHBYTES(''SHA2_256'', REPLACE(REPLACE(CAST(m.definition AS NVARCHAR(max)){#COLLATION#}, N''[''+ N''{#SOURCEDB#}'' +N'']'', N''[''+ N''{#TARGETDB#}'' +N'']''), N''{#SOURCEDB#}''+N''.'', N''{#TARGETDB#}''+N''.'')) AS src_hash) hsrc OUTER APPLY ( SELECT HASHBYTES(''SHA2_256'', CAST(tgtm.definition AS NVARCHAR(max)){#COLLATION#}) AS tgt_hash FROM {#TARGETDB_Q#}.sys.triggers ttr JOIN {#TARGETDB_Q#}.sys.objects tobj ON tobj.object_id=ttr.object_id JOIN {#TARGETDB_Q#}.sys.sql_modules tgtm ON tgtm.object_id=ttr.object_id JOIN {#TARGETDB_Q#}.sys.schemas ts ON ts.schema_id=tobj.schema_id WHERE ts.name{#COLLATION#}=s.name{#COLLATION#} AND tobj.name{#COLLATION#}=tr.name{#COLLATION#} ) htgt WHERE s.name{#COLLATION#}<>N''sys''{#COLLATION#} AND tr.parent_id IS NOT NULL AND m.definition IS NOT NULL -- Skip encrypted objects (WITH ENCRYPTION) AND (N''{#SOURCECOLLATION_NAME#}'' COLLATE Latin1_General_CI_AS<>N''{#TARGETCOLLATION_NAME#}'' COLLATE Latin1_General_CI_AS OR htgt.tgt_hash IS NULL OR hsrc.src_hash<>htgt.tgt_hash) AND NOT EXISTS (SELECT 1 FROM #TBDD_SYNC_DATABASE_EXCLUDEDOBJECTS ex WHERE (ex.IsWildcard=1 AND (pt.name{#COLLATION#} LIKE ex.Pattern{#COLLATION#} OR (ps.name{#COLLATION#}+N''.''{#COLLATION#}+pt.name{#COLLATION#}) LIKE ex.Pattern{#COLLATION#})) OR (ex.IsWildcard=0 AND (pt.name{#COLLATION#}=ex.Pattern{#COLLATION#} OR (ps.name{#COLLATION#}+N''.''{#COLLATION#}+pt.name{#COLLATION#})=ex.Pattern{#COLLATION#})) OR (ex.IsWildcard=1 AND (tr.name{#COLLATION#} LIKE ex.Pattern{#COLLATION#} OR (s.name{#COLLATION#}+N''.''{#COLLATION#}+tr.name{#COLLATION#}) LIKE ex.Pattern{#COLLATION#})) OR (ex.IsWildcard=0 AND (tr.name{#COLLATION#}=ex.Pattern{#COLLATION#} OR (s.name{#COLLATION#}+N''.''{#COLLATION#}+tr.name{#COLLATION#})=ex.Pattern{#COLLATION#})) ) ) AS X(Phase, Command) WHERE X.Command IS NOT NULL AND LEN(X.Command)>0;'; SET @DYNAMICSQL = REPLACE(REPLACE(REPLACE(@DYNAMICSQL, @PLACEHOLDERSOURCEDBQUOTED, @SOURCEDATABASEQUOTED), @PLACEHOLDERTARGETDBQUOTED, @TARGETDATABASEQUOTED), @PLACEHOLDERCOLLATION, @COMPARECOLLATION); SET @DYNAMICSQL = REPLACE(REPLACE(@DYNAMICSQL, @PLACEHOLDERSOURCEDB, @SOURCEDATABASE), @PLACEHOLDERTARGETDB, @TARGETDATABASE); SET @DYNAMICSQL = REPLACE(REPLACE(@DYNAMICSQL, @PLACEHOLDERSOURCECOLLATIONNAME, @SOURCECOLLATION), @PLACEHOLDERTARGETCOLLATIONNAME, @TARGETCOLLATION); SET @DYNAMICSQL = REPLACE(@DYNAMICSQL, @PLACEHOLDERDROPEXISTING, @DROPEXISTING_FILTER); BEGIN TRY EXEC sys.sp_executesql @DYNAMICSQL; IF @DEBUG = 1 PRINT '[DEBUG] Trigger commands built successfully'; END TRY BEGIN CATCH PRINT '[ERROR] Failed to build Trigger commands!'; PRINT '[ERROR] Error Message: ' + ERROR_MESSAGE(); PRINT '[ERROR] Dynamic SQL (first 8000 chars):'; PRINT SUBSTRING(@DYNAMICSQL, 1, 8000); IF LEN(@DYNAMICSQL) > 8000 PRINT '[ERROR] (continued): ' + SUBSTRING(@DYNAMICSQL, 8001, 8000); THROW; END CATCH; END ELSE PRINT '[INFO] Skipping Triggers (disabled by @pSYNCOBJECTS)'; ----------------------------------------------------------------------------------------------------------------------------- --=================================================-- Views --================================================-- IF @SYNC_VIEWS = 1 BEGIN SET @DYNAMICSQL = N' ;WITH ViewDeps AS ( SELECT v.object_id, 0 dep, CAST(CONCAT(N'','',v.object_id,N'','') AS NVARCHAR(MAX)) AS visited FROM {#SOURCEDB_Q#}.sys.views v WHERE NOT EXISTS (SELECT 1 FROM {#SOURCEDB_Q#}.sys.sql_expression_dependencies d JOIN {#SOURCEDB_Q#}.sys.views rv ON rv.object_id=d.referenced_id WHERE d.referencing_id=v.object_id) UNION ALL SELECT v.object_id, vd.dep+1, CAST(CONCAT(vd.visited,v.object_id,N'','') AS NVARCHAR(MAX)) FROM {#SOURCEDB_Q#}.sys.views v JOIN {#SOURCEDB_Q#}.sys.sql_expression_dependencies d ON d.referencing_id=v.object_id JOIN ViewDeps vd ON vd.object_id=d.referenced_id WHERE vd.visited NOT LIKE CONCAT(N''%,'',v.object_id,N'',%'') AND vd.dep < 50 ), MaxLevel AS (SELECT object_id, MAX(dep) dep FROM ViewDeps GROUP BY object_id) INSERT INTO #TBDD_SYNC_DATABASE_COMMANDS(Phase, Command) SELECT X.Phase, X.Command FROM ( -- First: Generate DROP statements for views that need recreation (collation mismatch OR hash mismatch) SELECT N''11A-Views-Drop'', N''EXEC {#TARGETDB_Q#}.sys.sp_executesql N''''DROP VIEW '' + QUOTENAME(ts.name) + N''.'' + QUOTENAME(tv.name) + N'''''';'', 0 FROM {#SOURCEDB_Q#}.sys.views v JOIN {#SOURCEDB_Q#}.sys.sql_modules m ON m.object_id=v.object_id JOIN {#SOURCEDB_Q#}.sys.schemas s ON s.schema_id=v.schema_id JOIN {#TARGETDB_Q#}.sys.views tv ON 1=1 JOIN {#TARGETDB_Q#}.sys.sql_modules tgtm ON tgtm.object_id=tv.object_id JOIN {#TARGETDB_Q#}.sys.schemas ts ON ts.schema_id=tv.schema_id AND ts.name{#COLLATION#}=s.name{#COLLATION#} AND tv.name{#COLLATION#}=v.name{#COLLATION#} CROSS APPLY (SELECT HASHBYTES(''SHA2_256'', REPLACE(REPLACE(CAST(m.definition AS NVARCHAR(max)){#COLLATION#}, N''[''+ N''{#SOURCEDB#}'' +N'']'', N''[''+ N''{#TARGETDB#}'' +N'']''), N''{#SOURCEDB#}''+N''.'', N''{#TARGETDB#}''+N''.'')) AS src_hash, HASHBYTES(''SHA2_256'', CAST(tgtm.definition AS NVARCHAR(max)){#COLLATION#}) AS tgt_hash) hcmp WHERE s.name{#COLLATION#}<>N''sys''{#COLLATION#} AND m.definition IS NOT NULL AND (N''{#SOURCECOLLATION_NAME#}'' COLLATE Latin1_General_CI_AS<>N''{#TARGETCOLLATION_NAME#}'' COLLATE Latin1_General_CI_AS OR hcmp.src_hash<>hcmp.tgt_hash) AND NOT EXISTS (SELECT 1 FROM #TBDD_SYNC_DATABASE_EXCLUDEDOBJECTS ex WHERE (ex.IsWildcard=1 AND (v.name{#COLLATION#} LIKE ex.Pattern{#COLLATION#} OR (s.name{#COLLATION#}+N''.''{#COLLATION#}+v.name{#COLLATION#}) LIKE ex.Pattern{#COLLATION#})) OR (ex.IsWildcard=0 AND (v.name{#COLLATION#}=ex.Pattern{#COLLATION#} OR (s.name{#COLLATION#}+N''.''{#COLLATION#}+v.name{#COLLATION#})=ex.Pattern{#COLLATION#}))){#DROPEXISTING_FILTER#} UNION ALL -- Second: Generate CREATE statements for all views (robust: handles varying whitespace and case-insensitive) SELECT N''11B-Views'', N''EXEC {#TARGETDB_Q#}.sys.sp_executesql N'''''' + REPLACE( REPLACE( REPLACE( -- Case-insensitive REPLACE chain on normalized definition: -- 1. CREATE OR ALTER VIEW -> placeholder (preserve existing) -- 2. ALTER VIEW -> CREATE OR ALTER VIEW -- 3. CREATE VIEW -> CREATE OR ALTER VIEW -- 4. placeholder -> CREATE OR ALTER VIEW (restore) REPLACE( REPLACE( REPLACE( REPLACE(norm.def COLLATE Latin1_General_CI_AS, N''CREATE OR ALTER VIEW'' COLLATE Latin1_General_CI_AS, N''<#COA_VIEW#>''), N''ALTER VIEW'' COLLATE Latin1_General_CI_AS, N''CREATE OR ALTER VIEW''), N''CREATE VIEW'' COLLATE Latin1_General_CI_AS, N''CREATE OR ALTER VIEW''), N''<#COA_VIEW#>'', N''CREATE OR ALTER VIEW''), N''[''+ N''{#SOURCEDB#}'' +N'']'', N''[''+ N''{#TARGETDB#}'' +N'']''), N''{#SOURCEDB#}''+N''.'', N''{#TARGETDB#}''+N''.''), CHAR(39), CHAR(39)+CHAR(39)) + '''''';'', ISNULL(ml.dep,999) FROM {#SOURCEDB_Q#}.sys.views v JOIN {#SOURCEDB_Q#}.sys.sql_modules m ON m.object_id=v.object_id JOIN {#SOURCEDB_Q#}.sys.schemas s ON s.schema_id=v.schema_id -- Normalize whitespace: collapse 8->1, 4->1, 2->1 (twice for 3+ spaces) CROSS APPLY (SELECT REPLACE(REPLACE(REPLACE(REPLACE(CAST(m.definition AS NVARCHAR(max)){#COLLATION#}, N'' '', N'' ''), N'' '', N'' ''), N'' '', N'' ''), N'' '', N'' '') AS def) norm CROSS APPLY (SELECT HASHBYTES(''SHA2_256'', REPLACE(REPLACE(CAST(m.definition AS NVARCHAR(max)){#COLLATION#}, N''[''+ N''{#SOURCEDB#}'' +N'']'', N''[''+ N''{#TARGETDB#}'' +N'']''), N''{#SOURCEDB#}''+N''.'', N''{#TARGETDB#}''+N''.'')) AS src_hash) hsrc OUTER APPLY ( SELECT HASHBYTES(''SHA2_256'', CAST(tm.definition AS NVARCHAR(max)){#COLLATION#}) AS tgt_hash FROM {#TARGETDB_Q#}.sys.views tv JOIN {#TARGETDB_Q#}.sys.sql_modules tm ON tm.object_id=tv.object_id JOIN {#TARGETDB_Q#}.sys.schemas ts ON ts.schema_id=tv.schema_id WHERE ts.name{#COLLATION#}=s.name{#COLLATION#} AND tv.name{#COLLATION#}=v.name{#COLLATION#} ) htgt LEFT JOIN MaxLevel ml ON ml.object_id=v.object_id WHERE s.name{#COLLATION#}<>N''sys''{#COLLATION#} AND m.definition IS NOT NULL -- Skip encrypted objects (WITH ENCRYPTION) AND (N''{#SOURCECOLLATION_NAME#}'' COLLATE Latin1_General_CI_AS<>N''{#TARGETCOLLATION_NAME#}'' COLLATE Latin1_General_CI_AS OR htgt.tgt_hash IS NULL OR hsrc.src_hash<>htgt.tgt_hash) AND NOT EXISTS (SELECT 1 FROM #TBDD_SYNC_DATABASE_EXCLUDEDOBJECTS ex WHERE (ex.IsWildcard=1 AND (v.name{#COLLATION#} LIKE ex.Pattern{#COLLATION#} OR (s.name{#COLLATION#}+N''.''{#COLLATION#}+v.name{#COLLATION#}) LIKE ex.Pattern{#COLLATION#})) OR (ex.IsWildcard=0 AND (v.name{#COLLATION#}=ex.Pattern{#COLLATION#} OR (s.name{#COLLATION#}+N''.''{#COLLATION#}+v.name{#COLLATION#})=ex.Pattern{#COLLATION#}))) ) AS X(Phase, Command, SortOrder) WHERE X.Command IS NOT NULL AND LEN(X.Command)>0 ORDER BY X.SortOrder OPTION(MAXRECURSION 100);'; SET @DYNAMICSQL = REPLACE(REPLACE(REPLACE(@DYNAMICSQL, @PLACEHOLDERSOURCEDBQUOTED, @SOURCEDATABASEQUOTED), @PLACEHOLDERTARGETDBQUOTED, @TARGETDATABASEQUOTED), @PLACEHOLDERCOLLATION, @COMPARECOLLATION); SET @DYNAMICSQL = REPLACE(REPLACE(@DYNAMICSQL, @PLACEHOLDERSOURCEDB, @SOURCEDATABASE), @PLACEHOLDERTARGETDB, @TARGETDATABASE); SET @DYNAMICSQL = REPLACE(REPLACE(@DYNAMICSQL, @PLACEHOLDERSOURCECOLLATIONNAME, @SOURCECOLLATION), @PLACEHOLDERTARGETCOLLATIONNAME, @TARGETCOLLATION); SET @DYNAMICSQL = REPLACE(@DYNAMICSQL, @PLACEHOLDERDROPEXISTING, @DROPEXISTING_FILTER); BEGIN TRY EXEC sys.sp_executesql @DYNAMICSQL; IF @DEBUG = 1 PRINT '[DEBUG] View commands built successfully'; END TRY BEGIN CATCH PRINT '[ERROR] Failed to build View commands!'; PRINT '[ERROR] Error Message: ' + ERROR_MESSAGE(); PRINT '[ERROR] Dynamic SQL (first 8000 chars):'; PRINT SUBSTRING(@DYNAMICSQL, 1, 8000); IF LEN(@DYNAMICSQL) > 8000 PRINT '[ERROR] (continued): ' + SUBSTRING(@DYNAMICSQL, 8001, 8000); THROW; END CATCH; END ELSE PRINT '[INFO] Skipping Views (disabled by @pSYNCOBJECTS)'; ----------------------------------------------------------------------------------------------------------------------------- --=================================================-- Functions --================================================-- IF @SYNC_FUNCTIONS = 1 BEGIN SET @DYNAMICSQL = N' ;WITH FuncDeps AS ( SELECT o.object_id, 0 dep, CAST(CONCAT(N'','',o.object_id,N'','') AS NVARCHAR(MAX)) AS visited FROM {#SOURCEDB_Q#}.sys.objects o WHERE o.type IN (N''FN'',N''TF'',N''IF'',N''FS'',N''FT'') AND NOT EXISTS(SELECT 1 FROM {#SOURCEDB_Q#}.sys.sql_expression_dependencies d JOIN {#SOURCEDB_Q#}.sys.objects ro ON ro.object_id=d.referenced_id AND ro.type IN (N''FN'',N''TF'',N''IF'',N''FS'',N''FT'') WHERE d.referencing_id=o.object_id) UNION ALL SELECT o.object_id, fd.dep+1, CAST(CONCAT(fd.visited,o.object_id,N'','') AS NVARCHAR(MAX)) FROM {#SOURCEDB_Q#}.sys.objects o JOIN {#SOURCEDB_Q#}.sys.sql_expression_dependencies d ON d.referencing_id=o.object_id JOIN FuncDeps fd ON fd.object_id=d.referenced_id WHERE fd.visited NOT LIKE CONCAT(N''%,'',o.object_id,N'',%'') AND fd.dep < 50 ), MaxLevel AS (SELECT object_id, MAX(dep) dep FROM FuncDeps GROUP BY object_id) INSERT INTO #TBDD_SYNC_DATABASE_COMMANDS(Phase, Command) SELECT X.Phase, X.Command FROM ( -- First: Generate DROP statements for functions that need recreation (collation mismatch OR hash mismatch) SELECT N''12A-Functions-Drop'', N''EXEC {#TARGETDB_Q#}.sys.sp_executesql N''''DROP FUNCTION '' + QUOTENAME(ts.name) + N''.'' + QUOTENAME(tobj.name) + N'''''';'', 0 FROM {#SOURCEDB_Q#}.sys.objects o JOIN {#SOURCEDB_Q#}.sys.sql_modules m ON m.object_id=o.object_id JOIN {#SOURCEDB_Q#}.sys.schemas s ON s.schema_id=o.schema_id JOIN {#TARGETDB_Q#}.sys.objects tobj ON tobj.type IN (N''FN'',N''TF'',N''IF'',N''FS'',N''FT'') JOIN {#TARGETDB_Q#}.sys.sql_modules tgtm ON tgtm.object_id=tobj.object_id JOIN {#TARGETDB_Q#}.sys.schemas ts ON ts.schema_id=tobj.schema_id AND ts.name{#COLLATION#}=s.name{#COLLATION#} AND tobj.name{#COLLATION#}=o.name{#COLLATION#} CROSS APPLY (SELECT HASHBYTES(''SHA2_256'', REPLACE(REPLACE(CAST(m.definition AS NVARCHAR(max)){#COLLATION#}, N''[''+ N''{#SOURCEDB#}'' +N'']'', N''[''+ N''{#TARGETDB#}'' +N'']''), N''{#SOURCEDB#}''+N''.'', N''{#TARGETDB#}''+N''.'')) AS src_hash, HASHBYTES(''SHA2_256'', CAST(tgtm.definition AS NVARCHAR(max)){#COLLATION#}) AS tgt_hash) hcmp WHERE s.name{#COLLATION#}<>N''sys''{#COLLATION#} AND o.type IN (N''FN'',N''TF'',N''IF'',N''FS'',N''FT'') AND m.definition IS NOT NULL AND (N''{#SOURCECOLLATION_NAME#}'' COLLATE Latin1_General_CI_AS<>N''{#TARGETCOLLATION_NAME#}'' COLLATE Latin1_General_CI_AS OR hcmp.src_hash<>hcmp.tgt_hash) AND NOT EXISTS (SELECT 1 FROM #TBDD_SYNC_DATABASE_EXCLUDEDOBJECTS ex WHERE (ex.IsWildcard=1 AND (o.name{#COLLATION#} LIKE ex.Pattern{#COLLATION#} OR (s.name{#COLLATION#}+N''.''{#COLLATION#}+o.name{#COLLATION#}) LIKE ex.Pattern{#COLLATION#})) OR (ex.IsWildcard=0 AND (o.name{#COLLATION#}=ex.Pattern{#COLLATION#} OR (s.name{#COLLATION#}+N''.''{#COLLATION#}+o.name{#COLLATION#})=ex.Pattern{#COLLATION#}))){#DROPEXISTING_FILTER#} UNION ALL -- Second: Generate CREATE statements for all functions (robust: handles varying whitespace and case-insensitive) SELECT N''12B-Functions'', N''EXEC {#TARGETDB_Q#}.sys.sp_executesql N'''''' + REPLACE( REPLACE( REPLACE( -- Case-insensitive REPLACE chain on normalized definition: -- 1. CREATE OR ALTER FUNCTION -> placeholder (preserve existing) -- 2. ALTER FUNCTION -> CREATE OR ALTER FUNCTION -- 3. CREATE FUNCTION -> CREATE OR ALTER FUNCTION -- 4. placeholder -> CREATE OR ALTER FUNCTION (restore) REPLACE( REPLACE( REPLACE( REPLACE(norm.def COLLATE Latin1_General_CI_AS, N''CREATE OR ALTER FUNCTION'' COLLATE Latin1_General_CI_AS, N''<#COA_FUNC#>''), N''ALTER FUNCTION'' COLLATE Latin1_General_CI_AS, N''CREATE OR ALTER FUNCTION''), N''CREATE FUNCTION'' COLLATE Latin1_General_CI_AS, N''CREATE OR ALTER FUNCTION''), N''<#COA_FUNC#>'', N''CREATE OR ALTER FUNCTION''), N''[''+ N''{#SOURCEDB#}'' +N'']'', N''[''+ N''{#TARGETDB#}'' +N'']''), N''{#SOURCEDB#}''+N''.'', N''{#TARGETDB#}''+N''.''), CHAR(39), CHAR(39)+CHAR(39)) + '''''';'', ISNULL(ml.dep,999) FROM {#SOURCEDB_Q#}.sys.objects o JOIN {#SOURCEDB_Q#}.sys.sql_modules m ON m.object_id=o.object_id JOIN {#SOURCEDB_Q#}.sys.schemas s ON s.schema_id=o.schema_id -- Normalize whitespace: collapse 8->1, 4->1, 2->1 (twice for 3+ spaces) CROSS APPLY (SELECT REPLACE(REPLACE(REPLACE(REPLACE(CAST(m.definition AS NVARCHAR(max)){#COLLATION#}, N'' '', N'' ''), N'' '', N'' ''), N'' '', N'' ''), N'' '', N'' '') AS def) norm CROSS APPLY (SELECT HASHBYTES(''SHA2_256'', REPLACE(REPLACE(CAST(m.definition AS NVARCHAR(max)){#COLLATION#}, N''[''+ N''{#SOURCEDB#}'' +N'']'', N''[''+ N''{#TARGETDB#}'' +N'']''), N''{#SOURCEDB#}''+N''.'', N''{#TARGETDB#}''+N''.'')) AS src_hash) hsrc OUTER APPLY ( SELECT HASHBYTES(''SHA2_256'', CAST(tm.definition AS NVARCHAR(max)){#COLLATION#}) AS tgt_hash FROM {#TARGETDB_Q#}.sys.objects tobj JOIN {#TARGETDB_Q#}.sys.sql_modules tm ON tm.object_id=tobj.object_id JOIN {#TARGETDB_Q#}.sys.schemas ts ON ts.schema_id=tobj.schema_id WHERE ts.name{#COLLATION#}=s.name{#COLLATION#} AND tobj.name{#COLLATION#}=o.name{#COLLATION#} AND tobj.type IN (N''FN'',N''TF'',N''IF'',N''FS'',N''FT'') ) htgt LEFT JOIN MaxLevel ml ON ml.object_id=o.object_id WHERE s.name{#COLLATION#}<>N''sys''{#COLLATION#} AND o.type IN (N''FN'',N''TF'',N''IF'',N''FS'',N''FT'') AND m.definition IS NOT NULL -- Skip encrypted objects (WITH ENCRYPTION) AND (N''{#SOURCECOLLATION_NAME#}'' COLLATE Latin1_General_CI_AS<>N''{#TARGETCOLLATION_NAME#}'' COLLATE Latin1_General_CI_AS OR htgt.tgt_hash IS NULL OR hsrc.src_hash<>htgt.tgt_hash) AND NOT EXISTS (SELECT 1 FROM #TBDD_SYNC_DATABASE_EXCLUDEDOBJECTS ex WHERE (ex.IsWildcard=1 AND (o.name{#COLLATION#} LIKE ex.Pattern{#COLLATION#} OR (s.name{#COLLATION#}+N''.''{#COLLATION#}+o.name{#COLLATION#}) LIKE ex.Pattern{#COLLATION#})) OR (ex.IsWildcard=0 AND (o.name{#COLLATION#}=ex.Pattern{#COLLATION#} OR (s.name{#COLLATION#}+N''.''{#COLLATION#}+o.name{#COLLATION#})=ex.Pattern{#COLLATION#}))) ) AS X(Phase, Command, SortOrder) WHERE X.Command IS NOT NULL AND LEN(X.Command)>0 ORDER BY X.SortOrder OPTION(MAXRECURSION 100);'; SET @DYNAMICSQL = REPLACE(REPLACE(REPLACE(@DYNAMICSQL, @PLACEHOLDERSOURCEDBQUOTED, @SOURCEDATABASEQUOTED), @PLACEHOLDERTARGETDBQUOTED, @TARGETDATABASEQUOTED), @PLACEHOLDERCOLLATION, @COMPARECOLLATION); SET @DYNAMICSQL = REPLACE(REPLACE(@DYNAMICSQL, @PLACEHOLDERSOURCEDB, @SOURCEDATABASE), @PLACEHOLDERTARGETDB, @TARGETDATABASE); SET @DYNAMICSQL = REPLACE(REPLACE(@DYNAMICSQL, @PLACEHOLDERSOURCECOLLATIONNAME, @SOURCECOLLATION), @PLACEHOLDERTARGETCOLLATIONNAME, @TARGETCOLLATION); SET @DYNAMICSQL = REPLACE(@DYNAMICSQL, @PLACEHOLDERDROPEXISTING, @DROPEXISTING_FILTER); BEGIN TRY EXEC sys.sp_executesql @DYNAMICSQL; IF @DEBUG = 1 PRINT '[DEBUG] Function commands built successfully'; END TRY BEGIN CATCH PRINT '[ERROR] Failed to build Function commands!'; PRINT '[ERROR] Error Message: ' + ERROR_MESSAGE(); PRINT '[ERROR] Dynamic SQL (first 8000 chars):'; PRINT SUBSTRING(@DYNAMICSQL, 1, 8000); IF LEN(@DYNAMICSQL) > 8000 PRINT '[ERROR] (continued): ' + SUBSTRING(@DYNAMICSQL, 8001, 8000); THROW; END CATCH; END ELSE PRINT '[INFO] Skipping Functions (disabled by @pSYNCOBJECTS)'; ----------------------------------------------------------------------------------------------------------------------------- --=================================================-- Procedures --================================================-- IF @SYNC_PROCEDURES = 1 BEGIN SET @DYNAMICSQL = N' INSERT INTO #TBDD_SYNC_DATABASE_COMMANDS(Phase, Command) SELECT * FROM ( -- First: Generate DROP statements for procedures that need recreation (collation mismatch OR hash mismatch) SELECT N''13A-Procedures-Drop'', N''EXEC {#TARGETDB_Q#}.sys.sp_executesql N''''DROP PROCEDURE '' + QUOTENAME(ts.name) + N''.'' + QUOTENAME(tp.name) + N'''''';'' FROM {#SOURCEDB_Q#}.sys.procedures p JOIN {#SOURCEDB_Q#}.sys.sql_modules m ON m.object_id=p.object_id JOIN {#SOURCEDB_Q#}.sys.schemas s ON s.schema_id=p.schema_id JOIN {#TARGETDB_Q#}.sys.procedures tp ON 1=1 JOIN {#TARGETDB_Q#}.sys.sql_modules tgtm ON tgtm.object_id=tp.object_id JOIN {#TARGETDB_Q#}.sys.schemas ts ON ts.schema_id=tp.schema_id AND ts.name{#COLLATION#}=s.name{#COLLATION#} AND tp.name{#COLLATION#}=p.name{#COLLATION#} CROSS APPLY (SELECT HASHBYTES(''SHA2_256'', REPLACE(REPLACE(CAST(m.definition AS NVARCHAR(max)){#COLLATION#}, N''[''+ N''{#SOURCEDB#}'' +N'']'', N''[''+ N''{#TARGETDB#}'' +N'']''), N''{#SOURCEDB#}''+N''.'', N''{#TARGETDB#}''+N''.'')) AS src_hash, HASHBYTES(''SHA2_256'', CAST(tgtm.definition AS NVARCHAR(max)){#COLLATION#}) AS tgt_hash) hcmp WHERE s.name{#COLLATION#}<>N''sys''{#COLLATION#} AND m.definition IS NOT NULL AND (N''{#SOURCECOLLATION_NAME#}'' COLLATE Latin1_General_CI_AS<>N''{#TARGETCOLLATION_NAME#}'' COLLATE Latin1_General_CI_AS OR hcmp.src_hash<>hcmp.tgt_hash) AND NOT EXISTS (SELECT 1 FROM #TBDD_SYNC_DATABASE_EXCLUDEDOBJECTS ex WHERE (ex.IsWildcard=1 AND (p.name{#COLLATION#} LIKE ex.Pattern{#COLLATION#} OR (s.name{#COLLATION#}+N''.''{#COLLATION#}+p.name{#COLLATION#}) LIKE ex.Pattern{#COLLATION#})) OR (ex.IsWildcard=0 AND (p.name{#COLLATION#}=ex.Pattern{#COLLATION#} OR (s.name{#COLLATION#}+N''.''{#COLLATION#}+p.name{#COLLATION#})=ex.Pattern{#COLLATION#}))){#DROPEXISTING_FILTER#} UNION ALL -- Second: Generate CREATE statements for all procedures (robust: handles varying whitespace and case-insensitive) SELECT N''13B-Procedures'', N''EXEC {#TARGETDB_Q#}.sys.sp_executesql N'''''' + REPLACE( REPLACE( REPLACE( -- Case-insensitive REPLACE chain on normalized definition: -- 1. CREATE OR ALTER PROCEDURE -> placeholder (preserve existing) -- 2. ALTER PROCEDURE -> CREATE OR ALTER PROCEDURE -- 3. CREATE PROCEDURE -> CREATE OR ALTER PROCEDURE -- 4. placeholder -> CREATE OR ALTER PROCEDURE (restore) REPLACE( REPLACE( REPLACE( REPLACE(norm.def COLLATE Latin1_General_CI_AS, N''CREATE OR ALTER PROCEDURE'' COLLATE Latin1_General_CI_AS, N''<#COA_PROC#>''), N''ALTER PROCEDURE'' COLLATE Latin1_General_CI_AS, N''CREATE OR ALTER PROCEDURE''), N''CREATE PROCEDURE'' COLLATE Latin1_General_CI_AS, N''CREATE OR ALTER PROCEDURE''), N''<#COA_PROC#>'', N''CREATE OR ALTER PROCEDURE''), N''[''+ N''{#SOURCEDB#}'' +N'']'', N''[''+ N''{#TARGETDB#}'' +N'']''), N''{#SOURCEDB#}''+N''.'', N''{#TARGETDB#}''+N''.''), CHAR(39), CHAR(39)+CHAR(39)) + '''''';'' FROM {#SOURCEDB_Q#}.sys.procedures p JOIN {#SOURCEDB_Q#}.sys.sql_modules m ON m.object_id=p.object_id JOIN {#SOURCEDB_Q#}.sys.schemas s ON s.schema_id=p.schema_id -- Normalize whitespace: collapse 8->1, 4->1, 2->1 (twice for 3+ spaces) CROSS APPLY (SELECT REPLACE(REPLACE(REPLACE(REPLACE(CAST(m.definition AS NVARCHAR(max)){#COLLATION#}, N'' '', N'' ''), N'' '', N'' ''), N'' '', N'' ''), N'' '', N'' '') AS def) norm CROSS APPLY (SELECT HASHBYTES(''SHA2_256'', REPLACE(REPLACE(CAST(m.definition AS NVARCHAR(max)){#COLLATION#}, N''[''+ N''{#SOURCEDB#}'' +N'']'', N''[''+ N''{#TARGETDB#}'' +N'']''), N''{#SOURCEDB#}''+N''.'', N''{#TARGETDB#}''+N''.'')) AS src_hash) hsrc OUTER APPLY ( SELECT HASHBYTES(''SHA2_256'', CAST(tm.definition AS NVARCHAR(max)){#COLLATION#}) AS tgt_hash FROM {#TARGETDB_Q#}.sys.procedures tp JOIN {#TARGETDB_Q#}.sys.sql_modules tm ON tm.object_id=tp.object_id JOIN {#TARGETDB_Q#}.sys.schemas ts ON ts.schema_id=tp.schema_id WHERE ts.name{#COLLATION#}=s.name{#COLLATION#} AND tp.name{#COLLATION#}=p.name{#COLLATION#} ) htgt WHERE s.name{#COLLATION#}<>N''sys''{#COLLATION#} AND m.definition IS NOT NULL -- Skip encrypted objects (WITH ENCRYPTION) AND (N''{#SOURCECOLLATION_NAME#}'' COLLATE Latin1_General_CI_AS<>N''{#TARGETCOLLATION_NAME#}'' COLLATE Latin1_General_CI_AS OR htgt.tgt_hash IS NULL OR hsrc.src_hash<>htgt.tgt_hash) AND NOT EXISTS (SELECT 1 FROM #TBDD_SYNC_DATABASE_EXCLUDEDOBJECTS ex WHERE (ex.IsWildcard=1 AND (p.name{#COLLATION#} LIKE ex.Pattern{#COLLATION#} OR (s.name{#COLLATION#}+N''.''{#COLLATION#}+p.name{#COLLATION#}) LIKE ex.Pattern{#COLLATION#})) OR (ex.IsWildcard=0 AND (p.name{#COLLATION#}=ex.Pattern{#COLLATION#} OR (s.name{#COLLATION#}+N''.''{#COLLATION#}+p.name{#COLLATION#})=ex.Pattern{#COLLATION#}))) ) AS X(Phase, Command) WHERE X.Command IS NOT NULL AND LEN(X.Command)>0;'; SET @DYNAMICSQL = REPLACE(REPLACE(REPLACE(@DYNAMICSQL, @PLACEHOLDERSOURCEDBQUOTED, @SOURCEDATABASEQUOTED), @PLACEHOLDERTARGETDBQUOTED, @TARGETDATABASEQUOTED), @PLACEHOLDERCOLLATION, @COMPARECOLLATION); SET @DYNAMICSQL = REPLACE(REPLACE(@DYNAMICSQL, @PLACEHOLDERSOURCEDB, @SOURCEDATABASE), @PLACEHOLDERTARGETDB, @TARGETDATABASE); SET @DYNAMICSQL = REPLACE(REPLACE(@DYNAMICSQL, @PLACEHOLDERSOURCECOLLATIONNAME, @SOURCECOLLATION), @PLACEHOLDERTARGETCOLLATIONNAME, @TARGETCOLLATION); SET @DYNAMICSQL = REPLACE(@DYNAMICSQL, @PLACEHOLDERDROPEXISTING, @DROPEXISTING_FILTER); BEGIN TRY EXEC sys.sp_executesql @DYNAMICSQL; IF @DEBUG = 1 PRINT '[DEBUG] Procedure commands built successfully'; END TRY BEGIN CATCH PRINT '[ERROR] Failed to build Procedure commands!'; PRINT '[ERROR] Error Message: ' + ERROR_MESSAGE(); PRINT '[ERROR] Dynamic SQL (first 8000 chars):'; PRINT SUBSTRING(@DYNAMICSQL, 1, 8000); IF LEN(@DYNAMICSQL) > 8000 PRINT '[ERROR] (continued): ' + SUBSTRING(@DYNAMICSQL, 8001, 8000); THROW; END CATCH; END ELSE PRINT '[INFO] Skipping Procedures (disabled by @pSYNCOBJECTS)'; ----------------------------------------------------------------------------------------------------------------------------- --=================================================-- Sequences (fehlend oder abweichend -> Drop/Create) --================================================-- IF @SYNC_SEQUENCES = 1 BEGIN SET @DYNAMICSQL = N' INSERT INTO #TBDD_SYNC_DATABASE_COMMANDS(Phase, Command) SELECT * FROM ( SELECT N''14-Sequences'', N''USE {#TARGETDB_Q#}; '' + CASE WHEN tseq.object_id IS NOT NULL THEN N''DROP SEQUENCE '' + QUOTENAME(s.name)+N''.'' + QUOTENAME(seq.name) + N''; '' ELSE N'''' END + N''CREATE SEQUENCE '' + QUOTENAME(s.name) + N''.'' + QUOTENAME(seq.name) + N'' AS '' + ty.name + N'' START WITH '' + CONVERT(NVARCHAR(50), ISNULL(seq.current_value, seq.start_value)) + N'' INCREMENT BY '' + CONVERT(NVARCHAR(50), seq.increment) + CASE WHEN seq.minimum_value IS NOT NULL THEN N'' MINVALUE '' + CONVERT(NVARCHAR(50), seq.minimum_value) ELSE N'' NO MINVALUE'' END + CASE WHEN seq.maximum_value IS NOT NULL THEN N'' MAXVALUE '' + CONVERT(NVARCHAR(50), seq.maximum_value) ELSE N'' NO MAXVALUE'' END + CASE WHEN seq.is_cycling=1 THEN N'' CYCLE'' ELSE N'' NO CYCLE'' END + CASE WHEN seq.is_cached=1 THEN N'' CACHE '' + CONVERT(NVARCHAR(50), ISNULL(seq.cache_size, 50)) ELSE N'' NO CACHE'' END + N'';'' FROM {#SOURCEDB_Q#}.sys.sequences seq JOIN {#SOURCEDB_Q#}.sys.schemas s ON s.schema_id=seq.schema_id JOIN {#SOURCEDB_Q#}.sys.types ty ON ty.user_type_id=seq.user_type_id LEFT JOIN {#TARGETDB_Q#}.sys.schemas ts ON ts.name{#COLLATION#}=s.name{#COLLATION#} LEFT JOIN {#TARGETDB_Q#}.sys.sequences tseq ON tseq.schema_id=ts.schema_id AND tseq.name{#COLLATION#}=seq.name{#COLLATION#} LEFT JOIN {#TARGETDB_Q#}.sys.types tty ON tty.user_type_id=tseq.user_type_id WHERE s.name{#COLLATION#}<>N''sys''{#COLLATION#} AND (tseq.object_id IS NULL OR seq.increment<>tseq.increment OR seq.minimum_value<>tseq.minimum_value OR seq.maximum_value<>tseq.maximum_value OR seq.is_cycling<>tseq.is_cycling OR ty.name{#COLLATION#}<>tty.name{#COLLATION#}) AND NOT EXISTS (SELECT 1 FROM #TBDD_SYNC_DATABASE_EXCLUDEDOBJECTS ex WHERE (ex.IsWildcard=1 AND (seq.name{#COLLATION#} LIKE ex.Pattern{#COLLATION#} OR (s.name{#COLLATION#}+N''.''{#COLLATION#}+seq.name{#COLLATION#}) LIKE ex.Pattern{#COLLATION#})) OR (ex.IsWildcard=0 AND (seq.name{#COLLATION#}=ex.Pattern{#COLLATION#} OR (s.name{#COLLATION#}+N''.''{#COLLATION#}+seq.name{#COLLATION#})=ex.Pattern{#COLLATION#}))) ) AS X(Phase, Command) WHERE X.Command IS NOT NULL AND LEN(X.Command)>0;'; SET @DYNAMICSQL = REPLACE(REPLACE(REPLACE(@DYNAMICSQL, @PLACEHOLDERSOURCEDBQUOTED, @SOURCEDATABASEQUOTED), @PLACEHOLDERTARGETDBQUOTED, @TARGETDATABASEQUOTED), @PLACEHOLDERCOLLATION, @COMPARECOLLATION); SET @DYNAMICSQL = REPLACE(REPLACE(@DYNAMICSQL, @PLACEHOLDERSOURCEDB, @SOURCEDATABASE), @PLACEHOLDERTARGETDB, @TARGETDATABASE); BEGIN TRY EXEC sys.sp_executesql @DYNAMICSQL; IF @DEBUG = 1 PRINT '[DEBUG] Sequence commands built successfully'; END TRY BEGIN CATCH PRINT '[ERROR] Failed to build Sequence commands!'; PRINT '[ERROR] Error Message: ' + ERROR_MESSAGE(); PRINT '[ERROR] Dynamic SQL (first 8000 chars):'; PRINT SUBSTRING(@DYNAMICSQL, 1, 8000); IF LEN(@DYNAMICSQL) > 8000 PRINT '[ERROR] (continued): ' + SUBSTRING(@DYNAMICSQL, 8001, 8000); THROW; END CATCH; END ELSE PRINT '[INFO] Skipping Sequences (disabled by @pSYNCOBJECTS)'; ----------------------------------------------------------------------------------------------------------------------------- --=================================================-- Synonyms (Drop/Create bei Abweichungen) --================================================-- IF @SYNC_SYNONYMS = 1 BEGIN SET @DYNAMICSQL = N' INSERT INTO #TBDD_SYNC_DATABASE_COMMANDS(Phase, Command) SELECT * FROM ( SELECT N''15-Synonyms'', N''USE {#TARGETDB_Q#}; '' + CASE WHEN tgt.object_id IS NOT NULL THEN N''DROP SYNONYM '' + QUOTENAME(s.name)+N''.'' + QUOTENAME(sn.name) + N''; '' ELSE N'''' END + N''CREATE SYNONYM '' + QUOTENAME(s.name) + N''.'' + QUOTENAME(sn.name) + N'' FOR '' + sn.base_object_name FROM {#SOURCEDB_Q#}.sys.synonyms sn JOIN {#SOURCEDB_Q#}.sys.schemas s ON s.schema_id=sn.schema_id OUTER APPLY ( SELECT tsn.object_id, tsn.base_object_name FROM {#TARGETDB_Q#}.sys.synonyms tsn JOIN {#TARGETDB_Q#}.sys.schemas ts ON ts.schema_id=tsn.schema_id WHERE ts.name{#COLLATION#}=s.name{#COLLATION#} AND tsn.name{#COLLATION#}=sn.name{#COLLATION#} ) tgt WHERE s.name{#COLLATION#}<>N''sys''{#COLLATION#} AND (tgt.object_id IS NULL OR ISNULL(tgt.base_object_name{#COLLATION#},N'''')<>ISNULL(sn.base_object_name{#COLLATION#},N'''')) AND (PARSENAME(sn.base_object_name,3) IS NULL OR PARSENAME(sn.base_object_name,3){#COLLATION#}=N''{#SOURCEDB#}''{#COLLATION#}) AND NOT EXISTS (SELECT 1 FROM #TBDD_SYNC_DATABASE_EXCLUDEDOBJECTS ex WHERE (ex.IsWildcard=1 AND (sn.name{#COLLATION#} LIKE ex.Pattern{#COLLATION#} OR (s.name{#COLLATION#}+N''.''{#COLLATION#}+sn.name{#COLLATION#}) LIKE ex.Pattern{#COLLATION#})) OR (ex.IsWildcard=0 AND (sn.name{#COLLATION#}=ex.Pattern{#COLLATION#} OR (s.name{#COLLATION#}+N''.''{#COLLATION#}+sn.name{#COLLATION#})=ex.Pattern{#COLLATION#}))) ) AS X(Phase, Command) WHERE X.Command IS NOT NULL AND LEN(X.Command)>0;'; SET @DYNAMICSQL = REPLACE(REPLACE(REPLACE(@DYNAMICSQL, @PLACEHOLDERSOURCEDBQUOTED, @SOURCEDATABASEQUOTED), @PLACEHOLDERTARGETDBQUOTED, @TARGETDATABASEQUOTED), @PLACEHOLDERCOLLATION, @COMPARECOLLATION); SET @DYNAMICSQL = REPLACE(REPLACE(@DYNAMICSQL, @PLACEHOLDERSOURCEDB, @SOURCEDATABASE), @PLACEHOLDERTARGETDB, @TARGETDATABASE); BEGIN TRY EXEC sys.sp_executesql @DYNAMICSQL; IF @DEBUG = 1 PRINT '[DEBUG] Synonym commands built successfully'; END TRY BEGIN CATCH PRINT '[ERROR] Failed to build Synonym commands!'; PRINT '[ERROR] Error Message: ' + ERROR_MESSAGE(); PRINT '[ERROR] Dynamic SQL (first 8000 chars):'; PRINT SUBSTRING(@DYNAMICSQL, 1, 8000); IF LEN(@DYNAMICSQL) > 8000 PRINT '[ERROR] (continued): ' + SUBSTRING(@DYNAMICSQL, 8001, 8000); THROW; END CATCH; END ELSE PRINT '[INFO] Skipping Synonyms (disabled by @pSYNCOBJECTS)'; ----------------------------------------------------------------------------------------------------------------------------- --=================================================-- Datenabgleich (optional, Tabellen mit PK) --================================================-- IF @INCLUDEDATA = 1 BEGIN --===============================================-- Log result to table --=================================================-- IF (UPPER(@LOGLEVEL) IN (N'INFO',N'WARN',N'ERROR')) BEGIN INSERT INTO [TBDD_SYNC_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [ADDED_WHO], [ADDED_WHEN]) VALUES ('INFO', '04-Data', 'Data-Sync aktiviert', 'Hash-basierter Datenabgleich, DeleteMissing: '+CONVERT(NVARCHAR(1),@DELETEMISSING), @MY_PROCEDURE_NAME, GETDATE()); END; ----------------------------------------------------------------------------------------------------------------------------- SET @DELCLAUSE = CASE WHEN @DELETEMISSING=1 THEN N' WHEN NOT MATCHED BY SOURCE THEN DELETE' ELSE N'' END; SET @DYNAMICSQL = N' INSERT INTO #TBDD_SYNC_DATABASE_COMMANDS(Phase, Command) SELECT * FROM ( SELECT N''20-Data'', N''USE {#TARGETDB_Q#}; IF OBJECT_ID(N'''''' + QUOTENAME(sch.name)+N''.'' + QUOTENAME(t.name) + N'''''', N''''U'''') IS NULL RETURN; DECLARE @rcs BIGINT, @rct BIGINT, @chks INT, @chkt INT; SELECT @rcs=COUNT(*), @chks=CHECKSUM_AGG(BINARY_CHECKSUM(''+cols.ChecksumCols+'')) FROM {#SOURCEDB_Q#}.''+QUOTENAME(sch.name)+N''.''{#COLLATION#}+QUOTENAME(t.name)+''; SELECT @rct=COUNT(*), @chkt=CHECKSUM_AGG(BINARY_CHECKSUM(''+cols.ChecksumCols+'')) FROM {#TARGETDB_Q#}.''+QUOTENAME(sch.name)+N''.''{#COLLATION#}+QUOTENAME(t.name)+''; IF @rcs<>@rct OR ISNULL(@chks,-1)<>ISNULL(@chkt,-1) BEGIN '' + CASE WHEN idc.object_id IS NOT NULL THEN N''SET IDENTITY_INSERT ''+QUOTENAME(sch.name)+N''.''{#COLLATION#}+QUOTENAME(t.name)+'' ON; '' ELSE N'''' END + N''MERGE {#TARGETDB_Q#}.''+QUOTENAME(sch.name)+N''.''{#COLLATION#}+QUOTENAME(t.name)+'' AS tgt USING {#SOURCEDB_Q#}.''+QUOTENAME(sch.name)+N''.''{#COLLATION#}+QUOTENAME(t.name)+'' AS src ON ''+pkhash.JoinCondition+'' '' + CASE WHEN cols.UpdateList IS NOT NULL AND cols.UpdateList<>'''' THEN N''WHEN MATCHED AND BINARY_CHECKSUM(''+pkhash.HashSrcCols+'') <> BINARY_CHECKSUM(''+pkhash.HashTgtCols+'') THEN UPDATE SET ''+cols.UpdateList+'' '' ELSE N'''' END + N''WHEN NOT MATCHED THEN INSERT(''+cols.InsertCols+'') VALUES(''+cols.InsertVals+'')'' + N''@DEL_CLAUSE@'' + N''; '' + CASE WHEN idc.object_id IS NOT NULL THEN N''SET IDENTITY_INSERT ''+QUOTENAME(sch.name)+N''.''{#COLLATION#}+QUOTENAME(t.name)+'' OFF;'' ELSE N'''' END + N'' END;'' FROM {#SOURCEDB_Q#}.sys.tables t JOIN {#SOURCEDB_Q#}.sys.schemas sch ON sch.schema_id=t.schema_id JOIN {#SOURCEDB_Q#}.sys.key_constraints pkc ON pkc.parent_object_id=t.object_id AND pkc.type{#COLLATION#}=''PK''{#COLLATION#} OUTER APPLY ( SELECT STUFF((SELECT '' AND src.''+QUOTENAME(c.name)+'' = tgt.''+QUOTENAME(c.name) FROM {#SOURCEDB_Q#}.sys.index_columns ic JOIN {#SOURCEDB_Q#}.sys.columns c ON c.object_id=ic.object_id AND c.column_id=ic.column_id WHERE ic.object_id=pkc.parent_object_id AND ic.index_id=pkc.unique_index_id ORDER BY ic.key_ordinal FOR XML PATH(''''), TYPE).value(''.'',''nvarchar(max)''),1,5,N'''') AS JoinCondition, STUFF((SELECT '','' + ''src.''+QUOTENAME(c.name) FROM {#SOURCEDB_Q#}.sys.columns c JOIN {#SOURCEDB_Q#}.sys.types tyh ON tyh.user_type_id=c.user_type_id WHERE c.object_id=t.object_id AND c.is_computed=0 AND tyh.name{#COLLATION#} NOT IN (N''text'',N''ntext'',N''image'',N''xml'',N''geography'',N''geometry'',N''hierarchyid'',N''timestamp'',N''rowversion'') ORDER BY c.column_id FOR XML PATH(''''), TYPE).value(''.'',''nvarchar(max)''),1,1,N'''') AS HashSrcCols, STUFF((SELECT '','' + ''tgt.''+QUOTENAME(c.name) FROM {#SOURCEDB_Q#}.sys.columns c JOIN {#SOURCEDB_Q#}.sys.types tyh ON tyh.user_type_id=c.user_type_id WHERE c.object_id=t.object_id AND c.is_computed=0 AND tyh.name{#COLLATION#} NOT IN (N''text'',N''ntext'',N''image'',N''xml'',N''geography'',N''geometry'',N''hierarchyid'',N''timestamp'',N''rowversion'') ORDER BY c.column_id FOR XML PATH(''''), TYPE).value(''.'',''nvarchar(max)''),1,1,N'''') AS HashTgtCols ) pkhash CROSS APPLY ( SELECT STUFF((SELECT '',''{#COLLATION#}+QUOTENAME(c.name) FROM {#SOURCEDB_Q#}.sys.columns c JOIN {#SOURCEDB_Q#}.sys.types ty2 ON ty2.user_type_id=c.user_type_id WHERE c.object_id=t.object_id AND c.is_computed=0 AND ty2.name{#COLLATION#} NOT IN (N''text'',N''ntext'',N''image'',N''xml'',N''geography'',N''geometry'',N''hierarchyid'',N''timestamp'',N''rowversion'') ORDER BY c.column_id FOR XML PATH(''''), TYPE).value(''.'',''nvarchar(max)''),1,1,N'''') AS InsertCols, STUFF((SELECT '','' + ''src.''+QUOTENAME(c.name) FROM {#SOURCEDB_Q#}.sys.columns c JOIN {#SOURCEDB_Q#}.sys.types ty2 ON ty2.user_type_id=c.user_type_id WHERE c.object_id=t.object_id AND c.is_computed=0 AND ty2.name{#COLLATION#} NOT IN (N''text'',N''ntext'',N''image'',N''xml'',N''geography'',N''geometry'',N''hierarchyid'',N''timestamp'',N''rowversion'') ORDER BY c.column_id FOR XML PATH(''''), TYPE).value(''.'',''nvarchar(max)''),1,1,N'''') AS InsertVals, STUFF((SELECT '',''{#COLLATION#}+QUOTENAME(c.name)+'' = src.''+QUOTENAME(c.name) FROM {#SOURCEDB_Q#}.sys.columns c JOIN {#SOURCEDB_Q#}.sys.types ty2 ON ty2.user_type_id=c.user_type_id LEFT JOIN {#SOURCEDB_Q#}.sys.index_columns ic ON ic.object_id=c.object_id AND ic.column_id=c.column_id AND ic.index_id=pkc.unique_index_id WHERE c.object_id=t.object_id AND c.is_computed=0 AND ISNULL(ic.key_ordinal,0)=0 AND ty2.name{#COLLATION#} NOT IN (N''text'',N''ntext'',N''image'',N''xml'',N''geography'',N''geometry'',N''hierarchyid'',N''timestamp'',N''rowversion'') ORDER BY c.column_id FOR XML PATH(''''), TYPE).value(''.'',''nvarchar(max)''),1,1,N'''') AS UpdateList, ISNULL(STUFF((SELECT '',''{#COLLATION#}+QUOTENAME(c.name) FROM {#SOURCEDB_Q#}.sys.columns c JOIN {#SOURCEDB_Q#}.sys.types ty2 ON ty2.user_type_id=c.user_type_id WHERE c.object_id=t.object_id AND c.is_computed=0 AND ty2.name{#COLLATION#} NOT IN (N''text'',N''ntext'',N''image'',N''xml'',N''geography'',N''geometry'',N''hierarchyid'',N''timestamp'',N''rowversion'') ORDER BY c.column_id FOR XML PATH(''''), TYPE).value(''.'',''nvarchar(max)''),1,1,N''''), N''0'') AS ChecksumCols ) cols LEFT JOIN {#SOURCEDB_Q#}.sys.identity_columns idc ON idc.object_id=t.object_id WHERE sch.name{#COLLATION#}<>N''sys''{#COLLATION#} AND t.is_ms_shipped=0 AND pkhash.JoinCondition IS NOT NULL AND NOT EXISTS (SELECT 1 FROM #TBDD_SYNC_DATABASE_EXCLUDEDOBJECTS ex WHERE (ex.IsWildcard=1 AND (t.name{#COLLATION#} LIKE ex.Pattern{#COLLATION#} OR (sch.name{#COLLATION#}+N''.''{#COLLATION#}+t.name{#COLLATION#}) LIKE ex.Pattern{#COLLATION#})) OR (ex.IsWildcard=0 AND (t.name{#COLLATION#}=ex.Pattern{#COLLATION#} OR (sch.name{#COLLATION#}+N''.''{#COLLATION#}+t.name{#COLLATION#})=ex.Pattern{#COLLATION#}))) ) AS X(Phase, Command) WHERE X.Command IS NOT NULL AND LEN(X.Command)>0;'; SET @DYNAMICSQL = REPLACE(@DYNAMICSQL, N'@DEL_CLAUSE@', @DELCLAUSE); SET @DYNAMICSQL = REPLACE(REPLACE(REPLACE(@DYNAMICSQL, @PLACEHOLDERSOURCEDBQUOTED, @SOURCEDATABASEQUOTED), @PLACEHOLDERTARGETDBQUOTED, @TARGETDATABASEQUOTED), @PLACEHOLDERCOLLATION, @COMPARECOLLATION); SET @DYNAMICSQL = REPLACE(REPLACE(@DYNAMICSQL, @PLACEHOLDERSOURCEDB, @SOURCEDATABASE), @PLACEHOLDERTARGETDB, @TARGETDATABASE); BEGIN TRY EXEC sys.sp_executesql @DYNAMICSQL; IF @DEBUG = 1 PRINT '[DEBUG] Data commands built successfully'; END TRY BEGIN CATCH PRINT '[ERROR] Failed to build Data commands!'; PRINT '[ERROR] Error Message: ' + ERROR_MESSAGE(); PRINT '[ERROR] Dynamic SQL (first 8000 chars):'; PRINT SUBSTRING(@DYNAMICSQL, 1, 8000); IF LEN(@DYNAMICSQL) > 8000 PRINT '[ERROR] (continued): ' + SUBSTRING(@DYNAMICSQL, 8001, 8000); THROW; END CATCH; END; ----------------------------------------------------------------------------------------------------------------------------- --=================================================-- Platzhalter ersetzen --================================================-- -- Performance: Ein UPDATE mit mehrfachem REPLACE statt vier separate UPDATEs UPDATE #TBDD_SYNC_DATABASE_COMMANDS SET Command = REPLACE( REPLACE( REPLACE( REPLACE(Command, @PLACEHOLDERSOURCEDBQUOTED, @SOURCEDATABASEQUOTED), @PLACEHOLDERTARGETDBQUOTED, @TARGETDATABASEQUOTED), @PLACEHOLDERSOURCEDB, @SOURCEDATABASE), @PLACEHOLDERTARGETDB, @TARGETDATABASE); --=================================================-- Befehle generiert --=================================================-- DECLARE @COMMANDCOUNT INT = (SELECT COUNT(*) FROM #TBDD_SYNC_DATABASE_COMMANDS); --===============================================-- Log result to table --=================================================-- IF (UPPER(@LOGLEVEL) IN (N'INFO',N'WARN',N'ERROR')) BEGIN INSERT INTO [TBDD_SYNC_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [ADDED_WHO], [ADDED_WHEN]) VALUES ('INFO', '05-Planning', 'Befehle generiert', 'Anzahl: '+CONVERT(NVARCHAR(10),@COMMANDCOUNT)+', Execute-Modus: '+CONVERT(NVARCHAR(1),@EXECUTE), @MY_PROCEDURE_NAME, GETDATE()); END; ----------------------------------------------------------------------------------------------------------------------------- --=================================================-- SYNC SUMMARY --=================================================-- -- Zusammenfassung der zu synchronisierenden Objekte (nur wenn Commands vorhanden) IF @COMMANDCOUNT > 0 BEGIN PRINT N''; PRINT N'===================================================================================================='; PRINT N' SYNCHRONIZATION SUMMARY'; PRINT N'===================================================================================================='; PRINT N'Source: ' + @SOURCEDATABASE + N' --> Target: ' + @TARGETDATABASE; PRINT N'Execute Mode: ' + CASE WHEN @EXECUTE = 1 THEN N'LIVE (Changes will be applied)' ELSE N'DRY-RUN (Preview only)' END; PRINT N'----------------------------------------------------------------------------------------------------'; -- Aggregierte Übersicht nach Objekttyp DECLARE @SummaryTable TABLE ( Category NVARCHAR(50), ObjectType NVARCHAR(50), ObjectCount INT, SortOrder INT ); INSERT INTO @SummaryTable (Category, ObjectType, ObjectCount, SortOrder) SELECT CASE WHEN Phase LIKE '01-Security%' THEN 'Security' WHEN Phase = '02-Schemas' THEN 'Schemas' WHEN Phase LIKE '03-Table%' THEN 'Tables' WHEN Phase = '04-FK-DropForPK' THEN 'FK Drops (for PK)' WHEN Phase = '05-PrimaryKeys' THEN 'Primary Keys' WHEN Phase = '06-ForeignKeys' THEN 'Foreign Keys' WHEN Phase = '07-Indexes' THEN 'Indexes' WHEN Phase LIKE '10%Triggers%' THEN 'Triggers' WHEN Phase LIKE '11%Views%' THEN 'Views' WHEN Phase LIKE '12%Functions%' THEN 'Functions' WHEN Phase LIKE '13%Procedures%' THEN 'Procedures' WHEN Phase = '14-Sequences' THEN 'Sequences' WHEN Phase = '15-Synonyms' THEN 'Synonyms' WHEN Phase = '20-Data' THEN 'Data Sync' ELSE 'Other' END, CASE WHEN Phase = '01-Security-Roles' THEN 'Roles' WHEN Phase = '01-Security-Users' THEN 'Users' WHEN Phase = '01-Security-RoleMembers' THEN 'Role Members' WHEN Phase = '01-Security-Grants' THEN 'Permissions' WHEN Phase = '02-Schemas' THEN 'Schemas' WHEN Phase = '03-Tables' THEN 'New Tables' WHEN Phase = '03-Table-AddColumns' THEN 'Add Columns' WHEN Phase = '03-Table-AlterColumns' THEN 'Alter Columns' WHEN Phase = '03-Table-Defaults' THEN 'Default Constraints' WHEN Phase = '03-Table-Checks' THEN 'Check Constraints' WHEN Phase = '03-Table-Unique' THEN 'Unique Constraints' WHEN Phase = '04-FK-DropForPK' THEN 'FK Drops' WHEN Phase = '05-PrimaryKeys' THEN 'Primary Keys' WHEN Phase = '06-ForeignKeys' THEN 'Foreign Keys' WHEN Phase = '07-Indexes' THEN 'Indexes' WHEN Phase LIKE '10%Triggers%' THEN 'Triggers' WHEN Phase LIKE '11%Views%' THEN 'Views' WHEN Phase LIKE '12%Functions%' THEN 'Functions' WHEN Phase LIKE '13%Procedures%' THEN 'Procedures' WHEN Phase = '14-Sequences' THEN 'Sequences' WHEN Phase = '15-Synonyms' THEN 'Synonyms' WHEN Phase = '20-Data' THEN 'Tables with Data' ELSE Phase END, COUNT(*), CASE WHEN Phase LIKE '01%' THEN 1 WHEN Phase LIKE '02%' THEN 2 WHEN Phase LIKE '03%' THEN 3 WHEN Phase LIKE '04%' THEN 4 WHEN Phase LIKE '05%' THEN 5 WHEN Phase LIKE '06%' THEN 6 WHEN Phase LIKE '07%' THEN 7 WHEN Phase LIKE '10%' THEN 10 WHEN Phase LIKE '11%' THEN 11 WHEN Phase LIKE '12%' THEN 12 WHEN Phase LIKE '13%' THEN 13 WHEN Phase LIKE '14%' THEN 14 WHEN Phase LIKE '15%' THEN 15 WHEN Phase LIKE '20%' THEN 20 ELSE 99 END FROM #TBDD_SYNC_DATABASE_COMMANDS GROUP BY Phase; -- Print Summary Header PRINT N''; PRINT N'TOTAL COMMANDS TO ' + CASE WHEN @EXECUTE = 1 THEN N'EXECUTE' ELSE N'PREVIEW' END + N': ' + CONVERT(NVARCHAR(10), @COMMANDCOUNT); PRINT N''; -- Kategorisierte Ausgabe per Cursor DECLARE @Cat NVARCHAR(50), @ObjType NVARCHAR(50), @ObjCount INT, @LastCat NVARCHAR(50) = N''; DECLARE summary_cursor CURSOR LOCAL FAST_FORWARD FOR SELECT Category, ObjectType, ObjectCount FROM @SummaryTable ORDER BY SortOrder, ObjectType; OPEN summary_cursor; FETCH NEXT FROM summary_cursor INTO @Cat, @ObjType, @ObjCount; WHILE @@FETCH_STATUS = 0 BEGIN IF @Cat <> @LastCat BEGIN IF @LastCat <> N'' PRINT N''; PRINT N'[ ' + @Cat + N' ]'; SET @LastCat = @Cat; END; PRINT N' ' + @ObjType + N': ' + CONVERT(NVARCHAR(10), @ObjCount); FETCH NEXT FROM summary_cursor INTO @Cat, @ObjType, @ObjCount; END; CLOSE summary_cursor; DEALLOCATE summary_cursor; -- Detaillierte Objektliste nur bei DEBUG-Modus IF @DEBUG = 1 BEGIN PRINT N''; PRINT N'===================================================================================================='; PRINT N' OBJECT DETAILS BY CATEGORY'; PRINT N'===================================================================================================='; -- Detaillierte Objektliste per Phase mit extrahierten Objektnamen -- Vereinfachte, robuste Extraktion DECLARE @DetailPhase NVARCHAR(50), @DetailObjectName NVARCHAR(500), @LastPhase NVARCHAR(50) = N''; DECLARE detail_cursor CURSOR LOCAL FAST_FORWARD FOR SELECT Phase, -- Phase-basierte Objektnamen-Extraktion CASE -- 02-Schemas: Extrahiere aus "name = N'SchemaName'" WHEN Phase = N'02-Schemas' AND CHARINDEX('name = N''', Command) > 0 THEN LEFT(SUBSTRING(Command, CHARINDEX('name = N''', Command) + 9, 100), ISNULL(NULLIF(CHARINDEX('''', SUBSTRING(Command, CHARINDEX('name = N''', Command) + 9, 100)), 0), 50) - 1) -- 11-Views: N'CREATE VIEW ObjectName WHEN Phase = N'11B-Views' AND CHARINDEX('N''CREATE VIEW ', Command) > 0 THEN LEFT(SUBSTRING(Command, CHARINDEX('N''CREATE VIEW ', Command) + 14, 200), ISNULL(NULLIF(CHARINDEX(' ', SUBSTRING(Command, CHARINDEX('N''CREATE VIEW ', Command) + 14, 200)), 0), 100) - 1) -- 12-Functions: N'CREATE FUNCTION ObjectName WHEN Phase = N'12B-Functions' AND CHARINDEX('N''CREATE FUNCTION ', Command) > 0 THEN LEFT(SUBSTRING(Command, CHARINDEX('N''CREATE FUNCTION ', Command) + 18, 200), ISNULL(NULLIF(CHARINDEX('(', SUBSTRING(Command, CHARINDEX('N''CREATE FUNCTION ', Command) + 18, 200)), 0), 100) - 1) -- 13-Procedures: N'CREATE PROCEDURE ObjectName WHEN Phase = N'13B-Procedures' AND CHARINDEX('N''CREATE PROCEDURE ', Command) > 0 THEN LEFT(SUBSTRING(Command, CHARINDEX('N''CREATE PROCEDURE ', Command) + 19, 200), ISNULL(NULLIF(CHARINDEX(' ', SUBSTRING(Command, CHARINDEX('N''CREATE PROCEDURE ', Command) + 19, 200)), 0), 100) - 1) -- 10-Triggers: N'CREATE TRIGGER ObjectName WHEN Phase = N'10B-Triggers' AND CHARINDEX('N''CREATE TRIGGER ', Command) > 0 THEN LEFT(SUBSTRING(Command, CHARINDEX('N''CREATE TRIGGER ', Command) + 17, 200), ISNULL(NULLIF(CHARINDEX(' ', SUBSTRING(Command, CHARINDEX('N''CREATE TRIGGER ', Command) + 17, 200)), 0), 100) - 1) WHEN Command LIKE '%ALTER TABLE %' THEN LEFT(SUBSTRING(Command, CHARINDEX('ALTER TABLE ', Command) + 12, 200), ISNULL(NULLIF(CHARINDEX(' ', SUBSTRING(Command, CHARINDEX('ALTER TABLE ', Command) + 12, 200)), 0), 200) - 1) WHEN Command LIKE '%CREATE TABLE %' THEN LEFT(SUBSTRING(Command, CHARINDEX('CREATE TABLE ', Command) + 13, 200), ISNULL(NULLIF(CHARINDEX('(', SUBSTRING(Command, CHARINDEX('CREATE TABLE ', Command) + 13, 200)), 0), 200) - 1) -- Constraints: ADD CONSTRAINT [Name] WHEN Command LIKE '%ADD CONSTRAINT %' THEN LEFT(SUBSTRING(Command, CHARINDEX('ADD CONSTRAINT ', Command) + 15, 200), ISNULL(NULLIF(CHARINDEX(' ', SUBSTRING(Command, CHARINDEX('ADD CONSTRAINT ', Command) + 15, 200)), 0), 200) - 1) -- DROP CONSTRAINT WHEN Command LIKE '%DROP CONSTRAINT %' THEN LEFT(SUBSTRING(Command, CHARINDEX('DROP CONSTRAINT ', Command) + 16, 200), ISNULL(NULLIF(CHARINDEX(';', SUBSTRING(Command, CHARINDEX('DROP CONSTRAINT ', Command) + 16, 200)), 0), 200) - 1) -- Indexes: CREATE ... INDEX [Name] ON (robuster Check #4) WHEN Command LIKE '%INDEX %' AND Command LIKE '% ON %' AND CHARINDEX(' ON ', Command) > 4 THEN REVERSE(LEFT(REVERSE(LEFT(Command, CHARINDEX(' ON ', Command) - 1)), ISNULL(NULLIF(CHARINDEX(' ', REVERSE(LEFT(Command, CHARINDEX(' ON ', Command) - 1))), 0), 100) - 1)) -- Triggers: CREATE OR ALTER TRIGGER [Name] ON WHEN Command LIKE '%CREATE OR ALTER TRIGGER %' AND Command LIKE '% ON %' THEN LEFT(SUBSTRING(Command, CHARINDEX('CREATE OR ALTER TRIGGER ', Command) + 24, 200), ISNULL(NULLIF(CHARINDEX(' ON ', SUBSTRING(Command, CHARINDEX('CREATE OR ALTER TRIGGER ', Command) + 24, 200)), 0), 200) - 1) -- Views: CREATE OR ALTER VIEW [Schema].[Name] WHEN Command LIKE '%CREATE OR ALTER VIEW %' THEN LEFT(SUBSTRING(Command, PATINDEX('%CREATE OR ALTER VIEW %', Command) + 21, 200), ISNULL(NULLIF(PATINDEX('%[^a-zA-Z0-9_.[]]]%', SUBSTRING(Command, PATINDEX('%CREATE OR ALTER VIEW %', Command) + 21, 200) + ' '), 0), 100) - 1) -- Functions: CREATE OR ALTER FUNCTION WHEN Command LIKE '%CREATE OR ALTER FUNCTION %' THEN LEFT(SUBSTRING(Command, PATINDEX('%CREATE OR ALTER FUNCTION %', Command) + 25, 200), ISNULL(NULLIF(CHARINDEX('(', SUBSTRING(Command, PATINDEX('%CREATE OR ALTER FUNCTION %', Command) + 25, 200)), 0), 100) - 1) -- Procedures: CREATE OR ALTER PROC[EDURE] WHEN Command LIKE '%CREATE OR ALTER PROCEDURE %' THEN LEFT(SUBSTRING(Command, PATINDEX('%CREATE OR ALTER PROCEDURE %', Command) + 26, 200), ISNULL(NULLIF(PATINDEX('%[^a-zA-Z0-9_.[]]]%', SUBSTRING(Command, PATINDEX('%CREATE OR ALTER PROCEDURE %', Command) + 26, 200) + ' '), 0), 100) - 1) WHEN Command LIKE '%CREATE OR ALTER PROC %' THEN LEFT(SUBSTRING(Command, PATINDEX('%CREATE OR ALTER PROC %', Command) + 21, 200), ISNULL(NULLIF(PATINDEX('%[^a-zA-Z0-9_.[]]]%', SUBSTRING(Command, PATINDEX('%CREATE OR ALTER PROC %', Command) + 21, 200) + ' '), 0), 100) - 1) -- Sequences WHEN Command LIKE '%CREATE SEQUENCE %' THEN LEFT(SUBSTRING(Command, CHARINDEX('CREATE SEQUENCE ', Command) + 16, 200), ISNULL(NULLIF(CHARINDEX(' ', SUBSTRING(Command, CHARINDEX('CREATE SEQUENCE ', Command) + 16, 200)), 0), 100) - 1) -- Synonyms WHEN Command LIKE '%CREATE SYNONYM %' THEN LEFT(SUBSTRING(Command, CHARINDEX('CREATE SYNONYM ', Command) + 15, 200), ISNULL(NULLIF(CHARINDEX(' FOR ', SUBSTRING(Command, CHARINDEX('CREATE SYNONYM ', Command) + 15, 200)), 0), 100) - 1) -- Data Sync: MERGE [DB].[Schema].[Table] AS tgt WHEN Command LIKE '%MERGE %' AND Command LIKE '% AS tgt%' THEN LEFT(SUBSTRING(Command, CHARINDEX('MERGE ', Command) + 6, 200), ISNULL(NULLIF(CHARINDEX(' AS tgt', SUBSTRING(Command, CHARINDEX('MERGE ', Command) + 6, 200)), 0), 100) - 1) -- Security: CREATE ROLE, CREATE USER, CREATE SCHEMA WHEN Command LIKE '%CREATE ROLE %' THEN LEFT(SUBSTRING(Command, CHARINDEX('CREATE ROLE ', Command) + 12, 100), ISNULL(NULLIF(CHARINDEX(';', SUBSTRING(Command, CHARINDEX('CREATE ROLE ', Command) + 12, 100)), 0), 50) - 1) WHEN Command LIKE '%CREATE USER %' THEN LEFT(SUBSTRING(Command, CHARINDEX('CREATE USER ', Command) + 12, 100), ISNULL(NULLIF(CHARINDEX(' ', SUBSTRING(Command, CHARINDEX('CREATE USER ', Command) + 12, 100)), 0), 50) - 1) WHEN Command LIKE '%CREATE SCHEMA %' THEN LEFT(SUBSTRING(Command, CHARINDEX('CREATE SCHEMA ', Command) + 14, 100), ISNULL(NULLIF(CHARINDEX(' ', SUBSTRING(Command, CHARINDEX('CREATE SCHEMA ', Command) + 14, 100)), 0), 50) - 1) -- Grants/RoleMembers: Zeige Anfang des Commands WHEN Phase LIKE '01-Security%' THEN LEFT(Command, 80) -- Fallback ELSE LEFT(Command, 80) END AS ObjectName FROM #TBDD_SYNC_DATABASE_COMMANDS ORDER BY Phase, Command; OPEN detail_cursor; FETCH NEXT FROM detail_cursor INTO @DetailPhase, @DetailObjectName; WHILE @@FETCH_STATUS = 0 BEGIN IF @DetailPhase <> @LastPhase BEGIN PRINT N''; PRINT N'--- ' + @DetailPhase + N' ---'; SET @LastPhase = @DetailPhase; END; -- Objektname ausgeben (max 100 Zeichen, bereinigt) SET @DetailObjectName = REPLACE(REPLACE(LTRIM(RTRIM(@DetailObjectName)), CHAR(13), ''), CHAR(10), ''); IF LEN(@DetailObjectName) > 100 SET @DetailObjectName = LEFT(@DetailObjectName, 97) + N'...'; PRINT N' ' + @DetailObjectName; FETCH NEXT FROM detail_cursor INTO @DetailPhase, @DetailObjectName; END; CLOSE detail_cursor; DEALLOCATE detail_cursor; PRINT N''; PRINT N'===================================================================================================='; END -- Ende IF @DEBUG = 1 END -- Ende von IF @COMMANDCOUNT > 0 ELSE BEGIN -- Keine Änderungen erforderlich PRINT N''; PRINT N'===================================================================================================='; PRINT N' SYNCHRONIZATION SUMMARY'; PRINT N'===================================================================================================='; PRINT N'Source: ' + @SOURCEDATABASE + N' --> Target: ' + @TARGETDATABASE; PRINT N''; PRINT N'NO CHANGES REQUIRED - Databases are already in sync!'; PRINT N'===================================================================================================='; END; --=================================================-- Ausgabe oder Ausführung --================================================-- IF @EXECUTE = 0 BEGIN -- Detailliste der Commands ausgeben PRINT N''; PRINT N' COMMAND DETAILS (DRY-RUN)'; PRINT N'===================================================================================================='; SELECT Step, Phase, Command FROM #TBDD_SYNC_DATABASE_COMMANDS ORDER BY Step; -- Nach DRY-RUN wird Validation durchgefuehrt (falls aktiviert) END ELSE BEGIN --=================================================-- Cursor-Ausfuehrung startet --=================================================-- --===============================================-- Log result to table --=================================================-- IF (UPPER(@LOGLEVEL) IN (N'INFO',N'WARN',N'ERROR')) BEGIN INSERT INTO [TBDD_SYNC_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [ADDED_WHO], [ADDED_WHEN]) VALUES ('INFO', '06-Execution', 'Cursor-Ausfuehrung startet', 'Anzahl Commands: '+CONVERT(NVARCHAR(10),@COMMANDCOUNT), @MY_PROCEDURE_NAME, GETDATE()); END; ----------------------------------------------------------------------------------------------------------------------------- SET @STEP = NULL; SET @PHASE = NULL; SET @COMMAND = NULL; -- Fehler-Counter für Gesamt-Statistik am Ende DECLARE @EXECUTION_ERRORS INT = 0; DECLARE @EXECUTION_SUCCESS INT = 0; -- Transaction-Modus: Bei @USETRANSACTION=1 wird alles in einer Transaction ausgefuehrt IF @USETRANSACTION = 1 BEGIN PRINT N'[INFO] Transaction mode enabled - starting transaction...'; BEGIN TRANSACTION SYNC_TRANSACTION; END; -- Äußeres TRY/CATCH für Cursor-Block BEGIN TRY DECLARE cmd_cur CURSOR LOCAL FAST_FORWARD FOR SELECT Step, Phase, Command FROM #TBDD_SYNC_DATABASE_COMMANDS ORDER BY Step; OPEN cmd_cur; FETCH NEXT FROM cmd_cur INTO @STEP, @PHASE, @COMMAND; WHILE @@FETCH_STATUS = 0 BEGIN PRINT 'Executing Step ' + CONVERT(NVARCHAR(10), @STEP) + ' (' + @PHASE + ')'; SET @SEVERITY = 'INFO'; SET @ERRMSG = NULL; BEGIN TRY -- Sicherheit #19: sp_executesql statt EXEC für bessere Parameterisierung EXEC sys.sp_executesql @COMMAND; SET @EXECUTION_SUCCESS = @EXECUTION_SUCCESS + 1; -- Erfolg zählen END TRY BEGIN CATCH SET @SEVERITY = 'ERROR'; SET @ERRMSG = ERROR_MESSAGE(); SET @RETURN_STATUS = 1; -- Status bei Fehler setzen SET @EXECUTION_ERRORS = @EXECUTION_ERRORS + 1; -- Fehler zählen PRINT '[ERROR] Step ' + CONVERT(NVARCHAR(10), @STEP) + ' (' + @PHASE + '): ' + @ERRMSG; -- Always output failed command for debugging (chunked for large statements) BEGIN SET @ERRPOS = 1; -- Reset for each error PRINT '[ERROR] Failed SQL (length: ' + CONVERT(NVARCHAR(10), LEN(@COMMAND)) + '):'; WHILE @ERRPOS <= LEN(@COMMAND) BEGIN PRINT SUBSTRING(@COMMAND, @ERRPOS, @ERRCHUNK); SET @ERRPOS = @ERRPOS + @ERRCHUNK; END; PRINT '[ERROR] --- End of failed SQL ---'; END; -- Abort bei kritischen Phasen IF @PHASE IN ('02-Schemas', '03-Tables', '05-PrimaryKeys') BEGIN PRINT 'CRITICAL ERROR in ' + @PHASE + ' - Aborting execution!'; -- Transaction-Rollback bei kritischem Fehler IF @USETRANSACTION = 1 AND @@TRANCOUNT > 0 BEGIN PRINT N'[INFO] Rolling back transaction due to critical error...'; ROLLBACK TRANSACTION SYNC_TRANSACTION; END; CLOSE cmd_cur; DEALLOCATE cmd_cur; SET @RETURN_STATUS = 1; GOTO CLEANUP_AND_EXIT; END; END CATCH; --================================================-- Log execution result to table --=================================================-- IF (UPPER(@LOGLEVEL) IN (N'INFO',N'WARN',N'ERROR')) BEGIN INSERT INTO [TBDD_SYNC_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [ADDED_WHO], [ADDED_WHEN]) VALUES (@SEVERITY, @PHASE, CONVERT(NVARCHAR(256),@STEP), ISNULL(@ERRMSG, N'OK'), @MY_PROCEDURE_NAME, GETDATE()); END; ----------------------------------------------------------------------------------------------------------------------- FETCH NEXT FROM cmd_cur INTO @STEP, @PHASE, @COMMAND; END CLOSE cmd_cur; DEALLOCATE cmd_cur; -- Transaction-COMMIT nach erfolgreicher Cursor-Ausfuehrung (ohne kritische Fehler) IF @USETRANSACTION = 1 AND @@TRANCOUNT > 0 BEGIN IF @EXECUTION_ERRORS = 0 BEGIN PRINT N'[INFO] All commands executed successfully - committing transaction...'; COMMIT TRANSACTION SYNC_TRANSACTION; END ELSE BEGIN PRINT N'[WARN] ' + CONVERT(NVARCHAR(10), @EXECUTION_ERRORS) + N' errors occurred - rolling back transaction...'; ROLLBACK TRANSACTION SYNC_TRANSACTION; SET @RETURN_STATUS = 1; END; END; END TRY BEGIN CATCH -- Äußeres CATCH für Cursor-Fehler (z.B. DEALLOCATE bei Abbruch) -- Transaction-Rollback bei unbehandeltem Fehler IF @USETRANSACTION = 1 AND @@TRANCOUNT > 0 BEGIN PRINT N'[ERROR] Rolling back transaction due to unhandled error...'; ROLLBACK TRANSACTION SYNC_TRANSACTION; END; -- Cursor sicher schließen falls offen IF CURSOR_STATUS('local', 'cmd_cur') >= 0 BEGIN CLOSE cmd_cur; DEALLOCATE cmd_cur; END; PRINT '[ERROR] Cursor execution failed: ' + ERROR_MESSAGE(); SET @RETURN_STATUS = 1; END CATCH; -- Ausführungs-Zusammenfassung ausgeben PRINT N''; PRINT N'Execution Summary: ' + CONVERT(NVARCHAR(10), @EXECUTION_SUCCESS) + N' successful, ' + CONVERT(NVARCHAR(10), @EXECUTION_ERRORS) + N' errors of ' + CONVERT(NVARCHAR(10), @COMMANDCOUNT) + N' total commands'; --===============================================-- Log result to table --=================================================-- IF (UPPER(@LOGLEVEL) IN (N'INFO',N'WARN',N'ERROR')) BEGIN INSERT INTO [TBDD_SYNC_DATABASE_LOG]([LOG_LEVEL],[MESSAGE1], [MESSAGE2], [MESSAGE3], [ADDED_WHO], [ADDED_WHEN]) VALUES ('INFO', '07-Complete', 'Cursor-Ausfuehrung abgeschlossen', 'Success: ' + CONVERT(NVARCHAR(10), @EXECUTION_SUCCESS) + ', Errors: ' + CONVERT(NVARCHAR(10), @EXECUTION_ERRORS) + ' of ' + CONVERT(NVARCHAR(10), @COMMANDCOUNT), @MY_PROCEDURE_NAME, GETDATE()); END; ----------------------------------------------------------------------------------------------------------------------------- END; -- End of ELSE block (EXECUTE = 1) --=================================================-- CLEANUP AND EXIT --=================================================-- --=================================================-- Validation Phase --==============================================-- -- @VALIDATION_MODE: 'NONE', 'SCHEMA', 'DATA', 'ALL' (definiert in Hauptblock) IF UPPER(@VALIDATION_MODE) <> N'NONE' BEGIN -- Validation auch bei @EXECUTE=0 (Preview) PRINT N''; PRINT N'===================================================================================================='; PRINT N'Starting validation (' + @VALIDATION_MODE + ')...'; PRINT N'===================================================================================================='; -- Reset validation counters for this run SET @VALIDATION_PASSED = 1; SET @VALIDATION_ERRORS = 0; SET @VALIDATION_WARNINGS = 0; -- Create validation results table CREATE TABLE #ValidationResults ( ValidationType NVARCHAR(20) NOT NULL, -- 'SCHEMA' or 'DATA' ObjectType NVARCHAR(50) NOT NULL, ObjectName NVARCHAR(256) NULL, SourceCount BIGINT NOT NULL, TargetCount BIGINT NOT NULL, Status NVARCHAR(10) NOT NULL, -- 'OK', 'WARN', 'ERROR' Message NVARCHAR(500) NULL ); --===================== SCHEMA VALIDATION =====================-- IF UPPER(@VALIDATION_MODE) IN (N'ALL', N'SCHEMA') BEGIN PRINT N''; PRINT N'--- Schema Validation ---'; -- Validate Tables SET @VALIDATION_SQL = N' SELECT @src = COUNT(*) FROM {#SOURCEDB_Q#}.sys.tables t JOIN {#SOURCEDB_Q#}.sys.schemas s ON s.schema_id = t.schema_id WHERE s.name{#COLLATION#}<>N''sys''{#COLLATION#} AND t.is_ms_shipped = 0 AND NOT EXISTS (SELECT 1 FROM #TBDD_SYNC_DATABASE_EXCLUDEDOBJECTS ex WHERE (ex.IsWildcard = 1 AND (t.name{#COLLATION#} LIKE ex.Pattern{#COLLATION#} OR (s.name{#COLLATION#} + N''.'' + t.name{#COLLATION#}) LIKE ex.Pattern{#COLLATION#})) OR (ex.IsWildcard = 0 AND (t.name{#COLLATION#} = ex.Pattern{#COLLATION#} OR (s.name{#COLLATION#} + N''.'' + t.name{#COLLATION#}) = ex.Pattern{#COLLATION#})));'; SET @VALIDATION_SQL = REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(@VALIDATION_SQL, @PLACEHOLDERSOURCEDBQUOTED, @SOURCEDATABASEQUOTED), @PLACEHOLDERTARGETDBQUOTED, @TARGETDATABASEQUOTED), @PLACEHOLDERSOURCEDB, @SOURCEDATABASE), @PLACEHOLDERTARGETDB, @TARGETDATABASE), @PLACEHOLDERCOLLATION, @COMPARECOLLATION); EXEC sys.sp_executesql @VALIDATION_SQL, N'@src INT OUTPUT', @src = @VALIDATION_SOURCE_COUNT OUTPUT; -- Target-Validation berücksichtigt auch Excludes für korrekten Vergleich SET @VALIDATION_SQL = N' SELECT @tgt = COUNT(*) FROM {#TARGETDB_Q#}.sys.tables t JOIN {#TARGETDB_Q#}.sys.schemas s ON s.schema_id = t.schema_id WHERE s.name{#COLLATION#}<>N''sys''{#COLLATION#} AND t.is_ms_shipped = 0 AND NOT EXISTS (SELECT 1 FROM #TBDD_SYNC_DATABASE_EXCLUDEDOBJECTS ex WHERE (ex.IsWildcard = 1 AND (t.name{#COLLATION#} LIKE ex.Pattern{#COLLATION#} OR (s.name{#COLLATION#} + N''.'' + t.name{#COLLATION#}) LIKE ex.Pattern{#COLLATION#})) OR (ex.IsWildcard = 0 AND (t.name{#COLLATION#} = ex.Pattern{#COLLATION#} OR (s.name{#COLLATION#} + N''.'' + t.name{#COLLATION#}) = ex.Pattern{#COLLATION#})));'; SET @VALIDATION_SQL = REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(@VALIDATION_SQL, @PLACEHOLDERSOURCEDBQUOTED, @SOURCEDATABASEQUOTED), @PLACEHOLDERTARGETDBQUOTED, @TARGETDATABASEQUOTED), @PLACEHOLDERSOURCEDB, @SOURCEDATABASE), @PLACEHOLDERTARGETDB, @TARGETDATABASE), @PLACEHOLDERCOLLATION, @COMPARECOLLATION); EXEC sys.sp_executesql @VALIDATION_SQL, N'@tgt INT OUTPUT', @tgt = @VALIDATION_TARGET_COUNT OUTPUT; INSERT INTO #ValidationResults VALUES ('SCHEMA', 'Tables', NULL, @VALIDATION_SOURCE_COUNT, @VALIDATION_TARGET_COUNT, CASE WHEN @VALIDATION_SOURCE_COUNT = @VALIDATION_TARGET_COUNT THEN 'OK' ELSE 'ERROR' END, CASE WHEN @VALIDATION_SOURCE_COUNT = @VALIDATION_TARGET_COUNT THEN NULL ELSE 'Mismatch: Source=' + CONVERT(NVARCHAR(10), @VALIDATION_SOURCE_COUNT) + ', Target=' + CONVERT(NVARCHAR(10), @VALIDATION_TARGET_COUNT) END); IF @VALIDATION_SOURCE_COUNT <> @VALIDATION_TARGET_COUNT BEGIN SET @VALIDATION_PASSED = 0; SET @VALIDATION_ERRORS = @VALIDATION_ERRORS + 1; END; PRINT 'Tables: Source=' + CONVERT(NVARCHAR(10), @VALIDATION_SOURCE_COUNT) + ', Target=' + CONVERT(NVARCHAR(10), @VALIDATION_TARGET_COUNT) + CASE WHEN @VALIDATION_SOURCE_COUNT = @VALIDATION_TARGET_COUNT THEN ' [OK]' ELSE ' [ERROR]' END; -- Validate Views SET @VALIDATION_SQL = N' SELECT @src = COUNT(*) FROM {#SOURCEDB_Q#}.sys.views v JOIN {#SOURCEDB_Q#}.sys.schemas s ON s.schema_id = v.schema_id WHERE s.name{#COLLATION#}<>N''sys''{#COLLATION#} AND NOT EXISTS (SELECT 1 FROM #TBDD_SYNC_DATABASE_EXCLUDEDOBJECTS ex WHERE (ex.IsWildcard = 1 AND (v.name{#COLLATION#} LIKE ex.Pattern{#COLLATION#} OR (s.name{#COLLATION#} + N''.'' + v.name{#COLLATION#}) LIKE ex.Pattern{#COLLATION#})) OR (ex.IsWildcard = 0 AND (v.name{#COLLATION#} = ex.Pattern{#COLLATION#} OR (s.name{#COLLATION#} + N''.'' + v.name{#COLLATION#}) = ex.Pattern{#COLLATION#})));'; SET @VALIDATION_SQL = REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(@VALIDATION_SQL, @PLACEHOLDERSOURCEDBQUOTED, @SOURCEDATABASEQUOTED), @PLACEHOLDERTARGETDBQUOTED, @TARGETDATABASEQUOTED), @PLACEHOLDERSOURCEDB, @SOURCEDATABASE), @PLACEHOLDERTARGETDB, @TARGETDATABASE), @PLACEHOLDERCOLLATION, @COMPARECOLLATION); EXEC sys.sp_executesql @VALIDATION_SQL, N'@src INT OUTPUT', @src = @VALIDATION_SOURCE_COUNT OUTPUT; -- Target-Validation berücksichtigt auch Excludes für korrekten Vergleich SET @VALIDATION_SQL = N' SELECT @tgt = COUNT(*) FROM {#TARGETDB_Q#}.sys.views v JOIN {#TARGETDB_Q#}.sys.schemas s ON s.schema_id = v.schema_id WHERE s.name{#COLLATION#}<>N''sys''{#COLLATION#} AND NOT EXISTS (SELECT 1 FROM #TBDD_SYNC_DATABASE_EXCLUDEDOBJECTS ex WHERE (ex.IsWildcard = 1 AND (v.name{#COLLATION#} LIKE ex.Pattern{#COLLATION#} OR (s.name{#COLLATION#} + N''.'' + v.name{#COLLATION#}) LIKE ex.Pattern{#COLLATION#})) OR (ex.IsWildcard = 0 AND (v.name{#COLLATION#} = ex.Pattern{#COLLATION#} OR (s.name{#COLLATION#} + N''.'' + v.name{#COLLATION#}) = ex.Pattern{#COLLATION#})));'; SET @VALIDATION_SQL = REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(@VALIDATION_SQL, @PLACEHOLDERSOURCEDBQUOTED, @SOURCEDATABASEQUOTED), @PLACEHOLDERTARGETDBQUOTED, @TARGETDATABASEQUOTED), @PLACEHOLDERSOURCEDB, @SOURCEDATABASE), @PLACEHOLDERTARGETDB, @TARGETDATABASE), @PLACEHOLDERCOLLATION, @COMPARECOLLATION); EXEC sys.sp_executesql @VALIDATION_SQL, N'@tgt INT OUTPUT', @tgt = @VALIDATION_TARGET_COUNT OUTPUT; INSERT INTO #ValidationResults VALUES ('SCHEMA', 'Views', NULL, @VALIDATION_SOURCE_COUNT, @VALIDATION_TARGET_COUNT, CASE WHEN @VALIDATION_SOURCE_COUNT = @VALIDATION_TARGET_COUNT THEN 'OK' ELSE 'ERROR' END, NULL); IF @VALIDATION_SOURCE_COUNT <> @VALIDATION_TARGET_COUNT BEGIN SET @VALIDATION_PASSED = 0; SET @VALIDATION_ERRORS = @VALIDATION_ERRORS + 1; END; PRINT 'Views: Source=' + CONVERT(NVARCHAR(10), @VALIDATION_SOURCE_COUNT) + ', Target=' + CONVERT(NVARCHAR(10), @VALIDATION_TARGET_COUNT) + CASE WHEN @VALIDATION_SOURCE_COUNT = @VALIDATION_TARGET_COUNT THEN ' [OK]' ELSE ' [ERROR]' END; -- Validate Stored Procedures SET @VALIDATION_SQL = N' SELECT @src = COUNT(*) FROM {#SOURCEDB_Q#}.sys.procedures p JOIN {#SOURCEDB_Q#}.sys.schemas s ON s.schema_id = p.schema_id WHERE s.name{#COLLATION#}<>N''sys''{#COLLATION#} AND NOT EXISTS (SELECT 1 FROM #TBDD_SYNC_DATABASE_EXCLUDEDOBJECTS ex WHERE (ex.IsWildcard = 1 AND (p.name{#COLLATION#} LIKE ex.Pattern{#COLLATION#} OR (s.name{#COLLATION#} + N''.'' + p.name{#COLLATION#}) LIKE ex.Pattern{#COLLATION#})) OR (ex.IsWildcard = 0 AND (p.name{#COLLATION#} = ex.Pattern{#COLLATION#} OR (s.name{#COLLATION#} + N''.'' + p.name{#COLLATION#}) = ex.Pattern{#COLLATION#})));'; SET @VALIDATION_SQL = REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(@VALIDATION_SQL, @PLACEHOLDERSOURCEDBQUOTED, @SOURCEDATABASEQUOTED), @PLACEHOLDERTARGETDBQUOTED, @TARGETDATABASEQUOTED), @PLACEHOLDERSOURCEDB, @SOURCEDATABASE), @PLACEHOLDERTARGETDB, @TARGETDATABASE), @PLACEHOLDERCOLLATION, @COMPARECOLLATION); EXEC sys.sp_executesql @VALIDATION_SQL, N'@src INT OUTPUT', @src = @VALIDATION_SOURCE_COUNT OUTPUT; -- Target-Validation berücksichtigt auch Excludes für korrekten Vergleich SET @VALIDATION_SQL = N' SELECT @tgt = COUNT(*) FROM {#TARGETDB_Q#}.sys.procedures p JOIN {#TARGETDB_Q#}.sys.schemas s ON s.schema_id = p.schema_id WHERE s.name{#COLLATION#}<>N''sys''{#COLLATION#} AND NOT EXISTS (SELECT 1 FROM #TBDD_SYNC_DATABASE_EXCLUDEDOBJECTS ex WHERE (ex.IsWildcard = 1 AND (p.name{#COLLATION#} LIKE ex.Pattern{#COLLATION#} OR (s.name{#COLLATION#} + N''.'' + p.name{#COLLATION#}) LIKE ex.Pattern{#COLLATION#})) OR (ex.IsWildcard = 0 AND (p.name{#COLLATION#} = ex.Pattern{#COLLATION#} OR (s.name{#COLLATION#} + N''.'' + p.name{#COLLATION#}) = ex.Pattern{#COLLATION#})));'; SET @VALIDATION_SQL = REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(@VALIDATION_SQL, @PLACEHOLDERSOURCEDBQUOTED, @SOURCEDATABASEQUOTED), @PLACEHOLDERTARGETDBQUOTED, @TARGETDATABASEQUOTED), @PLACEHOLDERSOURCEDB, @SOURCEDATABASE), @PLACEHOLDERTARGETDB, @TARGETDATABASE), @PLACEHOLDERCOLLATION, @COMPARECOLLATION); EXEC sys.sp_executesql @VALIDATION_SQL, N'@tgt INT OUTPUT', @tgt = @VALIDATION_TARGET_COUNT OUTPUT; INSERT INTO #ValidationResults VALUES ('SCHEMA', 'Procedures', NULL, @VALIDATION_SOURCE_COUNT, @VALIDATION_TARGET_COUNT, CASE WHEN @VALIDATION_SOURCE_COUNT = @VALIDATION_TARGET_COUNT THEN 'OK' ELSE 'ERROR' END, NULL); IF @VALIDATION_SOURCE_COUNT <> @VALIDATION_TARGET_COUNT BEGIN SET @VALIDATION_PASSED = 0; SET @VALIDATION_ERRORS = @VALIDATION_ERRORS + 1; END; PRINT 'Procedures: Source=' + CONVERT(NVARCHAR(10), @VALIDATION_SOURCE_COUNT) + ', Target=' + CONVERT(NVARCHAR(10), @VALIDATION_TARGET_COUNT) + CASE WHEN @VALIDATION_SOURCE_COUNT = @VALIDATION_TARGET_COUNT THEN ' [OK]' ELSE ' [ERROR]' END; -- Validate Functions SET @VALIDATION_SQL = N' SELECT @src = COUNT(*) FROM {#SOURCEDB_Q#}.sys.objects o JOIN {#SOURCEDB_Q#}.sys.schemas s ON s.schema_id = o.schema_id WHERE s.name{#COLLATION#}<>N''sys''{#COLLATION#} AND o.[type] IN (N''FN'',N''TF'',N''IF'',N''FS'',N''FT'') AND NOT EXISTS (SELECT 1 FROM #TBDD_SYNC_DATABASE_EXCLUDEDOBJECTS ex WHERE (ex.IsWildcard = 1 AND (o.name{#COLLATION#} LIKE ex.Pattern{#COLLATION#} OR (s.name{#COLLATION#} + N''.'' + o.name{#COLLATION#}) LIKE ex.Pattern{#COLLATION#})) OR (ex.IsWildcard = 0 AND (o.name{#COLLATION#} = ex.Pattern{#COLLATION#} OR (s.name{#COLLATION#} + N''.'' + o.name{#COLLATION#}) = ex.Pattern{#COLLATION#})));'; SET @VALIDATION_SQL = REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(@VALIDATION_SQL, @PLACEHOLDERSOURCEDBQUOTED, @SOURCEDATABASEQUOTED), @PLACEHOLDERTARGETDBQUOTED, @TARGETDATABASEQUOTED), @PLACEHOLDERSOURCEDB, @SOURCEDATABASE), @PLACEHOLDERTARGETDB, @TARGETDATABASE), @PLACEHOLDERCOLLATION, @COMPARECOLLATION); EXEC sys.sp_executesql @VALIDATION_SQL, N'@src INT OUTPUT', @src = @VALIDATION_SOURCE_COUNT OUTPUT; -- Target-Validation berücksichtigt auch Excludes für korrekten Vergleich SET @VALIDATION_SQL = N' SELECT @tgt = COUNT(*) FROM {#TARGETDB_Q#}.sys.objects o JOIN {#TARGETDB_Q#}.sys.schemas s ON s.schema_id = o.schema_id WHERE s.name{#COLLATION#}<>N''sys''{#COLLATION#} AND o.[type] IN (N''FN'',N''TF'',N''IF'',N''FS'',N''FT'') AND NOT EXISTS (SELECT 1 FROM #TBDD_SYNC_DATABASE_EXCLUDEDOBJECTS ex WHERE (ex.IsWildcard = 1 AND (o.name{#COLLATION#} LIKE ex.Pattern{#COLLATION#} OR (s.name{#COLLATION#} + N''.'' + o.name{#COLLATION#}) LIKE ex.Pattern{#COLLATION#})) OR (ex.IsWildcard = 0 AND (o.name{#COLLATION#} = ex.Pattern{#COLLATION#} OR (s.name{#COLLATION#} + N''.'' + o.name{#COLLATION#}) = ex.Pattern{#COLLATION#})));'; SET @VALIDATION_SQL = REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(@VALIDATION_SQL, @PLACEHOLDERSOURCEDBQUOTED, @SOURCEDATABASEQUOTED), @PLACEHOLDERTARGETDBQUOTED, @TARGETDATABASEQUOTED), @PLACEHOLDERSOURCEDB, @SOURCEDATABASE), @PLACEHOLDERTARGETDB, @TARGETDATABASE), @PLACEHOLDERCOLLATION, @COMPARECOLLATION); EXEC sys.sp_executesql @VALIDATION_SQL, N'@tgt INT OUTPUT', @tgt = @VALIDATION_TARGET_COUNT OUTPUT; INSERT INTO #ValidationResults VALUES ('SCHEMA', 'Functions', NULL, @VALIDATION_SOURCE_COUNT, @VALIDATION_TARGET_COUNT, CASE WHEN @VALIDATION_SOURCE_COUNT = @VALIDATION_TARGET_COUNT THEN 'OK' ELSE 'ERROR' END, NULL); IF @VALIDATION_SOURCE_COUNT <> @VALIDATION_TARGET_COUNT BEGIN SET @VALIDATION_PASSED = 0; SET @VALIDATION_ERRORS = @VALIDATION_ERRORS + 1; END; PRINT 'Functions: Source=' + CONVERT(NVARCHAR(10), @VALIDATION_SOURCE_COUNT) + ', Target=' + CONVERT(NVARCHAR(10), @VALIDATION_TARGET_COUNT) + CASE WHEN @VALIDATION_SOURCE_COUNT = @VALIDATION_TARGET_COUNT THEN ' [OK]' ELSE ' [ERROR]' END; -- Validate Triggers SET @VALIDATION_SQL = N' SELECT @src = COUNT(*) FROM {#SOURCEDB_Q#}.sys.triggers tr JOIN {#SOURCEDB_Q#}.sys.objects o ON o.object_id = tr.object_id JOIN {#SOURCEDB_Q#}.sys.schemas s ON s.schema_id = o.schema_id JOIN {#SOURCEDB_Q#}.sys.tables pt ON pt.object_id = tr.parent_id JOIN {#SOURCEDB_Q#}.sys.schemas ps ON ps.schema_id = pt.schema_id WHERE s.name{#COLLATION#}<>N''sys''{#COLLATION#} AND tr.parent_id IS NOT NULL AND NOT EXISTS (SELECT 1 FROM #TBDD_SYNC_DATABASE_EXCLUDEDOBJECTS ex WHERE (ex.IsWildcard = 1 AND (pt.name{#COLLATION#} LIKE ex.Pattern{#COLLATION#} OR (ps.name{#COLLATION#} + N''.'' + pt.name{#COLLATION#}) LIKE ex.Pattern{#COLLATION#})) OR (ex.IsWildcard = 0 AND (pt.name{#COLLATION#} = ex.Pattern{#COLLATION#} OR (ps.name{#COLLATION#} + N''.'' + pt.name{#COLLATION#}) = ex.Pattern{#COLLATION#}))) AND NOT EXISTS (SELECT 1 FROM #TBDD_SYNC_DATABASE_EXCLUDEDOBJECTS ex WHERE (ex.IsWildcard = 1 AND (tr.name{#COLLATION#} LIKE ex.Pattern{#COLLATION#} OR (s.name{#COLLATION#} + N''.'' + tr.name{#COLLATION#}) LIKE ex.Pattern{#COLLATION#})) OR (ex.IsWildcard = 0 AND (tr.name{#COLLATION#} = ex.Pattern{#COLLATION#} OR (s.name{#COLLATION#} + N''.'' + tr.name{#COLLATION#}) = ex.Pattern{#COLLATION#})));'; SET @VALIDATION_SQL = REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(@VALIDATION_SQL, @PLACEHOLDERSOURCEDBQUOTED, @SOURCEDATABASEQUOTED), @PLACEHOLDERTARGETDBQUOTED, @TARGETDATABASEQUOTED), @PLACEHOLDERSOURCEDB, @SOURCEDATABASE), @PLACEHOLDERTARGETDB, @TARGETDATABASE), @PLACEHOLDERCOLLATION, @COMPARECOLLATION); EXEC sys.sp_executesql @VALIDATION_SQL, N'@src INT OUTPUT', @src = @VALIDATION_SOURCE_COUNT OUTPUT; -- Target-Validation berücksichtigt auch Excludes für korrekten Vergleich SET @VALIDATION_SQL = N' SELECT @tgt = COUNT(*) FROM {#TARGETDB_Q#}.sys.triggers tr JOIN {#TARGETDB_Q#}.sys.objects o ON o.object_id = tr.object_id JOIN {#TARGETDB_Q#}.sys.schemas s ON s.schema_id = o.schema_id JOIN {#TARGETDB_Q#}.sys.tables pt ON pt.object_id = tr.parent_id JOIN {#TARGETDB_Q#}.sys.schemas ps ON ps.schema_id = pt.schema_id WHERE s.name{#COLLATION#}<>N''sys''{#COLLATION#} AND tr.parent_id IS NOT NULL AND NOT EXISTS (SELECT 1 FROM #TBDD_SYNC_DATABASE_EXCLUDEDOBJECTS ex WHERE (ex.IsWildcard = 1 AND (pt.name{#COLLATION#} LIKE ex.Pattern{#COLLATION#} OR (ps.name{#COLLATION#} + N''.'' + pt.name{#COLLATION#}) LIKE ex.Pattern{#COLLATION#})) OR (ex.IsWildcard = 0 AND (pt.name{#COLLATION#} = ex.Pattern{#COLLATION#} OR (ps.name{#COLLATION#} + N''.'' + pt.name{#COLLATION#}) = ex.Pattern{#COLLATION#}))) AND NOT EXISTS (SELECT 1 FROM #TBDD_SYNC_DATABASE_EXCLUDEDOBJECTS ex WHERE (ex.IsWildcard = 1 AND (tr.name{#COLLATION#} LIKE ex.Pattern{#COLLATION#} OR (s.name{#COLLATION#} + N''.'' + tr.name{#COLLATION#}) LIKE ex.Pattern{#COLLATION#})) OR (ex.IsWildcard = 0 AND (tr.name{#COLLATION#} = ex.Pattern{#COLLATION#} OR (s.name{#COLLATION#} + N''.'' + tr.name{#COLLATION#}) = ex.Pattern{#COLLATION#})));'; SET @VALIDATION_SQL = REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(@VALIDATION_SQL, @PLACEHOLDERSOURCEDBQUOTED, @SOURCEDATABASEQUOTED), @PLACEHOLDERTARGETDBQUOTED, @TARGETDATABASEQUOTED), @PLACEHOLDERSOURCEDB, @SOURCEDATABASE), @PLACEHOLDERTARGETDB, @TARGETDATABASE), @PLACEHOLDERCOLLATION, @COMPARECOLLATION); EXEC sys.sp_executesql @VALIDATION_SQL, N'@tgt INT OUTPUT', @tgt = @VALIDATION_TARGET_COUNT OUTPUT; INSERT INTO #ValidationResults VALUES ('SCHEMA', 'Triggers', NULL, @VALIDATION_SOURCE_COUNT, @VALIDATION_TARGET_COUNT, CASE WHEN @VALIDATION_SOURCE_COUNT = @VALIDATION_TARGET_COUNT THEN 'OK' ELSE 'ERROR' END, NULL); IF @VALIDATION_SOURCE_COUNT <> @VALIDATION_TARGET_COUNT BEGIN SET @VALIDATION_PASSED = 0; SET @VALIDATION_ERRORS = @VALIDATION_ERRORS + 1; END; PRINT 'Triggers: Source=' + CONVERT(NVARCHAR(10), @VALIDATION_SOURCE_COUNT) + ', Target=' + CONVERT(NVARCHAR(10), @VALIDATION_TARGET_COUNT) + CASE WHEN @VALIDATION_SOURCE_COUNT = @VALIDATION_TARGET_COUNT THEN ' [OK]' ELSE ' [ERROR]' END; -- Validate Indexes SET @VALIDATION_SQL = N' SELECT @src = COUNT(*) FROM {#SOURCEDB_Q#}.sys.indexes i JOIN {#SOURCEDB_Q#}.sys.tables t ON t.object_id = i.object_id JOIN {#SOURCEDB_Q#}.sys.schemas s ON s.schema_id = t.schema_id WHERE s.name{#COLLATION#}<>N''sys''{#COLLATION#} AND i.index_id > 0 AND NOT EXISTS (SELECT 1 FROM #TBDD_SYNC_DATABASE_EXCLUDEDOBJECTS ex WHERE (ex.IsWildcard = 1 AND (t.name{#COLLATION#} LIKE ex.Pattern{#COLLATION#} OR (s.name{#COLLATION#} + N''.'' + t.name{#COLLATION#}) LIKE ex.Pattern{#COLLATION#})) OR (ex.IsWildcard = 0 AND (t.name{#COLLATION#} = ex.Pattern{#COLLATION#} OR (s.name{#COLLATION#} + N''.'' + t.name{#COLLATION#}) = ex.Pattern{#COLLATION#})));'; SET @VALIDATION_SQL = REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(@VALIDATION_SQL, @PLACEHOLDERSOURCEDBQUOTED, @SOURCEDATABASEQUOTED), @PLACEHOLDERTARGETDBQUOTED, @TARGETDATABASEQUOTED), @PLACEHOLDERSOURCEDB, @SOURCEDATABASE), @PLACEHOLDERTARGETDB, @TARGETDATABASE), @PLACEHOLDERCOLLATION, @COMPARECOLLATION); EXEC sys.sp_executesql @VALIDATION_SQL, N'@src INT OUTPUT', @src = @VALIDATION_SOURCE_COUNT OUTPUT; -- Target-Validation berücksichtigt auch Excludes für korrekten Vergleich SET @VALIDATION_SQL = N' SELECT @tgt = COUNT(*) FROM {#TARGETDB_Q#}.sys.indexes i JOIN {#TARGETDB_Q#}.sys.tables t ON t.object_id = i.object_id JOIN {#TARGETDB_Q#}.sys.schemas s ON s.schema_id = t.schema_id WHERE s.name{#COLLATION#}<>N''sys''{#COLLATION#} AND i.index_id > 0 AND NOT EXISTS (SELECT 1 FROM #TBDD_SYNC_DATABASE_EXCLUDEDOBJECTS ex WHERE (ex.IsWildcard = 1 AND (t.name{#COLLATION#} LIKE ex.Pattern{#COLLATION#} OR (s.name{#COLLATION#} + N''.'' + t.name{#COLLATION#}) LIKE ex.Pattern{#COLLATION#})) OR (ex.IsWildcard = 0 AND (t.name{#COLLATION#} = ex.Pattern{#COLLATION#} OR (s.name{#COLLATION#} + N''.'' + t.name{#COLLATION#}) = ex.Pattern{#COLLATION#})));'; SET @VALIDATION_SQL = REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(@VALIDATION_SQL, @PLACEHOLDERSOURCEDBQUOTED, @SOURCEDATABASEQUOTED), @PLACEHOLDERTARGETDBQUOTED, @TARGETDATABASEQUOTED), @PLACEHOLDERSOURCEDB, @SOURCEDATABASE), @PLACEHOLDERTARGETDB, @TARGETDATABASE), @PLACEHOLDERCOLLATION, @COMPARECOLLATION); EXEC sys.sp_executesql @VALIDATION_SQL, N'@tgt INT OUTPUT', @tgt = @VALIDATION_TARGET_COUNT OUTPUT; INSERT INTO #ValidationResults VALUES ('SCHEMA', 'Indexes', NULL, @VALIDATION_SOURCE_COUNT, @VALIDATION_TARGET_COUNT, CASE WHEN @VALIDATION_SOURCE_COUNT = @VALIDATION_TARGET_COUNT THEN 'OK' ELSE 'WARN' END, NULL); IF @VALIDATION_SOURCE_COUNT <> @VALIDATION_TARGET_COUNT BEGIN SET @VALIDATION_WARNINGS = @VALIDATION_WARNINGS + 1; END; PRINT 'Indexes: Source=' + CONVERT(NVARCHAR(10), @VALIDATION_SOURCE_COUNT) + ', Target=' + CONVERT(NVARCHAR(10), @VALIDATION_TARGET_COUNT) + CASE WHEN @VALIDATION_SOURCE_COUNT = @VALIDATION_TARGET_COUNT THEN ' [OK]' ELSE ' [WARN]' END; -- Validate Foreign Keys SET @VALIDATION_SQL = N' SELECT @src = COUNT(*) FROM {#SOURCEDB_Q#}.sys.foreign_keys fk JOIN {#SOURCEDB_Q#}.sys.tables pt ON pt.object_id = fk.parent_object_id JOIN {#SOURCEDB_Q#}.sys.tables rt ON rt.object_id = fk.referenced_object_id JOIN {#SOURCEDB_Q#}.sys.schemas spt ON spt.schema_id = pt.schema_id JOIN {#SOURCEDB_Q#}.sys.schemas srt ON srt.schema_id = rt.schema_id WHERE spt.name{#COLLATION#}<>N''sys''{#COLLATION#} AND NOT EXISTS (SELECT 1 FROM #TBDD_SYNC_DATABASE_EXCLUDEDOBJECTS ex WHERE (ex.IsWildcard = 1 AND (pt.name{#COLLATION#} LIKE ex.Pattern{#COLLATION#} OR (spt.name{#COLLATION#} + N''.'' + pt.name{#COLLATION#}) LIKE ex.Pattern{#COLLATION#})) OR (ex.IsWildcard = 0 AND (pt.name{#COLLATION#} = ex.Pattern{#COLLATION#} OR (spt.name{#COLLATION#} + N''.'' + pt.name{#COLLATION#}) = ex.Pattern{#COLLATION#}))) AND NOT EXISTS (SELECT 1 FROM #TBDD_SYNC_DATABASE_EXCLUDEDOBJECTS ex WHERE (ex.IsWildcard = 1 AND (rt.name{#COLLATION#} LIKE ex.Pattern{#COLLATION#} OR (srt.name{#COLLATION#} + N''.'' + rt.name{#COLLATION#}) LIKE ex.Pattern{#COLLATION#})) OR (ex.IsWildcard = 0 AND (rt.name{#COLLATION#} = ex.Pattern{#COLLATION#} OR (srt.name{#COLLATION#} + N''.'' + rt.name{#COLLATION#}) = ex.Pattern{#COLLATION#})));'; SET @VALIDATION_SQL = REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(@VALIDATION_SQL, @PLACEHOLDERSOURCEDBQUOTED, @SOURCEDATABASEQUOTED), @PLACEHOLDERTARGETDBQUOTED, @TARGETDATABASEQUOTED), @PLACEHOLDERSOURCEDB, @SOURCEDATABASE), @PLACEHOLDERTARGETDB, @TARGETDATABASE), @PLACEHOLDERCOLLATION, @COMPARECOLLATION); EXEC sys.sp_executesql @VALIDATION_SQL, N'@src INT OUTPUT', @src = @VALIDATION_SOURCE_COUNT OUTPUT; -- Target-Validation berücksichtigt auch Excludes für korrekten Vergleich SET @VALIDATION_SQL = N' SELECT @tgt = COUNT(*) FROM {#TARGETDB_Q#}.sys.foreign_keys fk JOIN {#TARGETDB_Q#}.sys.tables pt ON pt.object_id = fk.parent_object_id JOIN {#TARGETDB_Q#}.sys.tables rt ON rt.object_id = fk.referenced_object_id JOIN {#TARGETDB_Q#}.sys.schemas spt ON spt.schema_id = pt.schema_id JOIN {#TARGETDB_Q#}.sys.schemas srt ON srt.schema_id = rt.schema_id WHERE spt.name{#COLLATION#}<>N''sys''{#COLLATION#} AND NOT EXISTS (SELECT 1 FROM #TBDD_SYNC_DATABASE_EXCLUDEDOBJECTS ex WHERE (ex.IsWildcard = 1 AND (pt.name{#COLLATION#} LIKE ex.Pattern{#COLLATION#} OR (spt.name{#COLLATION#} + N''.'' + pt.name{#COLLATION#}) LIKE ex.Pattern{#COLLATION#})) OR (ex.IsWildcard = 0 AND (pt.name{#COLLATION#} = ex.Pattern{#COLLATION#} OR (spt.name{#COLLATION#} + N''.'' + pt.name{#COLLATION#}) = ex.Pattern{#COLLATION#}))) AND NOT EXISTS (SELECT 1 FROM #TBDD_SYNC_DATABASE_EXCLUDEDOBJECTS ex WHERE (ex.IsWildcard = 1 AND (rt.name{#COLLATION#} LIKE ex.Pattern{#COLLATION#} OR (srt.name{#COLLATION#} + N''.'' + rt.name{#COLLATION#}) LIKE ex.Pattern{#COLLATION#})) OR (ex.IsWildcard = 0 AND (rt.name{#COLLATION#} = ex.Pattern{#COLLATION#} OR (srt.name{#COLLATION#} + N''.'' + rt.name{#COLLATION#}) = ex.Pattern{#COLLATION#})));'; SET @VALIDATION_SQL = REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(@VALIDATION_SQL, @PLACEHOLDERSOURCEDBQUOTED, @SOURCEDATABASEQUOTED), @PLACEHOLDERTARGETDBQUOTED, @TARGETDATABASEQUOTED), @PLACEHOLDERSOURCEDB, @SOURCEDATABASE), @PLACEHOLDERTARGETDB, @TARGETDATABASE), @PLACEHOLDERCOLLATION, @COMPARECOLLATION); EXEC sys.sp_executesql @VALIDATION_SQL, N'@tgt INT OUTPUT', @tgt = @VALIDATION_TARGET_COUNT OUTPUT; INSERT INTO #ValidationResults VALUES ('SCHEMA', 'ForeignKeys', NULL, @VALIDATION_SOURCE_COUNT, @VALIDATION_TARGET_COUNT, CASE WHEN @VALIDATION_SOURCE_COUNT = @VALIDATION_TARGET_COUNT THEN 'OK' ELSE 'ERROR' END, NULL); IF @VALIDATION_SOURCE_COUNT <> @VALIDATION_TARGET_COUNT BEGIN SET @VALIDATION_PASSED = 0; SET @VALIDATION_ERRORS = @VALIDATION_ERRORS + 1; END; PRINT 'ForeignKeys: Source=' + CONVERT(NVARCHAR(10), @VALIDATION_SOURCE_COUNT) + ', Target=' + CONVERT(NVARCHAR(10), @VALIDATION_TARGET_COUNT) + CASE WHEN @VALIDATION_SOURCE_COUNT = @VALIDATION_TARGET_COUNT THEN ' [OK]' ELSE ' [ERROR]' END; END; --===================== DATA VALIDATION =====================-- IF UPPER(@VALIDATION_MODE) IN (N'ALL', N'DATA') AND @EXECUTE = 1 BEGIN PRINT N''; PRINT N'--- Data Validation (Row Counts) ---'; -- Create temp table to hold table list for validation CREATE TABLE #TBDD_SYNC_DATABASE_DATA_VALIDATION ( SchemaName NVARCHAR(128) NOT NULL, TableName NVARCHAR(128) NOT NULL ); IF @DEBUG = 1 PRINT '[DEBUG] TBDD_SYNC_DATABASE_DATA_VALIDATION temp table created'; -- Populate table list dynamically -- Korrigiertes Collation-Handling: Beide Seiten der Verkettung mit COLLATE SET @VALIDATION_CURSOR_SQL = N' INSERT INTO #TBDD_SYNC_DATABASE_DATA_VALIDATION (SchemaName, TableName) SELECT s.name AS SchemaName, t.name AS TableName FROM {#SOURCEDB_Q#}.sys.tables t JOIN {#SOURCEDB_Q#}.sys.schemas s ON s.schema_id = t.schema_id WHERE s.name{#COLLATION#}<>N''sys''{#COLLATION#} AND t.is_ms_shipped = 0 AND NOT EXISTS (SELECT 1 FROM #TBDD_SYNC_DATABASE_EXCLUDEDOBJECTS ex WHERE (ex.IsWildcard = 1 AND (t.name{#COLLATION#} LIKE ex.Pattern{#COLLATION#} OR (s.name{#COLLATION#} + N''.'' + t.name{#COLLATION#}) LIKE ex.Pattern{#COLLATION#})) OR (ex.IsWildcard = 0 AND (t.name{#COLLATION#} = ex.Pattern{#COLLATION#} OR (s.name{#COLLATION#} + N''.'' + t.name{#COLLATION#}) = ex.Pattern{#COLLATION#}))) ORDER BY s.name, t.name;'; SET @VALIDATION_CURSOR_SQL = REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(@VALIDATION_CURSOR_SQL, @PLACEHOLDERSOURCEDBQUOTED, @SOURCEDATABASEQUOTED), @PLACEHOLDERTARGETDBQUOTED, @TARGETDATABASEQUOTED), @PLACEHOLDERSOURCEDB, @SOURCEDATABASE), @PLACEHOLDERTARGETDB, @TARGETDATABASE), @PLACEHOLDERCOLLATION, @COMPARECOLLATION); EXEC sys.sp_executesql @VALIDATION_CURSOR_SQL; -- Declare cursor on temp table (LOCAL für Session-Isolation) DECLARE data_val_cur CURSOR LOCAL FAST_FORWARD FOR SELECT SchemaName, TableName FROM #TBDD_SYNC_DATABASE_DATA_VALIDATION ORDER BY SchemaName, TableName; OPEN data_val_cur; FETCH NEXT FROM data_val_cur INTO @VALIDATION_SCHEMA_NAME, @VALIDATION_TABLE_NAME; WHILE @@FETCH_STATUS = 0 BEGIN -- Get source row count BEGIN TRY SET @VALIDATION_SQL = N'SELECT @cnt = COUNT_BIG(*) FROM {#SOURCEDB_Q#}.' + QUOTENAME(@VALIDATION_SCHEMA_NAME) + N'.' + QUOTENAME(@VALIDATION_TABLE_NAME) + N';'; SET @VALIDATION_SQL = REPLACE(REPLACE(REPLACE(REPLACE(@VALIDATION_SQL, @PLACEHOLDERSOURCEDBQUOTED, @SOURCEDATABASEQUOTED), @PLACEHOLDERTARGETDBQUOTED, @TARGETDATABASEQUOTED), @PLACEHOLDERSOURCEDB, @SOURCEDATABASE), @PLACEHOLDERTARGETDB, @TARGETDATABASE); EXEC sys.sp_executesql @VALIDATION_SQL, N'@cnt BIGINT OUTPUT', @cnt = @VALIDATION_SOURCE_ROWS OUTPUT; END TRY BEGIN CATCH SET @VALIDATION_SOURCE_ROWS = -1; -- Error reading source table PRINT N'[WARN] Could not read source table ' + @VALIDATION_SCHEMA_NAME + N'.' + @VALIDATION_TABLE_NAME + N': ' + ERROR_MESSAGE(); END CATCH; -- Get target row count BEGIN TRY SET @VALIDATION_SQL = N'SELECT @cnt = COUNT_BIG(*) FROM {#TARGETDB_Q#}.' + QUOTENAME(@VALIDATION_SCHEMA_NAME) + N'.' + QUOTENAME(@VALIDATION_TABLE_NAME) + N';'; SET @VALIDATION_SQL = REPLACE(REPLACE(REPLACE(REPLACE(@VALIDATION_SQL, @PLACEHOLDERSOURCEDBQUOTED, @SOURCEDATABASEQUOTED), @PLACEHOLDERTARGETDBQUOTED, @TARGETDATABASEQUOTED), @PLACEHOLDERSOURCEDB, @SOURCEDATABASE), @PLACEHOLDERTARGETDB, @TARGETDATABASE); EXEC sys.sp_executesql @VALIDATION_SQL, N'@cnt BIGINT OUTPUT', @cnt = @VALIDATION_TARGET_ROWS OUTPUT; END TRY BEGIN CATCH SET @VALIDATION_TARGET_ROWS = -1; -- Table doesn't exist END CATCH; INSERT INTO #ValidationResults VALUES ('DATA', 'TableRows', @VALIDATION_SCHEMA_NAME + N'.' + @VALIDATION_TABLE_NAME, @VALIDATION_SOURCE_ROWS, @VALIDATION_TARGET_ROWS, CASE WHEN @VALIDATION_SOURCE_ROWS = @VALIDATION_TARGET_ROWS THEN 'OK' WHEN @VALIDATION_TARGET_ROWS = -1 THEN 'ERROR' ELSE 'ERROR' END, CASE WHEN @VALIDATION_SOURCE_ROWS = @VALIDATION_TARGET_ROWS THEN NULL WHEN @VALIDATION_TARGET_ROWS = -1 THEN 'Table missing in target' ELSE 'Row mismatch' END); IF @VALIDATION_SOURCE_ROWS <> @VALIDATION_TARGET_ROWS BEGIN SET @VALIDATION_PASSED = 0; SET @VALIDATION_ERRORS = @VALIDATION_ERRORS + 1; PRINT @VALIDATION_SCHEMA_NAME + N'.' + @VALIDATION_TABLE_NAME + N': Source=' + CONVERT(NVARCHAR(20), @VALIDATION_SOURCE_ROWS) + N', Target=' + CONVERT(NVARCHAR(20), @VALIDATION_TARGET_ROWS) + N' [ERROR]'; END ELSE BEGIN PRINT @VALIDATION_SCHEMA_NAME + N'.' + @VALIDATION_TABLE_NAME + N': ' + CONVERT(NVARCHAR(20), @VALIDATION_SOURCE_ROWS) + N' rows [OK]'; END; FETCH NEXT FROM data_val_cur INTO @VALIDATION_SCHEMA_NAME, @VALIDATION_TABLE_NAME; END; CLOSE data_val_cur; DEALLOCATE data_val_cur; -- Cleanup temp table IF OBJECT_ID('tempdb..#TBDD_SYNC_DATABASE_DATA_VALIDATION') IS NOT NULL DROP TABLE #TBDD_SYNC_DATABASE_DATA_VALIDATION; END; -- Log validation results IF (UPPER(@LOGLEVEL) IN (N'INFO')) BEGIN INSERT INTO [TBDD_SYNC_DATABASE_LOG] ([LOG_LEVEL], [MESSAGE1], [MESSAGE2], [MESSAGE3], [ADDED_WHO], [ADDED_WHEN]) SELECT CASE WHEN Status = 'ERROR' THEN 'ERROR' WHEN Status = 'WARN' THEN 'WARN' ELSE 'INFO' END, 'Validation-' + ValidationType, ObjectType + ISNULL(' (' + ObjectName + ')', ''), 'Source=' + CONVERT(NVARCHAR(20), SourceCount) + ', Target=' + CONVERT(NVARCHAR(20), TargetCount) + ' [' + Status + ']', @MY_PROCEDURE_NAME, GETDATE() FROM #ValidationResults; END; -- Output validation summary PRINT N''; PRINT N'===================================================================================================='; IF @VALIDATION_PASSED = 1 BEGIN PRINT N'VALIDATION PASSED! All objects migrated successfully.'; IF @VALIDATION_WARNINGS > 0 BEGIN PRINT N'Warnings: ' + CONVERT(NVARCHAR(10), @VALIDATION_WARNINGS); END; IF (UPPER(@LOGLEVEL) IN (N'INFO')) BEGIN INSERT INTO [TBDD_SYNC_DATABASE_LOG] ([LOG_LEVEL], [MESSAGE1], [MESSAGE2], [MESSAGE3], [ADDED_WHO], [ADDED_WHEN]) VALUES ('INFO', '08-Validation', 'PASSED', 'All checks completed successfully', @MY_PROCEDURE_NAME, GETDATE()); END; END ELSE BEGIN PRINT N'VALIDATION FAILED! Errors: ' + CONVERT(NVARCHAR(10), @VALIDATION_ERRORS) + N', Warnings: ' + CONVERT(NVARCHAR(10), @VALIDATION_WARNINGS); SET @RETURN_STATUS = 1; -- Status bei Validation-Fehler setzen IF (UPPER(@LOGLEVEL) IN (N'INFO', N'WARN', N'ERROR')) BEGIN INSERT INTO [TBDD_SYNC_DATABASE_LOG] ([LOG_LEVEL], [MESSAGE1], [MESSAGE2], [MESSAGE3], [ADDED_WHO], [ADDED_WHEN]) VALUES ('ERROR', '08-Validation', 'FAILED', 'Errors: ' + CONVERT(NVARCHAR(10), @VALIDATION_ERRORS) + ', Warnings: ' + CONVERT(NVARCHAR(10), @VALIDATION_WARNINGS), @MY_PROCEDURE_NAME, GETDATE()); END; END; PRINT N'===================================================================================================='; -- Output validation details table (print each row for visibility) PRINT N''; PRINT N'--- Validation Details ---'; PRINT N''; DECLARE @vr_Type NVARCHAR(20), @vr_ObjType NVARCHAR(50), @vr_ObjName NVARCHAR(256), @vr_SrcCnt BIGINT, @vr_TgtCnt BIGINT, @vr_Status NVARCHAR(10), @vr_Msg NVARCHAR(500); DECLARE @vr_HasRows BIT = 0; DECLARE validation_cursor CURSOR LOCAL FAST_FORWARD FOR SELECT ValidationType, ObjectType, ObjectName, SourceCount, TargetCount, Status, Message FROM #ValidationResults ORDER BY CASE Status WHEN 'ERROR' THEN 1 WHEN 'WARN' THEN 2 ELSE 3 END, ValidationType, ObjectType; OPEN validation_cursor; FETCH NEXT FROM validation_cursor INTO @vr_Type, @vr_ObjType, @vr_ObjName, @vr_SrcCnt, @vr_TgtCnt, @vr_Status, @vr_Msg; WHILE @@FETCH_STATUS = 0 BEGIN SET @vr_HasRows = 1; PRINT N'[' + @vr_Status + N'] ' + @vr_Type + N' - ' + @vr_ObjType + ISNULL(N' (' + @vr_ObjName + N')', N'') + N': Source=' + CONVERT(NVARCHAR(20), @vr_SrcCnt) + N', Target=' + CONVERT(NVARCHAR(20), @vr_TgtCnt) + ISNULL(N' - ' + @vr_Msg, N''); FETCH NEXT FROM validation_cursor INTO @vr_Type, @vr_ObjType, @vr_ObjName, @vr_SrcCnt, @vr_TgtCnt, @vr_Status, @vr_Msg; END; CLOSE validation_cursor; DEALLOCATE validation_cursor; IF @vr_HasRows = 0 PRINT N'(No validation results to display)'; PRINT N''; -- ===================== DETAILED MISMATCH REPORT (Bidirectional) ===================== -- Show specific objects that differ between Source and Target IF @VALIDATION_PASSED = 0 AND UPPER(@VALIDATION_MODE) IN (N'ALL', N'SCHEMA') BEGIN PRINT N''; PRINT N'--- Detailed Mismatch Report ---'; PRINT N''; DECLARE @MismatchSQL NVARCHAR(MAX); DECLARE @MismatchName NVARCHAR(500); DECLARE @MismatchFound BIT = 0; CREATE TABLE #TempMismatch (ObjectName NVARCHAR(500)); -- Tables: Missing in Target (exist in Source) SET @MismatchSQL = N' SELECT s.name + N''.'' + t.name FROM ' + @SOURCEDATABASEQUOTED + N'.sys.tables t JOIN ' + @SOURCEDATABASEQUOTED + N'.sys.schemas s ON s.schema_id = t.schema_id WHERE s.name' + @COMPARECOLLATION + N'<>N''sys''' + @COMPARECOLLATION + N' AND t.is_ms_shipped = 0 AND NOT EXISTS (SELECT 1 FROM ' + @TARGETDATABASEQUOTED + N'.sys.tables tt JOIN ' + @TARGETDATABASEQUOTED + N'.sys.schemas ts ON ts.schema_id = tt.schema_id WHERE ts.name' + @COMPARECOLLATION + N'=s.name' + @COMPARECOLLATION + N' AND tt.name' + @COMPARECOLLATION + N'=t.name' + @COMPARECOLLATION + N')'; INSERT INTO #TempMismatch EXEC sys.sp_executesql @MismatchSQL; IF EXISTS (SELECT 1 FROM #TempMismatch) BEGIN SET @MismatchFound = 1; PRINT N'[Tables] Missing in Target (exist in Source):'; DECLARE mismatch_cur CURSOR LOCAL FAST_FORWARD FOR SELECT ObjectName FROM #TempMismatch; OPEN mismatch_cur; FETCH NEXT FROM mismatch_cur INTO @MismatchName; WHILE @@FETCH_STATUS = 0 BEGIN PRINT N' - ' + @MismatchName; FETCH NEXT FROM mismatch_cur INTO @MismatchName; END; CLOSE mismatch_cur; DEALLOCATE mismatch_cur; END; TRUNCATE TABLE #TempMismatch; -- Tables: Extra in Target (not in Source) SET @MismatchSQL = N' SELECT s.name + N''.'' + t.name FROM ' + @TARGETDATABASEQUOTED + N'.sys.tables t JOIN ' + @TARGETDATABASEQUOTED + N'.sys.schemas s ON s.schema_id = t.schema_id WHERE s.name' + @COMPARECOLLATION + N'<>N''sys''' + @COMPARECOLLATION + N' AND t.is_ms_shipped = 0 AND NOT EXISTS (SELECT 1 FROM ' + @SOURCEDATABASEQUOTED + N'.sys.tables st JOIN ' + @SOURCEDATABASEQUOTED + N'.sys.schemas ss ON ss.schema_id = st.schema_id WHERE ss.name' + @COMPARECOLLATION + N'=s.name' + @COMPARECOLLATION + N' AND st.name' + @COMPARECOLLATION + N'=t.name' + @COMPARECOLLATION + N')'; INSERT INTO #TempMismatch EXEC sys.sp_executesql @MismatchSQL; IF EXISTS (SELECT 1 FROM #TempMismatch) BEGIN SET @MismatchFound = 1; PRINT N'[Tables] Extra in Target (not in Source):'; DECLARE mismatch_cur CURSOR LOCAL FAST_FORWARD FOR SELECT ObjectName FROM #TempMismatch; OPEN mismatch_cur; FETCH NEXT FROM mismatch_cur INTO @MismatchName; WHILE @@FETCH_STATUS = 0 BEGIN PRINT N' - ' + @MismatchName; FETCH NEXT FROM mismatch_cur INTO @MismatchName; END; CLOSE mismatch_cur; DEALLOCATE mismatch_cur; END; TRUNCATE TABLE #TempMismatch; -- Views: Missing in Target SET @MismatchSQL = N' SELECT s.name + N''.'' + v.name FROM ' + @SOURCEDATABASEQUOTED + N'.sys.views v JOIN ' + @SOURCEDATABASEQUOTED + N'.sys.schemas s ON s.schema_id = v.schema_id WHERE s.name' + @COMPARECOLLATION + N'<>N''sys''' + @COMPARECOLLATION + N' AND NOT EXISTS (SELECT 1 FROM ' + @TARGETDATABASEQUOTED + N'.sys.views tv JOIN ' + @TARGETDATABASEQUOTED + N'.sys.schemas ts ON ts.schema_id = tv.schema_id WHERE ts.name' + @COMPARECOLLATION + N'=s.name' + @COMPARECOLLATION + N' AND tv.name' + @COMPARECOLLATION + N'=v.name' + @COMPARECOLLATION + N')'; INSERT INTO #TempMismatch EXEC sys.sp_executesql @MismatchSQL; IF EXISTS (SELECT 1 FROM #TempMismatch) BEGIN SET @MismatchFound = 1; PRINT N'[Views] Missing in Target:'; DECLARE mismatch_cur CURSOR LOCAL FAST_FORWARD FOR SELECT ObjectName FROM #TempMismatch; OPEN mismatch_cur; FETCH NEXT FROM mismatch_cur INTO @MismatchName; WHILE @@FETCH_STATUS = 0 BEGIN PRINT N' - ' + @MismatchName; FETCH NEXT FROM mismatch_cur INTO @MismatchName; END; CLOSE mismatch_cur; DEALLOCATE mismatch_cur; END; TRUNCATE TABLE #TempMismatch; -- Views: Extra in Target SET @MismatchSQL = N' SELECT s.name + N''.'' + v.name FROM ' + @TARGETDATABASEQUOTED + N'.sys.views v JOIN ' + @TARGETDATABASEQUOTED + N'.sys.schemas s ON s.schema_id = v.schema_id WHERE s.name' + @COMPARECOLLATION + N'<>N''sys''' + @COMPARECOLLATION + N' AND NOT EXISTS (SELECT 1 FROM ' + @SOURCEDATABASEQUOTED + N'.sys.views sv JOIN ' + @SOURCEDATABASEQUOTED + N'.sys.schemas ss ON ss.schema_id = sv.schema_id WHERE ss.name' + @COMPARECOLLATION + N'=s.name' + @COMPARECOLLATION + N' AND sv.name' + @COMPARECOLLATION + N'=v.name' + @COMPARECOLLATION + N')'; INSERT INTO #TempMismatch EXEC sys.sp_executesql @MismatchSQL; IF EXISTS (SELECT 1 FROM #TempMismatch) BEGIN SET @MismatchFound = 1; PRINT N'[Views] Extra in Target:'; DECLARE mismatch_cur CURSOR LOCAL FAST_FORWARD FOR SELECT ObjectName FROM #TempMismatch; OPEN mismatch_cur; FETCH NEXT FROM mismatch_cur INTO @MismatchName; WHILE @@FETCH_STATUS = 0 BEGIN PRINT N' - ' + @MismatchName; FETCH NEXT FROM mismatch_cur INTO @MismatchName; END; CLOSE mismatch_cur; DEALLOCATE mismatch_cur; END; TRUNCATE TABLE #TempMismatch; -- Procedures: Missing in Target SET @MismatchSQL = N' SELECT s.name + N''.'' + p.name FROM ' + @SOURCEDATABASEQUOTED + N'.sys.procedures p JOIN ' + @SOURCEDATABASEQUOTED + N'.sys.schemas s ON s.schema_id = p.schema_id WHERE s.name' + @COMPARECOLLATION + N'<>N''sys''' + @COMPARECOLLATION + N' AND NOT EXISTS (SELECT 1 FROM ' + @TARGETDATABASEQUOTED + N'.sys.procedures tp JOIN ' + @TARGETDATABASEQUOTED + N'.sys.schemas ts ON ts.schema_id = tp.schema_id WHERE ts.name' + @COMPARECOLLATION + N'=s.name' + @COMPARECOLLATION + N' AND tp.name' + @COMPARECOLLATION + N'=p.name' + @COMPARECOLLATION + N')'; INSERT INTO #TempMismatch EXEC sys.sp_executesql @MismatchSQL; IF EXISTS (SELECT 1 FROM #TempMismatch) BEGIN SET @MismatchFound = 1; PRINT N'[Procedures] Missing in Target:'; DECLARE mismatch_cur CURSOR LOCAL FAST_FORWARD FOR SELECT ObjectName FROM #TempMismatch; OPEN mismatch_cur; FETCH NEXT FROM mismatch_cur INTO @MismatchName; WHILE @@FETCH_STATUS = 0 BEGIN PRINT N' - ' + @MismatchName; FETCH NEXT FROM mismatch_cur INTO @MismatchName; END; CLOSE mismatch_cur; DEALLOCATE mismatch_cur; END; TRUNCATE TABLE #TempMismatch; -- Procedures: Extra in Target SET @MismatchSQL = N' SELECT s.name + N''.'' + p.name FROM ' + @TARGETDATABASEQUOTED + N'.sys.procedures p JOIN ' + @TARGETDATABASEQUOTED + N'.sys.schemas s ON s.schema_id = p.schema_id WHERE s.name' + @COMPARECOLLATION + N'<>N''sys''' + @COMPARECOLLATION + N' AND NOT EXISTS (SELECT 1 FROM ' + @SOURCEDATABASEQUOTED + N'.sys.procedures sp JOIN ' + @SOURCEDATABASEQUOTED + N'.sys.schemas ss ON ss.schema_id = sp.schema_id WHERE ss.name' + @COMPARECOLLATION + N'=s.name' + @COMPARECOLLATION + N' AND sp.name' + @COMPARECOLLATION + N'=p.name' + @COMPARECOLLATION + N')'; INSERT INTO #TempMismatch EXEC sys.sp_executesql @MismatchSQL; IF EXISTS (SELECT 1 FROM #TempMismatch) BEGIN SET @MismatchFound = 1; PRINT N'[Procedures] Extra in Target:'; DECLARE mismatch_cur CURSOR LOCAL FAST_FORWARD FOR SELECT ObjectName FROM #TempMismatch; OPEN mismatch_cur; FETCH NEXT FROM mismatch_cur INTO @MismatchName; WHILE @@FETCH_STATUS = 0 BEGIN PRINT N' - ' + @MismatchName; FETCH NEXT FROM mismatch_cur INTO @MismatchName; END; CLOSE mismatch_cur; DEALLOCATE mismatch_cur; END; TRUNCATE TABLE #TempMismatch; -- Functions: Missing in Target SET @MismatchSQL = N' SELECT s.name + N''.'' + o.name FROM ' + @SOURCEDATABASEQUOTED + N'.sys.objects o JOIN ' + @SOURCEDATABASEQUOTED + N'.sys.schemas s ON s.schema_id = o.schema_id WHERE o.type IN (N''FN'',N''TF'',N''IF'') AND s.name' + @COMPARECOLLATION + N'<>N''sys''' + @COMPARECOLLATION + N' AND NOT EXISTS (SELECT 1 FROM ' + @TARGETDATABASEQUOTED + N'.sys.objects tobj JOIN ' + @TARGETDATABASEQUOTED + N'.sys.schemas ts ON ts.schema_id = tobj.schema_id WHERE ts.name' + @COMPARECOLLATION + N'=s.name' + @COMPARECOLLATION + N' AND tobj.name' + @COMPARECOLLATION + N'=o.name' + @COMPARECOLLATION + N' AND tobj.type IN (N''FN'',N''TF'',N''IF''))'; INSERT INTO #TempMismatch EXEC sys.sp_executesql @MismatchSQL; IF EXISTS (SELECT 1 FROM #TempMismatch) BEGIN SET @MismatchFound = 1; PRINT N'[Functions] Missing in Target:'; DECLARE mismatch_cur CURSOR LOCAL FAST_FORWARD FOR SELECT ObjectName FROM #TempMismatch; OPEN mismatch_cur; FETCH NEXT FROM mismatch_cur INTO @MismatchName; WHILE @@FETCH_STATUS = 0 BEGIN PRINT N' - ' + @MismatchName; FETCH NEXT FROM mismatch_cur INTO @MismatchName; END; CLOSE mismatch_cur; DEALLOCATE mismatch_cur; END; TRUNCATE TABLE #TempMismatch; -- Functions: Extra in Target SET @MismatchSQL = N' SELECT s.name + N''.'' + o.name FROM ' + @TARGETDATABASEQUOTED + N'.sys.objects o JOIN ' + @TARGETDATABASEQUOTED + N'.sys.schemas s ON s.schema_id = o.schema_id WHERE o.type IN (N''FN'',N''TF'',N''IF'') AND s.name' + @COMPARECOLLATION + N'<>N''sys''' + @COMPARECOLLATION + N' AND NOT EXISTS (SELECT 1 FROM ' + @SOURCEDATABASEQUOTED + N'.sys.objects sobj JOIN ' + @SOURCEDATABASEQUOTED + N'.sys.schemas ss ON ss.schema_id = sobj.schema_id WHERE ss.name' + @COMPARECOLLATION + N'=s.name' + @COMPARECOLLATION + N' AND sobj.name' + @COMPARECOLLATION + N'=o.name' + @COMPARECOLLATION + N' AND sobj.type IN (N''FN'',N''TF'',N''IF''))'; INSERT INTO #TempMismatch EXEC sys.sp_executesql @MismatchSQL; IF EXISTS (SELECT 1 FROM #TempMismatch) BEGIN SET @MismatchFound = 1; PRINT N'[Functions] Extra in Target:'; DECLARE mismatch_cur CURSOR LOCAL FAST_FORWARD FOR SELECT ObjectName FROM #TempMismatch; OPEN mismatch_cur; FETCH NEXT FROM mismatch_cur INTO @MismatchName; WHILE @@FETCH_STATUS = 0 BEGIN PRINT N' - ' + @MismatchName; FETCH NEXT FROM mismatch_cur INTO @MismatchName; END; CLOSE mismatch_cur; DEALLOCATE mismatch_cur; END; DROP TABLE #TempMismatch; IF @MismatchFound = 0 PRINT N'(Count mismatch but no specific objects found - may be due to exclusions)'; PRINT N''; END; -- End of Detailed Mismatch Report IF OBJECT_ID('tempdb..#ValidationResults') IS NOT NULL DROP TABLE #ValidationResults; END; -- End of validation --=================================================-- Statistics Update --=================================================-- -- Stats-Block VOR CLEANUP, da #TBDD_SYNC_DATABASE_COMMANDS noch benötigt wird -- Statistiken nur für geänderte Tabellen aktualisieren (statt sp_updatestats für alle) IF @EXECUTE = 1 AND @INCLUDEDATA = 1 AND OBJECT_ID('tempdb..#TBDD_SYNC_DATABASE_COMMANDS') IS NOT NULL BEGIN BEGIN TRY DECLARE @UpdateStatsSQL NVARCHAR(MAX); DECLARE @StatTableName NVARCHAR(256); DECLARE @StatsUpdated INT = 0; -- Nur für Tabellen, die im Data-Sync waren, Statistiken aktualisieren DECLARE stats_cursor CURSOR LOCAL FAST_FORWARD FOR SELECT DISTINCT SUBSTRING(Command, CHARINDEX('MERGE ', Command) + 6, CHARINDEX(' AS tgt', Command) - CHARINDEX('MERGE ', Command) - 6) FROM #TBDD_SYNC_DATABASE_COMMANDS WHERE Phase = '20-Data' AND Command LIKE '%MERGE %'; OPEN stats_cursor; FETCH NEXT FROM stats_cursor INTO @StatTableName; WHILE @@FETCH_STATUS = 0 BEGIN BEGIN TRY SET @UpdateStatsSQL = N'USE ' + QUOTENAME(@TARGETDATABASE) + N'; UPDATE STATISTICS ' + @StatTableName + N';'; EXEC sys.sp_executesql @UpdateStatsSQL; SET @StatsUpdated = @StatsUpdated + 1; END TRY BEGIN CATCH PRINT '[WARN] Could not update stats for ' + @StatTableName + ': ' + ERROR_MESSAGE(); END CATCH; FETCH NEXT FROM stats_cursor INTO @StatTableName; END; CLOSE stats_cursor; DEALLOCATE stats_cursor; PRINT '[INFO] Statistics updated for ' + CONVERT(NVARCHAR(10), @StatsUpdated) + ' tables'; END TRY BEGIN CATCH PRINT '[WARN] Statistics update failed: ' + ERROR_MESSAGE(); END CATCH; END; --=================================================-- Cleanup and Exit --=================================================-- CLEANUP_AND_EXIT: -- Transaction Safety Net: Falls noch eine offene Transaction existiert, rollback -- Dies kann vorkommen bei GOTO-Sprung nach kritischem Fehler (falls Rollback nicht bereits erfolgt ist) IF @@TRANCOUNT > 0 BEGIN PRINT N'[WARN] Open transaction detected at cleanup - rolling back...'; ROLLBACK TRANSACTION; END; -- Cleanup: Temp-Tables explizit droppen IF OBJECT_ID('tempdb..#TBDD_SYNC_DATABASE_EXCLUDEDOBJECTS') IS NOT NULL DROP TABLE #TBDD_SYNC_DATABASE_EXCLUDEDOBJECTS; IF OBJECT_ID('tempdb..#TBDD_SYNC_DATABASE_COMMANDS') IS NOT NULL DROP TABLE #TBDD_SYNC_DATABASE_COMMANDS; -- DATA_VALIDATION-Tabelle wird bereits in der Validation-Phase gedroppt RETURN @RETURN_STATUS; END; GO