194 lines
7.9 KiB
Transact-SQL
194 lines
7.9 KiB
Transact-SQL
GO
|
|
SET ANSI_NULLS, ANSI_PADDING, ANSI_WARNINGS, ARITHABORT, CONCAT_NULL_YIELDS_NULL, QUOTED_IDENTIFIER ON;
|
|
|
|
SET NUMERIC_ROUNDABORT OFF;
|
|
|
|
|
|
GO
|
|
|
|
--The column [dbo].[T_ERTEKELESMONDATBANK].[C_FELADATELLATASIHELYID] is being dropped, data loss could occur.
|
|
|
|
|
|
--IF EXISTS (select top 1 1 from [dbo].[T_ERTEKELESMONDATBANK])
|
|
-- RAISERROR (N'Rows were detected. The schema update is terminating because data loss might occur.', 16, 127) WITH NOWAIT
|
|
|
|
GO
|
|
PRINT N'Dropping [dbo].[T_ERTEKELESMONDATBANK].[I_T_4027926_4027924]...';
|
|
|
|
|
|
GO
|
|
DROP INDEX [I_T_4027926_4027924]
|
|
ON [dbo].[T_ERTEKELESMONDATBANK];
|
|
|
|
|
|
GO
|
|
PRINT N'Dropping [dbo].[FK_4027926_4027924]...';
|
|
|
|
|
|
GO
|
|
ALTER TABLE [dbo].[T_ERTEKELESMONDATBANK] DROP CONSTRAINT [FK_4027926_4027924];
|
|
|
|
|
|
GO
|
|
PRINT N'Altering [dbo].[T_ERTEKELESMONDATBANK]...';
|
|
|
|
|
|
GO
|
|
ALTER TABLE [dbo].[T_ERTEKELESMONDATBANK] DROP COLUMN [C_FELADATELLATASIHELYID];
|
|
|
|
|
|
GO
|
|
PRINT N'Altering [dbo].[tr_ertekelesmondatbankLog]...';
|
|
|
|
|
|
GO
|
|
|
|
ALTER TRIGGER tr_ertekelesmondatbankLog ON T_ERTEKELESMONDATBANK
|
|
FOR INSERT, DELETE, UPDATE AS
|
|
BEGIN
|
|
SET NOCOUNT ON
|
|
DECLARE
|
|
@insTable TABLE (objectId int, intezmenyId int, tanevId int, creator int, modifier int, col nvarchar(30), val varchar(max))
|
|
DECLARE
|
|
@delTable TABLE (objectId int, intezmenyId int, tanevId int, creator int, modifier int, col nvarchar(30), val varchar(max))
|
|
DECLARE
|
|
@linkTable TABLE (id int, objectId int, intezmenyId int, tanevId int)
|
|
DECLARE
|
|
@action char(1),
|
|
@xml xml
|
|
|
|
SET @action =
|
|
CASE
|
|
WHEN NOT EXISTS (SELECT 1 FROM DELETED) THEN 'I'
|
|
WHEN NOT EXISTS (SELECT 1 FROM INSERTED) THEN 'D'
|
|
ELSE 'U'
|
|
END
|
|
|
|
|
|
INSERT INTO @insTable (objectId, intezmenyId, tanevId, creator, modifier, col, val)
|
|
SELECT ID, C_INTEZMENYID, C_TANEVID, CREATOR, MODIFIER, col, val
|
|
FROM
|
|
(
|
|
SELECT ID, C_INTEZMENYID AS C_INTEZMENYID, C_TANEVID AS C_TANEVID, CREATOR, MODIFIER, CAST( C_ERTEKELESTIPUSA AS nvarchar(MAX)) AS C_ERTEKELESTIPUSA, CAST( C_EVFOLYAMTIPUSA AS nvarchar(MAX)) AS C_EVFOLYAMTIPUSA, CAST( C_ROVIDNEV AS nvarchar(MAX)) AS C_ROVIDNEV, CAST( C_SZOVEG AS nvarchar(MAX)) AS C_SZOVEG, CAST( C_TANTARGYID AS nvarchar(MAX)) AS C_TANTARGYID, CAST( TOROLT AS nvarchar(MAX)) AS TOROLT, CAST( ELOZOTANEVIREKORDID AS nvarchar(MAX)) AS ELOZOTANEVIREKORDID, CAST( NNID AS nvarchar(MAX)) AS NNID
|
|
FROM INSERTED) p
|
|
UNPIVOT (val FOR col IN (C_ERTEKELESTIPUSA, C_EVFOLYAMTIPUSA, C_ROVIDNEV, C_SZOVEG, C_TANTARGYID, TOROLT, ELOZOTANEVIREKORDID, NNID)) AS unpvt
|
|
|
|
INSERT INTO @delTable (objectId, intezmenyId, tanevId, creator, modifier, col, val)
|
|
SELECT ID, C_INTEZMENYID, C_TANEVID, CREATOR, MODIFIER, col, val
|
|
FROM
|
|
(
|
|
SELECT ID, C_INTEZMENYID AS C_INTEZMENYID, C_TANEVID AS C_TANEVID, CREATOR, MODIFIER, CAST( C_ERTEKELESTIPUSA AS nvarchar(MAX)) AS C_ERTEKELESTIPUSA, CAST( C_EVFOLYAMTIPUSA AS nvarchar(MAX)) AS C_EVFOLYAMTIPUSA, CAST( C_ROVIDNEV AS nvarchar(MAX)) AS C_ROVIDNEV, CAST( C_SZOVEG AS nvarchar(MAX)) AS C_SZOVEG, CAST( C_TANTARGYID AS nvarchar(MAX)) AS C_TANTARGYID, CAST( TOROLT AS nvarchar(MAX)) AS TOROLT, CAST( ELOZOTANEVIREKORDID AS nvarchar(MAX)) AS ELOZOTANEVIREKORDID, CAST( NNID AS nvarchar(MAX)) AS NNID
|
|
FROM DELETED) p
|
|
UNPIVOT (val FOR col IN (C_ERTEKELESTIPUSA, C_EVFOLYAMTIPUSA, C_ROVIDNEV, C_SZOVEG, C_TANTARGYID, TOROLT, ELOZOTANEVIREKORDID, NNID)) AS unpvt
|
|
|
|
IF @action = 'I' BEGIN
|
|
INSERT INTO T_ENTITYHISTORY (C_ALTERATIONDATE, C_ENTITYID, C_ENTITYNAME, C_REASON, C_FELHASZNALOID, C_INTEZMENYID, C_TANEVID)
|
|
OUTPUT INSERTED.ID, INSERTED.C_ENTITYID, INSERTED.C_INTEZMENYID, INSERTED.C_TANEVID INTO @linkTable
|
|
SELECT DISTINCT GETDATE(), objectId, 'T_ERTEKELESMONDATBANK', 'New', creator, intezmenyId, tanevId FROM @insTable
|
|
|
|
INSERT INTO T_ENTITYATTRIBUTEHISTORY (C_CURRENTVALUE, C_ORIGINALVALUE, C_PROPERTYNAME, C_ENTITYHISTORYID)
|
|
SELECT val, NULL, col, lk.id
|
|
FROM @insTable i
|
|
INNER JOIN @linkTable lk ON i.objectId = lk.objectId AND i.intezmenyId = lk.intezmenyId AND i.tanevId = lk.tanevId
|
|
|
|
END
|
|
|
|
IF @action = 'D' BEGIN
|
|
INSERT INTO T_ENTITYHISTORY (C_ALTERATIONDATE, C_ENTITYID, C_ENTITYNAME, C_REASON, C_FELHASZNALOID, C_INTEZMENYID, C_TANEVID)
|
|
OUTPUT INSERTED.ID, INSERTED.C_ENTITYID, INSERTED.C_INTEZMENYID, INSERTED.C_TANEVID INTO @linkTable
|
|
SELECT DISTINCT GETDATE(), objectId, 'T_ERTEKELESMONDATBANK', 'Removed', modifier, intezmenyId, tanevId FROM @delTable
|
|
|
|
INSERT INTO T_ENTITYATTRIBUTEHISTORY (C_CURRENTVALUE, C_ORIGINALVALUE, C_PROPERTYNAME, C_ENTITYHISTORYID)
|
|
SELECT val, NULL, col, lk.id
|
|
FROM @delTable i
|
|
INNER JOIN @linkTable lk ON i.objectId = lk.objectId AND i.intezmenyId = lk.intezmenyId AND i.tanevId = lk.tanevId
|
|
|
|
END
|
|
|
|
IF @action = 'U' BEGIN
|
|
INSERT INTO T_ENTITYHISTORY (C_ALTERATIONDATE, C_ENTITYID, C_ENTITYNAME, C_REASON, C_FELHASZNALOID, C_INTEZMENYID, C_TANEVID)
|
|
OUTPUT INSERTED.ID, INSERTED.C_ENTITYID, INSERTED.C_INTEZMENYID, INSERTED.C_TANEVID INTO @linkTable
|
|
SELECT DISTINCT GETDATE(), i.objectId, 'T_ERTEKELESMONDATBANK',
|
|
CASE
|
|
WHEN i.val = 'T' AND d.val = 'F' THEN 'Logical Removed'
|
|
WHEN i.val = 'F' AND d.val = 'T' THEN 'Restored'
|
|
ELSE 'Modified'
|
|
END, i.modifier, i.intezmenyId, i.tanevId
|
|
FROM @insTable i
|
|
INNER JOIN @delTable d ON i.intezmenyId = d.intezmenyId AND i.objectId = d.objectId AND i.tanevId = d.tanevId AND i.col = d.col
|
|
WHERE i.col = 'TOROLT' AND d.COL = 'TOROLT'
|
|
|
|
INSERT INTO T_ENTITYATTRIBUTEHISTORY (C_CURRENTVALUE, C_ORIGINALVALUE, C_PROPERTYNAME, C_ENTITYHISTORYID)
|
|
SELECT i.val, d.val, ISNULL(i.col, d.col), lk.id
|
|
FROM @delTable d
|
|
FULL JOIN @insTable i ON i.objectId = d.objectId AND i.intezmenyId = d.intezmenyId AND i.tanevId = d.tanevId AND i.col = d.col
|
|
INNER JOIN @linkTable lk ON ISNULL(i.objectId, d.objectId) = lk.objectId AND ISNULL(i.intezmenyId, d.intezmenyId) = lk.intezmenyId AND ISNULL(i.tanevId, d.tanevId) = lk.tanevId
|
|
WHERE (i.val <> d.val OR ((i.val IS NULL OR d.val IS NULL) AND (i.val IS NOT NULL OR d.val IS NOT NULL)))
|
|
END
|
|
END
|
|
GO
|
|
PRINT N'Refreshing [dbo].[T_ERTEKELESMONDATBANK_OSSZES]...';
|
|
|
|
|
|
GO
|
|
EXECUTE sp_refreshsqlmodule N'[dbo].[T_ERTEKELESMONDATBANK_OSSZES]';
|
|
|
|
|
|
GO
|
|
PRINT N'Update complete.';
|
|
|
|
|
|
GO
|
|
|
|
|
|
PRINT '--- intézményi view-k (dbo táblákkal megegyezõ nevû és a tábla_OSSZES nevûek) frissítése ---'
|
|
|
|
DECLARE @viewname nvarchar(100), @pureview nvarchar(100)
|
|
|
|
DECLARE semaviewk CURSOR LOCAL FOR
|
|
SELECT '['+TABLE_SCHEMA + '].[' + TABLE_NAME + ']', TABLE_NAME
|
|
FROM INFORMATION_SCHEMA.TABLES
|
|
WHERE TABLE_TYPE = 'VIEW' and TABLE_SCHEMA LIKE 'KR[_]%[_]Schema'
|
|
AND TABLE_NAME in ('T_ERTEKELESMONDATBANK', 'T_ERTEKELESMONDATBANK_OSSZES') -- ha csak néhány VIEW frissült, akkor a gyorsabb futásért ide fel lehet sorolni
|
|
ORDER BY TABLE_SCHEMA, TABLE_NAME
|
|
|
|
OPEN semaviewk
|
|
FETCH NEXT FROM semaviewk INTO @viewname, @pureview
|
|
|
|
WHILE @@FETCH_STATUS = 0 BEGIN
|
|
PRINT @viewname
|
|
EXEC sp_refreshview @viewname
|
|
|
|
FETCH NEXT FROM semaviewk INTO @viewname, @pureview
|
|
END
|
|
|
|
CLOSE semaviewk
|
|
DEALLOCATE semaviewk
|
|
GO
|
|
|
|
|
|
-- Triggerek inicializálás az összes táblára
|
|
DECLARE tableCursor CURSOR LOCAL FOR
|
|
SELECT DISTINCT TABLE_NAME
|
|
FROM INFORMATION_SCHEMA.COLUMNS
|
|
WHERE COLUMN_NAME IN ('CREATOR', 'MODIFIER')
|
|
AND TABLE_NAME NOT IN ('T_ENTITYHISTORY', 'T_ENTITYATTRIBUTEHISTORY', 'T_LOG', 'T_GLOBALLOCK', 'T_USERPROFILE', 'T_OLDALLATOGATOTTSAG')
|
|
AND TABLE_NAME IN (
|
|
SELECT t.name
|
|
FROM sys.tables t
|
|
INNER JOIN sys.schemas s ON s.schema_id = t.schema_id
|
|
WHERE s.name ='dbo'
|
|
)
|
|
|
|
DECLARE @table nvarchar(35)
|
|
|
|
OPEN tableCursor
|
|
FETCH NEXT FROM tableCursor INTO @table
|
|
|
|
WHILE @@FETCH_STATUS = 0 BEGIN
|
|
EXEC sp_Global_CreateTriggers @table
|
|
FETCH NEXT FROM tableCursor INTO @table
|
|
END
|
|
|
|
CLOSE tableCursor
|
|
DEALLOCATE tableCursor
|