Files
2024-03-13 00:33:46 +01:00

249 lines
10 KiB
Transact-SQL

GO
SET ANSI_NULLS, ANSI_PADDING, ANSI_WARNINGS, ARITHABORT, CONCAT_NULL_YIELDS_NULL, QUOTED_IDENTIFIER ON;
SET NUMERIC_ROUNDABORT OFF;
GO
PRINT N'Creating [dbo].[T_NATKERDOIV]...';
GO
CREATE TABLE [dbo].[T_NATKERDOIV] (
[ID] INT IDENTITY (1, 1) NOT NULL,
[C_ISLATTA] CHAR (1) NOT NULL,
[C_KERDES01] INT NULL,
[C_KERDES02] INT NULL,
[C_KERDES03] INT NULL,
[C_KERDES04] INT NULL,
[C_KERDES05] INT NULL,
[C_KERDES06] INT NULL,
[C_KERDES07] INT NULL,
[C_KERDES08] INT NULL,
[C_KERDES09] INT NULL,
[C_KERDES10] INT NULL,
[C_KERDES11] NVARCHAR (1000) NULL,
[C_KERDES12] NVARCHAR (1000) NULL,
[C_ALKALMAZOTTID] INT NOT NULL,
[C_INTEZMENYID] INT NOT NULL,
[C_TANEVID] INT NOT NULL,
[TOROLT] CHAR (1) NOT NULL,
[SERIAL] INT NOT NULL,
[LASTCHANGED] DATETIME NOT NULL,
[CREATED] DATETIME NOT NULL,
[MODIFIER] INT NULL,
[CREATOR] INT NULL,
[ELOZOTANEVIREKORDID] INT NULL,
[NNID] INT NULL,
CONSTRAINT [PK_T_4027935] PRIMARY KEY CLUSTERED ([ID] ASC)
);
GO
PRINT N'Creating [dbo].[T_NATKERDOIV].[I_T_4027951_4027949]...';
GO
CREATE NONCLUSTERED INDEX [I_T_4027951_4027949]
ON [dbo].[T_NATKERDOIV]([C_ALKALMAZOTTID] ASC);
GO
PRINT N'Creating [dbo].[T_NATKERDOIV].[I_T_402793502_402793500]...';
GO
CREATE NONCLUSTERED INDEX [I_T_402793502_402793500]
ON [dbo].[T_NATKERDOIV]([C_INTEZMENYID] ASC);
GO
PRINT N'Creating [dbo].[T_NATKERDOIV].[I_T_402793505_402793503]...';
GO
CREATE NONCLUSTERED INDEX [I_T_402793505_402793503]
ON [dbo].[T_NATKERDOIV]([C_TANEVID] ASC);
GO
PRINT N'Creating unnamed constraint on [dbo].[T_NATKERDOIV]...';
GO
ALTER TABLE [dbo].[T_NATKERDOIV]
ADD DEFAULT ('F') FOR [C_ISLATTA];
GO
PRINT N'Creating unnamed constraint on [dbo].[T_NATKERDOIV]...';
GO
ALTER TABLE [dbo].[T_NATKERDOIV]
ADD DEFAULT (getdate()) FOR [CREATED];
GO
PRINT N'Creating unnamed constraint on [dbo].[T_NATKERDOIV]...';
GO
ALTER TABLE [dbo].[T_NATKERDOIV]
ADD DEFAULT (getdate()) FOR [LASTCHANGED];
GO
PRINT N'Creating unnamed constraint on [dbo].[T_NATKERDOIV]...';
GO
ALTER TABLE [dbo].[T_NATKERDOIV]
ADD DEFAULT ('F') FOR [TOROLT];
GO
PRINT N'Creating unnamed constraint on [dbo].[T_NATKERDOIV]...';
GO
ALTER TABLE [dbo].[T_NATKERDOIV]
ADD DEFAULT ((0)) FOR [SERIAL];
GO
PRINT N'Creating [dbo].[FK_4027951_4027949]...';
GO
ALTER TABLE [dbo].[T_NATKERDOIV] WITH NOCHECK
ADD CONSTRAINT [FK_4027951_4027949] FOREIGN KEY ([C_ALKALMAZOTTID]) REFERENCES [dbo].[T_ALKALMAZOTT] ([ID]);
GO
PRINT N'Creating [dbo].[FK_402793502_402793500]...';
GO
ALTER TABLE [dbo].[T_NATKERDOIV] WITH NOCHECK
ADD CONSTRAINT [FK_402793502_402793500] FOREIGN KEY ([C_INTEZMENYID]) REFERENCES [dbo].[T_INTEZMENY] ([ID]);
GO
PRINT N'Creating [dbo].[FK_402793505_402793503]...';
GO
ALTER TABLE [dbo].[T_NATKERDOIV] WITH NOCHECK
ADD CONSTRAINT [FK_402793505_402793503] FOREIGN KEY ([C_TANEVID]) REFERENCES [dbo].[T_TANEV] ([ID]);
GO
PRINT N'Creating [dbo].[tr_natkerdoivLog]...';
GO
CREATE TRIGGER tr_natkerdoivLog ON T_NATKERDOIV
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_ISLATTA AS nvarchar(MAX)) AS C_ISLATTA, CAST( C_KERDES01 AS nvarchar(MAX)) AS C_KERDES01, CAST( C_KERDES02 AS nvarchar(MAX)) AS C_KERDES02, CAST( C_KERDES03 AS nvarchar(MAX)) AS C_KERDES03, CAST( C_KERDES04 AS nvarchar(MAX)) AS C_KERDES04, CAST( C_KERDES05 AS nvarchar(MAX)) AS C_KERDES05, CAST( C_KERDES06 AS nvarchar(MAX)) AS C_KERDES06, CAST( C_KERDES07 AS nvarchar(MAX)) AS C_KERDES07, CAST( C_KERDES08 AS nvarchar(MAX)) AS C_KERDES08, CAST( C_KERDES09 AS nvarchar(MAX)) AS C_KERDES09, CAST( C_KERDES10 AS nvarchar(MAX)) AS C_KERDES10, CAST( C_KERDES11 AS nvarchar(MAX)) AS C_KERDES11, CAST( C_KERDES12 AS nvarchar(MAX)) AS C_KERDES12, CAST( C_ALKALMAZOTTID AS nvarchar(MAX)) AS C_ALKALMAZOTTID, 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_ISLATTA, C_KERDES01, C_KERDES02, C_KERDES03, C_KERDES04, C_KERDES05, C_KERDES06, C_KERDES07, C_KERDES08, C_KERDES09, C_KERDES10, C_KERDES11, C_KERDES12, C_ALKALMAZOTTID, 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_ISLATTA AS nvarchar(MAX)) AS C_ISLATTA, CAST( C_KERDES01 AS nvarchar(MAX)) AS C_KERDES01, CAST( C_KERDES02 AS nvarchar(MAX)) AS C_KERDES02, CAST( C_KERDES03 AS nvarchar(MAX)) AS C_KERDES03, CAST( C_KERDES04 AS nvarchar(MAX)) AS C_KERDES04, CAST( C_KERDES05 AS nvarchar(MAX)) AS C_KERDES05, CAST( C_KERDES06 AS nvarchar(MAX)) AS C_KERDES06, CAST( C_KERDES07 AS nvarchar(MAX)) AS C_KERDES07, CAST( C_KERDES08 AS nvarchar(MAX)) AS C_KERDES08, CAST( C_KERDES09 AS nvarchar(MAX)) AS C_KERDES09, CAST( C_KERDES10 AS nvarchar(MAX)) AS C_KERDES10, CAST( C_KERDES11 AS nvarchar(MAX)) AS C_KERDES11, CAST( C_KERDES12 AS nvarchar(MAX)) AS C_KERDES12, CAST( C_ALKALMAZOTTID AS nvarchar(MAX)) AS C_ALKALMAZOTTID, 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_ISLATTA, C_KERDES01, C_KERDES02, C_KERDES03, C_KERDES04, C_KERDES05, C_KERDES06, C_KERDES07, C_KERDES08, C_KERDES09, C_KERDES10, C_KERDES11, C_KERDES12, C_ALKALMAZOTTID, 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_NATKERDOIV', '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_NATKERDOIV', '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_NATKERDOIV',
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'Checking existing data against newly created constraints';
GO
ALTER TABLE [dbo].[T_NATKERDOIV] WITH CHECK CHECK CONSTRAINT [FK_4027951_4027949];
ALTER TABLE [dbo].[T_NATKERDOIV] WITH CHECK CHECK CONSTRAINT [FK_402793502_402793500];
ALTER TABLE [dbo].[T_NATKERDOIV] WITH CHECK CHECK CONSTRAINT [FK_402793505_402793503];
GO
PRINT N'Update complete.';
GO