SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO IF OBJECT_ID('[dbo].[sp_GenerateErtekelesekTempTablaByTanulo]') IS NOT NULL BEGIN DROP PROCEDURE [dbo].[sp_GenerateErtekelesekTempTablaByTanulo] END GO -- ============================================= -- Description: -- NOTE: EZT A NÉGY TÁROLT ELJÁRÁST EGYBEN KELL KEZELNI, HA MÓDOSÍTJUK!!! -- - sp_GenerateErtekelesekTempTabla -- - sp_GenerateErtekelesekTempTablaByFoglalkozas -- - sp_GenerateErtekelesekMagatartasSzorgalomTempTabla -- - sp_GenerateErtekelesekTempTablaByTanulo -- ============================================= CREATE PROCEDURE [dbo].[sp_GenerateErtekelesekTempTablaByTanulo] -- Add the parameters for the stored procedure here @pTanuloId INT, @pFelevVege DATE, @pEvkozi INT, @pFelevi INT, @pEvvegi INT AS BEGIN -- SET NOCOUNT ON added to prevent extra result sets from -- interfering with SELECT statements. SET NOCOUNT ON; DECLARE @TempErtekeles TABLE ( ID INT, ErtekelesDatuma NVARCHAR(255), ErtekelesTipusa INT, ErtekelesSzoveg NVARCHAR(MAX), Honap NVARCHAR(2), TantargyId INT, Nev NVARCHAR(255), Osztalyzat INT, Szazalek INT, Suly INT, TantargyKategoria INT ) INSERT INTO @TempErtekeles SELECT DISTINCT * FROM ( SELECT tanuloErtekeles.ID ID, tanuloErtekeles.C_ERTEKELESDATUM ErtekelesDatuma, tanuloErtekeles.C_ERTEKELESTIPUSA ErtekelesTipusa, tanuloErtekeles.C_ERTEKELESSZOVEG ErtekelesSzoveg, CASE WHEN tanuloErtekeles.C_ERTEKELESTIPUSA = @pFelevi THEN 'I' WHEN tanuloErtekeles.C_ERTEKELESTIPUSA = @pEvvegi THEN 'II' ELSE CASE WHEN CAST(tanuloErtekeles.C_ERTEKELESDATUM AS DATE) > @pFelevVege THEN CAST(MONTH(tanuloErtekeles.C_ERTEKELESDATUM) + 1 AS NVARCHAR(2)) ELSE CAST(MONTH(tanuloErtekeles.C_ERTEKELESDATUM) AS NVARCHAR(2)) END END Honap, tanuloErtekeles.C_TANTARGYID TantargyId, tantargy.C_NEV Nev, osztalyzat.C_VALUE Osztalyzat, osztalyzatErtekeles.C_SZAZALEK Szazalek, tanariAtlagSuly.C_SULY Suly, tantargyKategoria.C_VALUE TantargyKategoria FROM ( SELECT [ID], [C_NYOMTATASINEV] FROM [T_FELHASZNALO] WHERE [TOROLT] = 'F' AND [ID] = @pTanuloId ) AS felhasznalo LEFT JOIN ( SELECT [ID], [C_ERTEKELESDATUM], [C_ERTEKELESTIPUSA], [C_OSZTALYZAT], [C_ERTEKELESSZOVEG], [C_TANTARGYID], [C_TANULOID] FROM [T_TANULOERTEKELES] WHERE [TOROLT] = 'F' AND [C_TANTARGYID] IS NOT NULL ) AS tanuloErtekeles ON tanuloErtekeles.C_TANULOID = @pTanuloId LEFT JOIN ( SELECT [ID], [C_SZAZALEK], [C_ERTEKELESMODJA] FROM [T_OSZTALYZATERTEKELES] WHERE [TOROLT] = 'F' ) AS osztalyzatErtekeles ON osztalyzatErtekeles.ID = tanuloErtekeles.ID LEFT JOIN ( SELECT [ID], [C_NEV], [C_TARGYKATEGORIA] FROM [T_TANTARGY] WHERE [TOROLT] = 'F' ) AS tantargy ON tantargy.ID = tanuloErtekeles.C_TANTARGYID LEFT JOIN ( SELECT [ID], [C_VALUE] FROM [T_DICTIONARYITEMBASE] WHERE [TOROLT] = 'F' ) AS osztalyzat ON osztalyzat.ID = tanuloErtekeles.C_OSZTALYZAT LEFT JOIN ( SELECT [ID], [C_VALUE] FROM [T_DICTIONARYITEMBASE] WHERE [TOROLT] = 'F' ) AS tantargyKategoria ON tantargyKategoria.ID = tantargy.C_TARGYKATEGORIA LEFT JOIN T_TANARIATLAGSULY_OSSZES tanariAtlagSuly ON tanariAtlagSuly.C_ERTEKELESMODJA = osztalyzatErtekeles.C_ERTEKELESMODJA AND tanuloErtekeles.C_OSZTALYZAT IS NOT NULL AND tanariAtlagSuly.TOROLT = 'F' WHERE tanuloErtekeles.ID IS NOT NULL ) AS temp SELECT * FROM ( SELECT pivotErtekelesek.TantargyId ID, Nev Nev, [9] [09], [10] [10], [11] [11], [12] [12], [1] [01I], [2] [01II], [3] [02], [4] [03], [5] [04], [6] [05], [7] [06], [I] [I], [II] [II], atlag.Jegy Atlag, @pTanuloId TanuloId, pivotErtekelesek.TantargyKategoria TantargyKategoria FROM ( SELECT DISTINCT tempErtekeles1.Nev, STUFF ( (SELECT ',' + ISNULL(CAST(tempErtekeles2.Osztalyzat AS VARCHAR(1)), '') + ISNULL(CAST(tempErtekeles2.Szazalek AS VARCHAR(2)), '') + ISNULL(CAST( CASE WHEN tempErtekeles2.ErtekelesSzoveg IS NULL OR LTRIM(RTRIM(REPLACE(REPLACE(REPLACE(tempErtekeles2.ErtekelesSzoveg, CHAR(9), ''), CHAR(10), ''), CHAR(13), ''))) = '' THEN NULL ELSE 'sz' END AS VARCHAR(2)), '') FROM @TempErtekeles tempErtekeles2 WHERE tempErtekeles1.TantargyId = tempErtekeles2.TantargyId AND tempErtekeles1.Honap = tempErtekeles2.Honap FOR XML PATH ('') ), 1, 1, '' ) Ertekelesek, tempErtekeles1.Honap, tempErtekeles1.TantargyId, tempErtekeles1.TantargyKategoria FROM @TempErtekeles tempErtekeles1 ) AS erdemjegyek PIVOT ( MAX(Ertekelesek) FOR Honap IN ([I], [II], [9] ,[10] ,[11] ,[12] ,[1] ,[2] ,[3] ,[4] ,[5] ,[6], [7]) ) AS pivotErtekelesek LEFT JOIN ( SELECT TantargyId TantargyId, ROUND( SUM(CAST(Osztalyzat AS FLOAT) * CAST(ISNULL(Suly, 100) AS FLOAT) / 100) / SUM(CAST(ISNULL(Suly, 100) AS FLOAT) / 100) , 2) Jegy FROM @TempErtekeles WHERE ErtekelesTipusa = @pEvkozi AND Osztalyzat IS NOT NULL GROUP BY TantargyId ) AS atlag ON pivotErtekelesek.TantargyId = atlag.TantargyId ) AS result IF OBJECT_ID('tempdb..#TempErtekeles') IS NOT NULL DROP TABLE #TempErtekeles END GO