158 lines
7.8 KiB
Transact-SQL
158 lines
7.8 KiB
Transact-SQL
DROP PROCEDURE IF EXISTS [dbo].[uspGetTanuloszerzodes]
|
|
GO
|
|
|
|
CREATE PROCEDURE [dbo].[uspGetTanuloszerzodes]
|
|
@pOsztalyId INT,
|
|
@pIntezmenyId INT,
|
|
@pTanevId INT,
|
|
@pTanuloIdList nvarchar(max)
|
|
AS
|
|
BEGIN
|
|
|
|
SET NOCOUNT ON;
|
|
|
|
CREATE TABLE #Tanulok (Id int PRIMARY KEY)
|
|
INSERT INTO #Tanulok
|
|
SELECT CAST(value as int) FROM string_split(@pTanuloIdList, ',')
|
|
|
|
/*TANULO*/
|
|
SELECT DISTINCT
|
|
t.ID AS tanuloId
|
|
,f.C_NYILVANTARTASISZAM AS torzslapSzam
|
|
,f.C_OKTATASIAZONOSITO AS oktAzon
|
|
,f.C_TAJSZAM AS tajSzam
|
|
,f.C_ANYJANEVE AS anyjaNeve
|
|
,f.C_SZULETESIHELY AS szulHely
|
|
,dbo.fnGetDokumentumDatumFormatum(f.C_SZULETESIDATUM) AS szulIdo
|
|
,tt.C_NEV AS kepzes
|
|
,f.C_NYOMTATASINEV AS tanuloNeve
|
|
,f.C_SZULETESINEV AS szuletesiNev
|
|
,d.C_NAME AS allampolgarsaga
|
|
,ISNULL(Cim.Cim, '') AS tanuloCimText
|
|
,ISNULL(Email.C_EMAILCIM, '') AS tanuloEmailCim
|
|
,ISNULL(Telefon.C_TELEFONSZAM, '') AS tanuloTelefonszam
|
|
,IIF(t.C_SZAKKEPESITESSZAMA IS NOT NULL, 'van, '
|
|
+ 'OKJ száma: ............., megnevezése: ', 'nincs') AS okj
|
|
,ISNULL(gondviselo.GondviseloNeve, '') AS GondviseloNeve
|
|
,ISNULL(gondviselo.GondviseloCime, '') AS GondviseloCime
|
|
,ISNULL(gondviselo.GondviseloTelSzam, '') AS GondviseloTelSzam
|
|
,ISNULL(gondviselo.GondviseloEmail, '') AS GondviseloEmail
|
|
FROM T_TANULO_OSSZES t
|
|
INNER JOIN #Tanulok Tanulok ON t.ID = Tanulok.Id
|
|
LEFT JOIN fnGetDokumentumTanuloOrGondviseloCim (0, @pTanevId, @pOsztalyId) Cim on Cim.TanuloId = t.ID AND (cim.CimTipusa = 907 OR cim.IsAlapertelmezett = 'T')
|
|
LEFT JOIN (
|
|
SELECT
|
|
gondviselo.C_NEV AS GondviseloNeve
|
|
,ROW_NUMBER () OVER (PARTITION BY gondviselo.C_TANULOID ORDER BY gondviselo.CREATED) AS gondviselok
|
|
,cim.C_IRANYITOSZAM + ' ' + cim.C_VAROS + ', ' + cim.C_KOZTERULET + ' ' + cim.C_KOZTERULETJELLEGENEV + ' ' + cim.C_HAZSZAM + '.' + ' ' + ISNULL(cim.C_EMELET + '/', ' ') + ISNULL(cim.C_AJTO, ' ') AS GondviseloCime
|
|
,telefon.C_TELEFONSZAM AS GondviseloTelSzam
|
|
,email.C_EMAILCIM AS GondviseloEmail
|
|
,gondviselo.C_TANULOID AS TanuloId
|
|
FROM T_GONDVISELO_OSSZES gondviselo
|
|
LEFT JOIN T_CIM_OSSZES cim ON cim.C_FELHASZNALOID = gondviselo.ID AND (cim.C_ALAPERTELMEZETT = 'T' OR cim.C_CIMTIPUSA = 907) AND cim.TOROLT = 'F'
|
|
LEFT JOIN T_TELEFON_OSSZES telefon ON gondviselo.ID = telefon.C_FELHASZNALOID AND telefon.C_ALAPERTELMEZETT = 'T' AND telefon.TOROLT = 'F'
|
|
LEFT JOIN T_EMAIL_OSSZES email ON gondviselo.ID = email.C_FELHASZNALOID AND email.C_ALAPERTELMEZETT ='T' AND email.TOROLT = 'F'
|
|
WHERE
|
|
(gondviselo.C_ISTORVENYESKEPVISELO = 'T' OR gondviselo.C_GONDVISELESKEZDETE IS NOT NULL)
|
|
AND gondviselo.C_TANEVID = @pTanevId
|
|
AND gondviselo.TOROLT = 'F'
|
|
) AS gondviselo ON gondviselo.TanuloId = t.ID
|
|
LEFT JOIN T_EMAIL_OSSZES Email ON Email.C_FELHASZNALOID = t.ID
|
|
AND Email.C_TANEVID = @pTanevId
|
|
AND Email.TOROLT = 'F'
|
|
AND Email.C_ALAPERTELMEZETT = 'T'
|
|
AND Email.C_GONDVISELOID IS NULL
|
|
LEFT JOIN T_TELEFON_OSSZES Telefon ON Telefon.C_FELHASZNALOID = t.ID
|
|
AND Telefon.C_TANEVID = @pTanevId
|
|
AND Telefon.TOROLT = 'F'
|
|
AND Telefon.C_ALAPERTELMEZETT= 'T'
|
|
AND Telefon.C_GONDVISELOID IS NULL
|
|
INNER JOIN T_TANTERV_OSSZES tt ON tt.ID = t.C_TANTERVID
|
|
AND tt.TOROLT ='F'
|
|
INNER JOIN T_FELHASZNALO_OSSZES f ON f.ID = t.ID
|
|
AND f.TOROLT = 'F'
|
|
INNER JOIN T_DICTIONARYITEMBASE_OSSZES d ON d.id=f.C_ALLAMPOLGARSAGA
|
|
AND d.C_TANEVID = f.C_TANEVID
|
|
AND d.TOROLT = 'F'
|
|
WHERE t.TOROLT = 'F'
|
|
|
|
/*INTEZMENYADATOK*/
|
|
SELECT DISTINCT
|
|
INTEZMENY.C_INTEZMENYID AS intezmenyId
|
|
,INTEZMENY.C_NEV AS Nev
|
|
,INTEZMENY.C_IGAZGATONEVE AS IgazgatoNev
|
|
,dbo.fnGetDokumentumIntezmenyCime (@pTanevId) AS IntezmenyCim
|
|
,INTEZMENY.C_TELEFONSZAM AS IntezmenyTelefonszam
|
|
,INTEZMENY.C_EMAILCIM AS IntezmenyEmail
|
|
,INTEZMENY.C_OMKOD AS OktAzon
|
|
,TANEV.C_NEV
|
|
INTO #IntemenyAdatok
|
|
FROM T_TANEV_OSSZES TANEV
|
|
INNER JOIN T_INTEZMENYADATOK_OSSZES INTEZMENY ON TANEV.ID = INTEZMENY.C_TANEVID AND INTEZMENY.TOROLT = 'F'
|
|
WHERE TANEV.ID = @pTanevId
|
|
AND TANEV.TOROLT = 'F'
|
|
AND INTEZMENY.C_INTEZMENYID = @pIntezmenyId
|
|
|
|
CREATE TABLE #Osztalyok (Id int, FeladatellatasiHelyId int);
|
|
INSERT INTO #Osztalyok
|
|
SELECT DISTINCT C_OSZTALYCSOPORTID, C_FELADATELLATASIHELYID
|
|
FROM T_TANULOCSOPORT_OSSZES tcs
|
|
INNER JOIN #Tanulok Tanulok ON Tanulok.Id = tcs.C_TANULOID
|
|
INNER JOIN T_OSZTALY_OSSZES o ON o.ID = tcs.C_OSZTALYCSOPORTID AND o.TOROLT = 'F'
|
|
INNER JOIN T_OSZTALYCSOPORT_OSSZES ocs ON ocs.ID = o.ID
|
|
AND ocs.C_FELADATKATEGORIAID = 7553 /*OktNevelesiKategoriaEnum.Alapkepzes*/
|
|
AND ocs.TOROLT = 'F'
|
|
WHERE tcs.TOROLT = 'F'
|
|
AND tcs.C_TANEVID = @pTanevId
|
|
|
|
/*TAGINTEZMENYADATOK*/
|
|
SELECT DISTINCT
|
|
TAGINTEZMENY.C_INTEZMENYID AS intezmenyId
|
|
,TAGINTEZMENY.C_NEV AS TagintezmenyNev
|
|
,TAGINTEZMENY.C_IRANYITOSZAM + ' ' + TAGINTEZMENY.C_VAROS + ', '
|
|
+ TAGINTEZMENY.C_KOZTERULETNEV + ' ' + kozteruletJellege.C_NAME + ' '
|
|
+ TAGINTEZMENY.C_HAZSZAM
|
|
+ ISNULL(', ' + TAGINTEZMENY.C_EMELET + '. EMELET', '')
|
|
+ ISNULL(', ' + TAGINTEZMENY.C_AJTO + '. AJTÓ', '') AS TagintezmenyCim
|
|
INTO #TagintezmenyAdatok
|
|
FROM T_TANEV_OSSZES TANEV
|
|
INNER JOIN T_FELADATELLATASIHELY_OSSZES feh ON feh.C_TANEVID = TANEV.ID AND feh.TOROLT = 'F'
|
|
INNER JOIN #Osztalyok o ON o.FeladatellatasiHelyId = feh.ID
|
|
INNER JOIN T_MUKODESIHELY_OSSZES TAGINTEZMENY ON TAGINTEZMENY.ID = feh.C_MUKODESIHELYID AND TAGINTEZMENY.TOROLT = 'F'
|
|
INNER JOIN T_DICTIONARYITEMBASE_OSSZES kozteruletJellege ON
|
|
kozteruletJellege.ID = TAGINTEZMENY.C_KOZTERULETJELLEG
|
|
AND kozteruletJellege.C_TANEVID = @pTanevId
|
|
AND kozteruletJellege.TOROLT = 'F'
|
|
WHERE TANEV.ID = @pTanevId
|
|
AND TANEV.TOROLT = 'F'
|
|
AND TAGINTEZMENY.C_INTEZMENYID = @pIntezmenyId
|
|
|
|
|
|
/*==============INTÉZMÉNY/TAGINTÉZMÉNY==================*/
|
|
|
|
SELECT DISTINCT
|
|
*
|
|
FROM #IntemenyAdatok intezmeny
|
|
INNER JOIN #TagintezmenyAdatok tagintezmeny ON intezmeny.intezmenyId = tagintezmeny.intezmenyId
|
|
|
|
|
|
/*BESOROLAS*/
|
|
SELECT DISTINCT
|
|
TANCSOP.C_TANULOID AS tanuloId
|
|
,OKTATASINEVELESIFELADAT.C_NAME AS FeladatEllatasiHely
|
|
,MUNKAREND.C_NAME AS NappaliRend
|
|
,EVFOLYAM.C_NAME_1 AS Evfolyam
|
|
FROM T_TANULOCSOPORT_OSSZES TANCSOP
|
|
INNER JOIN #Tanulok Tanulok ON TANCSOP.C_TANULOID = Tanulok.Id
|
|
INNER JOIN T_OSZTALY_OSSZES OSZTALY ON OSZTALY.ID = TANCSOP.C_OSZTALYCSOPORTID AND OSZTALY.TOROLT = 'F'
|
|
INNER JOIN T_OSZTALYCSOPORT_OSSZES OSZTALYCSOP ON OSZTALYCSOP.ID = OSZTALY.ID AND OSZTALYCSOP.C_FELADATKATEGORIAID = 7553 /*OktNevelesiKategoriaEnum.Alapkepzes*/ AND OSZTALYCSOP.TOROLT = 'F'
|
|
INNER JOIN T_FELADATELLATASIHELY_OSSZES ON T_FELADATELLATASIHELY_OSSZES.ID = OSZTALYCSOP.C_FELADATELLATASIHELYID AND T_FELADATELLATASIHELY_OSSZES.C_TANEVID = OSZTALYCSOP.C_TANEVID AND T_FELADATELLATASIHELY_OSSZES.C_INTEZMENYID = @pIntezmenyId AND T_FELADATELLATASIHELY_OSSZES.TOROLT = 'F'
|
|
INNER JOIN T_DICTIONARYITEMBASE_OSSZES MUNKAREND ON OSZTALYCSOP.C_KEPZESIFORMA = MUNKAREND.ID AND MUNKAREND.C_TANEVID = OSZTALYCSOP.C_TANEVID AND MUNKAREND.TOROLT = 'F'
|
|
INNER JOIN T_DICTIONARYITEMBASE_OSSZES AS OKTATASINEVELESIFELADAT ON T_FELADATELLATASIHELY_OSSZES.C_OKTATASINEVELESIFELADATTIPUS = OKTATASINEVELESIFELADAT.ID AND OKTATASINEVELESIFELADAT.C_TANEVID = T_FELADATELLATASIHELY_OSSZES.C_TANEVID AND OKTATASINEVELESIFELADAT.TOROLT = 'F'
|
|
INNER JOIN T_DICTIONARYITEMBASE_OSSZES EVFOLYAM ON EVFOLYAM.ID = OSZTALYCSOP.C_EVFOLYAMTIPUSA AND EVFOLYAM.C_TANEVID = OSZTALYCSOP.C_TANEVID AND EVFOLYAM.TOROLT = 'F'
|
|
WHERE OSZTALYCSOP.C_TANEVID = @pTanevId
|
|
AND TANCSOP.TOROLT = 'F'
|
|
AND TANCSOP.C_TANEVID = @pTanevId
|
|
|
|
END
|
|
|