137 lines
No EOL
7.6 KiB
Transact-SQL
137 lines
No EOL
7.6 KiB
Transact-SQL
SET ANSI_NULLS ON
|
|
GO
|
|
SET QUOTED_IDENTIFIER ON
|
|
GO
|
|
|
|
|
|
CREATE PROCEDURE [dbo].[sp_GetTanuloElsoNegyedeviTantargyiStatisztika]
|
|
@tanevId int,
|
|
@intezmenyId int
|
|
|
|
AS
|
|
BEGIN
|
|
SET NOCOUNT ON;
|
|
|
|
declare @kezdodatum as date=(select distinct tr.c_datum from t_tanevrendje tr where c_naptipusa=1394);
|
|
declare @vegdatum as date=(select distinct tr.c_datum from t_tanevrendje tr where c_naptipusa=1403);
|
|
|
|
--Tanulók
|
|
create table #tanulok (Id int, Nev nvarchar(max), Osztaly int, Rendez nvarchar(max))
|
|
insert into #tanulok
|
|
select t.id as Tanulo, f.c_nyomtatasinev as Nev, tcs.c_osztalycsoportid as Osztaly, ocs.c_nev as Rendez from t_tanulo t
|
|
inner join t_tanulocsoport tcs on t.id=tcs.c_tanuloid and tcs.c_intezmenyid=@intezmenyid and tcs.c_tanevid=@tanevid and tcs.torolt='F'
|
|
inner join t_osztaly o on o.id=tcs.c_osztalycsoportid and o.c_alintezmenyid=@intezmenyid and o.c_altanevid=@tanevid and o.torolt='F'
|
|
inner join t_osztalycsoport ocs on ocs.id=o.id and ocs.c_intezmenyid=@intezmenyid and ocs.c_tanevid=@tanevid and ocs.torolt='F'
|
|
inner join t_felhasznalo f on f.id=t.id and f.torolt='F'
|
|
where t.c_alintezmenyid=@IntezmenyId and t.c_altanevid=@tanevid
|
|
order by Osztaly, Tanulo
|
|
insert into #tanulok values (-1, 'Összesen: ', -1, 'zzzz')
|
|
|
|
--Értékelések
|
|
create table #ertekeles(Tanulo int, Tantargy int, Ertekeles nvarchar(max))
|
|
insert into #ertekeles
|
|
select distinct te.c_tanuloid as Tanulo, te.c_tantargyid as Tantargy,
|
|
stuff((select ', '+isnull(cast(d.c_value as varchar(max)),'') from t_tanuloertekeles teOsszefuz
|
|
inner join (select distinct d.id, d.c_value from t_dictionaryitembase d) d on d.id=teOsszefuz.c_osztalyzat
|
|
where teOsszefuz.c_tanuloid=te.c_tanuloid and teOsszefuz.c_tantargyid=te.c_tantargyid and teOsszefuz.c_ertekelestipusa=1518
|
|
and teOsszefuz.torolt='F' and teOsszefuz.c_tanevid=@tanevid and teOsszefuz.c_intezmenyid=@intezmenyid
|
|
and convert(date,teOsszefuz.c_ertekelesdatum)>@kezdodatum and convert(date,teOsszefuz.c_ertekelesdatum)<@vegdatum
|
|
for xml path('')),1,1,'') as Ertekeles
|
|
from t_tanuloertekeles te
|
|
where te.c_tantargyid is not null and te.c_tanuloid in (select id from #tanulok)
|
|
|
|
insert into #ertekeles
|
|
select -1, Tantargy, Atlag from
|
|
(select te.c_tantargyid as Tantargy, round(avg(convert(float,d.c_value)),2) as Atlag from t_tanuloertekeles te
|
|
inner join (select distinct d.id, d.c_value from t_dictionaryitembase d) d on d.id=te.c_osztalyzat
|
|
where te.c_ertekelestipusa=1518 and te.torolt='F' and te.c_osztalyzat is not null and te.c_tantargyid is not null
|
|
and te.c_tanevid=@tanevid and te.c_intezmenyid=@intezmenyid
|
|
and convert(date,te.c_ertekelesdatum)>@kezdodatum and convert(date,te.c_ertekelesdatum)<@vegdatum
|
|
group by te.c_tantargyid)a
|
|
|
|
--Osztályátlag
|
|
create table #tanuloavg(Tanulo int, Atlag float)
|
|
insert into #tanuloavg
|
|
select te.c_tanuloid as Tanulo, round(avg(convert(float,d.c_value)),2) as Atlag from t_tanuloertekeles te
|
|
inner join (select distinct d.id, d.c_value from t_dictionaryitembase d) d on d.id=te.c_osztalyzat
|
|
where te.c_ertekelestipusa=1518 and te.torolt='F' and te.c_osztalyzat is not null and te.c_tantargyid is not null
|
|
and te.c_tanevid=@tanevid and te.c_intezmenyid=@intezmenyid
|
|
and convert(date,te.c_ertekelesdatum)>@kezdodatum and convert(date,te.c_ertekelesdatum)<@vegdatum
|
|
group by te.c_tanuloid
|
|
|
|
--Szorgalom, magatartás
|
|
declare @szorgmag table (Tanulo int, Szorgalom nvarchar(max), Magatartas nvarchar(max))
|
|
insert into @szorgmag
|
|
select distinct te.c_tanuloid as Tanulo,
|
|
--szorgalom
|
|
stuff((select ', '+isnull(cast(d.c_value as varchar(max)),'') from t_osztalyfonokiertekeles oe
|
|
inner join (select distinct d.id, d.c_value from t_dictionaryitembase d) d on d.id=oe.c_szorgalom
|
|
inner join t_tanuloertekeles teSz on teSz.id=oe.id
|
|
where teSz.c_tanuloid=te.c_tanuloid and oe.torolt='F' and convert(date,teSz.c_ertekelesdatum)>@kezdodatum and convert(date,teSz.c_ertekelesdatum)<@vegdatum
|
|
for xml path('')),1,1,'') as Szorgalom,
|
|
--magatartás
|
|
stuff((select ', '+isnull(cast(d.c_value as varchar(max)),'') from t_osztalyfonokiertekeles oe
|
|
inner join (select distinct d.id, d.c_value from t_dictionaryitembase d) d on d.id=oe.c_magatartas
|
|
inner join t_tanuloertekeles teM on teM.id=oe.id
|
|
where teM.c_tanuloid=te.c_tanuloid and oe.torolt='F'
|
|
and convert(date,teM.c_ertekelesdatum)>@kezdodatum and convert(date,teM.c_ertekelesdatum)<@vegdatum
|
|
for xml path('')),1,1,'') as Magatartas
|
|
from t_tanuloertekeles te
|
|
where te.c_tanuloid in (select id from #tanulok)
|
|
|
|
--Mulasztások
|
|
declare @mulasztas table (Tanulo int, Osztaly int, MulasztasTipus int, IgazoltE nvarchar(1), GaykorlatiE nvarchar(1), Keses int)
|
|
insert into @mulasztas
|
|
select tm.c_oratanuloiid Tanulo, tao.c_osztalycsoportid as Osztaly, tm.c_tipus MulasztasTipus, tm.c_igazolt as IgazoltE, t.c_gyakorlati as GyakorlatiE, tm.c_kesespercben Keses from t_tanulomulasztas tm
|
|
inner join t_tanulocsoport tcs on tcs.c_tanuloid=tm.c_oratanuloiid and tcs.torolt='F' and tcs.c_tanevid=@tanevid and tcs.c_intezmenyid=@intezmenyid
|
|
inner join t_tanitasiora tao on tao.id=tm.c_tanitasiorakid and tao.torolt='F' and tao.torolt='F' and tao.c_tanevid=@tanevid and tao.c_intezmenyid=@intezmenyid
|
|
inner join t_tantargy t on t.id=tao.c_tantargyid and t.torolt='F'
|
|
where tm.torolt='F' and tm.c_intezmenyid=@intezmenyid and tm.c_tanevid=@tanevid
|
|
and convert(date,tao.c_datum)>@kezdodatum and convert(date,tao.c_datum)<@vegdatum
|
|
|
|
create table #temp (Tanulo int, Szorgalom nvarchar(max),Magatartas nvarchar(max),oih int, onih int, oik int, onik int)
|
|
insert into #temp
|
|
select distinct t.id, sz.szorgalom, sz.magatartas, oih.oih, onih.onih, oik.oik, onik.onik from #tanulok t
|
|
left join @szorgmag sz on sz.tanulo=t.id
|
|
--igazolt hiányzások
|
|
left join (select m.Tanulo Tanulo, count(m.MulasztasTipus) oih from @mulasztas m where m.IgazoltE='T' and m.MulasztasTipus=1500 group by Tanulo )oih on oih.Tanulo=t.id
|
|
|
|
--igazolatlan hiányzások
|
|
left join (select m.Tanulo Tanulo, count(m.MulasztasTipus) onih from @mulasztas m where m.IgazoltE='F' and m.MulasztasTipus=1500 group by Tanulo )onih on onih.Tanulo=t.id
|
|
|
|
--igazolt késések
|
|
left join (select m.Tanulo Tanulo, sum(m.keses) oik from @mulasztas m where m.IgazoltE='T' and m.MulasztasTipus=1499 group by Tanulo)oik on oik.Tanulo=t.id
|
|
|
|
--igazolatlan késések
|
|
left join (select m.Tanulo Tanulo, sum(m.keses) onik from @mulasztas m where m.IgazoltE='F' and m.MulasztasTipus=1499 group by Tanulo)onik on onik.Tanulo=t.id
|
|
|
|
declare @cols as nvarchar(max),
|
|
@colsIn as nvarchar(max),
|
|
@query as nvarchar(4000);
|
|
|
|
select @cols= isnull(@cols + ',','') +quotename(Tantargy) + ' as '+quotename(nev),
|
|
@colsIn= isnull(@colsIn + ',','') +quotename(Tantargy)
|
|
from (select distinct t.id as Tantargy, t.c_nev as nev from t_foglalkozas f
|
|
inner join t_tantargy t on f.c_tantargyid=t.id) Tantargy
|
|
|
|
set @query='
|
|
select t.Nev as ''COLUMN108'', ocs.c_nev as ''COLUMN5286'', temp.Szorgalom as ''COLUMN2620'', temp.Magatartas as ''COLUMN2619'', '+@cols+', tavg.Atlag as ''COLUMN1817'', temp.oih as ''COLUMN5247'', temp.onih as ''COLUMN5254'', temp.oik as ''COLUMN5255'', temp.onik as ''COLUMN5256''
|
|
from #tanulok t
|
|
left join (select * from #ertekeles pivot (max(Ertekeles) for Tantargy in ('+@colsIn+'))pv) ertekeles on ertekeles.Tanulo=t.Id
|
|
left join #temp temp on temp.Tanulo=t.id
|
|
left join t_felhasznalo f on f.id=t.Id
|
|
left join t_osztalycsoport ocs on ocs.id=t.Osztaly
|
|
left join #tanuloavg tavg on tavg.tanulo=t.id
|
|
order by t.Rendez
|
|
'
|
|
EXEC sp_executesql @query
|
|
|
|
/*drop table #mulasztastmp */
|
|
drop table #tanulok
|
|
drop table #ertekeles
|
|
drop table #tanuloavg
|
|
|
|
End
|
|
|
|
|
|
GO |