148 lines
7.3 KiB
Transact-SQL
148 lines
7.3 KiB
Transact-SQL
DROP PROCEDURE IF EXISTS uspGetTanulokEsOsztalyokCsoportokGrid
|
|
GO
|
|
|
|
CREATE PROCEDURE uspGetTanulokEsOsztalyokCsoportokGrid
|
|
@pTanevId int = NULL
|
|
,@pTanuloSrc nvarchar(1000) = NULL
|
|
,@pOsztalyId int = NULL
|
|
,@pCsoportId int = NULL
|
|
,@pFeladatKategoriaId int = NULL
|
|
,@pBelepesiDatumTol datetime = NULL
|
|
,@pBelepesiDatumIg datetime = NULL
|
|
,@pKilepesiDatumTol datetime = NULL
|
|
,@pKilepesiDatumIg datetime = NULL
|
|
,@pZaradekokSzamaTol int = NULL
|
|
,@pZaradekokSzamaIg int = NULL
|
|
,@pKiVagyAtSorolasiZaradek bit = NULL
|
|
,@pNaplosorszamTol int = NULL
|
|
,@pNaplosorszamIg int = NULL
|
|
,@pTorzslapszam nvarchar(100) = NULL
|
|
,@pKileptetesiDatumTol datetime = NULL
|
|
,@pKileptetesiDatumIg datetime = NULL
|
|
,@pUtolsoModositasDatumTol datetime = NULL
|
|
,@pUtolsoModositasDatumIg datetime = NULL
|
|
,@pIsKiirt bit = 0
|
|
,@pIsZaradekBontott bit = 0
|
|
,@pIsExport bit = 0
|
|
,@pIsImport bit = 0
|
|
,@pIsCsoport bit = 0
|
|
,@pKovTanev bit = 0
|
|
|
|
AS
|
|
BEGIN
|
|
SET NOCOUNT ON;
|
|
DECLARE @sql nvarchar(max) = N''
|
|
DECLARE @osztalycsoportipus nvarchar(7) = IIF(@pIsCsoport = 0 ,'Osztaly','Csoport')
|
|
DECLARE @zaradeksql nvarchar(max) = N''
|
|
|
|
SET @sql += N'
|
|
|
|
CREATE TABLE #Zaradekok (C_TANULOCSOPORTID int NOT NULL PRIMARY KEY, KiVagyAtsorolasiZaradekokSzama int, ZaradekokSzama int)
|
|
INSERT INTO #Zaradekok
|
|
SELECT
|
|
C_TANULOCSOPORTID
|
|
,SUM(IIF(C_ISKIVAGYATSOROLASIZARADEK = ''T'',1,0)) as KiVagyAtsorolasiZaradekokSzama
|
|
,SUM(1) AS ZaradekokSzama
|
|
FROM T_ZARADEK_OSSZES
|
|
WHERE TOROLT = ''F''
|
|
AND C_TANEVID = @pTanevId
|
|
GROUP BY C_TANULOCSOPORTID
|
|
|
|
SELECT
|
|
tcs.ID as ID
|
|
,tcs.C_TANULOID as TanuloId
|
|
,tv.C_NEV as Tanev
|
|
,ocs.C_NEV as ' + @osztalycsoportipus + N'Nev
|
|
,f.C_NYOMTATASINEV as TanuloNev
|
|
,IIF(f.C_NEVSORREND = ''F'',
|
|
f.C_VEZETEKNEV + '' '' + f.C_UTONEV,
|
|
f.C_UTONEV + '' '' + f.C_VEZETEKNEV) AS NevElotagNelkul
|
|
,tcs.C_BELEPESDATUM as BelepesDatum
|
|
,tcs.C_KILEPESDATUM as KilepesDatum
|
|
,' + IIF(@pIsCsoport = 0,N'tta.C_NAPLOSORSZAM',N'NULL') + N' as NaploSorszam
|
|
,' + IIF(@pIsCsoport = 0,N'tta.C_TORZSLAPSZAM',N'NULL') + N' as TorzslapSzam
|
|
,tcs.C_KILEPESROGZITESDATUM as KilepesRogzitesDatum
|
|
,tcs.LASTCHANGED as UtolsoModositas
|
|
,ocs.ID as ' + @osztalycsoportipus + N'Id '+
|
|
IIF(@pIsCsoport = 1, N',TanuloOsztalyString.Osztalynev AS TanuloOsztalyai','') + N'
|
|
,ISNULL(zaradek.ZaradekokSzama,0) AS ZaradekokSzama
|
|
,IIF(zaradek.KiVagyAtsorolasiZaradekokSzama > 0 , ''Van'', ''Nincs'') AS Vegzaradek '+
|
|
IIF(@pIsCsoport = 1, N',C_ISAUTOEGYENICSOPORT AS IsAutoEgyeniCsoport','') + N'
|
|
FROM T_TANULOCSOPORT_OSSZES tcs ' +
|
|
IIF(@pIsCsoport = 0,N'INNER JOIN T_TANULOTANUGYIADATOK_OSSZES tta ON tta.C_TANULOCSOPORTID = tcs.ID AND tta.TOROLT = ''F''','') + N'
|
|
INNER JOIN T_TANEV_OSSZES tv on tv.ID = tcs.C_TANEVID and tv.TOROLT = ''F''
|
|
INNER JOIN T_FELHASZNALO_OSSZES f on f.ID = tcs.C_TANULOID and f.TOROLT = ''F''
|
|
INNER JOIN T_TANULO_OSSZES t on t.ID = tcs.C_TANULOID and t.TOROLT = ''F''
|
|
INNER JOIN T_OSZTALYCSOPORT_OSSZES ocs on ocs.ID = tcs.C_OSZTALYCSOPORTID
|
|
and ocs.TOROLT = ''F'' '+
|
|
IIF(@pFeladatKategoriaId IS NOT NULL,N' AND ocs.C_FELADATKATEGORIAID = @pFeladatKategoriaId','') + N'
|
|
INNER JOIN T_' + @osztalycsoportipus + N'_OSSZES cs on cs.ID = ocs.ID and cs.TOROLT = ''F''' +
|
|
IIF(@pIsCsoport = 1,N' CROSS APPLY fnGetTanuloOsztalyString(tcs.C_TANULOID, default, ocs.C_FELADATKATEGORIAID, default, @pKovTanev, @pOsztalyId) TanuloOsztalyString','') + N'
|
|
LEFT JOIN #Zaradekok zaradek ON zaradek.C_TANULOCSOPORTID = tcs.ID
|
|
WHERE tcs.TOROLT = ''F'' ' +
|
|
IIF(@pTanevId IS NULL,'',N' AND f.C_TANEVID = @pTanevId AND t.C_ALTANEVID = @pTanevId AND ocs.C_TANEVID = @pTanevId AND cs.C_ALTANEVID = @pTanevId ') +
|
|
IIF(@pIsKiirt = 1,N' AND tcs.C_KILEPESDATUM IS NOT NULL ','') +
|
|
IIF(@pTanuloSrc IS NOT NULL, N' AND LOWER(f.C_NYOMTATASINEV) LIKE ''%'' + LOWER(@pTanuloSrc) + ''%''','') +
|
|
IIF(@pIsCsoport = 0 AND @pOsztalyId IS NOT NULL, N' AND ocs.ID = @pOsztalyId ','') +
|
|
IIF(@pCsoportId IS NOT NULL, N' AND ocs.ID = @pCsoportId ','') +
|
|
IIF(@pBelepesiDatumTol IS NOT NULL, N' AND tcs.C_BELEPESDATUM >= @pBelepesiDatumTol ', '' ) +
|
|
IIF(@pBelepesiDatumIg IS NOT NULL, N' AND tcs.C_BELEPESDATUM <= @pBelepesiDatumIg ', '' ) +
|
|
IIF(@pKilepesiDatumTol IS NOT NULL, N' AND tcs.C_KILEPESDATUM >= @pKilepesiDatumTol ', '' ) +
|
|
IIF(@pKilepesiDatumIg IS NOT NULL, N' AND tcs.C_KILEPESDATUM <= @pKilepesiDatumIg ', '' ) +
|
|
IIF(@pIsCsoport = 0 AND @pNaplosorszamTol IS NOT NULL, N' AND tta.C_NAPLOSORSZAM >= @pNaplosorszamTol ', '' ) +
|
|
IIF(@pIsCsoport = 0 AND @pNaplosorszamIg IS NOT NULL, N' AND tta.C_NAPLOSORSZAM <= @pNaplosorszamIg ', '' ) +
|
|
IIF(@pIsCsoport = 0 AND @pTorzslapszam IS NOT NULL, N' AND tta.C_TORZSLAPSZAM LIKE ''%'' + LOWER(@pTorzslapszam) + ''%''', '' ) +
|
|
IIF(@pKileptetesiDatumTol IS NOT NULL, N' AND tcs.C_KILEPESROGZITESDATUM >= @pKileptetesiDatumTol ', '' ) +
|
|
IIF(@pKileptetesiDatumIg IS NOT NULL, N' AND tcs.C_KILEPESROGZITESDATUM <= @pKileptetesiDatumIg ', '' ) +
|
|
IIF(@pUtolsoModositasDatumTol IS NOT NULL, N' AND tcs.LASTCHANGED >= @pUtolsoModositasDatumTol ', '' ) +
|
|
IIF(@pUtolsoModositasDatumIg IS NOT NULL, N' AND tcs.LASTCHANGED <= @pUtolsoModositasDatumIg ', '' ) +
|
|
IIF(@pIsCsoport = 1 AND @pOsztalyId IS NOT NULL, N' AND TanuloOsztalyString.Osztalynev IS NOT NULL ','') +
|
|
IIF(@pZaradekokSzamaTol IS NOT NULL, N' AND ISNULL(zaradek.ZaradekokSzama, 0) >= @pZaradekokSzamaTol','') +
|
|
IIF(@pZaradekokSzamaIg IS NOT NULL, N' AND ISNULL(zaradek.ZaradekokSzama, 0) <= @pZaradekokSzamaIg','') +
|
|
IIF(@pKiVagyAtSorolasiZaradek = 1, N' AND zaradek.KiVagyAtsorolasiZaradekokSzama > 0','') +
|
|
IIF(@pKiVagyAtSorolasiZaradek IS NOT NULL AND @pKiVagyAtSorolasiZaradek = 0, N' AND (zaradek.KiVagyAtsorolasiZaradekokSzama < 1 OR zaradek.KiVagyAtsorolasiZaradekokSzama IS NULL)','')
|
|
|
|
EXEC sp_executesql @sql, N'
|
|
@pTanevId int = NULL
|
|
,@pTanuloSrc nvarchar(1000) = NULL
|
|
,@pFeladatKategoriaId int = NULL
|
|
,@pOsztalyId int = NULL
|
|
,@pCsoportId int = NULL
|
|
,@pBelepesiDatumTol datetime = NULL
|
|
,@pBelepesiDatumIg datetime = NULL
|
|
,@pKilepesiDatumTol datetime = NULL
|
|
,@pKilepesiDatumIg datetime = NULL
|
|
,@pZaradekokSzamaTol int = NULL
|
|
,@pZaradekokSzamaIg int = NULL
|
|
,@pKiVagyAtSorolasiZaradek int = NULL
|
|
,@pNaplosorszamTol int = NULL
|
|
,@pNaplosorszamIg int = NULL
|
|
,@pTorzslapszam nvarchar(1000) = NULL
|
|
,@pKileptetesiDatumTol datetime = NULL
|
|
,@pKileptetesiDatumIg datetime = NULL
|
|
,@pUtolsoModositasDatumTol datetime = NULL
|
|
,@pUtolsoModositasDatumIg datetime = NULL
|
|
,@pKovTanev bit = 0'
|
|
,@pTanevId = @pTanevId
|
|
,@pTanuloSrc = @pTanuloSrc
|
|
,@pFeladatKategoriaId = @pFeladatKategoriaId
|
|
,@pOsztalyId = @pOsztalyId
|
|
,@pCsoportId = @pCsoportId
|
|
,@pBelepesiDatumTol = @pBelepesiDatumTol
|
|
,@pBelepesiDatumIg = @pBelepesiDatumIg
|
|
,@pKilepesiDatumTol = @pKilepesiDatumTol
|
|
,@pKilepesiDatumIg = @pKilepesiDatumIg
|
|
,@pZaradekokSzamaTol = @pZaradekokSzamaTol
|
|
,@pZaradekokSzamaIg = @pZaradekokSzamaIg
|
|
,@pKiVagyAtSorolasiZaradek = @pKiVagyAtSorolasiZaradek
|
|
,@pNaplosorszamTol = @pNaplosorszamTol
|
|
,@pNaplosorszamIg = @pNaplosorszamIg
|
|
,@pTorzslapszam = @pTorzslapszam
|
|
,@pKileptetesiDatumTol = @pKileptetesiDatumTol
|
|
,@pKileptetesiDatumIg = @pKileptetesiDatumIg
|
|
,@pUtolsoModositasDatumTol = @pUtolsoModositasDatumTol
|
|
,@pUtolsoModositasDatumIg = @pUtolsoModositasDatumIg
|
|
,@pKovTanev = @pKovTanev
|
|
|
|
END
|
|
GO
|