368 lines
No EOL
13 KiB
Transact-SQL
368 lines
No EOL
13 KiB
Transact-SQL
DROP PROCEDURE IF EXISTS [dbo].[uspGetHaladasiNaploAdatok]
|
|
GO
|
|
|
|
CREATE PROCEDURE [dbo].[uspGetHaladasiNaploAdatok]
|
|
@tanevID int,
|
|
@osztalyID int = null,
|
|
@tanarID int = null,
|
|
@feladatKategoriaId int = null,
|
|
@isKapcsolodoCsoportokSzureseOsztalyBesorolasra int = null
|
|
AS
|
|
BEGIN
|
|
DECLARE @cTantargyId INT = 0
|
|
DECLARE @cOsztalyCsoportId INT = 0
|
|
DECLARE @cTanarId INT = 0
|
|
DECLARE @foglalkozasNev VARCHAR(255)
|
|
DECLARE @columns NVARCHAR(MAX), @columnsWithAlias nvarchar(max), @columnsWithType nvarchar(max), @sql NVARCHAR(MAX);
|
|
|
|
SET NOCOUNT ON;
|
|
CREATE TABLE #Foglalkozasok (
|
|
Nev nvarchar(511) COLLATE Hungarian_CI_AI
|
|
,C_TANTARGYID int
|
|
,C_OSZTALYCSOPORTID int
|
|
,C_INTEZMENYID int
|
|
,C_TANARID int
|
|
,VanTTF char(1)
|
|
)
|
|
|
|
INSERT INTO #Foglalkozasok
|
|
SELECT DISTINCT
|
|
ocs.C_NEV + ' - ' + tt.C_NEV AS Nev
|
|
,tn.C_TANTARGYID
|
|
,tn.C_OSZTALYCSOPORTID
|
|
,tn.C_INTEZMENYID
|
|
,tn.C_TANARID AS C_TANARID
|
|
,IIF(f.ID IS NULL,'F','T') AS VanTTF
|
|
FROM T_TANITASIORA_OSSZES tn
|
|
LEFT JOIN T_FOGLALKOZAS_OSSZES f ON f.C_TANTARGYID = tn.C_TANTARGYID AND f.C_OSZTALYCSOPORTID = tn.C_OSZTALYCSOPORTID AND f.C_TANARID = tn.C_TANARID AND f.TOROLT = 'F'
|
|
INNER JOIN T_OSZTALYCSOPORT_OSSZES OCS on OCS.ID = tn.C_OSZTALYCSOPORTID and OCS.TOROLT = 'F' AND (OCS.C_FELADATKATEGORIAID = @feladatKategoriaId OR @feladatKategoriaId IS NULL)
|
|
INNER JOIN T_TANTARGY_OSSZES tt on tt.ID = tn.C_TANTARGYID and tt.TOROLT = 'F'
|
|
LEFT JOIN (SELECT ID FROM fnGetDokumentumKapcsolodoOsztalycsoportok(@osztalyID, @tanevID, 0, @isKapcsolodoCsoportokSzureseOsztalyBesorolasra)) kocs ON kocs.ID = ocs.ID AND @osztalyID IS NOT NULL
|
|
WHERE tn.TOROLT = 'F'
|
|
AND tn.C_TANEVID = @tanevID
|
|
AND (
|
|
((@osztalyID IS NOT NULL) AND (kocs.ID IS NOT NULL))
|
|
OR
|
|
((@tanarID IS NOT NULL) AND tn.C_TANARID = @tanarID)
|
|
)
|
|
ORDER BY VanTTF DESC, Nev ASC
|
|
|
|
SELECT
|
|
IIF(fog.VanTTF = 'F','Egyedi-','') + Nev + ' - ' + felh.C_NYOMTATASINEV AS Nev
|
|
,fog.VanTTF AS VanTTF
|
|
FROM #Foglalkozasok fog
|
|
INNER JOIN T_FELHASZNALO_OSSZES felh on fog.C_TANARID = felh.ID
|
|
ORDER BY fog.VanTTF DESC, Nev ASC
|
|
|
|
SET @columns = N'';
|
|
SELECT @columns+=N', '+QUOTENAME([Name])
|
|
FROM
|
|
(
|
|
SELECT ID AS [Name]
|
|
FROM T_ORATULAJDONSAGTIPUS AS p
|
|
WHERE ID BETWEEN 8356 AND 8615
|
|
GROUP BY ID
|
|
) AS x;
|
|
SET @columnsWithAlias = N'';
|
|
SELECT @columnsWithAlias+=N', ISNULL('+QUOTENAME([Name]) + ', ''F'') AS ' +QUOTENAME([Name])
|
|
FROM
|
|
(
|
|
SELECT ID AS [Name]
|
|
FROM T_ORATULAJDONSAGTIPUS AS p
|
|
WHERE ID BETWEEN 8356 AND 8615
|
|
GROUP BY ID
|
|
) AS x;
|
|
SET @columnsWithType = N'';
|
|
SELECT @columnsWithType += N', '+QUOTENAME([Name]) + ' char'
|
|
FROM
|
|
(
|
|
SELECT ID AS [Name]
|
|
FROM T_ORATULAJDONSAGTIPUS AS p
|
|
WHERE ID BETWEEN 8356 AND 8615
|
|
GROUP BY ID
|
|
) AS x;
|
|
|
|
DECLARE foglalkozasCursor CURSOR FOR
|
|
SELECT C_TANTARGYID, C_OSZTALYCSOPORTID, C_TANARID FROM #Foglalkozasok fog
|
|
INNER JOIN T_FELHASZNALO_OSSZES felh on fog.C_TANARID = felh.ID
|
|
ORDER BY VanTTF DESC, IIF(fog.VanTTF = 'F','Egyedi-','') + Nev + ' - ' + felh.C_NYOMTATASINEV ASC
|
|
|
|
OPEN foglalkozasCursor
|
|
FETCH NEXT FROM foglalkozasCursor into @cTantargyId, @cOsztalyCsoportId, @cTanarId
|
|
|
|
WHILE @@FETCH_STATUS = 0 BEGIN
|
|
SET @sql = N'
|
|
SELECT
|
|
OraSorszam
|
|
,TanarNev
|
|
,TanarOktAzon
|
|
,Tema
|
|
,Helyettesitett
|
|
,Datum
|
|
,OraSzam
|
|
,Megjegyzes
|
|
,HaziFeladat
|
|
,TulOra
|
|
,TamopOra
|
|
,NemszakrendszeruOra
|
|
,IktOra
|
|
,NemzetisegiOra
|
|
,IsFelnottoktatasiSzerzodes
|
|
,TestnevelesOra
|
|
,IprOra
|
|
,DifferencialtOra
|
|
,KooperativOra
|
|
,MeresOra
|
|
,DramaOra
|
|
,ParhuzamosOra
|
|
,TiopOra
|
|
,VEKOP73317
|
|
,KAPOra
|
|
,Bontott
|
|
,Multikulturalis
|
|
,EFOP32317
|
|
,GINOP623
|
|
,EFOP31716
|
|
,EFOP33717
|
|
,TIOP1111212012001
|
|
,EFOP23517
|
|
-- Komplex alapprogram adatok
|
|
,DFHTora
|
|
,DFHTKIPora
|
|
,KIPOra
|
|
,TEorad
|
|
,Rahangolodas
|
|
,Komplexora
|
|
,DigitalisAlapuAlprogram
|
|
,TestmozgasAlapuAlprogram
|
|
,EletGyakorlatAlapuAlprogram
|
|
,MuveszetAlapuAlprogram
|
|
,LogikaiAlapuAlprogram
|
|
,DigEszkozTipus
|
|
,DigPlatformTipus
|
|
,DigTamEszkozTipus
|
|
' + @columnsWithAlias + N'
|
|
FROM (
|
|
SELECT
|
|
tn.ID
|
|
,CASE
|
|
WHEN tn.C_MEGTARTOTT = ''T'' THEN CAST(tn.C_ORAEVESSORSZAMA AS nvarchar(max))
|
|
ELSE ''Elmaradt''
|
|
END AS OraSorszam
|
|
,fh.C_NYOMTATASINEV AS TanarNev
|
|
,fh.C_OKTATASIAZONOSITO AS TanarOktAzon
|
|
,tn.C_TEMA AS Tema
|
|
,IIF(tn.C_HELYETTESITOTANARID IS NOT NULL, ''T'', ''F'') AS Helyettesitett
|
|
,FORMAT(tn.C_DATUM, ''yyyy.MM.dd.'') AS Datum
|
|
,tn.C_ORASZAM AS OraSzam
|
|
,tn.C_MEGJEGYZES AS Megjegyzes
|
|
,ISNULL(tn.C_HAZIFELADAT,hf.C_FELADATSZOVEGE) AS HaziFeladat
|
|
,tn.C_TULORA AS TulOra
|
|
,tn.C_TAMOPORA AS TamopOra
|
|
,tn.C_NEMSZAKRENDSZERUORA AS NemszakrendszeruOra
|
|
,tn.C_IKTTANORA AS IktOra
|
|
,tn.C_NEMZETISEGIORA AS NemzetisegiOra
|
|
,tn.C_ISFELNOTTOKTATASISZERZODES AS IsFelnottoktatasiSzerzodes
|
|
,tn.C_MINDENNAPOSTESTNEVELES AS TestnevelesOra
|
|
,tn.C_IPRTANORA AS IprOra
|
|
,tn.C_DIFFERENCIALT AS DifferencialtOra
|
|
,tn.C_KOOPERATIV AS KooperativOra
|
|
,tn.C_MERES AS MeresOra
|
|
,tn.C_DRAMA AS DramaOra
|
|
,tn.C_PARHUZAMOSORA AS ParhuzamosOra
|
|
,tn.C_TIOP12 AS TiopOra
|
|
,tn.C_VEKOP73317 AS VEKOP73317
|
|
,tn.C_KAPORA AS KAPOra
|
|
,tn.C_BONTOTT AS Bontott
|
|
,tn.C_MULTIKULTURALISORA AS Multikulturalis
|
|
,tn.C_EFOP32317 AS EFOP32317
|
|
,tn.C_GINOP623 AS GINOP623
|
|
,tn.C_EFOP31716 AS EFOP31716
|
|
,tn.C_EFOP33717 AS EFOP33717
|
|
,tn.C_TIOP1111212012001 AS TIOP1111212012001
|
|
,tn.C_EFOP23517 AS EFOP23517
|
|
-- Komplex alapprogram adatok
|
|
,tn.C_ISDFHTORA AS DFHTora
|
|
,tn.C_ISDFHTKIPORA AS DFHTKIPora
|
|
,tn.C_KIPORA KIPOra
|
|
,tn.C_ISTEORAD AS TEorad
|
|
,tn.C_ISRAHANGOLODAS AS Rahangolodas
|
|
,tn.C_KOMPLEXORA AS Komplexora
|
|
,tn.C_ISDIGITALISALAPUALPROGRAM AS DigitalisAlapuAlprogram
|
|
,tn.C_ISTESTMOZGASALAPUALPROGRAM AS TestmozgasAlapuAlprogram
|
|
,tn.C_ISELETGYAKORLATALAPUALPROGRA AS EletGyakorlatAlapuAlprogram
|
|
,tn.C_ISMUVESZETALAPUALPROGRAM AS MuveszetAlapuAlprogram
|
|
,tn.C_ISLOGIKAALAPUALPROGRAM AS LogikaiAlapuAlprogram
|
|
,dDigEszkozTipus.C_NAME AS DigEszkozTipus
|
|
,dDigPlatformTipus.C_NAME AS DigPlatformTipus
|
|
,ISNULL((SELECT STUFF((SELECT '', '' + d.C_NAME
|
|
FROM T_TANITASIORADIGTAMESZKOZ_OSSZES taodte
|
|
INNER JOIN T_DICTIONARYITEMBASE_OSSZES d ON d.ID = taodte.C_DIGTAMESZKOZTIPUSID AND d.C_TANEVID = taodte.C_TANEVID AND d.TOROLT = ''F'' AND d.ID != 8600 --Na
|
|
WHERE taodte.C_TANITASIORAID = tn.ID
|
|
AND taodte.TOROLT = ''F''
|
|
ORDER BY d.ID
|
|
FOR XML PATH('''')),1,2,'''')), '''') AS DigTamEszkozTipus
|
|
,tot.C_ORATULAJDONSAGID
|
|
,tot.C_BOOLERTEK
|
|
FROM T_TANITASIORA_OSSZES tn
|
|
INNER JOIN T_FELHASZNALO_OSSZES fh ON fh.ID = tn.C_TANARID
|
|
LEFT JOIN T_HAZIFELADATOK_OSSZES hf ON hf.C_TANITASIORAID = tn.ID AND hf.TOROLT = ''F''
|
|
LEFT JOIN T_TANITASIORATULAJDONSAG_OSSZES tot ON tot.C_TANITASIORAID = tn.ID AND tot.TOROLT = ''F''
|
|
LEFT JOIN T_DICTIONARYITEMBASE_OSSZES dDigEszkozTipus ON dDigEszkozTipus.ID = tn.C_DIGESZKOZTIPUSID AND dDigEszkozTipus.C_TANEVID = tn.C_TANEVID AND dDigEszkozTipus.TOROLT = ''F'' AND dDigEszkozTipus.ID != 8587 -- Na
|
|
LEFT JOIN T_DICTIONARYITEMBASE_OSSZES dDigPlatformTipus ON dDigPlatformTipus.ID = tn.C_DIGPLATFORMTIPUSID AND dDigPlatformTipus.C_TANEVID = tn.C_TANEVID AND dDigPlatformTipus.TOROLT = ''F'' AND dDigPlatformTipus.ID != 8573 --Na
|
|
WHERE
|
|
tn.TOROLT = ''F''
|
|
AND tn.C_TANEVID = @tanevID
|
|
AND tn.C_TANARID = @cTanarId
|
|
AND tn.C_TANTARGYID = @cTantargyId
|
|
AND tn.C_OSZTALYCSOPORTID = @cOsztalyCsoportId
|
|
) AS p PIVOT (MIN(C_BOOLERTEK) FOR C_ORATULAJDONSAGID IN (' + STUFF(@columns, 1, 2, '') + N'
|
|
)) AS j
|
|
ORDER BY j.Datum'
|
|
|
|
EXEC sp_executesql @sql
|
|
,N'@tanevID int
|
|
,@cTanarId int
|
|
,@cTantargyId int
|
|
,@cOsztalyCsoportId int'
|
|
,@tanevID = @tanevID
|
|
,@cTanarId = @cTanarId
|
|
,@cTantargyId = @cTantargyId
|
|
,@cOsztalyCsoportId = @cOsztalyCsoportId
|
|
|
|
FETCH NEXT FROM foglalkozasCursor
|
|
INTO @cTantargyId, @cOsztalyCsoportId, @cTanarId
|
|
END
|
|
|
|
CLOSE foglalkozasCursor
|
|
DEALLOCATE foglalkozasCursor
|
|
|
|
IF (SELECT COUNT(Nev) FROM #Foglalkozasok) = 0 BEGIN
|
|
SET @sql = N'CREATE TABLE #nincsAdat (
|
|
OraSorszam nvarchar(max)
|
|
,TanarNev nvarchar(1)
|
|
,TanarOktAzon nvarchar(1)
|
|
,Tema nvarchar(1)
|
|
,Helyettesitett nvarchar(1)
|
|
,Datum datetime
|
|
,OraSzam int
|
|
,Megjegyzes nvarchar(1)
|
|
,HaziFeladat nvarchar(1)
|
|
,TulOra char
|
|
,TamopOra char
|
|
,NemszakrendszeruOra char
|
|
,IktOra char
|
|
,NemzetisegiOra char
|
|
,IsFelnottoktatasiSzerzodes char
|
|
,TestnevelesOra char
|
|
,IprOra char
|
|
,DifferencialtOra char
|
|
,KooperativOra char
|
|
,MeresOra char
|
|
,DramaOra char
|
|
,ParhuzamosOra char
|
|
,TiopOra char
|
|
,VEKOP73317 char
|
|
,KAPOra char
|
|
,Bontott char
|
|
,Multikulturalis char
|
|
,EFOP32317 char
|
|
,GINOP623 char
|
|
,EFOP31716 char
|
|
,EFOP33717 char
|
|
,TIOP1111212012001 char
|
|
,EFOP23517 char
|
|
-- Komplex alapprogram adatok
|
|
,DFHTora char
|
|
,DFHTKIPora char
|
|
,KIPOra char
|
|
,TEorad char
|
|
,Rahangolodas char
|
|
,Komplexora char
|
|
,DigitalisAlapuAlprogram char
|
|
,TestmozgasAlapuAlprogram char
|
|
,EletGyakorlatAlapuAlprogram char
|
|
,MuveszetAlapuAlprogram char
|
|
,LogikaiAlapuAlprogram char
|
|
,DigEszkozTipus int
|
|
,DigPlatformTipus int
|
|
,DigTamEszkozTipus int
|
|
' + @columnsWithType + N'
|
|
)
|
|
SELECT * FROM #nincsAdat;'
|
|
|
|
EXEC sp_executesql @sql
|
|
END
|
|
|
|
-- Iktatás adatok
|
|
IF @tanarID IS NOT NULL BEGIN
|
|
SELECT
|
|
f.ID AS PedagogusId
|
|
,f.C_OKTATASIAZONOSITO AS PedagogusOktAzon
|
|
,mua.C_FELADATELLATASIHELYID AS FeladatEllatasiHelyId
|
|
FROM T_FELHASZNALO_OSSZES AS f
|
|
LEFT JOIN T_MUNKAUGYIADATOK_OSSZES AS mua ON mua.C_ALKALMAZOTTID = f.ID
|
|
WHERE f.ID = @tanarID
|
|
AND f.C_TANEVID = @tanevID
|
|
END
|
|
IF @osztalyID IS NOT NULL BEGIN
|
|
DECLARE @isCsoport INT = (SELECT COUNT(ID) FROM T_CSOPORT_OSSZES WHERE ID = @osztalyID)
|
|
IF @isCsoport = 0 BEGIN
|
|
SELECT
|
|
ocs.ID AS OsztalyId
|
|
,o.C_OSZTALYFONOKID AS OsztalyfonokId
|
|
,ocs.C_EVFOLYAMTIPUSA AS EvfolyamTipusa
|
|
,ocs.C_FELADATELLATASIHELYID AS FeladatEllatasiHelyId
|
|
,o.C_TANTERVID AS TantervId
|
|
,ocs.C_KEPZESIFORMA AS KepzesiForma
|
|
,o.C_AGAZAT AS Agazat
|
|
,o.C_SZAKMACSOPORT AS SzakmaCsoport
|
|
,o.C_SZAKKEPESITES AS Szakkepesites
|
|
,o.C_RESZSZAKKEPESITES AS Reszszakkepesites
|
|
,o.C_AGAZATUJSZKTTIPUSID AS UjSzktAgazat
|
|
,o.C_SZAKMATIPUSID AS UjSzktSzakma
|
|
,o.C_SZAKMAIRANYTIPUSID AS UjSzktSzakmairany
|
|
,o.C_TANULMANYITERULETNKTTIPUSID AS NktTanulmanyiTerulet
|
|
,o.C_SZAKKEPESITESNKTTIPUSID AS NktSzakkepesites
|
|
,o.C_SZAKIRANYNKTTIPUSID AS NktSzakirany
|
|
,ocs.C_KERESZTFELEVES AS OJCSJKeresztfeleves
|
|
,ocs.C_VEGZOSEVFOLYAM AS CSJVegzosEvfolyamu
|
|
,ocs.C_ISTECHNIKAI AS OJTechnikaiOsztaly
|
|
,o.C_NEMZETISEGI AS OJNemzetisegi
|
|
,o.C_KETTANNYELVU AS OJKettannyelvu
|
|
,o.C_NYELVIELOKESZITO AS OJNyelviElokeszito
|
|
,ocs.C_ISGYOGYPEDAGOGIAILOGOPEDIAI AS OJIsGyogypedagogiaiLogopediai
|
|
,o.C_SPORT AS OJSportOsztaly
|
|
,o.C_AJPROGRAM AS OJAranyJanosProgram
|
|
FROM T_OSZTALYCSOPORT_OSSZES ocs
|
|
INNER JOIN T_OSZTALY_OSSZES AS o ON ocs.id = o.ID
|
|
WHERE ocs.TOROLT='F'
|
|
AND ocs.ID = @osztalyId
|
|
AND ocs.C_TANEVID = @tanevId
|
|
END
|
|
ELSE BEGIN
|
|
SELECT
|
|
ocs.ID AS CsoportId
|
|
,cs.C_CSOPORTVEZETOID AS CsoportvezetoId
|
|
,cs.C_TIPUSA AS CsoportTipusa
|
|
,ISNULL(ocs.C_EVFOLYAMTIPUSA, 1296) AS EvfolyamTipusa -- 1296 = Na
|
|
,ocs.C_FELADATELLATASIHELYID AS FeladatEllatasiHelyId
|
|
,ocs.C_KERESZTFELEVES AS OJCSJKeresztfeleves
|
|
,ocs.C_VEGZOSEVFOLYAM AS CSJVegzosEvfolyamu
|
|
FROM T_OSZTALYCSOPORT_OSSZES AS ocs
|
|
INNER JOIN T_CSOPORT_OSSZES cs ON cs.ID = ocs.ID
|
|
WHERE ocs.TOROLT = 'F'
|
|
AND ocs.ID = @osztalyID
|
|
AND ocs.C_TANEVID = @tanevID
|
|
END
|
|
SELECT DISTINCT
|
|
felh.ID AS TanarId
|
|
,felh.C_OKTATASIAZONOSITO AS TanarOktAzon
|
|
FROM #Foglalkozasok fogl
|
|
INNER JOIN T_FELHASZNALO_OSSZES felh ON felh.ID = fogl.C_TANARID
|
|
END
|
|
|
|
DROP TABLE #Foglalkozasok
|
|
END
|
|
|
|
GO |