From c994c82859dcda1634a77744f0ceb7b3b7b381d6 Mon Sep 17 00:00:00 2001 From: Imran Imtiaz Date: Sun, 18 May 2025 11:38:45 +0400 Subject: [PATCH] Update PMDB.Update the next key to the max.sql The improved version of the script focuses on enhancing readability, maintainability, and safety. First, the script was reformatted with consistent indentation and clear section comments to make it easier to follow and understand. Descriptive print statements were added to highlight each major step of the process. The dynamic SQL construction was improved using QUOTENAME() to safely handle table and column names, reducing the risk of SQL injection or syntax errors due to invalid identifiers. The use of common table expressions (CTEs) was preserved, but clarified with proper aliasing and better naming conventions. The logic to generate and execute the dynamic SQL for identifying key mismatches was consolidated and simplified, using UNION ALL for clarity and performance. Furthermore, the manual update section was commented and provided as an optional, controlled block with an example, allowing administrators to adjust specific NEXTKEY values safely. Lastly, by default, the transaction is rolled back to ensure no unintended changes are made during testing, with a clear note to only commit after validation. These changes make the script more robust, user-friendly, and production-ready. --- PMDB.Update the next key to the max.sql | 127 +++++++++++++----------- 1 file changed, 71 insertions(+), 56 deletions(-) diff --git a/PMDB.Update the next key to the max.sql b/PMDB.Update the next key to the max.sql index 0418717..eebe25b 100644 --- a/PMDB.Update the next key to the max.sql +++ b/PMDB.Update the next key to the max.sql @@ -1,85 +1,100 @@ /*---------------------------------------------------------------------+ -| Purpose: Update the next key to the max -| Note: SQLCmdMode Script +| Purpose: Update the next key to the max if needed +| Notes: SQLCmdMode Script - Identifies and fixes key mismatches +----------------------------------------------------------------------*/ :setvar _server "Server1" :setvar _user "***username***" :setvar _password "***password***" :setvar _database "PMDB_TEST" + :connect $(_server) -U $(_user) -P $(_password) USE [$(_database)]; GO -SET XACT_ABORT ON -BEGIN TRANSACTION +--========================= +-- Begin Transaction +--========================= +SET XACT_ABORT ON; +BEGIN TRANSACTION; +GO PRINT '=====================================================================' -PRINT 'create a script for key errors and show the max key values and next key values' +PRINT 'Step 1: Checking for key mismatches and suggesting fixes' PRINT '=====================================================================' GO -DECLARE @S NVARCHAR(MAX) = '' +DECLARE @S NVARCHAR(MAX) = ''; -;WITH -key_table_list -AS -( - SELECT - key_name - , key_seq_num - , table_name = LEFT(key_name, CHARINDEX('_',key_name, 0)-1) - , column_name = RIGHT(key_name, LEN(key_name) - CHARINDEX('_',key_name, 0)) - FROM - NEXTKEY +--========================================== +-- CTE to extract table and column names from key_name +--========================================== +WITH key_table_list AS ( + SELECT + key_name, + key_seq_num, + table_name = LEFT(key_name, CHARINDEX('_', key_name) - 1), + column_name = RIGHT(key_name, LEN(key_name) - CHARINDEX('_', key_name)) + FROM NEXTKEY +), +--========================================== +-- CTE to generate dynamic SQL to compare max key and next key +--========================================== +single_script AS ( + SELECT + ROW_NUMBER() OVER (ORDER BY tl.table_name) AS RowNumber, + script = + 'SELECT table_name = ''' + tl.table_name + ''', ' + + 'max_key_seq_num = MAX(' + QUOTENAME(tl.column_name) + '), ' + + 'key_seq_num = ' + CAST(tl.key_seq_num AS VARCHAR) + ', ' + + 'KeyError = CASE WHEN MAX(' + QUOTENAME(tl.column_name) + ') > ' + CAST(tl.key_seq_num AS VARCHAR) + + ' THEN ''EXEC dbo.getnextkeys N'''''+ tl.key_name + ''''', '' + ' + + 'CAST(MAX(' + QUOTENAME(tl.column_name) + ') - ' + CAST(tl.key_seq_num AS VARCHAR) + ' + 1 AS VARCHAR) + '', @NewKeyStart OUTPUT'' ' + + 'ELSE NULL END ' + + 'FROM ' + QUOTENAME(tl.table_name) + FROM key_table_list tl + INNER JOIN sys.objects ob ON ob.name = tl.table_name + WHERE ob.type = 'U' -- User tables only ) -, -single_script -AS -( - SELECT - [RowNumber]= ROW_NUMBER() OVER(ORDER BY tl.table_name) - , script = 'SELECT table_name =''' + tl.table_name + ''', max_key_seq_num = MAX(' + tl.column_name + '), key_seq_num = ' - + CAST(tl.key_seq_num AS VARCHAR) + ', KeyError = CASE WHEN MAX(' + tl.column_name + ') > ' + CAST(tl.key_seq_num AS VARCHAR) - + ' THEN ''EXEC dbo.getnextkeys N''''' + tl.key_name + ''''', '' + CAST(MAX(' + tl.column_name + ') - ' + CAST(tl.key_seq_num AS VARCHAR) + ' + 1 AS VARCHAR) + '', @NewKeyStart OUTPUT'' ELSE NULL END FROM ' + tl.table_name - FROM - key_table_list tl - INNER JOIN sys.objects ob ON ob.name = tl.table_name - WHERE - 1=1 - AND ob.type = 'U' -) -SELECT @S = @S + CASE WHEN [RowNumber] != 1 THEN ' UNION ' ELSE '' END + script -FROM -single_script -EXEC ('SELECT * FROM (' + @S+ ') AS se WHERE KeyError IS NOT NULL') -GO +--========================================== +-- Build and execute final dynamic SQL +--========================================== +SELECT @S = @S + CASE WHEN RowNumber != 1 THEN ' UNION ALL ' ELSE '' END + script +FROM single_script; -PRINT '=====================================================================' -PRINT 'update next key to number of missing increments ' -PRINT '=====================================================================' +-- Execute the script to find key mismatches +EXEC('SELECT * FROM (' + @S + ') AS result WHERE KeyError IS NOT NULL'); GO ---declare @val as int ---declare @NewKeyStart as int ---set @val = (select max(task_id) from task) ----- before - ---select key_seq_num from nextkey where key_name='task_task_id' ---select max(task_id) from task ---Print @val +--========================= +-- Manual Fix Section (Optional) +-- Uncomment & use if automatic correction is needed +--========================= +/* +DECLARE @NewKeyStart INT; +DECLARE @nkeys INT; +DECLARE @tabcol NVARCHAR(100); ---EXEC dbo.getnextkeys @tabcol = N'task_task_id', @nkeys = 893, @startkey = @NewKeyStart OUTPUT +-- Example usage: +SET @tabcol = N'task_task_id'; +SET @nkeys = (SELECT MAX(task_id) - key_seq_num + 1 FROM task, nextkey WHERE key_name = @tabcol); +EXEC dbo.getnextkeys @tabcol = @tabcol, @nkeys = @nkeys, @startkey = @NewKeyStart OUTPUT; -----after ---select key_seq_num from nextkey where key_name='task_task_id' ---select max(task_id) from task +-- Check results: +SELECT key_seq_num FROM nextkey WHERE key_name = @tabcol; +SELECT MAX(task_id) FROM task; +*/ +GO PRINT '=====================================================================' -PRINT 'Finished!' +PRINT 'Finished key mismatch analysis. Review suggested scripts above.' PRINT '=====================================================================' GO -ROLLBACK TRANSACTION ---COMMIT TRANSACTION +--========================= +-- Rollback by default +--========================= +ROLLBACK TRANSACTION; +-- Use COMMIT only after verifying the fixes are correct +-- COMMIT TRANSACTION;