SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO DROP PROCEDURE IF EXISTS dbo.uspOsztondijHistoryFix GO CREATE PROCEDURE dbo.uspOsztondijHistoryFix AS SET NOCOUNT ON; /* Ez az sp beszúr nem létező entityhistory sorokat a T_OSZTONDIJHISTORY táblába, olyan esetekben, amikor egy öszondíj szempontjából releváns tábla/oszlop később lett hozzáadva (NOT NULL-al és default-al), mint ahogyan a táblában a sorok létrejöttek. Ekkor generálnunk kell egy olyan sort, amely azt mutatja mintha az oszlop értéke a sor beszúrásakor még NULL-lett volna és egy másik sort is be kell szúrni, amely pedig azt mutatja, mintha az oszlopot UPDATE-elték volna, amikor az oszlop és a hozzá tartozó default constraint létrejött. */ DROP TABLE IF EXISTS #TablaOszlopLista; CREATE TABLE #TablaOszlopLista( TablaId TINYINT, TablaNev SYSNAME COLLATE Hungarian_CI_AI, OszlopNev SYSNAME COLLATE Hungarian_CI_AI, PRIMARY KEY CLUSTERED (TablaId, OszlopNev), UNIQUE (TablaNev, OszlopNev) ); DROP TABLE IF EXISTS #columns CREATE TABLE #columns( table_name sysname, column_name sysname, created_date datetime, data_type sysname null, default_value nvarchar(100) null, primary key clustered (table_name, column_name) ) DECLARE @sql nvarchar(max) = '' SELECT @sql += CONCAT('(''', t.name, ''', ''', c.name, ''', ''', CONVERT(varchar(23), ISNULL(d.modify_date, GETDATE()), 121), ''', ''', y.name, ''', CAST(', ISNULL(d.definition, 'NULL'), ' AS nvarchar(100))),', CHAR(13)) FROM sys.tables t INNER JOIN sys.schemas s ON s.schema_id = t.schema_id INNER JOIN sys.columns c ON c.object_id = t.object_id INNER JOIN sys.types y ON y.system_type_id = c.system_type_id and y.user_type_id = c.user_type_id LEFT JOIN sys.default_constraints d ON d.parent_object_id = c.object_id AND d.parent_column_id = c.column_id AND c.is_nullable = 0 AND d.definition NOT LIKE '%next%' AND d.definition NOT LIKE '%getdate()%' AND d.definition NOT LIKE '%newid()%' WHERE s.name = 'dbo' AND c.name NOT IN ('SERIAL', 'LASTCHANGED', 'CREATED', 'ID', 'C_INTEZMENYID', 'C_ALINTEZMENYID', 'C_TANEVID', 'C_ALTANEVID') AND y.name NOT IN ('varbinary', 'binary') set @sql = 'SELECT * FROM ( VALUES ' + @sql + ' ('''', '''', '''', '''', '''') ) cols(table_name, column_name, created_date, data_type, default_value)' INSERT INTO #columns(table_name, column_name, created_date, data_type, default_value) EXEC(@sql) INSERT INTO #TablaOszlopLista(TablaId, TablaNev, OszlopNev) SELECT TablaId, TablaNev, OszlopNev FROM dbo.fnOsztondijHistoryOszlopok(); DROP TABLE IF EXISTS #TablaLista; CREATE TABLE #TablaLista( TablaId TINYINT, TablaNev SYSNAME COLLATE Hungarian_CI_AI, PRIMARY KEY CLUSTERED (TablaId), UNIQUE (TablaNev) ); INSERT INTO #TablaLista(TablaId, TablaNev) SELECT DISTINCT TablaId, TablaNev FROM #TablaOszlopLista; -- C_REASON = New: fantom sorok beszúrása az új oszlopok új sorainak INSERT INTO dbo.T_OSZTONDIJHISTORY( ID ,C_ENTITYID ,C_TABLEID ,C_ALTERATIONDATE ,C_REASONID ,C_FELHASZNALOID ,C_TANULOID ,C_TANEVID ,C_PROPERTYNAME ,C_ORIGINALVALUE ,C_CURRENTVALUE ) SELECT eh.ID, eh.C_ENTITYID, t.TablaId AS C_TABLEID, eh.C_ALTERATIONDATE, 1 AS C_REASONID, eh.C_FELHASZNALOID, CASE eh.C_ENTITYNAME WHEN 'T_OSZTALYCSOPORT' THEN 0 WHEN 'T_TANULO' THEN eh.C_ENTITYID WHEN 'T_TANULOCSOPORT' THEN tcs1.C_TANULOID WHEN 'T_TANULOMULASZTAS' THEN tm.C_ORATANULOIID WHEN 'T_TANULOTANUGYIADATOK' THEN tcs2.C_TANULOID ELSE null END AS C_TANULOID, eh.C_TANEVID, c.column_name AS C_PROPERTYNAME, NULL AS C_ORIGINALVALUE, NULL AS C_CURRENTVALUE FROM T_ENTITYHISTORY eh WITH (NOLOCK) INNER JOIN T_TANEV v WITH (NOLOCK) on v.ID = eh.C_TANEVID INNER JOIN T_INTEZMENY i WITH (NOLOCK) ON i.ID = v.C_INTEZMENYID INNER JOIN #TablaLista t ON t.TablaNev = eh.C_ENTITYNAME INNER JOIN #columns c on c.table_name = eh.C_ENTITYNAME LEFT JOIN T_TANULOCSOPORT tcs1 WITH (NOLOCK) ON tcs1.ID = eh.C_ENTITYID and eh.C_ENTITYNAME = 'T_TANULOCSOPORT' LEFT JOIN T_TANULOMULASZTAS tm WITH (NOLOCK) ON tm.ID = eh.C_ENTITYID and eh.C_ENTITYNAME = 'T_TANULOMULASZTAS' LEFT JOIN T_TANULOTANUGYIADATOK tt WITH (NOLOCK) ON tt.ID = eh.C_ENTITYID and eh.C_ENTITYNAME = 'T_TANULOTANUGYIADATOK' LEFT JOIN T_TANULOCSOPORT tcs2 WITH (NOLOCK) ON tcs2.ID = tt.C_TANULOCSOPORTID WHERE (v.C_AKTIV = 'T' OR v.C_KOVETKEZO = 'T') AND v.C_SORSZAM >= ((YEAR(GETDATE()) - 1 - 2000) * 2) AND v.TOROLT = 'F' AND i.TOROLT = 'F' AND eh.C_REASON = 'New' AND EXISTS(SELECT * FROM #TablaOszlopLista t WHERE t.TablaNev = c.table_name AND t.OszlopNev = c.column_name) AND NOT EXISTS( SELECT * FROM dbo.T_OSZTONDIJHISTORY oh WHERE oh.C_TANEVID = eh.C_TANEVID AND oh.ID = eh.ID AND oh.C_REASONID = 1 AND oh.C_PROPERTYNAME = c.column_name ) -- C_REASON = Modified: fantom sorok beszúrása az új oszlopok default hozzáadásakor INSERT INTO dbo.T_OSZTONDIJHISTORY( ID ,C_ENTITYID ,C_TABLEID ,C_ALTERATIONDATE ,C_REASONID ,C_FELHASZNALOID ,C_TANULOID ,C_TANEVID ,C_PROPERTYNAME ,C_ORIGINALVALUE ,C_CURRENTVALUE ) SELECT -eh.ID, eh.C_ENTITYID, t.TablaId AS C_TABLEID, c.created_date AS C_ALTERATIONDATE, 3 AS C_REASONID, 0 AS C_FELHASZNALOID, CASE eh.C_ENTITYNAME WHEN 'T_OSZTALYCSOPORT' THEN 0 WHEN 'T_TANULO' THEN eh.C_ENTITYID WHEN 'T_TANULOCSOPORT' THEN tcs1.C_TANULOID WHEN 'T_TANULOMULASZTAS' THEN tm.C_ORATANULOIID WHEN 'T_TANULOTANUGYIADATOK' THEN tcs2.C_TANULOID ELSE null END AS C_TANULOID, eh.C_TANEVID, c.column_name AS C_PROPERTYNAME, NULL AS C_ORIGINALVALUE, c.default_value AS C_CURRENTVALUE FROM T_ENTITYHISTORY eh WITH (NOLOCK) INNER JOIN T_TANEV v WITH (NOLOCK) on v.ID = eh.C_TANEVID INNER JOIN T_INTEZMENY i WITH (NOLOCK) ON i.ID = v.C_INTEZMENYID INNER JOIN #TablaLista t ON t.TablaNev = eh.C_ENTITYNAME INNER JOIN #columns c on c.table_name = eh.C_ENTITYNAME LEFT JOIN T_TANULOCSOPORT tcs1 WITH (NOLOCK) ON tcs1.ID = eh.C_ENTITYID and eh.C_ENTITYNAME = 'T_TANULOCSOPORT' LEFT JOIN T_TANULOMULASZTAS tm WITH (NOLOCK) ON tm.ID = eh.C_ENTITYID and eh.C_ENTITYNAME = 'T_TANULOMULASZTAS' LEFT JOIN T_TANULOTANUGYIADATOK tt WITH (NOLOCK) ON tt.ID = eh.C_ENTITYID and eh.C_ENTITYNAME = 'T_TANULOTANUGYIADATOK' LEFT JOIN T_TANULOCSOPORT tcs2 WITH (NOLOCK) ON tcs2.ID = tt.C_TANULOCSOPORTID WHERE (v.C_AKTIV = 'T' OR v.C_KOVETKEZO = 'T') AND v.C_SORSZAM >= ((YEAR(GETDATE()) - 1 - 2000) * 2) AND v.TOROLT = 'F' AND i.TOROLT = 'F' AND eh.C_REASON = 'New' AND c.default_value IS NOT NULL AND c.created_date BETWEEN v.C_KEZDONAP AND v.C_UTOLSONAP AND EXISTS(SELECT * FROM #TablaOszlopLista t WHERE t.TablaNev = c.table_name AND t.OszlopNev = c.column_name) AND NOT EXISTS( SELECT * FROM dbo.T_OSZTONDIJHISTORY oh WHERE oh.C_TANEVID = eh.C_TANEVID AND oh.C_TABLEID = t.TablaId AND oh.C_ENTITYID = eh.C_ENTITYID AND oh.C_PROPERTYNAME = c.column_name AND oh.C_CURRENTVALUE IS NOT NULL AND ( (oh.C_REASONID = 1 AND oh.C_ALTERATIONDATE <= eh.C_ALTERATIONDATE) OR (oh.C_REASONID = 3 AND oh.C_ALTERATIONDATE <= c.created_date) ) ) GO