92 lines
No EOL
3.3 KiB
Transact-SQL
92 lines
No EOL
3.3 KiB
Transact-SQL
DROP PROCEDURE IF EXISTS dbo.uspGetEbedNormativaRiport
|
|
GO
|
|
CREATE PROCEDURE dbo.uspGetEbedNormativaRiport
|
|
@pTanevId int
|
|
,@pTanevElsoNapja date
|
|
,@pTanevUtolsoNapja date
|
|
,@pOraszam int
|
|
,@pIsAmiHianyzasIsMegjelenjen bit
|
|
AS
|
|
BEGIN
|
|
SET NOCOUNT ON;
|
|
|
|
DROP TABLE IF EXISTS #TanuloCsoport;
|
|
CREATE TABLE #TanuloCsoport(
|
|
C_NAP DATETIME NOT NULL
|
|
,C_TANULOID INT NOT NULL
|
|
,C_OSZTALYCSOPORTID INT NOT NULL
|
|
,C_HIANYZOTT INT NOT NULL
|
|
,PRIMARY KEY CLUSTERED (C_NAP, C_TANULOID, C_OSZTALYCSOPORTID)
|
|
);
|
|
CREATE NONCLUSTERED INDEX [IX_Tanulocsoport_OCSID] ON #TanuloCsoport (C_OSZTALYCSOPORTID)
|
|
INCLUDE (C_NAP, C_TANULOID, C_HIANYZOTT);
|
|
|
|
WITH CTE AS
|
|
(
|
|
SELECT
|
|
nn.C_NAPDATUMA AS date
|
|
,tcs.C_TANULOID AS fid
|
|
,tcs.C_OSZTALYCSOPORTID AS ocsid
|
|
,ROW_NUMBER() OVER (
|
|
PARTITION BY nn.ID, tcs.C_TANULOID, tcs.C_OSZTALYCSOPORTID
|
|
ORDER BY tcs.C_TANULOID
|
|
) AS cnt
|
|
FROM
|
|
T_NAPTARINAP_OSSZES nn
|
|
INNER JOIN T_TANULOCSOPORT_OSSZES AS tcs ON tcs.TOROLT = 'F' AND tcs.C_TANEVID = nn.C_TANEVID AND nn.C_NAPDATUMA BETWEEN C_BELEPESDATUM AND ISNULL(C_KILEPESDATUM, @pTanevUtolsoNapja)
|
|
INNER JOIN T_OSZTALYCSOPORT_OSSZES AS ocs ON ocs.TOROLT = 'F' AND ocs.ID = tcs.C_OSZTALYCSOPORTID AND ocs.C_TANEVID = nn.C_TANEVID
|
|
INNER JOIN T_OSZTALY_OSSZES AS o ON o.TOROLT = 'F' AND o.ID = ocs.ID AND o.C_ALTANEVID = ocs.C_TANEVID
|
|
WHERE
|
|
nn.TOROLT = 'F'
|
|
AND nn.C_TANEVID = @pTanevId
|
|
AND nn.C_HETNAPJA BETWEEN 1408 AND 1412
|
|
AND C_NAPDATUMA BETWEEN @pTanevElsoNapja AND @pTanevUtolsoNapja
|
|
AND ocs.C_FELADATKATEGORIAID != IIF(@pIsAmiHianyzasIsMegjelenjen = 0, 7555, -1)
|
|
)
|
|
INSERT INTO #TanuloCsoport(C_NAP, C_TANULOID, C_OSZTALYCSOPORTID, C_HIANYZOTT)
|
|
SELECT
|
|
CTE.date
|
|
,CTE.fid
|
|
,CTE.ocsid
|
|
,0 AS C_HIANYZOTT
|
|
FROM CTE
|
|
WHERE CTE.cnt = 1;
|
|
|
|
UPDATE tcs
|
|
SET C_HIANYZOTT = 1
|
|
FROM #TanuloCsoport AS tcs
|
|
INNER JOIN T_TANITASIORA_OSSZES AS tao ON tao.TOROLT = 'F' AND tao.C_TANEVID = @pTanevId AND tao.C_DATUM = tcs.C_NAP AND tao.C_ORASZAM >= @pOraszam
|
|
INNER JOIN T_OSZTALYCSOPORT_OSSZES AS ocs ON ocs.TOROLT = 'F' AND ocs.ID = tcs.C_OSZTALYCSOPORTID AND ocs.C_TANEVID = tao.C_TANEVID AND tao.C_OSZTALYCSOPORTID = tcs.C_OSZTALYCSOPORTID AND ocs.C_FELADATKATEGORIAID != IIF(@pIsAmiHianyzasIsMegjelenjen = 0, 7555, -1)
|
|
WHERE EXISTS (
|
|
SELECT TOP 1 1
|
|
FROM T_TANULOMULASZTAS_OSSZES AS tm
|
|
WHERE
|
|
tm.TOROLT = 'F'
|
|
AND tm.C_TANITASIORAKID = tao.ID
|
|
AND tm.C_ORATANULOIID = tcs.C_TANULOID
|
|
AND tm.C_INTEZMENYID = tao.C_INTEZMENYID
|
|
AND tm.C_TANEVID = tao.C_TANEVID
|
|
AND tm.C_TIPUS != 1499
|
|
);
|
|
|
|
SELECT
|
|
f.C_OKTATASIAZONOSITO AS OktatasiAzonosito
|
|
,f.C_NYOMTATASINEV AS TanuloNev
|
|
,FORMAT(tcs.C_NAP, 'yyyy.MM.dd.') AS NapDatuma
|
|
,ocs.C_NEV AS OsztalyNev
|
|
,tcs.C_HIANYZOTT AS Hianyzott
|
|
FROM #TanuloCsoport tcs
|
|
INNER JOIN T_FELHASZNALO_OSSZES AS f ON f.TOROLT = 'F' AND f.ID = tcs.C_TANULOID AND f.C_TANEVID = @pTanevId
|
|
INNER JOIN T_OSZTALYCSOPORT_OSSZES AS ocs ON ocs.TOROLT = 'F' AND ocs.ID = tcs.C_OSZTALYCSOPORTID AND ocs.C_TANEVID = @pTanevId
|
|
WHERE EXISTS (
|
|
SELECT TOP 1 1
|
|
FROM T_TANITASIORA_OSSZES AS tao
|
|
WHERE
|
|
tao.TOROLT = 'F'
|
|
AND tao.C_TANEVID = @pTanevId
|
|
AND tao.C_DATUM = tcs.C_NAP
|
|
AND tao.C_ORASZAM >= @pOraszam
|
|
)
|
|
ORDER BY tcs.C_NAP, C_NYOMTATASINEV;
|
|
END
|
|
GO |