kreta/Kreta.DataAccess.Migrations/DBScripts/Database/dbo/Stored procedures/sp_GetHelyettesitesiNaplo.sql
2024-03-13 00:33:46 +01:00

275 lines
No EOL
16 KiB
Transact-SQL

DROP PROCEDURE IF EXISTS dbo.sp_GetHelyettesitesiNaplo
GO
-- ===================================================================
-- Author: Tóth Imre Attila
-- Create date: 2016. 08. 01.
-- Description: Lekérdezések a helyettesítési naplóhoz
-- ===================================================================
CREATE PROCEDURE [dbo].[sp_GetHelyettesitesiNaplo]
@tanarID int,
@tanevID int,
@intezmenyid int,
@bontas int = 0, -- 0 = havi, 1 = heti
@startDayOfWeek int = 1 -- 1 = Hétfő, 7 = Vasárnap
AS
BEGIN
SET NOCOUNT ON;
SET DATEFIRST @startDayOfWeek
-- ===================================
-- FEJLÉC
-- ===================================
DECLARE @table TABLE (
EvHonap nvarchar(7),
Helyettesito nvarchar(100)
,HelyettesitoId int
,FeladatEllatasiHelyId INT
)
INSERT INTO @table
SELECT DISTINCT
CASE
WHEN @bontas = 0 THEN FORMAT(C_DATUM, 'yyyy.MM')
WHEN @bontas = 1 THEN CAST(C_HETSORSZAMA AS nvarchar)
END AS EvHonap,
felhHelyettes.C_NYOMTATASINEV AS Helyettesito
,felhHelyettes.ID AS HelyettesitoId
,mua.C_FELADATELLATASIHELYID AS FeladatEllatasiHelyId
FROM T_TANITASIORA_OSSZES tOra
LEFT JOIN T_FELHASZNALO_OSSZES felhHelyettes on felhHelyettes.ID = tOra.C_HELYETTESITOTANARID
LEFT JOIN T_MUNKAUGYIADATOK_OSSZES mua ON mua.C_ALKALMAZOTTID = tOra.C_HELYETTESITOTANARID
WHERE tOra.C_HELYETTESITOTANARID = @tanarID
AND tOra.C_TANEVID = @tanevID
AND tOra.Torolt='F'
SELECT * FROM @table
SELECT DISTINCT
CASE
WHEN @bontas = 0 THEN FORMAT(C_NAPDATUMA, 'yyyy.MM')
WHEN @bontas = 1 THEN CAST(C_HETSORSZAMA AS nvarchar)
END AS EvHonap,
C_ALAPHETNAPJA AS Nap
,@tanarID AS HelyettesitoId
,C_NAPDATUMA
FROM T_NAPTARINAP_OSSZES AS nn
INNER JOIN @table AS eh ON CASE
WHEN @bontas = 0 THEN FORMAT(nn.C_NAPDATUMA, 'yyyy.MM')
WHEN @bontas = 1 THEN CAST(C_HETSORSZAMA AS nvarchar)
END = eh.EvHonap
WHERE nn.C_TANEVID = @tanevID AND nn.C_INTEZMENYID = @intezmenyid AND nn.TOROLT = 'F'
ORDER BY C_NAPDATUMA
-- ===================================
-- HELYETTESÍTÉSEK (SOROK)
-- ===================================
SELECT DISTINCT
C_DATUM
,CAST(IIF(tOra.C_PARHUZAMOSORA = 'T', NULL, ROW_NUMBER() OVER(PARTITION BY tOra.C_PARHUZAMOSORA ORDER BY C_DATUM)) as nvarchar(5)) + '.' AS Sorsz
,IIF(tOra.C_ORASZAM IS NOT NULL,CONVERT(NVARCHAR(5), tOra.C_ORASZAM) + '.',
CONCAT(CONVERT(NVARCHAR(5), tOra.C_ORAKEZDETE, 108), '-', CONVERT(NVARCHAR(5), tOra.C_ORAVEGE, 108))) AS Oraszam
,DicItemBase.C_NAME AS HelyettesitesTipusa
,FORMAT(C_DATUM, 'yyyy.MM.dd.') AS Datum
,CASE
WHEN @bontas = 0 THEN FORMAT(C_DATUM, 'yyyy.MM')
WHEN @bontas = 1 THEN CAST(C_HETSORSZAMA AS nvarchar)
END AS EvHonap
,felhOraTul.C_NYOMTATASINEV AS Helyettesitett
,osztcsop.C_NEV AS OsztalyCsoport
,tant.C_NEV AS Tantargy
,tOra.C_TEMA AS Tema
,tOra.C_ORAEVESSORSZAMA AS EvesSorszam
,helyettesito.ID AS HelyettesitoId
,helyettesito.C_OKTATASIAZONOSITO AS HelyettesitoOktatasiAzon
,tOra.C_HELYETTESITESOKA AS HelyettesitesOka
FROM T_TANITASIORA_OSSZES tOra
LEFT JOIN T_ORARENDIORA_OSSZES oo ON oo.ID = tOra.C_ORARENDIORAID
LEFT JOIN T_FELHASZNALO_OSSZES felhOraTul ON felhOraTul.ID = tOra.C_TANARID
LEFT JOIN T_FELHASZNALO_OSSZES helyettesito ON helyettesito.ID = tOra.C_HELYETTESITOTANARID
LEFT JOIN T_DICTIONARYITEMBASE_OSSZES DicItemBase ON DicItemBase.ID = tOra.C_HELYETTESITESTIPUSA AND DicItemBase.C_TANEVID = tOra.C_TANEVID AND DicItemBase.TOROLT = 'F'
LEFT JOIN T_OSZTALYCSOPORT_OSSZES osztcsop ON osztcsop.ID = tOra.C_OSZTALYCSOPORTID
LEFT JOIN T_TANTARGY_OSSZES tant ON tant.ID = tOra.C_TANTARGYID
WHERE helyettesito.ID = @tanarID
AND tOra.C_TANEVID = @tanevID
AND tOra.Torolt = 'F'
AND tOra.C_HELYETTESITESTIPUSA IN (1496, 1495, 1494, 7367)
-- ===================================
-- HELYETTESÍTÉSEK NAPIBONTÁSBAN
-- ===================================
CREATE TABLE #Helyettesitesek (
EvHonap nvarchar(15)
,OsztalyCsoport nvarchar(550),
[1] nvarchar(5) , [2] nvarchar(5), [3] nvarchar(5), [4] nvarchar(5), [5] nvarchar(5), [6] nvarchar(5), [7] nvarchar(5), [8] nvarchar(5), [9] nvarchar(5), [10] nvarchar(5),
[11] nvarchar(5), [12] nvarchar(5), [13] nvarchar(5), [14] nvarchar(5), [15] nvarchar(5), [16] nvarchar(5), [17] nvarchar(5), [18] nvarchar(5), [19] nvarchar(5), [20] nvarchar(5),
[21] nvarchar(5), [22] nvarchar(5), [23] nvarchar(5), [24] nvarchar(5), [25] nvarchar(5), [26] nvarchar(5), [27] nvarchar(5), [28] nvarchar(5), [29] nvarchar(5), [30] nvarchar(5), [31] nvarchar(5)
,Ossz int, HelyettesitoId int)
CREATE TABLE #HelyettesitesekParhuzamosOra (
EvHonap nvarchar(15)
,OsztalyCsoport nvarchar(550),
[1] nvarchar(5) , [2] nvarchar(5), [3] nvarchar(5), [4] nvarchar(5), [5] nvarchar(5), [6] nvarchar(5), [7] nvarchar(5), [8] nvarchar(5), [9] nvarchar(5), [10] nvarchar(5),
[11] nvarchar(5), [12] nvarchar(5), [13] nvarchar(5), [14] nvarchar(5), [15] nvarchar(5), [16] nvarchar(5), [17] nvarchar(5), [18] nvarchar(5), [19] nvarchar(5), [20] nvarchar(5),
[21] nvarchar(5), [22] nvarchar(5), [23] nvarchar(5), [24] nvarchar(5), [25] nvarchar(5), [26] nvarchar(5), [27] nvarchar(5), [28] nvarchar(5), [29] nvarchar(5), [30] nvarchar(5), [31] nvarchar(5)
,HelyettesitoId int)
INSERT INTO #Helyettesitesek
SELECT
EvHonap
,OsztalyCsoport = TantargyN + ' - ' + OsztCsopN,
ISNULL([1], 0) AS [1], ISNULL([2], 0) AS [2], ISNULL([3], 0) AS [3], ISNULL([4], 0) AS [4], ISNULL([5], 0) AS [5], ISNULL([6], 0) AS [6], ISNULL([7], 0) AS [7], ISNULL([8], 0) AS [8], ISNULL([9], 0) AS [9], ISNULL([10], 0) AS [10],
ISNULL([11], 0) AS [11], ISNULL([12], 0) AS [12], ISNULL([13], 0) AS [13], ISNULL([14], 0) AS [14], ISNULL([15], 0) AS [15], ISNULL([16], 0) AS [16], ISNULL([17], 0) AS [17], ISNULL([18], 0) AS [18], ISNULL([19], 0) AS [19], ISNULL([20], 0) AS [20],
ISNULL([21], 0) AS [21], ISNULL([22], 0) AS [22], ISNULL([23], 0) AS [23], ISNULL([24], 0) AS [24], ISNULL([25], 0) AS [25], ISNULL([26], 0) AS [26], ISNULL([27], 0) AS [27], ISNULL([28], 0) AS [28], ISNULL([29], 0) AS [29], ISNULL([30], 0) AS [30],
ISNULL([31], 0) AS [31],
ISNULL([1], 0) + ISNULL([2], 0) + ISNULL([3], 0) + ISNULL([4], 0) + ISNULL([5], 0) + ISNULL([6], 0) + ISNULL([7], 0) + ISNULL([8], 0) + ISNULL([9], 0) + ISNULL([10], 0) +
ISNULL([11], 0) + ISNULL([12], 0) + ISNULL([13], 0) + ISNULL([14], 0) + ISNULL([15], 0) + ISNULL([16], 0) + ISNULL([17], 0) + ISNULL([18], 0) + ISNULL([19], 0) + ISNULL([20], 0) +
ISNULL([21], 0) + ISNULL([22], 0) + ISNULL([23], 0) + ISNULL([24], 0) + ISNULL([25], 0) + ISNULL([26], 0) + ISNULL([27], 0) + ISNULL([28], 0) + ISNULL([29], 0) + ISNULL([30], 0) +
ISNULL([31], 0) AS Ossz
,HelyettesitoId
FROM (
SELECT
SUM(IIF(tOra.c_helyettesitestipusa IN(1496, 1495, 1494, 7367) AND tOra.C_PARHUZAMOSORA = 'F', 1 , 0)) as Tant,
osztCsop.C_NEV AS osztcsopN,
tant.C_NEV AS TantargyN,
CASE
WHEN @bontas = 0 THEN DATEPART(DAY, C_DATUM)
WHEN @bontas = 1 THEN DATEPART(dw, C_DATUM)
END AS Nap,
CASE
WHEN @bontas = 0 THEN FORMAT(C_DATUM, 'yyyy.MM')
WHEN @bontas = 1 THEN CAST(nn.C_HETSORSZAMA AS nvarchar)
END AS EvHonap
,tOra.C_HELYETTESITOTANARID AS HelyettesitoId
FROM T_TANITASIORA_OSSZES tOra
INNER JOIN T_TANTARGY_OSSZES tant on tant.ID = tOra.C_TANTARGYID
INNER JOIN T_OSZTALYCSOPORT_OSSZES osztCsop on osztCsop.ID = tOra.C_OSZTALYCSOPORTID
INNER JOIN T_NAPTARINAP_OSSZES nn ON nn.C_NAPDATUMA = tOra.C_DATUM AND nn.C_TANEVID = @tanevID AND nn.C_INTEZMENYID = @intezmenyid AND nn.TOROLT = 'F'
WHERE
tOra.C_HELYETTESITOTANARID = @tanarID
AND tOra.C_TANEVID = @tanevID
AND TOra.TOROLT='F'
GROUP BY
osztCsop.C_NEV, tant.C_NEV, C_DATUM, nn.C_HETSORSZAMA, tOra.c_helyettesitestipusa
, tOra.C_HELYETTESITOTANARID, C_PARHUZAMOSORA
) T
PIVOT (
MAX(Tant)
FOR Nap IN (
[1], [2], [3], [4], [5], [6], [7], [8], [9], [10],
[11], [12], [13], [14], [15], [16], [17], [18], [19], [20],
[21], [22], [23], [24], [25], [26], [27], [28], [29], [30], [31]
)
) Helyettesitesek
INSERT INTO #HelyettesitesekParhuzamosOra
SELECT
EvHonap
,OsztalyCsoport = TantargyN + ' - ' + OsztCsopN,
ISNULL([1], 0) AS [1], ISNULL([2], 0) AS [2], ISNULL([3], 0) AS [3], ISNULL([4], 0) AS [4], ISNULL([5], 0) AS [5], ISNULL([6], 0) AS [6], ISNULL([7], 0) AS [7], ISNULL([8], 0) AS [8], ISNULL([9], 0) AS [9], ISNULL([10], 0) AS [10],
ISNULL([11], 0) AS [11], ISNULL([12], 0) AS [12], ISNULL([13], 0) AS [13], ISNULL([14], 0) AS [14], ISNULL([15], 0) AS [15], ISNULL([16], 0) AS [16], ISNULL([17], 0) AS [17], ISNULL([18], 0) AS [18], ISNULL([19], 0) AS [19], ISNULL([20], 0) AS [20],
ISNULL([21], 0) AS [21], ISNULL([22], 0) AS [22], ISNULL([23], 0) AS [23], ISNULL([24], 0) AS [24], ISNULL([25], 0) AS [25], ISNULL([26], 0) AS [26], ISNULL([27], 0) AS [27], ISNULL([28], 0) AS [28], ISNULL([29], 0) AS [29], ISNULL([30], 0) AS [30],
ISNULL([31], 0) AS [31]
,HelyettesitoId
FROM (
SELECT
SUM(IIF(tOra.c_helyettesitestipusa IN(1496, 1495, 1494, 7367) AND tOra.C_PARHUZAMOSORA = 'T', 1 , 0)) as Tant,
osztCsop.C_NEV AS osztcsopN,
tant.C_NEV AS TantargyN,
CASE
WHEN @bontas = 0 THEN DATEPART(DAY, C_DATUM)
WHEN @bontas = 1 THEN DATEPART(dw, C_DATUM)
END AS Nap,
CASE
WHEN @bontas = 0 THEN FORMAT(C_DATUM, 'yyyy.MM')
WHEN @bontas = 1 THEN CAST(nn.C_HETSORSZAMA AS nvarchar)
END AS EvHonap
,tOra.C_HELYETTESITOTANARID AS HelyettesitoId
FROM T_TANITASIORA_OSSZES tOra
INNER JOIN T_TANTARGY_OSSZES tant on tant.ID = tOra.C_TANTARGYID
INNER JOIN T_OSZTALYCSOPORT_OSSZES osztCsop on osztCsop.ID = tOra.C_OSZTALYCSOPORTID
INNER JOIN T_NAPTARINAP_OSSZES nn ON nn.C_NAPDATUMA = tOra.C_DATUM AND nn.C_TANEVID = @tanevID AND nn.C_INTEZMENYID = @intezmenyid AND nn.TOROLT = 'F'
WHERE
tOra.C_HELYETTESITOTANARID = @tanarID
AND tOra.C_TANEVID = @tanevID
AND TOra.TOROLT='F'
GROUP BY
osztCsop.C_NEV, tant.C_NEV, C_DATUM, nn.C_HETSORSZAMA, tOra.c_helyettesitestipusa
, tOra.C_HELYETTESITOTANARID, C_PARHUZAMOSORA
) T
PIVOT (
max(Tant)
FOR Nap IN (
[1], [2], [3], [4], [5], [6], [7], [8], [9], [10],
[11], [12], [13], [14], [15], [16], [17], [18], [19], [20],
[21], [22], [23], [24], [25], [26], [27], [28], [29], [30], [31]
)
) Helyettesitesek
CREATE TABLE #Ossz (
EvHonap nvarchar(15)
,Összesen nvarchar(20),
[1] int , [2] int, [3] int, [4] int, [5] int, [6] int, [7] int, [8] int, [9] int, [10] int,
[11] int, [12] int, [13] int, [14] int, [15] int, [16] int, [17] int, [18] int, [19] int, [20] int,
[21] int, [22] int, [23] int, [24] int, [25] int, [26] int, [27] int, [28] int, [29] int, [30] int, [31] int
,Ossz int, HelyettesitoId int)
INSERT INTO #Ossz
SELECT EvHonap, 'Összesen',
SUM(CAST([1] as int)), SUM(CAST([2] as int)), SUM(CAST([3] as int)), SUM(CAST([4] as int)), SUM(CAST([5] as int)), SUM(CAST([6] as int)), SUM(CAST([7] as int)), SUM(CAST([8] as int)), SUM(CAST([9] as int)), SUM(CAST([10] as int)),
SUM(CAST([11] as int)), SUM(CAST([12] as int)), SUM(CAST([13] as int)), SUM(CAST([14] as int)), SUM(CAST([15] as int)), SUM(CAST([16] as int)), SUM(CAST([17] as int)), SUM(CAST([18] as int)), SUM(CAST([19] as int)), SUM(CAST([20] as int)),
SUM(CAST([21] as int)), SUM(CAST([22] as int)), SUM(CAST([23] as int)), SUM(CAST([24] as int)), SUM(CAST([25] as int)), SUM(CAST([26] as int)), SUM(CAST([27] as int)), SUM(CAST([28] as int)), SUM(CAST([29] as int)), SUM(CAST([30] as int)), SUM(CAST([31] as int))
,(SUM(CAST([1] as int)) + SUM(CAST([2] as int)) + SUM(CAST([3] as int)) + SUM(CAST([4] as int)) + SUM(CAST([5] as int)) + SUM(CAST([6] as int)) + SUM(CAST([7] as int)) + SUM(CAST([8] as int)) + SUM(CAST([9] as int)) + SUM(CAST([10] as int)) +
SUM(CAST([11] as int)) + SUM(CAST([12] as int)) + SUM(CAST([13] as int)) + SUM(CAST([14] as int)) + SUM(CAST([15] as int)) + SUM(CAST([16] as int)) + SUM(CAST([17] as int)) + SUM(CAST([18] as int)) + SUM(CAST([19] as int)) + SUM(CAST([20] as int)) +
SUM(CAST([21] as int)) + SUM(CAST([22] as int)) + SUM(CAST([23] as int)) + SUM(CAST([24] as int)) + SUM(CAST([25] as int)) + SUM(CAST([26] as int)) + SUM(CAST([27] as int)) + SUM(CAST([28] as int)) + SUM(CAST([29] as int)) + SUM(CAST([30] as int)) + SUM(CAST([31] as int))) AS [Ossz]
,HelyettesitoId
FROM #Helyettesitesek
GROUP BY EvHonap, HelyettesitoId
UPDATE h1 SET
[1] += CASE WHEN h2.[1] > 0 THEN ' ('+ h2.[1] + ')' ELSE '' END
,[2] += CASE WHEN h2.[2] > 0 THEN ' ('+ h2.[2] + ')' ELSE '' END
,[3] += CASE WHEN h2.[3] > 0 THEN ' ('+ h2.[3] + ')' ELSE '' END
,[4] += CASE WHEN h2.[4] > 0 THEN ' ('+ h2.[4] + ')' ELSE '' END
,[5] += CASE WHEN h2.[5] > 0 THEN ' ('+ h2.[5] + ')' ELSE '' END
,[6] += CASE WHEN h2.[6] > 0 THEN ' ('+ h2.[6] + ')' ELSE '' END
,[7] += CASE WHEN h2.[7] > 0 THEN ' ('+ h2.[7] + ')' ELSE '' END
,[8] += CASE WHEN h2.[8] > 0 THEN ' ('+ h2.[8] + ')' ELSE '' END
,[9] += CASE WHEN h2.[9] > 0 THEN ' ('+ h2.[9] + ')' ELSE '' END
,[10] += CASE WHEN h2.[10] > 0 THEN ' ('+ h2.[10] + ')' ELSE '' END
,[11] += CASE WHEN h2.[11] > 0 THEN ' ('+ h2.[11] + ')' ELSE '' END
,[12] += CASE WHEN h2.[12] > 0 THEN ' ('+ h2.[12] + ')' ELSE '' END
,[13] += CASE WHEN h2.[13] > 0 THEN ' ('+ h2.[13] + ')' ELSE '' END
,[14] += CASE WHEN h2.[14] > 0 THEN ' ('+ h2.[14] + ')' ELSE '' END
,[15] += CASE WHEN h2.[15] > 0 THEN ' ('+ h2.[15] + ')' ELSE '' END
,[16] += CASE WHEN h2.[16] > 0 THEN ' ('+ h2.[16] + ')' ELSE '' END
,[17] += CASE WHEN h2.[17] > 0 THEN ' ('+ h2.[17] + ')' ELSE '' END
,[18] += CASE WHEN h2.[18] > 0 THEN ' ('+ h2.[18] + ')' ELSE '' END
,[19] += CASE WHEN h2.[19] > 0 THEN ' ('+ h2.[19] + ')' ELSE '' END
,[20] += CASE WHEN h2.[20] > 0 THEN ' ('+ h2.[20] + ')' ELSE '' END
,[21] += CASE WHEN h2.[21] > 0 THEN ' ('+ h2.[21] + ')' ELSE '' END
,[22] += CASE WHEN h2.[22] > 0 THEN ' ('+ h2.[22] + ')' ELSE '' END
,[23] += CASE WHEN h2.[23] > 0 THEN ' ('+ h2.[23] + ')' ELSE '' END
,[24] += CASE WHEN h2.[24] > 0 THEN ' ('+ h2.[24] + ')' ELSE '' END
,[25] += CASE WHEN h2.[25] > 0 THEN ' ('+ h2.[25] + ')' ELSE '' END
,[26] += CASE WHEN h2.[26] > 0 THEN ' ('+ h2.[26] + ')' ELSE '' END
,[27] += CASE WHEN h2.[27] > 0 THEN ' ('+ h2.[27] + ')' ELSE '' END
,[28] += CASE WHEN h2.[28] > 0 THEN ' ('+ h2.[28] + ')' ELSE '' END
,[29] += CASE WHEN h2.[29] > 0 THEN ' ('+ h2.[29] + ')' ELSE '' END
,[30] += CASE WHEN h2.[30] > 0 THEN ' ('+ h2.[30] + ')' ELSE '' END
,[31] += CASE WHEN h2.[31] > 0 THEN ' ('+ h2.[31] + ')' ELSE '' END
FROM #Helyettesitesek h1
INNER JOIN #HelyettesitesekParhuzamosOra h2 on
h1.EvHonap = h2.EvHonap
AND h1.HelyettesitoId = h2.HelyettesitoId
AND h1.OsztalyCsoport = h2.OsztalyCsoport
--Helyettesítések párhuzamosan helyettesített órákkal
SELECT * FROM #Helyettesitesek
--Havi/Heti összesen helyettesített órák száma
SELECT * FROM #Ossz
DROP TABLE #Helyettesitesek
DROP TABLE #HelyettesitesekParhuzamosOra
DROP TABLE #Ossz
END
GO