336 lines
No EOL
13 KiB
Transact-SQL
336 lines
No EOL
13 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'Starting rebuilding table [dbo].[T_NEMKOTOTTMUNKAIDO]...';
|
|
|
|
|
|
GO
|
|
BEGIN TRANSACTION;
|
|
|
|
SET TRANSACTION ISOLATION LEVEL SERIALIZABLE;
|
|
|
|
SET XACT_ABORT ON;
|
|
|
|
CREATE TABLE [dbo].[tmp_ms_xx_T_NEMKOTOTTMUNKAIDO] (
|
|
[ID] INT IDENTITY (1, 1) NOT NULL,
|
|
[C_GROUPID] NVARCHAR (36) NULL,
|
|
[C_KEZDETE] DATETIME NOT NULL,
|
|
[C_MEGJEGYZES] NVARCHAR (MAX) NULL,
|
|
[C_MEGTARTOTT] CHAR (1) NULL,
|
|
[C_TEVEKENYSEGTIPUSA] INT NOT NULL,
|
|
[C_VEGE] DATETIME NOT NULL,
|
|
[C_HETIREND] INT NOT NULL,
|
|
[C_ADMINALTALTOROLT] CHAR (1) NULL,
|
|
[C_NAPLOZOTTMEGJEGYZES] NVARCHAR (MAX) NULL,
|
|
[C_TANARID] INT NOT NULL,
|
|
[C_TULAJDONOSID] INT NULL,
|
|
[C_INTEZMENYID] INT NOT NULL,
|
|
[C_TANEVID] INT NOT NULL,
|
|
[TOROLT] CHAR (1) DEFAULT ('F') NULL,
|
|
[SERIAL] INT NULL,
|
|
[LASTCHANGED] DATETIME DEFAULT (getdate()) NULL,
|
|
[CREATED] DATETIME DEFAULT (getdate()) NULL,
|
|
[MODIFIER] INT NULL,
|
|
[CREATOR] INT NULL,
|
|
[NNID] INT NULL,
|
|
CONSTRAINT [tmp_ms_xx_constraint_PK_T_40266771] PRIMARY KEY CLUSTERED ([ID] ASC)
|
|
);
|
|
|
|
IF EXISTS (SELECT TOP 1 1
|
|
FROM [dbo].[T_NEMKOTOTTMUNKAIDO])
|
|
BEGIN
|
|
SET IDENTITY_INSERT [dbo].[tmp_ms_xx_T_NEMKOTOTTMUNKAIDO] ON;
|
|
INSERT INTO [dbo].[tmp_ms_xx_T_NEMKOTOTTMUNKAIDO] ([ID], [C_GROUPID], [C_KEZDETE], [C_MEGJEGYZES], [C_MEGTARTOTT], [C_TEVEKENYSEGTIPUSA], [C_VEGE], [C_HETIREND], [C_ADMINALTALTOROLT], [C_TANARID], [C_TULAJDONOSID], [C_INTEZMENYID], [C_TANEVID], [TOROLT], [SERIAL], [LASTCHANGED], [CREATED], [MODIFIER], [CREATOR], [NNID])
|
|
SELECT [ID],
|
|
[C_GROUPID],
|
|
[C_KEZDETE],
|
|
[C_MEGJEGYZES],
|
|
[C_MEGTARTOTT],
|
|
[C_TEVEKENYSEGTIPUSA],
|
|
[C_VEGE],
|
|
[C_HETIREND],
|
|
[C_ADMINALTALTOROLT],
|
|
[C_TANARID],
|
|
[C_TULAJDONOSID],
|
|
[C_INTEZMENYID],
|
|
[C_TANEVID],
|
|
[TOROLT],
|
|
[SERIAL],
|
|
[LASTCHANGED],
|
|
[CREATED],
|
|
[MODIFIER],
|
|
[CREATOR],
|
|
[NNID]
|
|
FROM [dbo].[T_NEMKOTOTTMUNKAIDO]
|
|
ORDER BY [ID] ASC;
|
|
SET IDENTITY_INSERT [dbo].[tmp_ms_xx_T_NEMKOTOTTMUNKAIDO] OFF;
|
|
END
|
|
|
|
DROP TABLE [dbo].[T_NEMKOTOTTMUNKAIDO];
|
|
|
|
EXECUTE sp_rename N'[dbo].[tmp_ms_xx_T_NEMKOTOTTMUNKAIDO]', N'T_NEMKOTOTTMUNKAIDO';
|
|
|
|
EXECUTE sp_rename N'[dbo].[tmp_ms_xx_constraint_PK_T_40266771]', N'PK_T_4026677', N'OBJECT';
|
|
|
|
COMMIT TRANSACTION;
|
|
|
|
SET TRANSACTION ISOLATION LEVEL READ COMMITTED;
|
|
|
|
|
|
GO
|
|
PRINT N'Creating [dbo].[T_NEMKOTOTTMUNKAIDO].[I_T_4026677_4026682]...';
|
|
|
|
|
|
GO
|
|
CREATE NONCLUSTERED INDEX [I_T_4026677_4026682]
|
|
ON [dbo].[T_NEMKOTOTTMUNKAIDO]([C_INTEZMENYID] ASC, [C_TANEVID] ASC, [C_TEVEKENYSEGTIPUSA] ASC);
|
|
|
|
|
|
GO
|
|
PRINT N'Creating [dbo].[T_NEMKOTOTTMUNKAIDO].[I_T_4026677_4026746]...';
|
|
|
|
|
|
GO
|
|
CREATE NONCLUSTERED INDEX [I_T_4026677_4026746]
|
|
ON [dbo].[T_NEMKOTOTTMUNKAIDO]([C_INTEZMENYID] ASC, [C_TANEVID] ASC, [C_HETIREND] ASC);
|
|
|
|
|
|
GO
|
|
PRINT N'Creating [dbo].[T_NEMKOTOTTMUNKAIDO].[I_T_4026685_4026684]...';
|
|
|
|
|
|
GO
|
|
CREATE NONCLUSTERED INDEX [I_T_4026685_4026684]
|
|
ON [dbo].[T_NEMKOTOTTMUNKAIDO]([C_TANARID] ASC);
|
|
|
|
|
|
GO
|
|
PRINT N'Creating [dbo].[T_NEMKOTOTTMUNKAIDO].[I_T_4026688_4026687]...';
|
|
|
|
|
|
GO
|
|
CREATE NONCLUSTERED INDEX [I_T_4026688_4026687]
|
|
ON [dbo].[T_NEMKOTOTTMUNKAIDO]([C_TULAJDONOSID] ASC);
|
|
|
|
|
|
GO
|
|
PRINT N'Creating [dbo].[T_NEMKOTOTTMUNKAIDO].[I_T_402667702_402667700]...';
|
|
|
|
|
|
GO
|
|
CREATE NONCLUSTERED INDEX [I_T_402667702_402667700]
|
|
ON [dbo].[T_NEMKOTOTTMUNKAIDO]([C_INTEZMENYID] ASC);
|
|
|
|
|
|
GO
|
|
PRINT N'Creating [dbo].[T_NEMKOTOTTMUNKAIDO].[I_T_402667705_402667703]...';
|
|
|
|
|
|
GO
|
|
CREATE NONCLUSTERED INDEX [I_T_402667705_402667703]
|
|
ON [dbo].[T_NEMKOTOTTMUNKAIDO]([C_TANEVID] ASC);
|
|
|
|
|
|
GO
|
|
PRINT N'Creating [dbo].[FK_4026685_4026684]...';
|
|
|
|
|
|
GO
|
|
ALTER TABLE [dbo].[T_NEMKOTOTTMUNKAIDO] WITH NOCHECK
|
|
ADD CONSTRAINT [FK_4026685_4026684] FOREIGN KEY ([C_TANARID]) REFERENCES [dbo].[T_ALKALMAZOTT] ([ID]);
|
|
|
|
|
|
GO
|
|
PRINT N'Creating [dbo].[FK_4026688_4026687]...';
|
|
|
|
|
|
GO
|
|
ALTER TABLE [dbo].[T_NEMKOTOTTMUNKAIDO] WITH NOCHECK
|
|
ADD CONSTRAINT [FK_4026688_4026687] FOREIGN KEY ([C_TULAJDONOSID]) REFERENCES [dbo].[T_FELHASZNALO] ([ID]);
|
|
|
|
|
|
GO
|
|
PRINT N'Creating [dbo].[FK_402667702_402667700]...';
|
|
|
|
|
|
GO
|
|
ALTER TABLE [dbo].[T_NEMKOTOTTMUNKAIDO] WITH NOCHECK
|
|
ADD CONSTRAINT [FK_402667702_402667700] FOREIGN KEY ([C_INTEZMENYID]) REFERENCES [dbo].[T_INTEZMENY] ([ID]);
|
|
|
|
|
|
GO
|
|
PRINT N'Creating [dbo].[FK_402667705_402667703]...';
|
|
|
|
|
|
GO
|
|
ALTER TABLE [dbo].[T_NEMKOTOTTMUNKAIDO] WITH NOCHECK
|
|
ADD CONSTRAINT [FK_402667705_402667703] FOREIGN KEY ([C_TANEVID]) REFERENCES [dbo].[T_TANEV] ([ID]);
|
|
|
|
|
|
GO
|
|
PRINT N'Creating [dbo].[FK_4026677_4026682]...';
|
|
|
|
|
|
GO
|
|
ALTER TABLE [dbo].[T_NEMKOTOTTMUNKAIDO] WITH NOCHECK
|
|
ADD CONSTRAINT [FK_4026677_4026682] FOREIGN KEY ([C_TEVEKENYSEGTIPUSA], [C_INTEZMENYID], [C_TANEVID]) REFERENCES [dbo].[T_TEVEKENYSEGTIPUS] ([ID], [C_ALINTEZMENYID], [C_ALTANEVID]);
|
|
|
|
|
|
GO
|
|
PRINT N'Creating [dbo].[FK_4026677_4026746]...';
|
|
|
|
|
|
GO
|
|
ALTER TABLE [dbo].[T_NEMKOTOTTMUNKAIDO] WITH NOCHECK
|
|
ADD CONSTRAINT [FK_4026677_4026746] FOREIGN KEY ([C_HETIREND], [C_INTEZMENYID], [C_TANEVID]) REFERENCES [dbo].[T_HETIRENDTIPUS] ([ID], [C_ALINTEZMENYID], [C_ALTANEVID]);
|
|
|
|
|
|
GO
|
|
PRINT N'Creating [dbo].[tr_nemkotottmunkaidoLog]...';
|
|
|
|
|
|
GO
|
|
|
|
CREATE TRIGGER tr_nemkotottmunkaidoLog ON T_NEMKOTOTTMUNKAIDO
|
|
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_GROUPID AS nvarchar(MAX)) AS C_GROUPID, CONVERT(nvarchar(MAX), C_KEZDETE, 121) AS C_KEZDETE, CAST( C_MEGJEGYZES AS nvarchar(MAX)) AS C_MEGJEGYZES, CAST( C_MEGTARTOTT AS nvarchar(MAX)) AS C_MEGTARTOTT, CAST( C_TEVEKENYSEGTIPUSA AS nvarchar(MAX)) AS C_TEVEKENYSEGTIPUSA, CONVERT(nvarchar(MAX), C_VEGE, 121) AS C_VEGE, CAST( C_HETIREND AS nvarchar(MAX)) AS C_HETIREND, CAST( C_ADMINALTALTOROLT AS nvarchar(MAX)) AS C_ADMINALTALTOROLT, CAST( C_NAPLOZOTTMEGJEGYZES AS nvarchar(MAX)) AS C_NAPLOZOTTMEGJEGYZES, CAST( C_TANARID AS nvarchar(MAX)) AS C_TANARID, CAST( C_TULAJDONOSID AS nvarchar(MAX)) AS C_TULAJDONOSID, CAST( TOROLT AS nvarchar(MAX)) AS TOROLT, CAST( NNID AS nvarchar(MAX)) AS NNID
|
|
FROM INSERTED) p
|
|
UNPIVOT (val FOR col IN (C_GROUPID, C_KEZDETE, C_MEGJEGYZES, C_MEGTARTOTT, C_TEVEKENYSEGTIPUSA, C_VEGE, C_HETIREND, C_ADMINALTALTOROLT, C_NAPLOZOTTMEGJEGYZES, C_TANARID, C_TULAJDONOSID, 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_INTEZMENYID AS C_INTEZMENYID, C_TANEVID AS C_TANEVID, CREATOR, MODIFIER, CAST( C_GROUPID AS nvarchar(MAX)) AS C_GROUPID, CONVERT(nvarchar(MAX), C_KEZDETE, 121) AS C_KEZDETE, CAST( C_MEGJEGYZES AS nvarchar(MAX)) AS C_MEGJEGYZES, CAST( C_MEGTARTOTT AS nvarchar(MAX)) AS C_MEGTARTOTT, CAST( C_TEVEKENYSEGTIPUSA AS nvarchar(MAX)) AS C_TEVEKENYSEGTIPUSA, CONVERT(nvarchar(MAX), C_VEGE, 121) AS C_VEGE, CAST( C_HETIREND AS nvarchar(MAX)) AS C_HETIREND, CAST( C_ADMINALTALTOROLT AS nvarchar(MAX)) AS C_ADMINALTALTOROLT, CAST( C_NAPLOZOTTMEGJEGYZES AS nvarchar(MAX)) AS C_NAPLOZOTTMEGJEGYZES, CAST( C_TANARID AS nvarchar(MAX)) AS C_TANARID, CAST( C_TULAJDONOSID AS nvarchar(MAX)) AS C_TULAJDONOSID, CAST( TOROLT AS nvarchar(MAX)) AS TOROLT, CAST( NNID AS nvarchar(MAX)) AS NNID
|
|
FROM DELETED) p
|
|
UNPIVOT (val FOR col IN (C_GROUPID, C_KEZDETE, C_MEGJEGYZES, C_MEGTARTOTT, C_TEVEKENYSEGTIPUSA, C_VEGE, C_HETIREND, C_ADMINALTALTOROLT, C_NAPLOZOTTMEGJEGYZES, C_TANARID, C_TULAJDONOSID, 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_NEMKOTOTTMUNKAIDO', '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_NEMKOTOTTMUNKAIDO', '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_NEMKOTOTTMUNKAIDO',
|
|
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_NEMKOTOTTMUNKAIDO_OSSZES]...';
|
|
|
|
|
|
GO
|
|
EXECUTE sp_refreshsqlmodule N'[dbo].[T_NEMKOTOTTMUNKAIDO_OSSZES]';
|
|
|
|
GO
|
|
PRINT N'Checking existing data against newly created constraints';
|
|
|
|
|
|
GO
|
|
ALTER TABLE [dbo].[T_NEMKOTOTTMUNKAIDO] WITH CHECK CHECK CONSTRAINT [FK_4026685_4026684];
|
|
|
|
ALTER TABLE [dbo].[T_NEMKOTOTTMUNKAIDO] WITH CHECK CHECK CONSTRAINT [FK_4026688_4026687];
|
|
|
|
ALTER TABLE [dbo].[T_NEMKOTOTTMUNKAIDO] WITH CHECK CHECK CONSTRAINT [FK_402667702_402667700];
|
|
|
|
ALTER TABLE [dbo].[T_NEMKOTOTTMUNKAIDO] WITH CHECK CHECK CONSTRAINT [FK_402667705_402667703];
|
|
|
|
ALTER TABLE [dbo].[T_NEMKOTOTTMUNKAIDO] WITH CHECK CHECK CONSTRAINT [FK_4026677_4026682];
|
|
|
|
ALTER TABLE [dbo].[T_NEMKOTOTTMUNKAIDO] WITH CHECK CHECK CONSTRAINT [FK_4026677_4026746];
|
|
|
|
|
|
GO
|
|
PRINT N'Update complete.';
|
|
|
|
|
|
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_NEMKOTOTTMUNKAIDO', 'T_NEMKOTOTTMUNKAIDO_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 |