init
This commit is contained in:
@@ -0,0 +1,171 @@
|
||||
IF OBJECT_ID('[dbo].[fnGetLemorzsolodottTanulokByFelhely]') IS NOT NULL BEGIN
|
||||
DROP FUNCTION [dbo].[fnGetLemorzsolodottTanulokByFelhely]
|
||||
END
|
||||
GO
|
||||
|
||||
-- A Funkci<63> visszaadja a lemorzsol<6F>d<EFBFBD>s szempontj<74>b<EFBFBD>l relev<65>ns tanul<75>k list<73>j<EFBFBD>t az adott feladatell<6C>t<EFBFBD>si helyre, <20>vfolymaonk<6E>nt <20>s nemenk<6E>nt, valamint hogy
|
||||
CREATE FUNCTION [dbo].[fnGetLemorzsolodottTanulokByFelhely] (@feladatEllatasiHelyId INT, @tanevId INT, @isFelevi INT)
|
||||
RETURNS @retTable TABLE (
|
||||
TanuloId INT PRIMARY KEY,
|
||||
Evfolyam INT,
|
||||
Neme INT,
|
||||
TanuloNev nvarchar(max),
|
||||
OktatasiAzonosito nvarchar(max),
|
||||
TanuloOsztalyNev nvarchar(255),
|
||||
IsKozepesMiatt INT,
|
||||
IsRontasMiatt INT
|
||||
)
|
||||
BEGIN
|
||||
|
||||
-- Haszn<7A>lt temporary t<>bl<62>k elk<6C>sz<73>t<EFBFBD>se
|
||||
DECLARE @Evfolyamok TABLE
|
||||
(Id INT, Evfolyam INT)
|
||||
DECLARE @Osztalyzatok TABLE
|
||||
(Id INT, Ertek FLOAT)
|
||||
DECLARE @FHhozTartozoTanulok TABLE
|
||||
(TanuloId INT, Evfolyam INT, Neme INT, TanuloNev nvarchar(max), OktatasiAzonosito nvarchar(max), TanuloOsztalyNev nvarchar(255))
|
||||
DECLARE @TanuloAtlagok TABLE
|
||||
(TanuloId INT, AktualisAtlag FLOAT, KorabbiAtlag FLOAT)
|
||||
DECLARE @KozepesAlattiTanulok TABLE
|
||||
(TanuloId INT)
|
||||
DECLARE @RontottTanulok TABLE
|
||||
(TanuloId INT)
|
||||
|
||||
-- Mi a "K<>zepes" <20>rt<72>ke az adott feladatell<6C>t<EFBFBD>si helyen
|
||||
DECLARE @FelHelyTipusKozepes FLOAT = 3.0
|
||||
SELECT @FelHelyTipusKozepes =
|
||||
IIF(
|
||||
fh.C_OKTATASINEVELESIFELADATTIPUS IN (1160, 1161, 1162, 5435, 1176, 6463)
|
||||
, 2.5
|
||||
, 3.0
|
||||
)
|
||||
FROM T_FELADATELLATASIHELY fh
|
||||
WHERE fh.ID = @feladatEllatasiHelyId AND fh.TOROLT = 'F'
|
||||
|
||||
-- Az el<65>z<EFBFBD> tan<61>v ID-ja
|
||||
DECLARE @ElozoTanevId INT = 0
|
||||
SELECT @ElozoTanevId = ISNULL(elozotanev.ID,0)
|
||||
FROM T_TANEV_OSSZES akttanev
|
||||
INNER JOIN T_TANEV_OSSZES elozotanev ON elozotanev.C_INTEZMENYID = akttanev.C_INTEZMENYID AND elozotanev.TOROLT = 'F'
|
||||
WHERE akttanev.ID = @tanevId
|
||||
AND
|
||||
(
|
||||
(akttanev.C_NEV = '2017/2018' AND elozotanev.C_NEV = '2016/2017')
|
||||
OR
|
||||
(akttanev.C_NEV = '2018/2019' AND elozotanev.C_NEV = '2017/2018')
|
||||
OR
|
||||
(akttanev.C_NEV = '2019/2020' AND elozotanev.C_NEV = '2018/2019')
|
||||
OR
|
||||
(akttanev.C_NEV = '2020/2021' AND elozotanev.C_NEV = '2019/2020')
|
||||
OR
|
||||
(akttanev.C_NEV = '2021/2022' AND elozotanev.C_NEV = '2020/2021')
|
||||
OR
|
||||
(akttanev.C_NEV = '2022/2023' AND elozotanev.C_NEV = '2021/2022')
|
||||
)
|
||||
|
||||
DECLARE @BesorolasiDatum DATE = (SELECT TOP 1 C_DATUM from T_TANEVRENDJE tr WHERE C_NAPTIPUSA = IIF(@isFelevi = 0,1395,1400) AND C_TANEVID = @tanevid AND TOROLT='F')
|
||||
|
||||
INSERT INTO @Evfolyamok
|
||||
SELECT ID, Evfolyam FROM (SELECT DISTINCT id, CASE
|
||||
WHEN ID IN (1307,1330,1334) THEN 1307 /* 5. <20>vfolyam*/
|
||||
WHEN ID IN (1308) THEN 1308 /* 6. <20>vfolyam*/
|
||||
WHEN ID IN (1309,1331,1335,7109) THEN 1309 /* 7. <20>vfolyam*/
|
||||
WHEN ID IN (1310,1324,7110) THEN 1310 /* 8. <20>vfolyam*/
|
||||
WHEN ID IN (1311,1316,1332,1333,1336,3018,3019,3020,6702,7111, 7112, 7113, 7114, 7127, 7128)
|
||||
THEN 1311 /* 9. <20>vfolyam*/
|
||||
WHEN ID IN (1312,1323,6703,7115, 7116, 7117, 7118) THEN 1312 /* 10. <20>vfolyam*/
|
||||
WHEN ID IN (1313,1317,1325,3016,6704,7119, 7120, 7121, 7122) THEN 1313 /* 11. <20>vfolyam*/
|
||||
WHEN id in (1314,1318,1326,3017,3021,3022,1319,1322,6520,6705,6818,7123, 7124, 7125, 7126)
|
||||
THEN 1314 /* 12. <20>vfolyam*/
|
||||
WHEN ID IN (6471,6472,6473,6475) THEN 6471 /* KH 1. <20>vfolyam */
|
||||
WHEN ID IN (6474,6476) THEN 6474 /* KH 2. <20>vfolyam */
|
||||
WHEN ID IN (6477,6479,6481) THEN 6477 /* SzH 1. <20>vfolyam */
|
||||
WHEN ID IN (6478,6480,6482) THEN 6478 /* SzH 2. <20>vfolyam */
|
||||
ELSE NULL
|
||||
END AS Evfolyam
|
||||
FROM T_DICTIONARYITEMBASE
|
||||
WHERE C_TYPE = 'EvfolyamTipus' AND C_TANEVID = @tanevId) Evfolyamok
|
||||
WHERE Evfolyam IS NOT NULL
|
||||
|
||||
INSERT INTO @Osztalyzatok
|
||||
SELECT ID, CONVERT(FLOAT,C_VALUE)
|
||||
FROM T_DICTIONARYITEMBASE
|
||||
WHERE C_TYPE = 'OsztalyzatTipus' AND C_TANEVID = @tanevId
|
||||
|
||||
-- Egy adott FH-hoz tartoz<6F> tanul<75>k kilist<73>z<EFBFBD>sa (<28>vfolyamonk<6E>nt, nemenk<6E>nt)
|
||||
INSERT INTO @FHhozTartozoTanulok
|
||||
SELECT DISTINCT
|
||||
tcs.C_TANULOID,
|
||||
evf.Evfolyam,
|
||||
f.C_NEME,
|
||||
f.C_NYOMTATASINEV,
|
||||
f.C_OKTATASIAZONOSITO,
|
||||
ocs.C_NEV
|
||||
FROM T_OSZTALYCSOPORT ocs
|
||||
INNER JOIN T_TANULOCSOPORT tcs ON tcs.C_OSZTALYCSOPORTID = ocs.ID AND tcs.TOROLT = 'F' AND tcs.C_TANEVID = @tanevId
|
||||
AND tcs.C_BELEPESDATUM <= @BesorolasiDatum AND (tcs.C_KILEPESDATUM >= @BesorolasiDatum OR tcs.C_KILEPESDATUM IS NULL)
|
||||
INNER JOIN T_OSZTALY o ON o.id = tcs.C_OSZTALYCSOPORTID AND (o.C_KEPZESIFORMA IN (1096,5445) OR ocs.C_EVFOLYAMTIPUSA IN (6471,6472,6473,6475,6474,6476,6477,6479,6481,6478,6480,6482))
|
||||
INNER JOIN T_FELHASZNALO f ON f.id = tcs.C_TANULOID
|
||||
INNER JOIN @Evfolyamok evf ON evf.Id = ocs.C_EVFOLYAMTIPUSA
|
||||
WHERE
|
||||
ocs.C_FELADATELLATASIHELYID = @feladatEllatasiHelyId
|
||||
AND ocs.C_TANEVID = @tanevId
|
||||
|
||||
-- Visszat<61>r<EFBFBD>si t<>bla sz<73>m<EFBFBD>t<EFBFBD>sa
|
||||
|
||||
|
||||
INSERT INTO @KozepesAlattiTanulok (TanuloId)
|
||||
SELECT DISTINCT
|
||||
fht.TanuloId
|
||||
FROM T_TANULOERTEKELES te
|
||||
INNER JOIN T_TANTARGY tgy ON tgy.ID = te.C_TANTARGYID AND (tgy.C_FOTARGYE = 'T' OR tgy.C_ALTANTARGYKENTNYOMTATVANYBAN = 'T')
|
||||
INNER JOIN @Osztalyzatok o ON o.ID = te.C_ERTEKELESOSZTALYZATID
|
||||
INNER JOIN @FHhozTartozoTanulok fht ON fht.TanuloId = te.C_TANULOID
|
||||
WHERE
|
||||
te.C_TIPUSID = IIF(@isFelevi = 0,1520,1519)
|
||||
AND te.C_TANEVID = @tanevId
|
||||
GROUP BY fht.TanuloId
|
||||
HAVING ROUND(AVG(o.Ertek),1) < @FelHelyTipusKozepes
|
||||
|
||||
|
||||
INSERT INTO @TanuloAtlagok (TanuloId, AktualisAtlag, KorabbiAtlag)
|
||||
SELECT
|
||||
fht.TanuloId,
|
||||
(
|
||||
SELECT ROUND(AVG(o.Ertek),1) FROM T_TANULOERTEKELES te
|
||||
INNER JOIN @Osztalyzatok o ON o.ID = te.C_ERTEKELESOSZTALYZATID
|
||||
WHERE te.C_TANULOID = tanulo.ID AND te.C_TIPUSID = IIF(@isFelevi = 0,1520,1519)
|
||||
),
|
||||
(
|
||||
SELECT ROUND(AVG(o.Ertek),1) FROM T_TANULOERTEKELES_OSSZES te
|
||||
INNER JOIN @Osztalyzatok o ON o.ID = te.C_ERTEKELESOSZTALYZATID
|
||||
WHERE te.C_TANULOID = extanulo.ID AND te.C_TIPUSID = IIF(@isFelevi = 0,1519,1520) AND te.TOROLT = 'F'
|
||||
)
|
||||
FROM
|
||||
@FHhozTartozoTanulok fht
|
||||
INNER JOIN T_FELHASZNALO tanulo ON tanulo.ID = fht.TanuloId
|
||||
INNER JOIN T_FELHASZNALO_OSSZES extanulo ON tanulo.C_OKTATASIAZONOSITO = extanulo.C_OKTATASIAZONOSITO
|
||||
AND extanulo.C_TANEVID = IIF(@isFelevi = 0,@tanevId,@ElozoTanevId) AND extanulo.TOROLT = 'F'
|
||||
WHERE (
|
||||
(@isFelevi = 1 AND tanulo.ID <> extanulo.ID)
|
||||
OR
|
||||
(@isFelevi = 0 AND tanulo.ID = extanulo.ID)
|
||||
)
|
||||
|
||||
INSERT INTO @RontottTanulok (TanuloId)
|
||||
SELECT DISTINCT
|
||||
fht.TanuloId
|
||||
FROM @FHhozTartozoTanulok fht
|
||||
INNER JOIN @TanuloAtlagok ta ON ta.TanuloId = fht.TanuloId
|
||||
WHERE (ta.AktualisAtlag+1.1) <= ta.KorabbiAtlag
|
||||
|
||||
INSERT INTO @retTable (TanuloId, Evfolyam, Neme, TanuloNev, OktatasiAzonosito, TanuloOsztalyNev, IsKozepesMiatt, IsRontasMiatt)
|
||||
SELECT fht.TanuloId, fht.Evfolyam, fht.Neme, fht.TanuloNev, fht.OktatasiAzonosito, fht.TanuloOsztalyNev, IIF(kozepes.TanuloId IS NULL, 0, 1), IIF(rontott.TanuloId IS NULL, 0, 1)
|
||||
FROM @FHhozTartozoTanulok fht
|
||||
LEFT JOIN @KozepesAlattiTanulok kozepes ON kozepes.TanuloId = fht.TanuloId
|
||||
LEFT JOIN @RontottTanulok rontott ON rontott.TanuloId = fht.TanuloId
|
||||
WHERE (kozepes.TanuloId IS NOT NULL OR rontott.TanuloId IS NOT NULL)
|
||||
|
||||
RETURN
|
||||
END
|
||||
GO
|
Reference in New Issue
Block a user