144 lines
		
	
	
		
			5.4 KiB
		
	
	
	
		
			Transact-SQL
		
	
	
	
	
	
			
		
		
	
	
			144 lines
		
	
	
		
			5.4 KiB
		
	
	
	
		
			Transact-SQL
		
	
	
	
	
	
IF OBJECT_ID('[dbo].[sp_GetHelyettesitesiNaplo]') IS NOT NULL 
 | 
						|
BEGIN
 | 
						|
  DROP PROCEDURE [dbo].[sp_GetHelyettesitesiNaplo]
 | 
						|
END  
 | 
						|
GO
 | 
						|
-- ===================================================================
 | 
						|
-- Author: Tóth Imre Attila
 | 
						|
-- Create date: 2016. 08. 01.
 | 
						|
-- Description: Lekérdezések a helyettesítési naplóhoz
 | 
						|
-- ===================================================================
 | 
						|
CREATE PROCEDURE [dbo].[sp_GetHelyettesitesiNaplo]
 | 
						|
  @tanarID int,
 | 
						|
  @tanevID int,
 | 
						|
  @intezmenyid int
 | 
						|
AS  
 | 
						|
BEGIN
 | 
						|
SET NOCOUNT ON;
 | 
						|
 | 
						|
-- ===================================
 | 
						|
-- FEJLÉC
 | 
						|
