405 lines
15 KiB
Transact-SQL
405 lines
15 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'Dropping [dbo].[FK_4026691_4026690]...';
|
|
|
|
|
|
GO
|
|
ALTER TABLE [dbo].[T_HELYETTESITESIIDOSZAK] DROP CONSTRAINT [FK_4026691_4026690];
|
|
|
|
|
|
GO
|
|
PRINT N'Dropping [dbo].[FK_402628602_402628600]...';
|
|
|
|
|
|
GO
|
|
ALTER TABLE [dbo].[T_HELYETTESITESIIDOSZAK] DROP CONSTRAINT [FK_402628602_402628600];
|
|
|
|
|
|
GO
|
|
PRINT N'Dropping [dbo].[FK_402628605_402628603]...';
|
|
|
|
|
|
GO
|
|
ALTER TABLE [dbo].[T_HELYETTESITESIIDOSZAK] DROP CONSTRAINT [FK_402628605_402628603];
|
|
|
|
|
|
GO
|
|
PRINT N'Dropping [dbo].[FK_4026290_4026289]...';
|
|
|
|
|
|
GO
|
|
ALTER TABLE [dbo].[T_HELYETTESITESIIDOSZAK] DROP CONSTRAINT [FK_4026290_4026289];
|
|
|
|
|
|
GO
|
|
PRINT N'Dropping [dbo].[FK_4026291_4026289]...';
|
|
|
|
|
|
GO
|
|
ALTER TABLE [dbo].[T_HELYETTESITESIIDOSZAK] DROP CONSTRAINT [FK_4026291_4026289];
|
|
|
|
|
|
GO
|
|
PRINT N'Dropping [dbo].[FK_4026286_4026293]...';
|
|
|
|
|
|
GO
|
|
ALTER TABLE [dbo].[T_HELYETTESITESIIDOSZAK] DROP CONSTRAINT [FK_4026286_4026293];
|
|
|
|
|
|
GO
|
|
PRINT N'Starting rebuilding table [dbo].[T_HELYETTESITESIIDOSZAK]...';
|
|
|
|
|
|
GO
|
|
BEGIN TRANSACTION;
|
|
|
|
SET TRANSACTION ISOLATION LEVEL SERIALIZABLE;
|
|
|
|
SET XACT_ABORT ON;
|
|
|
|
CREATE TABLE [dbo].[tmp_ms_xx_T_HELYETTESITESIIDOSZAK] (
|
|
[ID] INT IDENTITY (1, 1) NOT NULL,
|
|
[C_HETSORSZAMA] INT NOT NULL,
|
|
[C_HELYETTESITESNAPJA] DATETIME NOT NULL,
|
|
[C_HELYETTESITESOKA] NVARCHAR (255) NULL,
|
|
[C_HELYETTESITESTIPUS] INT NOT NULL,
|
|
[C_ORARENDIORAORAOSSZEVONASID] INT NULL,
|
|
[C_ROGZITOID] INT NULL,
|
|
[C_INTEZMENYID] INT NOT NULL,
|
|
[C_TANEVID] INT NOT NULL,
|
|
[C_HELYETTESITETTORARENDID] INT NOT NULL,
|
|
[C_HELYETTESTANAROKID] INT NOT NULL,
|
|
[TOROLT] CHAR (1) DEFAULT ('F') NOT NULL,
|
|
[SERIAL] INT DEFAULT ((0)) NOT NULL,
|
|
[LASTCHANGED] DATETIME DEFAULT (getdate()) NOT NULL,
|
|
[CREATED] DATETIME DEFAULT (getdate()) NOT NULL,
|
|
[MODIFIER] INT NULL,
|
|
[CREATOR] INT NULL,
|
|
[ELOZOTANEVIREKORDID] INT NULL,
|
|
[NNID] INT NULL,
|
|
CONSTRAINT [tmp_ms_xx_constraint_PK_T_40262861] PRIMARY KEY CLUSTERED ([ID] ASC)
|
|
);
|
|
|
|
IF EXISTS (SELECT TOP 1 1
|
|
FROM [dbo].[T_HELYETTESITESIIDOSZAK])
|
|
BEGIN
|
|
SET IDENTITY_INSERT [dbo].[tmp_ms_xx_T_HELYETTESITESIIDOSZAK] ON;
|
|
INSERT INTO [dbo].[tmp_ms_xx_T_HELYETTESITESIIDOSZAK] ([ID], [C_HETSORSZAMA], [C_HELYETTESITESNAPJA], [C_HELYETTESITESOKA], [C_HELYETTESITESTIPUS], [C_ROGZITOID], [C_INTEZMENYID], [C_TANEVID], [C_HELYETTESITETTORARENDID], [C_HELYETTESTANAROKID], [TOROLT], [SERIAL], [LASTCHANGED], [CREATED], [MODIFIER], [CREATOR], [ELOZOTANEVIREKORDID], [NNID])
|
|
SELECT [ID],
|
|
[C_HETSORSZAMA],
|
|
[C_HELYETTESITESNAPJA],
|
|
[C_HELYETTESITESOKA],
|
|
[C_HELYETTESITESTIPUS],
|
|
[C_ROGZITOID],
|
|
[C_INTEZMENYID],
|
|
[C_TANEVID],
|
|
[C_HELYETTESITETTORARENDID],
|
|
[C_HELYETTESTANAROKID],
|
|
[TOROLT],
|
|
[SERIAL],
|
|
[LASTCHANGED],
|
|
[CREATED],
|
|
[MODIFIER],
|
|
[CREATOR],
|
|
[ELOZOTANEVIREKORDID],
|
|
[NNID]
|
|
FROM [dbo].[T_HELYETTESITESIIDOSZAK]
|
|
ORDER BY [ID] ASC;
|
|
SET IDENTITY_INSERT [dbo].[tmp_ms_xx_T_HELYETTESITESIIDOSZAK] OFF;
|
|
END
|
|
|
|
DROP TABLE [dbo].[T_HELYETTESITESIIDOSZAK];
|
|
|
|
EXECUTE sp_rename N'[dbo].[tmp_ms_xx_T_HELYETTESITESIIDOSZAK]', N'T_HELYETTESITESIIDOSZAK';
|
|
|
|
EXECUTE sp_rename N'[dbo].[tmp_ms_xx_constraint_PK_T_40262861]', N'PK_T_4026286', N'OBJECT';
|
|
|
|
COMMIT TRANSACTION;
|
|
|
|
SET TRANSACTION ISOLATION LEVEL READ COMMITTED;
|
|
|
|
|
|
GO
|
|
PRINT N'Creating [dbo].[T_HELYETTESITESIIDOSZAK].[I_T_4026286_4026293]...';
|
|
|
|
|
|
GO
|
|
CREATE NONCLUSTERED INDEX [I_T_4026286_4026293]
|
|
ON [dbo].[T_HELYETTESITESIIDOSZAK]([C_INTEZMENYID] ASC, [C_TANEVID] ASC, [C_HELYETTESITESTIPUS] ASC);
|
|
|
|
|
|
GO
|
|
PRINT N'Creating [dbo].[T_HELYETTESITESIIDOSZAK].[I_T_4026691_4026690]...';
|
|
|
|
|
|
GO
|
|
CREATE NONCLUSTERED INDEX [I_T_4026691_4026690]
|
|
ON [dbo].[T_HELYETTESITESIIDOSZAK]([C_ROGZITOID] ASC);
|
|
|
|
|
|
GO
|
|
PRINT N'Creating [dbo].[T_HELYETTESITESIIDOSZAK].[I_T_402628602_402628600]...';
|
|
|
|
|
|
GO
|
|
CREATE NONCLUSTERED INDEX [I_T_402628602_402628600]
|
|
ON [dbo].[T_HELYETTESITESIIDOSZAK]([C_INTEZMENYID] ASC);
|
|
|
|
|
|
GO
|
|
PRINT N'Creating [dbo].[T_HELYETTESITESIIDOSZAK].[I_T_402628605_402628603]...';
|
|
|
|
|
|
GO
|
|
CREATE NONCLUSTERED INDEX [I_T_402628605_402628603]
|
|
ON [dbo].[T_HELYETTESITESIIDOSZAK]([C_TANEVID] ASC);
|
|
|
|
|
|
GO
|
|
PRINT N'Creating [dbo].[T_HELYETTESITESIIDOSZAK].[I_T_4026290_4026289]...';
|
|
|
|
|
|
GO
|
|
CREATE NONCLUSTERED INDEX [I_T_4026290_4026289]
|
|
ON [dbo].[T_HELYETTESITESIIDOSZAK]([C_HELYETTESITETTORARENDID] ASC);
|
|
|
|
|
|
GO
|
|
PRINT N'Creating [dbo].[T_HELYETTESITESIIDOSZAK].[I_T_4026291_4026289]...';
|
|
|
|
|
|
GO
|
|
CREATE NONCLUSTERED INDEX [I_T_4026291_4026289]
|
|
ON [dbo].[T_HELYETTESITESIIDOSZAK]([C_HELYETTESTANAROKID] ASC);
|
|
|
|
|
|
GO
|
|
PRINT N'Creating [dbo].[FK_4026691_4026690]...';
|
|
|
|
|
|
GO
|
|
ALTER TABLE [dbo].[T_HELYETTESITESIIDOSZAK] WITH NOCHECK
|
|
ADD CONSTRAINT [FK_4026691_4026690] FOREIGN KEY ([C_ROGZITOID]) REFERENCES [dbo].[T_FELHASZNALO] ([ID]);
|
|
|
|
|
|
GO
|
|
PRINT N'Creating [dbo].[FK_402628602_402628600]...';
|
|
|
|
|
|
GO
|
|
ALTER TABLE [dbo].[T_HELYETTESITESIIDOSZAK] WITH NOCHECK
|
|
ADD CONSTRAINT [FK_402628602_402628600] FOREIGN KEY ([C_INTEZMENYID]) REFERENCES [dbo].[T_INTEZMENY] ([ID]);
|
|
|
|
|
|
GO
|
|
PRINT N'Creating [dbo].[FK_402628605_402628603]...';
|
|
|
|
|
|
GO
|
|
ALTER TABLE [dbo].[T_HELYETTESITESIIDOSZAK] WITH NOCHECK
|
|
ADD CONSTRAINT [FK_402628605_402628603] FOREIGN KEY ([C_TANEVID]) REFERENCES [dbo].[T_TANEV] ([ID]);
|
|
|
|
|
|
GO
|
|
PRINT N'Creating [dbo].[FK_4026290_4026289]...';
|
|
|
|
|
|
GO
|
|
ALTER TABLE [dbo].[T_HELYETTESITESIIDOSZAK] WITH NOCHECK
|
|
ADD CONSTRAINT [FK_4026290_4026289] FOREIGN KEY ([C_HELYETTESITETTORARENDID]) REFERENCES [dbo].[T_ORARENDIORA] ([ID]);
|
|
|
|
|
|
GO
|
|
PRINT N'Creating [dbo].[FK_4026291_4026289]...';
|
|
|
|
|
|
GO
|
|
ALTER TABLE [dbo].[T_HELYETTESITESIIDOSZAK] WITH NOCHECK
|
|
ADD CONSTRAINT [FK_4026291_4026289] FOREIGN KEY ([C_HELYETTESTANAROKID]) REFERENCES [dbo].[T_ALKALMAZOTT] ([ID]);
|
|
|
|
|
|
GO
|
|
PRINT N'Creating [dbo].[FK_4026286_4026293]...';
|
|
|
|
|
|
GO
|
|
ALTER TABLE [dbo].[T_HELYETTESITESIIDOSZAK] WITH NOCHECK
|
|
ADD CONSTRAINT [FK_4026286_4026293] FOREIGN KEY ([C_HELYETTESITESTIPUS], [C_INTEZMENYID], [C_TANEVID]) REFERENCES [dbo].[T_HELYETTESITESTIPUS] ([ID], [C_ALINTEZMENYID], [C_ALTANEVID]);
|
|
|
|
|
|
GO
|
|
PRINT N'Creating [dbo].[tr_helyettesitesiidoszakLog]...';
|
|
|
|
|
|
GO
|
|
|
|
CREATE TRIGGER tr_helyettesitesiidoszakLog ON T_HELYETTESITESIIDOSZAK
|
|
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_HETSORSZAMA AS nvarchar(MAX)) AS C_HETSORSZAMA, CONVERT(nvarchar(MAX), C_HELYETTESITESNAPJA, 121) AS C_HELYETTESITESNAPJA, CAST( C_HELYETTESITESOKA AS nvarchar(MAX)) AS C_HELYETTESITESOKA, CAST( C_HELYETTESITESTIPUS AS nvarchar(MAX)) AS C_HELYETTESITESTIPUS, CAST( C_ORARENDIORAORAOSSZEVONASID AS nvarchar(MAX)) AS C_ORARENDIORAORAOSSZEVONASID, CAST( C_ROGZITOID AS nvarchar(MAX)) AS C_ROGZITOID, CAST( C_HELYETTESITETTORARENDID AS nvarchar(MAX)) AS C_HELYETTESITETTORARENDID, CAST( C_HELYETTESTANAROKID AS nvarchar(MAX)) AS C_HELYETTESTANAROKID, 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_HETSORSZAMA, C_HELYETTESITESNAPJA, C_HELYETTESITESOKA, C_HELYETTESITESTIPUS, C_ORARENDIORAORAOSSZEVONASID, C_ROGZITOID, C_HELYETTESITETTORARENDID, C_HELYETTESTANAROKID, 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_HETSORSZAMA AS nvarchar(MAX)) AS C_HETSORSZAMA, CONVERT(nvarchar(MAX), C_HELYETTESITESNAPJA, 121) AS C_HELYETTESITESNAPJA, CAST( C_HELYETTESITESOKA AS nvarchar(MAX)) AS C_HELYETTESITESOKA, CAST( C_HELYETTESITESTIPUS AS nvarchar(MAX)) AS C_HELYETTESITESTIPUS, CAST( C_ORARENDIORAORAOSSZEVONASID AS nvarchar(MAX)) AS C_ORARENDIORAORAOSSZEVONASID, CAST( C_ROGZITOID AS nvarchar(MAX)) AS C_ROGZITOID, CAST( C_HELYETTESITETTORARENDID AS nvarchar(MAX)) AS C_HELYETTESITETTORARENDID, CAST( C_HELYETTESTANAROKID AS nvarchar(MAX)) AS C_HELYETTESTANAROKID, 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_HETSORSZAMA, C_HELYETTESITESNAPJA, C_HELYETTESITESOKA, C_HELYETTESITESTIPUS, C_ORARENDIORAORAOSSZEVONASID, C_ROGZITOID, C_HELYETTESITETTORARENDID, C_HELYETTESTANAROKID, 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_HELYETTESITESIIDOSZAK', '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_HELYETTESITESIIDOSZAK', '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_HELYETTESITESIIDOSZAK',
|
|
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_HELYETTESITESIIDOSZAK_OSSZES]...';
|
|
|
|
|
|
GO
|
|
EXECUTE sp_refreshsqlmodule N'[dbo].[T_HELYETTESITESIIDOSZAK_OSSZES]';
|
|
|
|
GO
|
|
PRINT N'Checking existing data against newly created constraints';
|
|
|
|
|
|
GO
|
|
ALTER TABLE [dbo].[T_HELYETTESITESIIDOSZAK] WITH CHECK CHECK CONSTRAINT [FK_4026691_4026690];
|
|
|
|
ALTER TABLE [dbo].[T_HELYETTESITESIIDOSZAK] WITH CHECK CHECK CONSTRAINT [FK_402628602_402628600];
|
|
|
|
ALTER TABLE [dbo].[T_HELYETTESITESIIDOSZAK] WITH CHECK CHECK CONSTRAINT [FK_402628605_402628603];
|
|
|
|
ALTER TABLE [dbo].[T_HELYETTESITESIIDOSZAK] WITH CHECK CHECK CONSTRAINT [FK_4026290_4026289];
|
|
|
|
ALTER TABLE [dbo].[T_HELYETTESITESIIDOSZAK] WITH CHECK CHECK CONSTRAINT [FK_4026291_4026289];
|
|
|
|
ALTER TABLE [dbo].[T_HELYETTESITESIIDOSZAK] WITH CHECK CHECK CONSTRAINT [FK_4026286_4026293];
|
|
|
|
|
|
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_HELYETTESITESIIDOSZAK', 'T_HELYETTESITESIIDOSZAK_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
|