133 lines
No EOL
6.1 KiB
Transact-SQL
133 lines
No EOL
6.1 KiB
Transact-SQL
SET ANSI_NULLS ON
|
|
GO
|
|
SET QUOTED_IDENTIFIER ON
|
|
GO
|
|
|
|
IF OBJECT_ID('[dbo].[sp_GetPedagogusOrarend]') IS NOT NULL
|
|
BEGIN
|
|
DROP PROCEDURE [dbo].[sp_GetPedagogusOrarend]
|
|
END
|
|
GO
|
|
-- =============================================
|
|
-- Author: Dőrr Tamás
|
|
-- Create date: 2015.12.16.
|
|
-- Description: sp_GetPedagogusOrarend
|
|
-- =============================================
|
|
CREATE PROCEDURE [dbo].[sp_GetPedagogusOrarend]
|
|
@PedagogusId int,
|
|
@TanevId int,
|
|
@intezmenyId int,
|
|
@Reszletes bit=0
|
|
|
|
AS
|
|
BEGIN
|
|
SET NOCOUNT ON;
|
|
|
|
/*Intézmény és tanár név*/
|
|
declare @AktivtanevId int = (select Id from T_TANEV_OSSZES tanev where c_aktiv='T' and c_intezmenyId=@intezmenyId)
|
|
|
|
declare @HetEleje date
|
|
declare @HetVege date
|
|
|
|
if (@tanevId=@AktivtanevId)
|
|
begin
|
|
set @HetEleje =(select top 1 nh.c_hetkezdonapja from T_NAPTARIHET_OSSZES nh where convert(date, getdate())>convert(date, nh.c_hetkezdonapja) and convert(date, getdate())<convert(date, nh.c_hetutolsonapja) and nh.torolt='F' and nh.c_tanevid=@tanevid and nh.c_intezmenyId=@intezmenyId)
|
|
set @HetVege =(select top 1 nh.c_hetutolsonapja from T_NAPTARIHET_OSSZES nh where convert(date, getdate())>convert(date, nh.c_hetkezdonapja) and convert(date, getdate())<convert(date, nh.c_hetutolsonapja) and nh.torolt='F' and nh.c_tanevid=@tanevid and nh.c_intezmenyId=@intezmenyId)
|
|
end
|
|
else
|
|
begin
|
|
declare @UtolsoNap date = (select top 1 c_napdatuma from t_naptarinap_osszes where c_naptipusa=1395 and c_intezmenyId=@intezmenyId and c_tanevId=@tanevid and torolt='F')
|
|
set @HetEleje =(select top 1 nh.c_hetkezdonapja from T_NAPTARIHET_OSSZES nh where @UtolsoNap>convert(date, nh.c_hetkezdonapja) and @UtolsoNap<convert(date, nh.c_hetutolsonapja) and nh.torolt='F' and nh.c_tanevid=@tanevid and nh.c_intezmenyId=@intezmenyId)
|
|
set @HetVege =(select top 1 nh.c_hetutolsonapja from T_NAPTARIHET_OSSZES nh where @UtolsoNap>convert(date, nh.c_hetkezdonapja) and @UtolsoNap<convert(date, nh.c_hetutolsonapja) and nh.torolt='F' and nh.c_tanevid=@tanevid and nh.c_intezmenyId=@intezmenyId)
|
|
end
|
|
|
|
if @Reszletes=1
|
|
begin
|
|
select top(1)
|
|
f.C_NYOMTATASINEV as TANAR_NEV
|
|
,i.C_NEV as INTEZMENY_NEV
|
|
,i.C_OMKOD as INTEZMENY_OMKOD
|
|
from T_ALKALMAZOTT_OSSZES a
|
|
join T_FELHASZNALO_OSSZES f on f.ID = a.ID and f.TOROLT = 'F'
|
|
join T_FOGLALKOZASOK_TANAROK on T_FOGLALKOZASOK_TANAROK.C_TANAROKID = a.ID
|
|
join T_FOGLALKOZAS_OSSZES fo on fo.ID = T_FOGLALKOZASOK_TANAROK.C_FOGLALKOZASOKID and fo.TOROLT = 'F'
|
|
join T_OSZTALYCSOPORT_OSSZES ocs on ocs.ID = fo.C_OSZTALYCSOPORTID and ocs.TOROLT = 'F'
|
|
join T_INTEZMENYADATOK_OSSZES i on i.C_INTEZMENYID = a.C_ALINTEZMENYID and i.C_TANEVID = a.C_ALTANEVID and i.TOROLT = 'F'
|
|
where a.ID = @PedagogusId
|
|
and a.C_ALTANEVID = @TanevId
|
|
and i.C_INTEZMENYID=@intezmenyId
|
|
and a.TOROLT = 'F'
|
|
end
|
|
|
|
declare @tmpTable table (TanarId int, Ora int, Hetirend int, TanarNev nvarchar(255), [1408] nvarchar(255), [1409] nvarchar(255), [1410] nvarchar(255), [1411] nvarchar(255), [1412] nvarchar(255), [1413] nvarchar(255))
|
|
|
|
DECLARE @ID INT = 0
|
|
WHILE (1 = 1)
|
|
BEGIN
|
|
|
|
SELECT TOP 1 @ID = ID FROM T_HETIRENDTIPUS_OSSZES WHERE TOROLT ='F' and ID != 1554 and ID > @ID and C_ALTANEVID = @TanevId ORDER BY ID
|
|
IF @@ROWCOUNT = 0 BREAK;
|
|
|
|
declare @Napok table (NapId int) insert into @Napok select ID from T_DICTIONARYITEMBASE_OSSZES where ID in (1408,1409,1410,1411,1412,1413) and C_TANEVID = @TanevId
|
|
declare @Orak table (OraId int) insert into @Orak select C_ORASZAM from T_CSENGETESIRENDORA where TOROLT = 'F' and C_TANEVID = @TanevId and C_ORASZAM<=10
|
|
declare @TenylegesOrak table (OraId int, NapId int, Leiras nvarchar(MAX), HetirendID int)
|
|
insert into @TenylegesOrak
|
|
select
|
|
csro.C_ORASZAM as ORASZAM
|
|
,oo.C_HETNAPJA as HETNAP,
|
|
STUFF((select ', ' + bocs.C_NEV + ' - ' + btt.C_NEV + ' - ' + bt.C_NEV from T_ALKALMAZOTT_OSSZES ba
|
|
join T_ORARENDIORA_OSSZES boo on boo.C_TANARID = ba.ID and boo.torolt='F' and ((boo.C_ORAERVENYESSEGKEZDETE<=@HetEleje) and (boo.c_oraervenyessegvege>=@HetVege)or
|
|
(boo.C_ORAERVENYESSEGKEZDETE>=@HetEleje) and (boo.C_ORAERVENYESSEGKEZDETE<=@HetVege))
|
|
join T_FELHASZNALO_OSSZES bf on bf.ID = a.ID
|
|
join T_TANTARGY_OSSZES btt on btt.ID = boo.C_TANTARGYID
|
|
join T_OSZTALYCSOPORT_OSSZES bocs on bocs.ID =boo.C_OSZTALYCSOPORTID
|
|
join T_TEREM_OSSZES bt on bt.ID = boo.C_TEREMID
|
|
left outer join T_CSENGETESIRENDORA_OSSZES bcsro on bcsro.ID = boo.C_CSENGETESIRENDORAID
|
|
where
|
|
a.ID = ba.ID
|
|
and a.C_ALTANEVID = ba.C_ALTANEVID
|
|
and boo.C_HETIREND in (@ID,1554)
|
|
and bcsro.C_ORASZAM=csro.c_oraszam
|
|
and boo.C_HETNAPJA=oo.C_HETNAPJA FOR XML PATH(''), TYPE).value('.','NVARCHAR(MAX)'),1,2,' ') MATRIX_DATA
|
|
,@ID AS HetiRendID
|
|
from T_ALKALMAZOTT_OSSZES a
|
|
join T_ORARENDIORA_OSSZES oo on oo.C_TANARID = a.ID and ((oo.C_ORAERVENYESSEGKEZDETE<=@HetEleje) and (oo.c_oraervenyessegvege>=@HetVege)or
|
|
(oo.C_ORAERVENYESSEGKEZDETE>=@HetEleje) and (oo.C_ORAERVENYESSEGKEZDETE<=@HetVege))
|
|
and oo.torolt='F'
|
|
join T_FELHASZNALO_OSSZES f on f.ID = a.ID
|
|
join T_TANTARGY_OSSZES tt on tt.ID = oo.C_TANTARGYID
|
|
join T_OSZTALYCSOPORT_OSSZES ocs on ocs.ID =oo.C_OSZTALYCSOPORTID
|
|
join T_TEREM_OSSZES t on t.ID = oo.C_TEREMID
|
|
left outer join T_CSENGETESIRENDORA_OSSZES csro on csro.ID = oo.C_CSENGETESIRENDORAID
|
|
where
|
|
a.ID = @PedagogusId
|
|
and a.C_ALTANEVID = @TanevId
|
|
and oo.C_HETIREND in (@ID,1554)
|
|
|
|
insert into @tmpTable
|
|
select * from
|
|
(
|
|
select
|
|
@PedagogusId as TanarId,
|
|
O.OraId as Ora
|
|
,N.NapId as Nap
|
|
,T.Leiras as Leiras
|
|
,@ID as HetiRend
|
|
,(select top 1 f.C_NYOMTATASINEV from T_FELHASZNALO_OSSZES f where f.ID = @PedagogusId and f.C_TANEVID = @TanevId and f.TOROLT = 'F') as TanarNev
|
|
from @Napok N
|
|
cross join @Orak O
|
|
left join @TenylegesOrak T on T.NapId = N.NapId and T.OraId = O.OraId AND T.HetiRendID in (@ID,1554)
|
|
) o1
|
|
PIVOT
|
|
(
|
|
MAX (Leiras)
|
|
FOR [Nap]
|
|
IN ([1408], [1409], [1410], [1411], [1412], [1413])
|
|
) p1
|
|
END
|
|
|
|
select * from @tmpTable
|
|
|
|
END
|
|
|
|
GO |