Files
kreta/Kreta.DataAccess.Migrations/Scripts/Archive/20170406154403_KRETA_689/create_table.sql
2024-03-13 00:33:46 +01:00

214 lines
7.2 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_MUKODESIHELYTIPUS]...';
GO
CREATE TABLE [dbo].[T_MUKODESIHELYTIPUS] (
[ID] INT NOT NULL,
[C_ALINTEZMENYID] INT NOT NULL,
[C_ALTANEVID] INT NOT NULL,
[TOROLT] CHAR (1) NULL,
[SERIAL] INT NULL,
[LASTCHANGED] DATETIME NULL,
[CREATED] DATETIME NULL,
[MODIFIER] INT NULL,
[CREATOR] INT NULL,
[NNID] INT NULL,
CONSTRAINT [PK_T_4027504] PRIMARY KEY CLUSTERED ([ID] ASC, [C_ALINTEZMENYID] ASC, [C_ALTANEVID] ASC)
);
GO
PRINT N'Creating [dbo].[T_MUKODESIHELYTIPUS].[I_T_402750402_402750400]...';
GO
CREATE NONCLUSTERED INDEX [I_T_402750402_402750400]
ON [dbo].[T_MUKODESIHELYTIPUS]([C_ALINTEZMENYID] ASC);
GO
PRINT N'Creating [dbo].[T_MUKODESIHELYTIPUS].[I_T_402750405_402750403]...';
GO
CREATE NONCLUSTERED INDEX [I_T_402750405_402750403]
ON [dbo].[T_MUKODESIHELYTIPUS]([C_ALTANEVID] ASC);
GO
PRINT N'Creating unnamed constraint on [dbo].[T_MUKODESIHELYTIPUS]...';
GO
ALTER TABLE [dbo].[T_MUKODESIHELYTIPUS]
ADD DEFAULT ('F') FOR [TOROLT];
GO
PRINT N'Creating unnamed constraint on [dbo].[T_MUKODESIHELYTIPUS]...';
GO
ALTER TABLE [dbo].[T_MUKODESIHELYTIPUS]
ADD DEFAULT (getdate()) FOR [LASTCHANGED];
GO
PRINT N'Creating unnamed constraint on [dbo].[T_MUKODESIHELYTIPUS]...';
GO
ALTER TABLE [dbo].[T_MUKODESIHELYTIPUS]
ADD DEFAULT (getdate()) FOR [CREATED];
GO
PRINT N'Creating [dbo].[FK_T_21038_4027517]...';
GO
ALTER TABLE [dbo].[T_MUKODESIHELYTIPUS] WITH NOCHECK
ADD CONSTRAINT [FK_T_21038_4027517] FOREIGN KEY ([ID], [C_ALINTEZMENYID], [C_ALTANEVID]) REFERENCES [dbo].[T_DICTIONARYITEMBASE] ([ID], [C_INTEZMENYID], [C_TANEVID]);
GO
PRINT N'Creating [dbo].[FK_402750402_402750400]...';
GO
ALTER TABLE [dbo].[T_MUKODESIHELYTIPUS] WITH NOCHECK
ADD CONSTRAINT [FK_402750402_402750400] FOREIGN KEY ([C_ALINTEZMENYID]) REFERENCES [dbo].[T_INTEZMENY] ([ID]);
GO
PRINT N'Creating [dbo].[FK_402750405_402750403]...';
GO
ALTER TABLE [dbo].[T_MUKODESIHELYTIPUS] WITH NOCHECK
ADD CONSTRAINT [FK_402750405_402750403] FOREIGN KEY ([C_ALTANEVID]) REFERENCES [dbo].[T_TANEV] ([ID]);
GO
PRINT N'Creating [dbo].[tr_mukodesihelytipusLog]...';
GO
CREATE TRIGGER tr_mukodesihelytipusLog ON T_MUKODESIHELYTIPUS
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_ALINTEZMENYID AS C_INTEZMENYID, C_ALTANEVID AS C_TANEVID, CREATOR, MODIFIER, CAST( TOROLT AS nvarchar(MAX)) AS TOROLT, CAST( NNID AS nvarchar(MAX)) AS NNID
FROM INSERTED) p
UNPIVOT (val FOR col IN (TOROLT, 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_ALINTEZMENYID AS C_INTEZMENYID, C_ALTANEVID AS C_TANEVID, CREATOR, MODIFIER, CAST( TOROLT AS nvarchar(MAX)) AS TOROLT, CAST( NNID AS nvarchar(MAX)) AS NNID
FROM DELETED) p
UNPIVOT (val FOR col IN (TOROLT, 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_MUKODESIHELYTIPUS', '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_MUKODESIHELYTIPUS', '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_MUKODESIHELYTIPUS',
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].[T_MUKODESIHELYTIPUS_OSSZES]...';
GO
CREATE VIEW dbo.T_MUKODESIHELYTIPUS_OSSZES
AS
SELECT *
FROM dbo.T_MUKODESIHELYTIPUS
GO
PRINT N'Checking existing data against newly created constraints';
GO
ALTER TABLE [dbo].[T_MUKODESIHELYTIPUS] WITH CHECK CHECK CONSTRAINT [FK_T_21038_4027517];
ALTER TABLE [dbo].[T_MUKODESIHELYTIPUS] WITH CHECK CHECK CONSTRAINT [FK_402750402_402750400];
ALTER TABLE [dbo].[T_MUKODESIHELYTIPUS] WITH CHECK CHECK CONSTRAINT [FK_402750405_402750403];
GO
PRINT N'Update complete.';
GO