8
0
Files
Skriptentwickung/current/[DD_SYS]-Database/[PRDD_MIGRATE_DATABASE]/[PRDD_MIGRATE_DATABASE].sql

3095 lines
170 KiB
Transact-SQL

USE [DD_SYS]
GO
/****** Object: StoredProcedure [dbo].[PRDD_MIGRATE_DATABASE] Script Date: 24.12.2025 14:51:05 ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
-- [PRDD_MIGRATE_DATABASE]
-- =================================================================
-- Clone a source database into a new target database with a new collation.
-- The source database remains unchanged; all objects and data are copied.
-- Minimum requirement: MS SQL Server 2016 SP1 (CREATE OR ALTER)
--
-- Returns: INT Value - 0 = Everything worked well
-- =================================================================
-- SUPPORTED OBJECTS:
-- Schemas, Partition Functions/Schemes, Sequences, User-Defined Types,
-- Table Types, Tables (with Collation conversion), Data, Default/Check
-- Constraints, Primary/Unique Keys, Indexes, Foreign Keys, Triggers,
-- Views, Functions, Stored Procedures, Statistics, Synonyms
--
-- NOT SUPPORTED (must be migrated manually):
-- - Memory-optimized tables (In-Memory OLTP)
-- - Filestream columns
-- - Filetables
-- - XML Schema Collections
-- - Full-Text Indexes / Full-Text Catalogs
-- - Extended Properties
-- - Database-level Triggers (DDL Triggers)
-- - CLR Assemblies
-- - Service Broker objects
-- - Linked Server references
-- - Database Mail / Alerts / Jobs
-- - Triggers/Views/Functions/Procedures with external database references (3-part names like [OtherDB].[dbo].[Table])
-- -> These objects are SKIPPED with WARN logging to avoid collation conflicts
-- -> References to the SOURCE database are automatically replaced with TARGET database
-- =================================================================
-- 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: 22.12.2025 / MK
-- Version Date / Editor: 24.12.2025 / MK
-- Version Number: 1.1.4.0
-- =================================================================
-- History:
-- 22.12.2025 / MK - First Version
-- 23.12.2025 / MK - Added @pPREVALIDATE parameter for SQL syntax pre-validation
-- 23.12.2025 / MK - Code Review fixes: Phase names, parameter output, skip phases
-- 23.12.2025 / MK - Code Review fixes: @PREVALIDATE default=1, kill_cursor error handling,
-- Temporal Tables/Columnstore Index warnings, LOGLEVEL validation
-- 23.12.2025 / MK - Pre-validation fix: USE [TargetDB] replaced with USE [SourceDB] for
-- syntax validation when target database doesn't exist yet
-- 24.12.2025 / MK - Bugfix: #SkippedObjects PRIMARY KEY violation when object has multiple
-- external DB references - added IGNORE_DUP_KEY and NOT EXISTS checks
-- 24.12.2025 / MK - @pNEWCOLLATION now optional - if NULL, source collation is used
-- (allows database cloning without collation change)
CREATE OR ALTER PROCEDURE [dbo].[PRDD_MIGRATE_DATABASE] (
@pDATABASE NVARCHAR(128) = NULL, -- Source database (unchanged)
@pTARGETDATABASE NVARCHAR(128) = NULL, -- Target database to create
@pNEWCOLLATION NVARCHAR(128) = NULL, -- New collation for target (e.g. 'Latin1_General_CI_AS'), NULL = use source collation
@pMODE NVARCHAR(10) = 'FULL', -- 'FULL' = All, 'SCHEMA' = Structure only, 'DATA' = Data only
@pEXECUTE BIT = 0, -- 0 = Only output commands, 1 = Execute commands
@pDROPTARGETIFEXISTS BIT = 0, -- 1 = Drop target DB if it already exists
@pSTOPONERROR BIT = 1, -- Stop execution on first error when @pEXECUTE = 1
@pBATCHSIZE INT = 1000000, -- Batch size for data copy (0 = no batching, default 1000000)
@pDATAPATH NVARCHAR(260) = NULL, -- Optional: Path for MDF data file (e.g. 'D:\Data\')
@pLOGPATH NVARCHAR(260) = NULL, -- Optional: Path for LDF log file (e.g. 'D:\Logs\')
@pEXCLUDEOBJECTS NVARCHAR(MAX) = NULL, -- Comma-separated list of objects to exclude (supports * as wildcard for LIKE)
@pVALIDATE NVARCHAR(10) = 'NONE', -- 'ALL' = Validate schema+data, 'SCHEMA' = Only objects, 'DATA' = Only row counts, 'NONE' = Skip
@pPREVALIDATE BIT = 1, -- 1 = Validate all SQL commands syntax BEFORE execution (default), 0 = Skip pre-validation
@pLOGLEVEL NVARCHAR(25) = 'INFO', -- Set to 'INFO','WARN','ERROR' or NULL to disable logging
@pDEBUG BIT = 0 -- 0 = No debug output, 1 = Print debug messages
)
AS
BEGIN
--=================================================-- Set session options --==================================================--
SET NOCOUNT ON;
SET ANSI_NULLS ON;
SET QUOTED_IDENTIFIER ON;
SET ANSI_PADDING ON;
SET ANSI_WARNINGS ON;
SET CONCAT_NULL_YIELDS_NULL ON;
SET ARITHABORT ON;
SET NUMERIC_ROUNDABORT OFF;
----------------------------------------------------------------------------------------------------------------------------
--=========================================-- Parameter copies (avoid sniffing) --========================================--
DECLARE @SOURCEDATABASE NVARCHAR(128) = NULLIF(LTRIM(RTRIM(ISNULL(@pDATABASE,N''))),N''),
@TARGETDATABASE NVARCHAR(128) = NULLIF(LTRIM(RTRIM(ISNULL(@pTARGETDATABASE,N''))),N''),
@NEWCOLLATION NVARCHAR(128) = NULLIF(LTRIM(RTRIM(ISNULL(@pNEWCOLLATION,N''))),N''),
@MODE NVARCHAR(10) = UPPER(ISNULL(NULLIF(LTRIM(RTRIM(@pMODE)),N''), N'FULL')),
@EXECUTECOMMANDS BIT = ISNULL(@pEXECUTE,0),
@DROPTARGETIFEXISTS BIT = ISNULL(@pDROPTARGETIFEXISTS,0),
@STOPONERROR BIT = ISNULL(@pSTOPONERROR,1),
@BATCHSIZE INT = CASE WHEN ISNULL(@pBATCHSIZE,1000000) < 1 THEN 0 ELSE ISNULL(@pBATCHSIZE,1000000) END,
@DATAFILEPATH NVARCHAR(260) = NULLIF(LTRIM(RTRIM(ISNULL(@pDATAPATH,N''))),N''),
@LOGFILEPATH NVARCHAR(260) = NULLIF(LTRIM(RTRIM(ISNULL(@pLOGPATH,N''))),N''),
@EXCLUDEOBJECTS NVARCHAR(MAX) = NULLIF(LTRIM(RTRIM(ISNULL(@pEXCLUDEOBJECTS,N''))),N''),
@VALIDATION_MODE NVARCHAR(10) = UPPER(ISNULL(NULLIF(LTRIM(RTRIM(@pVALIDATE)),N''), N'NONE')),
@PREVALIDATE BIT = ISNULL(@pPREVALIDATE, 1),
@LOGLEVEL NVARCHAR(25) = CASE WHEN @pLOGLEVEL IS NULL THEN NULL ELSE UPPER(LTRIM(RTRIM(@pLOGLEVEL))) END,
@DEBUG BIT = ISNULL(@pDEBUG, 0);
----------------------------------------------------------------------------------------------------------------------------
--=================================================-- Declare runtime variables --========================================--
DECLARE @MY_PROCEDURE_NAME NVARCHAR(128) = OBJECT_NAME(@@PROCID);
-- Platzhalter für dynamisches SQL (vermeidet komplexes Apostrophe-Escaping)
DECLARE @PH_SOURCEDB NVARCHAR(20) = N'{#SOURCEDB#}', -- Platzhalter für Quell-Datenbank (unquoted)
@PH_TARGETDB NVARCHAR(20) = N'{#TARGETDB#}', -- Platzhalter für Ziel-Datenbank (unquoted)
@PH_SOURCEDB_QUOTED NVARCHAR(20) = N'{#SOURCEDB_Q#}', -- Platzhalter für [Quell-Datenbank] (quoted)
@PH_TARGETDB_QUOTED NVARCHAR(20) = N'{#TARGETDB_Q#}', -- Platzhalter für [Ziel-Datenbank] (quoted)
@PH_BATCHSIZE NVARCHAR(20) = N'{#BATCHSIZE#}'; -- Platzhalter für Batch-Größe
DECLARE @RUN_ID UNIQUEIDENTIFIER = NEWID(),
@STARTTIME DATETIME = GETDATE(),
@STEPSTARTTIME DATETIME = NULL,
@ROWCOUNT_AFFECTED BIGINT = 0,
@TOTAL_ROWS_MIGRATED BIGINT = 0,
@SOURCEDATABASE_QUOTED SYSNAME = NULL,
@TARGETDATABASE_QUOTED SYSNAME = NULL,
@DETECTED_SOURCE_COLLATION SYSNAME = NULL,
@DETECTSQL NVARCHAR(MAX) = NULL,
@COMPATIBILITY_LEVEL INT = NULL,
@DYNAMICSQL NVARCHAR(MAX) = NULL,
@CURRENTSTEP INT = NULL,
@CURRENTPHASE NVARCHAR(50) = NULL,
@CURRENTCOMMAND NVARCHAR(MAX) = NULL,
@ERRORMESSAGE NVARCHAR(4000) = NULL,
@SOURCE_USER_ACCESS_ORIGINAL NVARCHAR(20) = NULL,
@KILLSESSIONID INT = 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_OBJECT_TYPE NVARCHAR(50) = NULL,
@VALIDATION_TABLE_NAME NVARCHAR(256) = NULL,
@VALIDATION_SCHEMA_NAME NVARCHAR(128) = NULL,
@VALIDATION_SOURCE_ROWS BIGINT = 0,
@VALIDATION_TARGET_ROWS BIGINT = 0,
@SOURCE_LOCKED BIT = 0,
@HAS_SOURCE_CONTROL BIT = 0,
@HAS_CREATE_DATABASE BIT = 0,
@HAS_ALTER_ANY_DATABASE BIT = 0,
@HAS_VIEW_SERVER_STATE BIT = 0,
@PERMISSION_SQL NVARCHAR(500) = NULL,
@MISSING_PERMISSIONS NVARCHAR(MAX) = N'',
@RETURN_STATUS INT = 0,
@RETURN_STATUS_TEXT NVARCHAR(MAX) = 'START PROCEDURE [' + @MY_PROCEDURE_NAME + '] @ ' + CONVERT(VARCHAR(50),GETDATE(),120);
DECLARE @tmp TABLE (x INT);
----------------------------------------------------------------------------------------------------------------------------
BEGIN TRY
--=================================================-- Output parameters --================================================--
PRINT '====================================================================================================';
PRINT @RETURN_STATUS_TEXT;
PRINT '';
PRINT 'PARAMETER01 - @DATABASE (source): ' + ISNULL(@SOURCEDATABASE, '(NULL)');
PRINT 'PARAMETER02 - @TARGETDATABASE: ' + ISNULL(@TARGETDATABASE, '(NULL)');
PRINT 'PARAMETER03 - @NEWCOLLATION: ' + ISNULL(@NEWCOLLATION, '(NULL)');
PRINT 'PARAMETER04 - @MODE: ' + @MODE + ' (FULL=All, SCHEMA=Structure, DATA=Data only)';
PRINT 'PARAMETER05 - @EXECUTE: ' + CONVERT(NVARCHAR(1),@EXECUTECOMMANDS);
PRINT 'PARAMETER06 - @DROPTARGETIFEXISTS: ' + CONVERT(NVARCHAR(1),@DROPTARGETIFEXISTS);
PRINT 'PARAMETER07 - @STOPONERROR: ' + CONVERT(NVARCHAR(1),@STOPONERROR);
PRINT 'PARAMETER08 - @BATCHSIZE: ' + CASE WHEN @BATCHSIZE = 0 THEN 'disabled' ELSE CONVERT(NVARCHAR(20),@BATCHSIZE) END;
PRINT 'PARAMETER09 - @DATAPATH: ' + ISNULL(@DATAFILEPATH, '(default)');
PRINT 'PARAMETER10 - @LOGPATH: ' + ISNULL(@LOGFILEPATH, '(default)');
PRINT 'PARAMETER11 - @EXCLUDEOBJECTS: ' + ISNULL(@EXCLUDEOBJECTS, '(none)');
PRINT 'PARAMETER12 - @VALIDATE: ' + @VALIDATION_MODE + ' (ALL=Schema+Data, SCHEMA=Objects, DATA=Rows, NONE=Skip)';
PRINT 'PARAMETER13 - @PREVALIDATE: ' + CONVERT(NVARCHAR(1), @PREVALIDATE) + ' (1=Syntax check before execution)';
PRINT 'PARAMETER14 - @LOGLEVEL: ' + ISNULL(@LOGLEVEL, '(disabled)');
PRINT 'PARAMETER15 - @DEBUG: ' + CONVERT(NVARCHAR(1), @DEBUG);
PRINT '';
----------------------------------------------------------------------------------------------------------------------------
--=================================================-- Prepare the log table --===========================================--
IF (@LOGLEVEL IS NOT NULL) BEGIN
IF EXISTS (SELECT 1 FROM [INFORMATION_SCHEMA].[TABLES] WHERE [TABLE_NAME] = N'TBDD_MIGRATE_DATABASE_LOG') BEGIN
PRINT 'INFO: Log table [TBDD_MIGRATE_DATABASE_LOG] already exists.';
END; ELSE BEGIN
PRINT 'INFO: Log table does not exist, creating [TBDD_MIGRATE_DATABASE_LOG]...';
CREATE TABLE [dbo].[TBDD_MIGRATE_DATABASE_LOG] (
[LOG_ID] BIGINT IDENTITY(1,1) NOT NULL,
[RUN_ID] UNIQUEIDENTIFIER NOT NULL,
[LOG_LEVEL] NVARCHAR(25) NOT NULL,
[STEP] INT NULL,
[PHASE] NVARCHAR(50) NULL,
[SOURCE_DATABASE] NVARCHAR(128) NULL,
[TARGET_DATABASE] NVARCHAR(128) NULL,
[NEW_COLLATION] NVARCHAR(128) NULL,
[MESSAGE] NVARCHAR(MAX) NOT NULL,
[COMMAND] NVARCHAR(MAX) NULL,
[ROWS_AFFECTED] BIGINT NULL,
[DURATION_MS] BIGINT NULL,
[ERROR_MESSAGE] NVARCHAR(MAX) NULL,
[ADDED_WHO] NVARCHAR(128) NOT NULL,
[ADDED_WHEN] DATETIME NOT NULL,
CONSTRAINT [PK_TBDD_MIGRATE_DATABASE_LOG_ID] 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];
ALTER TABLE [dbo].[TBDD_MIGRATE_DATABASE_LOG] ADD CONSTRAINT [DF_TBDD_MIGRATE_DATABASE_LOG_ADDED_WHO] DEFAULT (SUSER_SNAME()) FOR [ADDED_WHO];
ALTER TABLE [dbo].[TBDD_MIGRATE_DATABASE_LOG] ADD CONSTRAINT [DF_TBDD_MIGRATE_DATABASE_LOG_ADDED_WHEN] DEFAULT (SYSDATETIME()) FOR [ADDED_WHEN];
--=================================================-- Create index for efficient queries by RUN_ID --============--
CREATE NONCLUSTERED INDEX [IX_TBDD_MIGRATE_DATABASE_LOG_RUN_ID] ON [dbo].[TBDD_MIGRATE_DATABASE_LOG] ([RUN_ID] ASC);
PRINT 'INFO: Log table created successfully.';
END;
END; ELSE BEGIN
PRINT 'WARN: Logging to table is disabled (@pLOGLEVEL = NULL).';
END;
----------------------------------------------------------------------------------------------------------------------------
--=================================================-- Check for log table --=============================================--
IF (@LOGLEVEL IS NOT NULL) AND NOT EXISTS (SELECT 1 FROM [INFORMATION_SCHEMA].[TABLES] WHERE [TABLE_NAME] = N'TBDD_MIGRATE_DATABASE_LOG') BEGIN
SET @LOGLEVEL = NULL;
PRINT 'ERROR: Log table [TBDD_MIGRATE_DATABASE_LOG] does not exist. Logging disabled for this run!';
END;
----------------------------------------------------------------------------------------------------------------------------
--=================================================-- Log procedure start --=============================================--
IF (@LOGLEVEL IN ('INFO')) BEGIN
INSERT INTO [dbo].[TBDD_MIGRATE_DATABASE_LOG] ([RUN_ID], [LOG_LEVEL], [SOURCE_DATABASE], [TARGET_DATABASE], [NEW_COLLATION], [MESSAGE], [ADDED_WHO], [ADDED_WHEN])
VALUES (@RUN_ID, 'INFO', @SOURCEDATABASE, @TARGETDATABASE, @NEWCOLLATION, @RETURN_STATUS_TEXT, @MY_PROCEDURE_NAME, GETDATE());
END;
----------------------------------------------------------------------------------------------------------------------------
--=================================================-- Validate parameters --=============================================--
IF (@SOURCEDATABASE IS NULL) BEGIN
IF (@LOGLEVEL IN ('INFO', 'WARN', 'ERROR')) BEGIN
INSERT INTO [dbo].[TBDD_MIGRATE_DATABASE_LOG] ([RUN_ID], [LOG_LEVEL], [MESSAGE], [ERROR_MESSAGE], [ADDED_WHO], [ADDED_WHEN])
VALUES (@RUN_ID, 'ERROR', 'Parameter validation failed', 'Parameter @pDATABASE (source) is required!', @MY_PROCEDURE_NAME, GETDATE());
END;
RAISERROR('ERROR: Parameter @pDATABASE (source) is required!',16,1);
RETURN 1;
END;
IF (@TARGETDATABASE IS NULL) BEGIN
IF (@LOGLEVEL IN ('INFO', 'WARN', 'ERROR')) BEGIN
INSERT INTO [dbo].[TBDD_MIGRATE_DATABASE_LOG] ([RUN_ID], [LOG_LEVEL], [SOURCE_DATABASE], [MESSAGE], [ERROR_MESSAGE], [ADDED_WHO], [ADDED_WHEN])
VALUES (@RUN_ID, 'ERROR', @SOURCEDATABASE, 'Parameter validation failed', 'Parameter @pTARGETDATABASE is required!', @MY_PROCEDURE_NAME, GETDATE());
END;
RAISERROR('ERROR: Parameter @pTARGETDATABASE is required!',16,1);
RETURN 1;
END;
IF (DB_ID(@SOURCEDATABASE) IS NULL) BEGIN
IF (@LOGLEVEL IN ('INFO', 'WARN', 'ERROR')) BEGIN
INSERT INTO [dbo].[TBDD_MIGRATE_DATABASE_LOG] ([RUN_ID], [LOG_LEVEL], [SOURCE_DATABASE], [TARGET_DATABASE], [NEW_COLLATION], [MESSAGE], [ERROR_MESSAGE], [ADDED_WHO], [ADDED_WHEN])
VALUES (@RUN_ID, 'ERROR', @SOURCEDATABASE, @TARGETDATABASE, @NEWCOLLATION, 'Parameter validation failed', 'Source database not found: ' + @SOURCEDATABASE, @MY_PROCEDURE_NAME, GETDATE());
END;
RAISERROR('ERROR: Source database not found: %s',16,1,@SOURCEDATABASE);
RETURN 1;
END;
IF (@NEWCOLLATION IS NOT NULL) AND NOT EXISTS (SELECT 1 FROM sys.fn_helpcollations() WHERE [name] = @NEWCOLLATION) BEGIN
IF (@LOGLEVEL IN ('INFO', 'WARN', 'ERROR')) BEGIN
INSERT INTO [dbo].[TBDD_MIGRATE_DATABASE_LOG] ([RUN_ID], [LOG_LEVEL], [SOURCE_DATABASE], [TARGET_DATABASE], [NEW_COLLATION], [MESSAGE], [ERROR_MESSAGE], [ADDED_WHO], [ADDED_WHEN])
VALUES (@RUN_ID, 'ERROR', @SOURCEDATABASE, @TARGETDATABASE, @NEWCOLLATION, 'Parameter validation failed', 'Unknown collation: ' + @NEWCOLLATION, @MY_PROCEDURE_NAME, GETDATE());
END;
RAISERROR('ERROR: Unknown collation: %s',16,1,@NEWCOLLATION);
RETURN 1;
END;
IF (@SOURCEDATABASE = @TARGETDATABASE) BEGIN
IF (@LOGLEVEL IN ('INFO', 'WARN', 'ERROR')) BEGIN
INSERT INTO [dbo].[TBDD_MIGRATE_DATABASE_LOG] ([RUN_ID], [LOG_LEVEL], [SOURCE_DATABASE], [TARGET_DATABASE], [NEW_COLLATION], [MESSAGE], [ERROR_MESSAGE], [ADDED_WHO], [ADDED_WHEN])
VALUES (@RUN_ID, 'ERROR', @SOURCEDATABASE, @TARGETDATABASE, @NEWCOLLATION, 'Parameter validation failed', 'Source and target database must differ.', @MY_PROCEDURE_NAME, GETDATE());
END;
RAISERROR('ERROR: Source and target database must differ.',16,1);
RETURN 1;
END;
IF (DB_ID(@TARGETDATABASE) IS NOT NULL AND @DROPTARGETIFEXISTS = 0) BEGIN
IF (@LOGLEVEL IN ('INFO', 'WARN', 'ERROR')) BEGIN
INSERT INTO [dbo].[TBDD_MIGRATE_DATABASE_LOG] ([RUN_ID], [LOG_LEVEL], [SOURCE_DATABASE], [TARGET_DATABASE], [NEW_COLLATION], [MESSAGE], [ERROR_MESSAGE], [ADDED_WHO], [ADDED_WHEN])
VALUES (@RUN_ID, 'ERROR', @SOURCEDATABASE, @TARGETDATABASE, @NEWCOLLATION, 'Parameter validation failed', 'Target database already exists. Set @pDROPTARGETIFEXISTS=1 to drop it.', @MY_PROCEDURE_NAME, GETDATE());
END;
RAISERROR('ERROR: Target database already exists. Set @pDROPTARGETIFEXISTS=1 to drop it.',16,1);
RETURN 1;
END;
IF (@MODE NOT IN ('FULL', 'SCHEMA', 'DATA')) BEGIN
IF (@LOGLEVEL IN ('INFO', 'WARN', 'ERROR')) BEGIN
INSERT INTO [dbo].[TBDD_MIGRATE_DATABASE_LOG] ([RUN_ID], [LOG_LEVEL], [SOURCE_DATABASE], [TARGET_DATABASE], [NEW_COLLATION], [MESSAGE], [ERROR_MESSAGE], [ADDED_WHO], [ADDED_WHEN])
VALUES (@RUN_ID, 'ERROR', @SOURCEDATABASE, @TARGETDATABASE, @NEWCOLLATION, 'Parameter validation failed', 'Invalid @pMODE. Use FULL, SCHEMA, or DATA.', @MY_PROCEDURE_NAME, GETDATE());
END;
RAISERROR('ERROR: Invalid @pMODE. Use FULL, SCHEMA, or DATA.',16,1);
RETURN 1;
END;
IF (@VALIDATION_MODE NOT IN ('ALL', 'SCHEMA', 'DATA', 'NONE')) BEGIN
IF (@LOGLEVEL IN ('INFO', 'WARN', 'ERROR')) BEGIN
INSERT INTO [dbo].[TBDD_MIGRATE_DATABASE_LOG] ([RUN_ID], [LOG_LEVEL], [SOURCE_DATABASE], [TARGET_DATABASE], [NEW_COLLATION], [MESSAGE], [ERROR_MESSAGE], [ADDED_WHO], [ADDED_WHEN])
VALUES (@RUN_ID, 'ERROR', @SOURCEDATABASE, @TARGETDATABASE, @NEWCOLLATION, 'Parameter validation failed', 'Invalid @pVALIDATE. Use ALL, SCHEMA, DATA, or NONE.', @MY_PROCEDURE_NAME, GETDATE());
END;
RAISERROR('ERROR: Invalid @pVALIDATE. Use ALL, SCHEMA, DATA, or NONE.',16,1);
RETURN 1;
END;
IF (@LOGLEVEL IS NOT NULL AND @LOGLEVEL NOT IN ('INFO', 'WARN', 'ERROR')) BEGIN
RAISERROR('ERROR: Invalid @pLOGLEVEL. Use INFO, WARN, ERROR, or NULL to disable.',16,1);
RETURN 1;
END;
-- DATA mode requires target database to exist
IF (@MODE = 'DATA' AND DB_ID(@TARGETDATABASE) IS NULL) BEGIN
IF (@LOGLEVEL IN ('INFO', 'WARN', 'ERROR')) BEGIN
INSERT INTO [dbo].[TBDD_MIGRATE_DATABASE_LOG] ([RUN_ID], [LOG_LEVEL], [SOURCE_DATABASE], [TARGET_DATABASE], [NEW_COLLATION], [MESSAGE], [ERROR_MESSAGE], [ADDED_WHO], [ADDED_WHEN])
VALUES (@RUN_ID, 'ERROR', @SOURCEDATABASE, @TARGETDATABASE, @NEWCOLLATION, 'Parameter validation failed', 'DATA mode requires target database to exist.', @MY_PROCEDURE_NAME, GETDATE());
END;
RAISERROR('ERROR: DATA mode requires target database to exist. Run with @pMODE=SCHEMA first.',16,1);
RETURN 1;
END;
SET @SOURCEDATABASE_QUOTED = QUOTENAME(@SOURCEDATABASE);
SET @TARGETDATABASE_QUOTED = QUOTENAME(@TARGETDATABASE);
----------------------------------------------------------------------------------------------------------------------------
--=================================================-- Check required permissions --======================================--
SET @MISSING_PERMISSIONS = N'';
-- Check CONTROL permission on source database (required to read all objects and lock DB)
SET @PERMISSION_SQL = N'USE {#SOURCEDB_Q#}; SELECT @result = ISNULL(HAS_PERMS_BY_NAME(DB_NAME(), ''DATABASE'', ''CONTROL''), 0);';
SET @PERMISSION_SQL = REPLACE(REPLACE(REPLACE(REPLACE(@PERMISSION_SQL, @PH_SOURCEDB_QUOTED, @SOURCEDATABASE_QUOTED), @PH_TARGETDB_QUOTED, @TARGETDATABASE_QUOTED), @PH_SOURCEDB, @SOURCEDATABASE), @PH_TARGETDB, @TARGETDATABASE);
EXEC sys.sp_executesql @PERMISSION_SQL, N'@result BIT OUTPUT', @result = @HAS_SOURCE_CONTROL OUTPUT;
-- Check CREATE DATABASE permission on server level
SET @HAS_CREATE_DATABASE = ISNULL(HAS_PERMS_BY_NAME(NULL, NULL, 'CREATE ANY DATABASE'), 0);
-- Check ALTER ANY DATABASE permission (required to set RESTRICTED_USER, RECOVERY model, etc.)
SET @HAS_ALTER_ANY_DATABASE = ISNULL(HAS_PERMS_BY_NAME(NULL, NULL, 'ALTER ANY DATABASE'), 0);
-- Check VIEW SERVER STATE permission (required for sys.dm_exec_sessions to kill connections)
SET @HAS_VIEW_SERVER_STATE = ISNULL(HAS_PERMS_BY_NAME(NULL, NULL, 'VIEW SERVER STATE'), 0);
-- Build list of missing permissions
IF @HAS_SOURCE_CONTROL = 0
SET @MISSING_PERMISSIONS = @MISSING_PERMISSIONS + N'CONTROL on [' + @SOURCEDATABASE + N'], ';
IF @HAS_CREATE_DATABASE = 0 AND @MODE IN ('FULL', 'SCHEMA')
SET @MISSING_PERMISSIONS = @MISSING_PERMISSIONS + N'CREATE ANY DATABASE, ';
IF @HAS_ALTER_ANY_DATABASE = 0
SET @MISSING_PERMISSIONS = @MISSING_PERMISSIONS + N'ALTER ANY DATABASE, ';
IF @HAS_VIEW_SERVER_STATE = 0
SET @MISSING_PERMISSIONS = @MISSING_PERMISSIONS + N'VIEW SERVER STATE, ';
-- Remove trailing comma and space
IF LEN(@MISSING_PERMISSIONS) > 2
SET @MISSING_PERMISSIONS = LEFT(@MISSING_PERMISSIONS, LEN(@MISSING_PERMISSIONS) - 2);
-- Report missing permissions
IF @MISSING_PERMISSIONS <> N'' BEGIN
IF (@LOGLEVEL IN ('INFO', 'WARN', 'ERROR')) BEGIN
INSERT INTO [dbo].[TBDD_MIGRATE_DATABASE_LOG] ([RUN_ID], [LOG_LEVEL], [SOURCE_DATABASE], [TARGET_DATABASE], [NEW_COLLATION], [MESSAGE], [ERROR_MESSAGE], [ADDED_WHO], [ADDED_WHEN])
VALUES (@RUN_ID, 'ERROR', @SOURCEDATABASE, @TARGETDATABASE, @NEWCOLLATION, 'Permission check failed', 'Missing permissions: ' + @MISSING_PERMISSIONS, @MY_PROCEDURE_NAME, GETDATE());
END;
RAISERROR('ERROR: Missing required permissions: %s', 16, 1, @MISSING_PERMISSIONS);
RETURN 1;
END;
PRINT 'INFO: Permission check passed.';
IF @DEBUG = 1 BEGIN
PRINT 'DEBUG: CONTROL on source DB: ' + CASE WHEN @HAS_SOURCE_CONTROL = 1 THEN 'YES' ELSE 'NO' END;
PRINT 'DEBUG: CREATE ANY DATABASE: ' + CASE WHEN @HAS_CREATE_DATABASE = 1 THEN 'YES' ELSE 'NO' END;
PRINT 'DEBUG: ALTER ANY DATABASE: ' + CASE WHEN @HAS_ALTER_ANY_DATABASE = 1 THEN 'YES' ELSE 'NO' END;
PRINT 'DEBUG: VIEW SERVER STATE: ' + CASE WHEN @HAS_VIEW_SERVER_STATE = 1 THEN 'YES' ELSE 'NO' END;
END;
PRINT '';
----------------------------------------------------------------------------------------------------------------------------
--=================================================-- Parse excluded objects into temp table --=========================--
CREATE TABLE #ExcludedObjects
(
Pattern NVARCHAR(256) COLLATE DATABASE_DEFAULT NOT NULL,
IsWildcard BIT NOT NULL DEFAULT 0
);
IF @EXCLUDEOBJECTS IS NOT NULL BEGIN
-- Parse comma-separated list and convert * to % for LIKE
INSERT INTO #ExcludedObjects (Pattern, IsWildcard)
SELECT
REPLACE(LTRIM(RTRIM(value)), N'*', N'%') AS Pattern,
CASE WHEN CHARINDEX(N'*', value) > 0 THEN 1 ELSE 0 END AS IsWildcard
FROM STRING_SPLIT(@EXCLUDEOBJECTS, N',')
WHERE LTRIM(RTRIM(value)) <> N'';
PRINT 'INFO: Excluded object patterns:';
DECLARE @ExclPattern NVARCHAR(256);
DECLARE excl_cursor CURSOR FAST_FORWARD FOR SELECT Pattern FROM #ExcludedObjects;
OPEN excl_cursor;
FETCH NEXT FROM excl_cursor INTO @ExclPattern;
WHILE @@FETCH_STATUS = 0 BEGIN
PRINT ' - ' + @ExclPattern;
FETCH NEXT FROM excl_cursor INTO @ExclPattern;
END;
CLOSE excl_cursor;
DEALLOCATE excl_cursor;
PRINT '';
IF (@LOGLEVEL IN ('INFO')) BEGIN
INSERT INTO [dbo].[TBDD_MIGRATE_DATABASE_LOG] ([RUN_ID], [LOG_LEVEL], [SOURCE_DATABASE], [TARGET_DATABASE], [NEW_COLLATION], [MESSAGE], [ADDED_WHO], [ADDED_WHEN])
VALUES (@RUN_ID, 'INFO', @SOURCEDATABASE, @TARGETDATABASE, @NEWCOLLATION, 'Excluded objects: ' + @EXCLUDEOBJECTS, @MY_PROCEDURE_NAME, GETDATE());
END;
END;
-- Create helper function to check if an object is excluded (schema.name format)
-- We'll use a subquery pattern instead of a function for compatibility
----------------------------------------------------------------------------------------------------------------------------
--=================================================-- Normalize paths --=================================================--
IF @DATAFILEPATH IS NOT NULL AND RIGHT(@DATAFILEPATH, 1) <> N'\' SET @DATAFILEPATH = @DATAFILEPATH + N'\';
IF @LOGFILEPATH IS NOT NULL AND RIGHT(@LOGFILEPATH, 1) <> N'\' SET @LOGFILEPATH = @LOGFILEPATH + N'\';
----------------------------------------------------------------------------------------------------------------------------
--=================================================-- Detect source collation --=========================================--
SET @DETECTSQL = N'USE {#SOURCEDB_Q#};
SELECT @c = CONVERT(sysname, DATABASEPROPERTYEX(DB_NAME(), N''Collation'')),
@cl = compatibility_level
FROM sys.databases WHERE [name] = DB_NAME();';
SET @DETECTSQL = REPLACE(REPLACE(REPLACE(REPLACE(@DETECTSQL, @PH_SOURCEDB_QUOTED, @SOURCEDATABASE_QUOTED), @PH_TARGETDB_QUOTED, @TARGETDATABASE_QUOTED), @PH_SOURCEDB, @SOURCEDATABASE), @PH_TARGETDB, @TARGETDATABASE);
EXEC sys.sp_executesql @DETECTSQL, N'@c sysname OUTPUT, @cl int OUTPUT', @c = @DETECTED_SOURCE_COLLATION OUTPUT, @cl = @COMPATIBILITY_LEVEL OUTPUT;
PRINT 'INFO: Source collation: ' + ISNULL(@DETECTED_SOURCE_COLLATION,'(unknown)');
PRINT 'INFO: Source compatibility level: ' + ISNULL(CONVERT(nvarchar(10),@COMPATIBILITY_LEVEL),'(unknown)');
-- If no new collation specified, use source collation (migration without collation change)
IF @NEWCOLLATION IS NULL BEGIN
SET @NEWCOLLATION = @DETECTED_SOURCE_COLLATION;
PRINT 'INFO: No target collation specified - using source collation: ' + @NEWCOLLATION;
IF (@LOGLEVEL IN ('INFO')) BEGIN
INSERT INTO [dbo].[TBDD_MIGRATE_DATABASE_LOG] ([RUN_ID], [LOG_LEVEL], [SOURCE_DATABASE], [TARGET_DATABASE], [NEW_COLLATION], [MESSAGE], [ADDED_WHO], [ADDED_WHEN])
VALUES (@RUN_ID, 'INFO', @SOURCEDATABASE, @TARGETDATABASE, @NEWCOLLATION, 'No target collation specified - using source collation', @MY_PROCEDURE_NAME, GETDATE());
END;
END;
PRINT '';
----------------------------------------------------------------------------------------------------------------------------
--=================================================-- Basic preflight for unsupported features --=======================--
-- Check for Memory-optimized tables
SET @DYNAMICSQL = N'
SELECT TOP (1) 1
FROM {#SOURCEDB_Q#}.sys.tables
WHERE is_memory_optimized = 1;';
-- Ersetze Platzhalter durch tatsächliche Werte
SET @DYNAMICSQL = REPLACE(REPLACE(REPLACE(REPLACE(@DYNAMICSQL,
@PH_SOURCEDB_QUOTED, @SOURCEDATABASE_QUOTED),
@PH_TARGETDB_QUOTED, @TARGETDATABASE_QUOTED),
@PH_SOURCEDB, @SOURCEDATABASE),
@PH_TARGETDB, @TARGETDATABASE);
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) <= 4000 PRINT @DYNAMICSQL;
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) > 4000 PRINT LEFT(@DYNAMICSQL, 4000) + N'...(truncated)';
DELETE FROM @tmp;
BEGIN TRY
INSERT INTO @tmp(x) EXEC sys.sp_executesql @DYNAMICSQL;
END TRY BEGIN CATCH
PRINT N'ERROR in dynamic SQL:';
PRINT @DYNAMICSQL;
THROW;
END CATCH;
IF EXISTS (SELECT 1 FROM @tmp) BEGIN
IF (@LOGLEVEL IN ('INFO', 'WARN', 'ERROR')) BEGIN
INSERT INTO [dbo].[TBDD_MIGRATE_DATABASE_LOG] ([RUN_ID], [LOG_LEVEL], [SOURCE_DATABASE], [TARGET_DATABASE], [NEW_COLLATION], [MESSAGE], [ERROR_MESSAGE], [ADDED_WHO], [ADDED_WHEN])
VALUES (@RUN_ID, 'ERROR', @SOURCEDATABASE, @TARGETDATABASE, @NEWCOLLATION, 'Preflight check failed', 'Memory-optimized tables detected. Handle manually.', @MY_PROCEDURE_NAME, GETDATE());
END;
RAISERROR(N'Unsupported: memory-optimized tables detected. Handle manually.', 16, 1);
RETURN 1;
END;
-- Check for Filestream columns
SET @DYNAMICSQL = N'
SELECT TOP (1) 1
FROM {#SOURCEDB_Q#}.sys.columns AS c
JOIN {#SOURCEDB_Q#}.sys.tables AS t ON t.object_id = c.object_id
WHERE c.is_filestream = 1;';
-- Ersetze Platzhalter durch tatsächliche Werte
SET @DYNAMICSQL = REPLACE(REPLACE(REPLACE(REPLACE(@DYNAMICSQL,
@PH_SOURCEDB_QUOTED, @SOURCEDATABASE_QUOTED),
@PH_TARGETDB_QUOTED, @TARGETDATABASE_QUOTED),
@PH_SOURCEDB, @SOURCEDATABASE),
@PH_TARGETDB, @TARGETDATABASE);
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) <= 4000 PRINT @DYNAMICSQL;
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) > 4000 PRINT LEFT(@DYNAMICSQL, 4000) + N'...(truncated)';
DELETE FROM @tmp;
BEGIN TRY
INSERT INTO @tmp(x) EXEC sys.sp_executesql @DYNAMICSQL;
END TRY BEGIN CATCH
PRINT N'ERROR in dynamic SQL:';
PRINT @DYNAMICSQL;
THROW;
END CATCH;
IF EXISTS (SELECT 1 FROM @tmp) BEGIN
IF (@LOGLEVEL IN ('INFO', 'WARN', 'ERROR')) BEGIN
INSERT INTO [dbo].[TBDD_MIGRATE_DATABASE_LOG] ([RUN_ID], [LOG_LEVEL], [SOURCE_DATABASE], [TARGET_DATABASE], [NEW_COLLATION], [MESSAGE], [ERROR_MESSAGE], [ADDED_WHO], [ADDED_WHEN])
VALUES (@RUN_ID, 'ERROR', @SOURCEDATABASE, @TARGETDATABASE, @NEWCOLLATION, 'Preflight check failed', 'Filestream columns detected. Handle manually.', @MY_PROCEDURE_NAME, GETDATE());
END;
RAISERROR(N'Unsupported: Filestream columns detected. Handle manually.', 16, 1);
RETURN 1;
END;
-- Check for Filetables
SET @DYNAMICSQL = N'
SELECT TOP (1) 1
FROM {#SOURCEDB_Q#}.sys.tables
WHERE is_filetable = 1;';
-- Ersetze Platzhalter durch tatsächliche Werte
SET @DYNAMICSQL = REPLACE(REPLACE(REPLACE(REPLACE(@DYNAMICSQL,
@PH_SOURCEDB_QUOTED, @SOURCEDATABASE_QUOTED),
@PH_TARGETDB_QUOTED, @TARGETDATABASE_QUOTED),
@PH_SOURCEDB, @SOURCEDATABASE),
@PH_TARGETDB, @TARGETDATABASE);
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) <= 4000 PRINT @DYNAMICSQL;
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) > 4000 PRINT LEFT(@DYNAMICSQL, 4000) + N'...(truncated)';
DELETE FROM @tmp;
BEGIN TRY
INSERT INTO @tmp(x) EXEC sys.sp_executesql @DYNAMICSQL;
END TRY BEGIN CATCH
PRINT N'ERROR in dynamic SQL:';
PRINT @DYNAMICSQL;
THROW;
END CATCH;
IF EXISTS (SELECT 1 FROM @tmp) BEGIN
IF (@LOGLEVEL IN ('INFO', 'WARN', 'ERROR')) BEGIN
INSERT INTO [dbo].[TBDD_MIGRATE_DATABASE_LOG] ([RUN_ID], [LOG_LEVEL], [SOURCE_DATABASE], [TARGET_DATABASE], [NEW_COLLATION], [MESSAGE], [ERROR_MESSAGE], [ADDED_WHO], [ADDED_WHEN])
VALUES (@RUN_ID, 'ERROR', @SOURCEDATABASE, @TARGETDATABASE, @NEWCOLLATION, 'Preflight check failed', 'Filetables detected. Handle manually.', @MY_PROCEDURE_NAME, GETDATE());
END;
RAISERROR(N'Unsupported: Filetables detected. Handle manually.', 16, 1);
RETURN 1;
END;
-- Check for Temporal Tables (system-versioned)
SET @DYNAMICSQL = N'
SELECT TOP (1) 1
FROM {#SOURCEDB_Q#}.sys.tables
WHERE temporal_type IN (1, 2);'; -- 1 = History table, 2 = System-versioned table
-- Ersetze Platzhalter durch tatsächliche Werte
SET @DYNAMICSQL = REPLACE(REPLACE(REPLACE(REPLACE(@DYNAMICSQL,
@PH_SOURCEDB_QUOTED, @SOURCEDATABASE_QUOTED),
@PH_TARGETDB_QUOTED, @TARGETDATABASE_QUOTED),
@PH_SOURCEDB, @SOURCEDATABASE),
@PH_TARGETDB, @TARGETDATABASE);
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) <= 4000 PRINT @DYNAMICSQL;
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) > 4000 PRINT LEFT(@DYNAMICSQL, 4000) + N'...(truncated)';
DELETE FROM @tmp;
BEGIN TRY
INSERT INTO @tmp(x) EXEC sys.sp_executesql @DYNAMICSQL;
END TRY BEGIN CATCH
PRINT N'ERROR in dynamic SQL:';
PRINT @DYNAMICSQL;
THROW;
END CATCH;
IF EXISTS (SELECT 1 FROM @tmp) BEGIN
PRINT N'WARN: Temporal (system-versioned) tables detected. These will be migrated as regular tables without versioning.';
IF (@LOGLEVEL IN ('INFO', 'WARN')) BEGIN
INSERT INTO [dbo].[TBDD_MIGRATE_DATABASE_LOG] ([RUN_ID], [LOG_LEVEL], [SOURCE_DATABASE], [TARGET_DATABASE], [NEW_COLLATION], [MESSAGE], [ADDED_WHO], [ADDED_WHEN])
VALUES (@RUN_ID, 'WARN', @SOURCEDATABASE, @TARGETDATABASE, @NEWCOLLATION, 'Temporal tables detected - will be migrated as regular tables without system versioning', @MY_PROCEDURE_NAME, GETDATE());
END;
END;
-- Check for Columnstore Indexes
SET @DYNAMICSQL = N'
SELECT TOP (1) 1
FROM {#SOURCEDB_Q#}.sys.indexes
WHERE type IN (5, 6);'; -- 5 = Clustered columnstore, 6 = Nonclustered columnstore
-- Ersetze Platzhalter durch tatsächliche Werte
SET @DYNAMICSQL = REPLACE(REPLACE(REPLACE(REPLACE(@DYNAMICSQL,
@PH_SOURCEDB_QUOTED, @SOURCEDATABASE_QUOTED),
@PH_TARGETDB_QUOTED, @TARGETDATABASE_QUOTED),
@PH_SOURCEDB, @SOURCEDATABASE),
@PH_TARGETDB, @TARGETDATABASE);
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) <= 4000 PRINT @DYNAMICSQL;
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) > 4000 PRINT LEFT(@DYNAMICSQL, 4000) + N'...(truncated)';
DELETE FROM @tmp;
BEGIN TRY
INSERT INTO @tmp(x) EXEC sys.sp_executesql @DYNAMICSQL;
END TRY BEGIN CATCH
PRINT N'ERROR in dynamic SQL:';
PRINT @DYNAMICSQL;
THROW;
END CATCH;
IF EXISTS (SELECT 1 FROM @tmp) BEGIN
PRINT N'WARN: Columnstore indexes detected. These will NOT be migrated - recreate manually after migration.';
IF (@LOGLEVEL IN ('INFO', 'WARN')) BEGIN
INSERT INTO [dbo].[TBDD_MIGRATE_DATABASE_LOG] ([RUN_ID], [LOG_LEVEL], [SOURCE_DATABASE], [TARGET_DATABASE], [NEW_COLLATION], [MESSAGE], [ADDED_WHO], [ADDED_WHEN])
VALUES (@RUN_ID, 'WARN', @SOURCEDATABASE, @TARGETDATABASE, @NEWCOLLATION, 'Columnstore indexes detected - NOT migrated, recreate manually', @MY_PROCEDURE_NAME, GETDATE());
END;
END;
----------------------------------------------------------------------------------------------------------------------------
--=================================================-- Lock source database (RESTRICTED_USER) --=========================--
-- Save original user access mode
SELECT @SOURCE_USER_ACCESS_ORIGINAL = user_access_desc
FROM sys.databases
WHERE name = @SOURCEDATABASE;
PRINT 'INFO: Source database original user access mode: ' + ISNULL(@SOURCE_USER_ACCESS_ORIGINAL, '(unknown)');
-- Kill all active connections to source database (except own session)
PRINT 'INFO: Killing active connections to source database...';
BEGIN TRY
DECLARE kill_cursor CURSOR FAST_FORWARD FOR
SELECT session_id
FROM sys.dm_exec_sessions
WHERE database_id = DB_ID(@SOURCEDATABASE)
AND session_id <> @@SPID;
OPEN kill_cursor;
FETCH NEXT FROM kill_cursor INTO @KILLSESSIONID;
WHILE @@FETCH_STATUS = 0 BEGIN
BEGIN TRY
SET @DYNAMICSQL = N'KILL ' + CONVERT(NVARCHAR(10), @KILLSESSIONID) + N';';
PRINT 'INFO: Killing session ' + CONVERT(NVARCHAR(10), @KILLSESSIONID);
IF @DEBUG = 1 PRINT @DYNAMICSQL;
EXEC sys.sp_executesql @DYNAMICSQL;
END TRY BEGIN CATCH
PRINT 'WARN: Could not kill session ' + CONVERT(NVARCHAR(10), @KILLSESSIONID) + ': ' + ERROR_MESSAGE();
END CATCH;
FETCH NEXT FROM kill_cursor INTO @KILLSESSIONID;
END;
CLOSE kill_cursor;
DEALLOCATE kill_cursor;
END TRY BEGIN CATCH
-- Ensure cursor is cleaned up even on error
IF CURSOR_STATUS('local', 'kill_cursor') >= 0 BEGIN
CLOSE kill_cursor;
DEALLOCATE kill_cursor;
END;
PRINT 'WARN: Error during connection cleanup: ' + ERROR_MESSAGE();
END CATCH;
-- Set source database to RESTRICTED_USER mode
PRINT 'INFO: Setting source database to RESTRICTED_USER mode...';
BEGIN TRY
SET @DYNAMICSQL = N'ALTER DATABASE {#SOURCEDB_Q#} SET RESTRICTED_USER WITH ROLLBACK IMMEDIATE;';
-- Ersetze Platzhalter durch tatsächliche Werte
SET @DYNAMICSQL = REPLACE(REPLACE(REPLACE(REPLACE(@DYNAMICSQL,
@PH_SOURCEDB_QUOTED, @SOURCEDATABASE_QUOTED),
@PH_TARGETDB_QUOTED, @TARGETDATABASE_QUOTED),
@PH_SOURCEDB, @SOURCEDATABASE),
@PH_TARGETDB, @TARGETDATABASE);
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) <= 4000 PRINT @DYNAMICSQL;
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) > 4000 PRINT LEFT(@DYNAMICSQL, 4000) + N'...(truncated)';
BEGIN TRY
EXEC sys.sp_executesql @DYNAMICSQL;
END TRY BEGIN CATCH
PRINT N'ERROR in dynamic SQL:';
PRINT @DYNAMICSQL;
THROW;
END CATCH;
PRINT 'INFO: Source database is now in RESTRICTED_USER mode.';
SET @SOURCE_LOCKED = 1;
END TRY BEGIN CATCH
SET @ERRORMESSAGE = ERROR_MESSAGE();
PRINT 'ERROR: Could not set source database to RESTRICTED_USER: ' + @ERRORMESSAGE;
IF (@LOGLEVEL IN ('INFO', 'WARN', 'ERROR')) BEGIN
INSERT INTO [dbo].[TBDD_MIGRATE_DATABASE_LOG] ([RUN_ID], [LOG_LEVEL], [SOURCE_DATABASE], [TARGET_DATABASE], [NEW_COLLATION], [MESSAGE], [ERROR_MESSAGE], [ADDED_WHO], [ADDED_WHEN])
VALUES (@RUN_ID, 'ERROR', @SOURCEDATABASE, @TARGETDATABASE, @NEWCOLLATION, 'Failed to lock source database', @ERRORMESSAGE, @MY_PROCEDURE_NAME, GETDATE());
END;
RAISERROR(N'Failed to set source database to RESTRICTED_USER mode.', 16, 1);
RETURN 1;
END CATCH;
PRINT '';
----------------------------------------------------------------------------------------------------------------------------
--=================================================-- Prepare command list --============================================--
IF @DEBUG = 1 PRINT 'DEBUG: Creating #Commands table...';
CREATE TABLE #Commands
(
Step int IDENTITY(1,1) NOT NULL PRIMARY KEY,
Phase nvarchar(50) NOT NULL,
Command nvarchar(max) NOT NULL
);
----------------------------------------------------------------------------------------------------------------------------
--=================================================-- Collect objects to skip (external DB refs + dependents) --========--
-- This temp table collects all objects that must be skipped:
-- 1. Objects with external database references (other than source DB)
-- 2. Objects that depend on skipped objects (cascade)
CREATE TABLE #SkippedObjects
(
ObjectId INT NOT NULL,
SchemaName NVARCHAR(128) NOT NULL,
ObjectName NVARCHAR(128) NOT NULL,
ObjectType NVARCHAR(10) NOT NULL, -- 'VIEW', 'FUNCTION', 'PROCEDURE', 'TRIGGER'
SkipReason NVARCHAR(500) NOT NULL,
CONSTRAINT PK_SkippedObjects PRIMARY KEY CLUSTERED (ObjectId) WITH (IGNORE_DUP_KEY = ON)
);
-- Step 1: Insert objects with DIRECT external database references
SET @DYNAMICSQL = N'
-- Views with external DB references
INSERT INTO #SkippedObjects (ObjectId, SchemaName, ObjectName, ObjectType, SkipReason)
SELECT v.object_id, s.name, v.name, N''VIEW'', N''References external database(s)''
FROM {#SOURCEDB_Q#}.sys.views AS v
JOIN {#SOURCEDB_Q#}.sys.schemas AS s ON s.schema_id = v.schema_id
WHERE EXISTS (
SELECT 1 FROM {#SOURCEDB_Q#}.sys.sql_expression_dependencies AS d
WHERE d.referencing_id = v.object_id
AND d.referenced_database_name IS NOT NULL
AND d.referenced_database_name <> N''{#SOURCEDB#}''
)
AND NOT EXISTS (SELECT 1 FROM #SkippedObjects WHERE ObjectId = v.object_id);
-- Functions with external DB references
INSERT INTO #SkippedObjects (ObjectId, SchemaName, ObjectName, ObjectType, SkipReason)
SELECT o.object_id, s.name, o.name, N''FUNCTION'', N''References external database(s)''
FROM {#SOURCEDB_Q#}.sys.objects AS o
JOIN {#SOURCEDB_Q#}.sys.schemas AS s ON s.schema_id = o.schema_id
WHERE o.[type] IN (N''FN'',N''TF'',N''IF'',N''FS'',N''FT'')
AND EXISTS (
SELECT 1 FROM {#SOURCEDB_Q#}.sys.sql_expression_dependencies AS d
WHERE d.referencing_id = o.object_id
AND d.referenced_database_name IS NOT NULL
AND d.referenced_database_name <> N''{#SOURCEDB#}''
)
AND NOT EXISTS (SELECT 1 FROM #SkippedObjects WHERE ObjectId = o.object_id);
-- Procedures with external DB references
INSERT INTO #SkippedObjects (ObjectId, SchemaName, ObjectName, ObjectType, SkipReason)
SELECT p.object_id, s.name, p.name, N''PROCEDURE'', N''References external database(s)''
FROM {#SOURCEDB_Q#}.sys.procedures AS p
JOIN {#SOURCEDB_Q#}.sys.schemas AS s ON s.schema_id = p.schema_id
WHERE EXISTS (
SELECT 1 FROM {#SOURCEDB_Q#}.sys.sql_expression_dependencies AS d
WHERE d.referencing_id = p.object_id
AND d.referenced_database_name IS NOT NULL
AND d.referenced_database_name <> N''{#SOURCEDB#}''
)
AND NOT EXISTS (SELECT 1 FROM #SkippedObjects WHERE ObjectId = p.object_id);
-- Triggers with external DB references (using sys.sql_expression_dependencies)
INSERT INTO #SkippedObjects (ObjectId, SchemaName, ObjectName, ObjectType, SkipReason)
SELECT tr.object_id, s.name, tr.name, N''TRIGGER'', N''References external database(s)''
FROM {#SOURCEDB_Q#}.sys.triggers AS tr
JOIN {#SOURCEDB_Q#}.sys.objects AS o ON o.object_id = tr.object_id
JOIN {#SOURCEDB_Q#}.sys.schemas AS s ON s.schema_id = o.schema_id
WHERE tr.parent_id IS NOT NULL
AND EXISTS (
SELECT 1 FROM {#SOURCEDB_Q#}.sys.sql_expression_dependencies AS d
WHERE d.referencing_id = tr.object_id
AND d.referenced_database_name IS NOT NULL
AND d.referenced_database_name <> N''{#SOURCEDB#}''
)
AND NOT EXISTS (SELECT 1 FROM #SkippedObjects WHERE ObjectId = tr.object_id);';
IF @DEBUG = 1 PRINT 'DEBUG: Collecting objects with external DB references...';
-- Ersetze Platzhalter durch tatsächliche Werte
SET @DYNAMICSQL = REPLACE(REPLACE(REPLACE(REPLACE(@DYNAMICSQL,
@PH_SOURCEDB_QUOTED, @SOURCEDATABASE_QUOTED),
@PH_TARGETDB_QUOTED, @TARGETDATABASE_QUOTED),
@PH_SOURCEDB, @SOURCEDATABASE),
@PH_TARGETDB, @TARGETDATABASE);
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) <= 4000 PRINT @DYNAMICSQL;
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) > 4000 PRINT LEFT(@DYNAMICSQL, 4000) + N'...(truncated)';
BEGIN TRY
EXEC sys.sp_executesql @DYNAMICSQL;
END TRY BEGIN CATCH
PRINT N'ERROR in dynamic SQL:';
PRINT @DYNAMICSQL;
THROW;
END CATCH;
-- Step 2: Recursively add dependent objects (cascade)
-- Loop until no more dependents are found
DECLARE @ROWCOUNT_ADDED INT = 1;
WHILE @ROWCOUNT_ADDED > 0 BEGIN
SET @DYNAMICSQL = N'
INSERT INTO #SkippedObjects (ObjectId, SchemaName, ObjectName, ObjectType, SkipReason)
SELECT DISTINCT o.object_id, s.name, o.name,
CASE
WHEN o.[type] = N''V'' THEN N''VIEW''
WHEN o.[type] IN (N''FN'',N''TF'',N''IF'',N''FS'',N''FT'') THEN N''FUNCTION''
WHEN o.[type] = N''P'' THEN N''PROCEDURE''
ELSE N''OTHER''
END,
N''Depends on skipped object: '' + sk.SchemaName + N''.'' + sk.ObjectName
FROM {#SOURCEDB_Q#}.sys.sql_expression_dependencies AS d
JOIN {#SOURCEDB_Q#}.sys.objects AS o ON o.object_id = d.referencing_id
JOIN {#SOURCEDB_Q#}.sys.schemas AS s ON s.schema_id = o.schema_id
JOIN #SkippedObjects AS sk ON sk.ObjectId = d.referenced_id
WHERE o.[type] IN (N''V'', N''FN'', N''TF'', N''IF'', N''FS'', N''FT'', N''P'')
AND NOT EXISTS (SELECT 1 FROM #SkippedObjects WHERE ObjectId = o.object_id);';
-- Ersetze Platzhalter durch tatsächliche Werte
SET @DYNAMICSQL = REPLACE(REPLACE(REPLACE(REPLACE(@DYNAMICSQL,
@PH_SOURCEDB_QUOTED, @SOURCEDATABASE_QUOTED),
@PH_TARGETDB_QUOTED, @TARGETDATABASE_QUOTED),
@PH_SOURCEDB, @SOURCEDATABASE),
@PH_TARGETDB, @TARGETDATABASE);
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) <= 4000 PRINT @DYNAMICSQL;
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) > 4000 PRINT LEFT(@DYNAMICSQL, 4000) + N'...(truncated)';
BEGIN TRY
EXEC sys.sp_executesql @DYNAMICSQL;
SET @ROWCOUNT_ADDED = @@ROWCOUNT; -- Muss sofort nach EXEC gelesen werden
END TRY BEGIN CATCH
PRINT N'ERROR in dynamic SQL:';
PRINT @DYNAMICSQL;
THROW;
END CATCH;
IF @DEBUG = 1 PRINT 'DEBUG: Cascade dependency iteration added ' + CONVERT(NVARCHAR(10), @ROWCOUNT_ADDED) + ' objects.';
END;
-- Log count of skipped objects
DECLARE @SKIP_COUNT INT = (SELECT COUNT(*) FROM #SkippedObjects);
IF @SKIP_COUNT > 0 BEGIN
PRINT N'INFO: ' + CONVERT(NVARCHAR(10), @SKIP_COUNT) + N' objects will be SKIPPED due to external database references or dependencies.';
-- Log each skipped object
IF (@LOGLEVEL IN ('INFO', 'WARN')) BEGIN
INSERT INTO [dbo].[TBDD_MIGRATE_DATABASE_LOG]
([RUN_ID], [LOG_LEVEL], [SOURCE_DATABASE], [TARGET_DATABASE], [NEW_COLLATION], [MESSAGE], [ADDED_WHO], [ADDED_WHEN])
SELECT @RUN_ID, 'WARN', @SOURCEDATABASE, @TARGETDATABASE, @NEWCOLLATION,
N'SKIP ' + ObjectType + N': ' + SchemaName + N'.' + ObjectName + N' - ' + SkipReason,
@MY_PROCEDURE_NAME, GETDATE()
FROM #SkippedObjects
ORDER BY ObjectType, SchemaName, ObjectName;
END;
END;
----------------------------------------------------------------------------------------------------------------------------
--=================================================-- 00: Drop target if requested --===================================--
IF (DB_ID(@TARGETDATABASE) IS NOT NULL AND @DROPTARGETIFEXISTS = 1) BEGIN
INSERT INTO #Commands(Phase, Command)
VALUES
(N'00-DropTarget', N'USE [master]; ALTER DATABASE {#TARGETDB_Q#} SET SINGLE_USER WITH ROLLBACK IMMEDIATE; DROP DATABASE {#TARGETDB_Q#};');
END;
----------------------------------------------------------------------------------------------------------------------------
--=================================================-- 01: Create target database --=====================================--
IF @DATAFILEPATH IS NULL AND @LOGFILEPATH IS NULL BEGIN
-- Default paths (SQL Server decides)
INSERT INTO #Commands(Phase, Command)
VALUES
(N'01-CreateDb', N'USE [master]; CREATE DATABASE {#TARGETDB_Q#} COLLATE ' + @NEWCOLLATION + N';');
END; ELSE BEGIN
-- Custom paths specified
DECLARE @MDFFILEPATH NVARCHAR(520) = ISNULL(@DATAFILEPATH, N'') + @TARGETDATABASE + N'.mdf';
DECLARE @LDFFILEPATH NVARCHAR(520) = ISNULL(@LOGFILEPATH, @DATAFILEPATH) + @TARGETDATABASE + N'_log.ldf';
INSERT INTO #Commands(Phase, Command)
VALUES
(N'01-CreateDb',
N'USE [master]; CREATE DATABASE {#TARGETDB_Q#}
ON PRIMARY (NAME = N''' + @TARGETDATABASE + N''', FILENAME = N''' + @MDFFILEPATH + N''', SIZE = 64MB, FILEGROWTH = 64MB)
LOG ON (NAME = N''' + @TARGETDATABASE + N'_log'', FILENAME = N''' + @LDFFILEPATH + N''', SIZE = 64MB, FILEGROWTH = 64MB)
COLLATE ' + @NEWCOLLATION + N';');
END;
-- Set SIMPLE recovery model during migration to avoid transaction log issues
INSERT INTO #Commands(Phase, Command)
VALUES
(N'01-CreateDb', N'USE [master]; ALTER DATABASE {#TARGETDB_Q#} SET RECOVERY SIMPLE;');
-- Set Restricted Access (RESTRICTED_USER) to avoid external Session on target database
INSERT INTO #Commands(Phase, Command)
VALUES
(N'01-CreateDb', N'USE [master]; ALTER DATABASE {#TARGETDB_Q#} SET RESTRICTED_USER WITH ROLLBACK IMMEDIATE;');
IF (@COMPATIBILITY_LEVEL IS NOT NULL) BEGIN
INSERT INTO #Commands(Phase, Command)
VALUES
(N'01-CreateDb', N'USE [master]; ALTER DATABASE {#TARGETDB_Q#} SET COMPATIBILITY_LEVEL = ' + CONVERT(nvarchar(10), @COMPATIBILITY_LEVEL) + N';');
END;
----------------------------------------------------------------------------------------------------------------------------
IF @DEBUG = 1 PRINT 'DEBUG: Generating 02-Schemas commands...';
--=================================================-- 02: Schemas --=====================================================--
SET @DYNAMICSQL = N'
INSERT INTO #Commands(Phase, Command)
SELECT
N''02-Schemas'',
''USE {#TARGETDB_Q#}; IF NOT EXISTS (SELECT 1 FROM sys.schemas WHERE name = N'''''' + REPLACE(s.name, '''''''', '''''''''''') + N'''''') EXEC(''''CREATE SCHEMA '' + QUOTENAME(s.name) + N'''''');''
FROM {#SOURCEDB_Q#}.sys.schemas AS s
WHERE s.name NOT IN (N''sys'', N''INFORMATION_SCHEMA'')
-- Exclude schemas matching patterns in #ExcludedObjects
AND NOT EXISTS (
SELECT 1 FROM #ExcludedObjects AS ex
WHERE (ex.IsWildcard = 1 AND s.name COLLATE DATABASE_DEFAULT LIKE ex.Pattern)
OR (ex.IsWildcard = 0 AND s.name COLLATE DATABASE_DEFAULT = ex.Pattern)
);';
-- Ersetze Platzhalter durch tatsächliche Werte
SET @DYNAMICSQL = REPLACE(REPLACE(REPLACE(REPLACE(@DYNAMICSQL,
@PH_SOURCEDB_QUOTED, @SOURCEDATABASE_QUOTED),
@PH_TARGETDB_QUOTED, @TARGETDATABASE_QUOTED),
@PH_SOURCEDB, @SOURCEDATABASE),
@PH_TARGETDB, @TARGETDATABASE);
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) <= 4000 PRINT @DYNAMICSQL;
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) > 4000 PRINT LEFT(@DYNAMICSQL, 4000) + N'...(truncated)';
BEGIN TRY
EXEC sys.sp_executesql @DYNAMICSQL;
END TRY BEGIN CATCH
PRINT N'ERROR in dynamic SQL:';
PRINT @DYNAMICSQL;
THROW;
END CATCH;
----------------------------------------------------------------------------------------------------------------------------
IF @DEBUG = 1 PRINT 'DEBUG: Generating 02a-PartitionFunctions commands...';
--=================================================-- 02a: Partition Functions --=======================================--
SET @DYNAMICSQL = N'
INSERT INTO #Commands(Phase, Command)
SELECT
N''02a-PartitionFunctions'',
N''USE {#TARGETDB_Q#}; CREATE PARTITION FUNCTION '' + QUOTENAME(pf.name) + N''('' +
ty.name +
CASE
WHEN ty.name IN (N''varchar'',N''char'',N''varbinary'',N''binary'') THEN N''('' + CASE WHEN prm.max_length = -1 THEN N''max'' ELSE CONVERT(nvarchar(10), prm.max_length) END + N'')''
WHEN ty.name IN (N''nvarchar'',N''nchar'') THEN N''('' + CASE WHEN prm.max_length = -1 THEN N''max'' ELSE CONVERT(nvarchar(10), prm.max_length/2) END + N'')''
WHEN ty.name IN (N''decimal'',N''numeric'') THEN N''('' + CONVERT(nvarchar(10), prm.precision) + N'','' + CONVERT(nvarchar(10), prm.scale) + N'')''
WHEN ty.name IN (N''datetime2'',N''datetimeoffset'',N''time'') THEN N''('' + CONVERT(nvarchar(10), prm.scale) + N'')''
ELSE N''''
END +
N'') AS RANGE '' + CASE WHEN pf.boundary_value_on_right = 1 THEN N''RIGHT'' ELSE N''LEFT'' END +
N'' FOR VALUES ('' +
ISNULL(STUFF((
SELECT N'', '' +
CASE
WHEN SQL_VARIANT_PROPERTY(prv.value, ''BaseType'') IN (''char'',''varchar'',''nchar'',''nvarchar'') THEN N'''''''' + REPLACE(CONVERT(nvarchar(max), prv.value), '''''''', '''''''''''') + N''''''''
WHEN SQL_VARIANT_PROPERTY(prv.value, ''BaseType'') IN (''datetime'',''datetime2'',''date'',''smalldatetime'') THEN N'''''''' + CONVERT(nvarchar(50), prv.value, 121) + N''''''''
WHEN SQL_VARIANT_PROPERTY(prv.value, ''BaseType'') IN (''binary'',''varbinary'') THEN N''0x'' + CONVERT(nvarchar(max), CONVERT(varbinary(max), prv.value), 2)
ELSE CONVERT(nvarchar(max), prv.value)
END
FROM {#SOURCEDB_Q#}.sys.partition_range_values AS prv
WHERE prv.function_id = pf.function_id
ORDER BY prv.boundary_id
FOR XML PATH(''''), TYPE
).value(''.'', ''nvarchar(max)''), 1, 2, N''''), N'''') +
N'');''
FROM {#SOURCEDB_Q#}.sys.partition_functions AS pf
CROSS APPLY (
SELECT TOP 1 pp.parameter_id, pp.system_type_id, pp.max_length, pp.precision, pp.scale
FROM {#SOURCEDB_Q#}.sys.partition_parameters AS pp
WHERE pp.function_id = pf.function_id
) AS prm
JOIN {#SOURCEDB_Q#}.sys.types AS ty ON ty.system_type_id = prm.system_type_id AND ty.user_type_id = prm.system_type_id
-- Exclude partition functions matching patterns in #ExcludedObjects
WHERE NOT EXISTS (
SELECT 1 FROM #ExcludedObjects AS ex
WHERE (ex.IsWildcard = 1 AND pf.name COLLATE DATABASE_DEFAULT LIKE ex.Pattern)
OR (ex.IsWildcard = 0 AND pf.name COLLATE DATABASE_DEFAULT = ex.Pattern)
);';
-- Ersetze Platzhalter durch tatsächliche Werte
SET @DYNAMICSQL = REPLACE(REPLACE(REPLACE(REPLACE(@DYNAMICSQL,
@PH_SOURCEDB_QUOTED, @SOURCEDATABASE_QUOTED),
@PH_TARGETDB_QUOTED, @TARGETDATABASE_QUOTED),
@PH_SOURCEDB, @SOURCEDATABASE),
@PH_TARGETDB, @TARGETDATABASE);
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) <= 4000 PRINT @DYNAMICSQL;
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) > 4000 PRINT LEFT(@DYNAMICSQL, 4000) + N'...(truncated)';
BEGIN TRY
EXEC sys.sp_executesql @DYNAMICSQL;
END TRY BEGIN CATCH
PRINT N'ERROR in dynamic SQL:';
PRINT @DYNAMICSQL;
THROW;
END CATCH;
----------------------------------------------------------------------------------------------------------------------------
IF @DEBUG = 1 PRINT 'DEBUG: Generating 02b-PartitionSchemes commands...';
--=================================================-- 02b: Partition Schemes --=========================================--
SET @DYNAMICSQL = N'
INSERT INTO #Commands(Phase, Command)
SELECT
N''02b-PartitionSchemes'',
N''USE {#TARGETDB_Q#}; CREATE PARTITION SCHEME '' + QUOTENAME(ps.name) +
N'' AS PARTITION '' + QUOTENAME(pf.name) +
N'' TO ('' +
STUFF((
SELECT N'', '' + QUOTENAME(ds.name)
FROM {#SOURCEDB_Q#}.sys.destination_data_spaces AS dds
JOIN {#SOURCEDB_Q#}.sys.data_spaces AS ds ON ds.data_space_id = dds.data_space_id
WHERE dds.partition_scheme_id = ps.data_space_id
ORDER BY dds.destination_id
FOR XML PATH(''''), TYPE
).value(''.'', ''nvarchar(max)''), 1, 2, N'''') +
N'');''
FROM {#SOURCEDB_Q#}.sys.partition_schemes AS ps
JOIN {#SOURCEDB_Q#}.sys.partition_functions AS pf ON pf.function_id = ps.function_id
-- Exclude partition schemes matching patterns in #ExcludedObjects
WHERE NOT EXISTS (
SELECT 1 FROM #ExcludedObjects AS ex
WHERE (ex.IsWildcard = 1 AND ps.name COLLATE DATABASE_DEFAULT LIKE ex.Pattern)
OR (ex.IsWildcard = 0 AND ps.name COLLATE DATABASE_DEFAULT = ex.Pattern)
);';
-- Ersetze Platzhalter durch tatsächliche Werte
SET @DYNAMICSQL = REPLACE(REPLACE(REPLACE(REPLACE(@DYNAMICSQL,
@PH_SOURCEDB_QUOTED, @SOURCEDATABASE_QUOTED),
@PH_TARGETDB_QUOTED, @TARGETDATABASE_QUOTED),
@PH_SOURCEDB, @SOURCEDATABASE),
@PH_TARGETDB, @TARGETDATABASE);
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) <= 4000 PRINT @DYNAMICSQL;
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) > 4000 PRINT LEFT(@DYNAMICSQL, 4000) + N'...(truncated)';
BEGIN TRY
EXEC sys.sp_executesql @DYNAMICSQL;
END TRY BEGIN CATCH
PRINT N'ERROR in dynamic SQL:';
PRINT @DYNAMICSQL;
THROW;
END CATCH;
----------------------------------------------------------------------------------------------------------------------------
IF @DEBUG = 1 PRINT 'DEBUG: Generating 02c-Sequences commands...';
--=================================================-- 02c: Sequences --=================================================--
-- NOTE: For sequences, we use current_value + increment to get the next value that will be issued
-- This handles both positive and negative increments correctly
SET @DYNAMICSQL = N'
INSERT INTO #Commands(Phase, Command)
SELECT
N''02c-Sequences'',
N''USE {#TARGETDB_Q#}; CREATE SEQUENCE '' + QUOTENAME(s.name) + N''.'' + QUOTENAME(sq.name) +
N'' AS '' + ty.name +
-- Use current_value + increment to get next value (handles positive and negative increments)
-- If sequence was never used (current_value = start_value - increment), this still works
-- Added overflow protection: if at boundary, use start_value for cycling or current for non-cycling
N'' START WITH '' + CONVERT(nvarchar(30),
CASE
WHEN sq.is_exhausted = 1 THEN sq.start_value -- Exhausted sequence, restart from beginning
WHEN sq.is_cycling = 0 AND sq.increment > 0 AND CONVERT(bigint, sq.current_value) >= sq.maximum_value THEN CONVERT(bigint, sq.current_value) -- At max, non-cycling
WHEN sq.is_cycling = 0 AND sq.increment < 0 AND CONVERT(bigint, sq.current_value) <= sq.minimum_value THEN CONVERT(bigint, sq.current_value) -- At min, non-cycling
WHEN sq.is_cycling = 1 AND sq.increment > 0 AND CONVERT(bigint, sq.current_value) >= sq.maximum_value THEN sq.minimum_value -- At max, cycling -> wrap to min
WHEN sq.is_cycling = 1 AND sq.increment < 0 AND CONVERT(bigint, sq.current_value) <= sq.minimum_value THEN sq.maximum_value -- At min, cycling -> wrap to max
ELSE CONVERT(bigint, sq.current_value) + CONVERT(bigint, sq.increment) -- Normal: next value
END) +
N'' INCREMENT BY '' + CONVERT(nvarchar(30), sq.increment) +
CASE WHEN sq.minimum_value IS NOT NULL THEN N'' MINVALUE '' + CONVERT(nvarchar(30), sq.minimum_value) ELSE N'' NO MINVALUE'' END +
CASE WHEN sq.maximum_value IS NOT NULL THEN N'' MAXVALUE '' + CONVERT(nvarchar(30), sq.maximum_value) ELSE N'' NO MAXVALUE'' END +
CASE WHEN sq.is_cycling = 1 THEN N'' CYCLE'' ELSE N'' NO CYCLE'' END +
CASE WHEN sq.is_cached = 1 THEN N'' CACHE '' + CONVERT(nvarchar(30), sq.cache_size) ELSE N'' NO CACHE'' END +
N'';''
FROM {#SOURCEDB_Q#}.sys.sequences AS sq
JOIN {#SOURCEDB_Q#}.sys.schemas AS s ON s.schema_id = sq.schema_id
JOIN {#SOURCEDB_Q#}.sys.types AS ty ON ty.user_type_id = sq.user_type_id
WHERE s.name <> N''sys''
-- Exclude sequences matching patterns in #ExcludedObjects
AND NOT EXISTS (
SELECT 1 FROM #ExcludedObjects AS ex
WHERE (ex.IsWildcard = 1 AND (sq.name COLLATE DATABASE_DEFAULT LIKE ex.Pattern OR (s.name + N''.'' + sq.name) COLLATE DATABASE_DEFAULT LIKE ex.Pattern))
OR (ex.IsWildcard = 0 AND (sq.name COLLATE DATABASE_DEFAULT = ex.Pattern OR (s.name + N''.'' + sq.name) COLLATE DATABASE_DEFAULT = ex.Pattern))
);';
-- Ersetze Platzhalter durch tatsächliche Werte
SET @DYNAMICSQL = REPLACE(REPLACE(REPLACE(REPLACE(@DYNAMICSQL,
@PH_SOURCEDB_QUOTED, @SOURCEDATABASE_QUOTED),
@PH_TARGETDB_QUOTED, @TARGETDATABASE_QUOTED),
@PH_SOURCEDB, @SOURCEDATABASE),
@PH_TARGETDB, @TARGETDATABASE);
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) <= 4000 PRINT @DYNAMICSQL;
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) > 4000 PRINT LEFT(@DYNAMICSQL, 4000) + N'...(truncated)';
BEGIN TRY
EXEC sys.sp_executesql @DYNAMICSQL;
END TRY BEGIN CATCH
PRINT N'ERROR in dynamic SQL:';
PRINT @DYNAMICSQL;
THROW;
END CATCH;
----------------------------------------------------------------------------------------------------------------------------
IF @DEBUG = 1 PRINT 'DEBUG: Generating 02d-UserDefinedTypes commands...';
--=================================================-- 02d: User-Defined Types (Alias Types) --==========================--
SET @DYNAMICSQL = N'
INSERT INTO #Commands(Phase, Command)
SELECT
N''02d-UDT'',
N''USE {#TARGETDB_Q#}; CREATE TYPE '' + QUOTENAME(s.name) + N''.'' + QUOTENAME(t.name) +
N'' FROM '' + bty.name +
CASE
WHEN bty.name IN (N''varchar'',N''char'',N''varbinary'',N''binary'') THEN N''('' + CASE WHEN t.max_length = -1 THEN N''max'' ELSE CONVERT(nvarchar(10), t.max_length) END + N'')''
WHEN bty.name IN (N''nvarchar'',N''nchar'') THEN N''('' + CASE WHEN t.max_length = -1 THEN N''max'' ELSE CONVERT(nvarchar(10), t.max_length/2) END + N'')''
WHEN bty.name IN (N''decimal'',N''numeric'') THEN N''('' + CONVERT(nvarchar(10), t.precision) + N'','' + CONVERT(nvarchar(10), t.scale) + N'')''
WHEN bty.name IN (N''datetime2'',N''datetimeoffset'',N''time'') THEN N''('' + CONVERT(nvarchar(10), t.scale) + N'')''
ELSE N''''
END +
-- Add COLLATE for string-based types
CASE WHEN bty.name IN (N''char'',N''varchar'',N''nchar'',N''nvarchar'',N''text'',N''ntext'') THEN N'' COLLATE ' + @NEWCOLLATION + N''' ELSE N'''' END +
CASE WHEN t.is_nullable = 1 THEN N'' NULL'' ELSE N'' NOT NULL'' END +
N'';''
FROM {#SOURCEDB_Q#}.sys.types AS t
JOIN {#SOURCEDB_Q#}.sys.schemas AS s ON s.schema_id = t.schema_id
JOIN {#SOURCEDB_Q#}.sys.types AS bty ON bty.user_type_id = t.system_type_id
WHERE t.is_user_defined = 1
AND t.is_table_type = 0
AND t.is_assembly_type = 0
AND s.name <> N''sys''
-- Exclude UDTs matching patterns in #ExcludedObjects
AND NOT EXISTS (
SELECT 1 FROM #ExcludedObjects AS ex
WHERE (ex.IsWildcard = 1 AND (t.name COLLATE DATABASE_DEFAULT LIKE ex.Pattern OR (s.name + N''.'' + t.name) COLLATE DATABASE_DEFAULT LIKE ex.Pattern))
OR (ex.IsWildcard = 0 AND (t.name COLLATE DATABASE_DEFAULT = ex.Pattern OR (s.name + N''.'' + t.name) COLLATE DATABASE_DEFAULT = ex.Pattern))
);';
-- Ersetze Platzhalter durch tatsächliche Werte
SET @DYNAMICSQL = REPLACE(REPLACE(REPLACE(REPLACE(@DYNAMICSQL,
@PH_SOURCEDB_QUOTED, @SOURCEDATABASE_QUOTED),
@PH_TARGETDB_QUOTED, @TARGETDATABASE_QUOTED),
@PH_SOURCEDB, @SOURCEDATABASE),
@PH_TARGETDB, @TARGETDATABASE);
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) <= 4000 PRINT @DYNAMICSQL;
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) > 4000 PRINT LEFT(@DYNAMICSQL, 4000) + N'...(truncated)';
BEGIN TRY
EXEC sys.sp_executesql @DYNAMICSQL;
END TRY BEGIN CATCH
PRINT N'ERROR in dynamic SQL:';
PRINT @DYNAMICSQL;
THROW;
END CATCH;
----------------------------------------------------------------------------------------------------------------------------
IF @DEBUG = 1 PRINT 'DEBUG: Generating 02e-TableTypes commands...';
--=================================================-- 02e: Table Types --===============================================--
SET @DYNAMICSQL = N'
INSERT INTO #Commands(Phase, Command)
SELECT
N''02e-TableTypes'',
N''USE {#TARGETDB_Q#}; CREATE TYPE '' + QUOTENAME(s.name) + N''.'' + QUOTENAME(t.name) + N'' AS TABLE ('' +
STUFF((
SELECT N'', '' +
QUOTENAME(c.name) + N'' '' +
CASE
WHEN bty.name IN (N''varchar'',N''char'',N''varbinary'',N''binary'') THEN bty.name + N''('' + CASE WHEN c.max_length = -1 THEN N''max'' ELSE CONVERT(nvarchar(10), c.max_length) END + N'')''
WHEN bty.name IN (N''nvarchar'',N''nchar'') THEN bty.name + N''('' + CASE WHEN c.max_length = -1 THEN N''max'' ELSE CONVERT(nvarchar(10), c.max_length/2) END + N'')''
WHEN bty.name IN (N''decimal'',N''numeric'') THEN bty.name + N''('' + CONVERT(nvarchar(10), c.precision) + N'','' + CONVERT(nvarchar(10), c.scale) + N'')''
WHEN bty.name IN (N''datetime2'',N''datetimeoffset'',N''time'') THEN bty.name + N''('' + CONVERT(nvarchar(10), c.scale) + N'')''
ELSE bty.name
END +
CASE WHEN bty.name IN (N''char'',N''varchar'',N''nchar'',N''nvarchar'',N''text'',N''ntext'') THEN N'' COLLATE ' + @NEWCOLLATION + N''' ELSE N'''' END +
CASE WHEN c.is_nullable = 1 THEN N'' NULL'' ELSE N'' NOT NULL'' END
FROM {#SOURCEDB_Q#}.sys.table_types AS tt2
JOIN {#SOURCEDB_Q#}.sys.columns AS c ON c.object_id = tt2.type_table_object_id
JOIN {#SOURCEDB_Q#}.sys.types AS bty ON bty.user_type_id = c.system_type_id
WHERE tt2.user_type_id = t.user_type_id
ORDER BY c.column_id
FOR XML PATH(''''), TYPE
).value(''.'', ''nvarchar(max)''), 1, 2, N'''') + N'');''
FROM {#SOURCEDB_Q#}.sys.table_types AS t
JOIN {#SOURCEDB_Q#}.sys.schemas AS s ON s.schema_id = t.schema_id
WHERE s.name <> N''sys''
-- Exclude table types matching patterns in #ExcludedObjects
AND NOT EXISTS (
SELECT 1 FROM #ExcludedObjects AS ex
WHERE (ex.IsWildcard = 1 AND (t.name COLLATE DATABASE_DEFAULT LIKE ex.Pattern OR (s.name + N''.'' + t.name) COLLATE DATABASE_DEFAULT LIKE ex.Pattern))
OR (ex.IsWildcard = 0 AND (t.name COLLATE DATABASE_DEFAULT = ex.Pattern OR (s.name + N''.'' + t.name) COLLATE DATABASE_DEFAULT = ex.Pattern))
);';
-- Ersetze Platzhalter durch tatsächliche Werte
SET @DYNAMICSQL = REPLACE(REPLACE(REPLACE(REPLACE(@DYNAMICSQL,
@PH_SOURCEDB_QUOTED, @SOURCEDATABASE_QUOTED),
@PH_TARGETDB_QUOTED, @TARGETDATABASE_QUOTED),
@PH_SOURCEDB, @SOURCEDATABASE),
@PH_TARGETDB, @TARGETDATABASE);
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) <= 4000 PRINT @DYNAMICSQL;
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) > 4000 PRINT LEFT(@DYNAMICSQL, 4000) + N'...(truncated)';
BEGIN TRY
EXEC sys.sp_executesql @DYNAMICSQL;
END TRY BEGIN CATCH
PRINT N'ERROR in dynamic SQL:';
PRINT @DYNAMICSQL;
THROW;
END CATCH;
----------------------------------------------------------------------------------------------------------------------------
IF @DEBUG = 1 PRINT 'DEBUG: Generating 03-Tables commands...';
--=================================================-- 03: Tables --=====================================================--
SET @DYNAMICSQL = N'
INSERT INTO #Commands(Phase, Command)
SELECT
N''03-Tables'',
N''USE {#TARGETDB_Q#}; CREATE TABLE '' + QUOTENAME(sc.name) + N''.'' + QUOTENAME(t.name) + N''('' +
STUFF((
SELECT N'', '' +
CASE WHEN c.is_computed = 1 THEN
QUOTENAME(c.name) + N'' AS '' + REPLACE(REPLACE(cc.definition, N''[{#SOURCEDB#}].'', N''[{#TARGETDB#}].''), N''{#SOURCEDB#}.'', N''{#TARGETDB#}.'' ) + CASE WHEN cc.is_persisted = 1 THEN N'' PERSISTED'' ELSE N'''' END
ELSE
QUOTENAME(c.name) + N'' '' +
-- Use UDT name if user-defined, otherwise system type with size specs
CASE
WHEN ty.is_user_defined = 1 THEN QUOTENAME(tys.name) + N''.'' + QUOTENAME(ty.name)
WHEN ty.name 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 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 IN (N''decimal'',N''numeric'') THEN ty.name + N''('' + CONVERT(nvarchar(10), c.precision) + N'','' + CONVERT(nvarchar(10), c.scale) + N'')''
WHEN ty.name IN (N''datetime2'',N''datetimeoffset'',N''time'') THEN ty.name + N''('' + CONVERT(nvarchar(10), c.scale) + N'')''
ELSE ty.name
END +
-- Only add COLLATE for non-UDT string types (UDTs already have collation from CREATE TYPE)
CASE WHEN ty.is_user_defined = 0 AND ty.name IN (N''char'',N''varchar'',N''nchar'',N''nvarchar'',N''text'',N''ntext'') THEN N'' COLLATE ' + @NEWCOLLATION + N''' 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_rowguidcol = 1 THEN N'' ROWGUIDCOL'' ELSE N'''' END +
CASE WHEN c.is_nullable = 1 THEN N'' NULL'' ELSE N'' NOT NULL'' END
END
FROM {#SOURCEDB_Q#}.sys.columns AS c
LEFT JOIN {#SOURCEDB_Q#}.sys.identity_columns AS ic ON ic.object_id = c.object_id AND ic.column_id = c.column_id
LEFT JOIN {#SOURCEDB_Q#}.sys.computed_columns AS cc ON cc.object_id = c.object_id AND cc.column_id = c.column_id
JOIN {#SOURCEDB_Q#}.sys.types AS ty ON ty.user_type_id = c.user_type_id
LEFT JOIN {#SOURCEDB_Q#}.sys.schemas AS 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'');''
FROM {#SOURCEDB_Q#}.sys.tables AS t
JOIN {#SOURCEDB_Q#}.sys.schemas AS sc ON sc.schema_id = t.schema_id
WHERE sc.name <> N''sys'' AND t.is_ms_shipped = 0
-- Exclude tables matching patterns in #ExcludedObjects
AND NOT EXISTS (
SELECT 1 FROM #ExcludedObjects AS ex
WHERE (ex.IsWildcard = 1 AND (t.name COLLATE DATABASE_DEFAULT LIKE ex.Pattern OR (sc.name + N''.'' + t.name) COLLATE DATABASE_DEFAULT LIKE ex.Pattern))
OR (ex.IsWildcard = 0 AND (t.name COLLATE DATABASE_DEFAULT = ex.Pattern OR (sc.name + N''.'' + t.name) COLLATE DATABASE_DEFAULT = ex.Pattern))
);';
-- Ersetze Platzhalter durch tatsächliche Werte
SET @DYNAMICSQL = REPLACE(REPLACE(REPLACE(REPLACE(@DYNAMICSQL,
@PH_SOURCEDB_QUOTED, @SOURCEDATABASE_QUOTED),
@PH_TARGETDB_QUOTED, @TARGETDATABASE_QUOTED),
@PH_SOURCEDB, @SOURCEDATABASE),
@PH_TARGETDB, @TARGETDATABASE);
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) <= 4000 PRINT @DYNAMICSQL;
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) > 4000 PRINT LEFT(@DYNAMICSQL, 4000) + N'...(truncated)';
BEGIN TRY
EXEC sys.sp_executesql @DYNAMICSQL;
END TRY BEGIN CATCH
PRINT N'ERROR in dynamic SQL:';
PRINT @DYNAMICSQL;
THROW;
END CATCH;
----------------------------------------------------------------------------------------------------------------------------
IF @DEBUG = 1 PRINT 'DEBUG: Generating 04-Data commands...';
--=================================================-- 04: Data copy --==================================================--
-- Using TABLOCK hint for minimal logging in SIMPLE recovery mode
-- With batching support to prevent transaction log overflow
-- Strategy:
-- - Tables with single-column INT/BIGINT PK: Keyset pagination (no tempdb usage)
-- - Tables without suitable PK: Temp table approach (uses tempdb)
IF @BATCHSIZE = 0 BEGIN
-- No batching - single INSERT per table
SET @DYNAMICSQL = N'
INSERT INTO #Commands(Phase, Command)
SELECT
N''04-Data'',
N''USE {#TARGETDB_Q#}; '' +
CASE WHEN EXISTS (SELECT 1 FROM {#SOURCEDB_Q#}.sys.identity_columns AS ic WHERE ic.object_id = t.object_id) THEN N''SET IDENTITY_INSERT '' + QUOTENAME(sc.name) + N''.'' + QUOTENAME(t.name) + N'' ON; '' ELSE N'''' END +
N''INSERT INTO '' + QUOTENAME(sc.name) + N''.'' + QUOTENAME(t.name) + N'' WITH (TABLOCK) ('' +
STUFF((
SELECT N'', '' + QUOTENAME(c.name)
FROM {#SOURCEDB_Q#}.sys.columns AS c
JOIN {#SOURCEDB_Q#}.sys.types AS cty ON cty.user_type_id = c.user_type_id
WHERE c.object_id = t.object_id
AND c.is_computed = 0
AND cty.name NOT IN (N''timestamp'', N''rowversion'')
ORDER BY c.column_id
FOR XML PATH(''''), TYPE
).value(''.'', ''nvarchar(max)''), 1, 2, N'''') + N'') '' +
N''SELECT '' +
STUFF((
SELECT N'', '' + QUOTENAME(c.name)
FROM {#SOURCEDB_Q#}.sys.columns AS c
JOIN {#SOURCEDB_Q#}.sys.types AS cty ON cty.user_type_id = c.user_type_id
WHERE c.object_id = t.object_id
AND c.is_computed = 0
AND cty.name NOT IN (N''timestamp'', N''rowversion'')
ORDER BY c.column_id
FOR XML PATH(''''), TYPE
).value(''.'', ''nvarchar(max)''), 1, 2, N'''') +
N'' FROM {#SOURCEDB_Q#}.'' + QUOTENAME(sc.name) + N''.'' + QUOTENAME(t.name) + N''; '' +
CASE WHEN EXISTS (SELECT 1 FROM {#SOURCEDB_Q#}.sys.identity_columns AS ic WHERE ic.object_id = t.object_id) THEN N''SET IDENTITY_INSERT '' + QUOTENAME(sc.name) + N''.'' + QUOTENAME(t.name) + N'' OFF; '' ELSE N'''' END +
N''CHECKPOINT;''
FROM {#SOURCEDB_Q#}.sys.tables AS t
JOIN {#SOURCEDB_Q#}.sys.schemas AS sc ON sc.schema_id = t.schema_id
WHERE sc.name <> N''sys'' AND t.is_ms_shipped = 0
-- Exclude tables matching patterns in #ExcludedObjects
AND NOT EXISTS (
SELECT 1 FROM #ExcludedObjects AS ex
WHERE (ex.IsWildcard = 1 AND (t.name COLLATE DATABASE_DEFAULT LIKE ex.Pattern OR (sc.name + N''.'' + t.name) COLLATE DATABASE_DEFAULT LIKE ex.Pattern))
OR (ex.IsWildcard = 0 AND (t.name COLLATE DATABASE_DEFAULT = ex.Pattern OR (sc.name + N''.'' + t.name) COLLATE DATABASE_DEFAULT = ex.Pattern))
);';
-- Ersetze Platzhalter durch tatsächliche Werte
SET @DYNAMICSQL = REPLACE(REPLACE(REPLACE(REPLACE(@DYNAMICSQL,
@PH_SOURCEDB_QUOTED, @SOURCEDATABASE_QUOTED),
@PH_TARGETDB_QUOTED, @TARGETDATABASE_QUOTED),
@PH_SOURCEDB, @SOURCEDATABASE),
@PH_TARGETDB, @TARGETDATABASE);
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) <= 4000 PRINT @DYNAMICSQL;
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) > 4000 PRINT LEFT(@DYNAMICSQL, 4000) + N'...(truncated)';
BEGIN TRY
EXEC sys.sp_executesql @DYNAMICSQL;
END TRY BEGIN CATCH
PRINT N'ERROR in dynamic SQL:';
PRINT @DYNAMICSQL;
THROW;
END CATCH;
END; ELSE BEGIN
-- Batching enabled - use Keyset Pagination for tables with single-column INT/BIGINT PK (no tempdb usage)
-- This is the most efficient approach for large tables
SET @DYNAMICSQL = N'
INSERT INTO #Commands(Phase, Command)
SELECT
N''04-Data'',
N''USE {#TARGETDB_Q#}; '' +
CASE WHEN EXISTS (SELECT 1 FROM {#SOURCEDB_Q#}.sys.identity_columns AS ic WHERE ic.object_id = t.object_id) THEN N''SET IDENTITY_INSERT '' + QUOTENAME(sc.name) + N''.'' + QUOTENAME(t.name) + N'' ON; '' ELSE N'''' END +
-- Keyset pagination: Use PK column for efficient batching without tempdb
-- Optimized: Calculate batch MAX key BEFORE insert to avoid full table scans
N''DECLARE @LastKey BIGINT = NULL, @BatchMaxKey BIGINT, @Rows INT = 1; '' +
N''WHILE @Rows > 0 BEGIN '' +
-- Find the max key for this batch using index seek on source PK
N''SELECT @BatchMaxKey = MAX('' + QUOTENAME(pkc.pk_column_name) + N'') '' +
N''FROM (SELECT TOP ({#BATCHSIZE#}) '' + QUOTENAME(pkc.pk_column_name) + N'' '' +
N'' FROM {#SOURCEDB_Q#}.'' + QUOTENAME(sc.name) + N''.'' + QUOTENAME(t.name) + N'' '' +
N'' WHERE (@LastKey IS NULL OR '' + QUOTENAME(pkc.pk_column_name) + N'' > @LastKey) '' +
N'' ORDER BY '' + QUOTENAME(pkc.pk_column_name) + N'') AS __batch; '' +
N''IF @BatchMaxKey IS NULL SET @Rows = 0; ELSE BEGIN '' +
N''INSERT INTO '' + QUOTENAME(sc.name) + N''.'' + QUOTENAME(t.name) + N'' WITH (TABLOCK) ('' +
STUFF((
SELECT N'', '' + QUOTENAME(c.name)
FROM {#SOURCEDB_Q#}.sys.columns AS c
JOIN {#SOURCEDB_Q#}.sys.types AS cty ON cty.user_type_id = c.user_type_id
WHERE c.object_id = t.object_id
AND c.is_computed = 0
AND cty.name NOT IN (N''timestamp'', N''rowversion'')
ORDER BY c.column_id
FOR XML PATH(''''), TYPE
).value(''.'', ''nvarchar(max)''), 1, 2, N'''') + N'') '' +
N''SELECT '' +
STUFF((
SELECT N'', '' + QUOTENAME(c.name)
FROM {#SOURCEDB_Q#}.sys.columns AS c
JOIN {#SOURCEDB_Q#}.sys.types AS cty ON cty.user_type_id = c.user_type_id
WHERE c.object_id = t.object_id
AND c.is_computed = 0
AND cty.name NOT IN (N''timestamp'', N''rowversion'')
ORDER BY c.column_id
FOR XML PATH(''''), TYPE
).value(''.'', ''nvarchar(max)''), 1, 2, N'''') +
N'' FROM {#SOURCEDB_Q#}.'' + QUOTENAME(sc.name) + N''.'' + QUOTENAME(t.name) +
N'' WHERE (@LastKey IS NULL OR '' + QUOTENAME(pkc.pk_column_name) + N'' > @LastKey) '' +
N'' AND '' + QUOTENAME(pkc.pk_column_name) + N'' <= @BatchMaxKey; '' +
N''SET @Rows = @@ROWCOUNT; SET @LastKey = @BatchMaxKey; '' +
N''CHECKPOINT; '' +
N''END; END; '' +
CASE WHEN EXISTS (SELECT 1 FROM {#SOURCEDB_Q#}.sys.identity_columns AS ic WHERE ic.object_id = t.object_id) THEN N''SET IDENTITY_INSERT '' + QUOTENAME(sc.name) + N''.'' + QUOTENAME(t.name) + N'' OFF; '' ELSE N'''' END
FROM {#SOURCEDB_Q#}.sys.tables AS t
JOIN {#SOURCEDB_Q#}.sys.schemas AS sc ON sc.schema_id = t.schema_id
-- Find single-column INT/BIGINT primary key
CROSS APPLY (
SELECT c.name AS pk_column_name
FROM {#SOURCEDB_Q#}.sys.indexes AS i
JOIN {#SOURCEDB_Q#}.sys.index_columns AS ic ON ic.object_id = i.object_id AND ic.index_id = i.index_id
JOIN {#SOURCEDB_Q#}.sys.columns AS c ON c.object_id = ic.object_id AND c.column_id = ic.column_id
JOIN {#SOURCEDB_Q#}.sys.types AS ty ON ty.user_type_id = c.user_type_id
WHERE i.object_id = t.object_id
AND i.is_primary_key = 1
AND ty.name IN (N''int'', N''bigint'', N''smallint'', N''tinyint'')
-- Only select if PK has exactly one column
AND (SELECT COUNT(*) FROM {#SOURCEDB_Q#}.sys.index_columns AS ic2 WHERE ic2.object_id = i.object_id AND ic2.index_id = i.index_id) = 1
) AS pkc
WHERE sc.name <> N''sys'' AND t.is_ms_shipped = 0
-- Exclude tables matching patterns in #ExcludedObjects
AND NOT EXISTS (
SELECT 1 FROM #ExcludedObjects AS ex
WHERE (ex.IsWildcard = 1 AND (t.name COLLATE DATABASE_DEFAULT LIKE ex.Pattern OR (sc.name + N''.'' + t.name) COLLATE DATABASE_DEFAULT LIKE ex.Pattern))
OR (ex.IsWildcard = 0 AND (t.name COLLATE DATABASE_DEFAULT = ex.Pattern OR (sc.name + N''.'' + t.name) COLLATE DATABASE_DEFAULT = ex.Pattern))
);';
-- Ersetze Platzhalter durch tatsächliche Werte
SET @DYNAMICSQL = REPLACE(REPLACE(REPLACE(REPLACE(@DYNAMICSQL,
@PH_SOURCEDB_QUOTED, @SOURCEDATABASE_QUOTED),
@PH_TARGETDB_QUOTED, @TARGETDATABASE_QUOTED),
@PH_SOURCEDB, @SOURCEDATABASE),
@PH_TARGETDB, @TARGETDATABASE);
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) <= 4000 PRINT @DYNAMICSQL;
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) > 4000 PRINT LEFT(@DYNAMICSQL, 4000) + N'...(truncated)';
BEGIN TRY
EXEC sys.sp_executesql @DYNAMICSQL;
END TRY BEGIN CATCH
PRINT N'ERROR in dynamic SQL:';
PRINT @DYNAMICSQL;
THROW;
END CATCH;
-- Fallback for tables WITHOUT single-column INT/BIGINT PK: Use temp table approach
-- This uses tempdb but is necessary for tables without a suitable PK
SET @DYNAMICSQL = N'
INSERT INTO #Commands(Phase, Command)
SELECT
N''04-Data'',
N''USE {#TARGETDB_Q#}; '' +
CASE WHEN EXISTS (SELECT 1 FROM {#SOURCEDB_Q#}.sys.identity_columns AS ic WHERE ic.object_id = t.object_id) THEN N''SET IDENTITY_INSERT '' + QUOTENAME(sc.name) + N''.'' + QUOTENAME(t.name) + N'' ON; '' ELSE N'''' END +
-- Step 1: Create temp table with ROW_NUMBER computed only ONCE
N''SELECT '' +
STUFF((
SELECT N'', '' + QUOTENAME(c.name)
FROM {#SOURCEDB_Q#}.sys.columns AS c
JOIN {#SOURCEDB_Q#}.sys.types AS cty ON cty.user_type_id = c.user_type_id
WHERE c.object_id = t.object_id
AND c.is_computed = 0
AND cty.name NOT IN (N''timestamp'', N''rowversion'')
ORDER BY c.column_id
FOR XML PATH(''''), TYPE
).value(''.'', ''nvarchar(max)''), 1, 2, N'''') +
N'', ROW_NUMBER() OVER (ORDER BY (SELECT NULL)) AS __rn INTO #__BatchTemp FROM {#SOURCEDB_Q#}.'' + QUOTENAME(sc.name) + N''.'' + QUOTENAME(t.name) + N''; '' +
-- Step 2: Create clustered index on __rn for fast range seeks
N''CREATE CLUSTERED INDEX __IX_BatchTemp_rn ON #__BatchTemp (__rn); '' +
-- Step 3: Batch loop using indexed seeks on temp table
N''DECLARE @Offset BIGINT = 0, @Rows INT = 1; '' +
N''WHILE @Rows > 0 BEGIN '' +
N''INSERT INTO '' + QUOTENAME(sc.name) + N''.'' + QUOTENAME(t.name) + N'' WITH (TABLOCK) ('' +
STUFF((
SELECT N'', '' + QUOTENAME(c.name)
FROM {#SOURCEDB_Q#}.sys.columns AS c
JOIN {#SOURCEDB_Q#}.sys.types AS cty ON cty.user_type_id = c.user_type_id
WHERE c.object_id = t.object_id
AND c.is_computed = 0
AND cty.name NOT IN (N''timestamp'', N''rowversion'')
ORDER BY c.column_id
FOR XML PATH(''''), TYPE
).value(''.'', ''nvarchar(max)''), 1, 2, N'''') + N'') '' +
N''SELECT '' +
STUFF((
SELECT N'', '' + QUOTENAME(c.name)
FROM {#SOURCEDB_Q#}.sys.columns AS c
JOIN {#SOURCEDB_Q#}.sys.types AS cty ON cty.user_type_id = c.user_type_id
WHERE c.object_id = t.object_id
AND c.is_computed = 0
AND cty.name NOT IN (N''timestamp'', N''rowversion'')
ORDER BY c.column_id
FOR XML PATH(''''), TYPE
).value(''.'', ''nvarchar(max)''), 1, 2, N'''') +
N'' FROM #__BatchTemp WHERE __rn > @Offset AND __rn <= @Offset + {#BATCHSIZE#}; '' +
N''SET @Rows = @@ROWCOUNT; SET @Offset = @Offset + {#BATCHSIZE#}; '' +
N''CHECKPOINT; '' +
N''END; '' +
-- Step 4: Cleanup temp table (DBCC SHRINKFILE runs once after all temp-table operations in phase 04a)
N''DROP TABLE #__BatchTemp; '' +
CASE WHEN EXISTS (SELECT 1 FROM {#SOURCEDB_Q#}.sys.identity_columns AS ic WHERE ic.object_id = t.object_id) THEN N''SET IDENTITY_INSERT '' + QUOTENAME(sc.name) + N''.'' + QUOTENAME(t.name) + N'' OFF; '' ELSE N'''' END
FROM {#SOURCEDB_Q#}.sys.tables AS t
JOIN {#SOURCEDB_Q#}.sys.schemas AS sc ON sc.schema_id = t.schema_id
WHERE sc.name <> N''sys'' AND t.is_ms_shipped = 0
-- Exclude tables that already have keyset pagination (single-column INT/BIGINT PK)
AND NOT EXISTS (
SELECT 1
FROM {#SOURCEDB_Q#}.sys.indexes AS i
JOIN {#SOURCEDB_Q#}.sys.index_columns AS ic ON ic.object_id = i.object_id AND ic.index_id = i.index_id
JOIN {#SOURCEDB_Q#}.sys.columns AS c ON c.object_id = ic.object_id AND c.column_id = ic.column_id
JOIN {#SOURCEDB_Q#}.sys.types AS ty ON ty.user_type_id = c.user_type_id
WHERE i.object_id = t.object_id
AND i.is_primary_key = 1
AND ty.name IN (N''int'', N''bigint'', N''smallint'', N''tinyint'')
AND (SELECT COUNT(*) FROM {#SOURCEDB_Q#}.sys.index_columns AS ic2 WHERE ic2.object_id = i.object_id AND ic2.index_id = i.index_id) = 1
)
-- Exclude tables matching patterns in #ExcludedObjects
AND NOT EXISTS (
SELECT 1 FROM #ExcludedObjects AS ex
WHERE (ex.IsWildcard = 1 AND (t.name COLLATE DATABASE_DEFAULT LIKE ex.Pattern OR (sc.name + N''.'' + t.name) COLLATE DATABASE_DEFAULT LIKE ex.Pattern))
OR (ex.IsWildcard = 0 AND (t.name COLLATE DATABASE_DEFAULT = ex.Pattern OR (sc.name + N''.'' + t.name) COLLATE DATABASE_DEFAULT = ex.Pattern))
);';
-- Ersetze Platzhalter durch tatsächliche Werte
SET @DYNAMICSQL = REPLACE(REPLACE(REPLACE(REPLACE(@DYNAMICSQL,
@PH_SOURCEDB_QUOTED, @SOURCEDATABASE_QUOTED),
@PH_TARGETDB_QUOTED, @TARGETDATABASE_QUOTED),
@PH_SOURCEDB, @SOURCEDATABASE),
@PH_TARGETDB, @TARGETDATABASE);
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) <= 4000 PRINT @DYNAMICSQL;
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) > 4000 PRINT LEFT(@DYNAMICSQL, 4000) + N'...(truncated)';
BEGIN TRY
EXEC sys.sp_executesql @DYNAMICSQL;
END TRY BEGIN CATCH
PRINT N'ERROR in dynamic SQL:';
PRINT @DYNAMICSQL;
THROW;
END CATCH;
-- Add DBCC SHRINKFILE once after all temp-table data operations (if any temp tables were used)
-- Must execute in tempdb context to find the tempdev file
SET @DYNAMICSQL = N'
IF EXISTS (
SELECT 1 FROM {#SOURCEDB_Q#}.sys.tables AS t
JOIN {#SOURCEDB_Q#}.sys.schemas AS sc ON sc.schema_id = t.schema_id
WHERE sc.name <> N''sys'' AND t.is_ms_shipped = 0
AND NOT EXISTS (
SELECT 1
FROM {#SOURCEDB_Q#}.sys.indexes AS i
JOIN {#SOURCEDB_Q#}.sys.index_columns AS ic ON ic.object_id = i.object_id AND ic.index_id = i.index_id
JOIN {#SOURCEDB_Q#}.sys.columns AS c ON c.object_id = ic.object_id AND c.column_id = ic.column_id
JOIN {#SOURCEDB_Q#}.sys.types AS ty ON ty.user_type_id = c.user_type_id
WHERE i.object_id = t.object_id AND i.is_primary_key = 1 AND ty.name IN (N''int'', N''bigint'', N''smallint'', N''tinyint'')
AND (SELECT COUNT(*) FROM {#SOURCEDB_Q#}.sys.index_columns AS ic2 WHERE ic2.object_id = i.object_id AND ic2.index_id = i.index_id) = 1
)
)
INSERT INTO #Commands(Phase, Command) VALUES (N''04a-ShrinkTempdb'', N''USE tempdb; BEGIN TRY DECLARE @f sysname = (SELECT TOP (1) name FROM tempdb.sys.database_files WHERE type_desc = ''''ROWS''''); IF @f IS NOT NULL BEGIN DBCC SHRINKFILE(@f, 1); END END TRY BEGIN CATCH PRINT N''''WARN: DBCC SHRINKFILE skipped: '''' + ERROR_MESSAGE(); END CATCH;'');';
-- Ersetze Platzhalter durch tatsächliche Werte
SET @DYNAMICSQL = REPLACE(REPLACE(REPLACE(REPLACE(@DYNAMICSQL,
@PH_SOURCEDB_QUOTED, @SOURCEDATABASE_QUOTED),
@PH_TARGETDB_QUOTED, @TARGETDATABASE_QUOTED),
@PH_SOURCEDB, @SOURCEDATABASE),
@PH_TARGETDB, @TARGETDATABASE);
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) <= 4000 PRINT @DYNAMICSQL;
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) > 4000 PRINT LEFT(@DYNAMICSQL, 4000) + N'...(truncated)';
BEGIN TRY
EXEC sys.sp_executesql @DYNAMICSQL;
END TRY BEGIN CATCH
PRINT N'ERROR in dynamic SQL:';
PRINT @DYNAMICSQL;
THROW;
END CATCH;
END;
----------------------------------------------------------------------------------------------------------------------------
IF @DEBUG = 1 PRINT 'DEBUG: Generating 05-DefaultConstraints commands...';
--=================================================-- 05: Default constraints --========================================--
SET @DYNAMICSQL = N'
INSERT INTO #Commands(Phase, Command)
SELECT
N''05-Defaults'',
N''USE {#TARGETDB_Q#}; ALTER TABLE '' + QUOTENAME(s.name) + N''.'' + QUOTENAME(t.name) +
N'' ADD CONSTRAINT '' + QUOTENAME(dc.name) + N'' DEFAULT '' + REPLACE(REPLACE(dc.definition, N''[{#SOURCEDB#}].'', N''[{#TARGETDB#}].''), N''{#SOURCEDB#}.'', N''{#TARGETDB#}.'' ) +
N'' FOR '' + QUOTENAME(c.name) + N'';''
FROM {#SOURCEDB_Q#}.sys.default_constraints AS dc
JOIN {#SOURCEDB_Q#}.sys.tables AS t ON t.object_id = dc.parent_object_id
JOIN {#SOURCEDB_Q#}.sys.schemas AS s ON s.schema_id = t.schema_id
JOIN {#SOURCEDB_Q#}.sys.columns AS c ON c.object_id = dc.parent_object_id AND c.column_id = dc.parent_column_id
WHERE s.name <> N''sys''
-- Exclude constraints on tables matching patterns in #ExcludedObjects
AND NOT EXISTS (
SELECT 1 FROM #ExcludedObjects AS ex
WHERE (ex.IsWildcard = 1 AND (t.name COLLATE DATABASE_DEFAULT LIKE ex.Pattern OR (s.name + N''.'' + t.name) COLLATE DATABASE_DEFAULT LIKE ex.Pattern))
OR (ex.IsWildcard = 0 AND (t.name COLLATE DATABASE_DEFAULT = ex.Pattern OR (s.name + N''.'' + t.name) COLLATE DATABASE_DEFAULT = ex.Pattern))
);';
-- Ersetze Platzhalter durch tatsächliche Werte
SET @DYNAMICSQL = REPLACE(REPLACE(REPLACE(REPLACE(@DYNAMICSQL,
@PH_SOURCEDB_QUOTED, @SOURCEDATABASE_QUOTED),
@PH_TARGETDB_QUOTED, @TARGETDATABASE_QUOTED),
@PH_SOURCEDB, @SOURCEDATABASE),
@PH_TARGETDB, @TARGETDATABASE);
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) <= 4000 PRINT @DYNAMICSQL;
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) > 4000 PRINT LEFT(@DYNAMICSQL, 4000) + N'...(truncated)';
BEGIN TRY
EXEC sys.sp_executesql @DYNAMICSQL;
END TRY BEGIN CATCH
PRINT N'ERROR in dynamic SQL:';
PRINT @DYNAMICSQL;
THROW;
END CATCH;
----------------------------------------------------------------------------------------------------------------------------
IF @DEBUG = 1 PRINT 'DEBUG: Generating 06-CheckConstraints commands...';
--=================================================-- 06: Check constraints --==========================================--
SET @DYNAMICSQL = N'
INSERT INTO #Commands(Phase, Command)
SELECT
N''06-Checks'',
N''USE {#TARGETDB_Q#}; ALTER TABLE '' + QUOTENAME(s.name) + N''.'' + QUOTENAME(t.name) +
N'' WITH NOCHECK ADD CONSTRAINT '' + QUOTENAME(cc.name) + N'' CHECK '' + REPLACE(REPLACE(cc.definition, N''[{#SOURCEDB#}].'', N''[{#TARGETDB#}].''), N''{#SOURCEDB#}.'', N''{#TARGETDB#}.'' ) + N'';'' +
CASE WHEN cc.is_disabled = 1 THEN
N'' ALTER TABLE '' + QUOTENAME(s.name) + N''.'' + QUOTENAME(t.name) + N'' NOCHECK CONSTRAINT '' + QUOTENAME(cc.name) + N'';''
ELSE N'''' END
FROM {#SOURCEDB_Q#}.sys.check_constraints AS cc
JOIN {#SOURCEDB_Q#}.sys.tables AS t ON t.object_id = cc.parent_object_id
JOIN {#SOURCEDB_Q#}.sys.schemas AS s ON s.schema_id = t.schema_id
WHERE s.name <> N''sys''
-- Exclude constraints on tables matching patterns in #ExcludedObjects
AND NOT EXISTS (
SELECT 1 FROM #ExcludedObjects AS ex
WHERE (ex.IsWildcard = 1 AND (t.name COLLATE DATABASE_DEFAULT LIKE ex.Pattern OR (s.name + N''.'' + t.name) COLLATE DATABASE_DEFAULT LIKE ex.Pattern))
OR (ex.IsWildcard = 0 AND (t.name COLLATE DATABASE_DEFAULT = ex.Pattern OR (s.name + N''.'' + t.name) COLLATE DATABASE_DEFAULT = ex.Pattern))
);';
-- Ersetze Platzhalter durch tatsächliche Werte
SET @DYNAMICSQL = REPLACE(REPLACE(REPLACE(REPLACE(@DYNAMICSQL,
@PH_SOURCEDB_QUOTED, @SOURCEDATABASE_QUOTED),
@PH_TARGETDB_QUOTED, @TARGETDATABASE_QUOTED),
@PH_SOURCEDB, @SOURCEDATABASE),
@PH_TARGETDB, @TARGETDATABASE);
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) <= 4000 PRINT @DYNAMICSQL;
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) > 4000 PRINT LEFT(@DYNAMICSQL, 4000) + N'...(truncated)';
BEGIN TRY
EXEC sys.sp_executesql @DYNAMICSQL;
END TRY BEGIN CATCH
PRINT N'ERROR in dynamic SQL:';
PRINT @DYNAMICSQL;
THROW;
END CATCH;
----------------------------------------------------------------------------------------------------------------------------
IF @DEBUG = 1 PRINT 'DEBUG: Generating 07-PrimaryUniqueConstraints commands...';
--=================================================-- 07: Primary/Unique constraints (PK/UQ) --=========================--
SET @DYNAMICSQL = N'
INSERT INTO #Commands(Phase, Command)
SELECT
N''07-PK_UQ'',
N''USE {#TARGETDB_Q#}; ALTER TABLE '' + QUOTENAME(s.name) + N''.'' + QUOTENAME(t.name) +
N'' ADD CONSTRAINT '' + QUOTENAME(k.name) + N'' '' +
CASE WHEN k.[type] = ''PK'' THEN N''PRIMARY KEY '' ELSE N''UNIQUE '' END +
CASE WHEN i.[type] = 1 THEN N''CLUSTERED '' ELSE N''NONCLUSTERED '' END +
N''('' + kc.cols + N'')'' +
-- PK/UQ options (WITH clause)
N'' WITH ('' +
N''PAD_INDEX = '' + CASE WHEN i.is_padded = 1 THEN N''ON'' ELSE N''OFF'' END +
N'', FILLFACTOR = '' + CASE WHEN i.fill_factor = 0 THEN N''100'' ELSE CONVERT(nvarchar(3), i.fill_factor) END +
N'', IGNORE_DUP_KEY = '' + CASE WHEN i.ignore_dup_key = 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 +
ISNULL(N'', DATA_COMPRESSION = '' + pc.compression_desc, N'''') +
N'')'' +
CASE WHEN on_target.on_target IS NULL THEN N'''' ELSE N'' ON '' + on_target.on_target END +
N'';''
FROM {#SOURCEDB_Q#}.sys.key_constraints AS k
JOIN {#SOURCEDB_Q#}.sys.tables AS t ON t.object_id = k.parent_object_id
JOIN {#SOURCEDB_Q#}.sys.schemas AS s ON s.schema_id = t.schema_id
JOIN {#SOURCEDB_Q#}.sys.indexes AS i ON i.object_id = k.parent_object_id AND i.index_id = k.unique_index_id
-- Get data compression for partition 1 (or NULL if not applicable)
OUTER APPLY (
SELECT TOP 1 p.data_compression_desc AS compression_desc
FROM {#SOURCEDB_Q#}.sys.partitions AS p
WHERE p.object_id = i.object_id AND p.index_id = i.index_id AND p.partition_number = 1
) AS pc
CROSS APPLY
(
SELECT STUFF((
SELECT N'', '' + QUOTENAME(c.name) + CASE WHEN ic.is_descending_key = 1 THEN N'' DESC'' ELSE N'' ASC'' END
FROM {#SOURCEDB_Q#}.sys.index_columns AS ic
JOIN {#SOURCEDB_Q#}.sys.columns AS c ON c.object_id = ic.object_id AND c.column_id = ic.column_id
WHERE ic.object_id = k.parent_object_id
AND ic.index_id = k.unique_index_id
AND ic.is_included_column = 0
ORDER BY ic.key_ordinal
FOR XML PATH(''''), TYPE
).value(''.'', ''nvarchar(max)''), 1, 2, N'''') AS cols
) AS kc
OUTER APPLY
(
SELECT
CASE
WHEN ds.[type] = ''PS'' THEN QUOTENAME(ps.name) + N''('' + QUOTENAME(pc2.name) + N'')''
ELSE QUOTENAME(ds.name)
END AS on_target
FROM {#SOURCEDB_Q#}.sys.data_spaces AS ds
LEFT JOIN {#SOURCEDB_Q#}.sys.partition_schemes AS ps ON ps.data_space_id = ds.data_space_id
LEFT JOIN {#SOURCEDB_Q#}.sys.index_columns AS icp ON icp.object_id = i.object_id AND icp.index_id = i.index_id AND icp.partition_ordinal = 1
LEFT JOIN {#SOURCEDB_Q#}.sys.columns AS pc2 ON pc2.object_id = icp.object_id AND pc2.column_id = icp.column_id
WHERE ds.data_space_id = i.data_space_id
) AS on_target
WHERE s.name <> N''sys''
-- Exclude PK/UQ on tables matching patterns in #ExcludedObjects
AND NOT EXISTS (
SELECT 1 FROM #ExcludedObjects AS ex
WHERE (ex.IsWildcard = 1 AND (t.name COLLATE DATABASE_DEFAULT LIKE ex.Pattern OR (s.name + N''.'' + t.name) COLLATE DATABASE_DEFAULT LIKE ex.Pattern))
OR (ex.IsWildcard = 0 AND (t.name COLLATE DATABASE_DEFAULT = ex.Pattern OR (s.name + N''.'' + t.name) COLLATE DATABASE_DEFAULT = ex.Pattern))
);';
-- Ersetze Platzhalter durch tatsächliche Werte
SET @DYNAMICSQL = REPLACE(REPLACE(REPLACE(REPLACE(@DYNAMICSQL,
@PH_SOURCEDB_QUOTED, @SOURCEDATABASE_QUOTED),
@PH_TARGETDB_QUOTED, @TARGETDATABASE_QUOTED),
@PH_SOURCEDB, @SOURCEDATABASE),
@PH_TARGETDB, @TARGETDATABASE);
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) <= 4000 PRINT @DYNAMICSQL;
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) > 4000 PRINT LEFT(@DYNAMICSQL, 4000) + N'...(truncated)';
BEGIN TRY
EXEC sys.sp_executesql @DYNAMICSQL;
END TRY BEGIN CATCH
PRINT N'ERROR in dynamic SQL:';
PRINT @DYNAMICSQL;
THROW;
END CATCH;
----------------------------------------------------------------------------------------------------------------------------
IF @DEBUG = 1 PRINT 'DEBUG: Generating 08-Indexes commands...';
--=================================================-- 08: Non-constraint indexes --=====================================--
SET @DYNAMICSQL = N'
INSERT INTO #Commands(Phase, Command)
SELECT
N''08-Indexes'',
N''USE {#TARGETDB_Q#}; CREATE '' +
CASE WHEN i.is_unique = 1 THEN N''UNIQUE '' ELSE N'''' END +
CASE WHEN i.[type] = 1 THEN N''CLUSTERED '' ELSE N''NONCLUSTERED '' END +
N''INDEX '' + QUOTENAME(i.name) +
N'' ON '' + QUOTENAME(s.name) + N''.'' + QUOTENAME(t.name) +
N'' ('' + kc.key_cols + N'')'' +
CASE WHEN inc.included_cols IS NULL THEN N'''' ELSE N'' INCLUDE ('' + inc.included_cols + N'')'' END +
CASE WHEN i.has_filter = 1 THEN N'' WHERE '' + REPLACE(REPLACE(i.filter_definition, N''[{#SOURCEDB#}].'', N''[{#TARGETDB#}].''), N''{#SOURCEDB#}.'', N''{#TARGETDB#}.'' ) ELSE N'''' END +
-- Index options (WITH clause)
N'' WITH ('' +
N''PAD_INDEX = '' + CASE WHEN i.is_padded = 1 THEN N''ON'' ELSE N''OFF'' END +
N'', FILLFACTOR = '' + CASE WHEN i.fill_factor = 0 THEN N''100'' ELSE CONVERT(nvarchar(3), i.fill_factor) END +
N'', IGNORE_DUP_KEY = '' + CASE WHEN i.ignore_dup_key = 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 +
ISNULL(N'', DATA_COMPRESSION = '' + pc.compression_desc, N'''') +
N'')'' +
CASE WHEN on_target.on_target IS NULL THEN N'''' ELSE N'' ON '' + on_target.on_target END +
N'';''
FROM {#SOURCEDB_Q#}.sys.indexes AS i
JOIN {#SOURCEDB_Q#}.sys.tables AS t ON t.object_id = i.object_id
JOIN {#SOURCEDB_Q#}.sys.schemas AS s ON s.schema_id = t.schema_id
-- Get data compression for partition 1 (or NULL if not applicable)
OUTER APPLY (
SELECT TOP 1 p.data_compression_desc AS compression_desc
FROM {#SOURCEDB_Q#}.sys.partitions AS p
WHERE p.object_id = i.object_id AND p.index_id = i.index_id AND p.partition_number = 1
) AS pc
OUTER APPLY
(
SELECT STUFF((
SELECT N'', '' + QUOTENAME(c.name) + CASE WHEN ic.is_descending_key = 1 THEN N'' DESC'' ELSE N'' ASC'' END
FROM {#SOURCEDB_Q#}.sys.index_columns AS ic
JOIN {#SOURCEDB_Q#}.sys.columns AS 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, 2, N'''') AS key_cols
) AS kc
OUTER APPLY
(
SELECT STUFF((
SELECT N'', '' + QUOTENAME(c.name)
FROM {#SOURCEDB_Q#}.sys.index_columns AS ic
JOIN {#SOURCEDB_Q#}.sys.columns AS 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, 2, N'''') AS included_cols
) AS inc
OUTER APPLY
(
SELECT
CASE
WHEN ds.[type] = ''PS'' THEN QUOTENAME(ps.name) + N''('' + QUOTENAME(pc.name) + N'')''
ELSE QUOTENAME(ds.name)
END AS on_target
FROM {#SOURCEDB_Q#}.sys.data_spaces AS ds
LEFT JOIN {#SOURCEDB_Q#}.sys.partition_schemes AS ps ON ps.data_space_id = ds.data_space_id
LEFT JOIN {#SOURCEDB_Q#}.sys.index_columns AS icp ON icp.object_id = i.object_id AND icp.index_id = i.index_id AND icp.partition_ordinal = 1
LEFT JOIN {#SOURCEDB_Q#}.sys.columns AS pc ON pc.object_id = icp.object_id AND pc.column_id = icp.column_id
WHERE ds.data_space_id = i.data_space_id
) AS on_target
WHERE s.name <> N''sys''
AND i.index_id > 0
AND i.is_primary_key = 0
AND i.is_unique_constraint = 0
-- Exclude indexes on tables matching patterns in #ExcludedObjects
AND NOT EXISTS (
SELECT 1 FROM #ExcludedObjects AS ex
WHERE (ex.IsWildcard = 1 AND (t.name COLLATE DATABASE_DEFAULT LIKE ex.Pattern OR (s.name + N''.'' + t.name) COLLATE DATABASE_DEFAULT LIKE ex.Pattern))
OR (ex.IsWildcard = 0 AND (t.name COLLATE DATABASE_DEFAULT = ex.Pattern OR (s.name + N''.'' + t.name) COLLATE DATABASE_DEFAULT = ex.Pattern))
);';
-- Ersetze Platzhalter durch tatsächliche Werte
SET @DYNAMICSQL = REPLACE(REPLACE(REPLACE(REPLACE(@DYNAMICSQL,
@PH_SOURCEDB_QUOTED, @SOURCEDATABASE_QUOTED),
@PH_TARGETDB_QUOTED, @TARGETDATABASE_QUOTED),
@PH_SOURCEDB, @SOURCEDATABASE),
@PH_TARGETDB, @TARGETDATABASE);
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) <= 4000 PRINT @DYNAMICSQL;
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) > 4000 PRINT LEFT(@DYNAMICSQL, 4000) + N'...(truncated)';
BEGIN TRY
EXEC sys.sp_executesql @DYNAMICSQL;
END TRY BEGIN CATCH
PRINT N'ERROR in dynamic SQL:';
PRINT @DYNAMICSQL;
THROW;
END CATCH;
----------------------------------------------------------------------------------------------------------------------------
IF @DEBUG = 1 PRINT 'DEBUG: Generating 09-ForeignKeys commands...';
--=================================================-- 09: Foreign keys --===============================================--
SET @DYNAMICSQL = N'
INSERT INTO #Commands(Phase, Command)
SELECT
N''09-FK'',
N''USE {#TARGETDB_Q#}; ALTER TABLE '' + QUOTENAME(spt.name) + N''.'' + QUOTENAME(pt.name) +
N'' ADD CONSTRAINT '' + QUOTENAME(fk.name) +
N'' FOREIGN KEY ('' + fkc.parent_cols + N'') REFERENCES '' +
QUOTENAME(srt.name) + N''.'' + QUOTENAME(rt.name) + N'' ('' + fkc.ref_cols + N'')'' +
CASE WHEN fk.delete_referential_action_desc <> N''NO_ACTION'' THEN N'' ON DELETE '' + fk.delete_referential_action_desc ELSE N'''' END +
CASE WHEN fk.update_referential_action_desc <> N''NO_ACTION'' THEN N'' ON UPDATE '' + fk.update_referential_action_desc ELSE N'''' END +
CASE WHEN fk.is_not_for_replication = 1 THEN N'' NOT FOR REPLICATION'' ELSE N'''' END +
N'';'' +
CASE WHEN fk.is_disabled = 1 THEN N'' ALTER TABLE '' + QUOTENAME(spt.name) + N''.'' + QUOTENAME(pt.name) + N'' NOCHECK CONSTRAINT '' + QUOTENAME(fk.name) + N'';'' ELSE N'''' END
FROM {#SOURCEDB_Q#}.sys.foreign_keys AS fk
JOIN {#SOURCEDB_Q#}.sys.tables AS pt ON pt.object_id = fk.parent_object_id
JOIN {#SOURCEDB_Q#}.sys.tables AS rt ON rt.object_id = fk.referenced_object_id
JOIN {#SOURCEDB_Q#}.sys.schemas AS spt ON spt.schema_id = pt.schema_id
JOIN {#SOURCEDB_Q#}.sys.schemas AS srt ON srt.schema_id = rt.schema_id
CROSS APPLY
(
SELECT
STUFF((SELECT N'', '' + QUOTENAME(pc.name)
FROM {#SOURCEDB_Q#}.sys.foreign_key_columns AS fkc2
JOIN {#SOURCEDB_Q#}.sys.columns AS pc ON pc.object_id = fkc2.parent_object_id AND pc.column_id = fkc2.parent_column_id
WHERE fkc2.constraint_object_id = fk.object_id
ORDER BY fkc2.constraint_column_id
FOR XML PATH(''''), TYPE).value(''.'', ''nvarchar(max)''), 1, 2, N'''') AS parent_cols,
STUFF((SELECT N'', '' + QUOTENAME(rc.name)
FROM {#SOURCEDB_Q#}.sys.foreign_key_columns AS fkc2
JOIN {#SOURCEDB_Q#}.sys.columns AS rc ON rc.object_id = fkc2.referenced_object_id AND rc.column_id = fkc2.referenced_column_id
WHERE fkc2.constraint_object_id = fk.object_id
ORDER BY fkc2.constraint_column_id
FOR XML PATH(''''), TYPE).value(''.'', ''nvarchar(max)''), 1, 2, N'''') AS ref_cols
) AS fkc
WHERE spt.name <> N''sys''
-- Exclude FK on tables matching patterns in #ExcludedObjects (parent OR referenced table)
AND NOT EXISTS (
SELECT 1 FROM #ExcludedObjects AS ex
WHERE (ex.IsWildcard = 1 AND (pt.name COLLATE DATABASE_DEFAULT LIKE ex.Pattern OR (spt.name + N''.'' + pt.name) COLLATE DATABASE_DEFAULT LIKE ex.Pattern))
OR (ex.IsWildcard = 0 AND (pt.name COLLATE DATABASE_DEFAULT = ex.Pattern OR (spt.name + N''.'' + pt.name) COLLATE DATABASE_DEFAULT = ex.Pattern))
)
AND NOT EXISTS (
SELECT 1 FROM #ExcludedObjects AS ex
WHERE (ex.IsWildcard = 1 AND (rt.name COLLATE DATABASE_DEFAULT LIKE ex.Pattern OR (srt.name + N''.'' + rt.name) COLLATE DATABASE_DEFAULT LIKE ex.Pattern))
OR (ex.IsWildcard = 0 AND (rt.name COLLATE DATABASE_DEFAULT = ex.Pattern OR (srt.name + N''.'' + rt.name) COLLATE DATABASE_DEFAULT = ex.Pattern))
);';
-- Ersetze Platzhalter durch tatsächliche Werte
SET @DYNAMICSQL = REPLACE(REPLACE(REPLACE(REPLACE(@DYNAMICSQL,
@PH_SOURCEDB_QUOTED, @SOURCEDATABASE_QUOTED),
@PH_TARGETDB_QUOTED, @TARGETDATABASE_QUOTED),
@PH_SOURCEDB, @SOURCEDATABASE),
@PH_TARGETDB, @TARGETDATABASE);
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) <= 4000 PRINT @DYNAMICSQL;
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) > 4000 PRINT LEFT(@DYNAMICSQL, 4000) + N'...(truncated)';
BEGIN TRY
EXEC sys.sp_executesql @DYNAMICSQL;
END TRY BEGIN CATCH
PRINT N'ERROR in dynamic SQL:';
PRINT @DYNAMICSQL;
THROW;
END CATCH;
----------------------------------------------------------------------------------------------------------------------------
IF @DEBUG = 1 PRINT 'DEBUG: Generating 10-Triggers commands...';
--=================================================-- 10: Table triggers --=============================================--
-- CREATE TRIGGER must be the first statement in a batch, so we use sp_executesql with target DB context
-- Robust approach: Find "CREATE...TRIGGER" pattern and insert " OR ALTER" after CREATE (if not already present)
-- Triggers in #SkippedObjects are excluded (external DB refs or dependencies on skipped objects)
-- NOTE: References to source database are replaced with target database
SET @DYNAMICSQL = N'
INSERT INTO #Commands(Phase, Command)
SELECT
N''10-Triggers'',
N''EXEC {#TARGETDB_Q#}.sys.sp_executesql N'''''' +
REPLACE(
REPLACE(
REPLACE(
-- Only add OR ALTER if not already present
CASE
WHEN PATINDEX(N''%CREATE[^A-Za-z]%OR[^A-Za-z]%ALTER[^A-Za-z]%TRIGGER[^A-Za-z]%'', m.definition + N'' '') > 0
THEN m.definition -- Already has OR ALTER, keep as is
ELSE
-- Use STUFF to insert " OR ALTER" after "CREATE" in the "CREATE...TRIGGER" pattern
STUFF(m.definition,
PATINDEX(N''%CREATE[^A-Za-z]%TRIGGER[^A-Za-z]%'', m.definition + N'' '') + 6, -- +6 = length of "CREATE"
0, -- Delete 0 characters
N'' OR ALTER'') -- Insert " OR ALTER"
END,
N''[{#SOURCEDB#}].'', N''[{#TARGETDB#}].'' -- Replace [SourceDB]. with [TargetDB].
),
N''{#SOURCEDB#}.'', N''{#TARGETDB#}.'' -- Replace SourceDB. with TargetDB. (unquoted)
),
N'''''''', N''''''''''''
) + N'''''';''
FROM {#SOURCEDB_Q#}.sys.triggers AS tr
JOIN {#SOURCEDB_Q#}.sys.objects AS o ON o.object_id = tr.object_id
JOIN {#SOURCEDB_Q#}.sys.sql_modules AS m ON m.object_id = tr.object_id
JOIN {#SOURCEDB_Q#}.sys.schemas AS s ON s.schema_id = o.schema_id
JOIN {#SOURCEDB_Q#}.sys.tables AS pt ON pt.object_id = tr.parent_id
JOIN {#SOURCEDB_Q#}.sys.schemas AS ps ON ps.schema_id = pt.schema_id
WHERE s.name <> N''sys'' AND tr.parent_id IS NOT NULL AND m.definition IS NOT NULL
AND PATINDEX(N''%CREATE[^A-Za-z]%TRIGGER[^A-Za-z]%'', m.definition + N'' '') > 0
-- Exclude triggers in #SkippedObjects (external DB refs or cascade)
AND NOT EXISTS (SELECT 1 FROM #SkippedObjects WHERE ObjectId = tr.object_id)
-- Exclude triggers on tables matching patterns in #ExcludedObjects
AND NOT EXISTS (
SELECT 1 FROM #ExcludedObjects AS ex
WHERE (ex.IsWildcard = 1 AND (pt.name COLLATE DATABASE_DEFAULT LIKE ex.Pattern OR (ps.name + N''.'' + pt.name) COLLATE DATABASE_DEFAULT LIKE ex.Pattern))
OR (ex.IsWildcard = 0 AND (pt.name COLLATE DATABASE_DEFAULT = ex.Pattern OR (ps.name + N''.'' + pt.name) COLLATE DATABASE_DEFAULT = ex.Pattern))
)
-- Also exclude triggers by their own name
AND NOT EXISTS (
SELECT 1 FROM #ExcludedObjects AS ex
WHERE (ex.IsWildcard = 1 AND (tr.name COLLATE DATABASE_DEFAULT LIKE ex.Pattern OR (s.name + N''.'' + tr.name) COLLATE DATABASE_DEFAULT LIKE ex.Pattern))
OR (ex.IsWildcard = 0 AND (tr.name COLLATE DATABASE_DEFAULT = ex.Pattern OR (s.name + N''.'' + tr.name) COLLATE DATABASE_DEFAULT = ex.Pattern))
);';
-- Ersetze Platzhalter durch tatsächliche Werte
SET @DYNAMICSQL = REPLACE(REPLACE(REPLACE(REPLACE(@DYNAMICSQL,
@PH_SOURCEDB_QUOTED, @SOURCEDATABASE_QUOTED),
@PH_TARGETDB_QUOTED, @TARGETDATABASE_QUOTED),
@PH_SOURCEDB, @SOURCEDATABASE),
@PH_TARGETDB, @TARGETDATABASE);
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) <= 4000 PRINT @DYNAMICSQL;
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) > 4000 PRINT LEFT(@DYNAMICSQL, 4000) + N'...(truncated)';
BEGIN TRY
EXEC sys.sp_executesql @DYNAMICSQL;
END TRY BEGIN CATCH
PRINT N'ERROR in dynamic SQL:';
PRINT @DYNAMICSQL;
THROW;
END CATCH;
----------------------------------------------------------------------------------------------------------------------------
IF @DEBUG = 1 PRINT 'DEBUG: Generating 11-Views commands...';
--=================================================-- 11: Views (ordered by dependency level) --=========================--
-- Use recursive CTE to determine view dependency order
-- A view may appear at multiple levels; we take MAX(dep_level) to get the correct creation order
-- CREATE VIEW must be the first statement in a batch, so we use sp_executesql with target DB context
-- NOTE: References to source database are replaced with target database
-- Views in #SkippedObjects are excluded (external DB refs or dependencies on skipped objects)
SET @DYNAMICSQL = N'
;WITH ViewDeps AS (
-- Base: Views with no dependencies on other views
SELECT v.object_id, 0 AS dep_level
FROM {#SOURCEDB_Q#}.sys.views AS v
WHERE NOT EXISTS (
SELECT 1 FROM {#SOURCEDB_Q#}.sys.sql_expression_dependencies AS d
JOIN {#SOURCEDB_Q#}.sys.views AS rv ON rv.object_id = d.referenced_id
WHERE d.referencing_id = v.object_id
)
UNION ALL
-- Recursive: Views that depend on views at the current level
SELECT v.object_id, vd.dep_level + 1
FROM {#SOURCEDB_Q#}.sys.views AS v
JOIN {#SOURCEDB_Q#}.sys.sql_expression_dependencies AS d ON d.referencing_id = v.object_id
JOIN ViewDeps AS vd ON vd.object_id = d.referenced_id
),
ViewMaxLevel AS (
SELECT object_id, MAX(dep_level) AS max_level
FROM ViewDeps
GROUP BY object_id
)
INSERT INTO #Commands(Phase, Command)
SELECT
N''11-Views'',
N''EXEC {#TARGETDB_Q#}.sys.sp_executesql N'''''' +
REPLACE(
REPLACE(
REPLACE(
N''CREATE OR ALTER VIEW '' + QUOTENAME(s.name) + N''.'' + QUOTENAME(v.name) + N'' '' +
-- Extract everything after the view name (AS SELECT... or WITH ...)
LTRIM(SUBSTRING(m.definition, body_pos.pos, LEN(m.definition))),
N''[{#SOURCEDB#}].'', N''[{#TARGETDB#}].'' -- Replace [SourceDB]. with [TargetDB].
),
N''{#SOURCEDB#}.'', N''{#TARGETDB#}.'' -- Replace SourceDB. with TargetDB. (unquoted)
),
N'''''''', N''''''''''''
) + N'''''';''
FROM {#SOURCEDB_Q#}.sys.views AS v
JOIN {#SOURCEDB_Q#}.sys.sql_modules AS m ON m.object_id = v.object_id
JOIN {#SOURCEDB_Q#}.sys.schemas AS s ON s.schema_id = v.schema_id
LEFT JOIN ViewMaxLevel AS vml ON vml.object_id = v.object_id
CROSS APPLY (
-- Find position of view name (quoted or unquoted) in definition
SELECT COALESCE(
NULLIF(CHARINDEX(QUOTENAME(v.name), m.definition), 0),
NULLIF(CHARINDEX(v.name, m.definition), 0),
1
) AS name_pos
) AS name_search
CROSS APPLY (
-- Find position after view name: look for WITH or AS keyword after the view name
SELECT
name_search.name_pos + LEN(v.name) - 1 +
CASE
WHEN PATINDEX(N''%[^A-Za-z0-9_]WITH[^A-Za-z0-9_]%'', UPPER(SUBSTRING(m.definition, name_search.name_pos + LEN(v.name), 500))) > 0
AND PATINDEX(N''%[^A-Za-z0-9_]WITH[^A-Za-z0-9_]%'', UPPER(SUBSTRING(m.definition, name_search.name_pos + LEN(v.name), 500)))
< ISNULL(NULLIF(PATINDEX(N''%[^A-Za-z0-9_]AS[^A-Za-z0-9_]%'', UPPER(SUBSTRING(m.definition, name_search.name_pos + LEN(v.name), 500))), 0), 999999)
THEN PATINDEX(N''%[^A-Za-z0-9_]WITH[^A-Za-z0-9_]%'', UPPER(SUBSTRING(m.definition, name_search.name_pos + LEN(v.name), 500)))
WHEN PATINDEX(N''%[^A-Za-z0-9_]AS[^A-Za-z0-9_]%'', UPPER(SUBSTRING(m.definition, name_search.name_pos + LEN(v.name), 500))) > 0
THEN PATINDEX(N''%[^A-Za-z0-9_]AS[^A-Za-z0-9_]%'', UPPER(SUBSTRING(m.definition, name_search.name_pos + LEN(v.name), 500)))
ELSE 1
END AS pos
) AS body_pos
WHERE s.name <> N''sys''
-- Exclude views in #SkippedObjects (external DB refs or cascade)
AND NOT EXISTS (SELECT 1 FROM #SkippedObjects WHERE ObjectId = v.object_id)
-- Exclude views matching patterns in #ExcludedObjects
AND NOT EXISTS (
SELECT 1 FROM #ExcludedObjects AS ex
WHERE (ex.IsWildcard = 1 AND (v.name COLLATE DATABASE_DEFAULT LIKE ex.Pattern OR (s.name + N''.'' + v.name) COLLATE DATABASE_DEFAULT LIKE ex.Pattern))
OR (ex.IsWildcard = 0 AND (v.name COLLATE DATABASE_DEFAULT = ex.Pattern OR (s.name + N''.'' + v.name) COLLATE DATABASE_DEFAULT = ex.Pattern))
)
ORDER BY ISNULL(vml.max_level, 999)
OPTION (MAXRECURSION 0);';
-- Ersetze Platzhalter durch tatsächliche Werte
SET @DYNAMICSQL = REPLACE(REPLACE(REPLACE(REPLACE(@DYNAMICSQL,
@PH_SOURCEDB_QUOTED, @SOURCEDATABASE_QUOTED),
@PH_TARGETDB_QUOTED, @TARGETDATABASE_QUOTED),
@PH_SOURCEDB, @SOURCEDATABASE),
@PH_TARGETDB, @TARGETDATABASE);
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) <= 4000 PRINT @DYNAMICSQL;
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) > 4000 PRINT LEFT(@DYNAMICSQL, 4000) + N'...(truncated)';
BEGIN TRY
EXEC sys.sp_executesql @DYNAMICSQL;
END TRY BEGIN CATCH
PRINT N'ERROR in dynamic SQL:';
PRINT @DYNAMICSQL;
THROW;
END CATCH;
----------------------------------------------------------------------------------------------------------------------------
IF @DEBUG = 1 PRINT 'DEBUG: Generating 12-Functions commands...';
--=================================================-- 12: Functions (ordered by dependency level) --=====================--
-- Use recursive CTE to determine function dependency order
-- A function may appear at multiple levels; we take MAX(dep_level) to get the correct creation order
-- CREATE FUNCTION must be the first statement in a batch, so we use sp_executesql with target DB context
-- NOTE: References to source database are replaced with target database
-- NOTE: Functions with external DB refs OR cascade dependencies are already in #SkippedObjects
SET @DYNAMICSQL = N'
;WITH FuncDeps AS (
-- Base: Functions with no dependencies on other functions
SELECT o.object_id, 0 AS dep_level
FROM {#SOURCEDB_Q#}.sys.objects AS 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 AS d
JOIN {#SOURCEDB_Q#}.sys.objects AS 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
-- Recursive: Functions that depend on functions at the current level
SELECT o.object_id, fd.dep_level + 1
FROM {#SOURCEDB_Q#}.sys.objects AS o
JOIN {#SOURCEDB_Q#}.sys.sql_expression_dependencies AS d ON d.referencing_id = o.object_id
JOIN FuncDeps AS fd ON fd.object_id = d.referenced_id
WHERE o.[type] IN (N''FN'',N''TF'',N''IF'',N''FS'',N''FT'')
),
FuncMaxLevel AS (
SELECT object_id, MAX(dep_level) AS max_level
FROM FuncDeps
GROUP BY object_id
)
INSERT INTO #Commands(Phase, Command)
SELECT
N''12-Functions'',
N''EXEC {#TARGETDB_Q#}.sys.sp_executesql N'''''' +
REPLACE(
REPLACE(
REPLACE(
N''CREATE OR ALTER FUNCTION '' + QUOTENAME(s.name) + N''.'' + QUOTENAME(o.name) + N'' '' +
-- Extract everything after the function name (parameters and body)
LTRIM(SUBSTRING(m.definition, body_pos.pos, LEN(m.definition))),
N''[{#SOURCEDB#}].'', N''[{#TARGETDB#}].'' -- Replace [SourceDB]. with [TargetDB].
),
N''{#SOURCEDB#}.'', N''{#TARGETDB#}.'' -- Replace SourceDB. with TargetDB. (unquoted)
),
N'''''''', N''''''''''''
) + N'''''';''
FROM {#SOURCEDB_Q#}.sys.objects AS o
JOIN {#SOURCEDB_Q#}.sys.sql_modules AS m ON m.object_id = o.object_id
JOIN {#SOURCEDB_Q#}.sys.schemas AS s ON s.schema_id = o.schema_id
LEFT JOIN FuncMaxLevel AS fml ON fml.object_id = o.object_id
CROSS APPLY (
-- Find position of function name (quoted or unquoted) in definition
SELECT COALESCE(
NULLIF(CHARINDEX(QUOTENAME(o.name), m.definition), 0),
NULLIF(CHARINDEX(o.name, m.definition), 0),
1
) AS name_pos
) AS name_search
CROSS APPLY (
-- Find position of opening parenthesis AFTER the function name
-- This avoids false positives from comments or schema names before the function
SELECT name_search.name_pos + LEN(o.name) - 1 +
ISNULL(NULLIF(CHARINDEX(N''('', SUBSTRING(m.definition, name_search.name_pos + LEN(o.name), 500)), 0), 1) AS pos
) AS body_pos
WHERE s.name <> N''sys'' AND o.[type] IN (N''FN'',N''TF'',N''IF'',N''FS'',N''FT'') AND body_pos.pos > name_search.name_pos
-- EXCLUDE functions in #SkippedObjects (external DB refs or cascade dependencies)
AND NOT EXISTS (SELECT 1 FROM #SkippedObjects WHERE ObjectId = o.object_id)
-- Exclude functions matching patterns in #ExcludedObjects
AND NOT EXISTS (
SELECT 1 FROM #ExcludedObjects AS ex
WHERE (ex.IsWildcard = 1 AND (o.name COLLATE DATABASE_DEFAULT LIKE ex.Pattern OR (s.name + N''.'' + o.name) COLLATE DATABASE_DEFAULT LIKE ex.Pattern))
OR (ex.IsWildcard = 0 AND (o.name COLLATE DATABASE_DEFAULT = ex.Pattern OR (s.name + N''.'' + o.name) COLLATE DATABASE_DEFAULT = ex.Pattern))
)
ORDER BY ISNULL(fml.max_level, 999)
OPTION (MAXRECURSION 0);';
-- Ersetze Platzhalter durch tatsächliche Werte
SET @DYNAMICSQL = REPLACE(REPLACE(REPLACE(REPLACE(@DYNAMICSQL,
@PH_SOURCEDB_QUOTED, @SOURCEDATABASE_QUOTED),
@PH_TARGETDB_QUOTED, @TARGETDATABASE_QUOTED),
@PH_SOURCEDB, @SOURCEDATABASE),
@PH_TARGETDB, @TARGETDATABASE);
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) <= 4000 PRINT @DYNAMICSQL;
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) > 4000 PRINT LEFT(@DYNAMICSQL, 4000) + N'...(truncated)';
BEGIN TRY
EXEC sys.sp_executesql @DYNAMICSQL;
END TRY BEGIN CATCH
PRINT N'ERROR in dynamic SQL:';
PRINT @DYNAMICSQL;
THROW;
END CATCH;
----------------------------------------------------------------------------------------------------------------------------
IF @DEBUG = 1 PRINT 'DEBUG: Generating 13-Procedures commands...';
--=================================================-- 13: Stored procedures --==========================================--
-- CREATE PROCEDURE must be the first statement in a batch, so we use sp_executesql with target DB context
-- NOTE: References to source database are replaced with target database
-- NOTE: Procedures with external DB refs OR cascade dependencies are already in #SkippedObjects
-- Approach: Use STUFF to replace original CREATE PROCEDURE header with CREATE OR ALTER PROCEDURE [schema].[name]
-- Robust: Search for procedure name AFTER the PROC/PROCEDURE keyword to handle comments and varying whitespace
SET @DYNAMICSQL = N'
INSERT INTO #Commands(Phase, Command)
SELECT
N''13-Procedures'',
N''EXEC {#TARGETDB_Q#}.sys.sp_executesql N'''''' +
REPLACE(
REPLACE(
REPLACE(
-- Use STUFF to replace from position 1 up to end of procedure name with new header
STUFF(
m.definition,
1,
-- Length to replace: from start to end of procedure name (searching AFTER "PROC" keyword - covers PROC and PROCEDURE)
CASE
-- First try: find [Name] after PROC keyword
WHEN CHARINDEX(QUOTENAME(p.name), m.definition, PATINDEX(N''%[^A-Za-z]PROC[^A-Za-z]%'', UPPER(N'' '' + m.definition))) > 0
THEN CHARINDEX(QUOTENAME(p.name), m.definition, PATINDEX(N''%[^A-Za-z]PROC[^A-Za-z]%'', UPPER(N'' '' + m.definition))) + LEN(QUOTENAME(p.name)) - 1
-- Fallback: find unquoted Name after PROC keyword
ELSE CHARINDEX(p.name, m.definition, PATINDEX(N''%[^A-Za-z]PROC[^A-Za-z]%'', UPPER(N'' '' + m.definition)) + 4) + LEN(p.name) - 1
END,
-- New header (replaces everything from CREATE to proc name)
N''CREATE OR ALTER PROCEDURE '' + QUOTENAME(s.name) + N''.'' + QUOTENAME(p.name)
),
N''[{#SOURCEDB#}].'', N''[{#TARGETDB#}].''
),
N''{#SOURCEDB#}.'', N''{#TARGETDB#}.''
),
N'''''''', N''''''''''''
) + N'''''';''
FROM {#SOURCEDB_Q#}.sys.procedures AS p
JOIN {#SOURCEDB_Q#}.sys.sql_modules AS m ON m.object_id = p.object_id
JOIN {#SOURCEDB_Q#}.sys.schemas AS s ON s.schema_id = p.schema_id
WHERE s.name <> N''sys''
-- EXCLUDE procedures in #SkippedObjects (external DB refs or cascade dependencies)
AND NOT EXISTS (SELECT 1 FROM #SkippedObjects WHERE ObjectId = p.object_id)
-- Exclude procedures matching patterns in #ExcludedObjects
AND NOT EXISTS (
SELECT 1 FROM #ExcludedObjects AS ex
WHERE (ex.IsWildcard = 1 AND (p.name COLLATE DATABASE_DEFAULT LIKE ex.Pattern OR (s.name + N''.'' + p.name) COLLATE DATABASE_DEFAULT LIKE ex.Pattern))
OR (ex.IsWildcard = 0 AND (p.name COLLATE DATABASE_DEFAULT = ex.Pattern OR (s.name + N''.'' + p.name) COLLATE DATABASE_DEFAULT = ex.Pattern))
);';
-- Ersetze Platzhalter durch tatsächliche Werte
SET @DYNAMICSQL = REPLACE(REPLACE(REPLACE(REPLACE(@DYNAMICSQL,
@PH_SOURCEDB_QUOTED, @SOURCEDATABASE_QUOTED),
@PH_TARGETDB_QUOTED, @TARGETDATABASE_QUOTED),
@PH_SOURCEDB, @SOURCEDATABASE),
@PH_TARGETDB, @TARGETDATABASE);
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) <= 4000 PRINT @DYNAMICSQL;
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) > 4000 PRINT LEFT(@DYNAMICSQL, 4000) + N'...(truncated)';
BEGIN TRY
EXEC sys.sp_executesql @DYNAMICSQL;
END TRY BEGIN CATCH
PRINT N'ERROR in dynamic SQL:';
PRINT @DYNAMICSQL;
THROW;
END CATCH;
----------------------------------------------------------------------------------------------------------------------------
IF @DEBUG = 1 PRINT 'DEBUG: Generating 14-Statistics commands...';
--=================================================-- 14: User-created statistics --====================================--
SET @DYNAMICSQL = N'
INSERT INTO #Commands(Phase, Command)
SELECT
N''14-Statistics'',
N''USE {#TARGETDB_Q#}; CREATE STATISTICS '' + QUOTENAME(st.name) +
N'' ON '' + QUOTENAME(s.name) + N''.'' + QUOTENAME(t.name) +
N'' ('' + cols.stats_columns + N'')'' +
CASE WHEN st.has_filter = 1 THEN N'' WHERE '' + REPLACE(REPLACE(st.filter_definition, N''[{#SOURCEDB#}].'', N''[{#TARGETDB#}].''), N''{#SOURCEDB#}.'', N''{#TARGETDB#}.'' ) ELSE N'''' END +
CASE WHEN (st.no_recompute = 1 OR st.is_incremental = 1) THEN
N'' WITH '' +
STUFF(
(CASE WHEN st.no_recompute = 1 THEN N'', NORECOMPUTE'' ELSE N'''' END) +
(CASE WHEN st.is_incremental = 1 THEN N'', INCREMENTAL = ON'' ELSE N'''' END),
1, 2, N''''
)
ELSE N'''' END +
N'';''
FROM {#SOURCEDB_Q#}.sys.stats AS st
JOIN {#SOURCEDB_Q#}.sys.tables AS t ON t.object_id = st.object_id
JOIN {#SOURCEDB_Q#}.sys.schemas AS s ON s.schema_id = t.schema_id
LEFT JOIN {#SOURCEDB_Q#}.sys.indexes AS i ON i.object_id = st.object_id AND i.index_id = st.stats_id
CROSS APPLY
(
SELECT STUFF((
SELECT N'', '' + QUOTENAME(c.name)
FROM {#SOURCEDB_Q#}.sys.stats_columns AS sc
JOIN {#SOURCEDB_Q#}.sys.columns AS c ON c.object_id = sc.object_id AND c.column_id = sc.column_id
WHERE sc.object_id = st.object_id AND sc.stats_id = st.stats_id
ORDER BY sc.stats_column_id
FOR XML PATH(''''), TYPE
).value(''.'', ''nvarchar(max)''), 1, 2, N'''') AS stats_columns
) AS cols
WHERE i.index_id IS NULL -- only user-created stats
AND st.user_created = 1
AND s.name <> N''sys''
-- Exclude statistics on tables matching patterns in #ExcludedObjects
AND NOT EXISTS (
SELECT 1 FROM #ExcludedObjects AS ex
WHERE (ex.IsWildcard = 1 AND (t.name COLLATE DATABASE_DEFAULT LIKE ex.Pattern OR (s.name + N''.'' + t.name) COLLATE DATABASE_DEFAULT LIKE ex.Pattern))
OR (ex.IsWildcard = 0 AND (t.name COLLATE DATABASE_DEFAULT = ex.Pattern OR (s.name + N''.'' + t.name) COLLATE DATABASE_DEFAULT = ex.Pattern))
);';
-- Ersetze Platzhalter durch tatsächliche Werte
SET @DYNAMICSQL = REPLACE(REPLACE(REPLACE(REPLACE(@DYNAMICSQL,
@PH_SOURCEDB_QUOTED, @SOURCEDATABASE_QUOTED),
@PH_TARGETDB_QUOTED, @TARGETDATABASE_QUOTED),
@PH_SOURCEDB, @SOURCEDATABASE),
@PH_TARGETDB, @TARGETDATABASE);
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) <= 4000 PRINT @DYNAMICSQL;
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) > 4000 PRINT LEFT(@DYNAMICSQL, 4000) + N'...(truncated)';
BEGIN TRY
EXEC sys.sp_executesql @DYNAMICSQL;
END TRY BEGIN CATCH
PRINT N'ERROR in dynamic SQL:';
PRINT @DYNAMICSQL;
THROW;
END CATCH;
----------------------------------------------------------------------------------------------------------------------------
IF @DEBUG = 1 PRINT 'DEBUG: Generating 15-Synonyms commands...';
--=================================================-- 15: Synonyms --===================================================--
-- NOTE: Synonyms pointing to external databases (other than source) are skipped
-- PARSENAME automatically removes brackets, so we only compare unquoted names
-- NOTE: Synonyms pointing to source DB are included; base_object_name used as-is
SET @DYNAMICSQL = N'
DECLARE @SYN_SCHEMA SYSNAME, @SYN_NAME SYSNAME, @SYN_TARGET NVARCHAR(1035);
DECLARE syn_cursor CURSOR LOCAL FAST_FORWARD FOR
SELECT s.name, sn.name, sn.base_object_name
FROM {#SOURCEDB_Q#}.sys.synonyms AS sn
JOIN {#SOURCEDB_Q#}.sys.schemas AS s ON s.schema_id = sn.schema_id
WHERE s.name <> N''sys''
AND (PARSENAME(sn.base_object_name, 3) IS NULL OR PARSENAME(sn.base_object_name, 3) = N''{#SOURCEDB#}'')
AND NOT EXISTS (
SELECT 1 FROM #ExcludedObjects AS ex
WHERE (ex.IsWildcard = 1 AND (sn.name COLLATE DATABASE_DEFAULT LIKE ex.Pattern OR (s.name + N''.'' + sn.name) COLLATE DATABASE_DEFAULT LIKE ex.Pattern))
OR (ex.IsWildcard = 0 AND (sn.name COLLATE DATABASE_DEFAULT = ex.Pattern OR (s.name + N''.'' + sn.name) COLLATE DATABASE_DEFAULT = ex.Pattern))
);
OPEN syn_cursor;
FETCH NEXT FROM syn_cursor INTO @SYN_SCHEMA, @SYN_NAME, @SYN_TARGET;
WHILE @@FETCH_STATUS = 0
BEGIN
-- base_object_name wird direkt verwendet - kein Escaping nötig da EXEC() verwendet wird
INSERT INTO #Commands(Phase, Command)
VALUES (N''15-Synonyms'', N''USE {#TARGETDB_Q#}; CREATE SYNONYM '' + QUOTENAME(@SYN_SCHEMA) + N''.'' + QUOTENAME(@SYN_NAME) + N'' FOR '' + @SYN_TARGET + N'';'');
FETCH NEXT FROM syn_cursor INTO @SYN_SCHEMA, @SYN_NAME, @SYN_TARGET;
END;
CLOSE syn_cursor;
DEALLOCATE syn_cursor;';
-- Ersetze Platzhalter durch tatsächliche Werte
SET @DYNAMICSQL = REPLACE(REPLACE(REPLACE(REPLACE(@DYNAMICSQL,
@PH_SOURCEDB_QUOTED, @SOURCEDATABASE_QUOTED),
@PH_TARGETDB_QUOTED, @TARGETDATABASE_QUOTED),
@PH_SOURCEDB, @SOURCEDATABASE),
@PH_TARGETDB, @TARGETDATABASE);
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) <= 4000 PRINT @DYNAMICSQL;
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) > 4000 PRINT LEFT(@DYNAMICSQL, 4000) + N'...(truncated)';
BEGIN TRY
EXEC sys.sp_executesql @DYNAMICSQL;
END TRY BEGIN CATCH
PRINT N'ERROR in dynamic SQL:';
PRINT @DYNAMICSQL;
THROW;
END CATCH;
-- Log warnings for skipped synonyms with external DB references (using cursor approach)
SET @DYNAMICSQL = N'
DECLARE @SYN_SCHEMA SYSNAME, @SYN_NAME SYSNAME, @SYN_TARGET NVARCHAR(1035);
DECLARE syn_warn_cursor CURSOR LOCAL FAST_FORWARD FOR
SELECT s.name, sn.name, sn.base_object_name
FROM {#SOURCEDB_Q#}.sys.synonyms AS sn
JOIN {#SOURCEDB_Q#}.sys.schemas AS s ON s.schema_id = sn.schema_id
WHERE s.name <> N''sys''
AND PARSENAME(sn.base_object_name, 3) IS NOT NULL
AND PARSENAME(sn.base_object_name, 3) <> N''{#SOURCEDB#}'';
OPEN syn_warn_cursor;
FETCH NEXT FROM syn_warn_cursor INTO @SYN_SCHEMA, @SYN_NAME, @SYN_TARGET;
WHILE @@FETCH_STATUS = 0
BEGIN
INSERT INTO #Commands(Phase, Command)
VALUES (N''15-Synonyms-WARN'', N''PRINT N''''WARN: Synonym '' + QUOTENAME(@SYN_SCHEMA) + N''.'' + QUOTENAME(@SYN_NAME) + N'' points to external database and was SKIPPED: '' + @SYN_TARGET + N'''''';'');
FETCH NEXT FROM syn_warn_cursor INTO @SYN_SCHEMA, @SYN_NAME, @SYN_TARGET;
END;
CLOSE syn_warn_cursor;
DEALLOCATE syn_warn_cursor;';
-- Ersetze Platzhalter durch tatsächliche Werte
SET @DYNAMICSQL = REPLACE(REPLACE(REPLACE(REPLACE(@DYNAMICSQL,
@PH_SOURCEDB_QUOTED, @SOURCEDATABASE_QUOTED),
@PH_TARGETDB_QUOTED, @TARGETDATABASE_QUOTED),
@PH_SOURCEDB, @SOURCEDATABASE),
@PH_TARGETDB, @TARGETDATABASE);
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) <= 4000 PRINT @DYNAMICSQL;
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) > 4000 PRINT LEFT(@DYNAMICSQL, 4000) + N'...(truncated)';
BEGIN TRY
EXEC sys.sp_executesql @DYNAMICSQL;
END TRY BEGIN CATCH
PRINT N'ERROR in dynamic SQL:';
PRINT @DYNAMICSQL;
THROW;
END CATCH;
----------------------------------------------------------------------------------------------------------------------------
--=================================================-- 99: Finalize (Set FULL recovery model, restore source access) --===--
INSERT INTO #Commands(Phase, Command)
VALUES
(N'99-Finalize', N'USE [master]; ALTER DATABASE {#TARGETDB_Q#} SET RECOVERY FULL;');
-- Restore source database to original user access mode
INSERT INTO #Commands(Phase, Command)
VALUES
(N'99-Finalize', N'USE [master]; ALTER DATABASE {#SOURCEDB_Q#} SET ' + ISNULL(@SOURCE_USER_ACCESS_ORIGINAL, N'MULTI_USER') + N';');
----------------------------------------------------------------------------------------------------------------------------
--=================================================-- Output plan --====================================================--
-- Replace placeholders in all commands before output/execution
UPDATE #Commands SET Command = REPLACE(REPLACE(REPLACE(REPLACE(REPLACE(Command,
@PH_SOURCEDB_QUOTED, @SOURCEDATABASE_QUOTED),
@PH_TARGETDB_QUOTED, @TARGETDATABASE_QUOTED),
@PH_SOURCEDB, @SOURCEDATABASE),
@PH_TARGETDB, @TARGETDATABASE),
@PH_BATCHSIZE, CONVERT(NVARCHAR(20), @BATCHSIZE));
IF @DEBUG = 1 PRINT 'DEBUG: Placeholders in #Commands replaced with actual database names.';
-- Filter commands based on MODE
-- FULL: All phases
-- SCHEMA: All phases except 04-Data and 04a-ShrinkTempdb
-- DATA: Only 04-Data and 04a-ShrinkTempdb (target DB must exist)
SELECT Step, Phase, Command
FROM #Commands
WHERE (@MODE = 'FULL')
OR (@MODE = 'SCHEMA' AND Phase NOT IN ('04-Data', '04a-ShrinkTempdb'))
OR (@MODE = 'DATA' AND Phase IN ('04-Data', '04a-ShrinkTempdb'))
ORDER BY Step;
----------------------------------------------------------------------------------------------------------------------------
--=================================================-- Pre-Validation (compile all commands without execution) --=========--
IF @PREVALIDATE = 1 AND @EXECUTECOMMANDS = 1 BEGIN
PRINT '';
PRINT '=================================================================';
PRINT '=== PRE-VALIDATION: Checking SQL syntax of all commands... ===';
PRINT '=================================================================';
PRINT '';
-- Create temp table for validation errors
CREATE TABLE #PreValidationErrors
(
Step INT NOT NULL,
Phase NVARCHAR(50) NOT NULL,
ErrorNumber INT NOT NULL,
ErrorMessage NVARCHAR(4000) NOT NULL,
Command NVARCHAR(MAX) NOT NULL
);
DECLARE @PREVAL_STEP INT = NULL;
DECLARE @PREVAL_PHASE NVARCHAR(50) = NULL;
DECLARE @PREVAL_COMMAND NVARCHAR(MAX) = NULL;
DECLARE @PREVAL_ERRORS INT = 0;
DECLARE @PREVAL_TOTAL INT = 0;
DECLARE @PREVAL_SKIPPED INT = 0;
DECLARE @PREVAL_ERRNUM INT = NULL;
DECLARE @PREVAL_ERRMSG NVARCHAR(4000) = NULL;
-- Cursor through all commands to validate
DECLARE preval_cur CURSOR FAST_FORWARD FOR
SELECT Step, Phase, Command
FROM #Commands
WHERE (@MODE = 'FULL')
OR (@MODE = 'SCHEMA' AND Phase NOT IN ('04-Data', '04a-ShrinkTempdb'))
OR (@MODE = 'DATA' AND Phase IN ('04-Data', '04a-ShrinkTempdb'))
ORDER BY Step;
OPEN preval_cur;
FETCH NEXT FROM preval_cur INTO @PREVAL_STEP, @PREVAL_PHASE, @PREVAL_COMMAND;
WHILE @@FETCH_STATUS = 0 BEGIN
SET @PREVAL_TOTAL = @PREVAL_TOTAL + 1;
-- Skip certain phases that cannot be pre-validated:
-- - 00-DropTarget: DROP/ALTER DATABASE cannot be validated
-- - 01-CreateDb: CREATE DATABASE cannot run in a transaction
-- - 99-Finalize: ALTER DATABASE statements may fail without proper context
-- - 04-Data: INSERT statements may reference tables that don't exist yet
-- - 15-Synonyms-WARN: Only PRINT statements, no SQL to validate
-- - Phases that depend on previous phases having run successfully
IF @PREVAL_PHASE IN (N'00-DropTarget', N'01-CreateDb', N'99-Finalize', N'04-Data', N'04a-ShrinkTempdb', N'15-Synonyms-WARN') BEGIN
SET @PREVAL_SKIPPED = @PREVAL_SKIPPED + 1;
IF @DEBUG = 1 PRINT N'DEBUG: Skipping pre-validation for ' + @PREVAL_PHASE + N' (cannot be validated before dependent objects exist)';
END
ELSE BEGIN
-- Use SET PARSEONLY to check SQL syntax without execution
-- PARSEONLY validates T-SQL syntax but doesn't verify object existence
-- This catches syntax errors like malformed statements, incorrect escaping, etc.
BEGIN TRY
DECLARE @PREVAL_WRAPPER NVARCHAR(MAX);
DECLARE @PREVAL_COMMAND_MODIFIED NVARCHAR(MAX);
-- For syntax validation, replace USE [TargetDB] with USE [SourceDB]
-- This allows validation even when target database doesn't exist yet
-- The source database structure is identical, so syntax errors will be caught
SET @PREVAL_COMMAND_MODIFIED = REPLACE(@PREVAL_COMMAND, N'USE ' + @TARGETDATABASE_QUOTED, N'USE ' + @SOURCEDATABASE_QUOTED);
-- Method 1: SET PARSEONLY ON - validates basic T-SQL syntax
-- This will catch: syntax errors, malformed quotes, incorrect keywords
-- This will NOT catch: missing objects, wrong column names (those need runtime)
SET @PREVAL_WRAPPER = N'SET PARSEONLY ON; ' + @PREVAL_COMMAND_MODIFIED;
EXEC sys.sp_executesql @PREVAL_WRAPPER;
IF @DEBUG = 1 PRINT N'DEBUG: Step ' + CONVERT(NVARCHAR(10), @PREVAL_STEP) + N' (' + @PREVAL_PHASE + N') - Syntax OK';
END TRY
BEGIN CATCH
SET @PREVAL_ERRNUM = ERROR_NUMBER();
SET @PREVAL_ERRMSG = ERROR_MESSAGE();
-- Insert error into tracking table
INSERT INTO #PreValidationErrors (Step, Phase, ErrorNumber, ErrorMessage, Command)
VALUES (@PREVAL_STEP, @PREVAL_PHASE, @PREVAL_ERRNUM, @PREVAL_ERRMSG, @PREVAL_COMMAND);
SET @PREVAL_ERRORS = @PREVAL_ERRORS + 1;
PRINT N'ERROR: Step ' + CONVERT(NVARCHAR(10), @PREVAL_STEP) + N' (' + @PREVAL_PHASE + N'): ' + @PREVAL_ERRMSG;
IF @DEBUG = 1 BEGIN
PRINT N'DEBUG: Failed command (first 2000 chars):';
PRINT LEFT(@PREVAL_COMMAND, 2000);
END;
END CATCH;
END;
FETCH NEXT FROM preval_cur INTO @PREVAL_STEP, @PREVAL_PHASE, @PREVAL_COMMAND;
END;
CLOSE preval_cur;
DEALLOCATE preval_cur;
-- Summary
PRINT '';
PRINT '=================================================================';
PRINT N'=== PRE-VALIDATION SUMMARY ===';
PRINT '=================================================================';
PRINT N'Total commands: ' + CONVERT(NVARCHAR(10), @PREVAL_TOTAL);
PRINT N'Validated: ' + CONVERT(NVARCHAR(10), @PREVAL_TOTAL - @PREVAL_SKIPPED);
PRINT N'Skipped: ' + CONVERT(NVARCHAR(10), @PREVAL_SKIPPED) + N' (CREATE/ALTER DATABASE statements)';
PRINT N'Errors found: ' + CONVERT(NVARCHAR(10), @PREVAL_ERRORS);
PRINT '=================================================================';
PRINT '';
-- If errors were found, output detailed error list and abort
IF @PREVAL_ERRORS > 0 BEGIN
PRINT N'PRE-VALIDATION FAILED - The following commands have syntax errors:';
PRINT '';
-- Output all errors with details
DECLARE @ERR_STEP INT, @ERR_PHASE NVARCHAR(50), @ERR_NUM INT, @ERR_MSG NVARCHAR(4000), @ERR_CMD NVARCHAR(MAX);
DECLARE err_cur CURSOR FAST_FORWARD FOR
SELECT Step, Phase, ErrorNumber, ErrorMessage, Command FROM #PreValidationErrors ORDER BY Step;
OPEN err_cur;
FETCH NEXT FROM err_cur INTO @ERR_STEP, @ERR_PHASE, @ERR_NUM, @ERR_MSG, @ERR_CMD;
WHILE @@FETCH_STATUS = 0 BEGIN
PRINT N'─────────────────────────────────────────────────────────────';
PRINT N'Step ' + CONVERT(NVARCHAR(10), @ERR_STEP) + N' (' + @ERR_PHASE + N')';
PRINT N'Error ' + CONVERT(NVARCHAR(10), @ERR_NUM) + N': ' + @ERR_MSG;
PRINT N'Command (first 4000 chars):';
PRINT LEFT(@ERR_CMD, 4000);
IF LEN(@ERR_CMD) > 4000 PRINT N'... (truncated, total ' + CONVERT(NVARCHAR(20), LEN(@ERR_CMD)) + N' chars)';
PRINT '';
FETCH NEXT FROM err_cur INTO @ERR_STEP, @ERR_PHASE, @ERR_NUM, @ERR_MSG, @ERR_CMD;
END;
CLOSE err_cur;
DEALLOCATE err_cur;
-- Log pre-validation failure
IF (@LOGLEVEL IN ('INFO', 'WARN', 'ERROR')) BEGIN
INSERT INTO [dbo].[TBDD_MIGRATE_DATABASE_LOG]
([RUN_ID], [LOG_LEVEL], [SOURCE_DATABASE], [TARGET_DATABASE], [NEW_COLLATION], [MESSAGE], [ERROR_MESSAGE], [ADDED_WHO], [ADDED_WHEN])
VALUES
(@RUN_ID, 'ERROR', @SOURCEDATABASE, @TARGETDATABASE, @NEWCOLLATION,
'Pre-validation FAILED - ' + CONVERT(NVARCHAR(10), @PREVAL_ERRORS) + ' syntax errors found',
'Migration aborted before execution due to pre-validation errors', @MY_PROCEDURE_NAME, GETDATE());
END;
-- Cleanup temp tables
DROP TABLE #PreValidationErrors;
-- Restore source database to original access mode before aborting
BEGIN TRY
SET @DYNAMICSQL = N'ALTER DATABASE ' + @SOURCEDATABASE_QUOTED + N' SET ' + ISNULL(@SOURCE_USER_ACCESS_ORIGINAL, N'MULTI_USER') + N';';
IF @DEBUG = 1 PRINT @DYNAMICSQL;
EXEC sys.sp_executesql @DYNAMICSQL;
PRINT 'INFO: Source database restored to ' + ISNULL(@SOURCE_USER_ACCESS_ORIGINAL, 'MULTI_USER') + ' mode.';
END TRY BEGIN CATCH
PRINT 'WARN: Could not restore source database: ' + ERROR_MESSAGE();
END CATCH;
-- Cleanup
IF OBJECT_ID('tempdb..#Commands') IS NOT NULL DROP TABLE #Commands;
IF OBJECT_ID('tempdb..#ExcludedObjects') IS NOT NULL DROP TABLE #ExcludedObjects;
IF OBJECT_ID('tempdb..#SkippedObjects') IS NOT NULL DROP TABLE #SkippedObjects;
RAISERROR(N'Pre-validation failed with %d syntax error(s). Migration aborted. Please fix the errors and try again.', 16, 1, @PREVAL_ERRORS);
RETURN 1;
END;
-- Pre-validation passed
PRINT N'PRE-VALIDATION PASSED - All commands have valid SQL syntax.';
PRINT N'Proceeding with execution...';
PRINT '';
-- Log pre-validation success
IF (@LOGLEVEL IN ('INFO')) BEGIN
INSERT INTO [dbo].[TBDD_MIGRATE_DATABASE_LOG]
([RUN_ID], [LOG_LEVEL], [SOURCE_DATABASE], [TARGET_DATABASE], [NEW_COLLATION], [MESSAGE], [ADDED_WHO], [ADDED_WHEN])
VALUES
(@RUN_ID, 'INFO', @SOURCEDATABASE, @TARGETDATABASE, @NEWCOLLATION,
'Pre-validation PASSED - ' + CONVERT(NVARCHAR(10), @PREVAL_TOTAL - @PREVAL_SKIPPED) + ' commands validated', @MY_PROCEDURE_NAME, GETDATE());
END;
-- Cleanup
DROP TABLE #PreValidationErrors;
END;
----------------------------------------------------------------------------------------------------------------------------
--=================================================-- Execute plan --===================================================--
IF @EXECUTECOMMANDS = 1 BEGIN
-- Log execution start
IF (@LOGLEVEL IN ('INFO')) BEGIN
INSERT INTO [dbo].[TBDD_MIGRATE_DATABASE_LOG] ([RUN_ID], [LOG_LEVEL], [SOURCE_DATABASE], [TARGET_DATABASE], [NEW_COLLATION], [MESSAGE], [ADDED_WHO], [ADDED_WHEN])
VALUES (@RUN_ID, 'INFO', @SOURCEDATABASE, @TARGETDATABASE, @NEWCOLLATION, 'Starting execution of migration plan', @MY_PROCEDURE_NAME, GETDATE());
END;
DECLARE cmd_cur CURSOR FAST_FORWARD FOR
SELECT Step, Phase, Command
FROM #Commands
WHERE (@MODE = 'FULL')
OR (@MODE = 'SCHEMA' AND Phase NOT IN ('04-Data', '04a-ShrinkTempdb'))
OR (@MODE = 'DATA' AND Phase IN ('04-Data', '04a-ShrinkTempdb'))
ORDER BY Step;
OPEN cmd_cur;
FETCH NEXT FROM cmd_cur INTO @CURRENTSTEP, @CURRENTPHASE, @CURRENTCOMMAND;
IF @DEBUG = 1 PRINT 'DEBUG: Starting command execution loop...';
WHILE @@FETCH_STATUS = 0 BEGIN
SET @STEPSTARTTIME = GETDATE();
SET @ROWCOUNT_AFFECTED = 0;
BEGIN TRY
PRINT N'Executing step ' + CONVERT(NVARCHAR(20), @CURRENTSTEP) + N' (' + @CURRENTPHASE + N')';
IF @DEBUG = 1 PRINT 'DEBUG: Command length: ' + CONVERT(NVARCHAR(20), LEN(@CURRENTCOMMAND)) + ' chars';
EXEC (@CURRENTCOMMAND);
SET @ROWCOUNT_AFFECTED = @@ROWCOUNT;
IF @DEBUG = 1 PRINT 'DEBUG: Step completed, rows affected: ' + CONVERT(NVARCHAR(20), @ROWCOUNT_AFFECTED);
-- Track total rows migrated for data copy phase
IF @CURRENTPHASE = N'04-Data' BEGIN
SET @TOTAL_ROWS_MIGRATED = @TOTAL_ROWS_MIGRATED + @ROWCOUNT_AFFECTED;
END;
-- Log successful step
IF (@LOGLEVEL IN ('INFO')) BEGIN
INSERT INTO [dbo].[TBDD_MIGRATE_DATABASE_LOG]
([RUN_ID], [LOG_LEVEL], [STEP], [PHASE], [SOURCE_DATABASE], [TARGET_DATABASE], [NEW_COLLATION], [MESSAGE], [COMMAND], [ROWS_AFFECTED], [DURATION_MS], [ADDED_WHO], [ADDED_WHEN])
VALUES
(@RUN_ID, 'INFO', @CURRENTSTEP, @CURRENTPHASE, @SOURCEDATABASE, @TARGETDATABASE, @NEWCOLLATION,
'Step completed successfully', @CURRENTCOMMAND, @ROWCOUNT_AFFECTED,
DATEDIFF(MILLISECOND, @STEPSTARTTIME, GETDATE()), @MY_PROCEDURE_NAME, GETDATE());
END;
END TRY BEGIN CATCH
SET @ERRORMESSAGE = ERROR_MESSAGE();
PRINT N'FAILED step ' + CONVERT(NVARCHAR(20), @CURRENTSTEP) + N' (' + @CURRENTPHASE + N'): ' + @ERRORMESSAGE;
IF @DEBUG = 1 BEGIN
PRINT N'DEBUG: FAILED COMMAND (first 4000 chars):';
PRINT LEFT(@CURRENTCOMMAND, 4000);
IF LEN(@CURRENTCOMMAND) > 4000 BEGIN
PRINT N'DEBUG: ... (command truncated, total length: ' + CONVERT(NVARCHAR(20), LEN(@CURRENTCOMMAND)) + N' chars)';
END;
END;
-- Log error with FULL command for manual rework
IF (@LOGLEVEL IN ('INFO', 'WARN', 'ERROR')) BEGIN
INSERT INTO [dbo].[TBDD_MIGRATE_DATABASE_LOG]
([RUN_ID], [LOG_LEVEL], [STEP], [PHASE], [SOURCE_DATABASE], [TARGET_DATABASE], [NEW_COLLATION], [MESSAGE], [COMMAND], [DURATION_MS], [ERROR_MESSAGE], [ADDED_WHO], [ADDED_WHEN])
VALUES
(@RUN_ID, 'ERROR', @CURRENTSTEP, @CURRENTPHASE, @SOURCEDATABASE, @TARGETDATABASE, @NEWCOLLATION,
'Step failed with error', @CURRENTCOMMAND,
DATEDIFF(MILLISECOND, @STEPSTARTTIME, GETDATE()), @ERRORMESSAGE, @MY_PROCEDURE_NAME, GETDATE());
END;
IF @STOPONERROR = 1 BEGIN
-- Log abortion
IF (@LOGLEVEL IN ('INFO', 'WARN', 'ERROR')) BEGIN
INSERT INTO [dbo].[TBDD_MIGRATE_DATABASE_LOG]
([RUN_ID], [LOG_LEVEL], [SOURCE_DATABASE], [TARGET_DATABASE], [NEW_COLLATION], [MESSAGE], [ROWS_AFFECTED], [DURATION_MS], [ERROR_MESSAGE], [ADDED_WHO], [ADDED_WHEN])
VALUES
(@RUN_ID, 'ERROR', @SOURCEDATABASE, @TARGETDATABASE, @NEWCOLLATION,
'Migration ABORTED due to error (STOPONERROR=1)', @TOTAL_ROWS_MIGRATED,
DATEDIFF(MILLISECOND, @STARTTIME, GETDATE()), @ERRORMESSAGE, @MY_PROCEDURE_NAME, GETDATE());
END;
-- Restore source database to original user access mode before aborting
BEGIN TRY
SET @DYNAMICSQL = N'ALTER DATABASE {#SOURCEDB_Q#} SET ' + ISNULL(@SOURCE_USER_ACCESS_ORIGINAL, N'MULTI_USER') + N';';
-- Ersetze Platzhalter durch tatsächliche Werte
SET @DYNAMICSQL = REPLACE(REPLACE(REPLACE(REPLACE(@DYNAMICSQL,
@PH_SOURCEDB_QUOTED, @SOURCEDATABASE_QUOTED),
@PH_TARGETDB_QUOTED, @TARGETDATABASE_QUOTED),
@PH_SOURCEDB, @SOURCEDATABASE),
@PH_TARGETDB, @TARGETDATABASE);
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) <= 4000 PRINT @DYNAMICSQL;
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) > 4000 PRINT LEFT(@DYNAMICSQL, 4000) + N'...(truncated)';
BEGIN TRY
EXEC sys.sp_executesql @DYNAMICSQL;
END TRY BEGIN CATCH
PRINT N'ERROR in dynamic SQL:';
PRINT @DYNAMICSQL;
THROW;
END CATCH;
PRINT 'INFO: Source database restored to ' + ISNULL(@SOURCE_USER_ACCESS_ORIGINAL, 'MULTI_USER') + ' mode.';
END TRY BEGIN CATCH
PRINT 'WARN: Could not restore source database to ' + ISNULL(@SOURCE_USER_ACCESS_ORIGINAL, 'MULTI_USER') + ': ' + ERROR_MESSAGE();
END CATCH;
-- Cleanup
IF OBJECT_ID('tempdb..#Commands') IS NOT NULL DROP TABLE #Commands;
IF OBJECT_ID('tempdb..#ExcludedObjects') IS NOT NULL DROP TABLE #ExcludedObjects;
IF OBJECT_ID('tempdb..#SkippedObjects') IS NOT NULL DROP TABLE #SkippedObjects;
CLOSE cmd_cur;
DEALLOCATE cmd_cur;
THROW;
END;
END CATCH;
FETCH NEXT FROM cmd_cur INTO @CURRENTSTEP, @CURRENTPHASE, @CURRENTCOMMAND;
END;
CLOSE cmd_cur;
DEALLOCATE cmd_cur;
-- Log successful completion
IF (@LOGLEVEL IN ('INFO')) BEGIN
INSERT INTO [dbo].[TBDD_MIGRATE_DATABASE_LOG]
([RUN_ID], [LOG_LEVEL], [SOURCE_DATABASE], [TARGET_DATABASE], [NEW_COLLATION], [MESSAGE], [ROWS_AFFECTED], [DURATION_MS], [ADDED_WHO], [ADDED_WHEN])
VALUES
(@RUN_ID, 'INFO', @SOURCEDATABASE, @TARGETDATABASE, @NEWCOLLATION,
'Migration completed successfully', @TOTAL_ROWS_MIGRATED,
DATEDIFF(MILLISECOND, @STARTTIME, GETDATE()), @MY_PROCEDURE_NAME, GETDATE());
END;
PRINT N'';
PRINT N'====================================================================================================';
PRINT N'Migration completed successfully!';
PRINT N'Total rows migrated: ' + CONVERT(NVARCHAR(20), @TOTAL_ROWS_MIGRATED);
PRINT N'Total duration: ' + CONVERT(NVARCHAR(20), DATEDIFF(SECOND, @STARTTIME, GETDATE())) + N' seconds';
PRINT N'====================================================================================================';
--=================================================-- Validation Phase --==============================================--
IF @VALIDATION_MODE <> 'NONE' BEGIN
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 @VALIDATION_MODE IN ('ALL', '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 <> N''sys'' AND t.is_ms_shipped = 0
AND NOT EXISTS (SELECT 1 FROM #ExcludedObjects ex WHERE (ex.IsWildcard = 1 AND (t.name COLLATE DATABASE_DEFAULT LIKE ex.Pattern OR (s.name + N''.'' + t.name) COLLATE DATABASE_DEFAULT LIKE ex.Pattern)) OR (ex.IsWildcard = 0 AND (t.name COLLATE DATABASE_DEFAULT = ex.Pattern OR (s.name + N''.'' + t.name) COLLATE DATABASE_DEFAULT = ex.Pattern)));';
SET @VALIDATION_SQL = REPLACE(REPLACE(REPLACE(REPLACE(@VALIDATION_SQL, @PH_SOURCEDB_QUOTED, @SOURCEDATABASE_QUOTED), @PH_TARGETDB_QUOTED, @TARGETDATABASE_QUOTED), @PH_SOURCEDB, @SOURCEDATABASE), @PH_TARGETDB, @TARGETDATABASE);
EXEC sys.sp_executesql @VALIDATION_SQL, N'@src INT OUTPUT', @src = @VALIDATION_SOURCE_COUNT OUTPUT;
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 <> N''sys'' AND t.is_ms_shipped = 0;';
SET @VALIDATION_SQL = REPLACE(REPLACE(REPLACE(REPLACE(@VALIDATION_SQL, @PH_SOURCEDB_QUOTED, @SOURCEDATABASE_QUOTED), @PH_TARGETDB_QUOTED, @TARGETDATABASE_QUOTED), @PH_SOURCEDB, @SOURCEDATABASE), @PH_TARGETDB, @TARGETDATABASE);
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 (accounting for #SkippedObjects)
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 <> N''sys''
AND NOT EXISTS (SELECT 1 FROM #SkippedObjects sk WHERE sk.ObjectId = v.object_id)
AND NOT EXISTS (SELECT 1 FROM #ExcludedObjects ex WHERE (ex.IsWildcard = 1 AND (v.name COLLATE DATABASE_DEFAULT LIKE ex.Pattern OR (s.name + N''.'' + v.name) COLLATE DATABASE_DEFAULT LIKE ex.Pattern)) OR (ex.IsWildcard = 0 AND (v.name COLLATE DATABASE_DEFAULT = ex.Pattern OR (s.name + N''.'' + v.name) COLLATE DATABASE_DEFAULT = ex.Pattern)));';
SET @VALIDATION_SQL = REPLACE(REPLACE(REPLACE(REPLACE(@VALIDATION_SQL, @PH_SOURCEDB_QUOTED, @SOURCEDATABASE_QUOTED), @PH_TARGETDB_QUOTED, @TARGETDATABASE_QUOTED), @PH_SOURCEDB, @SOURCEDATABASE), @PH_TARGETDB, @TARGETDATABASE);
EXEC sys.sp_executesql @VALIDATION_SQL, N'@src INT OUTPUT', @src = @VALIDATION_SOURCE_COUNT OUTPUT;
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 <> N''sys'';';
SET @VALIDATION_SQL = REPLACE(REPLACE(REPLACE(REPLACE(@VALIDATION_SQL, @PH_SOURCEDB_QUOTED, @SOURCEDATABASE_QUOTED), @PH_TARGETDB_QUOTED, @TARGETDATABASE_QUOTED), @PH_SOURCEDB, @SOURCEDATABASE), @PH_TARGETDB, @TARGETDATABASE);
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 (accounting for #SkippedObjects)
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 <> N''sys''
AND NOT EXISTS (SELECT 1 FROM #SkippedObjects sk WHERE sk.ObjectId = p.object_id)
AND NOT EXISTS (SELECT 1 FROM #ExcludedObjects ex WHERE (ex.IsWildcard = 1 AND (p.name COLLATE DATABASE_DEFAULT LIKE ex.Pattern OR (s.name + N''.'' + p.name) COLLATE DATABASE_DEFAULT LIKE ex.Pattern)) OR (ex.IsWildcard = 0 AND (p.name COLLATE DATABASE_DEFAULT = ex.Pattern OR (s.name + N''.'' + p.name) COLLATE DATABASE_DEFAULT = ex.Pattern)));';
SET @VALIDATION_SQL = REPLACE(REPLACE(REPLACE(REPLACE(@VALIDATION_SQL, @PH_SOURCEDB_QUOTED, @SOURCEDATABASE_QUOTED), @PH_TARGETDB_QUOTED, @TARGETDATABASE_QUOTED), @PH_SOURCEDB, @SOURCEDATABASE), @PH_TARGETDB, @TARGETDATABASE);
EXEC sys.sp_executesql @VALIDATION_SQL, N'@src INT OUTPUT', @src = @VALIDATION_SOURCE_COUNT OUTPUT;
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 <> N''sys'';';
SET @VALIDATION_SQL = REPLACE(REPLACE(REPLACE(REPLACE(@VALIDATION_SQL, @PH_SOURCEDB_QUOTED, @SOURCEDATABASE_QUOTED), @PH_TARGETDB_QUOTED, @TARGETDATABASE_QUOTED), @PH_SOURCEDB, @SOURCEDATABASE), @PH_TARGETDB, @TARGETDATABASE);
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 (accounting for #SkippedObjects)
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 <> N''sys'' AND o.[type] IN (N''FN'',N''TF'',N''IF'',N''FS'',N''FT'')
AND NOT EXISTS (SELECT 1 FROM #SkippedObjects sk WHERE sk.ObjectId = o.object_id)
AND NOT EXISTS (SELECT 1 FROM #ExcludedObjects ex WHERE (ex.IsWildcard = 1 AND (o.name COLLATE DATABASE_DEFAULT LIKE ex.Pattern OR (s.name + N''.'' + o.name) COLLATE DATABASE_DEFAULT LIKE ex.Pattern)) OR (ex.IsWildcard = 0 AND (o.name COLLATE DATABASE_DEFAULT = ex.Pattern OR (s.name + N''.'' + o.name) COLLATE DATABASE_DEFAULT = ex.Pattern)));';
SET @VALIDATION_SQL = REPLACE(REPLACE(REPLACE(REPLACE(@VALIDATION_SQL, @PH_SOURCEDB_QUOTED, @SOURCEDATABASE_QUOTED), @PH_TARGETDB_QUOTED, @TARGETDATABASE_QUOTED), @PH_SOURCEDB, @SOURCEDATABASE), @PH_TARGETDB, @TARGETDATABASE);
EXEC sys.sp_executesql @VALIDATION_SQL, N'@src INT OUTPUT', @src = @VALIDATION_SOURCE_COUNT OUTPUT;
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 <> N''sys'' AND o.[type] IN (N''FN'',N''TF'',N''IF'',N''FS'',N''FT'');';
SET @VALIDATION_SQL = REPLACE(REPLACE(REPLACE(REPLACE(@VALIDATION_SQL, @PH_SOURCEDB_QUOTED, @SOURCEDATABASE_QUOTED), @PH_TARGETDB_QUOTED, @TARGETDATABASE_QUOTED), @PH_SOURCEDB, @SOURCEDATABASE), @PH_TARGETDB, @TARGETDATABASE);
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 (accounting for #SkippedObjects)
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 <> N''sys'' AND tr.parent_id IS NOT NULL
AND NOT EXISTS (SELECT 1 FROM #SkippedObjects sk WHERE sk.ObjectId = tr.object_id)
AND NOT EXISTS (SELECT 1 FROM #ExcludedObjects ex WHERE (ex.IsWildcard = 1 AND (pt.name COLLATE DATABASE_DEFAULT LIKE ex.Pattern OR (ps.name + N''.'' + pt.name) COLLATE DATABASE_DEFAULT LIKE ex.Pattern)) OR (ex.IsWildcard = 0 AND (pt.name COLLATE DATABASE_DEFAULT = ex.Pattern OR (ps.name + N''.'' + pt.name) COLLATE DATABASE_DEFAULT = ex.Pattern)))
AND NOT EXISTS (SELECT 1 FROM #ExcludedObjects ex WHERE (ex.IsWildcard = 1 AND (tr.name COLLATE DATABASE_DEFAULT LIKE ex.Pattern OR (s.name + N''.'' + tr.name) COLLATE DATABASE_DEFAULT LIKE ex.Pattern)) OR (ex.IsWildcard = 0 AND (tr.name COLLATE DATABASE_DEFAULT = ex.Pattern OR (s.name + N''.'' + tr.name) COLLATE DATABASE_DEFAULT = ex.Pattern)));';
SET @VALIDATION_SQL = REPLACE(REPLACE(REPLACE(REPLACE(@VALIDATION_SQL, @PH_SOURCEDB_QUOTED, @SOURCEDATABASE_QUOTED), @PH_TARGETDB_QUOTED, @TARGETDATABASE_QUOTED), @PH_SOURCEDB, @SOURCEDATABASE), @PH_TARGETDB, @TARGETDATABASE);
EXEC sys.sp_executesql @VALIDATION_SQL, N'@src INT OUTPUT', @src = @VALIDATION_SOURCE_COUNT OUTPUT;
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 WHERE s.name <> N''sys'' AND tr.parent_id IS NOT NULL;';
SET @VALIDATION_SQL = REPLACE(REPLACE(REPLACE(REPLACE(@VALIDATION_SQL, @PH_SOURCEDB_QUOTED, @SOURCEDATABASE_QUOTED), @PH_TARGETDB_QUOTED, @TARGETDATABASE_QUOTED), @PH_SOURCEDB, @SOURCEDATABASE), @PH_TARGETDB, @TARGETDATABASE);
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 <> N''sys'' AND i.index_id > 0
AND NOT EXISTS (SELECT 1 FROM #ExcludedObjects ex WHERE (ex.IsWildcard = 1 AND (t.name COLLATE DATABASE_DEFAULT LIKE ex.Pattern OR (s.name + N''.'' + t.name) COLLATE DATABASE_DEFAULT LIKE ex.Pattern)) OR (ex.IsWildcard = 0 AND (t.name COLLATE DATABASE_DEFAULT = ex.Pattern OR (s.name + N''.'' + t.name) COLLATE DATABASE_DEFAULT = ex.Pattern)));';
SET @VALIDATION_SQL = REPLACE(REPLACE(REPLACE(REPLACE(@VALIDATION_SQL, @PH_SOURCEDB_QUOTED, @SOURCEDATABASE_QUOTED), @PH_TARGETDB_QUOTED, @TARGETDATABASE_QUOTED), @PH_SOURCEDB, @SOURCEDATABASE), @PH_TARGETDB, @TARGETDATABASE);
EXEC sys.sp_executesql @VALIDATION_SQL, N'@src INT OUTPUT', @src = @VALIDATION_SOURCE_COUNT OUTPUT;
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 <> N''sys'' AND i.index_id > 0;';
SET @VALIDATION_SQL = REPLACE(REPLACE(REPLACE(REPLACE(@VALIDATION_SQL, @PH_SOURCEDB_QUOTED, @SOURCEDATABASE_QUOTED), @PH_TARGETDB_QUOTED, @TARGETDATABASE_QUOTED), @PH_SOURCEDB, @SOURCEDATABASE), @PH_TARGETDB, @TARGETDATABASE);
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 <> N''sys''
AND NOT EXISTS (SELECT 1 FROM #ExcludedObjects ex WHERE (ex.IsWildcard = 1 AND (pt.name COLLATE DATABASE_DEFAULT LIKE ex.Pattern OR (spt.name + N''.'' + pt.name) COLLATE DATABASE_DEFAULT LIKE ex.Pattern)) OR (ex.IsWildcard = 0 AND (pt.name COLLATE DATABASE_DEFAULT = ex.Pattern OR (spt.name + N''.'' + pt.name) COLLATE DATABASE_DEFAULT = ex.Pattern)))
AND NOT EXISTS (SELECT 1 FROM #ExcludedObjects ex WHERE (ex.IsWildcard = 1 AND (rt.name COLLATE DATABASE_DEFAULT LIKE ex.Pattern OR (srt.name + N''.'' + rt.name) COLLATE DATABASE_DEFAULT LIKE ex.Pattern)) OR (ex.IsWildcard = 0 AND (rt.name COLLATE DATABASE_DEFAULT = ex.Pattern OR (srt.name + N''.'' + rt.name) COLLATE DATABASE_DEFAULT = ex.Pattern)));';
SET @VALIDATION_SQL = REPLACE(REPLACE(REPLACE(REPLACE(@VALIDATION_SQL, @PH_SOURCEDB_QUOTED, @SOURCEDATABASE_QUOTED), @PH_TARGETDB_QUOTED, @TARGETDATABASE_QUOTED), @PH_SOURCEDB, @SOURCEDATABASE), @PH_TARGETDB, @TARGETDATABASE);
EXEC sys.sp_executesql @VALIDATION_SQL, N'@src INT OUTPUT', @src = @VALIDATION_SOURCE_COUNT OUTPUT;
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.schemas spt ON spt.schema_id = pt.schema_id WHERE spt.name <> N''sys'';';
SET @VALIDATION_SQL = REPLACE(REPLACE(REPLACE(REPLACE(@VALIDATION_SQL, @PH_SOURCEDB_QUOTED, @SOURCEDATABASE_QUOTED), @PH_TARGETDB_QUOTED, @TARGETDATABASE_QUOTED), @PH_SOURCEDB, @SOURCEDATABASE), @PH_TARGETDB, @TARGETDATABASE);
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 @VALIDATION_MODE IN ('ALL', 'DATA') AND @MODE IN ('FULL', 'DATA') BEGIN
PRINT N'';
PRINT N'--- Data Validation (Row Counts) ---';
-- Create temp table to hold table list for validation
CREATE TABLE #DataValidationTables (
SchemaName NVARCHAR(128) NOT NULL,
TableName NVARCHAR(128) NOT NULL
);
-- Populate table list dynamically
SET @VALIDATION_CURSOR_SQL = N'
INSERT INTO #DataValidationTables (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 <> N''sys'' AND t.is_ms_shipped = 0
AND NOT EXISTS (SELECT 1 FROM #ExcludedObjects ex WHERE (ex.IsWildcard = 1 AND (t.name COLLATE DATABASE_DEFAULT LIKE ex.Pattern OR (s.name + N''.'' + t.name) COLLATE DATABASE_DEFAULT LIKE ex.Pattern)) OR (ex.IsWildcard = 0 AND (t.name COLLATE DATABASE_DEFAULT = ex.Pattern OR (s.name + N''.'' + t.name) COLLATE DATABASE_DEFAULT = ex.Pattern)))
ORDER BY s.name, t.name;';
SET @VALIDATION_CURSOR_SQL = REPLACE(REPLACE(REPLACE(REPLACE(@VALIDATION_CURSOR_SQL, @PH_SOURCEDB_QUOTED, @SOURCEDATABASE_QUOTED), @PH_TARGETDB_QUOTED, @TARGETDATABASE_QUOTED), @PH_SOURCEDB, @SOURCEDATABASE), @PH_TARGETDB, @TARGETDATABASE);
EXEC sys.sp_executesql @VALIDATION_CURSOR_SQL;
-- Declare cursor on temp table (cursor visible in current scope)
DECLARE data_val_cur CURSOR FAST_FORWARD FOR
SELECT SchemaName, TableName FROM #DataValidationTables 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, @PH_SOURCEDB_QUOTED, @SOURCEDATABASE_QUOTED), @PH_TARGETDB_QUOTED, @TARGETDATABASE_QUOTED), @PH_SOURCEDB, @SOURCEDATABASE), @PH_TARGETDB, @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, @PH_SOURCEDB_QUOTED, @SOURCEDATABASE_QUOTED), @PH_TARGETDB_QUOTED, @TARGETDATABASE_QUOTED), @PH_SOURCEDB, @SOURCEDATABASE), @PH_TARGETDB, @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..#DataValidationTables') IS NOT NULL DROP TABLE #DataValidationTables;
END;
-- Log validation results
IF (@LOGLEVEL IN ('INFO')) BEGIN
INSERT INTO [dbo].[TBDD_MIGRATE_DATABASE_LOG]
([RUN_ID], [LOG_LEVEL], [SOURCE_DATABASE], [TARGET_DATABASE], [NEW_COLLATION], [MESSAGE], [ADDED_WHO], [ADDED_WHEN])
SELECT @RUN_ID,
CASE WHEN Status = 'ERROR' THEN 'ERROR' WHEN Status = 'WARN' THEN 'WARN' ELSE 'INFO' END,
@SOURCEDATABASE, @TARGETDATABASE, @NEWCOLLATION,
N'Validation ' + ValidationType + N' - ' + ObjectType + ISNULL(N': ' + ObjectName, N'') + N' - Source=' + CONVERT(NVARCHAR(20), SourceCount) + N', Target=' + CONVERT(NVARCHAR(20), TargetCount) + N' [' + Status + N']',
@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 and data migrated successfully.';
IF @VALIDATION_WARNINGS > 0 BEGIN
PRINT N'Warnings: ' + CONVERT(NVARCHAR(10), @VALIDATION_WARNINGS);
END;
-- Set target database to MULTI_USER mode
PRINT N'';
PRINT N'Setting target database to MULTI_USER mode...';
BEGIN TRY
SET @DYNAMICSQL = N'ALTER DATABASE {#TARGETDB_Q#} SET MULTI_USER;';
-- Ersetze Platzhalter durch tatsächliche Werte
SET @DYNAMICSQL = REPLACE(REPLACE(REPLACE(REPLACE(@DYNAMICSQL,
@PH_SOURCEDB_QUOTED, @SOURCEDATABASE_QUOTED),
@PH_TARGETDB_QUOTED, @TARGETDATABASE_QUOTED),
@PH_SOURCEDB, @SOURCEDATABASE),
@PH_TARGETDB, @TARGETDATABASE);
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) <= 4000 PRINT @DYNAMICSQL;
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) > 4000 PRINT LEFT(@DYNAMICSQL, 4000) + N'...(truncated)';
BEGIN TRY
EXEC sys.sp_executesql @DYNAMICSQL;
END TRY BEGIN CATCH
PRINT N'ERROR in dynamic SQL:';
PRINT @DYNAMICSQL;
THROW;
END CATCH;
PRINT N'SUCCESS: Target database ' + @TARGETDATABASE + N' is now in MULTI_USER mode.';
IF (@LOGLEVEL IN ('INFO')) BEGIN
INSERT INTO [dbo].[TBDD_MIGRATE_DATABASE_LOG]
([RUN_ID], [LOG_LEVEL], [SOURCE_DATABASE], [TARGET_DATABASE], [NEW_COLLATION], [MESSAGE], [ADDED_WHO], [ADDED_WHEN])
VALUES (@RUN_ID, 'INFO', @SOURCEDATABASE, @TARGETDATABASE, @NEWCOLLATION,
'Validation PASSED - Target database set to MULTI_USER', @MY_PROCEDURE_NAME, GETDATE());
END;
END TRY BEGIN CATCH
PRINT N'WARNING: Could not set target database to MULTI_USER: ' + ERROR_MESSAGE();
END CATCH;
END; ELSE BEGIN
SET @RETURN_STATUS = 2; -- Validation failed
PRINT N'VALIDATION FAILED! Errors: ' + CONVERT(NVARCHAR(10), @VALIDATION_ERRORS) + N', Warnings: ' + CONVERT(NVARCHAR(10), @VALIDATION_WARNINGS);
PRINT N'Target database remains in RESTRICTED_USER mode. Please review and fix issues manually.';
IF (@LOGLEVEL IN ('INFO', 'WARN', 'ERROR')) BEGIN
INSERT INTO [dbo].[TBDD_MIGRATE_DATABASE_LOG]
([RUN_ID], [LOG_LEVEL], [SOURCE_DATABASE], [TARGET_DATABASE], [NEW_COLLATION], [MESSAGE], [ERROR_MESSAGE], [ADDED_WHO], [ADDED_WHEN])
VALUES (@RUN_ID, 'ERROR', @SOURCEDATABASE, @TARGETDATABASE, @NEWCOLLATION,
'Validation FAILED - Target database remains in RESTRICTED_USER',
'Errors: ' + CONVERT(NVARCHAR(10), @VALIDATION_ERRORS) + ', Warnings: ' + CONVERT(NVARCHAR(10), @VALIDATION_WARNINGS),
@MY_PROCEDURE_NAME, GETDATE());
END;
END;
PRINT N'====================================================================================================';
-- Output validation details table
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;
IF OBJECT_ID('tempdb..#ValidationResults') IS NOT NULL DROP TABLE #ValidationResults;
END; -- End of validation
----------------------------------------------------------------------------------------------------------------------------
END; ELSE BEGIN
-- If not executing, restore source database to original user access mode immediately
PRINT 'INFO: Restoring source database to ' + ISNULL(@SOURCE_USER_ACCESS_ORIGINAL, 'MULTI_USER') + ' mode (script-only mode)...';
BEGIN TRY
SET @DYNAMICSQL = N'ALTER DATABASE {#SOURCEDB_Q#} SET ' + ISNULL(@SOURCE_USER_ACCESS_ORIGINAL, N'MULTI_USER') + N';';
-- Ersetze Platzhalter durch tatsächliche Werte
SET @DYNAMICSQL = REPLACE(REPLACE(REPLACE(REPLACE(@DYNAMICSQL,
@PH_SOURCEDB_QUOTED, @SOURCEDATABASE_QUOTED),
@PH_TARGETDB_QUOTED, @TARGETDATABASE_QUOTED),
@PH_SOURCEDB, @SOURCEDATABASE),
@PH_TARGETDB, @TARGETDATABASE);
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) <= 4000 PRINT @DYNAMICSQL;
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) > 4000 PRINT LEFT(@DYNAMICSQL, 4000) + N'...(truncated)';
BEGIN TRY
EXEC sys.sp_executesql @DYNAMICSQL;
END TRY BEGIN CATCH
PRINT N'ERROR in dynamic SQL:';
PRINT @DYNAMICSQL;
THROW;
END CATCH;
PRINT 'INFO: Source database restored to ' + ISNULL(@SOURCE_USER_ACCESS_ORIGINAL, 'MULTI_USER') + ' mode.';
SET @SOURCE_LOCKED = 0;
END TRY BEGIN CATCH
PRINT 'WARN: Could not restore source database to ' + ISNULL(@SOURCE_USER_ACCESS_ORIGINAL, 'MULTI_USER') + ': ' + ERROR_MESSAGE();
END CATCH;
-- Log script-only mode
IF (@LOGLEVEL IN ('INFO')) BEGIN
INSERT INTO [dbo].[TBDD_MIGRATE_DATABASE_LOG]
([RUN_ID], [LOG_LEVEL], [SOURCE_DATABASE], [TARGET_DATABASE], [NEW_COLLATION], [MESSAGE], [DURATION_MS], [ADDED_WHO], [ADDED_WHEN])
VALUES
(@RUN_ID, 'INFO', @SOURCEDATABASE, @TARGETDATABASE, @NEWCOLLATION,
'Script generated (EXECUTE=0, no commands executed)',
DATEDIFF(MILLISECOND, @STARTTIME, GETDATE()), @MY_PROCEDURE_NAME, GETDATE());
END;
END;
----------------------------------------------------------------------------------------------------------------------------
--=================================================-- Cleanup --=========================================================--
IF OBJECT_ID('tempdb..#Commands') IS NOT NULL DROP TABLE #Commands;
IF OBJECT_ID('tempdb..#ExcludedObjects') IS NOT NULL DROP TABLE #ExcludedObjects;
IF OBJECT_ID('tempdb..#SkippedObjects') IS NOT NULL DROP TABLE #SkippedObjects;
----------------------------------------------------------------------------------------------------------------------------
--=================================================-- Important hint --==================================================--
IF @VALIDATION_MODE = 'NONE' OR @EXECUTECOMMANDS = 0 BEGIN
PRINT N'';
PRINT N'NOTE: Target database may still be in RESTRICTED_USER mode.';
PRINT N' Use @pVALIDATE=ALL to auto-validate and set to MULTI_USER on success,';
PRINT N' or set it manually: ALTER DATABASE ' + ISNULL(@TARGETDATABASE_QUOTED, '[TargetDB]') + N' SET MULTI_USER;';
END;
----------------------------------------------------------------------------------------------------------------------------
END TRY
BEGIN CATCH
SET @ERRORMESSAGE = ERROR_MESSAGE();
IF ISNULL(@RETURN_STATUS,0) = 0 SET @RETURN_STATUS = 1;
-- Best-effort restore of source database access if it was locked
IF @SOURCE_LOCKED = 1 AND @SOURCEDATABASE_QUOTED IS NOT NULL BEGIN
BEGIN TRY
SET @DYNAMICSQL = N'ALTER DATABASE {#SOURCEDB_Q#} SET ' + ISNULL(@SOURCE_USER_ACCESS_ORIGINAL, N'MULTI_USER') + N';';
-- Ersetze Platzhalter durch tatsächliche Werte
SET @DYNAMICSQL = REPLACE(REPLACE(REPLACE(REPLACE(@DYNAMICSQL,
@PH_SOURCEDB_QUOTED, @SOURCEDATABASE_QUOTED),
@PH_TARGETDB_QUOTED, @TARGETDATABASE_QUOTED),
@PH_SOURCEDB, @SOURCEDATABASE),
@PH_TARGETDB, @TARGETDATABASE);
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) <= 4000 PRINT @DYNAMICSQL;
IF @DEBUG = 1 AND LEN(@DYNAMICSQL) > 4000 PRINT LEFT(@DYNAMICSQL, 4000) + N'...(truncated)';
BEGIN TRY
EXEC sys.sp_executesql @DYNAMICSQL;
END TRY BEGIN CATCH
PRINT N'ERROR in dynamic SQL:';
PRINT @DYNAMICSQL;
THROW;
END CATCH;
SET @SOURCE_LOCKED = 0;
END TRY BEGIN CATCH
PRINT 'WARN: CATCH could not restore source database access: ' + ERROR_MESSAGE();
END CATCH;
END;
-- Drop temp tables if they exist
IF OBJECT_ID('tempdb..#Commands') IS NOT NULL DROP TABLE #Commands;
IF OBJECT_ID('tempdb..#ExcludedObjects') IS NOT NULL DROP TABLE #ExcludedObjects;
IF OBJECT_ID('tempdb..#SkippedObjects') IS NOT NULL DROP TABLE #SkippedObjects;
-- Log error if logging is enabled and the table exists
IF (@LOGLEVEL IN ('INFO','WARN','ERROR')) AND OBJECT_ID(N'dbo.TBDD_MIGRATE_DATABASE_LOG','U') IS NOT NULL BEGIN
INSERT INTO [dbo].[TBDD_MIGRATE_DATABASE_LOG]
([RUN_ID], [LOG_LEVEL], [SOURCE_DATABASE], [TARGET_DATABASE], [NEW_COLLATION], [MESSAGE], [ERROR_MESSAGE], [ADDED_WHO], [ADDED_WHEN])
VALUES
(@RUN_ID, 'ERROR', @SOURCEDATABASE, @TARGETDATABASE, @NEWCOLLATION, 'Unhandled error in PRDD_MIGRATE_DATABASE', @ERRORMESSAGE, @MY_PROCEDURE_NAME, GETDATE());
END;
RAISERROR(@ERRORMESSAGE, 16, 1);
END CATCH;
RETURN @RETURN_STATUS;
END;
GO