325 lines
No EOL
11 KiB
Transact-SQL
325 lines
No EOL
11 KiB
Transact-SQL
DROP PROCEDURE IF EXISTS uspGetCsoportJelenletAdatok
|
|
GO
|
|
|
|
CREATE PROCEDURE uspGetCsoportJelenletAdatok
|
|
@pTanevId int
|
|
,@pCsoportId int
|
|
,@pTablazatElrendezes int = 0 -- 0: Tanulók adatai vízszintesen, 1: Órák adatai vízszintesen
|
|
,@pOsszesitesTipus int = 0 -- 0: Heti rendszerességgel, 1: Havi rendszerességgel
|
|
|
|
AS BEGIN
|
|
SET NOCOUNT ON;
|
|
|
|
DECLARE @oszlopNevek nvarchar(max)
|
|
,@sql nvarchar(max)
|
|
,@osszesMegtartottOrakSzama int
|
|
|
|
CREATE TABLE #Tanorak (
|
|
ID int
|
|
,HetSorszama int
|
|
,Datum datetime
|
|
,OraKezdete datetime
|
|
,Idopont nvarchar(100)
|
|
)
|
|
CREATE TABLE #Tanulok (
|
|
ID int
|
|
,TanuloNeve nvarchar(510)
|
|
)
|
|
CREATE TABLE #adatokTable (
|
|
TanuloId int
|
|
,TanuloNeve nvarchar(510)
|
|
,Sorszam int
|
|
,Idopont nvarchar(100)
|
|
,Jeloles nvarchar(100)
|
|
)
|
|
|
|
INSERT INTO #Tanorak
|
|
SELECT
|
|
tao.ID
|
|
,tao.C_HETSORSZAMA
|
|
,tao.C_DATUM
|
|
,tao.C_ORAKEZDETE
|
|
,CONVERT(nvarchar, tao.C_DATUM, 102) + ' (' + LOWER(d.C_NAME) + ') ' + IIF(@pTablazatElrendezes = 0, CHAR(10), '')
|
|
+ ISNULL(CONVERT(nvarchar, tao.C_ORASZAM) + '. óra', CONVERT(nvarchar(5), tao.C_ORAKEZDETE, 114) + '-' + CONVERT(nvarchar(5), tao.C_ORAVEGE, 114))
|
|
FROM T_TANITASIORA_OSSZES tao
|
|
INNER JOIN T_DICTIONARYITEMBASE_OSSZES d ON d.ID = tao.C_HETNAPJA AND d.C_TANEVID = tao.C_TANEVID AND d.TOROLT = 'F'
|
|
WHERE tao.C_TANEVID = @pTanevId
|
|
AND tao.C_OSZTALYCSOPORTID = @pCsoportId
|
|
AND tao.TOROLT = 'F'
|
|
AND tao.C_MEGTARTOTT = 'T'
|
|
|
|
INSERT INTO #Tanulok
|
|
SELECT
|
|
f.ID
|
|
,f.C_NYOMTATASINEV
|
|
FROM T_FELHASZNALO_OSSZES f
|
|
INNER JOIN T_TANULO_OSSZES t ON t.ID = f.ID AND t.TOROLT = 'F'
|
|
INNER JOIN fnGetDokumentumOsztalyokCsoportokTanuloi(@pTanevId, @pCsoportId, 'F') cst ON cst.TanuloId = t.ID AND cst.KilepesDatum IS NULL
|
|
WHERE f.C_TANEVID = @pTanevId
|
|
AND f.TOROLT = 'F'
|
|
|
|
IF @pOsszesitesTipus = 0
|
|
BEGIN
|
|
DECLARE jelenletCursor CURSOR
|
|
FOR
|
|
SELECT C_HETSORSZAMA
|
|
FROM T_NAPTARIHET_OSSZES nh
|
|
WHERE nh.TOROLT = 'F' AND nh.C_HETKEZDONAPJA <= GETDATE() AND nh.C_TANEVID = @pTanevId
|
|
END
|
|
ELSE
|
|
BEGIN
|
|
DECLARE jelenletCursor CURSOR
|
|
FOR
|
|
SELECT DISTINCT DATEPART(month, C_HETKEZDONAPJA) AS C_HETSORSZAMA, MIN(C_HETKEZDONAPJA)
|
|
FROM T_NAPTARIHET_OSSZES nh
|
|
WHERE nh.TOROLT = 'F' AND nh.C_HETKEZDONAPJA <= GETDATE() AND nh.C_TANEVID = @pTanevId
|
|
GROUP BY DATEPART(month, C_HETKEZDONAPJA)
|
|
ORDER BY MIN(C_HETKEZDONAPJA)
|
|
DECLARE @temp datetime
|
|
END
|
|
DECLARE @hetSorszama int
|
|
|
|
OPEN jelenletCursor
|
|
IF @pOsszesitesTipus = 0
|
|
BEGIN
|
|
FETCH NEXT FROM jelenletCursor INTO @hetSorszama
|
|
END
|
|
ELSE
|
|
BEGIN
|
|
FETCH NEXT FROM jelenletCursor INTO @hetSorszama, @temp
|
|
END
|
|
|
|
WHILE @@FETCH_STATUS = 0 BEGIN
|
|
SET @oszlopNevek = IIF(@pTablazatElrendezes = 0
|
|
,IIF(@pOsszesitesTipus = 0
|
|
,(SELECT STUFF((SELECT ',' + QUOTENAME(Idopont) FROM #Tanorak WHERE HetSorszama = @hetSorszama GROUP BY Datum, OraKezdete, Idopont ORDER BY Datum, OraKezdete FOR XML PATH ('')), 1, 1, ''))
|
|
,(SELECT STUFF((SELECT ',' + QUOTENAME(Idopont) FROM #Tanorak WHERE DATEPART(month, Datum) = @hetSorszama GROUP BY Datum, OraKezdete, Idopont ORDER BY Datum, OraKezdete FOR XML PATH ('')), 1, 1, ''))
|
|
)
|
|
,(SELECT STUFF((SELECT ',' + QUOTENAME(TanuloNeve) FROM #Tanulok ORDER BY TanuloNeve FOR XML PATH ('')), 1, 1, '')))
|
|
SET @sql = N'
|
|
INSERT INTO #adatokTable
|
|
SELECT
|
|
tanulo.ID
|
|
,tanulo.TanuloNeve
|
|
,' + IIF(@pOsszesitesTipus = 0, 'tao.HetSorszama', 'DATEPART(month, tao.Datum)') + N'
|
|
,tao.Idopont
|
|
,IIF(m.ID IS NULL, ''J'',
|
|
CASE m.C_TIPUS
|
|
WHEN 1817 THEN ''''
|
|
WHEN 1499 THEN ''K<sub>'' + CAST(m.C_KESESPERCBEN as nvarchar) + ''</sub>''
|
|
WHEN 1500 THEN IIF(m.C_IGAZOLT = ''T'', ''H<sub>ig</sub>'', ''H'')
|
|
END
|
|
) AS Jeloles
|
|
FROM #Tanulok tanulo
|
|
OUTER APPLY #Tanorak tao
|
|
LEFT JOIN T_TANULOMULASZTAS_OSSZES m ON m.C_TANITASIORAKID = tao.ID AND m.C_ORATANULOIID = tanulo.ID AND m.TOROLT = ''F''
|
|
' + IIF(@pTablazatElrendezes = 0, '', IIF(@pOsszesitesTipus = 0, N'
|
|
WHERE tao.HetSorszama = @hetSorszama', N'
|
|
WHERE DATEPART(month, tao.Datum) = @hetSorszama')) + N'
|
|
|
|
SELECT piv.*
|
|
,szumma.Osszesen
|
|
FROM
|
|
(
|
|
SELECT ' + IIF(@pTablazatElrendezes = 0, 'TanuloNeve', 'Idopont') + N', @hetSorszama AS Sorszam, ' + @oszlopNevek + N'
|
|
FROM (
|
|
SELECT TanuloNeve, Idopont, Jeloles FROM #adatokTable
|
|
) AS src
|
|
PIVOT
|
|
(
|
|
MAX(src.Jeloles)
|
|
FOR src.' + IIF(@pTablazatElrendezes = 0, 'Idopont', 'TanuloNeve') + N' IN (' + @oszlopNevek + N')
|
|
) AS p
|
|
) AS piv
|
|
LEFT JOIN
|
|
(
|
|
SELECT ' + IIF(@pTablazatElrendezes = 0, 'TanuloNeve', 'Idopont') + N', Sorszam
|
|
, CAST(SUM( case when SUBSTRING(Jeloles, 1, 1) IN (''J'', ''K'') then 1 else 0 end) AS nvarchar(3)) + ''/'' +
|
|
CAST(SUM( case when SUBSTRING(Jeloles, 1, 1) = ''H'' then 1 else 0 end) AS nvarchar(3)) AS Osszesen
|
|
FROM #adatokTable
|
|
GROUP BY ' + IIF(@pTablazatElrendezes = 0, 'TanuloNeve', 'Idopont') + N', Sorszam
|
|
) szumma ON szumma.' + IIF(@pTablazatElrendezes = 0, 'TanuloNeve', 'Idopont') + N' = piv.' + IIF(@pTablazatElrendezes = 0, 'TanuloNeve', 'Idopont') + N' AND szumma.Sorszam = piv.Sorszam
|
|
|
|
TRUNCATE TABLE #adatokTable
|
|
'
|
|
|
|
EXEC sp_executesql @sql
|
|
,N'@pTanevId int
|
|
,@pCsoportId int
|
|
,@hetSorszama int'
|
|
,@pTanevId = @pTanevId
|
|
,@pCsoportId = @pCsoportId
|
|
,@hetSorszama = @hetSorszama
|
|
|
|
IF @pOsszesitesTipus = 0
|
|
BEGIN
|
|
FETCH NEXT FROM jelenletCursor INTO @hetSorszama
|
|
END
|
|
ELSE
|
|
BEGIN
|
|
FETCH NEXT FROM jelenletCursor INTO @hetSorszama, @temp
|
|
END
|
|
END
|
|
CLOSE jelenletCursor
|
|
DEALLOCATE jelenletCursor
|
|
|
|
DECLARE @felevVege datetime
|
|
,@utolsoTanitasiNap datetime
|
|
SELECT @felevVege = FelevVege
|
|
,@utolsoTanitasiNap = UtolsoTanitasiNap
|
|
FROM dbo.fnGetElsoUtolsoTanitasiNapFelevVege(@pTanevId, @pCsoportId)
|
|
SELECT (SELECT C_HETSORSZAMA FROM T_NAPTARIHET_OSSZES nh WHERE nh.C_TANEVID = @pTanevId AND @felevVege BETWEEN C_HETKEZDONAPJA AND C_HETUTOLSONAPJA) AS FelevHetsorszam
|
|
,(SELECT C_HETSORSZAMA FROM T_NAPTARIHET_OSSZES nh WHERE nh.C_TANEVID = @pTanevId AND @utolsoTanitasiNap BETWEEN C_HETKEZDONAPJA AND C_HETUTOLSONAPJA) AS UtolsoTanitasiNapHetsorszam
|
|
|
|
INSERT INTO #adatokTable
|
|
SELECT
|
|
tanulo.ID
|
|
,tanulo.TanuloNeve
|
|
,IIF(tao.Datum <= @felevVege, 0, 1)
|
|
,tao.Idopont
|
|
,IIF(m.ID IS NULL, 'J',
|
|
CASE m.C_TIPUS
|
|
WHEN 1817 THEN ''
|
|
WHEN 1499 THEN 'J'
|
|
WHEN 1500 THEN 'H'
|
|
END
|
|
) AS Jeloles
|
|
FROM #Tanulok tanulo
|
|
OUTER APPLY #Tanorak tao
|
|
LEFT JOIN T_TANULOMULASZTAS_OSSZES m ON m.C_TANITASIORAKID = tao.ID AND m.C_ORATANULOIID = tanulo.ID AND m.TOROLT = 'F'
|
|
|
|
SET @oszlopNevek = (SELECT STUFF((SELECT DISTINCT ',' + QUOTENAME(Idopont) FROM #adatokTable WHERE Sorszam = 0 ORDER BY ',' + QUOTENAME(Idopont) FOR XML PATH ('')), 1, 1, ''))
|
|
SET @osszesMegtartottOrakSzama = (SELECT TOP 1 COUNT(Idopont) OVER() FROM #adatokTable WHERE Sorszam = 0 GROUP BY Idopont)
|
|
|
|
IF (@oszlopNevek is not null)
|
|
BEGIN
|
|
SET @sql = N'
|
|
;WITH PivotData AS
|
|
(
|
|
SELECT a.Sorszam, a.Idopont, a.Jeloles, COUNT(a.Jeloles) AS db
|
|
FROM #adatokTable a
|
|
WHERE a.Jeloles <> ''''
|
|
AND a.Sorszam = 0
|
|
GROUP BY a.Sorszam, a.Idopont, a.Jeloles
|
|
)
|
|
SELECT piv.Jeloles, ' + @oszlopNevek + N', j.Osszesen, j.Atlag
|
|
FROM (
|
|
SELECT Sorszam, Jeloles, ' + @oszlopNevek + N'
|
|
from PivotData
|
|
PIVOT
|
|
(
|
|
SUM(PivotData.db)
|
|
FOR PivotData.Idopont IN (' + @oszlopNevek + N')
|
|
) AS p
|
|
) piv
|
|
LEFT JOIN (
|
|
SELECT Sorszam, Jeloles
|
|
,IIF(Jeloles = ''J'', SUM( CASE WHEN Jeloles = ''J'' THEN 1 ELSE 0 END )
|
|
,SUM( CASE WHEN Jeloles = ''H'' THEN 1 ELSE 0 END )) AS Osszesen
|
|
,CAST((IIF(Jeloles = ''J'', SUM( CASE WHEN Jeloles = ''J'' THEN 1 ELSE 0 END )
|
|
,SUM( CASE WHEN Jeloles = ''H'' THEN 1 ELSE 0 END ))) / @osszesMegtartottOrakSzama AS numeric(5, 2)) AS Atlag
|
|
FROM #adatokTable
|
|
GROUP BY Sorszam, Jeloles
|
|
) j ON j.Sorszam = piv.Sorszam AND j.Jeloles = piv.Jeloles
|
|
ORDER BY j.Jeloles DESC
|
|
'
|
|
END
|
|
ELSE
|
|
BEGIN
|
|
SET @sql = N'
|
|
SELECT
|
|
null AS Jeloles
|
|
,null as Osszesen
|
|
,null as Atlag
|
|
'
|
|
END
|
|
|
|
exec sp_executesql @sql
|
|
,N'@osszesMegtartottOrakSzama numeric(5, 2)'
|
|
,@osszesMegtartottOrakSzama = @osszesMegtartottOrakSzama
|
|
|
|
-- Ez a rész azért szükséges, mert az SQL Server kb. 680 oszlopot képes kezelni a PIVOT-ban,
|
|
-- ezért 3 x 300-as blokkokra bontjuk a PIVOT-ot és csak azokat a blokkokat illesszük be, amelyeket kell
|
|
-- ha ez nem elég akkor további lebontások kellhetnek (4 x 200 stb.) esetleg a felül lévőbe is
|
|
SELECT DISTINCT DENSE_RANK() OVER(ORDER BY QUOTENAME(Idopont)) AS Id, QUOTENAME(Idopont) AS Oszlop
|
|
INTO #Oszlopok
|
|
FROM #adatokTable
|
|
ORDER BY QUOTENAME(Idopont)
|
|
|
|
DECLARE @OszlopNevek1 nvarchar(max), @OszlopNevek2 nvarchar(max), @OszlopNevek3 nvarchar(max)
|
|
|
|
SELECT @OszlopNevek1 = ISNULL(@OszlopNevek1 + ',', '') + Oszlop FROM #Oszlopok WHERE Id BETWEEN 1 AND 300 ORDER BY Id
|
|
SELECT @OszlopNevek2 = ISNULL(@OszlopNevek2 + ',', '') + Oszlop FROM #Oszlopok WHERE Id BETWEEN 301 AND 600 ORDER BY Id
|
|
SELECT @OszlopNevek3 = ISNULL(@OszlopNevek3 + ',', '') + Oszlop FROM #Oszlopok WHERE Id BETWEEN 601 AND 900 ORDER BY Id
|
|
|
|
IF (@oszlopNevek is not null)
|
|
BEGIN
|
|
SET @sql = '
|
|
WITH PivotData AS (
|
|
SELECT a.Idopont, a.Jeloles, COUNT(a.Jeloles) AS db
|
|
FROM #adatokTable a
|
|
WHERE a.Jeloles <> ''''
|
|
GROUP BY a.Idopont, a.Jeloles
|
|
)
|
|
SELECT
|
|
j.Jeloles' + CHAR(13)
|
|
+ ISNULL(',' + @OszlopNevek1 + CHAR(13), '') +
|
|
+ ISNULL(',' + @OszlopNevek2 + CHAR(13), '') +
|
|
+ ISNULL(',' + @OszlopNevek3 + CHAR(13), '') +
|
|
',j.Osszesen, j.Atlag
|
|
FROM (
|
|
SELECT
|
|
Jeloles,
|
|
COUNT(Jeloles) AS Osszesen,
|
|
CAST(1.0 * COUNT(Jeloles) / (SELECT COUNT(Idopont) FROM PivotData) AS numeric(5, 2)) AS Atlag
|
|
FROM PivotData
|
|
GROUP BY Jeloles
|
|
) j'
|
|
|
|
IF @OszlopNevek1 IS NOT NULL
|
|
SET @sql += '
|
|
LEFT JOIN (
|
|
SELECT Jeloles, ' + @OszlopNevek1 + '
|
|
FROM (
|
|
SELECT * FROM PivotData WHERE Idopont IN (' + REPLACE(REPLACE(@OszlopNevek1, '[', ''''), ']', '''') + ')
|
|
) pd
|
|
PIVOT (SUM(Db) FOR Idopont IN (' + @OszlopNevek1 + ')) AS p
|
|
) piv1 ON piv1.Jeloles = j.Jeloles'
|
|
|
|
IF @OszlopNevek2 IS NOT NULL
|
|
SET @sql += '
|
|
LEFT JOIN (
|
|
SELECT Jeloles, ' + @OszlopNevek2 + '
|
|
FROM (
|
|
SELECT * FROM PivotData WHERE Idopont IN (' + REPLACE(REPLACE(@OszlopNevek2, '[', ''''), ']', '''') + ')
|
|
) pd
|
|
PIVOT (SUM(Db) FOR Idopont IN (' + @OszlopNevek2 + ')) AS p
|
|
) piv2 ON piv2.Jeloles = j.Jeloles'
|
|
|
|
IF @OszlopNevek3 IS NOT NULL
|
|
SET @sql += '
|
|
LEFT JOIN (
|
|
SELECT Jeloles, ' + @OszlopNevek3 + '
|
|
FROM (
|
|
SELECT * FROM PivotData WHERE Idopont IN (' + REPLACE(REPLACE(@OszlopNevek3, '[', ''''), ']', '''') + ')
|
|
) pd
|
|
PIVOT (SUM(Db) FOR Idopont IN (' + @OszlopNevek3 + ')) AS p
|
|
) piv3 ON piv3.Jeloles = j.Jeloles'
|
|
|
|
SET @sql += '
|
|
ORDER BY j.Jeloles DESC'
|
|
|
|
END
|
|
ELSE
|
|
BEGIN
|
|
SET @sql = N'
|
|
SELECT
|
|
null AS Jeloles
|
|
,null as Osszesen
|
|
,null as Atlag
|
|
'
|
|
END
|
|
|
|
EXEC sp_executesql @sql
|
|
|
|
END |