-- ===================================
 | 
						|
  DECLARE @table TABLE (
 | 
						|
	  EvHonap nvarchar(10),
 | 
						|
	  Helyettesito nvarchar(100)
 | 
						|
	)
 | 
						|
 
 | 
						|
	INSERT INTO @table
 | 
						|
	SELECT DISTINCT 
 | 
						|
		format(C_DATUM, 'yyyy.MM') AS EvHonap,
 | 
						|
		felhHelyettes.C_NYOMTATASINEV AS Helyettesito
 | 
						|
	FROM T_TANITASIORA_OSSZES tOra
 | 
						|
		LEFT JOIN T_FELHASZNALO_OSSZES felhHelyettes on felhHelyettes.ID = tOra.C_HELYETTESITOTANARID
 | 
						|
	WHERE tOra.C_HELYETTESITOTANARID = @tanarID
 | 
						|
		AND tOra.C_TANEVID = @tanevID
 | 
						|
		AND tOra.Torolt='F'
 | 
						|
 | 
						|
	SELECT * FROM @table
 | 
						|
 | 
						|
	SELECT
 | 
						|
		format(C_NAPDATUMA, 'yyyy.MM') AS EvHonap,
 | 
						|
		C_HETNAPJA AS Nap
 | 
						|
	FROM T_NAPTARINAP_OSSZES 
 | 
						|
	WHERE format(C_NAPDATUMA, 'yyyy.MM') IN (SELECT EvHonap FROM @table)
 | 
						|
 | 
						|
  -- ===================================
 | 
						|
  -- HELYETTESÍTÉSEK (SOROK)
 | 
						|
  -- ===================================
 | 
						|
	
 | 
						|
  DECLARE @oraSorszam TABLE (Id int, EvesSorszam int)
 | 
						|
  
 | 
						|
  INSERT INTO @oraSorszam
 | 
						|
  SELECT DISTINCT 
 | 
						|
	s.Id
 | 
						|
	, s.EvesSorszam 
 | 
						|
  FROM (
 | 
						|
    SELECT DISTINCT 
 | 
						|
		tn.C_TANTARGYID
 | 
						|
		, tn.C_OSZTALYCSOPORTID
 | 
						|
		, tn.C_TANARID
 | 
						|
		, tn.C_INTEZMENYID
 | 
						|
    FROM T_TANITASIORA_OSSZES tn
 | 
						|
    WHERE C_HELYETTESITOTANARID = @tanarID 
 | 
						|
      AND C_TANEVID = @tanevID
 | 
						|
  ) x
 | 
						|
  CROSS APPLY dbo.fnGetEvesOraszamLista (
 | 
						|
     x.C_TANTARGYID
 | 
						|
    ,x.C_OSZTALYCSOPORTID
 | 
						|
    ,x.C_TANARID
 | 
						|
    ,GETDATE() 
 | 
						|
    ,x.C_INTEZMENYID
 | 
						|
    ,@tanevID
 | 
						|
  ) s
 | 
						|
  
 | 
						|
  SELECT DISTINCT 
 | 
						|
		 ROW_NUMBER() over(PARTITION BY FORMAT(C_DATUM, 'yyyy.MM') ORDER BY C_DATUM) Sorsz
 | 
						|
		,tOra.C_ORASZAM AS Oraszam
 | 
						|
		,DicItemBase.C_NAME AS HelyettesitesTipusa
 | 
						|
		,FORMAT(C_DATUM, 'yyyy.MM.dd.') AS Datum
 | 
						|
		,FORMAT(C_DATUM, 'yyyy.MM') AS EvHonap
 | 
						|
		,felhOraTul.C_NYOMTATASINEV AS Helyettesitett 
 | 
						|
		,osztcsop.C_NEV AS OsztalyCsoport
 | 
						|
		,tant.C_NEV AS Tantargy
 | 
						|
		,tOra.C_TEMA AS Tema
 | 
						|
		,s.EvesSorszam AS EvesSorszam
 | 
						|
	FROM T_TANITASIORA_OSSZES tOra
 | 
						|
		LEFT JOIN @oraSorszam s ON s.ID = tOra.ID
 | 
						|
		LEFT JOIN T_ORARENDIORA_OSSZES oo ON oo.ID = tOra.C_ORARENDIORAID
 | 
						|
		LEFT JOIN T_FELHASZNALO_OSSZES felhOraTul ON felhOraTul.ID = tOra.C_TANARID
 | 
						|
		LEFT JOIN T_FELHASZNALO_OSSZES helyettesito ON helyettesito.ID = tOra.C_HELYETTESITOTANARID
 | 
						|
		LEFT JOIN (SELECT DISTINCT ID, C_NAME FROM T_DICTIONARYITEMBASE_OSSZES) DicItemBase on DicItemBase.ID = tOra.C_HELYETTESITESTIPUSA
 | 
						|
		LEFT JOIN T_OSZTALYCSOPORT_OSSZES osztcsop ON osztcsop.ID = tOra.C_OSZTALYCSOPORTID
 | 
						|
		LEFT JOIN T_TANTARGY_OSSZES tant ON tant.ID = tOra.C_TANTARGYID
 | 
						|
	WHERE helyettesito.ID = @tanarID
 | 
						|
		AND tOra.C_TANEVID = @tanevID
 | 
						|
		AND tOra.Torolt = 'F'
 | 
						|
	ORDER BY Sorsz ASC
 | 
						|
	
 | 
						|
  -- ===================================
 | 
						|
  -- HELYETTESÍTÉSEK NAPIBONTÁSBAN
 | 
						|
  -- ===================================
 | 
						|
	SELECT
 | 
						|
		EvHonap,
 | 
						|
		OsztalyCsoport = TantargyN + ' - '  + OsztCsopN,
 | 
						|
		ISNULL([1], 0) AS [1], ISNULL([2], 0) AS [2], ISNULL([3], 0) AS [3], ISNULL([4], 0) AS [4], ISNULL([5], 0) AS [5], ISNULL([6], 0) AS [6], ISNULL([7], 0) AS [7], ISNULL([8], 0) AS [8], ISNULL([9], 0) AS [9], ISNULL([10], 0) AS [10], 
 | 
						|
		ISNULL([11], 0) AS [11], ISNULL([12], 0) AS [12], ISNULL([13], 0) AS [13], ISNULL([14], 0) AS [14], ISNULL([15], 0) AS [15], ISNULL([16], 0) AS [16], ISNULL([17], 0) AS [17], ISNULL([18], 0) AS [18], ISNULL([19], 0) AS [19], ISNULL([20], 0) AS [20],
 | 
						|
		ISNULL([21], 0) AS [21], ISNULL([22], 0) AS [22], ISNULL([23], 0) AS [23], ISNULL([24], 0) AS [24], ISNULL([25], 0) AS [25], ISNULL([26], 0) AS [26], ISNULL([27], 0) AS [27], ISNULL([28], 0) AS [28], ISNULL([29], 0) AS [29], ISNULL([30], 0) AS [30],
 | 
						|
		ISNULL([31], 0) AS [31],
 | 
						|
		ISNULL([1], 0) + ISNULL([2], 0) + ISNULL([3], 0) + ISNULL([4], 0) + ISNULL([5], 0) + ISNULL([6], 0) + ISNULL([7], 0) + ISNULL([8], 0) + ISNULL([9], 0) + ISNULL([10], 0) + 
 | 
						|
		ISNULL([11], 0) + ISNULL([12], 0) + ISNULL([13], 0) + ISNULL([14], 0) + ISNULL([15], 0) + ISNULL([16], 0) + ISNULL([17], 0) + ISNULL([18], 0) + ISNULL([19], 0) + ISNULL([20], 0) +
 | 
						|
		ISNULL([21], 0) + ISNULL([22], 0) + ISNULL([23], 0) + ISNULL([24], 0) + ISNULL([25], 0) + ISNULL([26], 0) + ISNULL([27], 0) + ISNULL([28], 0) + ISNULL([29], 0) + ISNULL([30], 0) +
 | 
						|
		ISNULL([31], 0) AS Ossz
 | 
						|
	FROM (
 | 
						|
		SELECT 
 | 
						|
			CASE (tOra.c_helyettesitestipusa)
 | 
						|
				WHEN '1496' THEN COUNT(tant.C_NEV)
 | 
						|
				WHEN '1494' THEN COUNT(tant.C_NEV)
 | 
						|
				WHEN '1495' THEN COUNT(tant.C_NEV)
 | 
						|
			END AS Tant,
 | 
						|
			osztCsop.C_NEV AS osztcsopN,
 | 
						|
			tant.C_NEV AS TantargyN,
 | 
						|
			DATEPART(DAY, C_DATUM) AS Nap,
 | 
						|
			FORMAT(C_DATUM, 'yyyy.MM') AS EvHonap
 | 
						|
		FROM T_TANITASIORA_OSSZES tOra
 | 
						|
			INNER JOIN T_TANTARGY_OSSZES tant on tant.ID = tOra.C_TANTARGYID
 | 
						|
			INNER JOIN T_OSZTALYCSOPORT_OSSZES osztCsop on osztCsop.ID = tOra.C_OSZTALYCSOPORTID
 | 
						|
		WHERE 
 | 
						|
			tOra.C_HELYETTESITOTANARID = @tanarID
 | 
						|
			AND tOra.C_TANEVID = @tanevID
 | 
						|
			AND TOra.TOROLT='F'
 | 
						|
		GROUP BY 
 | 
						|
			osztCsop.C_NEV, tant.C_NEV, C_DATUM, tOra.c_helyettesitestipusa
 | 
						|
	) T
 | 
						|
	PIVOT (
 | 
						|
		max(Tant)
 | 
						|
		FOR Nap IN (
 | 
						|
			[1], [2], [3], [4], [5], [6], [7], [8], [9], [10], 
 | 
						|
			[11], [12], [13], [14], [15], [16], [17], [18], [19], [20],
 | 
						|
			[21], [22], [23], [24], [25], [26], [27], [28], [29], [30], [31]
 | 
						|
			)
 | 
						|
	) Helyettesitesek
 | 
						|
 | 
						|
END
 | 
						|
 | 
						|
GO |