DECLARE @tablename VARCHAR(50) -- table name
DECLARE @columname VARCHAR(50) -- column name
DECLARE @schemaname VARCHAR(50) --schema name
DECLARE @maxid INT-- current value
DECLARE @newseed INT --new seed
DECLARE @newseed_string VARCHAR(50)
DECLARE @sqlcmd NVARCHAR(200) -- cmd
CREATE TABLE #Maxid(value int)
DECLARE identity_cursor CURSOR FOR
SELECT OBJECT_NAME(ic.object_id), ic.name, s.name
FROM sys.identity_columns ic
join sys.objects o ON ic.object_id=o.object_id
JOIN sys.schemas s ON o.schema_id=s.schema_id
where o.type='U'
OPEN identity_cursor
FETCH NEXT FROM identity_cursor INTO @tablename, @columname, @schemaname
WHILE @@FETCH_STATUS = 0
BEGINSET @sqlcmd='INSERT INTO #Maxid SELECT TOP 1 '+ @columname+ ' from '+ @schemaname+'.'+@tablename + ' order by ' +@columname+' desc'
exec sp_executesql @sqlcmd
SELECT TOP 1 @maxid= value FROM #Maxid
SET @newseed=@maxid +1
TRUNCATE TABLE #Maxid
SET @newseed_string=@newseed
SET @sqlcmd='DBCC CHECKIDENT ('''+@schemaname+'.'+@tablename+''', RESEED, '+@newseed_string+')'
exec sp_executesql @sqlcmd
FETCH NEXT FROM identity_cursor INTO @tablename, @columname, @schemaname
END
DROP TABLE #Maxid
CLOSE identity_cursor
DEALLOCATE identity_cursor
You must be a registered user to add a comment. If you've already registered, sign in. Otherwise, register and sign in.