kreta/Kreta.DataAccess.Migrations/Scripts/Archive/20181015113005_AL_18/AL_18.sql
2024-03-13 00:33:46 +01:00

45 lines
2.2 KiB
Transact-SQL

--Migration
CREATE table #tmp(
TableName nvarchar(128)
,TableCol nvarchar(128)
,dibValue nvarchar(200)
,dibID int
,dibType nvarchar(128)
,TanevID int
)
DECLARE @sql nvarchar(max)=''
SELECT @sql+=N'
SELECT DISTINCT
'''++OBJECT_NAME(dibfkRef.parent_object_id)++''' as TableName
,'''++COL_NAME(fkc.parent_object_id,fkc.parent_column_id)++''' as TableCol
,dib.C_NAME as dibValue
,dib.ID as dibID
,dib.C_TYPE as dibType
,tn.ID as TanevID
FROM T_INTEZMENY i
INNER JOIN T_TANEV tn ON tn.C_INTEZMENYID=i.ID AND tn.TOROLT=''F'' AND tn.C_NEV=''2018/2019''
INNER JOIN '+OBJECT_NAME(dibfkRef.parent_object_id)+' t ON t.'+CASE WHEN OBJECT_NAME(dibfkRef.parent_object_id) IN ('T_TANULO','T_ALKALMAZOTT','T_CSOPORT','T_OSZTALY') THEN 'C_ALTANEVID' ELSE 'C_TANEVID' END+'=tn.ID AND t.TOROLT=''F''
INNER JOIN T_DICTIONARYITEMBASE dib ON dib.ID=t.'+COL_NAME(fkc.parent_object_id,fkc.parent_column_id)+' AND dib.C_TANEVID=tn.ID AND dib.TOROLT=''T''
WHERE i.TOROLT=''F'''
FROM sys.foreign_keys dibfk
INNER JOIN sys.foreign_keys dibfkRef ON dibfk.parent_object_id=dibfkRef.referenced_object_id
INNER JOIN sys.foreign_key_columns fkc ON fkc.parent_object_id=dibfkRef.parent_object_id
AND fkc.referenced_object_id=dibfk.parent_object_id AND fkc.referenced_column_id=1 AND fkc.constraint_object_id=dibfkRef.object_id
WHERE OBJECT_NAME(dibfk.referenced_object_id)='T_DICTIONARYITEMBASE' AND OBJECT_NAME(dibfkRef.parent_object_id)<>'T_EVFOLYAMTIPUS_OKTATASINEVELE'
insert into #tmp (TableName,TableCol,dibValue,dibID,dibType,TanevID)
exec (@sql)
select * from #tmp
set @sql=N'DECLARE @newId INT
'
select @sql+= N'
SET @newId=(SELECT TOP 1 ID FROM T_DICTIONARYITEMBASE WHERE C_NAME='''+dibValue+''' AND C_TYPE='''+dibType+''' AND C_TANEVID='+cast(TanevID as VARCHAR)+' AND TOROLT=''F'')
IF @newId IS NOT NULL
UPDATE '+TableName+' SET '+TableCol+' = @newId WHERE C_TANEVID='+cast(TanevID AS VARCHAR)+' AND TOROLT=''F'' AND '+TableCol+' = '+CAST(dibID as VARCHAR)+'
ELSE
UPDATE T_DICTIONARYITEMBASE SET TOROLT=''F'' WHERE C_TANEVID='+cast(TanevID as VARCHAR)+' AND C_TYPE='''+dibType+''' AND C_NAME='''+dibValue+''' AND TOROLT=''T'' AND ID = '+CAST(dibID as VARCHAR)
FROM #tmp
exec(@sql)
print @sql
drop table #tmp