init
This commit is contained in:
@@ -0,0 +1,60 @@
|
||||
IF OBJECT_ID('dbo.T_ORAREND') IS NULL BEGIN
|
||||
CREATE TABLE T_ORAREND (
|
||||
C_ORARENDIORAID int NOT NULL
|
||||
,C_DATUM datetime NOT NULL
|
||||
,C_TANEVID int NOT NULL
|
||||
,C_INTEZMENYID int NOT NULL
|
||||
,CONSTRAINT PK_Orarend PRIMARY KEY (C_ORARENDIORAID, C_DATUM)
|
||||
);
|
||||
|
||||
CREATE INDEX NCI_Orarend_TanevId ON T_ORAREND ( C_TANEVID)
|
||||
CREATE INDEX NCI_Orarend_IntezmenyId ON T_ORAREND ( C_INTEZMENYID)
|
||||
CREATE INDEX NCI_Orarend_Datum_TanevId_IntezmenyId ON T_ORAREND (C_DATUM, C_TANEVID, C_INTEZMENYID)
|
||||
|
||||
ALTER TABLE [DBO].T_ORAREND
|
||||
ADD CONSTRAINT FK_Orarend_OrarendiOraId_REF_OrarendiOraId
|
||||
FOREIGN KEY (C_ORARENDIORAID)
|
||||
REFERENCES [DBO].T_ORARENDIORA (ID)
|
||||
|
||||
ALTER TABLE [DBO].T_ORAREND
|
||||
ADD CONSTRAINT FK_Orarend_TanevId_REF_Tanev
|
||||
FOREIGN KEY (C_TANEVID)
|
||||
REFERENCES [DBO].T_TANEV (ID)
|
||||
|
||||
ALTER TABLE [DBO].T_ORAREND
|
||||
ADD CONSTRAINT FK_Orarend_IntezmenyId_REF_Intezmeny
|
||||
FOREIGN KEY (C_INTEZMENYID)
|
||||
REFERENCES [DBO].T_INTEZMENY (ID)
|
||||
|
||||
END
|
||||
GO
|
||||
|
||||
|
||||
EXEC dev.uspCreateSchemaViews 'T_ORAREND'
|
||||
GO
|
||||
|
||||
DROP INDEX IF EXISTS NCI_TanevRendje_Datum_IntezmenyId_TanevId ON T_TANEVRENDJE
|
||||
GO
|
||||
|
||||
IF NOT EXISTS (SELECT 1 FROM sys.indexes WHERE name = 'NCI_TanevRendje_Datum_IntezmenyId_TanevId') BEGIN
|
||||
CREATE NONCLUSTERED INDEX NCI_TanevRendje_Datum_IntezmenyId_TanevId
|
||||
ON T_TANEVRENDJE (
|
||||
C_DATUM
|
||||
,C_TANEVID
|
||||
,C_INTEZMENYID
|
||||
)
|
||||
INCLUDE (C_OSSZESCSOPORTRAVONATKOZIK, C_CSENGETESIRENDID, C_EGYEDINAP)
|
||||
WHERE TOROLT = 'F'
|
||||
WITH (FILLFACTOR = 80)
|
||||
END
|
||||
GO
|
||||
|
||||
|
||||
IF NOT EXISTS (SELECT 1 FROM sys.indexes WHERE name = 'NCI_OrarendiOra_TanevId_IntezmenyId_HetNapja_OraervenyessegKezdete_OrarevenyessegVege') BEGIN
|
||||
CREATE INDEX NCI_OrarendiOra_TanevId_IntezmenyId_HetNapja_OraervenyessegKezdete_OrarevenyessegVege
|
||||
ON T_ORARENDIORA (C_TANEVID, C_INTEZMENYID, C_HETNAPJA, C_ORAERVENYESSEGKEZDETE, C_ORAERVENYESSEGVEGE)
|
||||
INCLUDE (C_EGYEDINAP, C_OSZTALYCSOPORTID, C_HETIREND, TOROLT)
|
||||
WHERE TOROLT = 'F'
|
||||
WITH (FILLFACTOR = 80)
|
||||
END
|
||||
GO
|
@@ -0,0 +1,34 @@
|
||||
DECLARE
|
||||
@intezmenyId int
|
||||
,@tanevId int
|
||||
,@sql nvarchar(max)
|
||||
,@azonosito nvarchar(50)
|
||||
|
||||
DECLARE TanevCur CURSOR LOCAL FOR
|
||||
SELECT i.ID, tv.ID, i.C_AZONOSITO FROM T_INTEZMENY i
|
||||
INNER JOIN T_TANEV tv ON tv.C_INTEZMENYID = i.ID AND tv.C_AKTIV = 'T' AND tv.TOROLT = 'F'
|
||||
WHERE i.TOROLT = 'F'
|
||||
|
||||
OPEN TanevCur
|
||||
FETCH NEXT FROM TanevCur
|
||||
INTO @intezmenyId, @tanevId, @azonosito
|
||||
|
||||
|
||||
WHILE @@FETCH_STATUS = 0 BEGIN
|
||||
|
||||
EXEC uspGenerateOrarend
|
||||
@pIntezmenyId = @intezmenyId
|
||||
,@pTanevId = @tanevId
|
||||
,@pIdoszakKezdete = NULL
|
||||
,@pIdoszakVege = NULL
|
||||
,@pOrarendiOraId = NULL
|
||||
,@pOsztalycsoportId = NULL
|
||||
|
||||
FETCH NEXT FROM TanevCur
|
||||
INTO @intezmenyId, @tanevId, @azonosito
|
||||
|
||||
END
|
||||
|
||||
CLOSE TanevCur
|
||||
DEALLOCATE TanevCur
|
||||
GO
|
@@ -0,0 +1,218 @@
|
||||
-- ============================================================================================
|
||||
-- Schema view-kat generál a paraméterekben megadott táblákhoz és schemákhoz,
|
||||
-- illetve, ha kéteznek akkor frissíti őket.
|
||||
--
|
||||
-- Ha a @pTables vagy a @pSchemas paraméter értéke NULL, akkor az összes
|
||||
-- táblára/schemára megcsinálja a view-kat
|
||||
|
||||
-- Amennyiben a dbo-ban van olyan KRÉTAidegen tábla, ami T_-sal kezdődik, van benne
|
||||
-- C_INTEZMENYID oszlop, de nincs benne TOROLT oszlop, valószínüleg el fog szállni az SP.
|
||||
|
||||
-- @pTables: tábla nevek vesszővel elválasztva, pl.: 'T_TANEV, T_UJTABLA,T_TANULO'
|
||||
-- @pSchemas: schema nevek vesszővel elválasztva, pl.: 'KR_asd_Schema,dbo, KR_dobokata_Schema'
|
||||
-- ============================================================================================
|
||||
DROP PROCEDURE IF EXISTS dev.uspCreateSchemaViews
|
||||
GO
|
||||
|
||||
CREATE PROCEDURE dev.uspCreateSchemaViews
|
||||
@pTables nvarchar(max)
|
||||
,@pSchemas nvarchar(max) = NULL
|
||||
,@pDebugMode bit = 0
|
||||
AS
|
||||
BEGIN
|
||||
SET NOCOUNT ON;
|
||||
|
||||
DECLARE
|
||||
@tableName nvarchar(255)
|
||||
,@schemaName nvarchar(255)
|
||||
,@isIdentity nvarchar(10)
|
||||
,@intezmenyId int
|
||||
,@tanevId int
|
||||
,@notExistingObject nvarchar(255)
|
||||
,@osszesView bit
|
||||
,@sql nvarchar(max)
|
||||
,@dbName nvarchar(50)
|
||||
,@tanevColumn nvarchar(50)
|
||||
,@intezmenyColumn nvarchar(50)
|
||||
|
||||
CREATE TABLE #Table (
|
||||
TableName nvarchar(255) COLLATE DATABASE_DEFAULT PRIMARY KEY
|
||||
)
|
||||
CREATE TABLE #Schema (
|
||||
SchemaName nvarchar(255) COLLATE DATABASE_DEFAULT PRIMARY KEY
|
||||
,IntezmenyAzonosito nvarchar(255) COLLATE DATABASE_DEFAULT
|
||||
)
|
||||
|
||||
IF @pTables IS NOT NULL BEGIN
|
||||
INSERT INTO #Table (TableName)
|
||||
SELECT DISTINCT LTRIM(RTRIM(s.value))
|
||||
FROM STRING_SPLIT(@pTables, ',') s
|
||||
|
||||
SET @notExistingObject = NULL
|
||||
SELECT @notExistingObject = ISNULL(@notExistingObject + ', ', '') + s.TableName
|
||||
FROM #Table s
|
||||
WHERE NOT EXISTS (
|
||||
SELECT 1 FROM sys.tables t
|
||||
WHERE s.TableName COLLATE HUNGARIAN_CI_AS = t.name COLLATE HUNGARIAN_CI_AS
|
||||
AND t.name LIKE 'T[_]%' AND t.schema_id = 1 )
|
||||
|
||||
IF @notExistingObject IS NOT NULL BEGIN
|
||||
SET @dbName = DB_NAME()
|
||||
RAISERROR('A paraméterekben megadott táblák közül a követtkezők nem léteznek a %s adatbázisban: %s', 16, 1, @dbName, @notExistingObject)
|
||||
RETURN
|
||||
END
|
||||
END
|
||||
ELSE BEGIN
|
||||
INSERT INTO #Table (TableName)
|
||||
SELECT t.name
|
||||
FROM sys.tables t
|
||||
WHERE t.name like 'T[_]%'
|
||||
AND t.schema_id = 1
|
||||
AND t.name NOT IN ('T_ENTITYATTRIBUTEHISTORY', 'T_ENTITYHISTORY')
|
||||
END
|
||||
|
||||
IF @pSchemas IS NOT NULL BEGIN
|
||||
INSERT INTO #Schema (SchemaName)
|
||||
SELECT DISTINCT LTRIM(RTRIM(s.value))
|
||||
FROM STRING_SPLIT(@pSchemas, ',') s
|
||||
|
||||
SET @notExistingObject = NULL
|
||||
|
||||
SELECT @notExistingObject = ISNULL(@notExistingObject + ', ', '') + s.SchemaName
|
||||
FROM #Schema s
|
||||
WHERE NOT EXISTS (SELECT 1 FROM sys.schemas t WHERE s.SchemaName COLLATE HUNGARIAN_CI_AS = t.name COLLATE HUNGARIAN_CI_AS)
|
||||
|
||||
IF @notExistingObject IS NOT NULL BEGIN
|
||||
SET @dbName = DB_NAME()
|
||||
RAISERROR('A paraméterekben megadott schemák közül a követtkezők nem léteznek a %s adatbázisban: %s', 16, 1, @dbName, @notExistingObject)
|
||||
RETURN
|
||||
END
|
||||
END
|
||||
ELSE BEGIN
|
||||
INSERT INTO #Schema (SchemaName, IntezmenyAzonosito)
|
||||
SELECT t.name, REPLACE(REPLACE(t.name, 'KR_', ''), '_Schema', '')
|
||||
FROM sys.schemas t
|
||||
WHERE name LIKE 'KR[_]%[_]Schema' OR name = 'dbo'
|
||||
END
|
||||
|
||||
-- normál táblák, ahol van ID, INTEZMENYID, TANEVID oszlopok és a T_EVFOLYAMTIPUS_OKTATASINEVELE tábla
|
||||
DECLARE ViewCursor CURSOR LOCAL FOR
|
||||
SELECT
|
||||
tbl.name AS TableName
|
||||
,COALESCE(cid.is_identity, 2) AS IsIdentity
|
||||
,'[' + s.SchemaName + ']' AS SchemaName
|
||||
,i.ID AS IntezmenyId
|
||||
,tv.ID AS TanevId
|
||||
,ctv.name AS TanevColumn
|
||||
,cin.name AS IntezmenyColumn
|
||||
FROM sys.tables tbl
|
||||
LEFT JOIN sys.columns cid ON tbl.object_id = cid.object_id AND cid.name = 'ID'
|
||||
INNER JOIN sys.columns cin ON tbl.object_id = cin.object_id AND cin.name IN ('C_INTEZMENYID', 'C_ALINTEZMENYID')
|
||||
LEFT JOIN sys.columns ctv ON tbl.object_id = ctv.object_id AND ctv.name IN ('C_TANEVID', 'C_ALTANEVID')
|
||||
INNER JOIN #Table t ON t.TableName COLLATE HUNGARIAN_CI_AS = tbl.name COLLATE HUNGARIAN_CI_AS
|
||||
CROSS JOIN #Schema s
|
||||
LEFT JOIN T_INTEZMENY i ON i.C_AZONOSITO = s.IntezmenyAzonosito AND i.TOROLT = 'F'
|
||||
LEFT JOIN T_TANEV tv ON tv.C_INTEZMENYID = i.ID AND tv.C_AKTIV = 'T' AND tv.TOROLT = 'F'
|
||||
WHERE tbl.schema_id = 1
|
||||
ORDER BY SchemaName, tbl.name
|
||||
|
||||
|
||||
OPEN ViewCursor
|
||||
|
||||
FETCH NEXT FROM ViewCursor
|
||||
INTO @tableName, @isIdentity, @schemaName, @intezmenyId, @tanevId, @tanevColumn, @intezmenyColumn
|
||||
|
||||
WHILE @@FETCH_STATUS = 0 BEGIN
|
||||
|
||||
IF @schemaName = '[dbo]' BEGIN
|
||||
SET @sql = N'
|
||||
CREATE OR ALTER VIEW ' + @schemaName + '.' + @tableName + '_OSSZES AS
|
||||
SELECT *
|
||||
FROM dbo.' + @tableName + ';'
|
||||
IF @pDebugMode = 1 PRINT @schemaName + '.' + @tableName + '_OSSZES (dbo)'
|
||||
EXEC sp_executesql @sql
|
||||
END
|
||||
ELSE BEGIN
|
||||
SET @sql = N'
|
||||
CREATE OR ALTER VIEW ' + @schemaName + '.' + @tableName + ' AS
|
||||
SELECT *
|
||||
FROM dbo.' + @tableName + '
|
||||
WHERE ' + @intezmenyColumn + ' = ' + CAST(@intezmenyId AS varchar(10)) + '
|
||||
' + ISNULL('AND ' + @tanevColumn + ' = ' + CAST(@tanevId AS varchar(10)), '') + '
|
||||
' + IIF(@isIdentity = 2, '', 'AND TOROLT = ''F''')
|
||||
IF @pDebugMode = 1 PRINT @schemaName + '.' + @tableName + ' (normal)'
|
||||
EXEC sp_executesql @sql
|
||||
|
||||
SET @sql = N'
|
||||
CREATE OR ALTER VIEW ' + @schemaName + '.' + @tableName + '_OSSZES AS
|
||||
SELECT *
|
||||
FROM dbo.' + @tableName + '
|
||||
WHERE ' + @intezmenyColumn + ' = ' + CAST(@intezmenyId AS varchar(10)) + ';'
|
||||
IF @pDebugMode = 1 PRINT @schemaName + '.' + @tableName + '_OSSZES (normal osszes)'
|
||||
EXEC sp_executesql @sql
|
||||
END
|
||||
|
||||
FETCH NEXT FROM ViewCursor
|
||||
INTO @tableName, @isIdentity, @schemaName, @intezmenyId, @tanevId, @tanevColumn, @intezmenyColumn
|
||||
|
||||
END
|
||||
|
||||
CLOSE ViewCursor
|
||||
DEALLOCATE ViewCursor
|
||||
|
||||
-- Kapcsolótáblák + T_INTEZMENY
|
||||
DECLARE ViewCursorKapcs CURSOR LOCAL FOR
|
||||
SELECT tbl.name AS TableName , '[' + s.SchemaName + ']' AS SchemaName, 0 AS OsszesView
|
||||
FROM sys.tables tbl
|
||||
INNER JOIN #Table t ON t.TableName COLLATE HUNGARIAN_CI_AS = tbl.name COLLATE HUNGARIAN_CI_AS
|
||||
CROSS JOIN #Schema s
|
||||
WHERE NOT EXISTS (SELECT 1 FROM sys.columns x WHERE x.object_id = tbl.object_id AND x.name = 'C_INTEZMENYID')
|
||||
AND NOT EXISTS (SELECT 1 FROM sys.columns x WHERE x.object_id = tbl.object_id AND x.name = 'C_ALINTEZMENYID')
|
||||
AND NOT EXISTS (SELECT 1 FROM sys.columns x WHERE x.object_id = tbl.object_id AND x.name = 'ID')
|
||||
AND tbl.schema_id = 1
|
||||
AND s.SchemaName <> 'dbo'
|
||||
|
||||
UNION ALL
|
||||
|
||||
SELECT tbl.name, '[' + s.SchemaName + ']', 1
|
||||
FROM sys.tables tbl
|
||||
INNER JOIN #Table t ON t.TableName COLLATE HUNGARIAN_CI_AS = tbl.name COLLATE HUNGARIAN_CI_AS
|
||||
CROSS JOIN #Schema s
|
||||
WHERE NOT EXISTS (SELECT 1 FROM sys.columns x WHERE x.object_id = tbl.object_id AND x.name = 'C_INTEZMENYID')
|
||||
AND NOT EXISTS (SELECT 1 FROM sys.columns x WHERE x.object_id = tbl.object_id AND x.name = 'C_ALINTEZMENYID')
|
||||
AND EXISTS (SELECT 1 FROM sys.columns x WHERE x.object_id = tbl.object_id AND x.name = 'ID')
|
||||
AND tbl.schema_id = 1
|
||||
AND s.SchemaName <> 'dbo'
|
||||
ORDER BY SchemaName, TableName
|
||||
|
||||
OPEN ViewCursorKapcs
|
||||
|
||||
FETCH NEXT FROM ViewCursorKapcs
|
||||
INTO @tableName, @schemaName, @osszesView
|
||||
|
||||
WHILE @@FETCH_STATUS = 0 BEGIN
|
||||
IF @osszesView = 1 BEGIN
|
||||
SET @sql = N'
|
||||
CREATE OR ALTER VIEW ' + @schemaName + '.' + @tableName + '_OSSZES AS
|
||||
SELECT *
|
||||
FROM dbo.' + @tableName + ';'
|
||||
IF @pDebugMode = 1 PRINT @schemaName + '.' + @tableName + '_OSSZES (kapcsolótábla)'
|
||||
EXEC sp_executesql @sql
|
||||
|
||||
END
|
||||
|
||||
SET @sql = N'
|
||||
CREATE OR ALTER VIEW ' + @schemaName + '.' + @tableName + ' AS
|
||||
SELECT *
|
||||
FROM dbo.' + @tableName + IIF(@osszesView = 1, ' WHERE TOROLT = ''F''', '') + ';'
|
||||
IF @pDebugMode = 1 PRINT @schemaName + '.' + @tableName + ' (nem intézményhez köthető tábla)'
|
||||
EXEC sp_executesql @sql
|
||||
|
||||
FETCH NEXT FROM ViewCursorKapcs
|
||||
INTO @tableName, @schemaName, @osszesView
|
||||
END
|
||||
|
||||
CLOSE ViewCursorKapcs
|
||||
DEALLOCATE ViewCursorKapcs
|
||||
END
|
||||
GO
|
@@ -0,0 +1,271 @@
|
||||
DROP PROCEDURE IF EXISTS uspGenerateOrarend
|
||||
GO
|
||||
|
||||
CREATE PROCEDURE uspGenerateOrarend
|
||||
@pIntezmenyId int
|
||||
,@pTanevId int
|
||||
,@pIdoszakKezdete datetime = NULL
|
||||
,@pIdoszakVege datetime = NULL
|
||||
,@pOrarendiOraId int = NULL
|
||||
,@pOsztalycsoportId int = NULL
|
||||
AS
|
||||
BEGIN
|
||||
SET NOCOUNT ON;
|
||||
DECLARE @sql nvarchar(max) = N'';
|
||||
|
||||
SELECT
|
||||
@pIdoszakKezdete = ISNULL(@pIdoszakKezdete, C_KEZDONAP)
|
||||
,@pIdoszakVege = ISNULL(@pIdoszakVege, C_UTOLSONAP)
|
||||
FROM T_TANEV
|
||||
WHERE ID = @pTanevId
|
||||
|
||||
IF @pOrarendiOraId IS NOT NULL BEGIN
|
||||
IF (SELECT TOROLT FROM T_ORARENDIORA_OSSZES WHERE ID = @pOrarendiOraId) = 'T' BEGIN
|
||||
DELETE orr
|
||||
FROM T_ORAREND orr
|
||||
WHERE orr.C_ORARENDIORAID = @pOrarendiOraId
|
||||
END
|
||||
END
|
||||
ELSE BEGIN
|
||||
DELETE orr
|
||||
FROM T_ORAREND orr
|
||||
INNER JOIN T_ORARENDIORA_OSSZES oo ON oo.ID = orr.C_ORARENDIORAID
|
||||
WHERE oo.TOROLT = 'T' AND oo.C_TANEVID = @pTanevId
|
||||
END
|
||||
|
||||
SET @sql += N'
|
||||
|
||||
CREATE TABLE #Osztalycsoport (
|
||||
Id int
|
||||
,IdoszakVege datetime
|
||||
,TanevId int
|
||||
)
|
||||
|
||||
DECLARE @VegzosUtolsoTanitasiNap datetime;
|
||||
SELECT @VegzosUtolsoTanitasiNap = MIN(C_DATUM)
|
||||
FROM T_TANEVRENDJE_OSSZES
|
||||
WHERE TOROLT = ''F''
|
||||
AND C_TANEVID = @pTanevId
|
||||
AND C_NAPTIPUSA IN (1402, 7600, 7601, 7602, 7603, 1395)
|
||||
AND C_OSSZESCSOPORTRAVONATKOZIK = ''T''
|
||||
|
||||
--PRINT ''Oszt<EFBFBD>lycsoport insert''
|
||||
|
||||
INSERT INTO #Osztalycsoport (Id, IdoszakVege, TanevId)
|
||||
SELECT ocs.ID, IIF(C_VEGZOSEVFOLYAM = ''T'', @VegzosUtolsoTanitasiNap, @pIdoszakVege), ocs.C_TANEVID
|
||||
FROM T_OSZTALYCSOPORT_OSSZES ocs
|
||||
' + IIF(@pOrarendiOraId IS NULL, '', 'INNER JOIN T_ORARENDIORA_OSSZES oo ON oo.C_OSZTALYCSOPORTID = ocs.ID AND oo.TOROLT = ''F'' AND oo.ID = @pOrarendiOraId') + '
|
||||
WHERE ocs.TOROLT = ''F'' ' + IIF(@pOsztalycsoportId IS NULL, '', 'AND ocs.ID = @pOsztalycsoportId') + '
|
||||
|
||||
--PRINT ''Oszt<EFBFBD>lycsoport update''
|
||||
|
||||
UPDATE ocs SET
|
||||
ocs.IdoszakVege = NewVegeDatum
|
||||
FROM #OsztalyCsoport ocs
|
||||
INNER JOIN (
|
||||
SELECT MIN(tr.C_DATUM) AS NewVegeDatum, ocstr.C_OSZTALYCSOPORTID
|
||||
FROM T_TANEVRENDJE_OSSZES tr
|
||||
INNER JOIN T_OSZTALYCSOPORT_TANEVRENDJE ocstr ON ocstr.C_TANEVRENDJEID = tr.ID
|
||||
WHERE tr.C_OSSZESCSOPORTRAVONATKOZIK = ''F''
|
||||
AND tr.TOROLT = ''F''
|
||||
AND tr.C_NAPTIPUSA IN (1402, 7600, 7601, 7602, 7603)
|
||||
AND tr.C_TANEVID = @pTanevId
|
||||
GROUP BY ocstr.C_OSZTALYCSOPORTID
|
||||
) x ON x.C_OSZTALYCSOPORTID = ocs.Id'
|
||||
|
||||
IF @pOsztalycsoportId IS NOT NULL OR @pOrarendiOraId IS NOT NULL BEGIN
|
||||
SET @sql += N'
|
||||
CREATE TABLE #OrarendiOra (
|
||||
Id int primary key
|
||||
);
|
||||
|
||||
--PRINT ''OrarendiOraTemp insert''
|
||||
INSERT INTO #OrarendiOra (id)
|
||||
SELECT ID
|
||||
FROM T_ORARENDIORA_OSSZES
|
||||
WHERE TOROLT = ''F''
|
||||
' + IIF(@pOsztalycsoportId IS NULL, '', 'AND C_OSZTALYCSOPORTID = @pOsztalycsoportId')
|
||||
+ IIF(@pOrarendiOraId IS NULL, '', 'AND ID = @pOrarendiOraId') + '
|
||||
'
|
||||
END
|
||||
SET @sql += N'
|
||||
CREATE TABLE #NaptariNap (
|
||||
C_TANEVID int
|
||||
,C_INTEZMENYID int
|
||||
,C_NAPDATUMA datetime
|
||||
,C_HETNAPJA int
|
||||
,C_HETIREND int
|
||||
,C_EGYEDINAP char(1) COLLATE Hungarian_CI_AI
|
||||
,INDEX IX_001 CLUSTERED (C_TANEVID, C_HETNAPJA, C_INTEZMENYID, C_NAPDATUMA)
|
||||
)
|
||||
|
||||
INSERT INTO #NaptariNap (
|
||||
C_TANEVID
|
||||
,C_INTEZMENYID
|
||||
,C_NAPDATUMA
|
||||
,C_HETNAPJA
|
||||
,C_HETIREND
|
||||
,C_EGYEDINAP
|
||||
) SELECT
|
||||
nn.C_TANEVID
|
||||
,nn.C_INTEZMENYID
|
||||
,nn.C_NAPDATUMA
|
||||
,nn.C_HETNAPJA
|
||||
,nn.C_HETIREND
|
||||
,ISNULL(tr.C_EGYEDINAP, ''F'')
|
||||
FROM T_NAPTARINAP_OSSZES nn
|
||||
LEFT JOIN T_TANEVRENDJE_OSSZES tr ON tr.C_DATUM = nn.C_NAPDATUMA AND tr.C_TANEVID = nn.C_TANEVID AND tr.C_OSSZESCSOPORTRAVONATKOZIK = ''T'' AND tr.TOROLT = ''F''
|
||||
WHERE nn.C_TANEVID = @pTanevId AND nn.TOROLT = ''F''
|
||||
AND nn.C_ORARENDINAP = ''T''
|
||||
AND nn.C_NAPDATUMA BETWEEN @pIdoszakKezdete AND @pIdoszakVege
|
||||
' + IIF(@pOrarendiOraId IS NULL, '', 'AND nn.C_HETNAPJA = (SELECT C_HETNAPJA FROM T_ORARENDIORA_OSSZES WHERE ID = @pOrarendiOraId)') + '
|
||||
|
||||
CREATE TABLE #NaptariNapOsztalycsoport (
|
||||
C_TANEVID int
|
||||
,C_INTEZMENYID int
|
||||
,C_NAPDATUMA datetime
|
||||
,C_HETNAPJA int
|
||||
,C_HETIREND int
|
||||
,C_EGYEDINAP char(1) COLLATE Hungarian_CI_AI
|
||||
,C_OSZTALYCSOPORTID int
|
||||
,INDEX IX_001 CLUSTERED (C_TANEVID, C_HETNAPJA, C_INTEZMENYID, C_NAPDATUMA, C_OSZTALYCSOPORTID)
|
||||
)
|
||||
INSERT INTO #NaptariNapOsztalycsoport (
|
||||
C_TANEVID
|
||||
,C_INTEZMENYID
|
||||
,C_NAPDATUMA
|
||||
,C_HETNAPJA
|
||||
,C_HETIREND
|
||||
,C_EGYEDINAP
|
||||
,C_OSZTALYCSOPORTID
|
||||
) SELECT
|
||||
tr.C_TANEVID
|
||||
,tr.C_INTEZMENYID
|
||||
,tr.C_DATUM
|
||||
,tr.C_HETNAPJA
|
||||
,tr.C_HETIREND
|
||||
,tr.C_EGYEDINAP
|
||||
,ocstr.C_OSZTALYCSOPORTID
|
||||
FROM T_TANEVRENDJE_OSSZES tr
|
||||
INNER JOIN T_OSZTALYCSOPORT_TANEVRENDJE ocstr ON ocstr.C_TANEVRENDJEID = tr.ID
|
||||
WHERE tr.C_TANEVID = @pTanevId
|
||||
AND tr.TOROLT = ''F''
|
||||
AND tr.C_ORARENDINAP = ''T''
|
||||
AND tr.C_OSSZESCSOPORTRAVONATKOZIK = ''F''
|
||||
AND tr.C_DATUM BETWEEN @pIdoszakKezdete AND @pIdoszakVege
|
||||
' + IIF(@pOsztalycsoportId IS NULL, '', 'AND ocstr.C_OSZTALYCSOPORTID = @pOsztalycsoportId' )
|
||||
|
||||
SET @sql += N'
|
||||
CREATE TABLE #Orarend (
|
||||
Datum datetime
|
||||
,OrarendiOraId int
|
||||
,PRIMARY KEY CLUSTERED (OrarendioraId, Datum)
|
||||
);
|
||||
|
||||
--PRINT ''Napt<EFBFBD>rinapTemp insert''
|
||||
INSERT INTO #Orarend (
|
||||
Datum
|
||||
,OrarendiOraId
|
||||
)
|
||||
|
||||
SELECT nn.C_NAPDATUMA, oo.ID
|
||||
FROM #NaptariNap nn
|
||||
INNER JOIN T_ORARENDIORA_OSSZES oo ON oo.C_HETNAPJA = nn.C_HETNAPJA
|
||||
AND (oo.C_HETIREND = 1554 OR oo.C_HETIREND = nn.C_HETIREND)
|
||||
AND nn.C_EGYEDINAP = oo.C_EGYEDINAP
|
||||
AND oo.TOROLT=''F''
|
||||
AND oo.C_TANEVID = nn.C_TANEVID
|
||||
AND oo.C_INTEZMENYID = nn.C_INTEZMENYID
|
||||
AND oo.C_ORAERVENYESSEGKEZDETE <= nn.C_NAPDATUMA AND oo.C_ORAERVENYESSEGVEGE > nn.C_NAPDATUMA
|
||||
INNER JOIN #Osztalycsoport ocs ON ocs.Id = oo.C_OSZTALYCSOPORTID AND ocs.IdoszakVege >= nn.C_NAPDATUMA
|
||||
'+IIF(@pOrarendiOraId IS NULL AND @pOsztalyCsoportId IS NULL, '', 'INNER JOIN #OrarendiOra oo2 ON oo2.Id = oo.ID') + '
|
||||
WHERE NOT EXISTS (
|
||||
SELECT 1 FROM T_TANEVRENDJE_OSSZES tr2
|
||||
INNER JOIN T_OSZTALYCSOPORT_TANEVRENDJE ocstr ON tr2.ID = ocstr.C_TANEVRENDJEID
|
||||
WHERE tr2.C_OSSZESCSOPORTRAVONATKOZIK = ''F'' AND tr2.TOROLT = ''F''
|
||||
AND ocs.Id = ocstr.C_OSZTALYCSOPORTID AND nn.C_NAPDATUMA = tr2.C_DATUM)
|
||||
UNION ALL
|
||||
SELECT nn.C_NAPDATUMA, oo.ID
|
||||
FROM #NaptariNap nn
|
||||
INNER JOIN T_ORARENDIORA_OSSZES oo ON oo.C_HETNAPJA = nn.C_HETNAPJA
|
||||
AND (oo.C_HETIREND = 1554 OR oo.C_HETIREND = nn.C_HETIREND)
|
||||
AND nn.C_EGYEDINAP = oo.C_EGYEDINAP
|
||||
AND oo.TOROLT=''F''
|
||||
AND oo.C_TANEVID = nn.C_TANEVID
|
||||
AND oo.C_INTEZMENYID = nn.C_INTEZMENYID
|
||||
AND oo.C_ORAERVENYESSEGKEZDETE = nn.C_NAPDATUMA AND oo.C_ORAERVENYESSEGVEGE = nn.C_NAPDATUMA
|
||||
INNER JOIN #Osztalycsoport ocs ON ocs.Id = oo.C_OSZTALYCSOPORTID AND ocs.IdoszakVege >= nn.C_NAPDATUMA
|
||||
'+IIF(@pOrarendiOraId IS NULL AND @pOsztalyCsoportId IS NULL, '', 'INNER JOIN #OrarendiOra oo2 ON oo2.Id = oo.ID') + '
|
||||
WHERE NOT EXISTS (
|
||||
SELECT 1 FROM T_TANEVRENDJE_OSSZES tr2
|
||||
INNER JOIN T_OSZTALYCSOPORT_TANEVRENDJE ocstr ON tr2.ID = ocstr.C_TANEVRENDJEID
|
||||
WHERE tr2.C_OSSZESCSOPORTRAVONATKOZIK = ''F'' AND tr2.TOROLT = ''F''
|
||||
AND ocs.Id = ocstr.C_OSZTALYCSOPORTID AND nn.C_NAPDATUMA = tr2.C_DATUM)
|
||||
UNION ALL
|
||||
SELECT nn.C_NAPDATUMA, oo.ID
|
||||
FROM #NaptariNapOsztalycsoport nn
|
||||
INNER JOIN T_ORARENDIORA_OSSZES oo ON oo.C_HETNAPJA = nn.C_HETNAPJA
|
||||
AND (oo.C_HETIREND = 1554 OR oo.C_HETIREND = nn.C_HETIREND)
|
||||
AND nn.C_EGYEDINAP = oo.C_EGYEDINAP
|
||||
AND oo.TOROLT=''F''
|
||||
AND oo.C_TANEVID = nn.C_TANEVID
|
||||
AND oo.C_INTEZMENYID = nn.C_INTEZMENYID
|
||||
AND oo.C_ORAERVENYESSEGKEZDETE <= nn.C_NAPDATUMA AND oo.C_ORAERVENYESSEGVEGE > nn.C_NAPDATUMA
|
||||
AND oo.C_OSZTALYCSOPORTID = nn.C_OSZTALYCSOPORTID
|
||||
INNER JOIN #Osztalycsoport ocs ON ocs.Id = nn.C_OSZTALYCSOPORTID AND ocs.IdoszakVege >= nn.C_NAPDATUMA
|
||||
'+IIF(@pOrarendiOraId IS NULL AND @pOsztalyCsoportId IS NULL, '', 'INNER JOIN #OrarendiOra oo2 ON oo2.Id = oo.ID') + '
|
||||
UNION ALL
|
||||
SELECT nn.C_NAPDATUMA, oo.ID
|
||||
FROM #NaptariNapOsztalycsoport nn
|
||||
INNER JOIN T_ORARENDIORA_OSSZES oo ON oo.C_HETNAPJA = nn.C_HETNAPJA
|
||||
AND (oo.C_HETIREND = 1554 OR oo.C_HETIREND = nn.C_HETIREND)
|
||||
AND nn.C_EGYEDINAP = oo.C_EGYEDINAP
|
||||
AND oo.TOROLT=''F''
|
||||
AND oo.C_TANEVID = nn.C_TANEVID
|
||||
AND oo.C_INTEZMENYID = nn.C_INTEZMENYID
|
||||
AND oo.C_ORAERVENYESSEGKEZDETE = nn.C_NAPDATUMA AND oo.C_ORAERVENYESSEGVEGE = nn.C_NAPDATUMA
|
||||
AND oo.C_OSZTALYCSOPORTID = nn.C_OSZTALYCSOPORTID
|
||||
INNER JOIN #Osztalycsoport ocs ON ocs.Id = nn.C_OSZTALYCSOPORTID AND ocs.IdoszakVege >= nn.C_NAPDATUMA
|
||||
'+IIF(@pOrarendiOraId IS NULL AND @pOsztalyCsoportId IS NULL, '', 'INNER JOIN #OrarendiOra oo2 ON oo2.Id = oo.ID') + '
|
||||
'
|
||||
|
||||
SET @sql += N'
|
||||
--PRINT ''MERGE''
|
||||
MERGE T_ORAREND_OSSZES trg
|
||||
USING #Orarend src ON
|
||||
trg.C_ORARENDIORAID = src.OrarendioraId AND src.Datum = trg.C_DATUM
|
||||
WHEN NOT MATCHED BY TARGET THEN
|
||||
INSERT (
|
||||
C_ORARENDIORAID
|
||||
,C_DATUM
|
||||
,C_TANEVID
|
||||
,C_INTEZMENYID
|
||||
) VALUES (
|
||||
src.OrarendiOraId
|
||||
,src.Datum
|
||||
,@pTanevId
|
||||
,@pIntezmenyId
|
||||
)
|
||||
WHEN NOT MATCHED BY SOURCE AND trg.C_TANEVID = @pTanevId AND trg.C_DATUM BETWEEN @pIdoszakKezdete AND @pIdoszakVege
|
||||
' + IIF(@pOrarendiOraId IS NULL AND @pOsztalyCsoportId IS NULL, '', 'AND trg.C_ORARENDIORAID IN (SELECT Id FROM #OrarendiOra)') + '
|
||||
THEN
|
||||
DELETE
|
||||
--OUTPUT $action, DELETED.C_DATUM, DELETED.C_ORARENDIORAID, INSERTED.C_DATUM, INSERTED.C_ORARENDIORAID
|
||||
;'
|
||||
--select @sql
|
||||
EXEC sp_executesql @sql,N'
|
||||
@pIntezmenyId int
|
||||
,@pTanevId int
|
||||
,@pIdoszakKezdete datetime
|
||||
,@pIdoszakVege datetime
|
||||
,@pOrarendiOraId int
|
||||
,@pOsztalycsoportId int'
|
||||
,@pIntezmenyId = @pIntezmenyId
|
||||
,@pTanevId = @pTanevId
|
||||
,@pIdoszakKezdete = @pIdoszakKezdete
|
||||
,@pIdoszakVege = @pIdoszakVege
|
||||
,@pOrarendiOraId = @pOrarendiOraId
|
||||
,@pOsztalycsoportId = @pOsztalycsoportId
|
||||
END
|
||||
GO
|
||||
|
Reference in New Issue
Block a user