init
This commit is contained in:
@@ -0,0 +1,17 @@
|
||||
--Migration
|
||||
IF OBJECT_ID('dbo.T_OSZTONDIJHISTORY') IS NULL
|
||||
CREATE TABLE dbo.T_OSZTONDIJHISTORY(
|
||||
ID INT NOT NULL,
|
||||
C_ENTITYID int NOT NULL,
|
||||
C_TABLEID tinyint NOT NULL,
|
||||
C_ALTERATIONDATE datetime NOT NULL,
|
||||
C_REASONID tinyint NOT NULL, -- 1:(New) INSERT, 2:(Removed) DELETE, 3:(Modified) UPDATE
|
||||
C_FELHASZNALOID int NULL,
|
||||
C_TANULOID int NOT NULL,
|
||||
C_TANEVID int NOT NULL,
|
||||
C_PROPERTYNAME varchar (100) COLLATE Hungarian_CI_AI NOT NULL,
|
||||
C_ORIGINALVALUE nvarchar (2000) COLLATE Hungarian_CI_AI NULL,
|
||||
C_CURRENTVALUE nvarchar (2000) COLLATE Hungarian_CI_AI NULL,
|
||||
CONSTRAINT PK_OsztondijHistory PRIMARY KEY CLUSTERED (C_TANEVID, C_TANULOID, ID, C_PROPERTYNAME)
|
||||
WITH (DATA_COMPRESSION = PAGE, FILLFACTOR = 100)
|
||||
)
|
@@ -0,0 +1,53 @@
|
||||
SET ANSI_NULLS ON
|
||||
GO
|
||||
SET QUOTED_IDENTIFIER ON
|
||||
GO
|
||||
DROP PROCEDURE IF EXISTS dbo.uspOsztondijHistory
|
||||
GO
|
||||
CREATE PROCEDURE dbo.uspOsztondijHistory(
|
||||
@pTanuloId int,
|
||||
@pTableId tinyint
|
||||
)
|
||||
WITH EXECUTE AS 'kreta_tech_user'
|
||||
AS
|
||||
DECLARE @TanevId INT,
|
||||
@OsztalyId INT;
|
||||
|
||||
SELECT @TanevId = C_ALTANEVID FROM T_TANULO WHERE ID = @pTanuloId;
|
||||
|
||||
SELECT
|
||||
oh.ID
|
||||
,oh.C_ENTITYID
|
||||
,oh.C_TABLEID
|
||||
,oh.C_ALTERATIONDATE
|
||||
,oh.C_REASONID
|
||||
,ISNULL(f.C_NYOMTATASINEV, '(rendszer)') as C_FELHASZNALONEV
|
||||
,oh.C_PROPERTYNAME
|
||||
,oh.C_ORIGINALVALUE
|
||||
,oh.C_CURRENTVALUE
|
||||
FROM T_OSZTONDIJHISTORY oh
|
||||
LEFT JOIN T_FELHASZNALO f ON f.ID = oh.C_FELHASZNALOID
|
||||
WHERE oh.C_TANEVID = @TanevId
|
||||
AND oh.C_TANULOID = @pTanuloId
|
||||
AND oh.C_TABLEID = @pTableId
|
||||
|
||||
UNION ALL
|
||||
|
||||
SELECT
|
||||
oh.ID
|
||||
,oh.C_ENTITYID
|
||||
,oh.C_TABLEID
|
||||
,oh.C_ALTERATIONDATE
|
||||
,oh.C_REASONID
|
||||
,ISNULL(f.C_NYOMTATASINEV, '(rendszer)') as C_FELHASZNALONEV
|
||||
,oh.C_PROPERTYNAME
|
||||
,oh.C_ORIGINALVALUE
|
||||
,oh.C_CURRENTVALUE
|
||||
FROM T_OSZTONDIJHISTORY oh
|
||||
LEFT JOIN T_FELHASZNALO f ON f.ID = oh.C_FELHASZNALOID
|
||||
WHERE oh.C_TANEVID = @TanevId
|
||||
AND oh.C_TANULOID = 0
|
||||
AND oh.C_TABLEID = @pTableId
|
||||
AND EXISTS(SELECT * FROM T_TANULOCSOPORT tcs WHERE tcs.C_OSZTALYCSOPORTID = oh.C_ENTITYID AND tcs.C_TANULOID = @pTanuloId)
|
||||
|
||||
|
@@ -0,0 +1,137 @@
|
||||
|
||||
SET ANSI_NULLS ON
|
||||
GO
|
||||
SET QUOTED_IDENTIFIER ON
|
||||
GO
|
||||
DROP PROCEDURE IF EXISTS dbo.uspOsztondijHistoryFeltoltes
|
||||
GO
|
||||
CREATE PROCEDURE dbo.uspOsztondijHistoryFeltoltes
|
||||
AS
|
||||
SET NOCOUNT ON;
|
||||
|
||||
DROP TABLE IF EXISTS #TablaOszlopLista;
|
||||
CREATE TABLE #TablaOszlopLista(
|
||||
TablaId TINYINT,
|
||||
TablaNev SYSNAME COLLATE Hungarian_CI_AI,
|
||||
OszlopNev SYSNAME COLLATE Hungarian_CI_AI,
|
||||
PRIMARY KEY CLUSTERED (TablaId, OszlopNev),
|
||||
UNIQUE (TablaNev, OszlopNev)
|
||||
);
|
||||
|
||||
INSERT INTO #TablaOszlopLista(TablaId, TablaNev, OszlopNev)
|
||||
VALUES
|
||||
(1, 'T_OSZTALYCSOPORT', 'C_EVFOLYAMTIPUSA'),
|
||||
(1, 'T_OSZTALYCSOPORT', 'C_ISTECHNIKAI'),
|
||||
(1, 'T_OSZTALYCSOPORT', 'C_KERESZTFELEVES'),
|
||||
(1, 'T_OSZTALYCSOPORT', 'C_FELADATKATEGORIAID'),
|
||||
(1, 'T_OSZTALYCSOPORT', 'C_VEGZOSEVFOLYAM'),
|
||||
(1, 'T_OSZTALYCSOPORT', 'TOROLT'),
|
||||
(2, 'T_TANULO', 'C_EVISMETLO'),
|
||||
(2, 'T_TANULO', 'C_ISBESZAMITASOS'),
|
||||
(2, 'T_TANULO', 'C_ISMASODIKTOBBSZAKMA'),
|
||||
(2, 'T_TANULO', 'C_ISOSZTONDIJBOLKIZARVA'),
|
||||
(2, 'T_TANULO', 'C_ISSZAKKEPZESIMUNKASZERZODESS'),
|
||||
(2, 'T_TANULO', 'C_JOGVISZONYATSZUNETELTETO'),
|
||||
(2, 'T_TANULO', 'C_JOGVISZONYTIPUSID'),
|
||||
(2, 'T_TANULO', 'C_KEZIATLAG'),
|
||||
(2, 'T_TANULO', 'C_SZAMITOTTATLAG'),
|
||||
(2, 'T_TANULO', 'C_TANULOSZERZODESES'),
|
||||
(2, 'T_TANULO', 'C_VENDEG'),
|
||||
(2, 'T_TANULO', 'C_ISBESZAMITASOSFIXSZAZALEK'),
|
||||
(2, 'T_TANULO', 'C_ISMULASZTASMIATTKIZART'),
|
||||
(2, 'T_TANULO', 'C_ISSIKERESAGAZATIVIZSGA'),
|
||||
(2, 'T_TANULO', 'C_ISATLAGSZAKKEPZESI'),
|
||||
(2, 'T_TANULO', 'C_ISINGYENESKEPZES'),
|
||||
(2, 'T_TANULO', 'TOROLT'),
|
||||
(3, 'T_TANULOCSOPORT', 'C_BELEPESDATUM'),
|
||||
(3, 'T_TANULOCSOPORT', 'C_KILEPESDATUM'),
|
||||
(3, 'T_TANULOCSOPORT', 'C_JOGVISZONYTIPUSID'),
|
||||
(3, 'T_TANULOCSOPORT', 'TOROLT'),
|
||||
(4, 'T_TANULOMULASZTAS', 'C_IGAZOLT'),
|
||||
(4, 'T_TANULOMULASZTAS', 'C_TIPUS'),
|
||||
(4, 'T_TANULOMULASZTAS', 'C_TANITASIORAKID'),
|
||||
(4, 'T_TANULOMULASZTAS', 'C_ORATANULOIID'),
|
||||
(4, 'T_TANULOMULASZTAS', 'TOROLT'),
|
||||
(5, 'T_TANULOTANUGYIADATOK', 'C_EVISMETLO'),
|
||||
(5, 'T_TANULOTANUGYIADATOK', 'C_ISBESZAMITASOS'),
|
||||
(5, 'T_TANULOTANUGYIADATOK', 'C_ISMASODIKTOBBSZAKMA'),
|
||||
(5, 'T_TANULOTANUGYIADATOK', 'C_ISSZAKKEPZESIMUNKASZERZODESS'),
|
||||
(5, 'T_TANULOTANUGYIADATOK', 'C_JOGVISZONYATSZUNETELTETO'),
|
||||
(5, 'T_TANULOTANUGYIADATOK', 'C_TANULOEVFOLYAMTIPUSID'),
|
||||
(5, 'T_TANULOTANUGYIADATOK', 'C_TANULOSZERZODESES'),
|
||||
(5, 'T_TANULOTANUGYIADATOK', 'C_VENDEG'),
|
||||
(5, 'T_TANULOTANUGYIADATOK', 'TOROLT'),
|
||||
(5, 'T_TANULOTANUGYIADATOK', 'C_ISBESZAMITASOSFIXSZAZALEK'),
|
||||
(5, 'T_TANULOTANUGYIADATOK', 'C_AGAZATUJSZKTTIPUSID'),
|
||||
(5, 'T_TANULOTANUGYIADATOK', 'C_SZAKMATIPUSID');
|
||||
|
||||
CREATE TABLE #TablaLista(
|
||||
TablaId TINYINT,
|
||||
TablaNev SYSNAME COLLATE Hungarian_CI_AI,
|
||||
PRIMARY KEY CLUSTERED (TablaId),
|
||||
UNIQUE (TablaNev)
|
||||
);
|
||||
|
||||
INSERT INTO #TablaLista(TablaId, TablaNev)
|
||||
SELECT DISTINCT TablaId, TablaNev
|
||||
FROM #TablaOszlopLista;
|
||||
|
||||
DECLARE @LastHistoryID INT = 0;
|
||||
SELECT @LastHistoryID = ISNULL(MAX(ID), 0) FROM dbo.T_OSZTONDIJHISTORY WITH (NOLOCK);
|
||||
|
||||
INSERT INTO dbo.T_OSZTONDIJHISTORY(
|
||||
ID
|
||||
,C_ENTITYID
|
||||
,C_TABLEID
|
||||
,C_ALTERATIONDATE
|
||||
,C_REASONID
|
||||
,C_FELHASZNALOID
|
||||
,C_TANULOID
|
||||
,C_TANEVID
|
||||
,C_PROPERTYNAME
|
||||
,C_ORIGINALVALUE
|
||||
,C_CURRENTVALUE
|
||||
)
|
||||
SELECT
|
||||
eh.ID,
|
||||
eh.C_ENTITYID,
|
||||
t.TablaId AS C_TABLEID,
|
||||
eh.C_ALTERATIONDATE,
|
||||
CASE eh.C_REASON
|
||||
WHEN 'New' THEN 1
|
||||
WHEN 'Removed' THEN 2
|
||||
WHEN 'Modified' THEN 3
|
||||
ELSE 0
|
||||
END AS C_REASONID,
|
||||
eh.C_FELHASZNALOID,
|
||||
CASE eh.C_ENTITYNAME
|
||||
WHEN 'T_OSZTALYCSOPORT' THEN 0
|
||||
WHEN 'T_TANULO' THEN eh.C_ENTITYID
|
||||
WHEN 'T_TANULOCSOPORT' THEN tcs1.C_TANULOID
|
||||
WHEN 'T_TANULOMULASZTAS' THEN tm.C_ORATANULOIID
|
||||
WHEN 'T_TANULOTANUGYIADATOK' THEN tcs2.C_TANULOID
|
||||
ELSE null
|
||||
END AS C_TANULOID,
|
||||
eh.C_TANEVID,
|
||||
eah.C_PROPERTYNAME,
|
||||
eah.C_ORIGINALVALUE,
|
||||
eah.C_CURRENTVALUE
|
||||
FROM T_ENTITYHISTORY eh WITH (NOLOCK)
|
||||
INNER JOIN T_TANEV v WITH (NOLOCK) on v.ID = eh.C_TANEVID
|
||||
INNER JOIN T_INTEZMENY i ON i.ID = v.C_INTEZMENYID
|
||||
LEFT JOIN T_ENTITYATTRIBUTEHISTORY eah WITH (NOLOCK) ON eah.C_ENTITYHISTORYID = eh.ID
|
||||
LEFT JOIN #TablaLista t ON t.TablaNev = eh.C_ENTITYNAME
|
||||
LEFT JOIN T_TANULOCSOPORT tcs1 WITH (NOLOCK) ON tcs1.ID = eh.C_ENTITYID --and eh.C_ENTITYNAME = 'T_TANULOCSOPORT'
|
||||
LEFT JOIN T_TANULOMULASZTAS tm WITH (NOLOCK) ON tm.ID = eh.C_ENTITYID --and eh.C_ENTITYNAME = 'T_TANULOMULASZTAS'
|
||||
LEFT JOIN T_TANULOTANUGYIADATOK tt WITH (NOLOCK) ON tt.ID = eh.C_ENTITYID --and eh.C_ENTITYNAME = 'T_TANULOTANUGYIADATOK'
|
||||
LEFT JOIN T_TANULOCSOPORT tcs2 WITH (NOLOCK) ON tcs2.ID = tt.C_TANULOCSOPORTID
|
||||
WHERE (v.C_AKTIV = 'T' OR v.C_KOVETKEZO = 'T')
|
||||
AND v.TOROLT = 'F'
|
||||
AND i.TOROLT = 'F'
|
||||
AND i.C_FENNTARTOAZONOSITO <> '999'
|
||||
AND i.C_AZONOSITO NOT LIKE '%deleted'
|
||||
AND i.C_AZONOSITO NOT LIKE '%moved'
|
||||
AND i.C_AZONOSITO NOT LIKE '%[_]old'
|
||||
AND eh.ID > @LastHistoryID
|
||||
AND EXISTS(SELECT * FROM #TablaOszlopLista t WHERE t.TablaNev = eh.C_ENTITYNAME AND t.OszlopNev = eah.C_PROPERTYNAME)
|
||||
go
|
Reference in New Issue
Block a user