kreta/Kreta.DataAccess.Migrations/Scripts/Archive/20170327110702_Init/Stored procedures/sp_GetOsztalyHaviStatisztika.sql
2024-03-13 00:33:46 +01:00

137 lines
8.7 KiB
Transact-SQL

SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE PROCEDURE [dbo].[sp_GetOsztalyHaviStatisztika]
@tanevId int,
@osztalyId int,
@intezmenyId int,
@honapId int
AS
BEGIN
SET NOCOUNT ON;
declare @honap nvarchar(50)= (select distinct d.c_value from t_dictionaryitembase d where d.id=@honapId)
--Fejléc
select * from
(select ocs.c_nev as COLUMN5286, CAST(YEAR(getdate()) AS VARCHAR)+'-'+@honap as COLUMN5287 from t_osztalycsoport ocs where ocs.id=@osztalyid) Tabla
--Tanulók
create table #tanulo (Id int, Nev nvarchar(max), Rendez nvarchar(max))
insert into #tanulo
select distinct tcs.c_tanuloid, f.c_nyomtatasinev as Nev, f.c_nyomtatasinev as Rendez from t_tanulocsoport tcs
left join t_felhasznalo f on f.id=tcs.c_tanuloid and f.torolt='F'
where tcs.c_osztalycsoportid=@osztalyId and tcs.c_intezmenyid=@intezmenyId and tcs.c_tanevid=@tanevId and tcs.torolt='F'
insert into #tanulo values (-1, 'Összesen: ', '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 (CAST(MONTH(teOsszefuz.c_ertekelesdatum) AS VARCHAR))=@honap
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 #tanulo)
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 (CAST(MONTH(te.c_ertekelesdatum) AS VARCHAR))=@honap
group by te.c_tantargyid)a
--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 and (CAST(MONTH(teSz.c_ertekelesdatum) AS VARCHAR))=@honap
where teSz.c_tanuloid=te.c_tanuloid and oe.torolt='F'
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 and (CAST(MONTH(teM.c_ertekelesdatum) AS VARCHAR))=@honap
where teM.c_tanuloid=te.c_tanuloid and oe.torolt='F'
for xml path('')),1,1,'') as Magatartas
from t_tanuloertekeles te
where te.c_tanuloid in (select id from #tanulo)
--Mulasztások
declare @mulasztas table (Tanulo int, MulasztasTipus int, IgazoltE nvarchar(1), GaykorlatiE nvarchar(1), Keses int)
insert into @mulasztas
select tm.c_oratanuloiid Tanulo, 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 and (CAST(MONTH(tao.c_datum) AS VARCHAR))=@honap
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
create table #temp (Tanulo int, Szorgalom nvarchar(max),Magatartas nvarchar(max), igyh int, ieh int, oih int, nigyh int, nieh int, onih int, igyk int, iek int, oik int, nigyk int, niek int, onik int)
insert into #temp
select t.id, sz.szorgalom, sz.magatartas, igyh.igyh, ieh.ieh, oih.oih, nigyh.nigyh, nieh.nieh, onih.onih, igyk.igyk, iek.iek, oik.oik, nigyk.nigyk, niek.niek, onik.onik from #tanulo t
left join @szorgmag sz on sz.tanulo=t.id
--igazolt hiányzások
left join (select m.Tanulo Tanulo, count(m.MulasztasTipus) igyh from @mulasztas m where m.IgazoltE='T' and m.GaykorlatiE='T' and m.MulasztasTipus=1500 group by Tanulo)igyh on igyh.Tanulo=t.id
left join (select m.Tanulo Tanulo, count(m.MulasztasTipus) ieh from @mulasztas m where m.IgazoltE='T' and m.GaykorlatiE='F' and m.MulasztasTipus=1500 group by Tanulo)ieh on ieh.Tanulo=t.id
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) nigyh from @mulasztas m where m.IgazoltE='F' and m.GaykorlatiE='T' and m.MulasztasTipus=1500 group by Tanulo)nigyh on nigyh.Tanulo=t.id
left join (select m.Tanulo Tanulo, count(m.MulasztasTipus) nieh from @mulasztas m where m.IgazoltE='F' and m.GaykorlatiE='F' and m.MulasztasTipus=1500 group by Tanulo)nieh on nieh.Tanulo=t.id
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) igyk from @mulasztas m where m.IgazoltE='T' and m.GaykorlatiE='T' and m.MulasztasTipus=1499 group by Tanulo)igyk on igyk.Tanulo=t.id
left join (select m.Tanulo Tanulo, sum(m.keses) iek from @mulasztas m where m.IgazoltE='T' and m.GaykorlatiE='F' and m.MulasztasTipus=1499 group by Tanulo)iek on iek.Tanulo=t.id
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) nigyk from @mulasztas m where m.IgazoltE='F' and m.GaykorlatiE='T' and m.MulasztasTipus=1499 group by Tanulo)nigyk on nigyk.Tanulo=t.id
left join (select m.Tanulo Tanulo, sum(m.keses) niek from @mulasztas m where m.IgazoltE='F' and m.GaykorlatiE='F' and m.MulasztasTipus=1499 group by Tanulo)niek on niek.Tanulo=t.id
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 and t.torolt='F'
where f.torolt='F' and f.c_intezmenyid=@intezmenyid and f.c_tanevid=@tanevid) Tantargy
set @query='select t.Nev as ''COLUMN108'', temp.Szorgalom as ''COLUMN2620'', temp. Magatartas as ''COLUMN2619'', '+@cols+', atlag.atlag as ''COLUMN1817'',
temp.igyh ''COLUMN5246'', temp.ieh ''COLUMN5245'', temp.oih ''COLUMN5247'',
temp.nigyh ''COLUMN5249'', temp.nieh ''COLUMN5248'', temp.onih ''COLUMN5254'',
temp.igyk ''COLUMN5251'', temp.iek ''COLUMN5250'', temp.oik ''COLUMN5255'',
temp.nigyk ''COLUMN5253'', temp.niek ''COLUMN5252'', temp.onik ''COLUMN5256''
from #tanulo t
left join (select * from #ertekeles pivot (max(Ertekeles) for Tantargy in ('+@colsIn+'))pv) ertekeles on t.id=ertekeles.Tanulo
left join #temp temp on temp.Tanulo=t.id
left join (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 (CAST(MONTH(te.c_ertekelesdatum) AS VARCHAR))=@honap
group by te.c_tanuloid)atlag on atlag.Tanulo=t.id
order by t.Rendez
'
EXEC sp_executesql @query, N'@tanevId int, @intezmenyId int,@honap int', @tanevId, @intezmenyId,@honap;
drop table #tanulo
drop table #ertekeles
drop table #temp
END