DROP PROCEDURE IF EXISTS dev.uspCloneIntezmenyMigration GO CREATE PROCEDURE dev.uspCloneIntezmenyMigration @pSourceIntezmenyId int ,@pSourceDatabase nvarchar(60) ,@pEntityHistoryMigration int /* 0 - Nem kell, 1 - csak migráció, 2 - átID-zás is */ AS BEGIN DECLARE @tableName nvarchar(50) ,@intezmenyIdColumn nvarchar(50) ,@isIdentity bit ,@columnList nvarchar(max) ,@sql nvarchar(max) ,@newIntezmenyId int ,@fenntartoAzonosito int ,@firstParentCol nvarchar(50) ,@firstRefObj nvarchar(50) ,@secondParentCol nvarchar(50) ,@secondRefObj nvarchar(50) SELECT @newIntezmenyId = t1.[newId] FROM MappingTable t1 WHERE t1.tableName = 'T_INTEZMENY' SELECT @fenntartoAzonosito = '000' IF NOT EXISTS (SELECT 1 FROM T_FENNTARTO WHERE ID = 0) BEGIN SET IDENTITY_INSERT T_FENNTARTO ON INSERT INTO T_FENNTARTO (ID, C_NEV, TOROLT, SERIAL, LASTCHANGED, CREATED, MODIFIER, CREATOR, ELOZOTANEVIREKORDID, NNID) VALUES (0, N'Technikai', 'F', 0, '2018-01-18 00:22:30', '2018-01-18 00:22:30', NULL, NULL, NULL, NULL) SET IDENTITY_INSERT T_FENNTARTO OFF END -- ============================================================== -- -- Az IDENTITY()-s táblák adatainak áttöltése -- -- ============================================================== -- DECLARE tbl_cur CURSOR LOCAL FOR SELECT DISTINCT TABLE_NAME, COLUMN_NAME--, COLUMNPROPERTY(OBJECT_ID(TABLE_NAME), 'ID', 'IsIdentity') FROM INFORMATION_SCHEMA.COLUMNS c WHERE COLUMN_NAME = N'C_INTEZMENYID' AND TABLE_NAME IN (SELECT TABLE_NAME FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_TYPE = 'BASE TABLE' AND TABLE_SCHEMA = 'dbo') AND c.TABLE_SCHEMA = 'dbo' AND TABLE_NAME NOT IN (N'T_ENTITYATTRIBUTEHISTORY', N'T_DICTIONARYTYPE') AND COLUMNPROPERTY(OBJECT_ID(TABLE_NAME), 'ID', 'IsIdentity') = 1 OPEN tbl_cur FETCH NEXT FROM tbl_cur INTO @tableName, @intezmenyIdColumn WHILE @@FETCH_STATUS = 0 BEGIN PRINT @tableName SELECT @columnList = ISNULL(@columnList + ', ', '') + c.COLUMN_NAME FROM INFORMATION_SCHEMA.COLUMNS c WHERE c.TABLE_NAME = @tableName AND c.TABLE_SCHEMA = 'dbo' AND c.COLUMN_NAME NOT IN (N'ID', @intezmenyIdColumn) SET @sql = N' INSERT INTO ' + @tableName + ' (ID, ' + @intezmenyIdColumn + ', ' + @columnList + ') SELECT t.[newId], @newIntezmenyId, ' + @columnList + ' FROM ' + @pSourceDatabase + '.dbo.' + @tableName + ' x INNER JOIN MappingTable t ON t.oldId = x.ID AND t.tableName = ''' + @tableName + ''' WHERE ' + @intezmenyIdColumn + ' = @intId' SET @sql = N' SET IDENTITY_INSERT ' + @tableName + ' ON' + @sql + ' SET IDENTITY_INSERT ' + @tableName + ' OFF' RAISERROR (@sql, 10, 1) WITH NOWAIT EXEC sp_executesql @sql, N'@intId int, @newIntezmenyId int', @pSourceIntezmenyId, @newIntezmenyId SET @columnList = NULL FETCH NEXT FROM tbl_cur INTO @tableName, @intezmenyIdColumn END CLOSE tbl_cur DEALLOCATE tbl_cur -- ============================================================== -- -- Az Intézmény adatainak áttöltése -- -- ============================================================== -- SET @sql = ' SET IDENTITY_INSERT T_INTEZMENY ON INSERT INTO T_INTEZMENY (ID, C_AZONOSITO, C_FENNTARTOAZONOSITO, C_NEPTUNNAPLOLINK, TOROLT, SERIAL, LASTCHANGED, CREATED, MODIFIER, CREATOR, C_FENNTARTOID) SELECT @newIntezmenyId, C_AZONOSITO, C_FENNTARTOAZONOSITO, C_NEPTUNNAPLOLINK, TOROLT, SERIAL, LASTCHANGED, CREATED, MODIFIER, CREATOR, C_FENNTARTOID FROM ' + @pSourceDatabase + '.dbo.T_INTEZMENY x INNER JOIN MappingTable t ON x.ID = t.oldId AND t.tableName = ''T_INTEZMENY'' SET IDENTITY_INSERT T_INTEZMENY OFF ' RAISERROR (@sql, 10, 1) WITH NOWAIT EXEC sp_executesql @sql, N'@newIntezmenyId int, @fenntartoAzonosito nvarchar(3)', @newIntezmenyId, @fenntartoAzonosito -- ============================================================== -- -- A nem IDENTITY()-s táblák adatainak áttöltése -- -- ============================================================== -- SELECT @newIntezmenyId = t1.[newId] FROM MappingTable t1 WHERE t1.tableName = 'T_INTEZMENY' DECLARE tbl_cur CURSOR LOCAL FOR SELECT DISTINCT TABLE_NAME, COLUMN_NAME--, COLUMNPROPERTY(OBJECT_ID(TABLE_NAME), 'ID', 'IsIdentity') FROM INFORMATION_SCHEMA.COLUMNS c WHERE COLUMN_NAME = N'C_ALINTEZMENYID' AND TABLE_NAME IN (SELECT TABLE_NAME FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_TYPE = 'BASE TABLE' AND TABLE_SCHEMA = 'dbo') AND TABLE_NAME NOT IN (N'T_ENTITYATTRIBUTEHISTORY', N'T_ENTITYHISTORY', N'T_DICTIONARYTYPE') AND TABLE_SCHEMA = 'dbo' AND COLUMNPROPERTY(OBJECT_ID(TABLE_NAME), 'ID', 'IsIdentity') = 0 OPEN tbl_cur FETCH NEXT FROM tbl_cur INTO @tableName, @intezmenyIdColumn WHILE @@FETCH_STATUS = 0 BEGIN PRINT @tableName SELECT @columnList = ISNULL(@columnList + ', ', '') + c.COLUMN_NAME FROM INFORMATION_SCHEMA.COLUMNS c WHERE c.TABLE_NAME = @tableName AND c.TABLE_SCHEMA = 'dbo' AND c.COLUMN_NAME NOT IN (N'ID', @intezmenyIdColumn) SET @sql = N' INSERT INTO ' + @tableName + ' (ID, ' + @intezmenyIdColumn + ', ' + @columnList + ') SELECT t.[newId], @newIntezmenyId, ' + @columnList + ' FROM ' + @pSourceDatabase + '.dbo.' + @tableName + ' x INNER JOIN MappingTable t ON t.oldId = x.ID AND t.tableName = ''' + @tableName + ''' WHERE ' + @intezmenyIdColumn + ' = @intId' RAISERROR (@sql, 10, 1) WITH NOWAIT EXEC sp_executesql @sql, N'@intId int, @newIntezmenyId int', @pSourceIntezmenyId, @newIntezmenyId SET @columnList = NULL FETCH NEXT FROM tbl_cur INTO @tableName, @intezmenyIdColumn END CLOSE tbl_cur DEALLOCATE tbl_cur -- ================================================================================ -- -- Kapcsolótáblák migrálása, ezt külön kell, mert nincsen nekik C_INTEZMENYID-juk -- -- ================================================================================ -- DECLARE tbl_cur CURSOR LOCAL FOR SELECT TABLE_NAME FROM INFORMATION_SCHEMA.TABLES t WHERE t.TABLE_NAME NOT IN ( SELECT TABLE_NAME FROM INFORMATION_SCHEMA.COLUMNS WHERE COLUMN_NAME = 'ID' ) AND t.TABLE_TYPE = 'BASE TABLE' AND t.TABLE_NAME LIKE 'T[_]%' AND t.TABLE_SCHEMA = 'dbo' AND t.TABLE_NAME NOT IN ('T_EVFOLYAMTIPUS_OKTATASINEVELE') OPEN tbl_cur FETCH NEXT FROM tbl_cur INTO @tableName WHILE @@FETCH_STATUS = 0 BEGIN SELECT TOP(1) @firstParentCol = pc.[name]-- AS parent_column_name ,@firstRefObj = OBJECT_NAME(rc.[object_id]) --as referenced_object_name FROM sys.foreign_key_columns f INNER JOIN sys.columns pc ON pc.[object_id] = f.parent_object_id AND pc.column_id = f.parent_column_id INNER JOIN sys.columns rc ON rc.[object_id] = f.referenced_object_id AND rc.column_id = f.referenced_column_id WHERE parent_object_id = OBJECT_ID(@tableName) ORDER BY f.constraint_object_id ASC SELECT TOP(1) @secondParentCol = pc.[name]-- AS parent_column_name ,@secondRefObj = OBJECT_NAME(rc.[object_id]) --as referenced_object_name FROM sys.foreign_key_columns f INNER JOIN sys.columns pc ON pc.[object_id] = f.parent_object_id AND pc.column_id = f.parent_column_id INNER JOIN sys.columns rc ON rc.[object_id] = f.referenced_object_id AND rc.column_id = f.referenced_column_id WHERE parent_object_id = OBJECT_ID(@tableName) ORDER BY f.constraint_object_id DESC SET @sql = N' INSERT INTO ' + @tableName + ' (' + @firstParentCol + ', ' + @secondParentCol + ') SELECT DISTINCT t1.[newId] AS ' + @firstParentCol + ', t2.[newId] AS ' + @secondParentCol + ' FROM ' + @pSourceDatabase + '.dbo.' + @tableName + ' x INNER JOIN MappingTable t1 ON t1.tableName = ''' + @firstRefObj + ''' AND ' + @firstParentCol + ' = t1.oldId INNER JOIN MappingTable t2 ON t2.tableName = ''' + @secondRefObj + ''' AND ' + @secondParentCol + ' = t2.oldId' --SELECT @sql RAISERROR (@sql, 10, 1) WITH NOWAIT EXEC sp_executesql @sql FETCH NEXT FROM tbl_cur INTO @tableName END CLOSE tbl_cur DEALLOCATE tbl_cur -- ============================================================== -- -- A T_DICTIONARYITEMBASE altáblák miglálása (100k alatt) -- -- ============================================================== -- DECLARE tbl_cur CURSOR LOCAL FOR SELECT OBJECT_NAME(parent_object_id) FROM sys.foreign_keys WHERE referenced_object_id = OBJECT_ID('T_DICTIONARYITEMBASE') SELECT @newIntezmenyId = t1.[newId] FROM MappingTable t1 WHERE t1.tableName = 'T_INTEZMENY' OPEN tbl_cur FETCH NEXT FROM tbl_cur INTO @tableName WHILE @@FETCH_STATUS = 0 BEGIN SELECT @columnList = ISNULL(@columnList + ', ', '') + c.COLUMN_NAME FROM INFORMATION_SCHEMA.COLUMNS c WHERE c.TABLE_NAME = @tableName AND c.TABLE_SCHEMA = 'dbo' AND c.COLUMN_NAME NOT IN (N'ID', N'C_ALINTEZMENYID') SET @sql = N' INSERT INTO ' + @tableName + ' (ID, C_ALINTEZMENYID, ' + @columnList + ') SELECT ID, @newIntezmenyId, ' + @columnList + ' FROM ' + @pSourceDatabase + '.dbo.' + @tableName + ' x WHERE C_ALINTEZMENYID = @intId AND ID < 100000' RAISERROR (@sql, 10, 1) WITH NOWAIT EXEC sp_executesql @sql, N'@intId int, @newIntezmenyId int', @pSourceIntezmenyId, @newIntezmenyId SET @columnList = NULL FETCH NEXT FROM tbl_cur INTO @tableName END CLOSE tbl_cur DEALLOCATE tbl_cur -- ============================================================== -- -- A T_DICTIONARYITEMBASE miglálása (100k alatt) -- -- ============================================================== -- SELECT @newIntezmenyId = t1.[newId] FROM MappingTable t1 WHERE t1.tableName = 'T_INTEZMENY' SET @sql = ' SET IDENTITY_INSERT T_DICTIONARYITEMBASE ON INSERT INTO T_DICTIONARYITEMBASE (ID, C_VALUE, C_NAME, C_NAME_1, C_NAME_2, C_NAME_3, C_NAME_4, C_VISIBLE, C_TYPE, C_PROTECTED, C_INTEZMENYID, C_TANEVID, TOROLT, SERIAL, LASTCHANGED, CREATED, MODIFIER, CREATOR, C_ORDER, C_DICTIONARYTYPEID) SELECT ID, C_VALUE, C_NAME, C_NAME_1, C_NAME_2, C_NAME_3, C_NAME_4, C_VISIBLE, C_TYPE, C_PROTECTED, @newIntezmenyId, C_TANEVID, TOROLT, SERIAL, LASTCHANGED, CREATED, MODIFIER, CREATOR, C_ORDER, C_DICTIONARYTYPEID FROM ' + @pSourceDatabase + '.dbo.T_DICTIONARYITEMBASE x WHERE C_INTEZMENYID = @pSourceIntezmenyId AND ID < 100000 SET IDENTITY_INSERT T_DICTIONARYITEMBASE OFF' RAISERROR (@sql, 10, 1) WITH NOWAIT EXEC sp_executesql @sql, N'@pSourceIntezmenyId int, @newIntezmenyId int', @pSourceIntezmenyId, @newIntezmenyId -- ============================================================== -- -- DICTIONARYTYPE külön kell áttölteni -- -- ============================================================== -- SET @sql = N' SET IDENTITY_INSERT T_DICTIONARYTYPE ON INSERT INTO T_DICTIONARYTYPE (ID, C_CODENAME, C_DESCRIPTION, C_ISCOLOREDITABLE, C_ISCUSTOMITEMALLOWED, C_NAME, C_INTEZMENYID, C_TANEVID, TOROLT, SERIAL, LASTCHANGED, CREATED, MODIFIER, CREATOR, ELOZOTANEVIREKORDID, NNID) SELECT ID, C_CODENAME, C_DESCRIPTION, C_ISCOLOREDITABLE, C_ISCUSTOMITEMALLOWED, C_NAME, @newIntezmenyId, C_TANEVID, TOROLT, SERIAL, LASTCHANGED, CREATED, MODIFIER, CREATOR, ELOZOTANEVIREKORDID, NNID FROM ' + @pSourceDatabase + '.dbo.T_DICTIONARYTYPE WHERE C_INTEZMENYID = @intId SET IDENTITY_INSERT T_DICTIONARYTYPE OFF' PRINT @sql EXEC sp_executesql @sql, N'@intId int, @newIntezmenyId int', @pSourceIntezmenyId, @newIntezmenyId -- ================================================================================ -- -- T_EVFOLYAMTIPUS_OKTATASINEVELE táblát külön kell kezelni -- -- ================================================================================ -- SET @sql = ' INSERT INTO T_EVFOLYAMTIPUS_OKTATASINEVELE (C_EVFOLYAMTIPUSID, C_OKTATASINEVELESIFELADATID, C_INTEZMENYID, C_TANEVID) SELECT ISNULL(eft.[newId], eo.C_EVFOLYAMTIPUSID), ISNULL(onf.[newId], eo.C_OKTATASINEVELESIFELADATID), @newIntezmenyId, t.[newId] FROM ' + @pSourceDatabase + '.dbo.T_EVFOLYAMTIPUS_OKTATASINEVELE eo INNER JOIN MappingTable t ON eo.C_TANEVID = t.oldId AND t.tableName = ''T_TANEV'' LEFT JOIN MappingTable onf ON eo.C_OKTATASINEVELESIFELADATID = onf.oldId AND onf.tableName = ''T_OKTATASINEVELESIFELADAT'' LEFT JOIN MappingTable eft ON eo.C_EVFOLYAMTIPUSID = eft.oldId AND eft.tableName = ''T_EVFOLYAMTIPUS'' WHERE eo.C_INTEZMENYID = @pSourceIntezmenyId' RAISERROR (@sql, 10, 1) WITH NOWAIT EXEC sp_executesql @sql, N'@pSourceIntezmenyId int, @newIntezmenyId int', @pSourceIntezmenyId, @newIntezmenyId -- ================================================================================ -- -- Az ENTITY HISTORY áttöltése -- -- ================================================================================ -- IF @pEntityHistoryMigration IN (1, 2) BEGIN SET @sql = N' SET IDENTITY_INSERT T_ENTITYHISTORY ON INSERT INTO T_ENTITYHISTORY (ID, C_ALTERATIONDATE, C_ENTITYID, C_ENTITYNAME, C_REASON, C_FELHASZNALOID, C_INTEZMENYID, C_TANEVID, CREATED) SELECT t.[newId], x.C_ALTERATIONDATE, x.C_ENTITYID, x.C_ENTITYNAME, x.C_REASON, x.C_FELHASZNALOID, @newIntezmenyId, x.C_TANEVID, x.CREATED FROM ' + @pSourceDatabase + '.dbo.T_ENTITYHISTORY x INNER JOIN MappingTable t ON t.oldId = x.ID AND t.tableName = ''T_ENTITYHISTORY'' WHERE x.C_INTEZMENYID = @pSourceIntezmenyId SET IDENTITY_INSERT T_ENTITYHISTORY OFF' RAISERROR (@sql, 10, 1) WITH NOWAIT EXEC sp_executesql @sql, N'@newIntezmenyId int, @pSourceIntezmenyId int', @newIntezmenyId, @pSourceIntezmenyId SET @sql = N' INSERT INTO T_ENTITYATTRIBUTEHISTORY (C_CURRENTVALUE, C_ORIGINALVALUE, C_PROPERTYNAME, C_ENTITYHISTORYID) SELECT C_CURRENTVALUE, C_ORIGINALVALUE, C_PROPERTYNAME, t.[newId] FROM ' + @pSourceDatabase + '.dbo.T_ENTITYATTRIBUTEHISTORY e INNER JOIN MappingTable t ON e.C_ENTITYHISTORYID = t.oldId AND t.tableName = ''T_ENTITYHISTORY'';' RAISERROR (@sql, 10, 1) WITH NOWAIT EXEC sp_executesql @sql, N'@newIntezmenyId int, @pSourceIntezmenyId int', @newIntezmenyId, @pSourceIntezmenyId END END GO