Files
kreta/Kreta.DataAccess.Migrations/Scripts/Archive/20170406125715_KRETA_681/KRETA_681.sql
2024-03-13 00:33:46 +01:00

268 lines
14 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_INTEZMENYADATSZOLGALTATAS]...';
GO
BEGIN TRANSACTION;
SET TRANSACTION ISOLATION LEVEL SERIALIZABLE;
SET XACT_ABORT ON;
CREATE TABLE [dbo].[tmp_ms_xx_T_INTEZMENYADATSZOLGALTATAS] (
[ID] INT IDENTITY (1, 1) NOT NULL,
[C_ELFOGADOTTESL] CHAR (1) NULL,
[C_ELFOGADOTTTTF] CHAR (1) NULL,
[C_VEGLEGESESL] CHAR (1) NULL,
[C_VEGLEGESTTF] CHAR (1) NULL,
[C_FENNTARTOTTFELUTASITASOKA] NVARCHAR (MAX) NULL,
[C_ELFOGADOTTESLDATUMA] DATETIME NULL,
[C_ELFOGADOTTLETSZAM] CHAR (1) NULL,
[C_ELFOGADOTTLETSZAMDATUMA] DATETIME NULL,
[C_ELFOGADOTTTTFDATUMA] DATETIME NULL,
[C_FENNTARTOESLELUTASITASOKA] NVARCHAR (MAX) NULL,
[C_VEGLEGESESLDATUMA] DATETIME NULL,
[C_VEGLEGESLETSZAM] CHAR (1) NULL,
[C_VEGLEGESLETSZAMDATUMA] DATETIME NULL,
[C_VEGLEGESTTFDATUMA] DATETIME NULL,
[C_BEIRATKOZASELUTASITASOKA] NVARCHAR (MAX) NULL,
[C_ELFOGADOTTBEIRATKOZAS] CHAR (1) NULL,
[C_VEGLEGESBEIRATKOZAS] CHAR (1) DEFAULT ('F') 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_40263461] PRIMARY KEY CLUSTERED ([ID] ASC)
);
IF EXISTS (SELECT TOP 1 1
FROM [dbo].[T_INTEZMENYADATSZOLGALTATAS])
BEGIN
SET IDENTITY_INSERT [dbo].[tmp_ms_xx_T_INTEZMENYADATSZOLGALTATAS] ON;
INSERT INTO [dbo].[tmp_ms_xx_T_INTEZMENYADATSZOLGALTATAS] ([ID], [C_ELFOGADOTTESL], [C_ELFOGADOTTTTF], [C_VEGLEGESESL], [C_VEGLEGESTTF], [C_FENNTARTOTTFELUTASITASOKA], [C_ELFOGADOTTESLDATUMA], [C_ELFOGADOTTLETSZAM], [C_ELFOGADOTTLETSZAMDATUMA], [C_ELFOGADOTTTTFDATUMA], [C_FENNTARTOESLELUTASITASOKA], [C_VEGLEGESESLDATUMA], [C_VEGLEGESLETSZAM], [C_VEGLEGESLETSZAMDATUMA], [C_VEGLEGESTTFDATUMA], [C_INTEZMENYID], [C_TANEVID], [TOROLT], [SERIAL], [LASTCHANGED], [CREATED], [MODIFIER], [CREATOR], [NNID])
SELECT [ID],
[C_ELFOGADOTTESL],
[C_ELFOGADOTTTTF],
[C_VEGLEGESESL],
[C_VEGLEGESTTF],
[C_FENNTARTOTTFELUTASITASOKA],
[C_ELFOGADOTTESLDATUMA],
[C_ELFOGADOTTLETSZAM],
[C_ELFOGADOTTLETSZAMDATUMA],
[C_ELFOGADOTTTTFDATUMA],
[C_FENNTARTOESLELUTASITASOKA],
[C_VEGLEGESESLDATUMA],
[C_VEGLEGESLETSZAM],
[C_VEGLEGESLETSZAMDATUMA],
[C_VEGLEGESTTFDATUMA],
[C_INTEZMENYID],
[C_TANEVID],
[TOROLT],
[SERIAL],
[LASTCHANGED],
[CREATED],
[MODIFIER],
[CREATOR],
[NNID]
FROM [dbo].[T_INTEZMENYADATSZOLGALTATAS]
ORDER BY [ID] ASC;
SET IDENTITY_INSERT [dbo].[tmp_ms_xx_T_INTEZMENYADATSZOLGALTATAS] OFF;
END
DROP TABLE [dbo].[T_INTEZMENYADATSZOLGALTATAS];
EXECUTE sp_rename N'[dbo].[tmp_ms_xx_T_INTEZMENYADATSZOLGALTATAS]', N'T_INTEZMENYADATSZOLGALTATAS';
EXECUTE sp_rename N'[dbo].[tmp_ms_xx_constraint_PK_T_40263461]', N'PK_T_4026346', N'OBJECT';
COMMIT TRANSACTION;
SET TRANSACTION ISOLATION LEVEL READ COMMITTED;
GO
PRINT N'Creating [dbo].[T_INTEZMENYADATSZOLGALTATAS].[I_T_4026359_4026358]...';
GO
CREATE NONCLUSTERED INDEX [I_T_4026359_4026358]
ON [dbo].[T_INTEZMENYADATSZOLGALTATAS]([C_INTEZMENYID] ASC);
GO
PRINT N'Creating [dbo].[T_INTEZMENYADATSZOLGALTATAS].[I_T_4026362_4026361]...';
GO
CREATE NONCLUSTERED INDEX [I_T_4026362_4026361]
ON [dbo].[T_INTEZMENYADATSZOLGALTATAS]([C_TANEVID] ASC);
GO
PRINT N'Creating [dbo].[FK_4026359_4026358]...';
GO
ALTER TABLE [dbo].[T_INTEZMENYADATSZOLGALTATAS] WITH NOCHECK
ADD CONSTRAINT [FK_4026359_4026358] FOREIGN KEY ([C_INTEZMENYID]) REFERENCES [dbo].[T_INTEZMENY] ([ID]);
GO
PRINT N'Creating [dbo].[FK_4026362_4026361]...';
GO
ALTER TABLE [dbo].[T_INTEZMENYADATSZOLGALTATAS] WITH NOCHECK
ADD CONSTRAINT [FK_4026362_4026361] FOREIGN KEY ([C_TANEVID]) REFERENCES [dbo].[T_TANEV] ([ID]);
GO
PRINT N'Creating [dbo].[tr_intezmenyadatszolgaltatasLog]...';
GO
CREATE TRIGGER tr_intezmenyadatszolgaltatasLog ON T_INTEZMENYADATSZOLGALTATAS
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_ELFOGADOTTESL AS nvarchar(MAX)) AS C_ELFOGADOTTESL, CAST( C_ELFOGADOTTTTF AS nvarchar(MAX)) AS C_ELFOGADOTTTTF, CAST( C_VEGLEGESESL AS nvarchar(MAX)) AS C_VEGLEGESESL, CAST( C_VEGLEGESTTF AS nvarchar(MAX)) AS C_VEGLEGESTTF, CAST( C_FENNTARTOTTFELUTASITASOKA AS nvarchar(MAX)) AS C_FENNTARTOTTFELUTASITASOKA, CONVERT(nvarchar(MAX), C_ELFOGADOTTESLDATUMA, 121) AS C_ELFOGADOTTESLDATUMA, CAST( C_ELFOGADOTTLETSZAM AS nvarchar(MAX)) AS C_ELFOGADOTTLETSZAM, CONVERT(nvarchar(MAX), C_ELFOGADOTTLETSZAMDATUMA, 121) AS C_ELFOGADOTTLETSZAMDATUMA, CONVERT(nvarchar(MAX), C_ELFOGADOTTTTFDATUMA, 121) AS C_ELFOGADOTTTTFDATUMA, CAST( C_FENNTARTOESLELUTASITASOKA AS nvarchar(MAX)) AS C_FENNTARTOESLELUTASITASOKA, CONVERT(nvarchar(MAX), C_VEGLEGESESLDATUMA, 121) AS C_VEGLEGESESLDATUMA, CAST( C_VEGLEGESLETSZAM AS nvarchar(MAX)) AS C_VEGLEGESLETSZAM, CONVERT(nvarchar(MAX), C_VEGLEGESLETSZAMDATUMA, 121) AS C_VEGLEGESLETSZAMDATUMA, CONVERT(nvarchar(MAX), C_VEGLEGESTTFDATUMA, 121) AS C_VEGLEGESTTFDATUMA, CAST( C_BEIRATKOZASELUTASITASOKA AS nvarchar(MAX)) AS C_BEIRATKOZASELUTASITASOKA, CAST( C_ELFOGADOTTBEIRATKOZAS AS nvarchar(MAX)) AS C_ELFOGADOTTBEIRATKOZAS, CAST( C_VEGLEGESBEIRATKOZAS AS nvarchar(MAX)) AS C_VEGLEGESBEIRATKOZAS, CAST( TOROLT AS nvarchar(MAX)) AS TOROLT, CAST( NNID AS nvarchar(MAX)) AS NNID
FROM INSERTED) p
UNPIVOT (val FOR col IN (C_ELFOGADOTTESL, C_ELFOGADOTTTTF, C_VEGLEGESESL, C_VEGLEGESTTF, C_FENNTARTOTTFELUTASITASOKA, C_ELFOGADOTTESLDATUMA, C_ELFOGADOTTLETSZAM, C_ELFOGADOTTLETSZAMDATUMA, C_ELFOGADOTTTTFDATUMA, C_FENNTARTOESLELUTASITASOKA, C_VEGLEGESESLDATUMA, C_VEGLEGESLETSZAM, C_VEGLEGESLETSZAMDATUMA, C_VEGLEGESTTFDATUMA, C_BEIRATKOZASELUTASITASOKA, C_ELFOGADOTTBEIRATKOZAS, C_VEGLEGESBEIRATKOZAS, 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_ELFOGADOTTESL AS nvarchar(MAX)) AS C_ELFOGADOTTESL, CAST( C_ELFOGADOTTTTF AS nvarchar(MAX)) AS C_ELFOGADOTTTTF, CAST( C_VEGLEGESESL AS nvarchar(MAX)) AS C_VEGLEGESESL, CAST( C_VEGLEGESTTF AS nvarchar(MAX)) AS C_VEGLEGESTTF, CAST( C_FENNTARTOTTFELUTASITASOKA AS nvarchar(MAX)) AS C_FENNTARTOTTFELUTASITASOKA, CONVERT(nvarchar(MAX), C_ELFOGADOTTESLDATUMA, 121) AS C_ELFOGADOTTESLDATUMA, CAST( C_ELFOGADOTTLETSZAM AS nvarchar(MAX)) AS C_ELFOGADOTTLETSZAM, CONVERT(nvarchar(MAX), C_ELFOGADOTTLETSZAMDATUMA, 121) AS C_ELFOGADOTTLETSZAMDATUMA, CONVERT(nvarchar(MAX), C_ELFOGADOTTTTFDATUMA, 121) AS C_ELFOGADOTTTTFDATUMA, CAST( C_FENNTARTOESLELUTASITASOKA AS nvarchar(MAX)) AS C_FENNTARTOESLELUTASITASOKA, CONVERT(nvarchar(MAX), C_VEGLEGESESLDATUMA, 121) AS C_VEGLEGESESLDATUMA, CAST( C_VEGLEGESLETSZAM AS nvarchar(MAX)) AS C_VEGLEGESLETSZAM, CONVERT(nvarchar(MAX), C_VEGLEGESLETSZAMDATUMA, 121) AS C_VEGLEGESLETSZAMDATUMA, CONVERT(nvarchar(MAX), C_VEGLEGESTTFDATUMA, 121) AS C_VEGLEGESTTFDATUMA, CAST( C_BEIRATKOZASELUTASITASOKA AS nvarchar(MAX)) AS C_BEIRATKOZASELUTASITASOKA, CAST( C_ELFOGADOTTBEIRATKOZAS AS nvarchar(MAX)) AS C_ELFOGADOTTBEIRATKOZAS, CAST( C_VEGLEGESBEIRATKOZAS AS nvarchar(MAX)) AS C_VEGLEGESBEIRATKOZAS, CAST( TOROLT AS nvarchar(MAX)) AS TOROLT, CAST( NNID AS nvarchar(MAX)) AS NNID
FROM DELETED) p
UNPIVOT (val FOR col IN (C_ELFOGADOTTESL, C_ELFOGADOTTTTF, C_VEGLEGESESL, C_VEGLEGESTTF, C_FENNTARTOTTFELUTASITASOKA, C_ELFOGADOTTESLDATUMA, C_ELFOGADOTTLETSZAM, C_ELFOGADOTTLETSZAMDATUMA, C_ELFOGADOTTTTFDATUMA, C_FENNTARTOESLELUTASITASOKA, C_VEGLEGESESLDATUMA, C_VEGLEGESLETSZAM, C_VEGLEGESLETSZAMDATUMA, C_VEGLEGESTTFDATUMA, C_BEIRATKOZASELUTASITASOKA, C_ELFOGADOTTBEIRATKOZAS, C_VEGLEGESBEIRATKOZAS, 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_INTEZMENYADATSZOLGALTATAS', '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_INTEZMENYADATSZOLGALTATAS', '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_INTEZMENYADATSZOLGALTATAS',
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_INTEZMENYADATSZOLGALTATAS_OSSZES]...';
GO
EXECUTE sp_refreshsqlmodule N'[dbo].[T_INTEZMENYADATSZOLGALTATAS_OSSZES]';
GO
ALTER TABLE [dbo].[T_INTEZMENYADATSZOLGALTATAS] WITH CHECK CHECK CONSTRAINT [FK_4026359_4026358];
ALTER TABLE [dbo].[T_INTEZMENYADATSZOLGALTATAS] WITH CHECK CHECK CONSTRAINT [FK_4026362_4026361];
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_INTEZMENYADATSZOLGALTATAS', 'T_INTEZMENYADATSZOLGALTATAS_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