163 lines
No EOL
8 KiB
Transact-SQL
163 lines
No EOL
8 KiB
Transact-SQL
DROP PROCEDURE IF EXISTS dbo.uspSzirStatIntezmeny
|
|
GO
|
|
|
|
CREATE PROCEDURE dbo.uspSzirStatIntezmeny
|
|
@pTanevId int
|
|
,@pIntezmenyid int
|
|
AS BEGIN
|
|
DECLARE @datum datetime, @IsSniKezelo bit
|
|
|
|
SELECT @datum = LEFT(tv.C_NEV, 4) + '1001' FROM T_TANEV tv WHERE ID = @pTanevId
|
|
SET @IsSniKezelo = dbo.fnGetRendszerbeallitasEnumBool(1666, @pIntezmenyid, @pTanevId)
|
|
|
|
SELECT
|
|
helyek.C_OKTATASINEVELESIFELADATTIPUS AS EllatottFeladatId,
|
|
ISNULL(feladat.C_NAME, 'ÖSSZESEN') AS EllatottFeladat,
|
|
SUM(ISNULL(helyek.HelyekSzama, 0)) AS HelyekSzama,
|
|
SUM(ISNULL(tanulok.OsszesTanulo, 0)) AS OsszesTanulo,
|
|
SUM(ISNULL(tanulok.Lanyok, 0)) AS Lanyok,
|
|
SUM(ISNULL(tanulok.Sni, 0)) AS Sni,
|
|
SUM(ISNULL(tanulok.NemNappali, 0)) AS NemNappali,
|
|
SUM(ISNULL(tanarok.OsszesTanar, 0)) AS OsszesTanar,
|
|
SUM(ISNULL(tanarok.NoiTanar, 0)) AS NoiTanar,
|
|
SUM(ISNULL(termek.TermekSzama, 0)) AS TermekSzama,
|
|
SUM(ISNULL(osztalyok.Osztalyok, 0)) AS OsztalyokSzama,
|
|
SUM(ISNULL(dolgozok.Osszes, 0)) AS OsszesDolgozo,
|
|
SUM(ISNULL(dolgozok.Nok, 0)) AS Nok
|
|
FROM T_INTEZMENY i
|
|
INNER JOIN T_TANEV t ON t.C_INTEZMENYID = i.ID AND t.TOROLT = 'F'
|
|
INNER JOIN ( -- helyek
|
|
|
|
SELECT mh.C_INTEZMENYID, mh.C_TANEVID, fh.C_OKTATASINEVELESIFELADATTIPUS, COUNT(*) AS HelyekSzama
|
|
FROM T_MUKODESIHELY mh
|
|
INNER JOIN T_FELADATELLATASIHELY fh ON fh.C_MUKODESIHELYID = mh.ID AND fh.C_INTEZMENYID = mh.C_INTEZMENYID AND fh.C_TANEVID = mh.C_TANEVID AND fh.TOROLT = 'F'
|
|
WHERE mh.C_TANEVID = @pTanevId
|
|
AND mh.TOROLT = 'F'
|
|
GROUP BY mh.C_INTEZMENYID, mh.C_TANEVID, fh.C_OKTATASINEVELESIFELADATTIPUS
|
|
|
|
) helyek ON helyek.C_INTEZMENYID = t.C_INTEZMENYID and helyek.C_TANEVID = t.ID
|
|
INNER JOIN T_DICTIONARYITEMBASE feladat ON feladat.ID = helyek.C_OKTATASINEVELESIFELADATTIPUS AND feladat.C_INTEZMENYID = helyek.C_INTEZMENYID AND feladat.C_TANEVID = helyek.C_TANEVID AND feladat.TOROLT = 'F'
|
|
LEFT JOIN ( -- tanulók
|
|
|
|
SELECT
|
|
C_OKTATASINEVELESIFELADATTIPUS,
|
|
SUM(1) AS OsszesTanulo,
|
|
SUM(CASE WHEN C_NEME = 5 THEN 1 ELSE 0 END) AS Lanyok,
|
|
SUM(CASE WHEN C_FOGYATEKOSSAGTIPUSID IS NOT NULL THEN 1 ELSE 0 END) AS Sni,
|
|
SUM(CASE WHEN C_TANTERVIJELLEGID IS NULL OR C_TANTERVIJELLEGID IN (1096, 1098) THEN 0 ELSE 1 END) AS NemNappali
|
|
FROM (
|
|
SELECT
|
|
f.ID,
|
|
f.C_NEME,
|
|
fh.C_OKTATASINEVELESIFELADATTIPUS,
|
|
sni.C_FOGYATEKOSSAGTIPUSID,
|
|
d.C_NAME,
|
|
tta.C_TANTERVIJELLEGID
|
|
FROM T_FELHASZNALO f
|
|
INNER JOIN T_TANULO t ON t.ID = f.ID AND t.TOROLT = 'F'
|
|
INNER JOIN T_TANULOCSOPORT tcs ON tcs.C_TANULOID = f.ID AND tcs.TOROLT = 'F'
|
|
INNER JOIN T_TANULOTANUGYIADATOK tta on tta.C_TANULOCSOPORTID = tcs.ID and tta.TOROLT = 'F'
|
|
LEFT JOIN T_TANULOSNI sni on sni.C_TANULOID = tcs.C_TANULOID /* and sni.C_KIALLITASDATUMA >= @datum */ and sni.TOROLT = 'F'
|
|
INNER JOIN T_OSZTALYCSOPORT ocs on ocs.ID = tcs.C_OSZTALYCSOPORTID AND ocs.TOROLT = 'F'
|
|
INNER JOIN T_FELADATELLATASIHELY fh on fh.ID = ocs.C_FELADATELLATASIHELYID and fh.TOROLT = 'F'
|
|
LEFT JOIN T_DICTIONARYITEMBASE d on d.ID = sni.C_FOGYATEKOSSAGTIPUSID and d.C_TANEVID = sni.C_TANEVID
|
|
WHERE f.TOROLT = 'F'
|
|
AND f.C_TANEVID = @pTanevId
|
|
AND tcs.C_BELEPESDATUM <= @datum AND ISNULL(tcs.C_KILEPESDATUM, '2999-01-01') > @datum
|
|
) t
|
|
GROUP BY C_OKTATASINEVELESIFELADATTIPUS
|
|
|
|
) tanulok on tanulok.C_OKTATASINEVELESIFELADATTIPUS = helyek.C_OKTATASINEVELESIFELADATTIPUS
|
|
LEFT JOIN ( -- tanárok
|
|
|
|
SELECT
|
|
fh.C_INTEZMENYID,
|
|
fh.C_TANEVID,
|
|
fh.C_OKTATASINEVELESIFELADATTIPUS,
|
|
SUM(1) AS OsszesTanar,
|
|
SUM(CASE WHEN f.C_NEME = 5 THEN 1 ELSE 0 END) AS NoiTanar
|
|
FROM T_ALKALMAZOTT a
|
|
INNER JOIN T_MUNKAUGYIADATOK m ON m.C_ALKALMAZOTTID = a.ID AND m.TOROLT = 'F'
|
|
INNER JOIN T_FELADATELLATASIHELY fh ON fh.ID = m.C_FELADATELLATASIHELYID AND fh.TOROLT = 'F'
|
|
INNER JOIN T_FELHASZNALO f ON f.ID = a.ID AND f.TOROLT = 'F'
|
|
INNER JOIN T_MUNKAKORTIPUS mt on mt.ID = m.C_MUNKAKORTIPUSA AND mt.C_ALTANEVID = m.C_TANEVID AND mt.TOROLT = 'F'
|
|
WHERE a.TOROLT = 'F'
|
|
AND ISNULL(f.C_ELOTAG,'') NOT LIKE '[[]%'
|
|
AND m.C_TARTOSHELYETTESITES = 'F'
|
|
AND a.C_ALLANDOHELYETTESITESRE = 'F'
|
|
AND mt.C_ALKALMAZOTTMUNKAKORTIPUSID = 8384
|
|
AND m.C_FOGLALKOZTATASTIPUS IN (6465, 6466)
|
|
AND ISNULL(m.C_ALKALMAZASKEZDETE, @datum) <= @datum AND ISNULL(m.C_ALKALMAZASMEGSZUNESE, @datum) >= @datum
|
|
GROUP BY fh.C_INTEZMENYID, fh.C_TANEVID, fh.C_OKTATASINEVELESIFELADATTIPUS
|
|
|
|
) tanarok ON tanarok.C_INTEZMENYID = helyek.C_INTEZMENYID AND tanarok.C_TANEVID = helyek.C_TANEVID AND tanarok.C_OKTATASINEVELESIFELADATTIPUS = helyek.C_OKTATASINEVELESIFELADATTIPUS
|
|
LEFT JOIN ( -- termek
|
|
|
|
SELECT x.C_INTEZMENYID, x.C_TANEVID, fh.C_OKTATASINEVELESIFELADATTIPUS, COUNT(*) AS TermekSzama
|
|
FROM (
|
|
SELECT
|
|
ocs.C_INTEZMENYID,
|
|
ocs.C_TANEVID,
|
|
ocs.C_FELADATELLATASIHELYID,
|
|
oo.C_TEREMID,
|
|
COUNT(*) AS CNT,
|
|
ROW_NUMBER() OVER (PARTITION BY oo.C_TEREMID ORDER BY (COUNT(*)) DESC) AS RN
|
|
FROM T_OSZTALYCSOPORT ocs
|
|
INNER JOIN T_ORARENDIORA oo ON oo.C_OSZTALYCSOPORTID = ocs.ID AND oo.TOROLT = 'F'
|
|
INNER JOIN T_ORAREND orr ON orr.C_ORARENDIORAID = oo.ID
|
|
INNER JOIN T_TEREM t ON t.ID = oo.C_TEREMID AND t.TOROLT = 'F'
|
|
WHERE ocs.TOROLT = 'F'
|
|
AND ocs.C_TANEVID = @pTanevId
|
|
AND t.C_JELLEG IN (207, 187, 181, 182, 184, 2996, 185, 190, 191)
|
|
-- trm.C_JELLEG IN (182, 181, 184, 185, 191, 190, 193, 194, 195, 196, 198, 199, 200, 201, 202, 188)
|
|
GROUP BY ocs.C_INTEZMENYID, ocs.C_TANEVID, ocs.C_FELADATELLATASIHELYID, oo.C_TEREMID
|
|
) x
|
|
INNER JOIN T_FELADATELLATASIHELY fh ON fh.ID = x.C_FELADATELLATASIHELYID AND fh.TOROLT = 'F'
|
|
WHERE x.RN = 1
|
|
GROUP BY x.C_INTEZMENYID, x.C_TANEVID, fh.C_OKTATASINEVELESIFELADATTIPUS
|
|
|
|
) termek ON termek.C_INTEZMENYID = helyek.C_INTEZMENYID AND termek.C_TANEVID = helyek.C_TANEVID AND termek.C_OKTATASINEVELESIFELADATTIPUS = helyek.C_OKTATASINEVELESIFELADATTIPUS
|
|
LEFT JOIN ( -- osztályok
|
|
|
|
SELECT fh.C_INTEZMENYID, fh.C_TANEVID, fh.C_OKTATASINEVELESIFELADATTIPUS, COUNT(*) AS Osztalyok
|
|
FROM T_OSZTALYCSOPORT ocs
|
|
LEFT JOIN T_OSZTALY o ON o.ID = ocs.ID AND o.TOROLT = 'F'
|
|
LEFT JOIN T_CSOPORT cs ON cs.ID = ocs.ID AND cs.TOROLT = 'F'
|
|
INNER JOIN T_FELADATELLATASIHELY fh ON fh.ID = ocs.C_FELADATELLATASIHELYID
|
|
WHERE ocs.TOROLT = 'F'
|
|
AND ocs.C_ISTECHNIKAI = 'F'
|
|
AND (o.ID IS NOT NULL OR cs.C_TIPUSA = 1032)
|
|
GROUP by fh.C_INTEZMENYID, fh.C_TANEVID, fh.C_OKTATASINEVELESIFELADATTIPUS
|
|
|
|
) osztalyok ON osztalyok.C_INTEZMENYID = helyek.C_INTEZMENYID AND osztalyok.C_TANEVID = helyek.C_TANEVID AND osztalyok.C_OKTATASINEVELESIFELADATTIPUS = helyek.C_OKTATASINEVELESIFELADATTIPUS
|
|
LEFT JOIN ( -- dolgozók
|
|
|
|
SELECT
|
|
fh.C_INTEZMENYID,
|
|
fh.C_TANEVID,
|
|
fh.C_OKTATASINEVELESIFELADATTIPUS,
|
|
SUM(1) AS Osszes,
|
|
SUM(CASE WHEN f.C_NEME = 5 THEN 1 ELSE 0 END) AS Nok
|
|
FROM T_ALKALMAZOTT a
|
|
INNER JOIN T_MUNKAUGYIADATOK m ON m.C_ALKALMAZOTTID = a.ID AND m.TOROLT = 'F'
|
|
INNER JOIN T_FELADATELLATASIHELY fh ON fh.ID = m.C_FELADATELLATASIHELYID AND fh.TOROLT = 'F'
|
|
INNER JOIN T_FELHASZNALO f ON f.ID = a.ID AND f.TOROLT = 'F'
|
|
INNER JOIN T_MUNKAKORTIPUS mt on mt.ID = m.C_MUNKAKORTIPUSA AND mt.C_ALTANEVID = m.C_TANEVID AND mt.TOROLT = 'F'
|
|
WHERE a.TOROLT = 'F'
|
|
AND ISNULL(f.C_ELOTAG,'') NOT LIKE '[[]%'
|
|
AND m.C_TARTOSHELYETTESITES = 'F'
|
|
AND a.C_ALLANDOHELYETTESITESRE = 'F'
|
|
AND mt.C_ALKALMAZOTTMUNKAKORTIPUSID <> 8384
|
|
AND m.C_FOGLALKOZTATASTIPUS IN (6465, 6466)
|
|
AND ISNULL(m.C_ALKALMAZASKEZDETE, @datum) <= @datum AND ISNULL(m.C_ALKALMAZASMEGSZUNESE, @datum) >= @datum
|
|
GROUP BY fh.C_INTEZMENYID, fh.C_TANEVID, fh.C_OKTATASINEVELESIFELADATTIPUS
|
|
|
|
) dolgozok ON dolgozok.C_INTEZMENYID = helyek.C_INTEZMENYID AND dolgozok.C_TANEVID = helyek.C_TANEVID AND dolgozok.C_OKTATASINEVELESIFELADATTIPUS = helyek.C_OKTATASINEVELESIFELADATTIPUS
|
|
WHERE 1 = 1
|
|
AND i.ID = @pIntezmenyid
|
|
AND i.TOROLT = 'F'
|
|
AND t.ID = @pTanevId
|
|
GROUP BY GROUPING SETS((helyek.C_OKTATASINEVELESIFELADATTIPUS, feladat.C_NAME), ())
|
|
|
|
END
|
|
GO |