kreta/Kreta.DataAccess.Migrations/Scripts/Archive/20190204140554_DB_201/uspCloneIntezmenyCreateMapping.sql
2024-03-13 00:33:46 +01:00

151 lines
5.8 KiB
Transact-SQL

DROP PROCEDURE IF EXISTS dev.uspCloneIntezmenyCreateMapping
GO
CREATE PROCEDURE dev.uspCloneIntezmenyCreateMapping
@pSourceIntezmenyId int
,@pSourceDatabase nvarchar(60)
AS
BEGIN
DECLARE
@sql nvarchar(max)
,@maxId int
,@tableName nvarchar(100)
,@mainTableName nvarchar(50)
,@isIdentity bit
-- ============================================================== --
-- Mapping tábla létrehozása --
-- ============================================================== --
DROP TABLE IF EXISTS MappingTable
CREATE TABLE MappingTable (
tableName nvarchar(50),
oldId int,
newId int
)
-- ============================================================== --
-- Mapping tábla feltöltése: Intezmeny --
-- ============================================================== --
SELECT @maxId = ISNULL(MAX(ID), 0) FROM T_INTEZMENY;
SET @sql = '
INSERT INTO MappingTable (tableName, oldId, [newId])
SELECT ''T_INTEZMENY'', ID, @maxId + 1
FROM ' + @pSourceDatabase + '.dbo.T_INTEZMENY
WHERE ID = @pSourceIntezmenyId
'
RAISERROR (@sql, 10, 1) WITH NOWAIT
EXEC sp_executesql @sql, N'@pSourceIntezmenyId int, @maxId int', @pSourceIntezmenyId, @maxId
-- ============================================================== --
-- Mapping tábla feltöltése: IDENTITY() táblákból --
-- ============================================================== --
DECLARE tbl_cur CURSOR LOCAL FOR
SELECT DISTINCT TABLE_NAME, COLUMNPROPERTY(OBJECT_ID(TABLE_NAME), 'ID', 'IsIdentity')
FROM INFORMATION_SCHEMA.COLUMNS c
INNER JOIN (
SELECT ta.name TableName, SUM(pa.rows) RowCnt
FROM sys.tables ta
INNER JOIN sys.partitions pa ON pa.OBJECT_ID = ta.OBJECT_ID
INNER JOIN sys.schemas sc ON ta.schema_id = sc.schema_id
WHERE ta.is_ms_shipped = 0 AND pa.index_id IN (1,0)
GROUP BY sc.name, ta.name
HAVING SUM(pa.rows) > 0
) x ON x.TableName = c.TABLE_NAME
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 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, @isIdentity
WHILE @@FETCH_STATUS = 0 BEGIN
SET @sql = N'
DECLARE @maxId int;
SELECT @maxId = ISNULL(MAX(ID), ' + CASE WHEN @tableName = 'T_DICTIONARYITEMBASE' THEN '100000' ELSE '0' END + ') FROM ' + @tableName + ';
INSERT INTO MappingTable (tableName, oldId, [newId])
SELECT DISTINCT ''' + @tableName + ''', ID, RANK() OVER(ORDER BY ID) + @maxId
FROM ' + @pSourceDatabase + '.dbo.' + @tableName + '
WHERE C_INTEZMENYID = @intId'
IF @tableName = 'T_DICTIONARYITEMBASE' BEGIN
SET @sql += ' AND ID >= 100000;'
END
RAISERROR (@sql, 10, 1) WITH NOWAIT
EXEC sp_executesql @sql, N'@intId int', @pSourceIntezmenyId
FETCH NEXT FROM tbl_cur
INTO @tableName, @isIdentity
END
CLOSE tbl_cur
DEALLOCATE tbl_cur
-- ============================================================== --
-- Mapping tábla feltöltése: nem IDENTITY() táblákból --
-- ============================================================== --
DECLARE tbl_cur CURSOR LOCAL FOR
SELECT DISTINCT TABLE_NAME, COLUMNPROPERTY(OBJECT_ID(TABLE_NAME), 'ID', 'IsIdentity')
FROM INFORMATION_SCHEMA.COLUMNS c
INNER JOIN (
SELECT ta.name TableName, SUM(pa.rows) RowCnt
FROM sys.tables ta
INNER JOIN sys.partitions pa ON pa.OBJECT_ID = ta.OBJECT_ID
INNER JOIN sys.schemas sc ON ta.schema_id = sc.schema_id
WHERE ta.is_ms_shipped = 0 AND pa.index_id IN (1,0)
GROUP BY sc.name, ta.name
HAVING SUM(pa.rows) > 0
) x ON x.TableName = c.TABLE_NAME
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 COLUMNPROPERTY(OBJECT_ID(TABLE_NAME), 'ID', 'IsIdentity') = 0
OPEN tbl_cur
FETCH NEXT FROM tbl_cur
INTO @tableName, @isIdentity
WHILE @@FETCH_STATUS = 0 BEGIN
SELECT @mainTableName = OBJECT_NAME(referenced_object_id)
FROM sys.foreign_key_columns f
INNER JOIN sys.columns rc ON rc.[object_id] = f.referenced_object_id AND rc.column_id = f.referenced_column_id
INNER JOIN sys.columns pc ON pc.[object_id] = f.parent_object_id AND rc.column_id = f.parent_column_id
WHERE parent_object_id = OBJECT_ID(@tableName) AND rc.[name] = 'ID' AND pc.[name] = 'ID'
SET @sql = N'
INSERT INTO MappingTable (tableName, oldId, [newId])
SELECT DISTINCT ''' + @tableName + ''', t.oldId, t.[newId]
FROM ' + @pSourceDatabase + '.dbo.' + @tableName + ' s
INNER JOIN MappingTable t ON t.oldId = s.ID AND t.tableName = @mainTableName
WHERE s.C_ALINTEZMENYID = @intId'
RAISERROR (@sql, 10, 1) WITH NOWAIT
EXEC sp_executesql @sql, N'@intId int, @mainTableName nvarchar(50)', @pSourceIntezmenyId, @mainTableName
FETCH NEXT FROM tbl_cur
INTO @tableName, @isIdentity
END
CLOSE tbl_cur
DEALLOCATE tbl_cur
-- ============================================================== --
-- MappingTable indexek --
-- ============================================================== --
CREATE CLUSTERED INDEX IX_MappingTable_01 ON MappingTable (oldId, [newId], tableName)
CREATE INDEX IX_MappingTable_02 ON MappingTable (tableName, oldId, [newId])
END
GO