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

689 lines
29 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_4026252_4026250]...';
GO
ALTER TABLE [dbo].[T_MUKODESIHELY] DROP CONSTRAINT [FK_4026252_4026250];
GO
PRINT N'Dropping [dbo].[FK_4026536_4026534]...';
GO
ALTER TABLE [dbo].[T_KIRTELEPHELY] DROP CONSTRAINT [FK_4026536_4026534];
GO
PRINT N'Dropping [dbo].[FK_4025687_4025686]...';
GO
ALTER TABLE [dbo].[T_CSENGETESIREND] DROP CONSTRAINT [FK_4025687_4025686];
GO
PRINT N'Dropping [dbo].[FK_4026032_4026030]...';
GO
ALTER TABLE [dbo].[T_FELADATELLATASIHELY] DROP CONSTRAINT [FK_4026032_4026030];
GO
PRINT N'Dropping [dbo].[FK_4025412_4025410]...';
GO
ALTER TABLE [dbo].[T_TEREM] DROP CONSTRAINT [FK_4025412_4025410];
GO
PRINT N'Starting rebuilding table [dbo].[T_INTEZMENYADATOK]...';
GO
BEGIN TRANSACTION;
SET TRANSACTION ISOLATION LEVEL SERIALIZABLE;
SET XACT_ABORT ON;
CREATE TABLE [dbo].[tmp_ms_xx_T_INTEZMENYADATOK] (
[ID] INT IDENTITY (1, 1) NOT NULL,
[C_CIME] NVARCHAR (2000) NOT NULL,
[C_IGAZGATONEVE] NVARCHAR (255) NULL,
[C_NEV] NVARCHAR (255) NOT NULL,
[C_OMKOD] NVARCHAR (20) NOT NULL,
[C_TELEFONSZAM] NVARCHAR (20) NULL,
[C_EMAILCIM] NVARCHAR (255) NULL,
[C_IRANYITOSZAM] NVARCHAR (20) NOT NULL,
[C_VAROS] NVARCHAR (255) NOT NULL,
[C_ROVIDNEV] NVARCHAR (255) NULL,
[C_ADMINEMAILCIM] NVARCHAR (255) NULL,
[C_KRETATIPUS] INT NOT NULL,
[C_ENGEDELYEZETTALLASHELYEK] NUMERIC (10, 2) NULL,
[C_INTEZMENYHONLAPJA] NVARCHAR (300) NULL,
[C_AJTO] NVARCHAR (30) NULL,
[C_EMELET] NVARCHAR (40) NULL,
[C_HAZSZAM] NVARCHAR (30) NULL,
[C_KOZTERULETJELLEG] INT NULL,
[C_KOZTERULETNEV] NVARCHAR (40) NULL,
[C_TANEVID] INT NOT NULL,
[C_INTEZMENYID] 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_40252091] PRIMARY KEY CLUSTERED ([ID] ASC)
);
IF EXISTS (SELECT TOP 1 1
FROM [dbo].[T_INTEZMENYADATOK])
BEGIN
SET IDENTITY_INSERT [dbo].[tmp_ms_xx_T_INTEZMENYADATOK] ON;
INSERT INTO [dbo].[tmp_ms_xx_T_INTEZMENYADATOK] ([ID], [C_CIME], [C_IGAZGATONEVE], [C_NEV], [C_OMKOD], [C_TELEFONSZAM], [C_EMAILCIM], [C_IRANYITOSZAM], [C_VAROS], [C_ROVIDNEV], [C_ADMINEMAILCIM], [C_KRETATIPUS], [C_ENGEDELYEZETTALLASHELYEK], [C_INTEZMENYHONLAPJA], [C_TANEVID], [C_INTEZMENYID], [TOROLT], [SERIAL], [LASTCHANGED], [CREATED], [MODIFIER], [CREATOR], [NNID])
SELECT [ID],
[C_CIME],
[C_IGAZGATONEVE],
[C_NEV],
[C_OMKOD],
[C_TELEFONSZAM],
[C_EMAILCIM],
[C_IRANYITOSZAM],
[C_VAROS],
[C_ROVIDNEV],
[C_ADMINEMAILCIM],
[C_KRETATIPUS],
[C_ENGEDELYEZETTALLASHELYEK],
[C_INTEZMENYHONLAPJA],
[C_TANEVID],
[C_INTEZMENYID],
[TOROLT],
[SERIAL],
[LASTCHANGED],
[CREATED],
[MODIFIER],
[CREATOR],
[NNID]
FROM [dbo].[T_INTEZMENYADATOK]
ORDER BY [ID] ASC;
SET IDENTITY_INSERT [dbo].[tmp_ms_xx_T_INTEZMENYADATOK] OFF;
END
DROP TABLE [dbo].[T_INTEZMENYADATOK];
EXECUTE sp_rename N'[dbo].[tmp_ms_xx_T_INTEZMENYADATOK]', N'T_INTEZMENYADATOK';
EXECUTE sp_rename N'[dbo].[tmp_ms_xx_constraint_PK_T_40252091]', N'PK_T_4025209', N'OBJECT';
COMMIT TRANSACTION;
SET TRANSACTION ISOLATION LEVEL READ COMMITTED;
GO
PRINT N'Creating [dbo].[T_INTEZMENYADATOK].[I_T_4025209_4026340]...';
GO
CREATE NONCLUSTERED INDEX [I_T_4025209_4026340]
ON [dbo].[T_INTEZMENYADATOK]([C_INTEZMENYID] ASC, [C_TANEVID] ASC, [C_KRETATIPUS] ASC);
GO
PRINT N'Creating [dbo].[T_INTEZMENYADATOK].[I_T_4025209_4027515]...';
GO
CREATE NONCLUSTERED INDEX [I_T_4025209_4027515]
ON [dbo].[T_INTEZMENYADATOK]([C_INTEZMENYID] ASC, [C_TANEVID] ASC, [C_KOZTERULETJELLEG] ASC);
GO
PRINT N'Creating [dbo].[T_INTEZMENYADATOK].[I_T_4026244_4026243]...';
GO
CREATE NONCLUSTERED INDEX [I_T_4026244_4026243]
ON [dbo].[T_INTEZMENYADATOK]([C_TANEVID] ASC);
GO
PRINT N'Creating [dbo].[T_INTEZMENYADATOK].[I_T_4026248_4026247]...';
GO
CREATE NONCLUSTERED INDEX [I_T_4026248_4026247]
ON [dbo].[T_INTEZMENYADATOK]([C_INTEZMENYID] ASC);
GO
PRINT N'Starting rebuilding table [dbo].[T_MUKODESIHELY]...';
GO
BEGIN TRANSACTION;
SET TRANSACTION ISOLATION LEVEL SERIALIZABLE;
SET XACT_ABORT ON;
CREATE TABLE [dbo].[tmp_ms_xx_T_MUKODESIHELY] (
[ID] INT IDENTITY (1, 1) NOT NULL,
[C_NEV] NVARCHAR (255) NOT NULL,
[C_CIME] NVARCHAR (1000) NULL,
[C_EMAILCIM] NVARCHAR (255) NULL,
[C_FAX] NVARCHAR (50) NULL,
[C_IRANYITOSZAM] NVARCHAR (20) NULL,
[C_TELEFONSZAM] NVARCHAR (50) NULL,
[C_VAROS] NVARCHAR (255) NULL,
[C_VEZETONEVE] NVARCHAR (255) NULL,
[C_TAGINTEZMENY] CHAR (1) DEFAULT ('F') NULL,
[C_TAGINTEZMENYIKOD] NVARCHAR (50) NULL,
[C_SZEKHELY] CHAR (1) DEFAULT ('F') NULL,
[C_AJTO] NVARCHAR (30) NULL,
[C_EMELET] NVARCHAR (40) NULL,
[C_HAZSZAM] NVARCHAR (30) NULL,
[C_KOZTERULETJELLEG] INT NULL,
[C_KOZTERULETNEV] NVARCHAR (40) NULL,
[C_MUKODESIHELYAZONOSITO] NVARCHAR (50) NULL,
[C_MUKODESIHELYTIPUSA] INT NULL,
[C_INTEZMENYADATOKID] INT NOT 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_40251481] PRIMARY KEY CLUSTERED ([ID] ASC)
);
IF EXISTS (SELECT TOP 1 1
FROM [dbo].[T_MUKODESIHELY])
BEGIN
SET IDENTITY_INSERT [dbo].[tmp_ms_xx_T_MUKODESIHELY] ON;
INSERT INTO [dbo].[tmp_ms_xx_T_MUKODESIHELY] ([ID], [C_NEV], [C_CIME], [C_EMAILCIM], [C_FAX], [C_IRANYITOSZAM], [C_TELEFONSZAM], [C_VAROS], [C_VEZETONEVE], [C_TAGINTEZMENY], [C_TAGINTEZMENYIKOD], [C_SZEKHELY], [C_INTEZMENYADATOKID], [C_INTEZMENYID], [C_TANEVID], [TOROLT], [SERIAL], [LASTCHANGED], [CREATED], [MODIFIER], [CREATOR], [NNID])
SELECT [ID],
[C_NEV],
[C_CIME],
[C_EMAILCIM],
[C_FAX],
[C_IRANYITOSZAM],
[C_TELEFONSZAM],
[C_VAROS],
[C_VEZETONEVE],
[C_TAGINTEZMENY],
[C_TAGINTEZMENYIKOD],
[C_SZEKHELY],
[C_INTEZMENYADATOKID],
[C_INTEZMENYID],
[C_TANEVID],
[TOROLT],
[SERIAL],
[LASTCHANGED],
[CREATED],
[MODIFIER],
[CREATOR],
[NNID]
FROM [dbo].[T_MUKODESIHELY]
ORDER BY [ID] ASC;
SET IDENTITY_INSERT [dbo].[tmp_ms_xx_T_MUKODESIHELY] OFF;
END
DROP TABLE [dbo].[T_MUKODESIHELY];
EXECUTE sp_rename N'[dbo].[tmp_ms_xx_T_MUKODESIHELY]', N'T_MUKODESIHELY';
EXECUTE sp_rename N'[dbo].[tmp_ms_xx_constraint_PK_T_40251481]', N'PK_T_4025148', N'OBJECT';
COMMIT TRANSACTION;
SET TRANSACTION ISOLATION LEVEL READ COMMITTED;
GO
PRINT N'Creating [dbo].[T_MUKODESIHELY].[I_T_4025148_4027508]...';
GO
CREATE NONCLUSTERED INDEX [I_T_4025148_4027508]
ON [dbo].[T_MUKODESIHELY]([C_INTEZMENYID] ASC, [C_TANEVID] ASC, [C_KOZTERULETJELLEG] ASC);
GO
PRINT N'Creating [dbo].[T_MUKODESIHELY].[I_T_4025148_4027511]...';
GO
CREATE NONCLUSTERED INDEX [I_T_4025148_4027511]
ON [dbo].[T_MUKODESIHELY]([C_INTEZMENYID] ASC, [C_TANEVID] ASC, [C_MUKODESIHELYTIPUSA] ASC);
GO
PRINT N'Creating [dbo].[T_MUKODESIHELY].[I_T_4026252_4026250]...';
GO
CREATE NONCLUSTERED INDEX [I_T_4026252_4026250]
ON [dbo].[T_MUKODESIHELY]([C_INTEZMENYADATOKID] ASC);
GO
PRINT N'Creating [dbo].[T_MUKODESIHELY].[I_T_402514802_402514800]...';
GO
CREATE NONCLUSTERED INDEX [I_T_402514802_402514800]
ON [dbo].[T_MUKODESIHELY]([C_INTEZMENYID] ASC);
GO
PRINT N'Creating [dbo].[T_MUKODESIHELY].[I_T_402514805_402514803]...';
GO
CREATE NONCLUSTERED INDEX [I_T_402514805_402514803]
ON [dbo].[T_MUKODESIHELY]([C_TANEVID] ASC);
GO
PRINT N'Creating [dbo].[T_MUKODESIHELY].[UK_4025200]...';
GO
CREATE UNIQUE NONCLUSTERED INDEX [UK_4025200]
ON [dbo].[T_MUKODESIHELY]([C_NEV] ASC, [C_INTEZMENYID] ASC, [C_TANEVID] ASC) WHERE ([TOROLT]='F');
GO
PRINT N'Creating [dbo].[FK_4025209_4026340]...';
GO
ALTER TABLE [dbo].[T_INTEZMENYADATOK] WITH NOCHECK
ADD CONSTRAINT [FK_4025209_4026340] FOREIGN KEY ([C_KRETATIPUS], [C_INTEZMENYID], [C_TANEVID]) REFERENCES [dbo].[T_KRETATIPUS] ([ID], [C_ALINTEZMENYID], [C_ALTANEVID]);
GO
PRINT N'Creating [dbo].[FK_4026244_4026243]...';
GO
ALTER TABLE [dbo].[T_INTEZMENYADATOK] WITH NOCHECK
ADD CONSTRAINT [FK_4026244_4026243] FOREIGN KEY ([C_TANEVID]) REFERENCES [dbo].[T_TANEV] ([ID]);
GO
PRINT N'Creating [dbo].[FK_4026248_4026247]...';
GO
ALTER TABLE [dbo].[T_INTEZMENYADATOK] WITH NOCHECK
ADD CONSTRAINT [FK_4026248_4026247] FOREIGN KEY ([C_INTEZMENYID]) REFERENCES [dbo].[T_INTEZMENY] ([ID]);
GO
PRINT N'Creating [dbo].[FK_4026252_4026250]...';
GO
ALTER TABLE [dbo].[T_MUKODESIHELY] WITH NOCHECK
ADD CONSTRAINT [FK_4026252_4026250] FOREIGN KEY ([C_INTEZMENYADATOKID]) REFERENCES [dbo].[T_INTEZMENYADATOK] ([ID]);
GO
PRINT N'Creating [dbo].[FK_4026536_4026534]...';
GO
ALTER TABLE [dbo].[T_KIRTELEPHELY] WITH NOCHECK
ADD CONSTRAINT [FK_4026536_4026534] FOREIGN KEY ([C_INTEZMENYADATOKID]) REFERENCES [dbo].[T_INTEZMENYADATOK] ([ID]);
GO
PRINT N'Creating [dbo].[FK_4025209_4027515]...';
GO
ALTER TABLE [dbo].[T_INTEZMENYADATOK] WITH NOCHECK
ADD CONSTRAINT [FK_4025209_4027515] FOREIGN KEY ([C_KOZTERULETJELLEG], [C_INTEZMENYID], [C_TANEVID]) REFERENCES [dbo].[T_KOZTERULETJELLEG] ([ID], [C_ALINTEZMENYID], [C_ALTANEVID]);
GO
PRINT N'Creating [dbo].[FK_4025687_4025686]...';
GO
ALTER TABLE [dbo].[T_CSENGETESIREND] WITH NOCHECK
ADD CONSTRAINT [FK_4025687_4025686] FOREIGN KEY ([C_MUKODESIHELYID]) REFERENCES [dbo].[T_MUKODESIHELY] ([ID]);
GO
PRINT N'Creating [dbo].[FK_402514802_402514800]...';
GO
ALTER TABLE [dbo].[T_MUKODESIHELY] WITH NOCHECK
ADD CONSTRAINT [FK_402514802_402514800] FOREIGN KEY ([C_INTEZMENYID]) REFERENCES [dbo].[T_INTEZMENY] ([ID]);
GO
PRINT N'Creating [dbo].[FK_402514805_402514803]...';
GO
ALTER TABLE [dbo].[T_MUKODESIHELY] WITH NOCHECK
ADD CONSTRAINT [FK_402514805_402514803] FOREIGN KEY ([C_TANEVID]) REFERENCES [dbo].[T_TANEV] ([ID]);
GO
PRINT N'Creating [dbo].[FK_4026032_4026030]...';
GO
ALTER TABLE [dbo].[T_FELADATELLATASIHELY] WITH NOCHECK
ADD CONSTRAINT [FK_4026032_4026030] FOREIGN KEY ([C_MUKODESIHELYID]) REFERENCES [dbo].[T_MUKODESIHELY] ([ID]);
GO
PRINT N'Creating [dbo].[FK_4025412_4025410]...';
GO
ALTER TABLE [dbo].[T_TEREM] WITH NOCHECK
ADD CONSTRAINT [FK_4025412_4025410] FOREIGN KEY ([C_MUKODESIHELYID]) REFERENCES [dbo].[T_MUKODESIHELY] ([ID]);
GO
PRINT N'Creating [dbo].[FK_4025148_4027508]...';
GO
ALTER TABLE [dbo].[T_MUKODESIHELY] WITH NOCHECK
ADD CONSTRAINT [FK_4025148_4027508] FOREIGN KEY ([C_KOZTERULETJELLEG], [C_INTEZMENYID], [C_TANEVID]) REFERENCES [dbo].[T_KOZTERULETJELLEG] ([ID], [C_ALINTEZMENYID], [C_ALTANEVID]);
GO
PRINT N'Creating [dbo].[FK_4025148_4027511]...';
GO
ALTER TABLE [dbo].[T_MUKODESIHELY] WITH NOCHECK
ADD CONSTRAINT [FK_4025148_4027511] FOREIGN KEY ([C_MUKODESIHELYTIPUSA], [C_INTEZMENYID], [C_TANEVID]) REFERENCES [dbo].[T_MUKODESIHELYTIPUS] ([ID], [C_ALINTEZMENYID], [C_ALTANEVID]);
GO
PRINT N'Creating [dbo].[tr_intezmenyadatokLog]...';
GO
CREATE TRIGGER tr_intezmenyadatokLog ON T_INTEZMENYADATOK
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_CIME AS nvarchar(MAX)) AS C_CIME, CAST( C_IGAZGATONEVE AS nvarchar(MAX)) AS C_IGAZGATONEVE, CAST( C_NEV AS nvarchar(MAX)) AS C_NEV, CAST( C_OMKOD AS nvarchar(MAX)) AS C_OMKOD, CAST( C_TELEFONSZAM AS nvarchar(MAX)) AS C_TELEFONSZAM, CAST( C_EMAILCIM AS nvarchar(MAX)) AS C_EMAILCIM, CAST( C_IRANYITOSZAM AS nvarchar(MAX)) AS C_IRANYITOSZAM, CAST( C_VAROS AS nvarchar(MAX)) AS C_VAROS, CAST( C_ROVIDNEV AS nvarchar(MAX)) AS C_ROVIDNEV, CAST( C_ADMINEMAILCIM AS nvarchar(MAX)) AS C_ADMINEMAILCIM, CAST( C_KRETATIPUS AS nvarchar(MAX)) AS C_KRETATIPUS, CAST( C_ENGEDELYEZETTALLASHELYEK AS nvarchar(MAX)) AS C_ENGEDELYEZETTALLASHELYEK, CAST( C_INTEZMENYHONLAPJA AS nvarchar(MAX)) AS C_INTEZMENYHONLAPJA, CAST( C_AJTO AS nvarchar(MAX)) AS C_AJTO, CAST( C_EMELET AS nvarchar(MAX)) AS C_EMELET, CAST( C_HAZSZAM AS nvarchar(MAX)) AS C_HAZSZAM, CAST( C_KOZTERULETJELLEG AS nvarchar(MAX)) AS C_KOZTERULETJELLEG, CAST( C_KOZTERULETNEV AS nvarchar(MAX)) AS C_KOZTERULETNEV, CAST( TOROLT AS nvarchar(MAX)) AS TOROLT, CAST( NNID AS nvarchar(MAX)) AS NNID
FROM INSERTED) p
UNPIVOT (val FOR col IN (C_CIME, C_IGAZGATONEVE, C_NEV, C_OMKOD, C_TELEFONSZAM, C_EMAILCIM, C_IRANYITOSZAM, C_VAROS, C_ROVIDNEV, C_ADMINEMAILCIM, C_KRETATIPUS, C_ENGEDELYEZETTALLASHELYEK, C_INTEZMENYHONLAPJA, C_AJTO, C_EMELET, C_HAZSZAM, C_KOZTERULETJELLEG, C_KOZTERULETNEV, 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_CIME AS nvarchar(MAX)) AS C_CIME, CAST( C_IGAZGATONEVE AS nvarchar(MAX)) AS C_IGAZGATONEVE, CAST( C_NEV AS nvarchar(MAX)) AS C_NEV, CAST( C_OMKOD AS nvarchar(MAX)) AS C_OMKOD, CAST( C_TELEFONSZAM AS nvarchar(MAX)) AS C_TELEFONSZAM, CAST( C_EMAILCIM AS nvarchar(MAX)) AS C_EMAILCIM, CAST( C_IRANYITOSZAM AS nvarchar(MAX)) AS C_IRANYITOSZAM, CAST( C_VAROS AS nvarchar(MAX)) AS C_VAROS, CAST( C_ROVIDNEV AS nvarchar(MAX)) AS C_ROVIDNEV, CAST( C_ADMINEMAILCIM AS nvarchar(MAX)) AS C_ADMINEMAILCIM, CAST( C_KRETATIPUS AS nvarchar(MAX)) AS C_KRETATIPUS, CAST( C_ENGEDELYEZETTALLASHELYEK AS nvarchar(MAX)) AS C_ENGEDELYEZETTALLASHELYEK, CAST( C_INTEZMENYHONLAPJA AS nvarchar(MAX)) AS C_INTEZMENYHONLAPJA, CAST( C_AJTO AS nvarchar(MAX)) AS C_AJTO, CAST( C_EMELET AS nvarchar(MAX)) AS C_EMELET, CAST( C_HAZSZAM AS nvarchar(MAX)) AS C_HAZSZAM, CAST( C_KOZTERULETJELLEG AS nvarchar(MAX)) AS C_KOZTERULETJELLEG, CAST( C_KOZTERULETNEV AS nvarchar(MAX)) AS C_KOZTERULETNEV, CAST( TOROLT AS nvarchar(MAX)) AS TOROLT, CAST( NNID AS nvarchar(MAX)) AS NNID
FROM DELETED) p
UNPIVOT (val FOR col IN (C_CIME, C_IGAZGATONEVE, C_NEV, C_OMKOD, C_TELEFONSZAM, C_EMAILCIM, C_IRANYITOSZAM, C_VAROS, C_ROVIDNEV, C_ADMINEMAILCIM, C_KRETATIPUS, C_ENGEDELYEZETTALLASHELYEK, C_INTEZMENYHONLAPJA, C_AJTO, C_EMELET, C_HAZSZAM, C_KOZTERULETJELLEG, C_KOZTERULETNEV, 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_INTEZMENYADATOK', '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_INTEZMENYADATOK', '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_INTEZMENYADATOK',
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].[tr_mukodesihelyLog]...';
GO
CREATE TRIGGER tr_mukodesihelyLog ON T_MUKODESIHELY
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_NEV AS nvarchar(MAX)) AS C_NEV, CAST( C_CIME AS nvarchar(MAX)) AS C_CIME, CAST( C_EMAILCIM AS nvarchar(MAX)) AS C_EMAILCIM, CAST( C_FAX AS nvarchar(MAX)) AS C_FAX, CAST( C_IRANYITOSZAM AS nvarchar(MAX)) AS C_IRANYITOSZAM, CAST( C_TELEFONSZAM AS nvarchar(MAX)) AS C_TELEFONSZAM, CAST( C_VAROS AS nvarchar(MAX)) AS C_VAROS, CAST( C_VEZETONEVE AS nvarchar(MAX)) AS C_VEZETONEVE, CAST( C_TAGINTEZMENY AS nvarchar(MAX)) AS C_TAGINTEZMENY, CAST( C_TAGINTEZMENYIKOD AS nvarchar(MAX)) AS C_TAGINTEZMENYIKOD, CAST( C_SZEKHELY AS nvarchar(MAX)) AS C_SZEKHELY, CAST( C_AJTO AS nvarchar(MAX)) AS C_AJTO, CAST( C_EMELET AS nvarchar(MAX)) AS C_EMELET, CAST( C_HAZSZAM AS nvarchar(MAX)) AS C_HAZSZAM, CAST( C_KOZTERULETJELLEG AS nvarchar(MAX)) AS C_KOZTERULETJELLEG, CAST( C_KOZTERULETNEV AS nvarchar(MAX)) AS C_KOZTERULETNEV, CAST( C_MUKODESIHELYAZONOSITO AS nvarchar(MAX)) AS C_MUKODESIHELYAZONOSITO, CAST( C_MUKODESIHELYTIPUSA AS nvarchar(MAX)) AS C_MUKODESIHELYTIPUSA, CAST( C_INTEZMENYADATOKID AS nvarchar(MAX)) AS C_INTEZMENYADATOKID, CAST( TOROLT AS nvarchar(MAX)) AS TOROLT, CAST( NNID AS nvarchar(MAX)) AS NNID
FROM INSERTED) p
UNPIVOT (val FOR col IN (C_NEV, C_CIME, C_EMAILCIM, C_FAX, C_IRANYITOSZAM, C_TELEFONSZAM, C_VAROS, C_VEZETONEVE, C_TAGINTEZMENY, C_TAGINTEZMENYIKOD, C_SZEKHELY, C_AJTO, C_EMELET, C_HAZSZAM, C_KOZTERULETJELLEG, C_KOZTERULETNEV, C_MUKODESIHELYAZONOSITO, C_MUKODESIHELYTIPUSA, C_INTEZMENYADATOKID, 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_NEV AS nvarchar(MAX)) AS C_NEV, CAST( C_CIME AS nvarchar(MAX)) AS C_CIME, CAST( C_EMAILCIM AS nvarchar(MAX)) AS C_EMAILCIM, CAST( C_FAX AS nvarchar(MAX)) AS C_FAX, CAST( C_IRANYITOSZAM AS nvarchar(MAX)) AS C_IRANYITOSZAM, CAST( C_TELEFONSZAM AS nvarchar(MAX)) AS C_TELEFONSZAM, CAST( C_VAROS AS nvarchar(MAX)) AS C_VAROS, CAST( C_VEZETONEVE AS nvarchar(MAX)) AS C_VEZETONEVE, CAST( C_TAGINTEZMENY AS nvarchar(MAX)) AS C_TAGINTEZMENY, CAST( C_TAGINTEZMENYIKOD AS nvarchar(MAX)) AS C_TAGINTEZMENYIKOD, CAST( C_SZEKHELY AS nvarchar(MAX)) AS C_SZEKHELY, CAST( C_AJTO AS nvarchar(MAX)) AS C_AJTO, CAST( C_EMELET AS nvarchar(MAX)) AS C_EMELET, CAST( C_HAZSZAM AS nvarchar(MAX)) AS C_HAZSZAM, CAST( C_KOZTERULETJELLEG AS nvarchar(MAX)) AS C_KOZTERULETJELLEG, CAST( C_KOZTERULETNEV AS nvarchar(MAX)) AS C_KOZTERULETNEV, CAST( C_MUKODESIHELYAZONOSITO AS nvarchar(MAX)) AS C_MUKODESIHELYAZONOSITO, CAST( C_MUKODESIHELYTIPUSA AS nvarchar(MAX)) AS C_MUKODESIHELYTIPUSA, CAST( C_INTEZMENYADATOKID AS nvarchar(MAX)) AS C_INTEZMENYADATOKID, CAST( TOROLT AS nvarchar(MAX)) AS TOROLT, CAST( NNID AS nvarchar(MAX)) AS NNID
FROM DELETED) p
UNPIVOT (val FOR col IN (C_NEV, C_CIME, C_EMAILCIM, C_FAX, C_IRANYITOSZAM, C_TELEFONSZAM, C_VAROS, C_VEZETONEVE, C_TAGINTEZMENY, C_TAGINTEZMENYIKOD, C_SZEKHELY, C_AJTO, C_EMELET, C_HAZSZAM, C_KOZTERULETJELLEG, C_KOZTERULETNEV, C_MUKODESIHELYAZONOSITO, C_MUKODESIHELYTIPUSA, C_INTEZMENYADATOKID, 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_MUKODESIHELY', '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_MUKODESIHELY', '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_MUKODESIHELY',
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_INTEZMENYADATOK_OSSZES]...';
GO
EXECUTE sp_refreshsqlmodule N'[dbo].[T_INTEZMENYADATOK_OSSZES]';
GO
PRINT N'Refreshing [dbo].[T_MUKODESIHELY_OSSZES]...';
GO
EXECUTE sp_refreshsqlmodule N'[dbo].[T_MUKODESIHELY_OSSZES]';
GO
PRINT N'Checking existing data against newly created constraints';
GO
ALTER TABLE [dbo].[T_INTEZMENYADATOK] WITH CHECK CHECK CONSTRAINT [FK_4025209_4026340];
ALTER TABLE [dbo].[T_INTEZMENYADATOK] WITH CHECK CHECK CONSTRAINT [FK_4026244_4026243];
ALTER TABLE [dbo].[T_INTEZMENYADATOK] WITH CHECK CHECK CONSTRAINT [FK_4026248_4026247];
ALTER TABLE [dbo].[T_MUKODESIHELY] WITH CHECK CHECK CONSTRAINT [FK_4026252_4026250];
ALTER TABLE [dbo].[T_KIRTELEPHELY] WITH CHECK CHECK CONSTRAINT [FK_4026536_4026534];
ALTER TABLE [dbo].[T_INTEZMENYADATOK] WITH CHECK CHECK CONSTRAINT [FK_4025209_4027515];
ALTER TABLE [dbo].[T_CSENGETESIREND] WITH CHECK CHECK CONSTRAINT [FK_4025687_4025686];
ALTER TABLE [dbo].[T_MUKODESIHELY] WITH CHECK CHECK CONSTRAINT [FK_402514802_402514800];
ALTER TABLE [dbo].[T_MUKODESIHELY] WITH CHECK CHECK CONSTRAINT [FK_402514805_402514803];
ALTER TABLE [dbo].[T_FELADATELLATASIHELY] WITH CHECK CHECK CONSTRAINT [FK_4026032_4026030];
ALTER TABLE [dbo].[T_TEREM] WITH CHECK CHECK CONSTRAINT [FK_4025412_4025410];
ALTER TABLE [dbo].[T_MUKODESIHELY] WITH CHECK CHECK CONSTRAINT [FK_4025148_4027508];
ALTER TABLE [dbo].[T_MUKODESIHELY] WITH CHECK CHECK CONSTRAINT [FK_4025148_4027511];
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_INTEZMENYADATOK', 'T_INTEZMENYADATOK_OSSZES',
'T_MUKODESIHELY', 'T_MUKODESIHELY_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