SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO IF OBJECT_ID('[dbo].[sp_GetPedagogusAltalAdottErtekelesek]') IS NOT NULL BEGIN DROP PROCEDURE [dbo].[sp_GetPedagogusAltalAdottErtekelesek] END GO CREATE PROCEDURE [dbo].[sp_GetPedagogusAltalAdottErtekelesek] @tanarID int, @pEvkozi int, @pFelevi int, @pEvvegi int, @tanevId int AS BEGIN DECLARE @osztalyID INT = 0 DECLARE @tantargyID INT = 0 DECLARE @RowID INT = 0 SET NOCOUNT ON; SELECT DISTINCT fog.ID, tt.ID TantargyID, ocs.ID OsztalyID, ocs.C_NEV + '_' + TT.C_NEV Nev INTO #Foglalkozasok FROM T_FOGLALKOZAS_OSSZES fog INNER JOIN T_OSZTALYCSOPORT_OSSZES ocs ON ocs.ID = fog.C_OSZTALYCSOPORTID AND ocs.TOROLT = 'F' LEFT JOIN T_OSZTALY_OSSZES o ON o.ID = ocs.ID AND o.TOROLT = 'F' LEFT JOIN T_CSOPORT_OSSZES cs ON cs.C_OSZTALYBONTASID = o.ID AND cs.TOROLT = 'F' INNER JOIN T_TANTARGY_OSSZES tt ON tt.ID = fog.C_TANTARGYID AND tt.TOROLT = 'F' INNER JOIN T_FOGLALKOZASOK_TANAROK ft ON ft.C_FOGLALKOZASOKID = fog.ID WHERE fog.TOROLT = 'F' AND ft.C_TANAROKID = @tanarID AND fog.C_TANEVID=@tanevId DECLARE @TempErtekeles TABLE ( ID INT, TanuloId INT, Nev NVARCHAR(255), OsztID INT, ErtekelesDatuma NVARCHAR(255), ErtekelesTipusa INT, Osztalyzat INT, Honap INT ) SELECT * FROM #Foglalkozasok WHILE (1 = 1) BEGIN DELETE FROM @TempErtekeles SELECT TOP 1 @RowID = ID, @tantargyID = TantargyID, @osztalyID = OsztalyID FROM #Foglalkozasok Foglalkozasok WHERE ID > @RowID ORDER BY ID IF @@ROWCOUNT = 0 BEGIN BREAK; END INSERT INTO @TempErtekeles SELECT * FROM ( SELECT DISTINCT te.ID ,tcs.C_TANULOID as TanuloId ,f.C_NYOMTATASINEV as Nev ,tcs.C_OSZTALYCSOPORTID as OsztID ,te.C_ERTEKELESDATUM as ErtekelesDatuma ,te.C_ERTEKELESTIPUSA as ErtekelesTipusa ,Jegy.C_VALUE as Osztalyzat ,MONTH(te.C_ERTEKELESDATUM) as Honap FROM T_TANULOCSOPORT_OSSZES tcs INNER JOIN T_FELHASZNALO_OSSZES f ON f.ID = tcs.C_TANULOID AND f.TOROLT = 'F' LEFT JOIN T_TANULOERTEKELES_OSSZES te ON te.C_TANTARGYID = @tantargyID AND te.C_TANULOID = tcs.C_TANULOID AND te.TOROLT = 'F' AND te.C_TANEVID=@TANEVID AND te.C_ERTEKELOID=@tanarID LEFT JOIN T_OSZTALYZATERTEKELES_OSSZES oe ON oe.ID = te.ID AND oe.TOROLT = 'F' AND oe.c_altanevId=@tanevid LEFT JOIN T_DICTIONARYITEMBASE_OSSZES Jegy ON Jegy.ID = te.C_OSZTALYZAT AND Jegy.TOROLT = 'F' WHERE tcs.TOROLT = 'F' AND TCS.C_TANEVID=@TANEVID AND tcs.C_BELEPESDATUM < GETDATE() AND (tcs.C_KILEPESDATUM IS NULL OR tcs.C_KILEPESDATUM >= GETDATE()) AND tcs.C_OSZTALYCSOPORTID = @osztalyID ) as temp SELECT result.* FROM ( SELECT pivotErtekel.TanuloId as ID, Nev, [9] as Szeptember, [10] as Október, [11] as November, [12] as December, [1] as Január, [2] as Február, [3] as Március, [4] as Április, [5] as Május, [6] as Június, felev.jegy as [I], evvege.jegy as [II], atlag.jegy as Atlag FROM( SELECT DISTINCT t1.Nev, STUFF( (SELECT ', ' + ISNULL(CAST(t2.Osztalyzat AS VARCHAR(1)), '') FROM @TempErtekeles t2 WHERE t1.TanuloId = t2.TanuloId AND t1.Honap = t2.Honap AND t1.ErtekelesTipusa = @pEvkozi AND t2.ErtekelesTipusa = @pEvkozi FOR XML PATH ('')) , 1, 1, '') AS Ertekelesek, t1.Honap, t1.TanuloId FROM @TempErtekeles t1 ) as erdemjegyek PIVOT ( MAX( Ertekelesek) FOR Honap IN ([9] ,[10] ,[11] ,[12] ,[1] ,[2] ,[3] ,[4] ,[5] ,[6]) ) AS pivotErtekel LEFT JOIN ( SELECT TanuloId, AVG(Osztalyzat) as jegy FROM @TempErtekeles WHERE ErtekelesTipusa = @pFelevi GROUP BY TanuloId ) as felev ON pivotErtekel.TanuloId = felev.TanuloId LEFT JOIN ( SELECT TanuloId, AVG(Osztalyzat) AS jegy FROM @TempErtekeles WHERE ErtekelesTipusa = @pEvvegi GROUP BY TanuloId ) as evvege ON pivotErtekel.TanuloId = evvege.TanuloId LEFT JOIN ( SELECT TanuloId, ROUND(AVG(CAST(Osztalyzat as FLOAT)),1) as jegy FROM @TempErtekeles WHERE ErtekelesTipusa = @pEvkozi GROUP BY TanuloId ) as atlag ON pivotErtekel.TanuloId = atlag.TanuloId ) as result END IF OBJECT_ID('tempdb..#TempErtekeles') IS NOT NULL DROP TABLE #TempErtekeles IF OBJECT_ID('tempdb..#Foglalkozasok') IS NOT NULL DROP TABLE #Foglalkozasok END GO