From 3096e432aa4c27e2f079e35f7166636564a0a9db Mon Sep 17 00:00:00 2001 From: KammM Date: Wed, 25 Feb 2026 17:01:06 +0100 Subject: [PATCH] PRDD_GET_DATABASE_OBJECT: Complete Rework --- .../[PRDD_GET_DATABASE_OBJECT].sql | 1071 +++++++++-------- 1 file changed, 581 insertions(+), 490 deletions(-) diff --git a/current/[DD_SYS]-Database/[PRDD_GET_DATABASE_OBJECT]/[PRDD_GET_DATABASE_OBJECT].sql b/current/[DD_SYS]-Database/[PRDD_GET_DATABASE_OBJECT]/[PRDD_GET_DATABASE_OBJECT].sql index 890f682..c1fbeba 100644 --- a/current/[DD_SYS]-Database/[PRDD_GET_DATABASE_OBJECT]/[PRDD_GET_DATABASE_OBJECT].sql +++ b/current/[DD_SYS]-Database/[PRDD_GET_DATABASE_OBJECT]/[PRDD_GET_DATABASE_OBJECT].sql @@ -13,36 +13,24 @@ GO -- (2) Table names -- (3) Column names -- (4) Data values in text-like table columns (optional) --- --- Optional: Replace @pSEARCHVALUE with @pREPLACEWITH inside found module definitions --- and/or data values in text-like table columns. +-- (5) SQL Agent Job names and job step definitions (Express-safe) + -- Minimum requirement: MS SQL Server 2016 -- --- Returns: INT Value - 0 = Everything worked well +-- Returns: INT Value - 0 = Everything worked well, 1 = Completed with warnings (see RS5), >1 = Error -- ================================================================= -- Copyright (c) 2026 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: 05.02.2026 / GPT --- Version Date / Editor: 16.02.2026 / GPT --- Version Number: 1.2.2.0 +-- Creation Date / Author: 05.02.2026 / MK +-- Version Date / Editor: 20.02.2026 / MK +-- Version Number: 2.0.0.0 -- ================================================================= -- History: --- 05.02.2026 / GPT - First Version (project style) --- 05.02.2026 / GPT - Added flow PRINT messages, removed compatibility wrapper --- 05.02.2026 / GPT - Renamed to PRDD_GET_DATABASE_OBJECT --- 05.02.2026 / GPT - Temp table naming changed to: #TBDD_GET_DATABASE_OBJECT_ --- 05.02.2026 / GPT - Critical review fixes: explicit SET options for replace, improved error context, replace warnings --- 05.02.2026 / GPT - Added optional data-value scan across textual table columns --- 05.02.2026 / GPT - Added optional data-value replace with dedicated log/resultset --- 06.02.2026 / GPT - Collation conflict fixes across cross-database scans and summaries (LIKE/EQUAL) --- 06.02.2026 / GPT - Added safe non-execute scan/plan SQL path to avoid compile-time collation conflicts --- 16.02.2026 / GPT - F01: LIKE-Wildcards (%,_,[) im Suchbegriff werden nun escaped --- 16.02.2026 / GPT - F02: Konsistente COLLATE-Angabe auf @sv in beiden SQL-Pfaden --- 16.02.2026 / GPT - F04: Cursor db_cur wird vor RETURN bei Collation-Fehler sauber geschlossen --- 16.02.2026 / GPT - F05: Kommentare werden vor CREATE-Position-Erkennung entfernt (Spaces preserving) +-- 05.02.2026 / MK - First Version +-- 20.02.2026 / MK - Komplette Review/Rework-Umsetzung CREATE OR ALTER PROCEDURE [dbo].[PRDD_GET_DATABASE_OBJECT] ( @pSEARCHVALUE NVARCHAR(100) = NULL, -- Search term @@ -51,13 +39,17 @@ CREATE OR ALTER PROCEDURE [dbo].[PRDD_GET_DATABASE_OBJECT] ( @pREPLACEWITH NVARCHAR(100) = NULL, -- Optional replacement term (module definitions / data values) @pDOREPLACE BIT = 0, -- 1 = execute replacement, 0 = only search / plan @pINCLUDEDATAVALUES BIT = 1, -- 1 = also scan text-like data values in tables, 0 = skip data scan - @pDOREPLACEDATAVALUES BIT = 0 -- 1 = execute data-value replace, 0 = only data scan / plan + @pDOREPLACEDATAVALUES BIT = 0, -- 1 = execute data-value replace, 0 = only data scan / plan + @pALLOWDIRTYREADS BIT = 1, -- 1 = use NOLOCK for data scan, 0 = consistent reads + @pINCLUDEAGENTJOBS BIT = 1, -- 1 = include SQL Agent scan, 0 = skip Agent scan completely + @pMAXDATACOLUMNSPERDB INT = 0 -- 0 = no limit, >0 = max scanned data columns per DB ) AS BEGIN --================================================-- Set session options --===============================================-- SET NOCOUNT ON; + SET XACT_ABORT ON; SET ANSI_NULLS ON; SET QUOTED_IDENTIFIER ON; ---------------------------------------------------------------------------------------------------------------------------- @@ -69,19 +61,66 @@ BEGIN @REPLACEWITH NVARCHAR(100) = NULLIF(LTRIM(RTRIM(ISNULL(@pREPLACEWITH,N''))),N''), @DOREPLACE BIT = ISNULL(@pDOREPLACE,0), @INCLUDEDATAVALUES BIT = ISNULL(@pINCLUDEDATAVALUES,1), - @DOREPLACEDATAVALUES BIT = ISNULL(@pDOREPLACEDATAVALUES,0); + @DOREPLACEDATAVALUES BIT = ISNULL(@pDOREPLACEDATAVALUES,0), + @ALLOWDIRTYREADS BIT = ISNULL(@pALLOWDIRTYREADS,1), + @INCLUDEAGENTJOBS BIT = ISNULL(@pINCLUDEAGENTJOBS,1), + @MAXDATACOLUMNSPERDB INT = ISNULL(@pMAXDATACOLUMNSPERDB,0); ---------------------------------------------------------------------------------------------------------------------------- --=================================================-- Declare runtime variables --========================================-- - DECLARE @MY_PROCEDURE_NAME NVARCHAR(128) = OBJECT_NAME(@@PROCID); - DECLARE @SQLCommand NVARCHAR(MAX) = NULL, - @CurrentDB NVARCHAR(128) = NULL, - @CurrentDBCollation SYSNAME = NULL, - @return_status INT = 0, - @return_status_text NVARCHAR(MAX) = 'START PROCEDURE [' + @MY_PROCEDURE_NAME + '] @ ' + CONVERT(varchar(50),GETDATE(),120), - @return_error_text NVARCHAR(MAX) = ''; - - DECLARE @START_TIME DATETIME2(0) = SYSDATETIME(); + DECLARE @MY_PROCEDURE_NAME NVARCHAR(128) = OBJECT_NAME(@@PROCID); + DECLARE @SQL_COMMAND NVARCHAR(MAX) = NULL, + @NOLOCK_HINT NVARCHAR(20) = N'', + @CURRENT_DB NVARCHAR(128) = NULL, + @DB_START_TIME DATETIME2(0) = NULL, + @DB_DURATION_SEC INT = 0, + @CURRENT_DB_COLLATION SYSNAME = NULL, + @START_TIME DATETIME2(0) = SYSDATETIME(), + @MISSING_INCLUDE NVARCHAR(MAX) = NULL, + @MISSING_EXCLUDE NVARCHAR(MAX) = NULL, + @BAD_INCLUDE NVARCHAR(MAX) = NULL, + @DBCOUNT INT = 0, + @DBINDEX INT = 0, + @AGENT_AVAILABLE BIT = 0, + @AGENT_SEARCHVALUE NVARCHAR(100) = @SEARCHVALUE, + @AGENT_SEARCHVALUE_LIKE NVARCHAR(400) = REPLACE(REPLACE(REPLACE(@SEARCHVALUE, N'[', N'[[]'), N'%', N'[%]'), N'_', N'[_]'), + @AGENT_JOB_COUNT INT = 0, + @DBCOUNT_FINAL INT = 0, + @TOTAL_MODULES INT = 0, + @TOTAL_TABLES INT = 0, + @TOTAL_COLUMNS INT = 0, + @TOTAL_DATA_COLUMNS INT = 0, + @TOTAL_DATA_ROWS BIGINT = 0, + @TOTAL_ERRORS INT = 0, + @TOTAL_REPLACE_PLANNED INT = 0, + @TOTAL_REPLACE_UPDATED INT = 0, + @TOTAL_REPLACE_SKIPPED INT = 0, + @TOTAL_REPLACE_ERRORS INT = 0, + @TOTAL_DATA_REPLACE_PLANNED INT = 0, + @TOTAL_DATA_REPLACE_UPDATED INT = 0, + @TOTAL_DATA_REPLACE_SKIPPED INT = 0, + @TOTAL_DATA_REPLACE_ERRORS INT = 0, + @TOTAL_DATA_REPLACE_ROWS BIGINT = 0, + @TOTAL_AGENT_JOBS INT = 0, + @COUNT_MODULES INT = 0, + @COUNT_TABLES INT = 0, + @COUNT_COLUMNS INT = 0, + @COUNT_DATA_COLUMNS INT = 0, + @COUNT_DATA_ROWS BIGINT = 0, + @COUNT_DATA_PLAN INT = 0, + @COUNT_DATA_UPD INT = 0, + @COUNT_DATA_SKIP INT = 0, + @COUNT_DATA_ERR INT = 0, + @COUNT_DB_ERRORS INT = 0, + @COUNT_PLANNED INT = 0, + @COUNT_UPDATED INT = 0, + @COUNT_SKIPPED INT = 0, + @COUNT_REPL_ERR INT = 0, + @START_TRANCOUNT INT = @@TRANCOUNT, + @HAS_ENTRY_SAVEPOINT BIT = 0, + @RETURN_STATUS INT = 0, + @RETURN_STATUS_TEXT NVARCHAR(MAX) = concat('START PROCEDURE [',@MY_PROCEDURE_NAME, '] @ ', CONVERT(varchar(50),GETDATE(),120)), + @RETURN_ERROR_TEXT NVARCHAR(MAX) = ''; ---------------------------------------------------------------------------------------------------------------------------- IF (@DOREPLACEDATAVALUES = 1) BEGIN @@ -90,7 +129,7 @@ BEGIN --=================================================-- Flow / Parameter output --==========================================-- PRINT '===================================================================================================='; - PRINT @return_status_text; + PRINT @RETURN_STATUS_TEXT; PRINT ''; PRINT 'PARAMETER01 - @SEARCHVALUE: ' + CONVERT(NVARCHAR(200),@SEARCHVALUE); PRINT 'PARAMETER02 - @INCLUDEDATABASES: ' + CONVERT(NVARCHAR(200),ISNULL(@INCLUDEDATABASES,N'')); @@ -99,80 +138,55 @@ BEGIN PRINT 'PARAMETER05 - @DOREPLACE: ' + CONVERT(NVARCHAR(10),@DOREPLACE); PRINT 'PARAMETER06 - @INCLUDEDATAVALUES: ' + CONVERT(NVARCHAR(10),@INCLUDEDATAVALUES); PRINT 'PARAMETER07 - @DOREPLACEDATAVALUES: ' + CONVERT(NVARCHAR(10),@DOREPLACEDATAVALUES); + PRINT 'PARAMETER08 - @ALLOWDIRTYREADS: ' + CONVERT(NVARCHAR(10),@ALLOWDIRTYREADS); + PRINT 'PARAMETER09 - @INCLUDEAGENTJOBS: ' + CONVERT(NVARCHAR(10),@INCLUDEAGENTJOBS); + PRINT 'PARAMETER10 - @MAXDATACOLUMNSPERDB: ' + CONVERT(NVARCHAR(20),@MAXDATACOLUMNSPERDB); PRINT ''; IF (@REPLACEWITH IS NOT NULL) AND (LEN(@REPLACEWITH) > 0) AND (@DOREPLACE = 0) BEGIN PRINT 'MODE: SEARCH + REPLACE PLAN (DRY-RUN) - no changes will be executed.'; PRINT 'INFO: Resultset [OBJECT_DEFINITION] contains the CURRENT definition (no replace applied).'; - END - ELSE IF (@REPLACEWITH IS NOT NULL) AND (LEN(@REPLACEWITH) > 0) AND (@DOREPLACE = 1) BEGIN + END ELSE IF (@REPLACEWITH IS NOT NULL) AND (LEN(@REPLACEWITH) > 0) AND (@DOREPLACE = 1) BEGIN PRINT 'MODE: SEARCH + REPLACE EXECUTION - module definitions may be ALTERed!'; PRINT 'INFO: Resultset [OBJECT_DEFINITION] may contain PRE-REPLACE definitions (captured before ALTER).'; - END - ELSE BEGIN + END ELSE BEGIN PRINT 'MODE: SEARCH ONLY'; END; - IF ((@DOREPLACE = 1) OR (@DOREPLACEDATAVALUES = 1)) AND (@REPLACEWITH IS NOT NULL) AND (@SEARCHVALUE = @REPLACEWITH) BEGIN + -- F23: Explicit COLLATE avoids implicit collation pitfalls between variables + IF ((@DOREPLACE = 1) OR (@DOREPLACEDATAVALUES = 1)) AND (@REPLACEWITH IS NOT NULL) AND (@SEARCHVALUE COLLATE DATABASE_DEFAULT = @REPLACEWITH COLLATE DATABASE_DEFAULT) BEGIN PRINT 'WARNING: @SEARCHVALUE equals @REPLACEWITH -> replace execution will do no functional changes.'; END; IF (@INCLUDEDATAVALUES = 1) BEGIN PRINT 'DATA VALUE SCAN: ENABLED (text-like columns in user tables).'; - END - ELSE BEGIN + END ELSE BEGIN PRINT 'DATA VALUE SCAN: DISABLED.'; END; IF (@DOREPLACEDATAVALUES = 1) BEGIN PRINT 'DATA VALUE REPLACE: EXECUTION ENABLED (matched rows in text-like columns will be updated).'; - END - ELSE IF (@REPLACEWITH IS NOT NULL) AND (LEN(@REPLACEWITH) > 0) AND (@INCLUDEDATAVALUES = 1) BEGIN + END ELSE IF (@REPLACEWITH IS NOT NULL) AND (LEN(@REPLACEWITH) > 0) AND (@INCLUDEDATAVALUES = 1) BEGIN PRINT 'DATA VALUE REPLACE: PLAN ONLY (no data row updates).'; END; PRINT '----------------------------------------------------------------------------------------------------'; ---------------------------------------------------------------------------------------------------------------------------- - --=================================================-- Validate parameters --==============================================-- - IF (@SEARCHVALUE IS NULL) OR (LEN(@SEARCHVALUE) = 0) BEGIN - SET @return_status = 10; - SET @return_status_text = 'ERROR: @pSEARCHVALUE must not be NULL/empty!'; - PRINT @return_status_text; - RAISERROR(@return_status_text,16,1); - RETURN @return_status; - END; - - IF (@DOREPLACE = 1) AND ((@REPLACEWITH IS NULL) OR (LEN(@REPLACEWITH) = 0)) BEGIN - SET @return_status = 11; - SET @return_status_text = 'ERROR: @pREPLACEWITH must be set when @pDOREPLACE = 1!'; - PRINT @return_status_text; - RAISERROR(@return_status_text,16,1); - RETURN @return_status; - END; - - IF (@DOREPLACEDATAVALUES = 1) AND ((@REPLACEWITH IS NULL) OR (LEN(@REPLACEWITH) = 0)) BEGIN - SET @return_status = 12; - SET @return_status_text = 'ERROR: @pREPLACEWITH must be set when @pDOREPLACEDATAVALUES = 1!'; - PRINT @return_status_text; - RAISERROR(@return_status_text,16,1); - RETURN @return_status; - END; - - PRINT 'STEP: Parameter validation OK.'; - PRINT '----------------------------------------------------------------------------------------------------'; - ---------------------------------------------------------------------------------------------------------------------------- + SET @NOLOCK_HINT = CASE WHEN @ALLOWDIRTYREADS = 1 THEN N' WITH (NOLOCK)' ELSE N'' END; --==============================================-- Prepare temp tables --================================================-- - IF OBJECT_ID('tempdb..#TBDD_GET_DATABASE_OBJECT_DB_INCLUDE') IS NOT NULL BEGIN DROP TABLE #TBDD_GET_DATABASE_OBJECT_DB_INCLUDE; END; - IF OBJECT_ID('tempdb..#TBDD_GET_DATABASE_OBJECT_DB_EXCLUDE') IS NOT NULL BEGIN DROP TABLE #TBDD_GET_DATABASE_OBJECT_DB_EXCLUDE; END; - IF OBJECT_ID('tempdb..#TBDD_GET_DATABASE_OBJECT_DB_LIST') IS NOT NULL BEGIN DROP TABLE #TBDD_GET_DATABASE_OBJECT_DB_LIST; END; - - IF OBJECT_ID('tempdb..#TBDD_GET_DATABASE_OBJECT_RESULTS') IS NOT NULL BEGIN DROP TABLE #TBDD_GET_DATABASE_OBJECT_RESULTS; END; - IF OBJECT_ID('tempdb..#TBDD_GET_DATABASE_OBJECT_DATAMATCHES') IS NOT NULL BEGIN DROP TABLE #TBDD_GET_DATABASE_OBJECT_DATAMATCHES; END; - IF OBJECT_ID('tempdb..#TBDD_GET_DATABASE_OBJECT_DATAREPLACELOG') IS NOT NULL BEGIN DROP TABLE #TBDD_GET_DATABASE_OBJECT_DATAREPLACELOG; END; - IF OBJECT_ID('tempdb..#TBDD_GET_DATABASE_OBJECT_REPLACELOG') IS NOT NULL BEGIN DROP TABLE #TBDD_GET_DATABASE_OBJECT_REPLACELOG; END; - IF OBJECT_ID('tempdb..#TBDD_GET_DATABASE_OBJECT_ERRORS') IS NOT NULL BEGIN DROP TABLE #TBDD_GET_DATABASE_OBJECT_ERRORS; END; + -- R01: Temp tables must exist before validation, because GOTO EMPTY_RESULTSETS + -- references them. Moved above parameter validation to prevent runtime errors. + DROP TABLE IF EXISTS #TBDD_GET_DATABASE_OBJECT_DB_INCLUDE; + DROP TABLE IF EXISTS #TBDD_GET_DATABASE_OBJECT_DB_EXCLUDE; + DROP TABLE IF EXISTS #TBDD_GET_DATABASE_OBJECT_DB_LIST; + DROP TABLE IF EXISTS #TBDD_GET_DATABASE_OBJECT_RESULTS; + DROP TABLE IF EXISTS #TBDD_GET_DATABASE_OBJECT_DATAMATCHES; + DROP TABLE IF EXISTS #TBDD_GET_DATABASE_OBJECT_DATAREPLACELOG; + DROP TABLE IF EXISTS #TBDD_GET_DATABASE_OBJECT_REPLACELOG; + DROP TABLE IF EXISTS #TBDD_GET_DATABASE_OBJECT_ERRORS; + DROP TABLE IF EXISTS #TBDD_GET_DATABASE_OBJECT_AGENTJOBS; CREATE TABLE #TBDD_GET_DATABASE_OBJECT_DB_INCLUDE ( [DBNAME] [NVARCHAR](128) NOT NULL PRIMARY KEY CLUSTERED ([DBNAME] ASC) @@ -231,10 +245,61 @@ BEGIN [ERROR_MESSAGE] [NVARCHAR](MAX) NOT NULL ); + CREATE TABLE #TBDD_GET_DATABASE_OBJECT_AGENTJOBS ( + [MATCH_TYPE] [NVARCHAR](20) NOT NULL, -- JOB_NAME / JOB_STEP_NAME / JOB_STEP_BODY + [JOB_NAME] [NVARCHAR](128) NOT NULL, + [JOB_ENABLED] [BIT] NOT NULL, + [STEP_ID] [INT] NULL, + [STEP_NAME] [NVARCHAR](128) NULL, + [STEP_SUBSYSTEM] [NVARCHAR](40) NULL, + [STEP_DATABASE] [NVARCHAR](128) NULL, + [STEP_COMMAND] [NVARCHAR](MAX) NULL + ); + PRINT 'STEP: Temporary tables prepared (#TBDD_GET_DATABASE_OBJECT_*).'; PRINT '----------------------------------------------------------------------------------------------------'; ---------------------------------------------------------------------------------------------------------------------------- + IF @START_TRANCOUNT > 0 BEGIN + SAVE TRANSACTION DD_PRDD_ENTRY; + SET @HAS_ENTRY_SAVEPOINT = 1; + END; + + BEGIN TRY + + --=================================================-- Validate parameters --==============================================-- + IF (@SEARCHVALUE IS NULL) OR (LEN(@SEARCHVALUE) = 0) BEGIN + SET @RETURN_STATUS = 10; + SET @RETURN_STATUS_TEXT = 'ERROR: @pSEARCHVALUE must not be NULL/empty!'; + PRINT @RETURN_STATUS_TEXT; + THROW 50000, @RETURN_STATUS_TEXT, 1; + END; + + IF (@DOREPLACE = 1) AND ((@REPLACEWITH IS NULL) OR (LEN(@REPLACEWITH) = 0)) BEGIN + SET @RETURN_STATUS = 11; + SET @RETURN_STATUS_TEXT = 'ERROR: @pREPLACEWITH must be set when @pDOREPLACE = 1!'; + PRINT @RETURN_STATUS_TEXT; + THROW 50000, @RETURN_STATUS_TEXT, 1; + END; + + IF (@DOREPLACEDATAVALUES = 1) AND ((@REPLACEWITH IS NULL) OR (LEN(@REPLACEWITH) = 0)) BEGIN + SET @RETURN_STATUS = 12; + SET @RETURN_STATUS_TEXT = 'ERROR: @pREPLACEWITH must be set when @pDOREPLACEDATAVALUES = 1!'; + PRINT @RETURN_STATUS_TEXT; + THROW 50000, @RETURN_STATUS_TEXT, 1; + END; + + IF (@MAXDATACOLUMNSPERDB < 0) BEGIN + SET @RETURN_STATUS = 13; + SET @RETURN_STATUS_TEXT = 'ERROR: @pMAXDATACOLUMNSPERDB must be >= 0!'; + PRINT @RETURN_STATUS_TEXT; + THROW 50000, @RETURN_STATUS_TEXT, 1; + END; + + PRINT 'STEP: Parameter validation OK.'; + PRINT '----------------------------------------------------------------------------------------------------'; + ---------------------------------------------------------------------------------------------------------------------------- + --===========================================-- Parse whitelist / blacklist --===========================================-- IF (@INCLUDEDATABASES IS NOT NULL) BEGIN INSERT INTO #TBDD_GET_DATABASE_OBJECT_DB_INCLUDE([DBNAME]) @@ -244,8 +309,7 @@ BEGIN AND TRY_CONVERT(NVARCHAR(128),LTRIM(RTRIM([value]))) IS NOT NULL; PRINT 'STEP: Whitelist parsed: ' + CONVERT(NVARCHAR(20),@@ROWCOUNT) + ' entry/entries.'; - END - ELSE BEGIN + END ELSE BEGIN PRINT 'STEP: Whitelist not set -> all user DBs are candidates (before blacklist).'; END; @@ -257,50 +321,45 @@ BEGIN AND TRY_CONVERT(NVARCHAR(128),LTRIM(RTRIM([value]))) IS NOT NULL; PRINT 'STEP: Blacklist parsed: ' + CONVERT(NVARCHAR(20),@@ROWCOUNT) + ' entry/entries.'; - END - ELSE BEGIN - PRINT 'STEP: Blacklist not set.'; + END ELSE BEGIN + PRINT 'STEP: Blacklist not set -> no user DBs are excluded.'; END; PRINT '----------------------------------------------------------------------------------------------------'; ---------------------------------------------------------------------------------------------------------------------------- --====================================-- Validate: DB names exist (whitelist/blacklist) --==============================-- - DECLARE @MissingInclude NVARCHAR(MAX) = NULL; - DECLARE @MissingExclude NVARCHAR(MAX) = NULL; - SELECT @MissingInclude = + SELECT @MISSING_INCLUDE = STUFF(( SELECT N', ' + i.[DBNAME] FROM #TBDD_GET_DATABASE_OBJECT_DB_INCLUDE i - LEFT JOIN [sys].[databases] d ON d.[name] = i.[DBNAME] + LEFT JOIN [sys].[databases] d ON d.[name] COLLATE DATABASE_DEFAULT = i.[DBNAME] WHERE d.[name] IS NULL FOR XML PATH(''), TYPE ).value('.','NVARCHAR(MAX)'),1,2,N''); - IF (@MissingInclude IS NOT NULL) AND (LEN(@MissingInclude) > 0) BEGIN - SET @return_status = 20; - SET @return_status_text = 'ERROR: Whitelist contains non-existing database(s): ' + @MissingInclude; - PRINT @return_status_text; - RAISERROR(@return_status_text,16,1); - RETURN @return_status; + IF (@MISSING_INCLUDE IS NOT NULL) AND (LEN(@MISSING_INCLUDE) > 0) BEGIN + SET @RETURN_STATUS = 20; + SET @RETURN_STATUS_TEXT = 'ERROR: Whitelist contains non-existing database(s): ' + @MISSING_INCLUDE; + PRINT @RETURN_STATUS_TEXT; + THROW 50000, @RETURN_STATUS_TEXT, 1; END; - SELECT @MissingExclude = + SELECT @MISSING_EXCLUDE = STUFF(( SELECT N', ' + e.[DBNAME] FROM #TBDD_GET_DATABASE_OBJECT_DB_EXCLUDE e - LEFT JOIN [sys].[databases] d ON d.[name] = e.[DBNAME] + LEFT JOIN [sys].[databases] d ON d.[name] COLLATE DATABASE_DEFAULT = e.[DBNAME] WHERE d.[name] IS NULL FOR XML PATH(''), TYPE ).value('.','NVARCHAR(MAX)'),1,2,N''); - IF (@MissingExclude IS NOT NULL) AND (LEN(@MissingExclude) > 0) BEGIN - SET @return_status = 21; - SET @return_status_text = 'ERROR: Blacklist contains non-existing database(s): ' + @MissingExclude; - PRINT @return_status_text; - RAISERROR(@return_status_text,16,1); - RETURN @return_status; + IF (@MISSING_EXCLUDE IS NOT NULL) AND (LEN(@MISSING_EXCLUDE) > 0) BEGIN + SET @RETURN_STATUS = 21; + SET @RETURN_STATUS_TEXT = 'ERROR: Blacklist contains non-existing database(s): ' + @MISSING_EXCLUDE; + PRINT @RETURN_STATUS_TEXT; + THROW 50000, @RETURN_STATUS_TEXT, 1; END; PRINT 'STEP: Database name validation OK (whitelist/blacklist).'; @@ -310,14 +369,14 @@ BEGIN --===========================-- Validate: included DBs are eligible & accessible --======================================-- IF EXISTS (SELECT 1 FROM #TBDD_GET_DATABASE_OBJECT_DB_INCLUDE) BEGIN - DECLARE @BadInclude NVARCHAR(MAX) = NULL; + SET @BAD_INCLUDE = NULL; - SELECT @BadInclude = + SELECT @BAD_INCLUDE = STUFF(( SELECT N', ' + i.[DBNAME] FROM #TBDD_GET_DATABASE_OBJECT_DB_INCLUDE i LEFT JOIN [sys].[databases] d - ON d.[name] = i.[DBNAME] + ON d.[name] COLLATE DATABASE_DEFAULT = i.[DBNAME] AND d.[database_id] > 4 AND d.[state_desc] = N'ONLINE' AND d.[is_distributor] = 0 @@ -328,12 +387,11 @@ BEGIN FOR XML PATH(''), TYPE ).value('.','NVARCHAR(MAX)'),1,2,N''); - IF (@BadInclude IS NOT NULL) AND (LEN(@BadInclude) > 0) BEGIN - SET @return_status = 22; - SET @return_status_text = 'ERROR: Whitelist contains database(s) that are not searchable (system/offline/snapshot/no access/read-only in replace-mode): ' + @BadInclude; - PRINT @return_status_text; - RAISERROR(@return_status_text,16,1); - RETURN @return_status; + IF (@BAD_INCLUDE IS NOT NULL) AND (LEN(@BAD_INCLUDE) > 0) BEGIN + SET @RETURN_STATUS = 22; + SET @RETURN_STATUS_TEXT = 'ERROR: Whitelist contains database(s) that are not searchable (system/offline/snapshot/no access/read-only in replace-mode): ' + @BAD_INCLUDE; + PRINT @RETURN_STATUS_TEXT; + THROW 50000, @RETURN_STATUS_TEXT, 1; END; END; @@ -361,56 +419,55 @@ BEGIN ) AND d.[name] NOT IN (SELECT [DBNAME] FROM #TBDD_GET_DATABASE_OBJECT_DB_EXCLUDE); - DECLARE @DBCOUNT INT = (SELECT COUNT(*) FROM #TBDD_GET_DATABASE_OBJECT_DB_LIST); + SET @DBCOUNT = (SELECT COUNT(*) FROM #TBDD_GET_DATABASE_OBJECT_DB_LIST); PRINT 'STEP: Worklist created: ' + CONVERT(NVARCHAR(20),@DBCOUNT) + ' database(s).'; PRINT '----------------------------------------------------------------------------------------------------'; IF (@DBCOUNT = 0) BEGIN PRINT 'INFO: No databases to process based on whitelist/blacklist and eligibility filters.'; - PRINT 'END PROCEDURE [' + @MY_PROCEDURE_NAME + '] @ ' + CONVERT(varchar(50),GETDATE(),120); - PRINT '===================================================================================================='; - RETURN 0; + -- R05: Temp tables are empty -> GOTO EMPTY_RESULTSETS outputs 0-row resultsets via central path + GOTO EMPTY_RESULTSETS; END; ---------------------------------------------------------------------------------------------------------------------------- --===============================================-- Search / Replace loop --=============================================-- - BEGIN TRY - - DECLARE @DBINDEX INT = 0; + SET @DBINDEX = 0; DECLARE db_cur CURSOR LOCAL FAST_FORWARD FOR SELECT [DBNAME] FROM #TBDD_GET_DATABASE_OBJECT_DB_LIST ORDER BY [DBNAME]; OPEN db_cur; - FETCH NEXT FROM db_cur INTO @CurrentDB; + FETCH NEXT FROM db_cur INTO @CURRENT_DB; WHILE @@FETCH_STATUS = 0 BEGIN SET @DBINDEX = @DBINDEX + 1; - SELECT @CurrentDBCollation = d.[collation_name] FROM [sys].[databases] d WHERE d.[name] COLLATE DATABASE_DEFAULT = @CurrentDB; - - IF (@CurrentDBCollation IS NULL) BEGIN - SET @return_status = 23; - SET @return_status_text = 'ERROR: Could not resolve collation for database [' + @CurrentDB + '].'; - PRINT @return_status_text; + SET @DB_START_TIME = SYSDATETIME(); + SET @CURRENT_DB_COLLATION = NULL; -- F15: Reset before SELECT to avoid stale value on no-match + SELECT @CURRENT_DB_COLLATION = d.[collation_name] FROM [sys].[databases] d WHERE d.[name] COLLATE DATABASE_DEFAULT = @CURRENT_DB; + + IF (@CURRENT_DB_COLLATION IS NULL) BEGIN + SET @RETURN_STATUS = 23; + SET @RETURN_STATUS_TEXT = 'ERROR: Could not resolve collation for database [' + @CURRENT_DB + '].'; + PRINT @RETURN_STATUS_TEXT; IF CURSOR_STATUS('local','db_cur') >= 0 CLOSE db_cur; IF CURSOR_STATUS('local','db_cur') >= -1 DEALLOCATE db_cur; - RAISERROR(@return_status_text,16,1); - RETURN @return_status; + THROW 50000, @RETURN_STATUS_TEXT, 1; END; PRINT '----------------------------------------------------------------------------------------------------'; - PRINT 'PROCESSING DATABASE [' + @CurrentDB + '] (' + CONVERT(NVARCHAR(10),@DBINDEX) + '/' + CONVERT(NVARCHAR(10),@DBCOUNT) + ')'; + PRINT 'PROCESSING DATABASE [' + @CURRENT_DB + '] (' + CONVERT(NVARCHAR(10),@DBINDEX) + '/' + CONVERT(NVARCHAR(10),@DBCOUNT) + ')'; PRINT 'STEP: Scan modules/tables/columns' + CASE WHEN (@INCLUDEDATAVALUES = 1) THEN '/data values' ELSE '' END + CASE WHEN (@REPLACEWITH IS NOT NULL) AND (LEN(@REPLACEWITH) > 0) THEN ' + replace handling (module/data plan)' ELSE '' END + CASE WHEN (@DOREPLACEDATAVALUES = 1) THEN ' + data replace execution' ELSE '' END + '.'; - SET @SQLCommand = N' -BEGIN TRY - USE ' + QUOTENAME(@CurrentDB) + N'; + -- F08: @SQL_COMMAND is NVARCHAR(MAX) (~1 GB capacity). Generated SQL grows linearly + -- per-database with collation-placeholder replacements and is well within limits. + SET @SQL_COMMAND = N' + USE ' + QUOTENAME(@CURRENT_DB) + N'; DECLARE @sv NVARCHAR(100) = @pSEARCHVALUE; DECLARE @svLIKE NVARCHAR(400) = REPLACE(REPLACE(REPLACE(@sv, N''['', N''[[]''), N''%'', N''[%]''), N''_'', N''[_]''); @@ -418,6 +475,7 @@ BEGIN TRY DECLARE @do BIT = @pDOREPLACE; DECLARE @scanData BIT = @pINCLUDEDATAVALUES; DECLARE @doDataReplace BIT = @pDOREPLACEDATAVALUES; + DECLARE @maxDataColsEffective INT = CASE WHEN @pMAXDATACOLUMNSPERDB > 0 THEN @pMAXDATACOLUMNSPERDB ELSE 2147483647 END; -- 1) Modules (find) INSERT INTO #TBDD_GET_DATABASE_OBJECT_RESULTS([DATABASE_NAME],[OBJECT_TYPE],[SCHEMA_NAME],[OBJECT_NAME],[COLUMN_NAME],[OBJECT_DEFINITION]) @@ -431,8 +489,8 @@ BEGIN TRY FROM [sys].[sql_modules] m JOIN [sys].[objects] o ON m.[object_id] = o.[object_id] JOIN [sys].[schemas] s ON o.[schema_id] = s.[schema_id] - WHERE o.[type] COLLATE __COLLATION__ IN (N''P'',N''PC'',N''V'',N''FN'',N''TF'',N''IF'',N''TR'') - AND m.[definition] COLLATE __COLLATION__ LIKE N''%'' + (@svLIKE COLLATE __COLLATION__) + N''%''; + WHERE o.[type] COLLATE __DD_COLLATION_A7F3__ IN (N''P'',N''V'',N''FN'',N''TF'',N''IF'',N''TR'') + AND m.[definition] COLLATE __DD_COLLATION_A7F3__ LIKE N''%'' + (@svLIKE COLLATE __DD_COLLATION_A7F3__) + N''%''; -- Optional: plan/execute replacement (modules only) IF (@rv IS NOT NULL) AND (LEN(@rv) > 0) BEGIN @@ -446,15 +504,15 @@ BEGIN TRY s.[name], o.[name], CASE WHEN LEN(@sv) = 0 THEN 0 - ELSE (LEN(m.[definition]) - LEN(REPLACE(m.[definition] COLLATE __COLLATION__,@sv COLLATE __COLLATION__,N''''))) / NULLIF(LEN(@sv),0) + ELSE (LEN(m.[definition]) - LEN(REPLACE(m.[definition] COLLATE __DD_COLLATION_A7F3__,@sv COLLATE __DD_COLLATION_A7F3__,N''''))) / NULLIF(LEN(@sv),0) END, N''PLANNED'', NULL FROM [sys].[sql_modules] m JOIN [sys].[objects] o ON m.[object_id] = o.[object_id] JOIN [sys].[schemas] s ON o.[schema_id] = s.[schema_id] - WHERE o.[type] COLLATE __COLLATION__ IN (N''P'',N''PC'',N''V'',N''FN'',N''TF'',N''IF'',N''TR'') - AND m.[definition] COLLATE __COLLATION__ LIKE N''%'' + (@svLIKE COLLATE __COLLATION__) + N''%''; + WHERE o.[type] COLLATE __DD_COLLATION_A7F3__ IN (N''P'',N''V'',N''FN'',N''TF'',N''IF'',N''TR'') + AND m.[definition] COLLATE __DD_COLLATION_A7F3__ LIKE N''%'' + (@svLIKE COLLATE __DD_COLLATION_A7F3__) + N''%''; END ELSE BEGIN @@ -475,15 +533,16 @@ BEGIN TRY @cStart INT, @cEnd INT, @pos INT, - @occ INT; + @occ INT, + @moduleTranStarted BIT; DECLARE cur CURSOR LOCAL FAST_FORWARD FOR SELECT o.[object_id], o.[type], o.[type_desc], s.[name], o.[name], m.[definition] FROM [sys].[sql_modules] m JOIN [sys].[objects] o ON m.[object_id] = o.[object_id] JOIN [sys].[schemas] s ON o.[schema_id] = s.[schema_id] - WHERE o.[type] COLLATE __COLLATION__ IN (N''P'',N''PC'',N''V'',N''FN'',N''TF'',N''IF'',N''TR'') - AND m.[definition] COLLATE __COLLATION__ LIKE N''%'' + (@svLIKE COLLATE __COLLATION__) + N''%''; + WHERE o.[type] COLLATE __DD_COLLATION_A7F3__ IN (N''P'',N''V'',N''FN'',N''TF'',N''IF'',N''TR'') + AND m.[definition] COLLATE __DD_COLLATION_A7F3__ LIKE N''%'' + (@svLIKE COLLATE __DD_COLLATION_A7F3__) + N''%''; OPEN cur; FETCH NEXT FROM cur INTO @object_id, @type, @typedesc, @schema, @name, @def; @@ -493,10 +552,10 @@ BEGIN TRY SET @occ = CASE WHEN LEN(@sv) = 0 THEN 0 - ELSE (LEN(@def) - LEN(REPLACE(@def COLLATE __COLLATION__,@sv COLLATE __COLLATION__,N''''))) / NULLIF(LEN(@sv),0) + ELSE (LEN(@def) - LEN(REPLACE(@def COLLATE __DD_COLLATION_A7F3__,@sv COLLATE __DD_COLLATION_A7F3__,N''''))) / NULLIF(LEN(@sv),0) END; - SET @newdef = REPLACE(@def COLLATE __COLLATION__,@sv COLLATE __COLLATION__,@rv); + SET @newdef = REPLACE(@def COLLATE __DD_COLLATION_A7F3__,@sv COLLATE __DD_COLLATION_A7F3__,@rv); IF (@occ = 0) OR (@newdef = @def) BEGIN INSERT INTO #TBDD_GET_DATABASE_OBJECT_REPLACELOG([DATABASE_NAME],[OBJECT_TYPE],[SCHEMA_NAME],[OBJECT_NAME],[OCCURRENCE_COUNT],[ACTION],[ERROR_MESSAGE]) @@ -507,23 +566,26 @@ BEGIN TRY END; SET @execdef = @newdef; - SET @u = UPPER(@execdef COLLATE __COLLATION__); + SET @u = UPPER(@execdef COLLATE __DD_COLLATION_A7F3__); -- F05: Strip comments from @u to avoid matching CREATE inside comments. -- Replaces comment text with spaces to preserve character positions. + -- R07: Note: String literals (e.g. N''CREATE PROC x'') are not stripped. + -- This is acceptable because sys.sql_modules.definition always starts + -- with the actual CREATE statement, so PATINDEX finds the real one first. SET @uClean = @u; -- Strip multi-line comments /* ... */ - SET @cStart = CHARINDEX(N''/*'', @uClean COLLATE __COLLATION__); + SET @cStart = CHARINDEX(N''/*'', @uClean COLLATE __DD_COLLATION_A7F3__); WHILE @cStart > 0 BEGIN - SET @cEnd = CHARINDEX(N''*/'', @uClean COLLATE __COLLATION__, @cStart + 2); + SET @cEnd = CHARINDEX(N''*/'', @uClean COLLATE __DD_COLLATION_A7F3__, @cStart + 2); IF @cEnd > 0 SET @uClean = LEFT(@uClean, @cStart - 1) + REPLICATE(N'' '', @cEnd - @cStart + 2) + SUBSTRING(@uClean, @cEnd + 2, LEN(@uClean)); ELSE BREAK; - SET @cStart = CHARINDEX(N''/*'', @uClean COLLATE __COLLATION__, @cStart + 1); + SET @cStart = CHARINDEX(N''/*'', @uClean COLLATE __DD_COLLATION_A7F3__, @cStart + 1); END; -- Strip single-line comments -- ... - SET @cStart = CHARINDEX(N''--'', @uClean COLLATE __COLLATION__); + SET @cStart = CHARINDEX(N''--'', @uClean COLLATE __DD_COLLATION_A7F3__); WHILE @cStart > 0 BEGIN SET @cEnd = CHARINDEX(NCHAR(10), @uClean, @cStart); IF @cEnd > 0 @@ -532,45 +594,72 @@ BEGIN TRY SET @uClean = LEFT(@uClean, @cStart - 1) + REPLICATE(N'' '', LEN(@uClean) - @cStart + 1); BREAK; END; - SET @cStart = CHARINDEX(N''--'', @uClean COLLATE __COLLATION__, @cStart + 1); + SET @cStart = CHARINDEX(N''--'', @uClean COLLATE __DD_COLLATION_A7F3__, @cStart + 1); END; -- If not already CREATE OR ALTER, try to replace first CREATE with ALTER for supported object kinds. - IF PATINDEX(N''%CREATE OR ALTER%'' COLLATE __COLLATION__, @uClean COLLATE __COLLATION__) = 0 BEGIN + IF PATINDEX(N''%CREATE OR ALTER%'' COLLATE __DD_COLLATION_A7F3__, @uClean COLLATE __DD_COLLATION_A7F3__) = 0 BEGIN SET @pos = 0; - IF @type COLLATE __COLLATION__ IN (N''P'',N''PC'') BEGIN - SET @pos = PATINDEX(N''%CREATE%PROCEDURE%'' COLLATE __COLLATION__, @uClean COLLATE __COLLATION__); - IF @pos = 0 SET @pos = PATINDEX(N''%CREATE%PROC%'' COLLATE __COLLATION__, @uClean COLLATE __COLLATION__); + -- N01: PC (CLR) types are excluded by the cursor filter; only P remains here + IF @type COLLATE __DD_COLLATION_A7F3__ = N''P'' BEGIN + SET @pos = PATINDEX(N''%CREATE%PROCEDURE%'' COLLATE __DD_COLLATION_A7F3__, @uClean COLLATE __DD_COLLATION_A7F3__); + IF @pos = 0 SET @pos = PATINDEX(N''%CREATE%PROC%'' COLLATE __DD_COLLATION_A7F3__, @uClean COLLATE __DD_COLLATION_A7F3__); END - ELSE IF @type COLLATE __COLLATION__ = N''V'' BEGIN - SET @pos = PATINDEX(N''%CREATE%VIEW%'' COLLATE __COLLATION__, @uClean COLLATE __COLLATION__); + ELSE IF @type COLLATE __DD_COLLATION_A7F3__ = N''V'' BEGIN + SET @pos = PATINDEX(N''%CREATE%VIEW%'' COLLATE __DD_COLLATION_A7F3__, @uClean COLLATE __DD_COLLATION_A7F3__); END - ELSE IF @type COLLATE __COLLATION__ IN (N''FN'',N''TF'',N''IF'') BEGIN - SET @pos = PATINDEX(N''%CREATE%FUNCTION%'' COLLATE __COLLATION__, @uClean COLLATE __COLLATION__); + ELSE IF @type COLLATE __DD_COLLATION_A7F3__ IN (N''FN'',N''TF'',N''IF'') BEGIN + SET @pos = PATINDEX(N''%CREATE%FUNCTION%'' COLLATE __DD_COLLATION_A7F3__, @uClean COLLATE __DD_COLLATION_A7F3__); END - ELSE IF @type COLLATE __COLLATION__ = N''TR'' BEGIN - SET @pos = PATINDEX(N''%CREATE%TRIGGER%'' COLLATE __COLLATION__, @uClean COLLATE __COLLATION__); + ELSE IF @type COLLATE __DD_COLLATION_A7F3__ = N''TR'' BEGIN + SET @pos = PATINDEX(N''%CREATE%TRIGGER%'' COLLATE __DD_COLLATION_A7F3__, @uClean COLLATE __DD_COLLATION_A7F3__); END; + -- F03: @pos found on @uClean (comments replaced with equal-length spaces), + -- so character positions match @execdef exactly. STUFF is safe. IF (@pos > 0) BEGIN - SET @execdef = STUFF(@execdef COLLATE __COLLATION__,@pos,6,N''ALTER'' COLLATE __COLLATION__); -- CREATE(6) -> ALTER + SET @execdef = STUFF(@execdef COLLATE __DD_COLLATION_A7F3__,@pos,6,N''ALTER'' COLLATE __DD_COLLATION_A7F3__); -- CREATE(6) -> ALTER END; END; BEGIN TRY + SET @moduleTranStarted = 0; + IF @@TRANCOUNT = 0 BEGIN + SET @moduleTranStarted = 1; + BEGIN TRAN; -- F04: per-object transaction for module ALTER + END + ELSE BEGIN + SAVE TRANSACTION DD_MOD_REPL; + END; + EXEC (@execdef); + IF @moduleTranStarted = 1 COMMIT TRAN; + INSERT INTO #TBDD_GET_DATABASE_OBJECT_REPLACELOG([DATABASE_NAME],[OBJECT_TYPE],[SCHEMA_NAME],[OBJECT_NAME],[OCCURRENCE_COUNT],[ACTION],[ERROR_MESSAGE]) VALUES (DB_NAME(),@typedesc,@schema,@name,@occ,N''UPDATED'',NULL); - END TRY BEGIN CATCH - + IF (XACT_STATE() = -1) AND (@moduleTranStarted = 1) BEGIN + ROLLBACK TRAN; + END + ELSE IF (XACT_STATE() = 1) BEGIN + IF @moduleTranStarted = 1 + ROLLBACK TRAN; + ELSE IF @@TRANCOUNT > 0 + ROLLBACK TRANSACTION DD_MOD_REPL; + END; INSERT INTO #TBDD_GET_DATABASE_OBJECT_REPLACELOG([DATABASE_NAME],[OBJECT_TYPE],[SCHEMA_NAME],[OBJECT_NAME],[OCCURRENCE_COUNT],[ACTION],[ERROR_MESSAGE]) - VALUES (DB_NAME(),@typedesc,@schema,@name,@occ,N''ERROR'',ERROR_MESSAGE() + N'' (Proc: '' + ISNULL(ERROR_PROCEDURE(),N'''') + N'' / Line: '' + CONVERT(NVARCHAR(10),ERROR_LINE()) + N'')''); - + VALUES (DB_NAME(),@typedesc,@schema,@name,@occ,N''ERROR'',ERROR_MESSAGE()); + INSERT INTO #TBDD_GET_DATABASE_OBJECT_ERRORS([DATABASE_NAME],[ERROR_NUMBER],[ERROR_MESSAGE]) + VALUES ( + DB_NAME(), + ERROR_NUMBER(), + N''MODULE_REPLACE [''+QUOTENAME(@schema)+N''.''+QUOTENAME(@name)+N'']: ''+ERROR_MESSAGE() + + N'' (ErrNo: '' + CONVERT(NVARCHAR(20),ERROR_NUMBER()) + N'' / Line: '' + CONVERT(NVARCHAR(10),ERROR_LINE()) + N'')'' + ); END CATCH; FETCH NEXT FROM cur INTO @object_id, @type, @typedesc, @schema, @name, @def; @@ -595,7 +684,7 @@ BEGIN TRY NULL FROM [sys].[tables] t JOIN [sys].[schemas] s ON t.[schema_id] = s.[schema_id] - WHERE t.[name] COLLATE __COLLATION__ LIKE N''%'' + (@svLIKE COLLATE __COLLATION__) + N''%''; + WHERE t.[name] COLLATE __DD_COLLATION_A7F3__ LIKE N''%'' + (@svLIKE COLLATE __DD_COLLATION_A7F3__) + N''%''; -- 3) Columns by name INSERT INTO #TBDD_GET_DATABASE_OBJECT_RESULTS([DATABASE_NAME],[OBJECT_TYPE],[SCHEMA_NAME],[OBJECT_NAME],[COLUMN_NAME],[OBJECT_DEFINITION]) @@ -609,9 +698,11 @@ BEGIN TRY FROM [sys].[columns] c JOIN [sys].[tables] t ON c.[object_id] = t.[object_id] JOIN [sys].[schemas] s ON t.[schema_id] = s.[schema_id] - WHERE c.[name] COLLATE __COLLATION__ LIKE N''%'' + (@svLIKE COLLATE __COLLATION__) + N''%''; + WHERE c.[name] COLLATE __DD_COLLATION_A7F3__ LIKE N''%'' + (@svLIKE COLLATE __DD_COLLATION_A7F3__) + N''%''; -- 4) Data values in text-like table columns (optional) + -- F11/P3: Data scan uses optional NOLOCK based on @pALLOWDIRTYREADS + -- (1=WITH (NOLOCK), 0=consistent reads). IF (@scanData = 1) BEGIN DECLARE @dSchema SYSNAME, @@ -622,10 +713,12 @@ BEGIN TRY @dUpdateSQL NVARCHAR(MAX), @dMatchCount BIGINT, @dUpdatedRows INT, - @dSample NVARCHAR(4000); + @dSample NVARCHAR(4000), + @dataTranStarted BIT; DECLARE cur_data_cols CURSOR LOCAL FAST_FORWARD FOR SELECT + TOP (@maxDataColsEffective) s.[name] AS [SCHEMA_NAME], t.[name] AS [TABLE_NAME], c.[name] AS [COLUMN_NAME], @@ -635,7 +728,8 @@ BEGIN TRY JOIN [sys].[columns] c ON t.[object_id] = c.[object_id] WHERE t.[is_ms_shipped] = 0 AND c.[is_computed] = 0 - AND TYPE_NAME(c.[system_type_id]) COLLATE __COLLATION__ IN (N''varchar'',N''nvarchar'',N''char'',N''nchar'',N''text'',N''ntext''); + AND TYPE_NAME(c.[system_type_id]) COLLATE __DD_COLLATION_A7F3__ IN (N''varchar'',N''nvarchar'',N''char'',N''nchar'',N''text'',N''ntext'') + ORDER BY s.[name], t.[name], c.[column_id]; OPEN cur_data_cols; FETCH NEXT FROM cur_data_cols INTO @dSchema, @dTable, @dColumn, @dSystemType; @@ -652,9 +746,9 @@ BEGIN TRY SET @dSQL = N'' SELECT @pMatchCount = COUNT_BIG(1), - @pSample = MIN(LEFT(TRY_CONVERT(NVARCHAR(MAX),'' + QUOTENAME(@dColumn) + N'') COLLATE __COLLATION__,4000)) -FROM '' + QUOTENAME(@dSchema) + N''.'' + QUOTENAME(@dTable) + N'' WITH (NOLOCK) -WHERE TRY_CONVERT(NVARCHAR(MAX),'' + QUOTENAME(@dColumn) + N'') COLLATE __COLLATION__ LIKE N''''%'''' + (@pSVLIKE COLLATE __COLLATION__) + N''''%'''';''; + @pSample = MIN(LEFT(TRY_CONVERT(NVARCHAR(MAX),'' + QUOTENAME(@dColumn) + N'') COLLATE __DD_COLLATION_A7F3__,4000)) +FROM '' + QUOTENAME(@dSchema) + N''.'' + QUOTENAME(@dTable) + N''' + @NOLOCK_HINT + N' +WHERE TRY_CONVERT(NVARCHAR(MAX),'' + QUOTENAME(@dColumn) + N'') COLLATE __DD_COLLATION_A7F3__ LIKE N''''%'''' + (@pSVLIKE COLLATE __DD_COLLATION_A7F3__) + N''''%'''';''; EXEC sp_executesql @dSQL, @@ -686,12 +780,13 @@ WHERE TRY_CONVERT(NVARCHAR(MAX),'' + QUOTENAME(@dColumn) + N'') COLLATE __COLLAT @dColumn, CONVERT(INT,CASE WHEN @dMatchCount > 2147483647 THEN 2147483647 ELSE @dMatchCount END), 0, - N''PLANNED'', - NULL + CASE WHEN @dSystemType IN (35,99) THEN N''SKIPPED'' ELSE N''PLANNED'' END, + CASE WHEN @dSystemType IN (35,99) THEN N''Data type TEXT/NTEXT not supported for replace execution.'' ELSE NULL END ); END ELSE BEGIN - IF (@sv = @rv) BEGIN + -- R02: Use target-DB collation for consistency with REPLACE collation + IF (@sv COLLATE __DD_COLLATION_A7F3__ = @rv COLLATE __DD_COLLATION_A7F3__) BEGIN INSERT INTO #TBDD_GET_DATABASE_OBJECT_DATAREPLACELOG([DATABASE_NAME],[SCHEMA_NAME],[TABLE_NAME],[COLUMN_NAME],[MATCH_COUNT],[UPDATED_ROWS],[ACTION],[ERROR_MESSAGE]) VALUES ( DB_NAME(), @@ -721,29 +816,71 @@ WHERE TRY_CONVERT(NVARCHAR(MAX),'' + QUOTENAME(@dColumn) + N'') COLLATE __COLLAT ELSE BEGIN SET @dUpdateSQL = N'' UPDATE '' + QUOTENAME(@dSchema) + N''.'' + QUOTENAME(@dTable) + N'' -SET '' + QUOTENAME(@dColumn) + N'' = REPLACE(TRY_CONVERT(NVARCHAR(MAX),'' + QUOTENAME(@dColumn) + N'') COLLATE __COLLATION__, @pSV COLLATE __COLLATION__, @pRV COLLATE __COLLATION__) -WHERE TRY_CONVERT(NVARCHAR(MAX),'' + QUOTENAME(@dColumn) + N'') COLLATE __COLLATION__ LIKE N''''%'''' + (@pSVLIKE COLLATE __COLLATION__) + N''''%''''; +SET '' + QUOTENAME(@dColumn) + N'' = REPLACE(TRY_CONVERT(NVARCHAR(MAX),'' + QUOTENAME(@dColumn) + N'') COLLATE __DD_COLLATION_A7F3__, @pSV COLLATE __DD_COLLATION_A7F3__, @pRV COLLATE __DD_COLLATION_A7F3__) +WHERE TRY_CONVERT(NVARCHAR(MAX),'' + QUOTENAME(@dColumn) + N'') COLLATE __DD_COLLATION_A7F3__ LIKE N''''%'''' + (@pSVLIKE COLLATE __DD_COLLATION_A7F3__) + N''''%''''; SET @pUpdatedRows = @@ROWCOUNT;''; - EXEC sp_executesql - @dUpdateSQL, - N''@pSV NVARCHAR(100), @pSVLIKE NVARCHAR(400), @pRV NVARCHAR(100), @pUpdatedRows INT OUTPUT'', - @pSV = @sv, - @pSVLIKE = @svLIKE, - @pRV = @rv, - @pUpdatedRows = @dUpdatedRows OUTPUT; + BEGIN TRY + SET @dataTranStarted = 0; + IF @@TRANCOUNT = 0 BEGIN + SET @dataTranStarted = 1; + BEGIN TRAN; -- F12: per-column transaction for data UPDATE + END + ELSE BEGIN + SAVE TRANSACTION DD_DATA_REPL; + END; + + EXEC sp_executesql + @dUpdateSQL, + N''@pSV NVARCHAR(100), @pSVLIKE NVARCHAR(400), @pRV NVARCHAR(100), @pUpdatedRows INT OUTPUT'', + @pSV = @sv, + @pSVLIKE = @svLIKE, + @pRV = @rv, + @pUpdatedRows = @dUpdatedRows OUTPUT; + + IF @dataTranStarted = 1 COMMIT TRAN; + + INSERT INTO #TBDD_GET_DATABASE_OBJECT_DATAREPLACELOG([DATABASE_NAME],[SCHEMA_NAME],[TABLE_NAME],[COLUMN_NAME],[MATCH_COUNT],[UPDATED_ROWS],[ACTION],[ERROR_MESSAGE]) + VALUES ( + DB_NAME(), + @dSchema, + @dTable, + @dColumn, + CONVERT(INT,CASE WHEN @dMatchCount > 2147483647 THEN 2147483647 ELSE @dMatchCount END), + ISNULL(@dUpdatedRows,0), + N''UPDATED'', + NULL + ); + END TRY BEGIN CATCH + IF (XACT_STATE() = -1) AND (@dataTranStarted = 1) BEGIN + ROLLBACK TRAN; + END + ELSE IF (XACT_STATE() = 1) BEGIN + IF @dataTranStarted = 1 + ROLLBACK TRAN; + ELSE IF @@TRANCOUNT > 0 + ROLLBACK TRANSACTION DD_DATA_REPL; + END; + INSERT INTO #TBDD_GET_DATABASE_OBJECT_DATAREPLACELOG([DATABASE_NAME],[SCHEMA_NAME],[TABLE_NAME],[COLUMN_NAME],[MATCH_COUNT],[UPDATED_ROWS],[ACTION],[ERROR_MESSAGE]) + VALUES ( + DB_NAME(), + @dSchema, + @dTable, + @dColumn, + CONVERT(INT,CASE WHEN @dMatchCount > 2147483647 THEN 2147483647 ELSE @dMatchCount END), + 0, + N''ERROR'', + ERROR_MESSAGE() + ); + INSERT INTO #TBDD_GET_DATABASE_OBJECT_ERRORS([DATABASE_NAME],[ERROR_NUMBER],[ERROR_MESSAGE]) + VALUES ( + DB_NAME(), + ERROR_NUMBER(), + N''DATA_REPLACE [''+QUOTENAME(@dSchema)+N''.''+QUOTENAME(@dTable)+N''.''+QUOTENAME(@dColumn)+N'']: ''+ERROR_MESSAGE() + + N'' (ErrNo: '' + CONVERT(NVARCHAR(20),ERROR_NUMBER()) + N'' / Line: '' + CONVERT(NVARCHAR(10),ERROR_LINE()) + N'')'' + ); + END CATCH; - INSERT INTO #TBDD_GET_DATABASE_OBJECT_DATAREPLACELOG([DATABASE_NAME],[SCHEMA_NAME],[TABLE_NAME],[COLUMN_NAME],[MATCH_COUNT],[UPDATED_ROWS],[ACTION],[ERROR_MESSAGE]) - VALUES ( - DB_NAME(), - @dSchema, - @dTable, - @dColumn, - CONVERT(INT,CASE WHEN @dMatchCount > 2147483647 THEN 2147483647 ELSE @dMatchCount END), - ISNULL(@dUpdatedRows,0), - N''UPDATED'', - NULL - ); END; END; END; @@ -752,32 +889,16 @@ SET @pUpdatedRows = @@ROWCOUNT;''; END; END TRY BEGIN CATCH - INSERT INTO #TBDD_GET_DATABASE_OBJECT_ERRORS([DATABASE_NAME],[ERROR_NUMBER],[ERROR_MESSAGE]) VALUES ( DB_NAME(), ERROR_NUMBER(), - N''DATA_SCAN ['' + @dSchema + N''.'' + @dTable + N''.'' + @dColumn + N'']: '' - + ERROR_MESSAGE() - + N'' (Proc: '' + ISNULL(ERROR_PROCEDURE(),N'''') + N'' / Line: '' + CONVERT(NVARCHAR(10),ERROR_LINE()) + N'')'' + N''DATA_SCAN [''+QUOTENAME(@dSchema)+N''.''+QUOTENAME(@dTable)+N''.''+QUOTENAME(@dColumn)+N'']: ''+ERROR_MESSAGE() + + N'' (ErrNo: '' + CONVERT(NVARCHAR(20),ERROR_NUMBER()) + N'' / Line: '' + CONVERT(NVARCHAR(10),ERROR_LINE()) + N'')'' ); - - IF (ISNULL(@dMatchCount,0) > 0) AND (@rv IS NOT NULL) AND (LEN(@rv) > 0) BEGIN - INSERT INTO #TBDD_GET_DATABASE_OBJECT_DATAREPLACELOG([DATABASE_NAME],[SCHEMA_NAME],[TABLE_NAME],[COLUMN_NAME],[MATCH_COUNT],[UPDATED_ROWS],[ACTION],[ERROR_MESSAGE]) - VALUES ( - DB_NAME(), - ISNULL(@dSchema,N''''), - ISNULL(@dTable,N''''), - ISNULL(@dColumn,N''''), - CONVERT(INT,CASE WHEN @dMatchCount > 2147483647 THEN 2147483647 ELSE @dMatchCount END), - 0, - N''ERROR'', - ERROR_MESSAGE() + N'' (Proc: '' + ISNULL(ERROR_PROCEDURE(),N'''') + N'' / Line: '' + CONVERT(NVARCHAR(10),ERROR_LINE()) + N'')'' - ); - END; - END CATCH; + FETCH NEXT FROM cur_data_cols INTO @dSchema, @dTable, @dColumn, @dSystemType; END; @@ -786,320 +907,234 @@ SET @pUpdatedRows = @@ROWCOUNT;''; END; -END TRY BEGIN CATCH - INSERT INTO #TBDD_GET_DATABASE_OBJECT_ERRORS([DATABASE_NAME],[ERROR_NUMBER],[ERROR_MESSAGE]) - VALUES ( - N''' + REPLACE(@CurrentDB,'''','''''') + N''', - ERROR_NUMBER(), - ERROR_MESSAGE() + N'' (Proc: '' + ISNULL(ERROR_PROCEDURE(),N'''') + N'' / Line: '' + CONVERT(NVARCHAR(10),ERROR_LINE()) + N'')'' - ); -END CATCH;'; - - IF (@DOREPLACE = 0) AND (@DOREPLACEDATAVALUES = 0) BEGIN - SET @SQLCommand = N' -BEGIN TRY - USE ' + QUOTENAME(@CurrentDB) + N'; - - DECLARE @sv NVARCHAR(100) = @pSEARCHVALUE; - DECLARE @svLIKE NVARCHAR(400) = REPLACE(REPLACE(REPLACE(@sv, N''['', N''[[]''), N''%'', N''[%]''), N''_'', N''[_]''); - DECLARE @rv NVARCHAR(100) = @pREPLACEWITH; - DECLARE @scanData BIT = @pINCLUDEDATAVALUES; - - -- 1) Modules (find) - INSERT INTO #TBDD_GET_DATABASE_OBJECT_RESULTS([DATABASE_NAME],[OBJECT_TYPE],[SCHEMA_NAME],[OBJECT_NAME],[COLUMN_NAME],[OBJECT_DEFINITION]) - SELECT - DB_NAME(), - o.[type_desc], - s.[name], - o.[name], - NULL, - m.[definition] - FROM [sys].[sql_modules] m - JOIN [sys].[objects] o ON m.[object_id] = o.[object_id] - JOIN [sys].[schemas] s ON o.[schema_id] = s.[schema_id] - WHERE o.[type] COLLATE __COLLATION__ IN (N''P'',N''PC'',N''V'',N''FN'',N''TF'',N''IF'',N''TR'') - AND m.[definition] COLLATE __COLLATION__ LIKE N''%'' + (@svLIKE COLLATE __COLLATION__) + N''%''; +'; - -- Optional: replace plan (modules only) - IF (@rv IS NOT NULL) AND (LEN(@rv) > 0) BEGIN - INSERT INTO #TBDD_GET_DATABASE_OBJECT_REPLACELOG([DATABASE_NAME],[OBJECT_TYPE],[SCHEMA_NAME],[OBJECT_NAME],[OCCURRENCE_COUNT],[ACTION],[ERROR_MESSAGE]) - SELECT - DB_NAME(), - o.[type_desc], - s.[name], - o.[name], - CASE WHEN LEN(@sv) = 0 THEN 0 - ELSE (LEN(m.[definition]) - LEN(REPLACE(m.[definition] COLLATE __COLLATION__,@sv COLLATE __COLLATION__,N''''))) / NULLIF(LEN(@sv),0) - END, - N''PLANNED'', - NULL - FROM [sys].[sql_modules] m - JOIN [sys].[objects] o ON m.[object_id] = o.[object_id] - JOIN [sys].[schemas] s ON o.[schema_id] = s.[schema_id] - WHERE o.[type] COLLATE __COLLATION__ IN (N''P'',N''PC'',N''V'',N''FN'',N''TF'',N''IF'',N''TR'') - AND m.[definition] COLLATE __COLLATION__ LIKE N''%'' + (@svLIKE COLLATE __COLLATION__) + N''%''; - END; + -- P3: Duplicate Search-Only dynamic SQL branch removed. + -- Replace-capable template above now handles all modes (search-only, plan, execute). - -- 2) Tables by name - INSERT INTO #TBDD_GET_DATABASE_OBJECT_RESULTS([DATABASE_NAME],[OBJECT_TYPE],[SCHEMA_NAME],[OBJECT_NAME],[COLUMN_NAME],[OBJECT_DEFINITION]) - SELECT - DB_NAME(), - N''TABLE'', - s.[name], - t.[name], - NULL, - NULL - FROM [sys].[tables] t - JOIN [sys].[schemas] s ON t.[schema_id] = s.[schema_id] - WHERE t.[name] COLLATE __COLLATION__ LIKE N''%'' + (@svLIKE COLLATE __COLLATION__) + N''%''; + SET @SQL_COMMAND = REPLACE(@SQL_COMMAND,N'__DD_COLLATION_A7F3__',@CURRENT_DB_COLLATION); - -- 3) Columns by name - INSERT INTO #TBDD_GET_DATABASE_OBJECT_RESULTS([DATABASE_NAME],[OBJECT_TYPE],[SCHEMA_NAME],[OBJECT_NAME],[COLUMN_NAME],[OBJECT_DEFINITION]) - SELECT - DB_NAME(), - N''COLUMN'', - s.[name], - t.[name], - c.[name], - NULL - FROM [sys].[columns] c - JOIN [sys].[tables] t ON c.[object_id] = t.[object_id] - JOIN [sys].[schemas] s ON t.[schema_id] = s.[schema_id] - WHERE c.[name] COLLATE __COLLATION__ LIKE N''%'' + (@svLIKE COLLATE __COLLATION__) + N''%''; + EXEC sp_executesql + @SQL_COMMAND, + N'@pSEARCHVALUE NVARCHAR(100), @pREPLACEWITH NVARCHAR(100), @pDOREPLACE BIT, @pINCLUDEDATAVALUES BIT, @pDOREPLACEDATAVALUES BIT, @pMAXDATACOLUMNSPERDB INT', + @pSEARCHVALUE = @SEARCHVALUE, + @pREPLACEWITH = @REPLACEWITH, + @pDOREPLACE = @DOREPLACE, + @pINCLUDEDATAVALUES = @INCLUDEDATAVALUES, + @pDOREPLACEDATAVALUES = @DOREPLACEDATAVALUES, + @pMAXDATACOLUMNSPERDB = @MAXDATACOLUMNSPERDB; - -- 4) Data values in text-like table columns (optional) - IF (@scanData = 1) BEGIN + -- Per-DB summary: N02 consolidated counting (one query per source table) + SELECT + @COUNT_TABLES = SUM(CASE WHEN [OBJECT_TYPE] COLLATE DATABASE_DEFAULT = N'TABLE' THEN 1 ELSE 0 END), + @COUNT_COLUMNS = SUM(CASE WHEN [OBJECT_TYPE] COLLATE DATABASE_DEFAULT = N'COLUMN' THEN 1 ELSE 0 END), + @COUNT_MODULES = SUM(CASE WHEN [OBJECT_TYPE] COLLATE DATABASE_DEFAULT NOT IN (N'TABLE',N'COLUMN') THEN 1 ELSE 0 END) + FROM #TBDD_GET_DATABASE_OBJECT_RESULTS + WHERE [DATABASE_NAME] COLLATE DATABASE_DEFAULT = @CURRENT_DB; - DECLARE @dSchema SYSNAME, - @dTable SYSNAME, - @dColumn SYSNAME, - @dSQL NVARCHAR(MAX), - @dMatchCount BIGINT, - @dSample NVARCHAR(4000); + SELECT + @COUNT_DATA_COLUMNS = COUNT(*), + @COUNT_DATA_ROWS = ISNULL(SUM(CONVERT(BIGINT,[MATCH_COUNT])),0) + FROM #TBDD_GET_DATABASE_OBJECT_DATAMATCHES + WHERE [DATABASE_NAME] COLLATE DATABASE_DEFAULT = @CURRENT_DB; - DECLARE cur_data_cols CURSOR LOCAL FAST_FORWARD FOR SELECT - s.[name] AS [SCHEMA_NAME], - t.[name] AS [TABLE_NAME], - c.[name] AS [COLUMN_NAME] - FROM [sys].[tables] t - JOIN [sys].[schemas] s ON t.[schema_id] = s.[schema_id] - JOIN [sys].[columns] c ON t.[object_id] = c.[object_id] - WHERE t.[is_ms_shipped] = 0 - AND c.[is_computed] = 0 - AND TYPE_NAME(c.[system_type_id]) COLLATE __COLLATION__ IN (N''varchar'',N''nvarchar'',N''char'',N''nchar'',N''text'',N''ntext''); + @COUNT_DATA_PLAN = SUM(CASE WHEN [ACTION] COLLATE DATABASE_DEFAULT = N'PLANNED' THEN 1 ELSE 0 END), + @COUNT_DATA_UPD = SUM(CASE WHEN [ACTION] COLLATE DATABASE_DEFAULT = N'UPDATED' THEN 1 ELSE 0 END), + @COUNT_DATA_SKIP = SUM(CASE WHEN [ACTION] COLLATE DATABASE_DEFAULT = N'SKIPPED' THEN 1 ELSE 0 END), + @COUNT_DATA_ERR = SUM(CASE WHEN [ACTION] COLLATE DATABASE_DEFAULT = N'ERROR' THEN 1 ELSE 0 END) + FROM #TBDD_GET_DATABASE_OBJECT_DATAREPLACELOG + WHERE [DATABASE_NAME] COLLATE DATABASE_DEFAULT = @CURRENT_DB; + + SELECT @COUNT_DB_ERRORS = COUNT(*) + FROM #TBDD_GET_DATABASE_OBJECT_ERRORS + WHERE [DATABASE_NAME] COLLATE DATABASE_DEFAULT = @CURRENT_DB; + + -- Coalesce NULLs from empty aggregations + SELECT @COUNT_MODULES = ISNULL(@COUNT_MODULES,0), @COUNT_TABLES = ISNULL(@COUNT_TABLES,0), + @COUNT_COLUMNS = ISNULL(@COUNT_COLUMNS,0), @COUNT_DATA_COLUMNS = ISNULL(@COUNT_DATA_COLUMNS,0), + @COUNT_DATA_PLAN = ISNULL(@COUNT_DATA_PLAN,0), @COUNT_DATA_UPD = ISNULL(@COUNT_DATA_UPD,0), + @COUNT_DATA_SKIP = ISNULL(@COUNT_DATA_SKIP,0), @COUNT_DATA_ERR = ISNULL(@COUNT_DATA_ERR,0); + + PRINT 'RESULT: [' + @CURRENT_DB + '] Modules=' + CONVERT(NVARCHAR(20),@COUNT_MODULES) + + ' Tables=' + CONVERT(NVARCHAR(20),@COUNT_TABLES) + + ' Columns=' + CONVERT(NVARCHAR(20),@COUNT_COLUMNS) + + ' DataCols=' + CONVERT(NVARCHAR(20),@COUNT_DATA_COLUMNS) + + ' DataRows=' + CONVERT(NVARCHAR(20),@COUNT_DATA_ROWS) + + ' Errors=' + CONVERT(NVARCHAR(20),@COUNT_DB_ERRORS); + SET @DB_DURATION_SEC = DATEDIFF(SECOND,@DB_START_TIME,SYSDATETIME()); + PRINT 'RESULT: [' + @CURRENT_DB + '] Duration (sec)=' + CONVERT(NVARCHAR(20),@DB_DURATION_SEC) + + CASE WHEN @MAXDATACOLUMNSPERDB > 0 THEN ' DataColumnLimit=' + CONVERT(NVARCHAR(20),@MAXDATACOLUMNSPERDB) ELSE '' END; - OPEN cur_data_cols; - FETCH NEXT FROM cur_data_cols INTO @dSchema, @dTable, @dColumn; + IF (@REPLACEWITH IS NOT NULL) AND (LEN(@REPLACEWITH) > 0) BEGIN - WHILE @@FETCH_STATUS = 0 - BEGIN - BEGIN TRY - SET @dMatchCount = 0; - SET @dSample = NULL; + SELECT + @COUNT_PLANNED = ISNULL(SUM(CASE WHEN [ACTION] COLLATE DATABASE_DEFAULT = N'PLANNED' THEN 1 ELSE 0 END),0), + @COUNT_UPDATED = ISNULL(SUM(CASE WHEN [ACTION] COLLATE DATABASE_DEFAULT = N'UPDATED' THEN 1 ELSE 0 END),0), + @COUNT_SKIPPED = ISNULL(SUM(CASE WHEN [ACTION] COLLATE DATABASE_DEFAULT = N'SKIPPED' THEN 1 ELSE 0 END),0), + @COUNT_REPL_ERR = ISNULL(SUM(CASE WHEN [ACTION] COLLATE DATABASE_DEFAULT = N'ERROR' THEN 1 ELSE 0 END),0) + FROM #TBDD_GET_DATABASE_OBJECT_REPLACELOG + WHERE [DATABASE_NAME] COLLATE DATABASE_DEFAULT = @CURRENT_DB; - SET @dSQL = N'' -SELECT - @pMatchCount = COUNT_BIG(1), - @pSample = MIN(LEFT(TRY_CONVERT(NVARCHAR(MAX),'' + QUOTENAME(@dColumn) + N'') COLLATE __COLLATION__,4000)) -FROM '' + QUOTENAME(@dSchema) + N''.'' + QUOTENAME(@dTable) + N'' WITH (NOLOCK) -WHERE TRY_CONVERT(NVARCHAR(MAX),'' + QUOTENAME(@dColumn) + N'') COLLATE __COLLATION__ LIKE N''''%'''' + (@pSVLIKE COLLATE __COLLATION__) + N''''%'''';''; + PRINT 'REPLACE: [' + @CURRENT_DB + '] Planned=' + CONVERT(NVARCHAR(20),@COUNT_PLANNED) + + ' Updated=' + CONVERT(NVARCHAR(20),@COUNT_UPDATED) + + ' Skipped=' + CONVERT(NVARCHAR(20),@COUNT_SKIPPED) + + ' Errors=' + CONVERT(NVARCHAR(20),@COUNT_REPL_ERR); - EXEC sp_executesql - @dSQL, - N''@pSV NVARCHAR(100), @pSVLIKE NVARCHAR(400), @pMatchCount BIGINT OUTPUT, @pSample NVARCHAR(4000) OUTPUT'', - @pSV = @sv, - @pSVLIKE = @svLIKE, - @pMatchCount = @dMatchCount OUTPUT, - @pSample = @dSample OUTPUT; + PRINT 'DATA REPLACE: [' + @CURRENT_DB + '] Planned=' + CONVERT(NVARCHAR(20),@COUNT_DATA_PLAN) + + ' Updated=' + CONVERT(NVARCHAR(20),@COUNT_DATA_UPD) + + ' Skipped=' + CONVERT(NVARCHAR(20),@COUNT_DATA_SKIP) + + ' Errors=' + CONVERT(NVARCHAR(20),@COUNT_DATA_ERR); - IF (ISNULL(@dMatchCount,0) > 0) BEGIN - INSERT INTO #TBDD_GET_DATABASE_OBJECT_DATAMATCHES([DATABASE_NAME],[SCHEMA_NAME],[TABLE_NAME],[COLUMN_NAME],[MATCH_COUNT],[SAMPLE_VALUE]) - VALUES ( - DB_NAME(), - @dSchema, - @dTable, - @dColumn, - CONVERT(INT,CASE WHEN @dMatchCount > 2147483647 THEN 2147483647 ELSE @dMatchCount END), - @dSample - ); + END; - IF (@rv IS NOT NULL) AND (LEN(@rv) > 0) BEGIN - INSERT INTO #TBDD_GET_DATABASE_OBJECT_DATAREPLACELOG([DATABASE_NAME],[SCHEMA_NAME],[TABLE_NAME],[COLUMN_NAME],[MATCH_COUNT],[UPDATED_ROWS],[ACTION],[ERROR_MESSAGE]) - VALUES ( - DB_NAME(), - @dSchema, - @dTable, - @dColumn, - CONVERT(INT,CASE WHEN @dMatchCount > 2147483647 THEN 2147483647 ELSE @dMatchCount END), - 0, - N''PLANNED'', - NULL - ); - END; - END; - END TRY BEGIN CATCH - INSERT INTO #TBDD_GET_DATABASE_OBJECT_ERRORS([DATABASE_NAME],[ERROR_NUMBER],[ERROR_MESSAGE]) - VALUES ( - DB_NAME(), - ERROR_NUMBER(), - N''DATA_SCAN ['' + @dSchema + N''.'' + @dTable + N''.'' + @dColumn + N'']: '' - + ERROR_MESSAGE() - + N'' (Proc: '' + ISNULL(ERROR_PROCEDURE(),N'''') + N'' / Line: '' + CONVERT(NVARCHAR(10),ERROR_LINE()) + N'')'' - ); - END CATCH; + FETCH NEXT FROM db_cur INTO @CURRENT_DB; - FETCH NEXT FROM cur_data_cols INTO @dSchema, @dTable, @dColumn; END; - CLOSE cur_data_cols; - DEALLOCATE cur_data_cols; - END; - -END TRY BEGIN CATCH - INSERT INTO #TBDD_GET_DATABASE_OBJECT_ERRORS([DATABASE_NAME],[ERROR_NUMBER],[ERROR_MESSAGE]) - VALUES ( - N''' + REPLACE(@CurrentDB,'''','''''') + N''', - ERROR_NUMBER(), - ERROR_MESSAGE() + N'' (Proc: '' + ISNULL(ERROR_PROCEDURE(),N'''') + N'' / Line: '' + CONVERT(NVARCHAR(10),ERROR_LINE()) + N'')'' - ); -END CATCH;'; - END; - - SET @SQLCommand = REPLACE(@SQLCommand,N'__COLLATION__',@CurrentDBCollation); + CLOSE db_cur; + DEALLOCATE db_cur; + ---------------------------------------------------------------------------------------------------------------------------- - EXEC sp_executesql - @SQLCommand, - N'@pSEARCHVALUE NVARCHAR(100), @pREPLACEWITH NVARCHAR(100), @pDOREPLACE BIT, @pINCLUDEDATAVALUES BIT, @pDOREPLACEDATAVALUES BIT', - @pSEARCHVALUE = @SEARCHVALUE, - @pREPLACEWITH = @REPLACEWITH, - @pDOREPLACE = @DOREPLACE, - @pINCLUDEDATAVALUES = @INCLUDEDATAVALUES, - @pDOREPLACEDATAVALUES = @DOREPLACEDATAVALUES; - - -- Per-DB summary - DECLARE @cntModules INT = 0, - @cntTables INT = 0, - @cntColumns INT = 0, - @cntDataColumns INT = 0, - @cntDataRows BIGINT = 0, - @cntDataPlan INT = 0, - @cntDataUpd INT = 0, - @cntDataSkip INT = 0, - @cntDataErr INT = 0, - @cntDbErrors INT = 0; - - SELECT @cntTables = COUNT(*) FROM #TBDD_GET_DATABASE_OBJECT_RESULTS WHERE [DATABASE_NAME] COLLATE DATABASE_DEFAULT = @CurrentDB AND [OBJECT_TYPE] COLLATE DATABASE_DEFAULT = N'TABLE'; - SELECT @cntColumns = COUNT(*) FROM #TBDD_GET_DATABASE_OBJECT_RESULTS WHERE [DATABASE_NAME] COLLATE DATABASE_DEFAULT = @CurrentDB AND [OBJECT_TYPE] COLLATE DATABASE_DEFAULT = N'COLUMN'; - SELECT @cntModules = COUNT(*) FROM #TBDD_GET_DATABASE_OBJECT_RESULTS WHERE [DATABASE_NAME] COLLATE DATABASE_DEFAULT = @CurrentDB AND [OBJECT_TYPE] COLLATE DATABASE_DEFAULT NOT IN (N'TABLE',N'COLUMN'); - SELECT @cntDataColumns = COUNT(*) FROM #TBDD_GET_DATABASE_OBJECT_DATAMATCHES WHERE [DATABASE_NAME] COLLATE DATABASE_DEFAULT = @CurrentDB; - SELECT @cntDataRows = ISNULL(SUM(CONVERT(BIGINT,[MATCH_COUNT])),0) FROM #TBDD_GET_DATABASE_OBJECT_DATAMATCHES WHERE [DATABASE_NAME] COLLATE DATABASE_DEFAULT = @CurrentDB; - SELECT @cntDataPlan = COUNT(*) FROM #TBDD_GET_DATABASE_OBJECT_DATAREPLACELOG WHERE [DATABASE_NAME] COLLATE DATABASE_DEFAULT = @CurrentDB AND [ACTION] COLLATE DATABASE_DEFAULT = N'PLANNED'; - SELECT @cntDataUpd = COUNT(*) FROM #TBDD_GET_DATABASE_OBJECT_DATAREPLACELOG WHERE [DATABASE_NAME] COLLATE DATABASE_DEFAULT = @CurrentDB AND [ACTION] COLLATE DATABASE_DEFAULT = N'UPDATED'; - SELECT @cntDataSkip = COUNT(*) FROM #TBDD_GET_DATABASE_OBJECT_DATAREPLACELOG WHERE [DATABASE_NAME] COLLATE DATABASE_DEFAULT = @CurrentDB AND [ACTION] COLLATE DATABASE_DEFAULT = N'SKIPPED'; - SELECT @cntDataErr = COUNT(*) FROM #TBDD_GET_DATABASE_OBJECT_DATAREPLACELOG WHERE [DATABASE_NAME] COLLATE DATABASE_DEFAULT = @CurrentDB AND [ACTION] COLLATE DATABASE_DEFAULT = N'ERROR'; - SELECT @cntDbErrors = COUNT(*) FROM #TBDD_GET_DATABASE_OBJECT_ERRORS WHERE [DATABASE_NAME] COLLATE DATABASE_DEFAULT = @CurrentDB; - - PRINT 'RESULT: [' + @CurrentDB + '] Modules=' + CONVERT(NVARCHAR(20),@cntModules) - + ' Tables=' + CONVERT(NVARCHAR(20),@cntTables) - + ' Columns=' + CONVERT(NVARCHAR(20),@cntColumns) - + ' DataCols=' + CONVERT(NVARCHAR(20),@cntDataColumns) - + ' DataRows=' + CONVERT(NVARCHAR(20),@cntDataRows) - + ' Errors=' + CONVERT(NVARCHAR(20),@cntDbErrors); + --========================================-- SQL Agent Job scan (Express-safe) --==========================================-- + -- SQL Agent is not available on SQL Express editions. We detect availability by checking + -- whether the msdb.dbo.sysjobs table exists before attempting to query it. + ---------------------------------------------------------------------------------------------------------------------------- + SET @AGENT_AVAILABLE = 0; - IF (@REPLACEWITH IS NOT NULL) AND (LEN(@REPLACEWITH) > 0) BEGIN + IF ((@INCLUDEAGENTJOBS = 1) AND OBJECT_ID(N'msdb.dbo.sysjobs', N'U') IS NOT NULL + AND OBJECT_ID(N'msdb.dbo.sysjobsteps', N'U') IS NOT NULL + AND HAS_DBACCESS(N'msdb') = 1) BEGIN + SET @AGENT_AVAILABLE = 1; + END; - DECLARE @cntPlanned INT = 0, - @cntUpdated INT = 0, - @cntSkipped INT = 0, - @cntReplErr INT = 0; + IF (@AGENT_AVAILABLE = 1) BEGIN - SELECT @cntPlanned = COUNT(*) FROM #TBDD_GET_DATABASE_OBJECT_REPLACELOG WHERE [DATABASE_NAME] COLLATE DATABASE_DEFAULT = @CurrentDB AND [ACTION] COLLATE DATABASE_DEFAULT = N'PLANNED'; - SELECT @cntUpdated = COUNT(*) FROM #TBDD_GET_DATABASE_OBJECT_REPLACELOG WHERE [DATABASE_NAME] COLLATE DATABASE_DEFAULT = @CurrentDB AND [ACTION] COLLATE DATABASE_DEFAULT = N'UPDATED'; - SELECT @cntSkipped = COUNT(*) FROM #TBDD_GET_DATABASE_OBJECT_REPLACELOG WHERE [DATABASE_NAME] COLLATE DATABASE_DEFAULT = @CurrentDB AND [ACTION] COLLATE DATABASE_DEFAULT = N'SKIPPED'; - SELECT @cntReplErr = COUNT(*) FROM #TBDD_GET_DATABASE_OBJECT_REPLACELOG WHERE [DATABASE_NAME] COLLATE DATABASE_DEFAULT = @CurrentDB AND [ACTION] COLLATE DATABASE_DEFAULT = N'ERROR'; + PRINT '----------------------------------------------------------------------------------------------------'; + PRINT 'STEP: Scanning SQL Agent Jobs (job names + step definitions)...'; - PRINT 'REPLACE: [' + @CurrentDB + '] Planned=' + CONVERT(NVARCHAR(20),@cntPlanned) - + ' Updated=' + CONVERT(NVARCHAR(20),@cntUpdated) - + ' Skipped=' + CONVERT(NVARCHAR(20),@cntSkipped) - + ' Errors=' + CONVERT(NVARCHAR(20),@cntReplErr); + BEGIN TRY - PRINT 'DATA REPLACE: [' + @CurrentDB + '] Planned=' + CONVERT(NVARCHAR(20),@cntDataPlan) - + ' Updated=' + CONVERT(NVARCHAR(20),@cntDataUpd) - + ' Skipped=' + CONVERT(NVARCHAR(20),@cntDataSkip) - + ' Errors=' + CONVERT(NVARCHAR(20),@cntDataErr); + -- F07: @AGENT_SEARCHVALUE and @AGENT_SEARCHVALUE_LIKE already initialized in the DECLARE block. + -- F25: Bracket-escaping for LIKE special chars ([[] for [, [%] for %, [_] for _) is standard + -- T-SQL and requires no explicit ESCAPE clause. + -- F26: COLLATE DATABASE_DEFAULT below forces DD_SYS collation, resolving potential conflicts + -- between msdb column collation (server-level) and the @AGENT_SEARCHVALUE_LIKE variable. - END; + -- 5a) Job names matching the search term + INSERT INTO #TBDD_GET_DATABASE_OBJECT_AGENTJOBS + ([MATCH_TYPE],[JOB_NAME],[JOB_ENABLED],[STEP_ID],[STEP_NAME],[STEP_SUBSYSTEM],[STEP_DATABASE],[STEP_COMMAND]) + SELECT + N'JOB_NAME', + j.[name], + j.[enabled], + NULL, + NULL, + NULL, + NULL, + NULL + FROM [msdb].[dbo].[sysjobs] j + WHERE j.[name] COLLATE DATABASE_DEFAULT LIKE N'%' + @AGENT_SEARCHVALUE_LIKE + N'%'; - FETCH NEXT FROM db_cur INTO @CurrentDB; + -- 5b) Job step names matching the search term + INSERT INTO #TBDD_GET_DATABASE_OBJECT_AGENTJOBS + ([MATCH_TYPE],[JOB_NAME],[JOB_ENABLED],[STEP_ID],[STEP_NAME],[STEP_SUBSYSTEM],[STEP_DATABASE],[STEP_COMMAND]) + SELECT + N'JOB_STEP_NAME', + j.[name], + j.[enabled], + js.[step_id], + js.[step_name], + js.[subsystem], + js.[database_name], + NULL + FROM [msdb].[dbo].[sysjobs] j + JOIN [msdb].[dbo].[sysjobsteps] js ON j.[job_id] = js.[job_id] + WHERE js.[step_name] COLLATE DATABASE_DEFAULT LIKE N'%' + @AGENT_SEARCHVALUE_LIKE + N'%'; - END; + -- 5c) Job step commands (body/definition) matching the search term + INSERT INTO #TBDD_GET_DATABASE_OBJECT_AGENTJOBS + ([MATCH_TYPE],[JOB_NAME],[JOB_ENABLED],[STEP_ID],[STEP_NAME],[STEP_SUBSYSTEM],[STEP_DATABASE],[STEP_COMMAND]) + SELECT + N'JOB_STEP_BODY', + j.[name], + j.[enabled], + js.[step_id], + js.[step_name], + js.[subsystem], + js.[database_name], + js.[command] + FROM [msdb].[dbo].[sysjobs] j + JOIN [msdb].[dbo].[sysjobsteps] js ON j.[job_id] = js.[job_id] + WHERE js.[command] COLLATE DATABASE_DEFAULT LIKE N'%' + @AGENT_SEARCHVALUE_LIKE + N'%'; + + SET @AGENT_JOB_COUNT = (SELECT COUNT(*) FROM #TBDD_GET_DATABASE_OBJECT_AGENTJOBS); + PRINT 'RESULT: SQL Agent Jobs - ' + CONVERT(NVARCHAR(20),@AGENT_JOB_COUNT) + ' match(es) found.'; + + END TRY BEGIN CATCH + + INSERT INTO #TBDD_GET_DATABASE_OBJECT_ERRORS([DATABASE_NAME],[ERROR_NUMBER],[ERROR_MESSAGE]) + VALUES ( + N'msdb', + ERROR_NUMBER(), + N'AGENT_SCAN: ' + ERROR_MESSAGE() + + N' (Proc: ' + ISNULL(ERROR_PROCEDURE(),N'') + N' / Line: ' + CONVERT(NVARCHAR(10),ERROR_LINE()) + N')' + ); + PRINT 'WARNING: SQL Agent Job scan failed: ' + ERROR_MESSAGE(); + + END CATCH; + + END ELSE BEGIN + PRINT '----------------------------------------------------------------------------------------------------'; + PRINT 'STEP: SQL Agent Job scan SKIPPED (disabled by @pINCLUDEAGENTJOBS or SQL Agent not available/no access).'; + END; + PRINT '----------------------------------------------------------------------------------------------------'; - CLOSE db_cur; - DEALLOCATE db_cur; + --================================================-- Global summary --====================================================-- + SET @DBCOUNT_FINAL = (SELECT COUNT(*) FROM #TBDD_GET_DATABASE_OBJECT_DB_LIST); - END TRY BEGIN CATCH + -- R04: Global summary consolidated (one query per source table) + SELECT + @TOTAL_TABLES = ISNULL(SUM(CASE WHEN [OBJECT_TYPE] COLLATE DATABASE_DEFAULT = N'TABLE' THEN 1 ELSE 0 END),0), + @TOTAL_COLUMNS = ISNULL(SUM(CASE WHEN [OBJECT_TYPE] COLLATE DATABASE_DEFAULT = N'COLUMN' THEN 1 ELSE 0 END),0), + @TOTAL_MODULES = ISNULL(SUM(CASE WHEN [OBJECT_TYPE] COLLATE DATABASE_DEFAULT NOT IN (N'TABLE',N'COLUMN') THEN 1 ELSE 0 END),0) + FROM #TBDD_GET_DATABASE_OBJECT_RESULTS; - IF CURSOR_STATUS('local','db_cur') >= 0 BEGIN - CLOSE db_cur; - END; + SELECT + @TOTAL_DATA_COLUMNS = COUNT(*), + @TOTAL_DATA_ROWS = ISNULL(SUM(CONVERT(BIGINT,[MATCH_COUNT])),0) + FROM #TBDD_GET_DATABASE_OBJECT_DATAMATCHES; - IF CURSOR_STATUS('local','db_cur') >= -1 BEGIN - DEALLOCATE db_cur; - END; + SELECT @TOTAL_ERRORS = COUNT(*) FROM #TBDD_GET_DATABASE_OBJECT_ERRORS; + SELECT @TOTAL_AGENT_JOBS = COUNT(*) FROM #TBDD_GET_DATABASE_OBJECT_AGENTJOBS; - SELECT - @return_status = ERROR_NUMBER(), - @return_error_text = ERROR_MESSAGE() + ' (Proc: ' + ISNULL(ERROR_PROCEDURE(),'') + ' / Line: ' + CONVERT(NVARCHAR(10),ERROR_LINE()) + ')'; - SET @return_status_text = 'ERROR: ' + @return_error_text; - PRINT @return_status_text; - RAISERROR(@return_status_text,16,1); - RETURN @return_status; + IF (@RETURN_STATUS = 0) AND (@TOTAL_ERRORS > 0) BEGIN + SET @RETURN_STATUS = 1; + SET @RETURN_STATUS_TEXT = 'WARNING: Completed with logged errors (see RS5).'; + PRINT @RETURN_STATUS_TEXT; + END; - END CATCH; - ---------------------------------------------------------------------------------------------------------------------------- + SELECT + @TOTAL_REPLACE_PLANNED = ISNULL(SUM(CASE WHEN [ACTION] COLLATE DATABASE_DEFAULT = N'PLANNED' THEN 1 ELSE 0 END),0), + @TOTAL_REPLACE_UPDATED = ISNULL(SUM(CASE WHEN [ACTION] COLLATE DATABASE_DEFAULT = N'UPDATED' THEN 1 ELSE 0 END),0), + @TOTAL_REPLACE_SKIPPED = ISNULL(SUM(CASE WHEN [ACTION] COLLATE DATABASE_DEFAULT = N'SKIPPED' THEN 1 ELSE 0 END),0), + @TOTAL_REPLACE_ERRORS = ISNULL(SUM(CASE WHEN [ACTION] COLLATE DATABASE_DEFAULT = N'ERROR' THEN 1 ELSE 0 END),0) + FROM #TBDD_GET_DATABASE_OBJECT_REPLACELOG; - --================================================-- Global summary --====================================================-- - DECLARE @DBCOUNT_FINAL INT = (SELECT COUNT(*) FROM #TBDD_GET_DATABASE_OBJECT_DB_LIST); - - DECLARE @TOTAL_MODULES INT = 0, - @TOTAL_TABLES INT = 0, - @TOTAL_COLUMNS INT = 0, - @TOTAL_DATA_COLUMNS INT = 0, - @TOTAL_DATA_ROWS BIGINT = 0, - @TOTAL_ERRORS INT = 0, - @TOTAL_REPLACE_PLANNED INT = 0, - @TOTAL_REPLACE_UPDATED INT = 0, - @TOTAL_REPLACE_SKIPPED INT = 0, - @TOTAL_REPLACE_ERRORS INT = 0, - @TOTAL_DATA_REPLACE_PLANNED INT = 0, - @TOTAL_DATA_REPLACE_UPDATED INT = 0, - @TOTAL_DATA_REPLACE_SKIPPED INT = 0, - @TOTAL_DATA_REPLACE_ERRORS INT = 0, - @TOTAL_DATA_REPLACE_ROWS BIGINT = 0; - - SELECT @TOTAL_TABLES = COUNT(*) FROM #TBDD_GET_DATABASE_OBJECT_RESULTS WHERE [OBJECT_TYPE] COLLATE DATABASE_DEFAULT = N'TABLE'; - SELECT @TOTAL_COLUMNS = COUNT(*) FROM #TBDD_GET_DATABASE_OBJECT_RESULTS WHERE [OBJECT_TYPE] COLLATE DATABASE_DEFAULT = N'COLUMN'; - SELECT @TOTAL_MODULES = COUNT(*) FROM #TBDD_GET_DATABASE_OBJECT_RESULTS WHERE [OBJECT_TYPE] COLLATE DATABASE_DEFAULT NOT IN (N'TABLE',N'COLUMN'); - SELECT @TOTAL_DATA_COLUMNS = COUNT(*) FROM #TBDD_GET_DATABASE_OBJECT_DATAMATCHES; - SELECT @TOTAL_DATA_ROWS = ISNULL(SUM(CONVERT(BIGINT,[MATCH_COUNT])),0) FROM #TBDD_GET_DATABASE_OBJECT_DATAMATCHES; - SELECT @TOTAL_ERRORS = COUNT(*) FROM #TBDD_GET_DATABASE_OBJECT_ERRORS; - - SELECT @TOTAL_REPLACE_PLANNED = COUNT(*) FROM #TBDD_GET_DATABASE_OBJECT_REPLACELOG WHERE [ACTION] COLLATE DATABASE_DEFAULT = N'PLANNED'; - SELECT @TOTAL_REPLACE_UPDATED = COUNT(*) FROM #TBDD_GET_DATABASE_OBJECT_REPLACELOG WHERE [ACTION] COLLATE DATABASE_DEFAULT = N'UPDATED'; - SELECT @TOTAL_REPLACE_SKIPPED = COUNT(*) FROM #TBDD_GET_DATABASE_OBJECT_REPLACELOG WHERE [ACTION] COLLATE DATABASE_DEFAULT = N'SKIPPED'; - SELECT @TOTAL_REPLACE_ERRORS = COUNT(*) FROM #TBDD_GET_DATABASE_OBJECT_REPLACELOG WHERE [ACTION] COLLATE DATABASE_DEFAULT = N'ERROR'; - SELECT @TOTAL_DATA_REPLACE_PLANNED = COUNT(*) FROM #TBDD_GET_DATABASE_OBJECT_DATAREPLACELOG WHERE [ACTION] COLLATE DATABASE_DEFAULT = N'PLANNED'; - SELECT @TOTAL_DATA_REPLACE_UPDATED = COUNT(*) FROM #TBDD_GET_DATABASE_OBJECT_DATAREPLACELOG WHERE [ACTION] COLLATE DATABASE_DEFAULT = N'UPDATED'; - SELECT @TOTAL_DATA_REPLACE_SKIPPED = COUNT(*) FROM #TBDD_GET_DATABASE_OBJECT_DATAREPLACELOG WHERE [ACTION] COLLATE DATABASE_DEFAULT = N'SKIPPED'; - SELECT @TOTAL_DATA_REPLACE_ERRORS = COUNT(*) FROM #TBDD_GET_DATABASE_OBJECT_DATAREPLACELOG WHERE [ACTION] COLLATE DATABASE_DEFAULT = N'ERROR'; - SELECT @TOTAL_DATA_REPLACE_ROWS = ISNULL(SUM(CONVERT(BIGINT,[UPDATED_ROWS])),0) FROM #TBDD_GET_DATABASE_OBJECT_DATAREPLACELOG WHERE [ACTION] COLLATE DATABASE_DEFAULT = N'UPDATED'; + SELECT + @TOTAL_DATA_REPLACE_PLANNED = ISNULL(SUM(CASE WHEN [ACTION] COLLATE DATABASE_DEFAULT = N'PLANNED' THEN 1 ELSE 0 END),0), + @TOTAL_DATA_REPLACE_UPDATED = ISNULL(SUM(CASE WHEN [ACTION] COLLATE DATABASE_DEFAULT = N'UPDATED' THEN 1 ELSE 0 END),0), + @TOTAL_DATA_REPLACE_SKIPPED = ISNULL(SUM(CASE WHEN [ACTION] COLLATE DATABASE_DEFAULT = N'SKIPPED' THEN 1 ELSE 0 END),0), + @TOTAL_DATA_REPLACE_ERRORS = ISNULL(SUM(CASE WHEN [ACTION] COLLATE DATABASE_DEFAULT = N'ERROR' THEN 1 ELSE 0 END),0), + @TOTAL_DATA_REPLACE_ROWS = ISNULL(SUM(CASE WHEN [ACTION] COLLATE DATABASE_DEFAULT = N'UPDATED' THEN CONVERT(BIGINT,[UPDATED_ROWS]) ELSE 0 END),0) + FROM #TBDD_GET_DATABASE_OBJECT_DATAREPLACELOG; PRINT '----------------------------------------------------------------------------------------------------'; PRINT 'SUMMARY: Databases processed: ' + CONVERT(NVARCHAR(20),@DBCOUNT_FINAL); PRINT 'SUMMARY: Modules=' + CONVERT(NVARCHAR(20),@TOTAL_MODULES) + ' Tables=' + CONVERT(NVARCHAR(20),@TOTAL_TABLES) + ' Columns=' + CONVERT(NVARCHAR(20),@TOTAL_COLUMNS) + + ' AgentJobMatches=' + CONVERT(NVARCHAR(20),@TOTAL_AGENT_JOBS) + ' Errors=' + CONVERT(NVARCHAR(20),@TOTAL_ERRORS); PRINT 'SUMMARY: DataColumnsWithMatches=' + CONVERT(NVARCHAR(20),@TOTAL_DATA_COLUMNS) + ' DataRowsMatched=' + CONVERT(NVARCHAR(20),@TOTAL_DATA_ROWS); @@ -1120,7 +1155,51 @@ END CATCH;'; PRINT '----------------------------------------------------------------------------------------------------'; ---------------------------------------------------------------------------------------------------------------------------- + END TRY BEGIN CATCH + + IF (XACT_STATE() = -1) BEGIN + IF (@START_TRANCOUNT = 0) AND (@@TRANCOUNT > 0) BEGIN + ROLLBACK TRAN; + PRINT 'WARNING: Uncommittable transaction rolled back in global CATCH.'; + END ELSE BEGIN + PRINT 'WARNING: Uncommittable outer transaction detected in global CATCH (no full rollback by procedure).'; + END; + END + ELSE BEGIN + IF (@HAS_ENTRY_SAVEPOINT = 1) AND (@@TRANCOUNT >= @START_TRANCOUNT) BEGIN + ROLLBACK TRANSACTION DD_PRDD_ENTRY; + END ELSE IF (@START_TRANCOUNT = 0) AND (@@TRANCOUNT > 0) BEGIN + ROLLBACK TRAN; + END; + END; + + IF CURSOR_STATUS('local','db_cur') >= 0 BEGIN + CLOSE db_cur; + END; + + IF CURSOR_STATUS('local','db_cur') >= -1 BEGIN + DEALLOCATE db_cur; + END; + + IF @RETURN_STATUS = 0 SET @RETURN_STATUS = ERROR_NUMBER(); + SET @RETURN_ERROR_TEXT = ERROR_MESSAGE() + ' (Proc: ' + ISNULL(ERROR_PROCEDURE(),'') + ' / Line: ' + CONVERT(NVARCHAR(10),ERROR_LINE()) + ')'; + SET @RETURN_STATUS_TEXT = 'ERROR: ' + @RETURN_ERROR_TEXT; + PRINT @RETURN_STATUS_TEXT; + + IF OBJECT_ID(N'tempdb..#TBDD_GET_DATABASE_OBJECT_ERRORS', N'U') IS NOT NULL BEGIN + INSERT INTO #TBDD_GET_DATABASE_OBJECT_ERRORS([DATABASE_NAME],[ERROR_NUMBER],[ERROR_MESSAGE]) + VALUES (ISNULL(@CURRENT_DB,N''), @RETURN_STATUS, @RETURN_STATUS_TEXT); + END; + + END CATCH; + --================================================-- Output resultsets --=================================================-- + -- N03: EMPTY_RESULTSETS label — GOTO target for all error-RETURN paths to ensure + -- the 6-resultset contract is always fulfilled, even on validation errors. + -- P2: Procedure-wide CATCH writes error context and then continues with fixed + -- output resultsets (partial data may be present, depending on fail position). + EMPTY_RESULTSETS: + SELECT [DATABASE_NAME], [OBJECT_TYPE], @@ -1170,15 +1249,27 @@ END CATCH;'; [ERROR_MESSAGE] FROM #TBDD_GET_DATABASE_OBJECT_ERRORS ORDER BY [DATABASE_NAME]; + + SELECT + [MATCH_TYPE], + [JOB_NAME], + [JOB_ENABLED], + [STEP_ID], + [STEP_NAME], + [STEP_SUBSYSTEM], + [STEP_DATABASE], + [STEP_COMMAND] + FROM #TBDD_GET_DATABASE_OBJECT_AGENTJOBS + ORDER BY [JOB_NAME],[MATCH_TYPE],[STEP_ID]; ---------------------------------------------------------------------------------------------------------------------------- - SET @return_status_text = 'END PROCEDURE [' + @MY_PROCEDURE_NAME + '] @ ' + CONVERT(varchar(50),GETDATE(),120); + SET @RETURN_STATUS_TEXT = 'END PROCEDURE [' + @MY_PROCEDURE_NAME + '] @ ' + CONVERT(varchar(50),GETDATE(),120); PRINT ''; - PRINT @return_status_text; + PRINT @RETURN_STATUS_TEXT; PRINT '===================================================================================================='; - Return @return_status; + RETURN @RETURN_STATUS; END; -GO +GO \ No newline at end of file