181 lines
		
	
	
		
			9.2 KiB
		
	
	
	
		
			Transact-SQL
		
	
	
	
	
	
			
		
		
	
	
			181 lines
		
	
	
		
			9.2 KiB
		
	
	
	
		
			Transact-SQL
		
	
	
	
	
	
 | 
						|
/****** Object:  StoredProcedure [dbo].[sp_GetHelyettesitesekOrarend]    Script Date: 2016.06.19. 17:08:47 ******/
 | 
						|
SET ANSI_NULLS ON
 | 
						|
GO
 | 
						|
SET QUOTED_IDENTIFIER ON
 | 
						|
GO
 | 
						|
-- =============================================
 | 
						|
-- Author:			Dőrr Tamás
 | 
						|
-- Create date:		2016.06.08.
 | 
						|
-- Description:		
 | 
						|
-- =============================================
 | 
						|
IF OBJECT_ID('dbo.sp_GetHelyettesitesekOrarend') IS NOT NULL BEGIN
 | 
						|
  DROP PROCEDURE dbo.sp_GetHelyettesitesekOrarend
 | 
						|
END
 | 
						|
GO
 | 
						|
 | 
						|
CREATE PROCEDURE [dbo].[sp_GetHelyettesitesekOrarend]
 | 
						|
	@IntezmenyId int,
 | 
						|
	@TanevId int,
 | 
						|
	@IdoszakKezdete datetime,
 | 
						|
	@IdoszakVege datetime,
 | 
						|
	@TanarId int,
 | 
						|
	@CsakOrarendiOrak bit
 | 
						|
AS
 | 
						|
