156 lines
8.5 KiB
Transact-SQL
156 lines
8.5 KiB
Transact-SQL
DROP PROCEDURE IF EXISTS uspSzirStatInfra
|
|
GO
|
|
|
|
CREATE PROCEDURE uspSzirStatInfra
|
|
@pTanevId int
|
|
,@pIntezmenyid int
|
|
AS BEGIN
|
|
SELECT
|
|
fhely.ID AS FeladatellatasiHelyId
|
|
,ia.C_OMKOD AS IntezmenyOmAzonosito
|
|
,ia.C_NEV AS IntezmenyNev
|
|
,ia.C_VAROS AS IntezenyTelepules
|
|
,ia.C_IRANYITOSZAM AS IntezmenyIrszam
|
|
,RTRIM(CONCAT(ia.C_KOZTERULETNEV, ' ', ia.C_KOZTERULETJELLEGENEV,' ', ia.C_HAZSZAM, ' ', ia.C_EMELET, ' ', ia.C_AJTO)) AS IntezmenyCim
|
|
,ISNULL(NULLIF(ia.C_EMAILCIM, ''), '-') AS IntezmenyEmailcim
|
|
,CONCAT(ia.C_OMKOD, '/', fhely.C_FELADATELLATASIHELYKOD) AS FelhelyAzonosito
|
|
,mhely.C_NEV AS FelhelyNev
|
|
,mhely.C_VAROS AS FelhelyTelepules
|
|
,mhely.C_IRANYITOSZAM AS FelhelyIrszam
|
|
,RTRIM(CONCAT(mhely.C_KOZTERULETNEV, ' ', mhely.C_KOZTERULETJELLEGENEV,' ', mhely.C_HAZSZAM, ' ', mhely.C_EMELET, ' ', mhely.C_AJTO)) AS FelhelyCim
|
|
,ISNULL(NULLIF(mhely.C_EMAILCIM, ''), '-') AS FelhelyEmailcim
|
|
,fhelytip.C_NAME AS FelhelyTipus
|
|
,ISNULL(OvodaiCsoportszoba, 0) AS OvodaiCsoportszoba
|
|
,ISNULL(OvodaiCsoportszobaFerohely, 0) AS OvodaiCsoportszobaFerohely
|
|
,ISNULL(IskolaiOsztalyterem, 0) AS IskolaiOsztalyterem
|
|
,ISNULL(IskolaiOsztalyteremFerohely, 0) AS IskolaiOsztalyteremFerohely
|
|
,ISNULL(IskolaiSzakterem, 0) AS IskolaiSzakterem
|
|
,ISNULL(IskolaiSzakteremFerohely, 0) AS IskolaiSzakteremFerohely
|
|
,ISNULL(IskolaiTanulocsoportSzoba, 0) AS IskolaiTanulocsoportSzoba
|
|
,ISNULL(IskolaiTanulocsoportSzobaFerohely, 0) AS IskolaiTanulocsoportSzobaFerohely
|
|
,ISNULL(Tornaterem, 0) AS Tornaterem
|
|
,ISNULL(Tornaszoba, 0) AS Tornaszoba
|
|
,ISNULL(Uszomedence, 0) AS Uszomedence
|
|
,ISNULL(SzakmaiGyakorloterem, 0) AS SzakmaiGyakorloterem
|
|
,ISNULL(SzakmaiLaboratorium, 0) AS SzakmaiLaboratorium
|
|
,ISNULL(DemonstraciosTerem, 0) AS DemonstraciosTerem
|
|
,ISNULL(Tangazdasag, 0) AS Tangazdasag
|
|
,ISNULL(Taniroda, 0) AS Taniroda
|
|
,ISNULL(Tanudvar, 0) AS Tanudvar
|
|
,ISNULL(Tanbolt, 0) AS Tanbolt
|
|
,ISNULL(Tankonyha, 0) AS Tankonyha
|
|
,ISNULL(KollegiumiHaloszoba, 0) AS KollegiumiHaloszoba
|
|
,ISNULL(KollegiumiHaloszobaFerohely, 0) AS KollegiumiHaloszobaFerohely
|
|
,szirfelhely.C_NOTEBOOKOKSZAMA AS Notebook
|
|
,szirfelhely.C_ASZTALIGEPEKSZAMA AS AsztaliGep
|
|
,szirfelhely.C_OKOSTELEFONOKSZAMA AS Okostelefon
|
|
,szirfelhely.C_TABLETEKSZAMA AS Tablet
|
|
,ISNULL(internet.InteraktivTabla, 0) AS InteraktivTabla
|
|
,IIF(ISNULL(internet.FelhelyInternetkapcsolat, 0) = 0, 'Nem', 'Igen') AS FelhelyInternetkapcsolat
|
|
,ISNULL(internet.OsztalyteremInternetkapcsolat, 0) AS OsztalyteremInternetkapcsolat
|
|
,ISNULL(internet.SzakteremInternetkapcsolat, 0) AS SzakteremInternetkapcsolat
|
|
,ISNULL(internet.SzamitogepInternetkapcsolatTanulo, 0) AS SzamitogepInternetkapcsolatTanulo
|
|
,ISNULL(internet.SzamitogepInternetkapcsolatPedagogus, 0) AS SzamitogepInternetkapcsolatPedagogus
|
|
,ISNULL(internet.OsztalyteremWifi, 0) AS OsztalyteremWifi
|
|
FROM T_INTEZMENY i
|
|
INNER JOIN T_INTEZMENYADATOK ia ON ia.C_INTEZMENYID = i.ID AND ia.TOROLT = 'F'
|
|
INNER JOIN T_FELADATELLATASIHELY fhely ON fhely.C_TANEVID = ia.C_TANEVID AND fhely.TOROLT = 'F'
|
|
INNER JOIN T_MUKODESIHELY mhely ON mhely.ID = fhely.C_MUKODESIHELYID AND mhely.TOROLT = 'F'
|
|
INNER JOIN T_DICTIONARYITEMBASE fhelytip ON fhelytip.ID = fhely.C_OKTATASINEVELESIFELADATTIPUS AND fhelytip.C_TANEVID = fhely.C_TANEVID AND fhelytip.C_INTEZMENYID = fhely.C_INTEZMENYID AND fhelytip.TOROLT = 'F'
|
|
LEFT JOIN (
|
|
SELECT pvt.C_FELADATELLATASIHELYID,
|
|
ISNULL([182], 0) AS OvodaiCsoportszoba
|
|
,ISNULL([181], 0) AS IskolaiOsztalyterem
|
|
,ISNULL([184], 0) AS IskolaiSzakterem
|
|
,ISNULL([185], 0) AS IskolaiTanulocsoportSzoba
|
|
,ISNULL([191], 0) AS Tornaterem
|
|
,ISNULL([190], 0) AS Tornaszoba
|
|
,ISNULL([193], 0) AS Uszomedence
|
|
,ISNULL([194], 0) AS SzakmaiGyakorloterem
|
|
,ISNULL([195], 0) AS SzakmaiLaboratorium
|
|
,ISNULL([196], 0) AS DemonstraciosTerem
|
|
,ISNULL([198], 0) AS Tangazdasag
|
|
,ISNULL([199], 0) AS Taniroda
|
|
,ISNULL([200], 0) AS Tanudvar
|
|
,ISNULL([201], 0) AS Tanbolt
|
|
,ISNULL([202], 0) AS Tankonyha
|
|
,ISNULL([188], 0) AS KollegiumiHaloszoba
|
|
FROM (
|
|
SELECT x.C_FELADATELLATASIHELYID, x.C_JELLEG, COUNT(*) CNT
|
|
FROM (
|
|
SELECT ocs.C_FELADATELLATASIHELYID, oo.C_TEREMID, trm.C_JELLEG, 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 trm ON trm.ID = oo.C_TEREMID AND trm.TOROLT = 'F'
|
|
WHERE trm.C_JELLEG IN (182, 181, 184, 185, 191, 190, 193, 194, 195, 196, 198, 199, 200, 201, 202, 188)
|
|
AND ocs.TOROLT = 'F'
|
|
AND ocs.C_TANEVID = @pTanevId
|
|
GROUP BY ocs.C_FELADATELLATASIHELYID, oo.C_TEREMID, trm.C_JELLEG--, trm.C_KAPACITAS
|
|
) x
|
|
WHERE RN = 1
|
|
GROUP BY x.C_FELADATELLATASIHELYID, x.C_JELLEG
|
|
) tbl PIVOT
|
|
( MAX(CNT)
|
|
FOR C_JELLEG IN ([182], [181], [184], [185], [191], [190], [193], [194], [195], [196], [198], [199], [200], [201], [202], [188])
|
|
) AS pvt
|
|
) szamossag ON szamossag.C_FELADATELLATASIHELYID = fhely.ID
|
|
LEFT JOIN (
|
|
SELECT pvt.C_FELADATELLATASIHELYID,
|
|
ISNULL([182], 0) AS OvodaiCsoportszobaFerohely
|
|
,ISNULL([181], 0) AS IskolaiOsztalyteremFerohely
|
|
,ISNULL([184], 0) AS IskolaiSzakteremFerohely
|
|
,ISNULL([185], 0) AS IskolaiTanulocsoportSzobaFerohely
|
|
,ISNULL([188], 0) AS KollegiumiHaloszobaFerohely
|
|
FROM (
|
|
SELECT x.C_FELADATELLATASIHELYID, x.C_JELLEG, SUM(C_KAPACITAS) AS C_KAPACITAS
|
|
FROM (
|
|
SELECT ocs.C_FELADATELLATASIHELYID, oo.C_TEREMID, trm.C_JELLEG, 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 trm ON trm.ID = oo.C_TEREMID AND trm.TOROLT = 'F'
|
|
WHERE trm.C_JELLEG IN (182, 181, 184, 185, 188)
|
|
AND ocs.TOROLT = 'F'
|
|
AND ocs.C_TANEVID = @pTanevId
|
|
GROUP BY ocs.C_FELADATELLATASIHELYID, oo.C_TEREMID, trm.C_JELLEG
|
|
) x
|
|
INNER JOIN T_TEREM trm ON trm.ID = x.C_TEREMID AND trm.TOROLT = 'F'
|
|
WHERE RN = 1
|
|
GROUP BY x.C_FELADATELLATASIHELYID, x.C_JELLEG
|
|
) tbl PIVOT
|
|
( MAX(C_KAPACITAS)
|
|
FOR C_JELLEG IN ([182], [181], [184], [185], [188])
|
|
) AS pvt
|
|
) ferohely ON ferohely.C_FELADATELLATASIHELYID = fhely.ID
|
|
LEFT JOIN T_SZIRSTATFELADATELLATASIHELY szirfelhely ON szirfelhely.C_FELADATELLATASIHELYID = fhely.ID AND szirfelhely.TOROLT = 'F'
|
|
LEFT JOIN (
|
|
SELECT x.C_FELADATELLATASIHELYID--, trm.C_JELLEG
|
|
,SUM(IIF(trm.C_ISINTERAKTTABLAVALMUNKAALLOM = 'T', 1, 0)) AS InteraktivTabla
|
|
,SUM(IIF(trm.C_ISINTERNETKAPCSOLATELERHETO = 'T' OR trm.C_WIFILEFEDETT = 'T', 1, 0)) AS FelhelyInternetkapcsolat
|
|
,SUM(IIF(trm.C_ISINTERNETKAPCSOLATELERHETO = 'T' AND trm.C_JELLEG = 181, 1, 0)) AS OsztalyteremInternetkapcsolat
|
|
,SUM(IIF(trm.C_ISINTERNETKAPCSOLATELERHETO = 'T' AND trm.C_JELLEG = 184, 1, 0)) AS SzakteremInternetkapcsolat
|
|
,SUM(trm.C_TANULOKSZAMARAHOZZAFERHINTER) AS SzamitogepInternetkapcsolatTanulo
|
|
,SUM(trm.C_PEDAGOGUSHOZZAFERHINTERNETES) AS SzamitogepInternetkapcsolatPedagogus
|
|
,SUM(IIF(trm.C_WIFILEFEDETT = 'T' AND trm.C_JELLEG = 181, 1, 0)) AS OsztalyteremWifi
|
|
|
|
FROM (
|
|
SELECT ocs.C_FELADATELLATASIHELYID, oo.C_TEREMID, trm.C_JELLEG, ROW_NUMBER() OVER (PARTITION BY oo.C_TEREMID ORDER BY (COUNT(*)) desc) AS RN, COUNT(*) CNT
|
|
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 trm ON trm.ID = oo.C_TEREMID AND trm.TOROLT = 'F'
|
|
WHERE ocs.C_TANEVID = @pTanevId
|
|
AND ocs.TOROLT = 'F'
|
|
GROUP BY ocs.C_FELADATELLATASIHELYID, oo.C_TEREMID, trm.C_JELLEG
|
|
) x
|
|
INNER JOIN T_TEREM trm ON trm.ID = x.C_TEREMID AND trm.TOROLT = 'F'
|
|
WHERE RN = 1
|
|
GROUP BY x.C_FELADATELLATASIHELYID
|
|
) internet ON internet.C_FELADATELLATASIHELYID = fhely.ID
|
|
WHERE i.ID = @pIntezmenyId
|
|
AND ia.C_TANEVID = @pTanevId
|
|
AND fhely.C_TANEVID = @pTanevId
|
|
AND i.TOROLT = 'F'
|
|
END
|
|
GO
|