init
This commit is contained in:
@@ -0,0 +1,416 @@
|
||||
GO
|
||||
PRINT N'Creating [dbo].[tr_emailLog]...';
|
||||
|
||||
|
||||
GO
|
||||
|
||||
CREATE TRIGGER tr_emailLog ON T_EMAIL
|
||||
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_EMAILTIPUSA AS nvarchar(MAX)) AS C_EMAILTIPUSA, CAST( C_EMAILCIM AS nvarchar(MAX)) AS C_EMAILCIM, CAST( C_ALAPERTELMEZETT AS nvarchar(MAX)) AS C_ALAPERTELMEZETT, CAST( C_PUBLIKUSEMAILCIM AS nvarchar(MAX)) AS C_PUBLIKUSEMAILCIM, CAST( C_GONDVISELOID AS nvarchar(MAX)) AS C_GONDVISELOID, CAST( C_FELHASZNALOID AS nvarchar(MAX)) AS C_FELHASZNALOID, 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_EMAILTIPUSA, C_EMAILCIM, C_ALAPERTELMEZETT, C_PUBLIKUSEMAILCIM, C_GONDVISELOID, C_FELHASZNALOID, 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_EMAILTIPUSA AS nvarchar(MAX)) AS C_EMAILTIPUSA, CAST( C_EMAILCIM AS nvarchar(MAX)) AS C_EMAILCIM, CAST( C_ALAPERTELMEZETT AS nvarchar(MAX)) AS C_ALAPERTELMEZETT, CAST( C_PUBLIKUSEMAILCIM AS nvarchar(MAX)) AS C_PUBLIKUSEMAILCIM, CAST( C_GONDVISELOID AS nvarchar(MAX)) AS C_GONDVISELOID, CAST( C_FELHASZNALOID AS nvarchar(MAX)) AS C_FELHASZNALOID, 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_EMAILTIPUSA, C_EMAILCIM, C_ALAPERTELMEZETT, C_PUBLIKUSEMAILCIM, C_GONDVISELOID, C_FELHASZNALOID, 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_EMAIL', '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_EMAIL', '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_EMAIL',
|
||||
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'Creating [dbo].[tr_tanuloertekelesLog]...';
|
||||
|
||||
|
||||
GO
|
||||
|
||||
CREATE TRIGGER tr_tanuloertekelesLog ON T_TANULOERTEKELES
|
||||
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, CONVERT(nvarchar(MAX), C_ERTEKELESDATUM, 121) AS C_ERTEKELESDATUM, CAST( C_ERTEKELESTIPUSA AS nvarchar(MAX)) AS C_ERTEKELESTIPUSA, CAST( C_ERTEKELESSZOVEG AS nvarchar(MAX)) AS C_ERTEKELESSZOVEG, CAST( C_NEMMEGIRTDOLGOZAT AS nvarchar(MAX)) AS C_NEMMEGIRTDOLGOZAT, CONVERT(nvarchar(MAX), C_ROGZITESDATUM, 121) AS C_ROGZITESDATUM, CAST( C_OSZTALYZAT AS nvarchar(MAX)) AS C_OSZTALYZAT, CAST( C_LATTAMOZAS AS nvarchar(MAX)) AS C_LATTAMOZAS, CAST( C_TANTARGYID AS nvarchar(MAX)) AS C_TANTARGYID, CAST( C_TANULOID AS nvarchar(MAX)) AS C_TANULOID, CAST( C_OSZTALYCSOPORTID AS nvarchar(MAX)) AS C_OSZTALYCSOPORTID, CAST( C_ERTEKELOID AS nvarchar(MAX)) AS C_ERTEKELOID, CAST( C_TANORAID AS nvarchar(MAX)) AS C_TANORAID, 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_ERTEKELESDATUM, C_ERTEKELESTIPUSA, C_ERTEKELESSZOVEG, C_NEMMEGIRTDOLGOZAT, C_ROGZITESDATUM, C_OSZTALYZAT, C_LATTAMOZAS, C_TANTARGYID, C_TANULOID, C_OSZTALYCSOPORTID, C_ERTEKELOID, C_TANORAID, 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, CONVERT(nvarchar(MAX), C_ERTEKELESDATUM, 121) AS C_ERTEKELESDATUM, CAST( C_ERTEKELESTIPUSA AS nvarchar(MAX)) AS C_ERTEKELESTIPUSA, CAST( C_ERTEKELESSZOVEG AS nvarchar(MAX)) AS C_ERTEKELESSZOVEG, CAST( C_NEMMEGIRTDOLGOZAT AS nvarchar(MAX)) AS C_NEMMEGIRTDOLGOZAT, CONVERT(nvarchar(MAX), C_ROGZITESDATUM, 121) AS C_ROGZITESDATUM, CAST( C_OSZTALYZAT AS nvarchar(MAX)) AS C_OSZTALYZAT, CAST( C_LATTAMOZAS AS nvarchar(MAX)) AS C_LATTAMOZAS, CAST( C_TANTARGYID AS nvarchar(MAX)) AS C_TANTARGYID, CAST( C_TANULOID AS nvarchar(MAX)) AS C_TANULOID, CAST( C_OSZTALYCSOPORTID AS nvarchar(MAX)) AS C_OSZTALYCSOPORTID, CAST( C_ERTEKELOID AS nvarchar(MAX)) AS C_ERTEKELOID, CAST( C_TANORAID AS nvarchar(MAX)) AS C_TANORAID, 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_ERTEKELESDATUM, C_ERTEKELESTIPUSA, C_ERTEKELESSZOVEG, C_NEMMEGIRTDOLGOZAT, C_ROGZITESDATUM, C_OSZTALYZAT, C_LATTAMOZAS, C_TANTARGYID, C_TANULOID, C_OSZTALYCSOPORTID, C_ERTEKELOID, C_TANORAID, 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_TANULOERTEKELES', '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_TANULOERTEKELES', '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_TANULOERTEKELES',
|
||||
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'Creating [dbo].[tr_tanuloesemenyLog]...';
|
||||
|
||||
|
||||
GO
|
||||
|
||||
CREATE TRIGGER tr_tanuloesemenyLog ON T_TANULOESEMENY
|
||||
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, CONVERT(nvarchar(MAX), C_KEZDETE, 121) AS C_KEZDETE, CAST( C_MEGJEGYZES AS nvarchar(MAX)) AS C_MEGJEGYZES, CAST( C_TARTALOM AS nvarchar(MAX)) AS C_TARTALOM, CAST( C_TIPUS AS nvarchar(MAX)) AS C_TIPUS, CAST( C_TARGY AS nvarchar(MAX)) AS C_TARGY, CAST( C_FALIUJSAGMEGJELENES AS nvarchar(MAX)) AS C_FALIUJSAGMEGJELENES, CAST( C_MINDENKINEK AS nvarchar(MAX)) AS C_MINDENKINEK, CONVERT(nvarchar(MAX), C_VEGE, 121) AS C_VEGE, CONVERT(nvarchar(MAX), C_ROGZITESDATUMA, 121) AS C_ROGZITESDATUMA, CAST( C_LATTAMOZAS AS nvarchar(MAX)) AS C_LATTAMOZAS, CAST( C_FELJEGYZOID AS nvarchar(MAX)) AS C_FELJEGYZOID, CAST( C_TANTARGYID AS nvarchar(MAX)) AS C_TANTARGYID, CAST( C_TANITASIORAID AS nvarchar(MAX)) AS C_TANITASIORAID, 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_KEZDETE, C_MEGJEGYZES, C_TARTALOM, C_TIPUS, C_TARGY, C_FALIUJSAGMEGJELENES, C_MINDENKINEK, C_VEGE, C_ROGZITESDATUMA, C_LATTAMOZAS, C_FELJEGYZOID, C_TANTARGYID, C_TANITASIORAID, 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, CONVERT(nvarchar(MAX), C_KEZDETE, 121) AS C_KEZDETE, CAST( C_MEGJEGYZES AS nvarchar(MAX)) AS C_MEGJEGYZES, CAST( C_TARTALOM AS nvarchar(MAX)) AS C_TARTALOM, CAST( C_TIPUS AS nvarchar(MAX)) AS C_TIPUS, CAST( C_TARGY AS nvarchar(MAX)) AS C_TARGY, CAST( C_FALIUJSAGMEGJELENES AS nvarchar(MAX)) AS C_FALIUJSAGMEGJELENES, CAST( C_MINDENKINEK AS nvarchar(MAX)) AS C_MINDENKINEK, CONVERT(nvarchar(MAX), C_VEGE, 121) AS C_VEGE, CONVERT(nvarchar(MAX), C_ROGZITESDATUMA, 121) AS C_ROGZITESDATUMA, CAST( C_LATTAMOZAS AS nvarchar(MAX)) AS C_LATTAMOZAS, CAST( C_FELJEGYZOID AS nvarchar(MAX)) AS C_FELJEGYZOID, CAST( C_TANTARGYID AS nvarchar(MAX)) AS C_TANTARGYID, CAST( C_TANITASIORAID AS nvarchar(MAX)) AS C_TANITASIORAID, 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_KEZDETE, C_MEGJEGYZES, C_TARTALOM, C_TIPUS, C_TARGY, C_FALIUJSAGMEGJELENES, C_MINDENKINEK, C_VEGE, C_ROGZITESDATUMA, C_LATTAMOZAS, C_FELJEGYZOID, C_TANTARGYID, C_TANITASIORAID, 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_TANULOESEMENY', '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_TANULOESEMENY', '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_TANULOESEMENY',
|
||||
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'Creating [dbo].[tr_telefonLog]...';
|
||||
|
||||
|
||||
GO
|
||||
|
||||
CREATE TRIGGER tr_telefonLog ON T_TELEFON
|
||||
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_TELEFONTIPUSA AS nvarchar(MAX)) AS C_TELEFONTIPUSA, CAST( C_TELEFONSZAM AS nvarchar(MAX)) AS C_TELEFONSZAM, CAST( C_LEIRAS AS nvarchar(MAX)) AS C_LEIRAS, CAST( C_ALAPERTELMEZETT AS nvarchar(MAX)) AS C_ALAPERTELMEZETT, CAST( C_PUBLIKUSTELEFONSZAM AS nvarchar(MAX)) AS C_PUBLIKUSTELEFONSZAM, CAST( C_GONDVISELOID AS nvarchar(MAX)) AS C_GONDVISELOID, CAST( C_FELHASZNALOID AS nvarchar(MAX)) AS C_FELHASZNALOID, 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_TELEFONTIPUSA, C_TELEFONSZAM, C_LEIRAS, C_ALAPERTELMEZETT, C_PUBLIKUSTELEFONSZAM, C_GONDVISELOID, C_FELHASZNALOID, 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_TELEFONTIPUSA AS nvarchar(MAX)) AS C_TELEFONTIPUSA, CAST( C_TELEFONSZAM AS nvarchar(MAX)) AS C_TELEFONSZAM, CAST( C_LEIRAS AS nvarchar(MAX)) AS C_LEIRAS, CAST( C_ALAPERTELMEZETT AS nvarchar(MAX)) AS C_ALAPERTELMEZETT, CAST( C_PUBLIKUSTELEFONSZAM AS nvarchar(MAX)) AS C_PUBLIKUSTELEFONSZAM, CAST( C_GONDVISELOID AS nvarchar(MAX)) AS C_GONDVISELOID, CAST( C_FELHASZNALOID AS nvarchar(MAX)) AS C_FELHASZNALOID, 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_TELEFONTIPUSA, C_TELEFONSZAM, C_LEIRAS, C_ALAPERTELMEZETT, C_PUBLIKUSTELEFONSZAM, C_GONDVISELOID, C_FELHASZNALOID, 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_TELEFON', '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_TELEFON', '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_TELEFON',
|
||||
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 '--- 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_EMAIL', 'T_EMAIL_OSSZES',
|
||||
'T_TANULOESEMENY', 'T_TANULOESEMENY_OSSZES',
|
||||
'T_TELEFON', 'T_TELEFON_OSSZES',
|
||||
'T_TANULOERTEKELES', 'T_TANULOERTEKELES_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
|
Reference in New Issue
Block a user