BEGIN
 | 
						|
	SET NOCOUNT ON;
 | 
						|
	
 | 
						|
	DECLARE @KezdoHet int = DATEPART( ISO_WEEK, @IdoszakKezdete);
 | 
						|
	DECLARE @ZaroHet int = DATEPART( ISO_WEEK, @IdoszakVege);
 | 
						|
	
 | 
						|
	
 | 
						|
	SELECT NAPTARINAP.Datum Datum
 | 
						|
	INTO #TEMPORARENDINAPOK
 | 
						|
	FROM (
 | 
						|
			(SELECT C_NAPDATUMA Datum FROM T_NAPTARINAP NAPTARINAP WHERE (TOROLT = 'F' AND C_NAPDATUMA >= @IdoszakKezdete AND C_NAPDATUMA < @IdoszakVege AND C_INTEZMENYID = @IntezmenyId AND C_TANEVID=@TanevId))
 | 
						|
		EXCEPT
 | 
						|
			(SELECT C_DATUM Datum FROM T_TANEVRENDJE TANEVRENDJE WHERE (TOROLT = 'F' AND (C_NAPTIPUSA IN (1386,1387,1389,1391,1392,1396,1397,1398,1399,1401) OR C_ORARENDINAP = 'F')  AND C_INTEZMENYID = @IntezmenyId AND C_TANEVID=@TanevId))
 | 
						|
		UNION
 | 
						|
			(SELECT Datum FROM (
 | 
						|
				SELECT
 | 
						|
					C_DATUM Datum,
 | 
						|
					COUNT (C_DATUM) DatumCounter
 | 
						|
				FROM
 | 
						|
					(SELECT C_DATUM, C_ORARENDINAP FROM T_TANEVRENDJE TANEVRENDJE WHERE (TOROLT = 'F') AND C_INTEZMENYID = @IntezmenyId AND C_TANEVID=@TanevId) TANEVRENDJE1 GROUP BY C_ORARENDINAP, C_DATUM
 | 
						|
			) TANEVRENDJE2
 | 
						|
			GROUP BY Datum
 | 
						|
			HAVING COUNT(Datum) = 2
 | 
						|
			)
 | 
						|
		) NAPTARINAP
 | 
						|
	
 | 
						|
	
 | 
						|
	DECLARE @VegzosUtolsoTanitasiNap_spGetOrarend DATETIME;
 | 
						|
	
 | 
						|
	
 | 
						|
	SELECT
 | 
						|
		@VegzosUtolsoTanitasiNap_spGetOrarend = C_DATUM
 | 
						|
	FROM
 | 
						|
		T_TANEVRENDJE
 | 
						|
	WHERE
 | 
						|
		TOROLT = 'F'
 | 
						|
		AND C_TANEVID = (SELECT ID FROM T_TANEV WHERE TOROLT = 'F' AND C_AKTIV = 'T' AND C_INTEZMENYID = @IntezmenyId)
 | 
						|
		AND C_NAPTIPUSA = 1402  AND C_INTEZMENYID = @IntezmenyId AND C_TANEVID=@TanevId
 | 
						|
	
 | 
						|
	
 | 
						|
	/*Tanítási órák*/
 | 
						|
	SELECT
 | 
						|
		TANITASIORA.ID Id,
 | 
						|
		TANITASIORA.C_ORARENDIORAID ORARENDIID,
 | 
						|
        TANITASIORA.C_BONTOTT Bontott,
 | 
						|
        (SELECT T_NAPTARINAP.C_HETIREND FROM T_NAPTARINAP WHERE T_NAPTARINAP.ID = TANITASIORA.C_NAPTARINAPID) Hetirend,
 | 
						|
        TANITASIORA.C_HETNAPJA HetNapja,
 | 
						|
        '' ErvenyessegKezdete,
 | 
						|
        '' ErvenyessegVege,
 | 
						|
        TANITASIORA.C_ORAKEZDETE OraKezdete,
 | 
						|
        TANITASIORA.C_ORAVEGE OraVege,
 | 
						|
        TANITASIORA.C_ORASZAM Oraszam,
 | 
						|
        ISNULL(TARGY.C_ROVIDNEV, TARGY.C_NEV) TargyNev,
 | 
						|
        TANITASIORA.C_MEGTARTOTT Megtartott,
 | 
						|
        TANITASIORA.C_CSENGETESIRENDORAID CsengetesiRendOraID,
 | 
						|
        OSZTALY.C_NEV OsztalyNev,
 | 
						|
        TANAR.C_NYOMTATASINEV TanarNev,
 | 
						|
        TEREM.C_NEV TeremNev,
 | 
						|
        'TanitasiOra' OraTipus,
 | 
						|
        ''Hianyzas,
 | 
						|
		'' Keses,
 | 
						|
		TANITASIORA.C_HELYETTESITOTANARID HelyettesitoTanarID,
 | 
						|
		TANAR.ID TanarID,
 | 
						|
		TANITASIORA.C_ADMINALTALKIIRT AdminAltalKiirt
 | 
						|
	INTO #TEMPORAK
 | 
						|
	FROM T_TANITASIORA TANITASIORA
 | 
						|
		LEFT JOIN T_TANTARGY TARGY ON (TARGY.ID = TANITASIORA.C_TANTARGYID  AND TARGY.C_INTEZMENYID = @IntezmenyId AND TARGY.C_TANEVID=@TanevId)
 | 
						|
        LEFT JOIN T_ORAK_TANAROK ON TANITASIORA.ID = T_ORAK_TANAROK.C_ORAKID
 | 
						|
        LEFT JOIN T_FELHASZNALO TANAR ON T_ORAK_TANAROK.C_TANAROKID = TANAR.ID
 | 
						|
        LEFT JOIN T_OSZTALYCSOPORT OSZTALY ON (TANITASIORA.C_OSZTALYCSOPORTID = OSZTALY.ID  AND OSZTALY.C_INTEZMENYID = @IntezmenyId AND OSZTALY.C_TANEVID=@TanevId)
 | 
						|
        LEFT JOIN T_TEREM TEREM ON (TEREM.id = TANITASIORA.C_TEREMID  AND TEREM.C_INTEZMENYID = @IntezmenyId AND TEREM.C_TANEVID=@TanevId)
 | 
						|
	WHERE
 | 
						|
		@CsakOrarendiOrak = 0 AND TANITASIORA.TOROLT='F'  AND TANITASIORA.C_INTEZMENYID = @IntezmenyId AND TANITASIORA.C_TANEVID=@TanevId
 | 
						|
		AND TANITASIORA.C_CSENGETESIRENDORAID IS NOT NULL
 | 
						|
		AND (TANITASIORA.C_ORAKEZDETE >= @IdoszakKezdete
 | 
						|
		AND TANITASIORA.C_ORAVEGE <= (CASE WHEN OSZTALY.C_VEGZOSEVFOLYAM = 'T' AND @VegzosUtolsoTanitasiNap_spGetOrarend IS NOT NULL AND @IdoszakVege > @VegzosUtolsoTanitasiNap_spGetOrarend THEN @VegzosUtolsoTanitasiNap_spGetOrarend ELSE @IdoszakVege END))
 | 
						|
		AND (@TanarId IS NULL OR ( TANITASIORA.C_HELYETTESITOTANARID = @TanarId OR TANITASIORA.C_ORATULAJDONOSID = @TanarId OR T_ORAK_TANAROK.C_TANAROKID = @TanarId))
 | 
						|
	
 | 
						|
	
 | 
						|
	/*Órarendi órák*/
 | 
						|
	INSERT INTO #TEMPORAK
 | 
						|
		SELECT DISTINCT
 | 
						|
			OrarendiOrak.Id, ORARENDIID, Bontott, Hetirend, HetNapja, ErvenyessegKezdete, ErvenyessegVege, OraKezdete, OraVege,
 | 
						|
			Oraszam, TargyNev, Megtartott, CsengetesiRendOraID, OsztalyNev, TanarNev, TeremNev, OraTipus, Hianyzas, Keses,
 | 
						|
			T_HELYETTESITESIIDOSZAK.C_HELYETTESTANAROKID HelyettesitoTanarID, TanarID,AdminAltalKiirt
 | 
						|
		FROM (
 | 
						|
			SELECT
 | 
						|
				T_ORARENDIORA.ID Id,
 | 
						|
				T_ORARENDIORA.ID ORARENDIID,
 | 
						|
				T_ORARENDIORA.C_BONTOTT Bontott,
 | 
						|
				T_ORARENDIORA.C_HETIREND Hetirend,
 | 
						|
				T_ORARENDIORA.C_HETNAPJA HetNapja,
 | 
						|
				T_ORARENDIORA.C_ORAERVENYESSEGKEZDETE ErvenyessegKezdete,
 | 
						|
				T_ORARENDIORA.C_ORAERVENYESSEGVEGE ErvenyessegVege,
 | 
						|
				CASE
 | 
						|
					WHEN T_ORARENDIORA.C_ORAKEZDETE IS NULL THEN DATEADD(HOUR, DATEPART(HOUR, T_CSENGETESIRENDORA.C_KEZDETE), DATEADD(MINUTE, DATEPART(MINUTE,T_CSENGETESIRENDORA.C_KEZDETE),  NAPTAR.C_NAPDATUMA))
 | 
						|
					ELSE T_ORARENDIORA.C_ORAKEZDETE
 | 
						|
				END OraKezdete,
 | 
						|
				CASE
 | 
						|
					WHEN T_ORARENDIORA.C_ORAVEGE IS NULL THEN DATEADD(HOUR, DATEPART(HOUR, T_CSENGETESIRENDORA.C_VEGE), DATEADD(MINUTE, DATEPART(MINUTE,T_CSENGETESIRENDORA.C_VEGE),  NAPTAR.C_NAPDATUMA))
 | 
						|
					ELSE T_ORARENDIORA.C_ORAVEGE
 | 
						|
				END OraVege,
 | 
						|
				T_CSENGETESIRENDORA.C_ORASZAM Oraszam,
 | 
						|
				ISNULL(TARGY.C_ROVIDNEV, TARGY.C_NEV) TargyNev,
 | 
						|
				'F' Megtartott,
 | 
						|
				T_CSENGETESIRENDORA.ID CsengetesiRendOraID,
 | 
						|
				OSZTALY.C_NEV OsztalyNev,
 | 
						|
				TANAR.C_NYOMTATASINEV TanarNev,
 | 
						|
				TEREM.C_NEV TeremNev,
 | 
						|
				'OrarendiOra'  OraTipus,
 | 
						|
				'F' Hianyzas,
 | 
						|
				'F' Keses,
 | 
						|
				TANAR.ID TanarID,
 | 
						|
				'F' AdminAltalKiirt
 | 
						|
			 FROM
 | 
						|
				T_ORARENDIORA
 | 
						|
				INNER JOIN T_CSENGETESIRENDORA ON (T_CSENGETESIRENDORA.ID=T_ORARENDIORA.C_CSENGETESIRENDORAID  AND T_CSENGETESIRENDORA.C_INTEZMENYID = @IntezmenyId AND T_CSENGETESIRENDORA.C_TANEVID=@TanevId)
 | 
						|
				INNER JOIN T_FOGLALKOZAS ON (T_FOGLALKOZAS.ID= T_ORARENDIORA.C_FOGLALKOZASID  AND T_FOGLALKOZAS.C_INTEZMENYID = @IntezmenyId AND T_FOGLALKOZAS.C_TANEVID=@TanevId)
 | 
						|
				INNER JOIN T_NAPTARINAP NAPTAR ON (( T_ORARENDIORA.C_HETIREND = 1554 OR NAPTAR.C_HETIREND = T_ORARENDIORA.C_HETIREND ) AND NAPTAR.C_HETNAPJA = T_ORARENDIORA.C_HETNAPJA  AND NAPTAR.C_INTEZMENYID = @IntezmenyId AND NAPTAR.C_TANEVID=@TanevId)
 | 
						|
				INNER JOIN #TEMPORARENDINAPOK ORARENDINAPOK ON ORARENDINAPOK.Datum = NAPTAR.C_NAPDATUMA
 | 
						|
				LEFT JOIN T_FOGLALKOZASOK_TANAROK ON T_FOGLALKOZASOK_TANAROK.C_FOGLALKOZASOKID = T_FOGLALKOZAS.ID
 | 
						|
				LEFT JOIN T_TANTARGY TARGY ON (TARGY.ID= T_FOGLALKOZAS.C_TANTARGYID AND TARGY.TOROLT = 'F' AND TARGY.C_INTEZMENYID = @IntezmenyId AND TARGY.C_TANEVID=@TanevId)
 | 
						|
				LEFT JOIN T_FELHASZNALO TANAR ON T_FOGLALKOZASOK_TANAROK.C_TANAROKID = TANAR.ID AND TANAR.TOROLT= 'F'
 | 
						|
				LEFT JOIN T_OSZTALYCSOPORT OSZTALY ON (T_FOGLALKOZAS.C_OSZTALYCSOPORTID = OSZTALY.ID  AND OSZTALY.C_INTEZMENYID = @IntezmenyId AND OSZTALY.C_TANEVID=@TanevId)
 | 
						|
				LEFT JOIN T_TEREM TEREM ON (TEREM.id = T_ORARENDIORA.C_TEREMID AND TEREM.C_INTEZMENYID = @IntezmenyId AND TEREM.C_TANEVID=@TanevId)
 | 
						|
			 WHERE
 | 
						|
				T_ORARENDIORA.TOROLT='F'
 | 
						|
				AND T_ORARENDIORA.C_CSENGETESIRENDORAID IS NOT NULL
 | 
						|
				AND T_ORARENDIORA.C_INTEZMENYID = @IntezmenyId AND T_ORARENDIORA.C_TANEVID=@TanevId
 | 
						|
				AND T_ORARENDIORA.C_ORAERVENYESSEGVEGE >= @IdoszakKezdete AND T_ORARENDIORA.C_ORAERVENYESSEGKEZDETE <= (CASE WHEN OSZTALY.C_VEGZOSEVFOLYAM = 'T' AND @VegzosUtolsoTanitasiNap_spGetOrarend IS NOT NULL AND @IdoszakVege > @VegzosUtolsoTanitasiNap_spGetOrarend THEN @VegzosUtolsoTanitasiNap_spGetOrarend ELSE @IdoszakVege END)
 | 
						|
				AND NAPTAR.C_NAPDATUMA BETWEEN @IdoszakKezdete AND (CASE WHEN OSZTALY.C_VEGZOSEVFOLYAM = 'T' AND @VegzosUtolsoTanitasiNap_spGetOrarend IS NOT NULL AND @IdoszakVege > @VegzosUtolsoTanitasiNap_spGetOrarend THEN @VegzosUtolsoTanitasiNap_spGetOrarend ELSE @IdoszakVege END)
 | 
						|
				--AND NAPTAR.C_NAPDATUMA BETWEEN  CAST(T_ORARENDIORA.C_ORAERVENYESSEGKEZDETE AS DATE) AND CAST(T_ORARENDIORA.C_ORAERVENYESSEGVEGE AS DATE)
 | 
						|
				AND (
 | 
						|
					(NAPTAR.C_NAPDATUMA >= T_ORARENDIORA.C_ORAERVENYESSEGKEZDETE AND NAPTAR.C_NAPDATUMA < T_ORARENDIORA.C_ORAERVENYESSEGVEGE) 
 | 
						|
					OR
 | 
						|
					(NAPTAR.C_NAPDATUMA = T_ORARENDIORA.C_ORAERVENYESSEGKEZDETE AND NAPTAR.C_NAPDATUMA = T_ORARENDIORA.C_ORAERVENYESSEGVEGE)
 | 
						|
				)
 | 
						|
				
 | 
						|
			) OrarendiOrak
 | 
						|
			LEFT JOIN T_HELYETTESITESIIDOSZAK ON (OrarendiOrak.ID = T_HELYETTESITESIIDOSZAK.C_HELYETTESITETTORARENDID And T_HELYETTESITESIIDOSZAK.C_HETSORSZAMA >= @KezdoHet AND (T_HELYETTESITESIIDOSZAK.C_HETSORSZAMA <= @ZaroHet)
 | 
						|
		) WHERE (@TanarId IS NULL OR OrarendiOrak.TanarID = @TanarId OR T_HELYETTESITESIIDOSZAK.C_HELYETTESTANAROKID = @TanarId)
 | 
						|
				AND NOT EXISTS (
 | 
						|
					SELECT 1 FROM #TEMPORAK TANORAK WHERE TANORAK.ORARENDIID = OrarendiOrak.ID AND TANORAK.OraKezdete = OrarendiOrak.[OraKezdete] AND TANORAK.OraVege = OrarendiOrak.[OraVege]
 | 
						|
				)
 | 
						|
	
 | 
						|
	--SELECT * FROM #TEMPORAK order by orakezdete
 | 
						|
	
 | 
						|
	
 | 
						|
	SELECT t.*, hi.ID as HelyettesitesId, f.C_NYOMTATASINEV as HelyettesitoTanarNev FROM #TEMPORAK t
 | 
						|
	LEFT JOIN T_HELYETTESITESIIDOSZAK hi ON hi.C_HELYETTESITETTORARENDID = t.ORARENDIID AND DATEDIFF(DAY, t.OraKezdete, hi.C_HELYETTESITESNAPJA) = 0
 | 
						|
	LEFT JOIN T_FELHASZNALO f ON f.ID = hi.C_HELYETTESTANAROKID
 | 
						|
	ORDER BY t.orakezdete
 | 
						|
	
 | 
						|
	
 | 
						|
	DROP TABLE #TEMPORAK
 | 
						|
	DROP TABLE #TEMPORARENDINAPOK
 | 
						|
END |