168 lines
No EOL
6.4 KiB
Transact-SQL
168 lines
No EOL
6.4 KiB
Transact-SQL
GO
|
|
/****** Object: StoredProcedure [dbo].[sp_TanariOrarendErtekelesData] Script Date: 2016.07.15. 13:33:34 ******/
|
|
SET ANSI_NULLS ON
|
|
GO
|
|
SET QUOTED_IDENTIFIER ON
|
|
GO
|
|
-- =============================================
|
|
-- Author: DT
|
|
-- Create date: 2016-07-15
|
|
-- Description:
|
|
-- =============================================
|
|
CREATE PROCEDURE [dbo].[sp_TanariOrarendErtekelesData]
|
|
-- Add the parameters for the stored procedure here
|
|
@pTantargyId int,
|
|
@pOsztalyId int,
|
|
@pFelevVege Date,
|
|
@pEvkozi int,
|
|
@pFelevi int,
|
|
@pEvvegi int,
|
|
@pDate Date,
|
|
@pOraDate Date
|
|
AS
|
|
BEGIN
|
|
-- SET NOCOUNT ON added to prevent extra result sets from
|
|
-- interfering with SELECT statements.
|
|
SET NOCOUNT ON;
|
|
|
|
DECLARE @TempErtekeles TABLE (
|
|
ID INT,
|
|
TanuloId INT,
|
|
Nev NVARCHAR(255),
|
|
ErtekelesDatuma NVARCHAR(255),
|
|
ErtekelesTipusa INT,
|
|
Osztalyzat INT,
|
|
Honap INT
|
|
)
|
|
|
|
INSERT INTO @TempErtekeles
|
|
SELECT *
|
|
FROM (
|
|
Select
|
|
te.ID
|
|
,tcs.C_TANULOID as TanuloId
|
|
,t.C_NYOMTATASINEV as Nev
|
|
,te.C_ERTEKELESDATUM as ErtekelesDatuma
|
|
,te.C_ERTEKELESTIPUSA as ErtekelesTipusa
|
|
,Jegy.C_VALUE as Osztalyzat
|
|
,CASE WHEN te.C_ERTEKELESDATUM > @pFelevVege
|
|
THEN MONTH(te.C_ERTEKELESDATUM) + 1
|
|
ELSE MONTH(te.C_ERTEKELESDATUM)
|
|
END as Honap
|
|
From(
|
|
SELECT [C_TANULOID]
|
|
FROM [T_TANULOCSOPORT] where [TOROLT] = 'F'
|
|
and [C_BELEPESDATUM] < GETDATE()
|
|
and ([C_KILEPESDATUM] is null or [C_KILEPESDATUM] >= GETDATE())
|
|
and [C_OSZTALYCSOPORTID] = @pOsztalyId) as tcs
|
|
Inner join (
|
|
SELECT [ID]
|
|
,[C_NYOMTATASINEV]
|
|
FROM [T_FELHASZNALO] where [TOROLT] = 'F' ) as t
|
|
On t.[ID] = tcs.C_TANULOID
|
|
Left join (SELECT [ID]
|
|
,[C_ERTEKELESDATUM]
|
|
,[C_ERTEKELESTIPUSA]
|
|
,[C_OSZTALYZAT]
|
|
,[C_TANULOID]
|
|
FROM [T_TANULOERTEKELES] where [TOROLT] = 'F' And [C_TANTARGYID] = @pTantargyId) as te
|
|
on tcs.C_TANULOID = te.C_TANULOID
|
|
Left join(SELECT [ID]
|
|
,[C_VALUE]
|
|
FROM [T_DICTIONARYITEMBASE] where [TOROLT] = 'F' ) as Jegy
|
|
On Jegy.ID = te.C_OSZTALYZAT
|
|
) as temp
|
|
|
|
SELECT
|
|
result.*
|
|
,result2.Nev
|
|
,result2.Atlag
|
|
,result2.Oka
|
|
,result2.ErtkelesMentesseg
|
|
,result2.OraMentesseg
|
|
,result2.SzovegesenErtekelheto
|
|
,@pTantargyId as TantargyId
|
|
FROM (
|
|
select pivotErtekel.TanuloId as ID,
|
|
[9] as [09],
|
|
[10],
|
|
[11],
|
|
[12],
|
|
[1] as [01I],
|
|
[2] as [01II],
|
|
[3] as [02],
|
|
[4] as [03],
|
|
[5] as [04],
|
|
[6] as [05],
|
|
[7] as [06],
|
|
felev.jegy as [I],
|
|
evvege.jegy as [II]
|
|
From(
|
|
select distinct t1.Nev,
|
|
STUFF(
|
|
(SELECT ', ' + 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 Osztalyzatok,
|
|
t1.Honap,
|
|
t1.TanuloId
|
|
from @TempErtekeles t1
|
|
) as erdemjegyek
|
|
PIVOT
|
|
( max( Osztalyzatok) FOR Honap In ([9] ,[10] ,[11] ,[12] ,[1] ,[2] ,[3] ,[4] ,[5] ,[6], [7])
|
|
) 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
|
|
join (
|
|
SELECT
|
|
T_FELHASZNALO.ID ID,
|
|
T_FELHASZNALO.C_NYOMTATASINEV + ' (' + CONVERT(nvarchar(50), T_FELHASZNALO.C_SZULETESIDATUM,102) + ')' as Nev,
|
|
isnull(Atlag.C_EVVEGIATLAG, 0) Atlag,
|
|
T_TANULOMENTESSEG.C_MENTESSEGOKA Oka,
|
|
T_TANULOMENTESSEG.C_ERTEKELESMENTESITES ErtkelesMentesseg,
|
|
T_TANULOMENTESSEG.C_ORAMENTESITES OraMentesseg,
|
|
T_TANULOMENTESSEG.C_SZOVEGESENERTEKELHETO SzovegesenErtekelheto
|
|
from
|
|
T_TANULOCSOPORT
|
|
inner Join T_FELHASZNALO on T_FELHASZNALO.id=T_TANULOCSOPORT.c_tanuloid
|
|
left join T_TARGYTANULOATLAG Atlag on Atlag.C_TANTARGYID = @pTantargyId and Atlag.C_TANULOID = T_FELHASZNALO.ID
|
|
left join T_TANULOMENTESSEG on T_FELHASZNALO.ID = T_TANULOMENTESSEG.C_TANULOID
|
|
and T_TANULOMENTESSEG.TOROLT = 'F'
|
|
and T_TANULOMENTESSEG.C_TANTARGYID = @pTantargyId
|
|
and (@pDate between isnull(T_TANULOMENTESSEG.C_KEZDETE, @pDate) and isnull(T_TANULOMENTESSEG.C_VEGE, @pDate))
|
|
where T_TANULOCSOPORT.torolt = 'F'
|
|
and T_TANULOCSOPORT.C_BELEPESDATUM < @pDate
|
|
and (T_TANULOCSOPORT.C_KILEPESDATUM is null or T_TANULOCSOPORT.C_KILEPESDATUM >= @pDate)
|
|
and T_TANULOCSOPORT.c_osztalycsoportid = @pOsztalyId
|
|
) as result2 on result2.ID = result.ID
|
|
|
|
IF OBJECT_ID('tempdb..#TempErtekeles') IS NOT NULL drop table #TempErtekeles
|
|
|
|
END |