kreta/Kreta.DataAccess.Migrations/DBScripts/Database/dev/uspIntezmenyCloneMigration.sql
2024-03-13 00:33:46 +01:00

579 lines
28 KiB
Transact-SQL

DROP PROCEDURE IF EXISTS dev.uspIntezmenyCloneMigration
GO
CREATE PROCEDURE dev.uspIntezmenyCloneMigration
@pSourceIntezmenyIds nvarchar(1000)
,@pSourceDatabase nvarchar(60)
,@pArchivalandoRelativTanevSorszam int = NULL -- az aktív tanévhez képest hány tanével régebbi legyen az első másolandó tanév. 1, akkor az aktív tanév előtti tanév és mminden régebbi másolásra kerül, 2 esetén aktív előtt kettővel és régebbi tanévek NULL esetén teljes suli másolás van.
,@pEntityHistoryMigration bit = 1
,@pDebugMode bit = 0
AS
BEGIN
DECLARE
@tableName nvarchar(50)
,@intezmenyIdColumn nvarchar(50)
,@tanevIdColumn nvarchar(50)
,@columnList nvarchar(MAX)
,@sql nvarchar(MAX)
,@newIntezmenyId int
,@firstParentCol nvarchar(50)
,@firstRefObj nvarchar(50)
,@secondParentCol nvarchar(50)
,@secondRefObj nvarchar(50)
,@message nvarchar(MAX)
,@rowCount int
RAISERROR ('DATA MIGRATION... ', 10, 1) WITH NOWAIT
IF @pSourceIntezmenyIds IS NULL BEGIN
PRINT 1
SET @sql = '
SELECT @pSourceIntezmenyIds = CONCAT(@pSourceIntezmenyIds + '','', i.ID) FROM ' + @pSourceDatabase + '.dbo.T_INTEZMENY i WHERE i.TOROLT = ''F''
'
PRINT @sql
EXEC sp_executesql @sql, N'@pSourceIntezmenyIds nvarchar(1000) output', @pSourceIntezmenyIds OUTPUT
END
PRINT @pSourceIntezmenyIds
CREATE TABLE #Tanev (TanevId int PRIMARY KEY)
IF @pArchivalandoRelativTanevSorszam IS NOT NULL
SET @sql =
'
SELECT x.TanevId--, x.IntezmenyId, x.RN
FROM (
SELECT i.ID AS IntezmenyId, tv.ID AS TanevId, ROW_NUMBER() OVER(PARTITION BY tv.C_INTEZMENYID ORDER BY tv.C_SORSZAM DESC) AS RN
FROM ' + @pSourceDatabase + '.dbo.T_INTEZMENY i
INNER JOIN ' + @pSourceDatabase + '.dbo.T_TANEV tva ON tva.C_INTEZMENYID = i.ID AND tva.TOROLT = ''F''
INNER JOIN ' + @pSourceDatabase + '.dbo.T_TANEV tv ON tv.C_INTEZMENYID = i.ID AND tv.TOROLT = ''F''
WHERE tva.C_AKTIV = ''T''
AND i.TOROLT = ''F''
AND tva.C_SORSZAM > tv.C_SORSZAM
AND i.ID IN (' + @pSourceIntezmenyIds + ')
) x
WHERE RN >= @pArchivalandoRelativTanevSorszam
'
ELSE
SET @sql = '
SELECT tva.ID AS TanevId
FROM ' + @pSourceDatabase + '.dbo.T_INTEZMENY i
INNER JOIN ' + @pSourceDatabase + '.dbo.T_TANEV tva ON tva.C_INTEZMENYID = i.ID AND tva.TOROLT = ''F''
WHERE i.ID IN (' + @pSourceIntezmenyIds + ')
'
PRINT @pSourceIntezmenyIds
PRINT @sql
INSERT INTO #Tanev (TanevId)
EXEC sp_executesql @sql, N'@pArchivalandoRelativTanevSorszam int', @pArchivalandoRelativTanevSorszam
SELECT * FROM #Tanev
--RETURN
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) VALUES
(0, N'Technikai', 'F', 0, '2018-01-18 00:22:30', '2018-01-18 00:22:30', 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 t.name AS TableName, c.name AS IntezmenyColumn, IIF(t.name = 'T_TANEV', 'ID', c2.name) AS TanevColumn--, COLUMNPROPERTY(OBJECT_ID(TABLE_NAME), 'ID', 'IsIdentity')
FROM sys.tables t
INNER JOIN sys.columns c ON t.object_id = c.object_id
LEFT JOIN sys.columns c2 ON t.object_id = c2.object_id AND c2.name IN (N'C_ALTANEVID', N'C_TANEVID')
WHERE c.name IN (N'C_ALINTEZMENYID', N'C_INTEZMENYID')
AND t.name LIKE 'T[_]%'
AND t.schema_id = SCHEMA_ID('dbo')
AND t.name NOT IN (N'T_ENTITYATTRIBUTEHISTORY', N'T_DICTIONARYTYPE', 'T_ENTITYHISTORY')
AND COLUMNPROPERTY(OBJECT_ID(t.name), 'ID', 'IsIdentity') = 1
ORDER BY t.name
OPEN tbl_cur
FETCH NEXT FROM tbl_cur
INTO @tableName, @intezmenyIdColumn, @tanevIdColumn
WHILE @@FETCH_STATUS = 0 BEGIN
--PRINT @tableName
SELECT @columnList = ISNULL(@columnList + ', ', '') + c.name
FROM sys.columns c
WHERE c.object_id = OBJECT_ID(@tableName)
AND c.name NOT IN (N'ID', @intezmenyIdColumn)
AND c.is_computed = 0
SET @sql = N'
INSERT INTO ' + @tableName + ' (ID, ' + @intezmenyIdColumn + ', ' + @columnList + ')
SELECT ID, ' + @intezmenyIdColumn + ', ' + @columnList + '
FROM ' + @pSourceDatabase + '.dbo.' + @tableName + ' x
' + IIF(@pArchivalandoRelativTanevSorszam IS NULL OR @tanevIdColumn IS NULL , '', 'INNER JOIN #Tanev t ON t.TanevId = x.' + @tanevIdColumn) + '
WHERE ' + @intezmenyIdColumn + ' IN (' + @pSourceIntezmenyIds + ')'
-- + IIF(@pArchivalandoRelativTanevSorszam IS NOT NULL, 'AND C_TANEVID IN ()', '')
SET @sql = N'
SET IDENTITY_INSERT ' + @tableName + ' ON' + @sql + '
SET @rowCount = @@ROWCOUNT
SET IDENTITY_INSERT ' + @tableName + ' OFF
'
IF @pDebugMode = 1 RAISERROR (@sql, 10, 1) WITH NOWAIT
EXEC sp_executesql @sql, N'@intId nvarchar(255), @newIntezmenyId int, @rowCount int output', @pSourceIntezmenyIds, @newIntezmenyId, @rowCount output
SET @message = ' CPA ' + FORMAT(GETDATE(), 'HH:mm:ss.ff') + ' - ' + @tableName + ' - ' + CAST(@rowCount AS nvarchar(20)) + ' sor'
RAISERROR (@message, 10, 1) WITH NOWAIT
SET @columnList = NULL
FETCH NEXT FROM tbl_cur
INTO @tableName, @intezmenyIdColumn, @tanevIdColumn
END
CLOSE tbl_cur
DEALLOCATE tbl_cur
-- ============================================================== --
-- Az Intézmény adatainak áttöltése --
-- ============================================================== --
SELECT @columnList = ISNULL(@columnList + ', ', '') + c.COLUMN_NAME
FROM INFORMATION_SCHEMA.COLUMNS c
WHERE c.TABLE_NAME = 'T_INTEZMENY' AND c.TABLE_SCHEMA = 'dbo' --AND c.COLUMN_NAME NOT IN (N'ID')
SET @sql = '
SET IDENTITY_INSERT T_INTEZMENY ON
INSERT INTO T_INTEZMENY (' + @columnList + ')
SELECT ' + @columnList + '
FROM ' + @pSourceDatabase + '.dbo.T_INTEZMENY x
WHERE ID IN (' + @pSourceIntezmenyIds + ')
SET @rowCount = @@ROWCOUNT
SET IDENTITY_INSERT T_INTEZMENY OFF
'
IF @pDebugMode = 1 RAISERROR (@sql, 10, 1) WITH NOWAIT
EXEC sp_executesql @sql, N'@newIntezmenyId int, @intId nvarchar(255), @rowCount int output', @newIntezmenyId, @pSourceIntezmenyIds, @rowCount output
SET @message = ' CPB ' + FORMAT(GETDATE(), 'HH:mm:ss.ff') + ' - T_INTEZMENY - ' + CAST(@rowCount AS nvarchar(20)) + ' sor'
RAISERROR (@message, 10, 1) WITH NOWAIT
SET @columnList = NULL
-- ============================================================== --
-- A nem IDENTITY()-s táblák adatainak áttöltése --
-- ============================================================== --
DECLARE tbl_cur CURSOR LOCAL FOR
SELECT DISTINCT t.name, c.name AS IntezmenyColumn, c2.name AS TanevColumn--, COLUMNPROPERTY(OBJECT_ID(TABLE_NAME), 'ID', 'IsIdentity')
FROM sys.tables t
INNER JOIN sys.columns c ON t.object_id = c.object_id
INNER JOIN sys.columns c2 ON t.object_id = c2.object_id
WHERE c.name IN (N'C_ALINTEZMENYID', N'C_INTEZMENYID')
AND c2.name IN (N'C_ALTANEVID', N'C_TANEVID')
AND t.name NOT IN (N'T_ENTITYATTRIBUTEHISTORY', N'T_ENTITYHISTORY', N'T_DICTIONARYTYPE', 'T_ENTITYBLOBVALUES', 'T_ENTITYATTRIBUTEHISTORY_ARCHIVE')
AND t.schema_id = SCHEMA_ID('dbo')
AND COLUMNPROPERTY(OBJECT_ID(t.name), 'ID', 'IsIdentity') = 0
ORDER BY t.name
OPEN tbl_cur
FETCH NEXT FROM tbl_cur
INTO @tableName, @intezmenyIdColumn, @tanevIdColumn
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'
SET @sql = N'
INSERT INTO ' + @tableName + ' (' + @columnList + ')
SELECT ' + @columnList + '
FROM ' + @pSourceDatabase + '.dbo.' + @tableName + ' x
' + IIF(@pArchivalandoRelativTanevSorszam IS NULL, '', 'INNER JOIN #Tanev t ON t.TanevId = x.' + @tanevIdColumn + '') + '
WHERE x.' + @intezmenyIdColumn + ' IN (' + @pSourceIntezmenyIds + ')
SET @rowCount = @@ROWCOUNT
'
IF @pDebugMode = 1 RAISERROR (@sql, 10, 1) WITH NOWAIT
EXEC sp_executesql @sql, N'@rowCount int output', @rowCount output
SET @message = ' CPC ' + FORMAT(GETDATE(), 'HH:mm:ss.ff') + ' - ' + @tableName + ' - ' + CAST(@rowCount AS nvarchar(20)) + ' sor'
RAISERROR (@message, 10, 1) WITH NOWAIT
SET @columnList = NULL
FETCH NEXT FROM tbl_cur
INTO @tableName, @intezmenyIdColumn, @tanevIdColumn
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 t.name
FROM sys.tables t
WHERE NOT EXISTS (SELECT 1 FROM sys.columns c WHERE c.name = 'ID' AND c.object_id = t.object_id)
AND t.name LIKE 'T[_]%'
AND t.schema_id = SCHEMA_ID('dbo')
AND t.name NOT IN ('T_EVFOLYAMTIPUS_OKTATASINEVELE', 'T_AMIFOTARGY_AMIALTARGY', 'T_ORAREND', 'T_ENTITYBLOBVALUES',
'T_ENTITYATTRIBUTEHISTORY', 'T_ORARENDTELJES', 'T_ENTITYATTRIBUTEHISTORY_ARCHIVE', 'T_ENTITYBLOBVALUES_ARCHIVE'
)
ORDER BY t.name
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 f.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 f.parent_object_id = OBJECT_ID(@tableName)
ORDER BY f.constraint_object_id DESC
SET @sql = N'
INSERT INTO ' + @tableName + ' (' + @firstParentCol + ', ' + @secondParentCol + ')
SELECT ' + @firstParentCol + ', ' + @secondParentCol + '
FROM ' + @pSourceDatabase + '.dbo.' + @tableName + ' x
INNER JOIN ' + @pSourceDatabase + '.dbo.' + @firstRefObj + ' s ON s.ID = x.' + @firstParentCol + ' AND s.C_' + IIF(@firstRefObj IN ('T_TANULO', 'T_ALKALMAZOTT', 'T_OSZTALY', 'T_CSOPORT'), 'AL', '') + 'INTEZMENYID IN (' + @pSourceIntezmenyIds + ')' + '
INNER JOIN ' + @pSourceDatabase + '.dbo.' + @secondRefObj + ' z ON z.ID = x.' + @secondParentCol + ' AND z.C_' + IIF(@secondRefObj IN ('T_TANULO', 'T_ALKALMAZOTT', 'T_OSZTALY', 'T_CSOPORT'), 'AL', '') + 'INTEZMENYID IN (' + @pSourceIntezmenyIds + ')' + '
' + IIF(@pArchivalandoRelativTanevSorszam IS NULL, '', 'INNER JOIN #Tanev t ON t.TanevId = s.C_' + IIF(@firstRefObj IN ('T_TANULO', 'T_ALKALMAZOTT', 'T_OSZTALY', 'T_CSOPORT'), 'AL', '') + 'TANEVID') + '
SET @rowCount = @@ROWCOUNT
'
IF @pDebugMode = 1 RAISERROR (@sql, 10, 1) WITH NOWAIT
EXEC sp_executesql @sql, N'@intId nvarchar(255), @rowCount int output', @pSourceIntezmenyIds, @rowCount output
SET @message = ' CPD ' + FORMAT(GETDATE(), 'HH:mm:ss.ff') + ' - ' + @tableName + ' - ' + CAST(@rowCount AS nvarchar(20)) + ' sor'
RAISERROR (@message, 10, 1) WITH NOWAIT
FETCH NEXT FROM tbl_cur
INTO @tableName
END
CLOSE tbl_cur
DEALLOCATE tbl_cur
-- ============================================================== --
-- DICTIONARYTYPE külön kell áttölteni --
-- ============================================================== --
SET @columnList = NULL
SELECT @columnList = ISNULL(@columnList + ', ', '') + c.COLUMN_NAME
FROM INFORMATION_SCHEMA.COLUMNS c
WHERE c.TABLE_NAME = 'T_DICTIONARYTYPE' AND c.TABLE_SCHEMA = 'dbo'
SET @sql = N'
SET IDENTITY_INSERT T_DICTIONARYTYPE ON
INSERT INTO T_DICTIONARYTYPE (' + @columnList + ')
SELECT ' + @columnList + '
FROM ' + @pSourceDatabase + '.dbo.T_DICTIONARYTYPE x
' + IIF(@pArchivalandoRelativTanevSorszam IS NULL, '', 'INNER JOIN #Tanev t ON t.TanevId = x.C_TANEVID') + '
WHERE x.C_INTEZMENYID IN (' + @pSourceIntezmenyIds + ')
SET @rowCount = @@ROWCOUNT
SET IDENTITY_INSERT T_DICTIONARYTYPE OFF
'
IF @pDebugMode = 1 RAISERROR (@sql, 10, 1) WITH NOWAIT
EXEC sp_executesql @sql, N'@intId nvarchar(255), @newIntezmenyId int, @rowCount int output', @pSourceIntezmenyIds, @newIntezmenyId, @rowCount output
SET @message = ' CPG ' + FORMAT(GETDATE(), 'HH:mm:ss.ff') + ' - T_DICTIONARYTYPE - ' + CAST(@rowCount AS nvarchar(20)) + ' sor'
RAISERROR (@message, 10, 1) WITH NOWAIT
-- ================================================================================ --
-- T_EVFOLYAMTIPUS_OKTATASINEVELE táblát külön kell kezelni --
-- ================================================================================ --
SET @columnList = NULL
SELECT @columnList = ISNULL(@columnList + ', ', '') + c.COLUMN_NAME
FROM INFORMATION_SCHEMA.COLUMNS c
WHERE c.TABLE_NAME = 'T_EVFOLYAMTIPUS_OKTATASINEVELE' AND c.TABLE_SCHEMA = 'dbo'
SET @sql = '
INSERT INTO T_EVFOLYAMTIPUS_OKTATASINEVELE (' + @columnList + ')
SELECT ' + @columnList + '
FROM ' + @pSourceDatabase + '.dbo.T_EVFOLYAMTIPUS_OKTATASINEVELE x
' + IIF(@pArchivalandoRelativTanevSorszam IS NULL, '', 'INNER JOIN #Tanev t ON t.TanevId = x.C_TANEVID') + '
WHERE x.C_INTEZMENYID IN (' + @pSourceIntezmenyIds + ')
SET @rowCount = @@ROWCOUNT
'
IF @pDebugMode = 1 RAISERROR (@sql, 10, 1) WITH NOWAIT
EXEC sp_executesql @sql, N'@intId nvarchar(255), @newIntezmenyId int, @rowCount int output', @pSourceIntezmenyIds, @newIntezmenyId, @rowCount output
SET @message = ' CPH ' + FORMAT(GETDATE(), 'HH:mm:ss.ff') + ' - T_EVFOLYAMTIPUS_OKTATASINEVELE - ' + CAST(@rowCount AS nvarchar(20)) + ' sor'
RAISERROR (@message, 10, 1) WITH NOWAIT
-- ================================================================================ --
-- DASHBOARDUZENETEK áttöltése --
-- ================================================================================ --
SET @columnList = NULL
SELECT @columnList = ISNULL(@columnList + ', ', '') + c.COLUMN_NAME
FROM INFORMATION_SCHEMA.COLUMNS c
WHERE c.TABLE_NAME = 'T_DASHBOARDUZENET' AND c.TABLE_SCHEMA = 'dbo'
SET @sql = N'
SET IDENTITY_INSERT T_DASHBOARDUZENET ON;
INSERT INTO T_DASHBOARDUZENET (' + @columnList + ')
SELECT ' + @columnList + '
FROM ' + @pSourceDatabase + '.dbo.T_DASHBOARDUZENET d
WHERE NOT EXISTS (SELECT 1 FROM T_DASHBOARDUZENET x WHERE d.C_EGYEDIAZONOSITO = x.C_EGYEDIAZONOSITO);
SET @rowCount = @@ROWCOUNT;
SET IDENTITY_INSERT T_DASHBOARDUZENET OFF;
'
IF @pDebugMode = 1 RAISERROR (@sql, 10, 1) WITH NOWAIT
EXEC sp_executesql @sql, N'@rowCount int output', @rowCount output
SET @message = ' CPI ' + FORMAT(GETDATE(), 'HH:mm:ss.ff') + ' - T_DASHBOARDUZENET - ' + CAST(@rowCount AS nvarchar(20)) + ' sor'
RAISERROR (@message, 10, 1) WITH NOWAIT
-- ================================================================================ --
-- Az ORAREND áttöltése --
-- ================================================================================ --
SET @columnList = NULL
SELECT @columnList = ISNULL(@columnList + ', ', '') + c.COLUMN_NAME
FROM INFORMATION_SCHEMA.COLUMNS c
WHERE c.TABLE_NAME = 'T_ORAREND' AND c.TABLE_SCHEMA = 'dbo'
SET @sql = N'
INSERT INTO T_ORAREND (' + @columnList + ')
SELECT ' + @columnList + '
FROM ' + @pSourceDatabase + '.dbo.T_ORAREND x
' + IIF(@pArchivalandoRelativTanevSorszam IS NULL, '', 'INNER JOIN #Tanev t ON t.TanevId = x.C_TANEVID') + '
WHERE x.C_INTEZMENYID IN (' + @pSourceIntezmenyIds + ')
SET @rowCount = @@ROWCOUNT
'
IF @pDebugMode = 1 RAISERROR (@sql, 10, 1) WITH NOWAIT
EXEC sp_executesql @sql, N'@IntId nvarchar(255), @newIntezmenyId int, @rowCount int output', @pSourceIntezmenyIds, @newIntezmenyId, @rowCount output
SET @message = ' CPJ ' + FORMAT(GETDATE(), 'HH:mm:ss.ff') + ' - T_ORAREND - ' + CAST(@rowCount AS nvarchar(20)) + ' sor'
RAISERROR (@message, 10, 1) WITH NOWAIT
-- ================================================================================ --
-- Az T_ORARENDTELJES áttöltése --
-- ================================================================================ --
SET @columnList = NULL
SELECT @columnList = ISNULL(@columnList + ', ', '') + c.COLUMN_NAME
FROM INFORMATION_SCHEMA.COLUMNS c
WHERE c.TABLE_NAME = 'T_ORARENDTELJES' AND c.TABLE_SCHEMA = 'dbo'
SET @sql = N'
INSERT INTO T_ORARENDTELJES (' + @columnList + ')
SELECT ' + @columnList + '
FROM ' + @pSourceDatabase + '.dbo.T_ORARENDTELJES x
' + IIF(@pArchivalandoRelativTanevSorszam IS NULL, '', 'INNER JOIN #Tanev t ON t.TanevId = x.C_TANEVID') + '
WHERE x.C_INTEZMENYID IN (' + @pSourceIntezmenyIds + ')
SET @rowCount = @@ROWCOUNT
'
IF @pDebugMode = 1 RAISERROR (@sql, 10, 1) WITH NOWAIT
EXEC sp_executesql @sql, N'@IntId nvarchar(255), @newIntezmenyId int, @rowCount int output', @pSourceIntezmenyIds, @newIntezmenyId, @rowCount output
SET @message = ' CPK ' + FORMAT(GETDATE(), 'HH:mm:ss.ff') + ' - T_ORARENDTELJES - ' + CAST(@rowCount AS nvarchar(20)) + ' sor'
RAISERROR (@message, 10, 1) WITH NOWAIT
-- ================================================================================ --
-- Az T_OSZTONDIJHISTORY áttöltése --
-- ================================================================================ --
SET @columnList = NULL
SELECT @columnList = ISNULL(@columnList + ', x.', 'x.') + c.COLUMN_NAME
FROM INFORMATION_SCHEMA.COLUMNS c
WHERE c.TABLE_NAME = 'T_OSZTONDIJHISTORY' AND c.TABLE_SCHEMA = 'dbo'
SET @sql = N'
INSERT INTO T_OSZTONDIJHISTORY (' + @columnList + ')
SELECT ' + @columnList + '
FROM ' + @pSourceDatabase + '.dbo.T_OSZTONDIJHISTORY x
' + IIF(@pArchivalandoRelativTanevSorszam IS NULL, '', 'INNER JOIN #Tanev t ON t.TanevId = x.C_TANEVID') + '
INNER JOIN T_Tanev tanev ON tanev.ID = x.C_TANEVID
WHERE tanev.C_INTEZMENYID IN (' + @pSourceIntezmenyIds + ')
SET @rowCount = @@ROWCOUNT
'
print @sql
IF @pDebugMode = 1 RAISERROR (@sql, 10, 1) WITH NOWAIT
EXEC sp_executesql @sql, N'@IntId nvarchar(255), @newIntezmenyId int, @rowCount int output', @pSourceIntezmenyIds, @newIntezmenyId, @rowCount output
SET @message = ' CPK ' + FORMAT(GETDATE(), 'HH:mm:ss.ff') + ' - T_OSZTONDIJHISTORY - ' + CAST(@rowCount AS nvarchar(20)) + ' sor'
RAISERROR (@message, 10, 1) WITH NOWAIT
-- ================================================================================ --
-- Az ENTITY HISTORY áttöltése --
-- ================================================================================ --
IF @pEntityHistoryMigration = 1 AND @pArchivalandoRelativTanevSorszam IS NULL 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 ID, x.C_ALTERATIONDATE, x.C_ENTITYID, x.C_ENTITYNAME, x.C_REASON, x.C_FELHASZNALOID, x.C_INTEZMENYID, x.C_TANEVID, x.CREATED
FROM ' + @pSourceDatabase + '.dbo.T_ENTITYHISTORY x
WHERE x.C_INTEZMENYID IN (' + @pSourceIntezmenyIds + ')
SET @rowCount = @@ROWCOUNT
SET IDENTITY_INSERT T_ENTITYHISTORY OFF'
IF @pDebugMode = 1 RAISERROR (@sql, 10, 1) WITH NOWAIT
EXEC sp_executesql @sql, N'@IntId nvarchar(255), @newIntezmenyId int, @rowCount int output', @pSourceIntezmenyIds, @newIntezmenyId, @rowCount output
SET @message = ' CPL ' + FORMAT(GETDATE(), 'HH:mm:ss.ff') + ' - T_ENTITYHISTORY - ' + CAST(@rowCount AS nvarchar(20)) + ' sor'
RAISERROR (@message, 10, 1) WITH NOWAIT
-- EntityAttributeHistory
SET @sql = N'
--SET IDENTITY_INSERT T_ENTITYATTRIBUTEHISTORY ON
INSERT INTO T_ENTITYATTRIBUTEHISTORY (C_CURRENTVALUE, C_ORIGINALVALUE, C_PROPERTYNAME, C_ENTITYHISTORYID)
SELECT C_CURRENTVALUE, C_ORIGINALVALUE, C_PROPERTYNAME, C_ENTITYHISTORYID
FROM ' + @pSourceDatabase + '.dbo.T_ENTITYATTRIBUTEHISTORY e
INNER JOIN ' + @pSourceDatabase + '.dbo.T_ENTITYHISTORY x ON x.ID = e.C_ENTITYHISTORYID AND x.C_INTEZMENYID IN (' + @pSourceIntezmenyIds + ');
SET @rowCount = @@ROWCOUNT
--SET IDENTITY_INSERT T_ENTITYATTRIBUTEHISTORY OFF
'
IF @pDebugMode = 1 RAISERROR (@sql, 10, 1) WITH NOWAIT
EXEC sp_executesql @sql, N'@IntId nvarchar(255), @newIntezmenyId int, @rowCount int output', @pSourceIntezmenyIds, @newIntezmenyId, @rowCount output
SET @message = ' CPL ' + FORMAT(GETDATE(), 'HH:mm:ss.ff') + ' - T_ENTITYATTRIBUTEHISTORY - ' + CAST(@rowCount AS nvarchar(20)) + ' sor'
RAISERROR (@message, 10, 1) WITH NOWAIT
SET @sql = N'
INSERT INTO T_ENTITYBLOBVALUES (C_CURRENTVALUE, C_ORIGINALVALUE, C_PROPERTYNAME, C_ENTITYHISTORYID)
SELECT C_CURRENTVALUE, C_ORIGINALVALUE, C_PROPERTYNAME, C_ENTITYHISTORYID
FROM ' + @pSourceDatabase + '.dbo.T_ENTITYBLOBVALUES e
INNER JOIN ' + @pSourceDatabase + '.dbo.T_ENTITYHISTORY x ON x.ID = e.C_ENTITYHISTORYID AND x.C_INTEZMENYID IN (' + @pSourceIntezmenyIds + ');
SET @rowCount = @@ROWCOUNT
'
IF @pDebugMode = 1 RAISERROR (@sql, 10, 1) WITH NOWAIT
EXEC sp_executesql @sql, N'@IntId nvarchar(255), @newIntezmenyId int, @rowCount int output', @pSourceIntezmenyIds, @newIntezmenyId, @rowCount output
SET @message = ' CPL ' + FORMAT(GETDATE(), 'HH:mm:ss.ff') + ' - T_ENTITYBLOBVALUES - ' + CAST(@rowCount AS nvarchar(20)) + ' sor'
RAISERROR (@message, 10, 1) WITH NOWAIT
-- EntityAttributeHistory_Archive
IF OBJECT_ID('dbo.T_ENTITYATTRIBUTEHISTORY_ARCHIVE') IS NOT NULL BEGIN
SET @sql = N'
--SET IDENTITY_INSERT T_ENTITYATTRIBUTEHISTORY_ARCHIVE ON
INSERT INTO T_ENTITYATTRIBUTEHISTORY_ARCHIVE (ID, C_CURRENTVALUE, C_ORIGINALVALUE, C_PROPERTYNAME, C_ENTITYHISTORYID)
SELECT e.ID, C_CURRENTVALUE, C_ORIGINALVALUE, C_PROPERTYNAME, C_ENTITYHISTORYID
FROM ' + @pSourceDatabase + '.dbo.T_ENTITYATTRIBUTEHISTORY_ARCHIVE e
INNER JOIN ' + @pSourceDatabase + '.dbo.T_ENTITYHISTORY x ON x.ID = e.C_ENTITYHISTORYID AND x.C_INTEZMENYID IN (' + @pSourceIntezmenyIds + ');
SET @rowCount = @@ROWCOUNT
--SET IDENTITY_INSERT T_ENTITYATTRIBUTEHISTORY_ARCHIVE OFF
'
IF @pDebugMode = 1 RAISERROR (@sql, 10, 1) WITH NOWAIT
EXEC sp_executesql @sql, N'@IntId nvarchar(255), @newIntezmenyId int, @rowCount int output', @pSourceIntezmenyIds, @newIntezmenyId, @rowCount output
SET @message = ' CPL ' + FORMAT(GETDATE(), 'HH:mm:ss.ff') + ' - T_ENTITYATTRIBUTEHISTORY_ARCHIVE - ' + CAST(@rowCount AS nvarchar(20)) + ' sor'
RAISERROR (@message, 10, 1) WITH NOWAIT
END
IF OBJECT_ID('dbo.T_ENTITYBLOBVALUES_ARCHIVE') IS NOT NULL BEGIN
SET @sql = N'
INSERT INTO T_ENTITYBLOBVALUES_ARCHIVE (C_CURRENTVALUE, C_ORIGINALVALUE, C_PROPERTYNAME, C_ENTITYHISTORYID)
SELECT C_CURRENTVALUE, C_ORIGINALVALUE, C_PROPERTYNAME, C_ENTITYHISTORYID
FROM ' + @pSourceDatabase + '.dbo.T_ENTITYBLOBVALUES_ARCHIVE e
INNER JOIN ' + @pSourceDatabase + '.dbo.T_ENTITYHISTORY x ON x.ID = e.C_ENTITYHISTORYID AND x.C_INTEZMENYID IN (' + @pSourceIntezmenyIds + ');
SET @rowCount = @@ROWCOUNT
'
IF @pDebugMode = 1 RAISERROR (@sql, 10, 1) WITH NOWAIT
EXEC sp_executesql @sql, N'@IntId nvarchar(255), @newIntezmenyId int, @rowCount int output', @pSourceIntezmenyIds, @newIntezmenyId, @rowCount output
SET @message = ' CPL ' + FORMAT(GETDATE(), 'HH:mm:ss.ff') + ' - T_ENTITYBLOBVALUES_ARCHIVE - ' + CAST(@rowCount AS nvarchar(20)) + ' sor'
RAISERROR (@message, 10, 1) WITH NOWAIT
END
END
-- ================================================================================ --
-- Az VersionInfo és dev táblák áttöltése --
-- ================================================================================ --
SET @sql = N'
INSERT INTO VersionInfo (Version, Description, AppliedOn)
SELECT Version, Description, MIN(AppliedOn)
FROM ' + @pSourceDatabase + '.dbo.VersionInfo x
WHERE NOT EXISTS (SELECT 1 FROM VersionInfo s WHERE s.Version = x.Version)
GROUP BY Version, Description
SET @rowCount = @@ROWCOUNT
'
IF @pDebugMode = 1 RAISERROR (@sql, 10, 1) WITH NOWAIT
EXEC sp_executesql @sql, N'@IntId nvarchar(255), @newIntezmenyId int, @rowCount int output', @pSourceIntezmenyIds, @newIntezmenyId, @rowCount output
SET @message = ' CPM ' + FORMAT(GETDATE(), 'HH:mm:ss.ff') + ' - VersionInfo - ' + CAST(@rowCount AS nvarchar(20)) + ' sor'
RAISERROR (@message, 10, 1) WITH NOWAIT
SET @sql = N'
INSERT INTO dev.EnvironmentInfo ([Key], Value, Description)
SELECT [Key], Value, Description
FROM ' + @pSourceDatabase + '.dev.EnvironmentInfo x
WHERE NOT EXISTS (SELECT 1 FROM dev.EnvironmentInfo s WHERE s.[Key] = x.[Key])
SET @rowCount = @@ROWCOUNT
'
IF @pDebugMode = 1 RAISERROR (@sql, 10, 1) WITH NOWAIT
EXEC sp_executesql @sql, N'@IntId nvarchar(255), @newIntezmenyId int, @rowCount int output', @pSourceIntezmenyIds, @newIntezmenyId, @rowCount output
SET @message = ' CPN ' + FORMAT(GETDATE(), 'HH:mm:ss.ff') + ' - EnvironmentInfo - ' + CAST(@rowCount AS nvarchar(20)) + ' sor'
RAISERROR (@message, 10, 1) WITH NOWAIT
SET @sql = N'
INSERT INTO dev.ElearningKurzusEvfolyamMapping (evfolyamId, Azonosito)
SELECT evfolyamId, Azonosito
FROM ' + @pSourceDatabase + '.dev.ElearningKurzusEvfolyamMapping x
WHERE NOT EXISTS (SELECT 1 FROM dev.ElearningKurzusEvfolyamMapping s WHERE s.evfolyamId = x.evfolyamId AND s.Azonosito = x.Azonosito)
SET @rowCount = @@ROWCOUNT
'
IF @pDebugMode = 1 RAISERROR (@sql, 10, 1) WITH NOWAIT
EXEC sp_executesql @sql, N'@IntId nvarchar(255), @newIntezmenyId int, @rowCount int output', @pSourceIntezmenyIds, @newIntezmenyId, @rowCount output
SET @message = ' CPO ' + FORMAT(GETDATE(), 'HH:mm:ss.ff') + ' - EnvironmentInfo - ' + CAST(@rowCount AS nvarchar(20)) + ' sor'
RAISERROR (@message, 10, 1) WITH NOWAIT
SET @sql = N'
SET IDENTITY_INSERT core.AdatszotarElemek ON
INSERT INTO core.AdatszotarElemek (Id,Nev,PluszOszlopok,TableName,TableSchemaName)
SELECT Id, Nev, PluszOszlopok, TableName, TableSchemaName
FROM ' + @pSourceDatabase + '.core.AdatszotarElemek x
WHERE NOT EXISTS (SELECT 1 FROM core.AdatszotarElemek s WHERE x.Id = s.Id)
SET IDENTITY_INSERT core.AdatszotarElemek OFF
'
IF @pDebugMode = 1 RAISERROR (@sql, 10, 1) WITH NOWAIT
EXEC sp_executesql @sql, N'@IntId nvarchar(255), @newIntezmenyId int, @rowCount int output', @pSourceIntezmenyIds, @newIntezmenyId, @rowCount output
SET @message = ' CPP ' + FORMAT(GETDATE(), 'HH:mm:ss.ff') + ' - core.AdatszotarElemek - ' + CAST(@rowCount AS nvarchar(20)) + ' sor'
RAISERROR (@message, 10, 1) WITH NOWAIT
IF @pArchivalandoRelativTanevSorszam IS NOT NULL BEGIN
SET @sql = N'
UPDATE x SET
C_ARCHIVADATBAZIS = ''' + @pSourceDatabase + '''
FROM ' + @pSourceDatabase + '.dbo.T_TANEV x
INNER JOIN #Tanev t On t.TanevId = x.ID
'
IF @pDebugMode = 1 RAISERROR (@sql, 10, 1) WITH NOWAIT
EXEC sp_executesql @sql, N'@IntId nvarchar(255), @newIntezmenyId int, @rowCount int output', @pSourceIntezmenyIds, @newIntezmenyId, @rowCount output
SET @message = ' CPQ ' + FORMAT(GETDATE(), 'HH:mm:ss.ff') + ' - T_TANEV update - ' + CAST(@rowCount AS nvarchar(20)) + ' sor'
RAISERROR (@message, 10, 1) WITH NOWAIT
END
END
GO