387 lines
No EOL
19 KiB
Transact-SQL
387 lines
No EOL
19 KiB
Transact-SQL
DROP PROCEDURE IF EXISTS [dbo].[sp_GetOsztalyTanuloinakHaviMulasztasaiOsszesitoje_honapra]
|
|
GO
|
|
|
|
CREATE PROCEDURE [dbo].[sp_GetOsztalyTanuloinakHaviMulasztasaiOsszesitoje_honapra]
|
|
@pTanevId INT,
|
|
@pIntezmenyId INT,
|
|
@pOsztalyId INT,
|
|
@pHonap INT,
|
|
@pElmeletgyakorlat BIT = 0,
|
|
@pMulasztandoOrakszamaTeljesNaposMulasztashoz INT = 3
|
|
AS
|
|
BEGIN
|
|
SET NOCOUNT ON;
|
|
DECLARE @idoszakEleje DATE = (SELECT TOP 1 C_KEZDONAP FROM T_TANEV_OSSZES WHERE ID = @pTanevId);
|
|
DECLARE @iskolaErdekuParam INT = 1683;
|
|
DECLARE @iskolaErdekuSzamit BIT = dbo.fnGetRendszerbeallitasEnumBool(@iskolaErdekuParam, @pIntezmenyId, @pTanevId);
|
|
DECLARE @pAtsoroltTanuloAdatok INT = 1;
|
|
DECLARE @pMulasztasTipusIdKeses INT = 1499;
|
|
DECLARE @pMulasztasTipusIdHianyzas INT = 1500;
|
|
--Osztály tanulói
|
|
CREATE TABLE #tanulo (Id INT)
|
|
INSERT INTO #tanulo
|
|
SELECT DISTINCT tcs.c_tanuloid AS Id
|
|
FROM T_TANULOCSOPORT_OSSZES tcs
|
|
INNER JOIN T_FELHASZNALO_OSSZES f ON f.id = tcs.c_tanuloid
|
|
WHERE tcs.torolt='F' AND f.torolt='F' AND tcs.c_tanevid=@pTanevId AND tcs.c_intezmenyid=@pIntezmenyId AND tcs.c_osztalycsoportid=@pOsztalyId;
|
|
|
|
--Igazolástípusok
|
|
CREATE TABLE #igazolastipus (Id INT, Nev NVARCHAR(MAX), Sorrend INT);
|
|
INSERT INTO #igazolastipus
|
|
SELECT T_IGAZOLASTIPUS_OSSZES.ID AS Id, C_NAME AS Nev, C_ORDER AS Sorrrend
|
|
FROM T_IGAZOLASTIPUS_OSSZES
|
|
INNER JOIN T_DICTIONARYITEMBASE_OSSZES ON T_IGAZOLASTIPUS_OSSZES.ID = T_DICTIONARYITEMBASE_OSSZES.ID
|
|
WHERE T_DICTIONARYITEMBASE_OSSZES.C_INTEZMENYID = @pIntezmenyId AND T_DICTIONARYITEMBASE_OSSZES.C_TANEVID = @pTanevId AND T_IGAZOLASTIPUS_OSSZES.C_ALINTEZMENYID = @pIntezmenyId AND T_IGAZOLASTIPUS_OSSZES.C_ALTANEVID = @pTanevId
|
|
AND T_IGAZOLASTIPUS_OSSZES.TOROLT = 'F' AND T_DICTIONARYITEMBASE_OSSZES.TOROLT = 'F'
|
|
ORDER BY C_ORDER, C_NAME;
|
|
|
|
--Igazolások és típusai
|
|
CREATE TABLE #igazolas (Tanulo INT, IgazoltE NVARCHAR(1), IgazolasTipus INT, Gyakorlati CHAR(1), HianyzasErtek FLOAT, KesettPerc FLOAT)
|
|
INSERT INTO #igazolas
|
|
SELECT TanuloId AS Tanulo, Igazolt AS IgazoltE, IgazolasTipusa AS IgazolasTipus, IIF(@pElmeletgyakorlat=0, 'F', Gyakorlati) AS Gyakorlati,
|
|
SUM(CAST(IIF(Tipusa = @pMulasztasTipusIdHianyzas, 1, IIF(Tipusa = @pMulasztasTipusIdKeses,CAST(KesesPercben AS FLOAT) / 45, 0)) AS FLOAT)) AS HianyzasErtek, KesesPercben AS KesettPerc
|
|
FROM fnGetDokumentumMulasztasokOsztalyonkentReszletes (@pTanevId, @pOsztalyId, @iskolaErdekuSzamit, 0, IIF(@pAtsoroltTanuloAdatok > 0, 1, 0), @idoszakEleje, GETDATE(), DEFAULT) AS MULASZTASOK
|
|
WHERE (CAST(MONTH(Datum) AS VARCHAR)) = @pHonap AND Tipusa IN (@pMulasztasTipusIdKeses, @pMulasztasTipusIdHianyzas)
|
|
GROUP BY IIF(@pElmeletgyakorlat=0, 'F', Gyakorlati), TanuloId, Igazolt, IgazolasTipusa, KesesPercben;
|
|
|
|
--Mulasztások
|
|
CREATE TABLE #mulasztas (Nap NVARCHAR(5), Tanulo INT, Osztaly INT, HianyzasErtek FLOAT)
|
|
INSERT INTO #mulasztas
|
|
SELECT CAST(CAST(DAY(Datum) AS INT) AS NVARCHAR) + (IIF(@pElmeletgyakorlat=0, '', IIF(Gyakorlati = 'T', '_GY', '_E'))) AS Nap, TanuloId AS Tanulo, OsztalyCsoportId AS Osztaly,
|
|
SUM(CAST(IIF(Tipusa = @pMulasztasTipusIdHianyzas, 1, IIF(Tipusa = @pMulasztasTipusIdKeses, CAST(KesesPercben AS FLOAT) / 45, 0)) AS FLOAT)) AS HianyzasErtek
|
|
FROM fnGetDokumentumMulasztasokOsztalyonkentReszletes (@pTanevId, @pOsztalyId, @iskolaErdekuSzamit, 0, IIF(@pAtsoroltTanuloAdatok > 0, 1, 0), @idoszakEleje, GETDATE(), DEFAULT) AS MULASZTASOK
|
|
WHERE (CAST(MONTH(Datum) AS VARCHAR)) = @pHonap AND Tipusa IN (@pMulasztasTipusIdKeses, @pMulasztasTipusIdHianyzas)
|
|
GROUP BY CAST(DAY(Datum) AS INT), Gyakorlati, TanuloId, OsztalyCsoportId;
|
|
|
|
--Teljes napos mulasztások száma
|
|
CREATE TABLE #teljesnaposmul (Tanulo INT, HianyzasErtek INT)
|
|
INSERT INTO #teljesnaposmul
|
|
SELECT Tanulo, SUM(TeljesNapiMul) AS HianyzasErtek
|
|
FROM (
|
|
SELECT Tanulo, Nap, IIF(SUM(HianyzasErtek) >= @pMulasztandoOrakszamaTeljesNaposMulasztashoz, 1, 0) AS TeljesNapiMul
|
|
FROM #mulasztas
|
|
GROUP BY Tanulo, Nap
|
|
) AS TeljesNapiMulasztasok
|
|
GROUP BY Tanulo
|
|
DECLARE @query AS NVARCHAR(MAX);
|
|
IF @pElmeletgyakorlat=0
|
|
BEGIN
|
|
DECLARE @colsHeader AS NVARCHAR(MAX);
|
|
DECLARE @cols AS NVARCHAR(MAX);
|
|
DECLARE @colsSum AS NVARCHAR(MAX);
|
|
SELECT @colsHeader = ISNULL(@colsHeader + ', ', '') + QUOTENAME(Id) + ' AS ' + QUOTENAME(Nev),
|
|
@cols = ISNULL(@cols + ', ', '') + QUOTENAME(Id),
|
|
@colsSum = ISNULL(@colsSum + ', ', '') + 'SUM( [' + CAST(Id as nvarchar(max)) + '] ) AS ' + QUOTENAME(Id)
|
|
FROM #igazolastipus AS Igazolastipus
|
|
ORDER BY Sorrend, Nev;
|
|
PRINT @cols;
|
|
PRINT @colsSum;
|
|
PRINT @colsHeader;
|
|
SET @query =
|
|
'SELECT
|
|
f.c_nyomtatasinev AS COLUMN108,
|
|
f.C_OKTATASIAZONOSITO AS COLUMN109,
|
|
IIF(m.[1]=0, NULL, FLOOR(m.[1])) AS [1],
|
|
IIF(m.[2]=0, NULL, FLOOR(m.[2])) AS [2],
|
|
IIF(m.[3]=0, NULL, FLOOR(m.[3])) AS [3],
|
|
IIF(m.[4]=0, NULL, FLOOR(m.[4])) AS [4],
|
|
IIF(m.[5]=0, NULL, FLOOR(m.[5])) AS [5],
|
|
IIF(m.[6]=0, NULL, FLOOR(m.[6])) AS [6],
|
|
IIF(m.[7]=0, NULL, FLOOR(m.[7])) AS [7],
|
|
IIF(m.[8]=0, NULL, FLOOR(m.[8])) AS [8],
|
|
IIF(m.[9]=0, NULL, FLOOR(m.[9])) AS [9],
|
|
IIF(m.[10]=0, NULL, FLOOR(m.[10])) AS [10],
|
|
IIF(m.[11]=0, NULL, FLOOR(m.[11])) AS [11],
|
|
IIF(m.[12]=0, NULL, FLOOR(m.[12])) AS [12],
|
|
IIF(m.[13]=0, NULL, FLOOR(m.[13])) AS [13],
|
|
IIF(m.[14]=0, NULL, FLOOR(m.[14])) AS [14],
|
|
IIF(m.[15]=0, NULL, FLOOR(m.[15])) AS [15],
|
|
IIF(m.[16]=0, NULL, FLOOR(m.[16])) AS [16],
|
|
IIF(m.[17]=0, NULL, FLOOR(m.[17])) AS [17],
|
|
IIF(m.[18]=0, NULL, FLOOR(m.[18])) AS [18],
|
|
IIF(m.[19]=0, NULL, FLOOR(m.[19])) AS [19],
|
|
IIF(m.[20]=0, NULL, FLOOR(m.[20])) AS [20],
|
|
IIF(m.[21]=0, NULL, FLOOR(m.[21])) AS [21],
|
|
IIF(m.[22]=0, NULL, FLOOR(m.[22])) AS [22],
|
|
IIF(m.[23]=0, NULL, FLOOR(m.[23])) AS [23],
|
|
IIF(m.[24]=0, NULL, FLOOR(m.[24])) AS [24],
|
|
IIF(m.[25]=0, NULL, FLOOR(m.[25])) AS [25],
|
|
IIF(m.[26]=0, NULL, FLOOR(m.[26])) AS [26],
|
|
IIF(m.[27]=0, NULL, FLOOR(m.[27])) AS [27],
|
|
IIF(m.[28]=0, NULL, FLOOR(m.[28])) AS [28],
|
|
IIF(m.[29]=0, NULL, FLOOR(m.[29])) AS [29],
|
|
IIF(m.[30]=0, NULL, FLOOR(m.[30])) AS [30],
|
|
IIF(m.[31]=0, NULL, FLOOR(m.[31])) AS [31],
|
|
FLOOR(OSSZES.MULASZTASOKSZAMA) AS COLUMN2672,
|
|
FLOOR(IGAZOLT.IGAZOLTSZAMA) AS COLUMN2568, ' + @colsHeader + ',
|
|
FLOOR(IGAZOLATLAN.IGAZOLATLANSZAMA) AS COLUMN1911,
|
|
TELJESNAPOSMULASZTAS.HianyzasErtek AS COLUMNTELJESNAPOSMULASZTASOK,
|
|
IGAZOLTKESES.IGAZOLTPERC AS COLUMNIGAZOLTKESESPERCBEN,
|
|
IGAZOLATLANKESES.IGAZOLATLANPERC AS COLUMNIGAZOLATLANKESESPERCBEN
|
|
FROM #tanulo AS tanulok
|
|
LEFT JOIN (
|
|
SELECT Tanulo, ' + @colsSum + '
|
|
FROM #igazolas AS igazolasok
|
|
PIVOT (SUM(HianyzasErtek) FOR IgazolasTipus IN (' + @cols + ')) AS PIVOTTABLE
|
|
GROUP BY Tanulo
|
|
) AS IGAZOLASTIPUSOKSZERINT ON IGAZOLASTIPUSOKSZERINT.Tanulo = tanulok.Id
|
|
LEFT JOIN (
|
|
SELECT Tanulo, HianyzasErtek
|
|
FROM #teljesnaposmul AS teljesnaposmul
|
|
) AS TELJESNAPOSMULASZTAS ON TELJESNAPOSMULASZTAS.Tanulo = tanulok.Id
|
|
LEFT JOIN (
|
|
SELECT Tanulo,
|
|
SUM([1]) AS [1],
|
|
SUM([2]) AS [2],
|
|
SUM([3]) AS [3],
|
|
SUM([4]) AS [4],
|
|
SUM([5]) AS [5],
|
|
SUM([6]) AS [6],
|
|
SUM([7]) AS [7],
|
|
SUM([8]) AS [8],
|
|
SUM([9]) AS [9],
|
|
SUM([10]) AS [10],
|
|
SUM([11]) AS [11],
|
|
SUM([12]) AS [12],
|
|
SUM([13]) AS [13],
|
|
SUM([14]) AS [14],
|
|
SUM([15]) AS [15],
|
|
SUM([16]) AS [16],
|
|
SUM([17]) AS [17],
|
|
SUM([18]) AS [18],
|
|
SUM([19]) AS [19],
|
|
SUM([20]) AS [20],
|
|
SUM([21]) AS [21],
|
|
SUM([22]) AS [22],
|
|
SUM([23]) AS [23],
|
|
SUM([24]) AS [24],
|
|
SUM([25]) AS [25],
|
|
SUM([26]) AS [26],
|
|
SUM([27]) AS [27],
|
|
SUM([28]) AS [28],
|
|
SUM([29]) AS [29],
|
|
SUM([30]) AS [30],
|
|
SUM([31]) AS [31]
|
|
FROM #mulasztas AS mulasztas
|
|
PIVOT (SUM(mulasztas.HianyzasErtek) 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])) pv
|
|
GROUP BY Tanulo
|
|
) m ON m.Tanulo = tanulok.id
|
|
LEFT JOIN (SELECT Tanulo, SUM(HianyzasErtek) AS MULASZTASOKSZAMA FROM #igazolas GROUP BY Tanulo) AS OSSZES ON OSSZES.Tanulo = tanulok.Id
|
|
LEFT JOIN (SELECT Tanulo, SUM(HianyzasErtek) AS IGAZOLTSZAMA FROM #igazolas i WHERE i.IgazoltE=''T'' GROUP BY Tanulo) AS IGAZOLT ON IGAZOLT.Tanulo = tanulok.Id
|
|
LEFT JOIN (SELECT Tanulo, SUM(HianyzasErtek) AS IGAZOLATLANSZAMA FROM #igazolas i WHERE i.IgazoltE=''F'' GROUP BY Tanulo) AS IGAZOLATLAN ON IGAZOLATLAN.Tanulo = tanulok.Id
|
|
LEFT JOIN (SELECT Tanulo, SUM(KesettPerc) AS IGAZOLTPERC FROM #igazolas i WHERE i.IgazoltE=''T'' GROUP BY Tanulo) AS IGAZOLTKESES ON IGAZOLTKESES.Tanulo = tanulok.Id
|
|
LEFT JOIN (SELECT Tanulo, SUM(KesettPerc) AS IGAZOLATLANPERC FROM #igazolas i WHERE (i.IgazoltE=''F'' OR i.IgazoltE IS NULL) GROUP BY Tanulo) AS IGAZOLATLANKESES ON IGAZOLATLANKESES.Tanulo = tanulok.Id
|
|
INNER JOIN T_FELHASZNALO_OSSZES f ON f.id = tanulok.Id
|
|
--GROUP BY f.c_nyomtatasinev, tanulok.Id, f.id
|
|
ORDER BY f.c_nyomtatasinev';
|
|
exec sp_executesql @query;
|
|
END
|
|
ELSE
|
|
BEGIN
|
|
DECLARE @colsHeader_E AS NVARCHAR(MAX);
|
|
DECLARE @colsHeader_GY AS NVARCHAR(MAX);
|
|
DECLARE @cols_E AS NVARCHAR(MAX);
|
|
DECLARE @cols_GY AS NVARCHAR(MAX);
|
|
DECLARE @colsSum_E AS NVARCHAR(MAX);
|
|
DECLARE @colsSum_GY AS NVARCHAR(MAX);
|
|
SELECT @colsHeader_E = ISNULL(@colsHeader_E + ', ', '') + QUOTENAME(Id) + ' AS ' + QUOTENAME(Nev + ' (elméleti)'),
|
|
@colsHeader_GY = ISNULL(@colsHeader_GY + ', ', '') + QUOTENAME(-Id) + ' AS ' + QUOTENAME(Nev + ' (gyakorlati)'),
|
|
@cols_E = ISNULL(@cols_E + ', ', '') + QUOTENAME(Id),
|
|
@cols_GY = ISNULL(@cols_GY + ', ', '') + QUOTENAME(-Id),
|
|
@colsSum_E = ISNULL(@colsSum_E + ', ', '') + 'SUM( [' + CAST(Id as nvarchar(max)) + '] ) AS ' + QUOTENAME(Id),
|
|
@colsSum_GY = ISNULL(@colsSum_GY + ', ', '') + 'SUM( [' + CAST(-Id as nvarchar(max)) + '] ) AS ' + QUOTENAME(-Id)
|
|
FROM #igazolastipus AS Igazolastipus
|
|
ORDER BY Sorrend, Nev;
|
|
|
|
SET @query =
|
|
'SELECT f.c_nyomtatasinev AS COLUMN108,
|
|
f.C_OKTATASIAZONOSITO AS COLUMN109,
|
|
IIF(m.[1_E]=0, NULL, FLOOR(m.[1_E])) AS [1 E],
|
|
IIF(m.[1_GY]=0, NULL, FLOOR(m.[1_GY])) AS [1 GY],
|
|
IIF(m.[2_E]=0, NULL, FLOOR(m.[2_E])) AS [2 E],
|
|
IIF(m.[2_GY]=0, NULL, FLOOR(m.[2_GY])) AS [2 GY],
|
|
IIF(m.[3_E]=0, NULL, FLOOR(m.[3_E])) AS [3 E],
|
|
IIF(m.[3_GY]=0, NULL, FLOOR(m.[3_GY])) AS [3 GY],
|
|
IIF(m.[4_E]=0, NULL, FLOOR(m.[4_E])) AS [4 E],
|
|
IIF(m.[4_GY]=0, NULL, FLOOR(m.[4_GY])) AS [4 GY],
|
|
IIF(m.[5_E]=0, NULL, FLOOR(m.[5_E])) AS [5 E],
|
|
IIF(m.[5_GY]=0, NULL, FLOOR(m.[5_GY])) AS [5 GY],
|
|
IIF(m.[6_E]=0, NULL, FLOOR(m.[6_E])) AS [6 E],
|
|
IIF(m.[6_GY]=0, NULL, FLOOR(m.[6_GY])) AS [6 GY],
|
|
IIF(m.[7_E]=0, NULL, FLOOR(m.[7_E])) AS [7 E],
|
|
IIF(m.[7_GY]=0, NULL, FLOOR(m.[7_GY])) AS [7 GY],
|
|
IIF(m.[8_E]=0, NULL, FLOOR(m.[8_E])) AS [8 E],
|
|
IIF(m.[8_GY]=0, NULL, FLOOR(m.[8_GY])) AS [8 GY],
|
|
IIF(m.[9_E]=0, NULL, FLOOR(m.[9_E])) AS [9 E],
|
|
IIF(m.[9_GY]=0, NULL, FLOOR(m.[9_GY])) AS [9 GY],
|
|
IIF(m.[10_E]=0, NULL, FLOOR(m.[10_E])) AS [10 E],
|
|
IIF(m.[10_GY]=0, NULL, FLOOR(m.[10_GY])) AS [10 GY],
|
|
IIF(m.[11_E]=0, NULL, FLOOR(m.[11_E])) AS [11 E],
|
|
IIF(m.[11_GY]=0, NULL, FLOOR(m.[11_GY])) AS [11 GY],
|
|
IIF(m.[12_E]=0, NULL, FLOOR(m.[12_E])) AS [12 E],
|
|
IIF(m.[12_GY]=0, NULL, FLOOR(m.[12_GY])) AS [12 GY],
|
|
IIF(m.[13_E]=0, NULL, FLOOR(m.[13_E])) AS [13 E],
|
|
IIF(m.[13_GY]=0, NULL, FLOOR(m.[13_GY])) AS [13 GY],
|
|
IIF(m.[14_E]=0, NULL, FLOOR(m.[14_E])) AS [14 E],
|
|
IIF(m.[14_GY]=0, NULL, FLOOR(m.[14_GY])) AS [14 GY],
|
|
IIF(m.[15_E]=0, NULL, FLOOR(m.[15_E])) AS [15 E],
|
|
IIF(m.[15_GY]=0, NULL, FLOOR(m.[15_GY])) AS [15 GY],
|
|
IIF(m.[16_E]=0, NULL, FLOOR(m.[16_E])) AS [16 E],
|
|
IIF(m.[16_GY]=0, NULL, FLOOR(m.[16_GY])) AS [16 GY],
|
|
IIF(m.[17_E]=0, NULL, FLOOR(m.[17_E])) AS [17 E],
|
|
IIF(m.[17_GY]=0, NULL, FLOOR(m.[17_GY])) AS [17 GY],
|
|
IIF(m.[18_E]=0, NULL, FLOOR(m.[18_E])) AS [18 E],
|
|
IIF(m.[18_GY]=0, NULL, FLOOR(m.[18_GY])) AS [18 GY],
|
|
IIF(m.[19_E]=0, NULL, FLOOR(m.[19_E])) AS [19 E],
|
|
IIF(m.[19_GY]=0, NULL, FLOOR(m.[19_GY])) AS [19 GY],
|
|
IIF(m.[20_E]=0, NULL, FLOOR(m.[20_E])) AS [20 E],
|
|
IIF(m.[20_GY]=0, NULL, FLOOR(m.[20_GY])) AS [20 GY],
|
|
IIF(m.[21_E]=0, NULL, FLOOR(m.[21_E])) AS [21 E],
|
|
IIF(m.[21_GY]=0, NULL, FLOOR(m.[21_GY])) AS [21 GY],
|
|
IIF(m.[22_E]=0, NULL, FLOOR(m.[22_E])) AS [22 E],
|
|
IIF(m.[22_GY]=0, NULL, FLOOR(m.[22_GY])) AS [22 GY],
|
|
IIF(m.[23_E]=0, NULL, FLOOR(m.[23_E])) AS [23 E],
|
|
IIF(m.[23_GY]=0, NULL, FLOOR(m.[23_GY])) AS [23 GY],
|
|
IIF(m.[24_E]=0, NULL, FLOOR(m.[24_E])) AS [24 E],
|
|
IIF(m.[24_GY]=0, NULL, FLOOR(m.[24_GY])) AS [24 GY],
|
|
IIF(m.[25_E]=0, NULL, FLOOR(m.[25_E])) AS [25 E],
|
|
IIF(m.[25_GY]=0, NULL, FLOOR(m.[25_GY])) AS [25 GY],
|
|
IIF(m.[26_E]=0, NULL, FLOOR(m.[26_E])) AS [26 E],
|
|
IIF(m.[26_GY]=0, NULL, FLOOR(m.[26_GY])) AS [26 GY],
|
|
IIF(m.[27_E]=0, NULL, FLOOR(m.[27_E])) AS [27 E],
|
|
IIF(m.[27_GY]=0, NULL, FLOOR(m.[27_GY])) AS [27 GY],
|
|
IIF(m.[28_E]=0, NULL, FLOOR(m.[28_E])) AS [28 E],
|
|
IIF(m.[28_GY]=0, NULL, FLOOR(m.[28_GY])) AS [28 GY],
|
|
IIF(m.[29_E]=0, NULL, FLOOR(m.[29_E])) AS [29 E],
|
|
IIF(m.[29_GY]=0, NULL, FLOOR(m.[29_GY])) AS [29 GY],
|
|
IIF(m.[30_E]=0, NULL, FLOOR(m.[30_E])) AS [30 E],
|
|
IIF(m.[30_GY]=0, NULL, FLOOR(m.[30_GY])) AS [30 GY],
|
|
IIF(m.[31_E]=0, NULL, FLOOR(m.[31_E])) AS [31 E],
|
|
FLOOR(osszes_e.MULASZTASOKSZAMA) AS COLUMN2672_E,
|
|
FLOOR(igazolt_e.IGAZOLTSZAMA) AS COLUMN2568_E,
|
|
' + @colsHeader_E + ',
|
|
FLOOR(igazolatlan_e.IGAZOLATLANSZAMA) AS COLUMN1911_E,
|
|
FLOOR(osszes_gy.MULASZTASOKSZAMA) AS COLUMN2672_GY,
|
|
FLOOR(igazolt_gy.IGAZOLTSZAMA) AS COLUMN2568_GY,
|
|
' + @colsHeader_GY + ',
|
|
FLOOR(igazolatlan_gy.IGAZOLATLANSZAMA) AS COLUMN1911_GY,
|
|
TELJESNAPOSMULASZTAS.HianyzasErtek AS COLUMNTELJESNAPOSMULASZTASOK,
|
|
igazoltkeses_e.IGAZOLTPERC AS COLUMNIGAZOLTKESESPERCBEN_E,
|
|
igazoltkeses_gy.IGAZOLTPERC AS COLUMNIGAZOLTKESESPERCBEN_GY,
|
|
igazolatlankeses_e.IGAZOLATLANPERC AS COLUMNIGAZOLATLANKESESPERCBEN_E,
|
|
igazolatlankeses_gy.IGAZOLATLANPERC AS COLUMNIGAZOLATLANKESESPERCBEN_GY
|
|
FROM #tanulo AS tanulok
|
|
LEFT JOIN (
|
|
SELECT Tanulo, ' + @colsSum_E + '
|
|
FROM (
|
|
SELECT *
|
|
FROM #igazolas AS igazolasok
|
|
WHERE Gyakorlati = ''F'' OR Gyakorlati IS NULL
|
|
) AS igazolasok
|
|
PIVOT (SUM(HianyzasErtek) FOR IgazolasTipus IN (' + @cols_E + ')) AS PIVOTTABLE_E
|
|
GROUP BY Tanulo
|
|
) AS IGAZOLASTIPUSOKSZERINT_E ON IGAZOLASTIPUSOKSZERINT_E.Tanulo = tanulok.Id
|
|
LEFT JOIN (
|
|
SELECT Tanulo, ' + @colsSum_Gy + '
|
|
FROM (
|
|
SELECT Tanulo, IgazoltE, -IgazolasTipus AS IgazolasTipus, Gyakorlati, HianyzasErtek
|
|
FROM #igazolas AS igazolasok
|
|
WHERE Gyakorlati = ''T''
|
|
) AS igazolasok
|
|
PIVOT (SUM(HianyzasErtek) FOR IgazolasTipus IN (' + @cols_GY + ')) AS PIVOTTABLE_GY
|
|
GROUP BY Tanulo
|
|
) AS IGAZOLASTIPUSOKSZERINT_GY ON IGAZOLASTIPUSOKSZERINT_GY.Tanulo = tanulok.Id
|
|
LEFT JOIN (
|
|
SELECT Tanulo, HianyzasErtek
|
|
FROM #teljesnaposmul AS teljesnaposmul
|
|
) AS TELJESNAPOSMULASZTAS ON TELJESNAPOSMULASZTAS.Tanulo = tanulok.Id
|
|
LEFT JOIN (
|
|
SELECT
|
|
Tanulo,
|
|
SUM([1_E]) AS [1_E],
|
|
SUM([2_E]) AS [2_E],
|
|
SUM([3_E]) AS [3_E],
|
|
SUM([4_E]) AS [4_E],
|
|
SUM([5_E]) AS [5_E],
|
|
SUM([6_E]) AS [6_E],
|
|
SUM([7_E]) AS [7_E],
|
|
SUM([8_E]) AS [8_E],
|
|
SUM([9_E]) AS [9_E],
|
|
SUM([10_E]) AS [10_E],
|
|
SUM([11_E]) AS [11_E],
|
|
SUM([12_E]) AS [12_E],
|
|
SUM([13_E]) AS [13_E],
|
|
SUM([14_E]) AS [14_E],
|
|
SUM([15_E]) AS [15_E],
|
|
SUM([16_E]) AS [16_E],
|
|
SUM([17_E]) AS [17_E],
|
|
SUM([18_E]) AS [18_E],
|
|
SUM([19_E]) AS [19_E],
|
|
SUM([20_E]) AS [20_E],
|
|
SUM([21_E]) AS [21_E],
|
|
SUM([22_E]) AS [22_E],
|
|
SUM([23_E]) AS [23_E],
|
|
SUM([24_E]) AS [24_E],
|
|
SUM([25_E]) AS [25_E],
|
|
SUM([26_E]) AS [26_E],
|
|
SUM([27_E]) AS [27_E],
|
|
SUM([28_E]) AS [28_E],
|
|
SUM([29_E]) AS [29_E],
|
|
SUM([30_E]) AS [30_E],
|
|
SUM([31_E]) AS [31_E],
|
|
SUM([1_GY]) AS [1_GY],
|
|
SUM([2_GY]) AS [2_GY],
|
|
SUM([3_GY]) AS [3_GY],
|
|
SUM([4_GY]) AS [4_GY],
|
|
SUM([5_GY]) AS [5_GY],
|
|
SUM([6_GY]) AS [6_GY],
|
|
SUM([7_GY]) AS [7_GY],
|
|
SUM([8_GY]) AS [8_GY],
|
|
SUM([9_GY]) AS [9_GY],
|
|
SUM([10_GY]) AS [10_GY],
|
|
SUM([11_GY]) AS [11_GY],
|
|
SUM([12_GY]) AS [12_GY],
|
|
SUM([13_GY]) AS [13_GY],
|
|
SUM([14_GY]) AS [14_GY],
|
|
SUM([15_GY]) AS [15_GY],
|
|
SUM([16_GY]) AS [16_GY],
|
|
SUM([17_GY]) AS [17_GY],
|
|
SUM([18_GY]) AS [18_GY],
|
|
SUM([19_GY]) AS [19_GY],
|
|
SUM([20_GY]) AS [20_GY],
|
|
SUM([21_GY]) AS [21_GY],
|
|
SUM([22_GY]) AS [22_GY],
|
|
SUM([23_GY]) AS [23_GY],
|
|
SUM([24_GY]) AS [24_GY], SUM([25_GY]) AS [25_GY], SUM([26_GY]) AS [26_GY], SUM([27_GY]) AS [27_GY], SUM([28_GY]) AS [28_GY], SUM([29_GY]) AS [29_GY],SUM([30_GY]) AS [30_GY], SUM([31_GY]) AS [31_GY]
|
|
FROM #mulasztas AS m
|
|
PIVOT (SUM(HianyzasErtek) for Nap in
|
|
(
|
|
[1_E],[2_E],[3_E],[4_E],[5_E],[6_E],[7_E],[8_E],[9_E],[10_E],[11_E],[12_E],[13_E],[14_E],[15_E],[16_E],[17_E],[18_E],[19_E],[20_E],[21_E],[22_E],[23_E],[24_E],[25_E],[26_E],[27_E],[28_E],[29_E],[30_E],[31_E],
|
|
[1_GY],[2_GY],[3_GY],[4_GY],[5_GY],[6_GY],[7_GY],[8_GY],[9_GY],[10_GY],[11_GY],[12_GY],[13_GY],[14_GY],[15_GY],[16_GY],[17_GY],[18_GY],[19_GY],[20_GY],[21_GY],[22_GY],[23_GY],[24_GY],[25_GY],[26_GY],[27_GY],[28_GY],[29_GY],[30_GY],[31_GY]
|
|
)
|
|
) pv
|
|
GROUP BY Tanulo
|
|
) m ON m.Tanulo = tanulok.id
|
|
LEFT JOIN (SELECT Tanulo, SUM(HianyzasErtek) AS MULASZTASOKSZAMA FROM #igazolas WHERE (Gyakorlati = ''F'' OR Gyakorlati IS NULL) GROUP BY Tanulo) AS Osszes_E ON Osszes_E.Tanulo = tanulok.Id
|
|
LEFT JOIN (SELECT Tanulo, SUM(HianyzasErtek) AS IGAZOLTSZAMA FROM #igazolas i WHERE (Gyakorlati = ''F'' OR Gyakorlati IS NULL) AND i.IgazoltE=''T'' GROUP BY Tanulo) AS Igazolt_E ON Igazolt_E.Tanulo = tanulok.Id
|
|
LEFT JOIN (SELECT Tanulo, SUM(HianyzasErtek) AS IGAZOLATLANSZAMA FROM #igazolas i WHERE (Gyakorlati = ''F'' OR Gyakorlati IS NULL) AND i.IgazoltE=''F'' GROUP BY Tanulo) AS Igazolatlan_E ON Igazolatlan_E.Tanulo = tanulok.Id
|
|
LEFT JOIN (SELECT Tanulo, SUM(HianyzasErtek) AS MULASZTASOKSZAMA FROM #igazolas WHERE Gyakorlati = ''T'' GROUP BY Tanulo) AS Osszes_Gy ON Osszes_Gy.Tanulo = tanulok.Id
|
|
LEFT JOIN (SELECT Tanulo, SUM(HianyzasErtek) AS IGAZOLTSZAMA FROM #igazolas i WHERE Gyakorlati = ''T'' AND i.IgazoltE=''T'' GROUP BY Tanulo) AS Igazolt_Gy ON Igazolt_Gy.Tanulo = tanulok.Id
|
|
LEFT JOIN (SELECT Tanulo, SUM(HianyzasErtek) AS IGAZOLATLANSZAMA FROM #igazolas i WHERE Gyakorlati = ''T'' AND i.IgazoltE=''F'' GROUP BY Tanulo) AS Igazolatlan_Gy ON Igazolatlan_Gy.Tanulo = tanulok.Id'
|
|
SET @query +=
|
|
' LEFT JOIN (SELECT Tanulo, SUM(KesettPerc) AS IGAZOLTPERC FROM #igazolas i WHERE (Gyakorlati = ''F'' OR Gyakorlati IS NULL) AND i.IgazoltE=''T'' GROUP BY Tanulo) AS igazoltkeses_e ON igazoltkeses_e.Tanulo = tanulok.Id
|
|
LEFT JOIN (SELECT Tanulo, SUM(KesettPerc) AS IGAZOLTPERC FROM #igazolas i WHERE Gyakorlati = ''T'' AND i.IgazoltE=''T'' GROUP BY Tanulo) AS igazoltkeses_gy ON igazoltkeses_gy.Tanulo = tanulok.Id
|
|
LEFT JOIN (SELECT Tanulo, SUM(KesettPerc) AS IGAZOLATLANPERC FROM #igazolas i WHERE (Gyakorlati = ''F'' OR Gyakorlati IS NULL) AND (i.IgazoltE=''F'' OR i.IgazoltE IS NULL) GROUP BY Tanulo) AS igazolatlankeses_e ON igazolatlankeses_e.Tanulo = tanulok.Id
|
|
LEFT JOIN (SELECT Tanulo, SUM(KesettPerc) AS IGAZOLATLANPERC FROM #igazolas i WHERE Gyakorlati = ''T'' AND (i.IgazoltE=''F'' OR i.IgazoltE IS NULL) GROUP BY Tanulo) AS igazolatlankeses_gy ON igazolatlankeses_gy.Tanulo = tanulok.Id
|
|
INNER JOIN T_FELHASZNALO_OSSZES f ON f.id = tanulok.Id
|
|
ORDER BY f.c_nyomtatasinev';
|
|
exec sp_executesql @query;
|
|
END
|
|
DROP TABLE #mulasztas
|
|
DROP TABLE #tanulo
|
|
DROP TABLE #igazolas
|
|
DROP TABLE #igazolastipus
|
|
DROP TABLE #teljesnaposmul
|
|
END
|
|
|
|
GO |