131 lines
5.3 KiB
Transact-SQL
131 lines
5.3 KiB
Transact-SQL
DROP PROCEDURE IF EXISTS uspGetAtlag
|
|
GO
|
|
|
|
CREATE PROCEDURE uspGetAtlag
|
|
@pOsztalyCsoportId int
|
|
,@pTantargyId int
|
|
,@pAtlagMegjelenitesTipus int
|
|
,@pAtlagbaBeleszamitoOsztalyTipus int
|
|
,@pErtekelesTipusa int
|
|
,@pDatum datetime = NULL
|
|
,@pTanevId int
|
|
AS BEGIN
|
|
SET NOCOUNT ON;
|
|
|
|
IF @pDatum IS NULL
|
|
SET @pDatum = CONVERT(date, GETDATE())
|
|
|
|
IF (@pAtlagbaBeleszamitoOsztalyTipus = 1)
|
|
BEGIN
|
|
IF (@pAtlagMegjelenitesTipus = 1)
|
|
/* Összes jegy átlaga minden tanuló */
|
|
SELECT
|
|
te.C_TANTARGYID
|
|
,ROUND(SUM(CAST(d.C_VALUE AS float) * CAST(ISNULL(em.C_SULY, 100) AS float) / 100) / SUM(CAST(ISNULL(em.C_SULY, 100) AS float) / 100), 2) AS Atlag
|
|
FROM T_TANULOERTEKELES_OSSZES te
|
|
INNER JOIN T_DICTIONARYITEMBASE_OSSZES d ON d.ID = te.C_ERTEKELESOSZTALYZATID AND d.C_TANEVID = te.C_TANEVID AND d.TOROLT = 'F'
|
|
LEFT JOIN T_ERTEKELESMOD_OSSZES em ON em.ID = te.C_ERTEKELESMODID AND em.C_ALTANEVID = te.C_TANEVID AND em.TOROLT = 'F'
|
|
WHERE te.C_TANTARGYID = @pTantargyId
|
|
AND te.C_TIPUSID = @pErtekelesTipusa
|
|
AND te.C_ERTEKELESOSZTALYZATID IS NOT NULL
|
|
AND te.C_TANEVID = @pTanevId
|
|
AND te.TOROLT = 'F'
|
|
AND te.C_TANULOID IN
|
|
(SELECT C_TANULOID from T_TANULOCSOPORT_OSSZES tcs where tcs.C_OSZTALYCSOPORTID = @pOsztalyCsoportId
|
|
AND tcs.TOROLT = 'F'
|
|
AND C_TANEVID = @pTanevId
|
|
AND tcs.TOROLT = 'F')
|
|
GROUP BY
|
|
te.C_TANTARGYID
|
|
|
|
IF (@pAtlagMegjelenitesTipus = 2)
|
|
/* Átlagok átlaga minden tanuló */
|
|
SELECT
|
|
ertekeles.C_TANTARGYID
|
|
,ROUND(AVG(ertekeles.Atlag), 2) AS Atlag
|
|
FROM (
|
|
SELECT
|
|
te.C_TANTARGYID
|
|
,te.C_TANULOID
|
|
,ROUND(SUM(CAST(d.C_VALUE AS float) * CAST(ISNULL(em.C_SULY, 100) AS float) / 100) / SUM(CAST(ISNULL(em.C_SULY, 100) AS float) / 100), 2) AS Atlag
|
|
FROM T_TANULOERTEKELES_OSSZES te
|
|
INNER JOIN T_DICTIONARYITEMBASE_OSSZES d ON d.ID = te.C_ERTEKELESOSZTALYZATID AND d.C_TANEVID = te.C_TANEVID AND d.TOROLT = 'F'
|
|
LEFT JOIN T_ERTEKELESMOD_OSSZES em ON em.ID = te.C_ERTEKELESMODID AND em.C_ALTANEVID = te.C_TANEVID AND em.TOROLT = 'F'
|
|
WHERE te.C_TANTARGYID = @pTantargyId
|
|
AND te.C_TIPUSID = @pErtekelesTipusa
|
|
AND te.C_ERTEKELESOSZTALYZATID IS NOT NULL
|
|
AND te.C_TANEVID = @pTanevId
|
|
AND te.TOROLT = 'F'
|
|
AND te.C_TANULOID IN
|
|
(SELECT C_TANULOID from T_TANULOCSOPORT_OSSZES tcs where tcs.C_OSZTALYCSOPORTID = @pOsztalyCsoportId
|
|
AND tcs.TOROLT = 'F'
|
|
AND C_TANEVID = @pTanevId
|
|
AND tcs.TOROLT = 'F')
|
|
GROUP BY
|
|
te.C_TANTARGYID
|
|
,te.C_TANULOID
|
|
) ertekeles
|
|
GROUP BY
|
|
ertekeles.C_TANTARGYID
|
|
END
|
|
|
|
IF (@pAtlagbaBeleszamitoOsztalyTipus = 2)
|
|
BEGIN
|
|
IF (@pAtlagMegjelenitesTipus = 1)
|
|
/* Összes jegy átlaga minden tanulóra, aki az osztályban jelenleg van */
|
|
SELECT
|
|
te.C_TANTARGYID
|
|
,ROUND(SUM(CAST(d.C_VALUE AS float) * CAST(ISNULL(em.C_SULY, 100) AS float) / 100) / SUM(CAST(ISNULL(em.C_SULY, 100) AS float) / 100), 2) AS Atlag
|
|
FROM T_TANULOERTEKELES_OSSZES te
|
|
INNER JOIN T_DICTIONARYITEMBASE_OSSZES d ON d.ID = te.C_ERTEKELESOSZTALYZATID AND d.C_TANEVID = te.C_TANEVID AND d.TOROLT = 'F'
|
|
LEFT JOIN T_ERTEKELESMOD_OSSZES em ON em.ID = te.C_ERTEKELESMODID AND em.C_ALTANEVID = te.C_TANEVID AND em.TOROLT = 'F'
|
|
WHERE te.C_TANTARGYID = @pTantargyId
|
|
AND te.C_TIPUSID = @pErtekelesTipusa
|
|
AND te.C_ERTEKELESOSZTALYZATID IS NOT NULL
|
|
AND te.C_TANEVID = @pTanevId
|
|
AND te.TOROLT = 'F'
|
|
AND te.C_TANULOID IN
|
|
(SELECT C_TANULOID from T_TANULOCSOPORT_OSSZES tcs where tcs.C_OSZTALYCSOPORTID = @pOsztalyCsoportId
|
|
AND C_TANEVID = @pTanevId
|
|
AND tcs.TOROLT = 'F'
|
|
AND tcs.C_BELEPESDATUM <= @pDatum
|
|
AND (tcs.C_KILEPESDATUM > @pDatum OR tcs.C_KILEPESDATUM IS NULL))
|
|
GROUP BY
|
|
te.C_TANTARGYID
|
|
|
|
IF (@pAtlagMegjelenitesTipus = 2)
|
|
/* Átlagok átlaga minden tanulóra, aki az osztályban jelenleg van */
|
|
SELECT
|
|
ertekeles.C_TANTARGYID
|
|
,ROUND(AVG(ertekeles.Atlag), 2) AS Atlag
|
|
FROM (
|
|
SELECT
|
|
te.C_TANTARGYID
|
|
,te.C_TANULOID
|
|
,ROUND(SUM(CAST(d.C_VALUE AS float) * CAST(ISNULL(em.C_SULY, 100) AS float) / 100) / SUM(CAST(ISNULL(em.C_SULY, 100) AS float) / 100), 2) AS Atlag
|
|
FROM T_TANULOERTEKELES_OSSZES te
|
|
INNER JOIN T_DICTIONARYITEMBASE_OSSZES d ON d.ID = te.C_ERTEKELESOSZTALYZATID AND d.C_TANEVID = te.C_TANEVID AND d.TOROLT = 'F'
|
|
LEFT JOIN T_ERTEKELESMOD_OSSZES em ON em.ID = te.C_ERTEKELESMODID AND em.C_ALTANEVID = te.C_TANEVID AND em.TOROLT = 'F'
|
|
WHERE te.C_TANTARGYID = @pTantargyId
|
|
AND te.C_TIPUSID = @pErtekelesTipusa
|
|
AND te.C_ERTEKELESOSZTALYZATID IS NOT NULL
|
|
AND te.C_TANEVID = @pTanevId
|
|
AND te.TOROLT = 'F'
|
|
AND te.C_TANULOID IN
|
|
(SELECT C_TANULOID from T_TANULOCSOPORT_OSSZES tcs where tcs.C_OSZTALYCSOPORTID = @pOsztalyCsoportId
|
|
AND C_TANEVID = @pTanevId
|
|
AND tcs.TOROLT = 'F'
|
|
AND tcs.C_BELEPESDATUM <= @pDatum
|
|
AND (tcs.C_KILEPESDATUM > @pDatum OR tcs.C_KILEPESDATUM IS NULL))
|
|
GROUP BY
|
|
te.C_TANTARGYID
|
|
,te.C_TANULOID
|
|
) ertekeles
|
|
GROUP BY
|
|
ertekeles.C_TANTARGYID
|
|
END
|
|
|
|
END
|
|
|
|
GO
|
|
|