443 lines
16 KiB
Transact-SQL
443 lines
16 KiB
Transact-SQL
GO
|
|
SET ANSI_NULLS, ANSI_PADDING, ANSI_WARNINGS, ARITHABORT, CONCAT_NULL_YIELDS_NULL, QUOTED_IDENTIFIER ON;
|
|
|
|
SET NUMERIC_ROUNDABORT OFF;
|
|
|
|
|
|
GO
|
|
/*
|
|
The column [dbo].[T_FOGLALKOZAS].[C_TANAROKID] is being dropped, data loss could occur.
|
|
|
|
The column [dbo].[T_FOGLALKOZAS].[C_TANARID] on table [dbo].[T_FOGLALKOZAS] must be added, but the column has no default value and does not allow NULL values. If the table contains data, the ALTER script will not work. To avoid this issue you must either: add a default value to the column, mark it as allowing NULL values, or enable the generation of smart-defaults as a deployment option.
|
|
*/
|
|
|
|
--IF EXISTS (select top 1 1 from [dbo].[T_FOGLALKOZAS])
|
|
-- RAISERROR (N'Rows were detected. The schema update is terminating because data loss might occur.', 16, 127) WITH NOWAIT
|
|
|
|
|
|
GO
|
|
PRINT N'Dropping [dbo].[FK_4026077_4026075]...';
|
|
|
|
|
|
GO
|
|
ALTER TABLE [dbo].[T_TANULOTARGYMULASZTASSTATISZT] DROP CONSTRAINT [FK_4026077_4026075];
|
|
|
|
|
|
GO
|
|
PRINT N'Dropping [dbo].[FK_4025949_4025947]...';
|
|
|
|
|
|
GO
|
|
ALTER TABLE [dbo].[T_TEREM_FOGLALKOZAS] DROP CONSTRAINT [FK_4025949_4025947];
|
|
|
|
|
|
GO
|
|
PRINT N'Dropping [dbo].[FK_4025422_4025423]...';
|
|
|
|
|
|
GO
|
|
ALTER TABLE [dbo].[T_FOGLALKOZAS] DROP CONSTRAINT [FK_4025422_4025423];
|
|
|
|
|
|
GO
|
|
PRINT N'Dropping [dbo].[FK_4025428_4025426]...';
|
|
|
|
|
|
GO
|
|
ALTER TABLE [dbo].[T_FOGLALKOZAS] DROP CONSTRAINT [FK_4025428_4025426];
|
|
|
|
|
|
GO
|
|
PRINT N'Dropping [dbo].[FK_4025431_4025429]...';
|
|
|
|
|
|
GO
|
|
ALTER TABLE [dbo].[T_FOGLALKOZAS] DROP CONSTRAINT [FK_4025431_4025429];
|
|
|
|
|
|
GO
|
|
PRINT N'Dropping [dbo].[FK_402542202_402542200]...';
|
|
|
|
|
|
GO
|
|
ALTER TABLE [dbo].[T_FOGLALKOZAS] DROP CONSTRAINT [FK_402542202_402542200];
|
|
|
|
|
|
GO
|
|
PRINT N'Dropping [dbo].[FK_402542205_402542203]...';
|
|
|
|
|
|
GO
|
|
ALTER TABLE [dbo].[T_FOGLALKOZAS] DROP CONSTRAINT [FK_402542205_402542203];
|
|
|
|
|
|
GO
|
|
PRINT N'Starting rebuilding table [dbo].[T_FOGLALKOZAS]...';
|
|
|
|
|
|
GO
|
|
BEGIN TRANSACTION;
|
|
|
|
SET TRANSACTION ISOLATION LEVEL SERIALIZABLE;
|
|
|
|
SET XACT_ABORT ON;
|
|
|
|
CREATE TABLE [dbo].[tmp_ms_xx_T_FOGLALKOZAS] (
|
|
[ID] INT IDENTITY (1, 1) NOT NULL,
|
|
[C_FOGLALKOZASTIPUSA] INT NOT NULL,
|
|
[C_ORASZAM] NUMERIC (10, 2) NOT NULL,
|
|
[C_NEV] NVARCHAR (255) NULL,
|
|
[C_ERTEKELESKELL] CHAR (1) DEFAULT ('F') NULL,
|
|
[C_MULASZTASKELL] CHAR (1) DEFAULT ('F') NULL,
|
|
[C_TANARFELVEHETI] CHAR (1) DEFAULT ('T') NULL,
|
|
[C_IMPORTALT] CHAR (1) DEFAULT ('F') NULL,
|
|
[C_TANTARGYID] INT NULL,
|
|
[C_OSZTALYCSOPORTID] INT NULL,
|
|
[C_TANARID] INT NOT NULL,
|
|
[C_INTEZMENYID] INT NOT NULL,
|
|
[C_TANEVID] 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_40254221] PRIMARY KEY CLUSTERED ([ID] ASC)
|
|
);
|
|
|
|
IF EXISTS (SELECT TOP 1 1
|
|
FROM [dbo].[T_FOGLALKOZAS])
|
|
BEGIN
|
|
SET IDENTITY_INSERT [dbo].[tmp_ms_xx_T_FOGLALKOZAS] ON;
|
|
INSERT INTO [dbo].[tmp_ms_xx_T_FOGLALKOZAS] ([ID], [C_FOGLALKOZASTIPUSA], [C_ORASZAM], [C_NEV], [C_ERTEKELESKELL], [C_MULASZTASKELL], [C_TANARFELVEHETI], [C_IMPORTALT], [C_TANTARGYID], [C_OSZTALYCSOPORTID], [C_TANARID], [C_INTEZMENYID], [C_TANEVID], [TOROLT], [SERIAL], [LASTCHANGED], [CREATED], [MODIFIER], [CREATOR], [ELOZOTANEVIREKORDID], [NNID])
|
|
SELECT [ID],
|
|
[C_FOGLALKOZASTIPUSA],
|
|
[C_ORASZAM],
|
|
[C_NEV],
|
|
[C_ERTEKELESKELL],
|
|
[C_MULASZTASKELL],
|
|
[C_TANARFELVEHETI],
|
|
[C_IMPORTALT],
|
|
[C_TANTARGYID],
|
|
[C_OSZTALYCSOPORTID],
|
|
[C_TANAROKID],
|
|
[C_INTEZMENYID],
|
|
[C_TANEVID],
|
|
[TOROLT],
|
|
[SERIAL],
|
|
[LASTCHANGED],
|
|
[CREATED],
|
|
[MODIFIER],
|
|
[CREATOR],
|
|
[ELOZOTANEVIREKORDID],
|
|
[NNID]
|
|
FROM [dbo].[T_FOGLALKOZAS]
|
|
ORDER BY [ID] ASC;
|
|
SET IDENTITY_INSERT [dbo].[tmp_ms_xx_T_FOGLALKOZAS] OFF;
|
|
END
|
|
|
|
DROP TABLE [dbo].[T_FOGLALKOZAS];
|
|
|
|
EXECUTE sp_rename N'[dbo].[tmp_ms_xx_T_FOGLALKOZAS]', N'T_FOGLALKOZAS';
|
|
|
|
EXECUTE sp_rename N'[dbo].[tmp_ms_xx_constraint_PK_T_40254221]', N'PK_T_4025422', N'OBJECT';
|
|
|
|
COMMIT TRANSACTION;
|
|
|
|
SET TRANSACTION ISOLATION LEVEL READ COMMITTED;
|
|
|
|
|
|
GO
|
|
PRINT N'Creating [dbo].[T_FOGLALKOZAS].[I_T_4025422_4025423]...';
|
|
|
|
|
|
GO
|
|
CREATE NONCLUSTERED INDEX [I_T_4025422_4025423]
|
|
ON [dbo].[T_FOGLALKOZAS]([C_INTEZMENYID] ASC, [C_TANEVID] ASC, [C_FOGLALKOZASTIPUSA] ASC);
|
|
|
|
|
|
GO
|
|
PRINT N'Creating [dbo].[T_FOGLALKOZAS].[I_T_4025428_4025426]...';
|
|
|
|
|
|
GO
|
|
CREATE NONCLUSTERED INDEX [I_T_4025428_4025426]
|
|
ON [dbo].[T_FOGLALKOZAS]([C_TANTARGYID] ASC);
|
|
|
|
|
|
GO
|
|
PRINT N'Creating [dbo].[T_FOGLALKOZAS].[I_T_4025431_4025429]...';
|
|
|
|
|
|
GO
|
|
CREATE NONCLUSTERED INDEX [I_T_4025431_4025429]
|
|
ON [dbo].[T_FOGLALKOZAS]([C_OSZTALYCSOPORTID] ASC);
|
|
|
|
|
|
GO
|
|
PRINT N'Creating [dbo].[T_FOGLALKOZAS].[I_T_4025437_4025435]...';
|
|
|
|
|
|
GO
|
|
CREATE NONCLUSTERED INDEX [I_T_4025437_4025435]
|
|
ON [dbo].[T_FOGLALKOZAS]([C_TANARID] ASC);
|
|
|
|
|
|
GO
|
|
PRINT N'Creating [dbo].[T_FOGLALKOZAS].[I_T_402542202_402542200]...';
|
|
|
|
|
|
GO
|
|
CREATE NONCLUSTERED INDEX [I_T_402542202_402542200]
|
|
ON [dbo].[T_FOGLALKOZAS]([C_INTEZMENYID] ASC);
|
|
|
|
|
|
GO
|
|
PRINT N'Creating [dbo].[T_FOGLALKOZAS].[I_T_402542205_402542203]...';
|
|
|
|
|
|
GO
|
|
CREATE NONCLUSTERED INDEX [I_T_402542205_402542203]
|
|
ON [dbo].[T_FOGLALKOZAS]([C_TANEVID] ASC);
|
|
|
|
|
|
GO
|
|
PRINT N'Creating [dbo].[FK_4026077_4026075]...';
|
|
|
|
|
|
GO
|
|
ALTER TABLE [dbo].[T_TANULOTARGYMULASZTASSTATISZT] WITH NOCHECK
|
|
ADD CONSTRAINT [FK_4026077_4026075] FOREIGN KEY ([C_TARGYMULASZTASSTATISZTIKAIID]) REFERENCES [dbo].[T_FOGLALKOZAS] ([ID]);
|
|
|
|
|
|
GO
|
|
PRINT N'Creating [dbo].[FK_4025949_4025947]...';
|
|
|
|
|
|
GO
|
|
ALTER TABLE [dbo].[T_TEREM_FOGLALKOZAS] WITH NOCHECK
|
|
ADD CONSTRAINT [FK_4025949_4025947] FOREIGN KEY ([C_FOGLALKOZASID]) REFERENCES [dbo].[T_FOGLALKOZAS] ([ID]);
|
|
|
|
|
|
GO
|
|
PRINT N'Creating [dbo].[FK_4025422_4025423]...';
|
|
|
|
|
|
GO
|
|
ALTER TABLE [dbo].[T_FOGLALKOZAS] WITH NOCHECK
|
|
ADD CONSTRAINT [FK_4025422_4025423] FOREIGN KEY ([C_FOGLALKOZASTIPUSA], [C_INTEZMENYID], [C_TANEVID]) REFERENCES [dbo].[T_FOGLALKOZASTIPUS] ([ID], [C_ALINTEZMENYID], [C_ALTANEVID]);
|
|
|
|
|
|
GO
|
|
PRINT N'Creating [dbo].[FK_4025428_4025426]...';
|
|
|
|
|
|
GO
|
|
ALTER TABLE [dbo].[T_FOGLALKOZAS] WITH NOCHECK
|
|
ADD CONSTRAINT [FK_4025428_4025426] FOREIGN KEY ([C_TANTARGYID]) REFERENCES [dbo].[T_TANTARGY] ([ID]);
|
|
|
|
|
|
GO
|
|
PRINT N'Creating [dbo].[FK_4025431_4025429]...';
|
|
|
|
|
|
GO
|
|
ALTER TABLE [dbo].[T_FOGLALKOZAS] WITH NOCHECK
|
|
ADD CONSTRAINT [FK_4025431_4025429] FOREIGN KEY ([C_OSZTALYCSOPORTID]) REFERENCES [dbo].[T_OSZTALYCSOPORT] ([ID]);
|
|
|
|
|
|
GO
|
|
PRINT N'Creating [dbo].[FK_402542202_402542200]...';
|
|
|
|
|
|
GO
|
|
ALTER TABLE [dbo].[T_FOGLALKOZAS] WITH NOCHECK
|
|
ADD CONSTRAINT [FK_402542202_402542200] FOREIGN KEY ([C_INTEZMENYID]) REFERENCES [dbo].[T_INTEZMENY] ([ID]);
|
|
|
|
|
|
GO
|
|
PRINT N'Creating [dbo].[FK_402542205_402542203]...';
|
|
|
|
|
|
GO
|
|
ALTER TABLE [dbo].[T_FOGLALKOZAS] WITH NOCHECK
|
|
ADD CONSTRAINT [FK_402542205_402542203] FOREIGN KEY ([C_TANEVID]) REFERENCES [dbo].[T_TANEV] ([ID]);
|
|
|
|
|
|
GO
|
|
PRINT N'Creating [dbo].[tr_foglalkozasLog]...';
|
|
|
|
|
|
GO
|
|
|
|
CREATE TRIGGER tr_foglalkozasLog ON T_FOGLALKOZAS
|
|
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_FOGLALKOZASTIPUSA AS nvarchar(MAX)) AS C_FOGLALKOZASTIPUSA, CAST( C_ORASZAM AS nvarchar(MAX)) AS C_ORASZAM, CAST( C_NEV AS nvarchar(MAX)) AS C_NEV, CAST( C_ERTEKELESKELL AS nvarchar(MAX)) AS C_ERTEKELESKELL, CAST( C_MULASZTASKELL AS nvarchar(MAX)) AS C_MULASZTASKELL, CAST( C_TANARFELVEHETI AS nvarchar(MAX)) AS C_TANARFELVEHETI, CAST( C_IMPORTALT AS nvarchar(MAX)) AS C_IMPORTALT, CAST( C_TANTARGYID AS nvarchar(MAX)) AS C_TANTARGYID, CAST( C_OSZTALYCSOPORTID AS nvarchar(MAX)) AS C_OSZTALYCSOPORTID, CAST( C_TANARID AS nvarchar(MAX)) AS C_TANARID, 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_FOGLALKOZASTIPUSA, C_ORASZAM, C_NEV, C_ERTEKELESKELL, C_MULASZTASKELL, C_TANARFELVEHETI, C_IMPORTALT, C_TANTARGYID, C_OSZTALYCSOPORTID, C_TANARID, 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_FOGLALKOZASTIPUSA AS nvarchar(MAX)) AS C_FOGLALKOZASTIPUSA, CAST( C_ORASZAM AS nvarchar(MAX)) AS C_ORASZAM, CAST( C_NEV AS nvarchar(MAX)) AS C_NEV, CAST( C_ERTEKELESKELL AS nvarchar(MAX)) AS C_ERTEKELESKELL, CAST( C_MULASZTASKELL AS nvarchar(MAX)) AS C_MULASZTASKELL, CAST( C_TANARFELVEHETI AS nvarchar(MAX)) AS C_TANARFELVEHETI, CAST( C_IMPORTALT AS nvarchar(MAX)) AS C_IMPORTALT, CAST( C_TANTARGYID AS nvarchar(MAX)) AS C_TANTARGYID, CAST( C_OSZTALYCSOPORTID AS nvarchar(MAX)) AS C_OSZTALYCSOPORTID, CAST( C_TANARID AS nvarchar(MAX)) AS C_TANARID, 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_FOGLALKOZASTIPUSA, C_ORASZAM, C_NEV, C_ERTEKELESKELL, C_MULASZTASKELL, C_TANARFELVEHETI, C_IMPORTALT, C_TANTARGYID, C_OSZTALYCSOPORTID, C_TANARID, 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_FOGLALKOZAS', '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_FOGLALKOZAS', '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_FOGLALKOZAS',
|
|
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_FOGLALKOZAS_OSSZES]...';
|
|
|
|
|
|
GO
|
|
EXECUTE sp_refreshsqlmodule N'[dbo].[T_FOGLALKOZAS_OSSZES]';
|
|
|
|
|
|
GO
|
|
PRINT N'Checking existing data against newly created constraints';
|
|
|
|
|
|
GO
|
|
ALTER TABLE [dbo].[T_TANULOTARGYMULASZTASSTATISZT] WITH CHECK CHECK CONSTRAINT [FK_4026077_4026075];
|
|
|
|
ALTER TABLE [dbo].[T_TEREM_FOGLALKOZAS] WITH CHECK CHECK CONSTRAINT [FK_4025949_4025947];
|
|
|
|
ALTER TABLE [dbo].[T_FOGLALKOZAS] WITH CHECK CHECK CONSTRAINT [FK_4025422_4025423];
|
|
|
|
ALTER TABLE [dbo].[T_FOGLALKOZAS] WITH CHECK CHECK CONSTRAINT [FK_4025428_4025426];
|
|
|
|
ALTER TABLE [dbo].[T_FOGLALKOZAS] WITH CHECK CHECK CONSTRAINT [FK_4025431_4025429];
|
|
|
|
ALTER TABLE [dbo].[T_FOGLALKOZAS] WITH CHECK CHECK CONSTRAINT [FK_402542202_402542200];
|
|
|
|
ALTER TABLE [dbo].[T_FOGLALKOZAS] WITH CHECK CHECK CONSTRAINT [FK_402542205_402542203];
|
|
|
|
|
|
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_FOGLALKOZAS', 'T_FOGLALKOZAS_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
|