init
This commit is contained in:
@@ -0,0 +1,145 @@
|
||||
IF OBJECT_ID('[dbo].[sp_GetHelyettesitesiNaplo]') IS NOT NULL
|
||||
BEGIN
|
||||
DROP PROCEDURE [dbo].[sp_GetHelyettesitesiNaplo]
|
||||
END
|
||||
GO
|
||||
-- ===================================================================
|
||||
-- Author: Tóth Imre Attila
|
||||
-- Create date: 2016. 08. 01.
|
||||
-- Description: Lekérdezések a helyettesítési naplóhoz
|
||||
-- ===================================================================
|
||||
CREATE PROCEDURE [dbo].[sp_GetHelyettesitesiNaplo]
|
||||
@tanarID int,
|
||||
@tanevID int,
|
||||
@intezmenyid int
|
||||
AS
|
||||
BEGIN
|
||||
SET NOCOUNT ON;
|
||||
|
||||
-- ===================================
|
||||
-- FEJLÉC
|
||||
-- ===================================
|
||||
DECLARE @table TABLE (
|
||||
EvHonap nvarchar(10),
|
||||
Helyettesito nvarchar(100)
|
||||
)
|
||||
|
||||
INSERT INTO @table
|
||||
SELECT DISTINCT
|
||||
format(C_DATUM, 'yyyy.MM') AS EvHonap,
|
||||
felhHelyettes.C_NYOMTATASINEV AS Helyettesito
|
||||
FROM T_TANITASIORA_OSSZES tOra
|
||||
LEFT JOIN T_FELHASZNALO_OSSZES felhHelyettes on felhHelyettes.ID = tOra.C_HELYETTESITOTANARID
|
||||
WHERE tOra.C_HELYETTESITOTANARID = @tanarID
|
||||
AND tOra.C_TANEVID = @tanevID
|
||||
AND tOra.Torolt='F'
|
||||
|
||||
SELECT * FROM @table
|
||||
|
||||
SELECT
|
||||
format(C_NAPDATUMA, 'yyyy.MM') AS EvHonap,
|
||||
C_HETNAPJA AS Nap
|
||||
FROM T_NAPTARINAP_OSSZES
|
||||
WHERE format(C_NAPDATUMA, 'yyyy.MM') IN (SELECT EvHonap FROM @table)
|
||||
|
||||
-- ===================================
|
||||
-- HELYETTESÍTÉSEK (SOROK)
|
||||
-- ===================================
|
||||
|
||||
DECLARE @oraSorszam TABLE (Id int, EvesSorszam int)
|
||||
|
||||
INSERT INTO @oraSorszam
|
||||
SELECT DISTINCT
|
||||
s.Id
|
||||
, s.EvesSorszam
|
||||
FROM (
|
||||
SELECT DISTINCT
|
||||
tn.C_TANTARGYID
|
||||
, tn.C_OSZTALYCSOPORTID
|
||||
, ot.C_TANAROKID
|
||||
, tn.C_INTEZMENYID
|
||||
FROM T_TANITASIORA_OSSZES tn
|
||||
INNER JOIN T_ORAK_TANAROK ot ON ot.C_ORAKID = tn.ID
|
||||
WHERE C_HELYETTESITOTANARID = @tanarID
|
||||
AND C_TANEVID = @tanevID
|
||||
) x
|
||||
CROSS APPLY dbo.fnGetEvesOraszamLista (
|
||||
x.C_TANTARGYID
|
||||
,x.C_OSZTALYCSOPORTID
|
||||
,x.C_TANAROKID
|
||||
,GETDATE()
|
||||
,x.C_INTEZMENYID
|
||||
,@tanevID
|
||||
) s
|
||||
|
||||
SELECT DISTINCT
|
||||
ROW_NUMBER() over(PARTITION BY FORMAT(C_DATUM, 'yyyy.MM') ORDER BY C_DATUM) Sorsz
|
||||
,tOra.C_ORASZAM AS Oraszam
|
||||
,DicItemBase.C_NAME AS HelyettesitesTipusa
|
||||
,FORMAT(C_DATUM, 'yyyy.MM.dd.') AS Datum
|
||||
,FORMAT(C_DATUM, 'yyyy.MM') AS EvHonap
|
||||
,felhOraTul.C_NYOMTATASINEV AS Helyettesitett
|
||||
,osztcsop.C_NEV AS OsztalyCsoport
|
||||
,tant.C_NEV AS Tantargy
|
||||
,tOra.C_TEMA AS Tema
|
||||
,s.EvesSorszam AS EvesSorszam
|
||||
FROM T_TANITASIORA_OSSZES tOra
|
||||
LEFT JOIN @oraSorszam s ON s.ID = tOra.ID
|
||||
LEFT JOIN T_ORARENDIORA_OSSZES oo ON oo.ID = tOra.C_ORARENDIORAID
|
||||
LEFT JOIN T_FELHASZNALO_OSSZES felhOraTul ON felhOraTul.ID = oo.C_TANARID
|
||||
LEFT JOIN T_FELHASZNALO_OSSZES helyettesito ON helyettesito.ID = tOra.C_HELYETTESITOTANARID
|
||||
LEFT JOIN (SELECT DISTINCT ID, C_NAME FROM T_DICTIONARYITEMBASE_OSSZES) DicItemBase on DicItemBase.ID = tOra.C_HELYETTESITESTIPUSA
|
||||
LEFT JOIN T_OSZTALYCSOPORT_OSSZES osztcsop ON osztcsop.ID = tOra.C_OSZTALYCSOPORTID
|
||||
LEFT JOIN T_TANTARGY_OSSZES tant ON tant.ID = tOra.C_TANTARGYID
|
||||
WHERE helyettesito.ID = @tanarID
|
||||
AND tOra.C_TANEVID = @tanevID
|
||||
AND TOra.Torolt = 'F'
|
||||
ORDER BY Sorsz ASC
|
||||
|
||||
-- ===================================
|
||||
-- HELYETTESÍTÉSEK NAPIBONTÁSBAN
|
||||
-- ===================================
|
||||
SELECT
|
||||
EvHonap,
|
||||
OsztalyCsoport = TantargyN + ' - ' + OsztCsopN,
|
||||
ISNULL([1], 0) AS [1], ISNULL([2], 0) AS [2], ISNULL([3], 0) AS [3], ISNULL([4], 0) AS [4], ISNULL([5], 0) AS [5], ISNULL([6], 0) AS [6], ISNULL([7], 0) AS [7], ISNULL([8], 0) AS [8], ISNULL([9], 0) AS [9], ISNULL([10], 0) AS [10],
|
||||
ISNULL([11], 0) AS [11], ISNULL([12], 0) AS [12], ISNULL([13], 0) AS [13], ISNULL([14], 0) AS [14], ISNULL([15], 0) AS [15], ISNULL([16], 0) AS [16], ISNULL([17], 0) AS [17], ISNULL([18], 0) AS [18], ISNULL([19], 0) AS [19], ISNULL([20], 0) AS [20],
|
||||
ISNULL([21], 0) AS [21], ISNULL([22], 0) AS [22], ISNULL([23], 0) AS [23], ISNULL([24], 0) AS [24], ISNULL([25], 0) AS [25], ISNULL([26], 0) AS [26], ISNULL([27], 0) AS [27], ISNULL([28], 0) AS [28], ISNULL([29], 0) AS [29], ISNULL([30], 0) AS [30],
|
||||
ISNULL([31], 0) AS [31],
|
||||
ISNULL([1], 0) + ISNULL([2], 0) + ISNULL([3], 0) + ISNULL([4], 0) + ISNULL([5], 0) + ISNULL([6], 0) + ISNULL([7], 0) + ISNULL([8], 0) + ISNULL([9], 0) + ISNULL([10], 0) +
|
||||
ISNULL([11], 0) + ISNULL([12], 0) + ISNULL([13], 0) + ISNULL([14], 0) + ISNULL([15], 0) + ISNULL([16], 0) + ISNULL([17], 0) + ISNULL([18], 0) + ISNULL([19], 0) + ISNULL([20], 0) +
|
||||
ISNULL([21], 0) + ISNULL([22], 0) + ISNULL([23], 0) + ISNULL([24], 0) + ISNULL([25], 0) + ISNULL([26], 0) + ISNULL([27], 0) + ISNULL([28], 0) + ISNULL([29], 0) + ISNULL([30], 0) +
|
||||
ISNULL([31], 0) AS Ossz
|
||||
FROM (
|
||||
SELECT
|
||||
CASE (tOra.c_helyettesitestipusa)
|
||||
WHEN '1496' THEN COUNT(tant.C_NEV)
|
||||
WHEN '1494' THEN COUNT(tant.C_NEV)
|
||||
WHEN '1495' THEN COUNT(tant.C_NEV)
|
||||
END AS Tant,
|
||||
osztCsop.C_NEV AS osztcsopN,
|
||||
tant.C_NEV AS TantargyN,
|
||||
DATEPART(DAY, C_DATUM) AS Nap,
|
||||
FORMAT(C_DATUM, 'yyyy.MM') AS EvHonap
|
||||
FROM T_TANITASIORA_OSSZES tOra
|
||||
INNER JOIN T_TANTARGY_OSSZES tant on tant.ID = tOra.C_TANTARGYID
|
||||
INNER JOIN T_OSZTALYCSOPORT_OSSZES osztCsop on osztCsop.ID = tOra.C_OSZTALYCSOPORTID
|
||||
WHERE
|
||||
tOra.C_HELYETTESITOTANARID = @tanarID
|
||||
AND tOra.C_TANEVID = @tanevID
|
||||
AND TOra.TOROLT='F'
|
||||
GROUP BY
|
||||
osztCsop.C_NEV, tant.C_NEV, C_DATUM, tOra.c_helyettesitestipusa
|
||||
) T
|
||||
PIVOT (
|
||||
max(Tant)
|
||||
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]
|
||||
)
|
||||
) Helyettesitesek
|
||||
|
||||
END
|
||||
|
||||
GO
|
@@ -0,0 +1,379 @@
|
||||
SET ANSI_NULLS ON
|
||||
GO
|
||||
SET QUOTED_IDENTIFIER ON
|
||||
GO
|
||||
|
||||
IF OBJECT_ID('[dbo].[sp_GetMunkaidoElszamoloLap]') IS NOT NULL
|
||||
BEGIN
|
||||
DROP PROCEDURE [dbo].[sp_GetMunkaidoElszamoloLap]
|
||||
END
|
||||
GO
|
||||
|
||||
CREATE PROCEDURE [dbo].[sp_GetMunkaidoElszamoloLap]
|
||||
@tanarid INT,
|
||||
@tanevId INT,
|
||||
@honapId INT,
|
||||
@isKlebersberg BIT
|
||||
AS
|
||||
BEGIN
|
||||
SET NOCOUNT ON;
|
||||
DECLARE @Honap INT = (
|
||||
SELECT DISTINCT
|
||||
dictionaryItemBase.C_VALUE
|
||||
FROM
|
||||
T_DICTIONARYITEMBASE_OSSZES dictionaryItemBase
|
||||
WHERE
|
||||
dictionaryItemBase.ID = @honapId
|
||||
)
|
||||
SELECT TOP 1
|
||||
FORMAT(c_napdatuma, 'yyyy') Ev,
|
||||
FORMAT(c_napdatuma, 'MM') Honap
|
||||
FROM
|
||||
T_NAPTARINAP_OSSZES naptariNap
|
||||
WHERE
|
||||
DATEPART(MONTH,naptariNap.C_NAPDATUMA) = @Honap
|
||||
AND naptariNap.C_TANEVID = @tanevId
|
||||
AND naptariNap.TOROLT = 'F'
|
||||
|
||||
--===================================
|
||||
--FEJLÉC
|
||||
--===================================
|
||||
SELECT
|
||||
f.C_NYOMTATASINEV TanarNev
|
||||
,f.C_OKTATASIAZONOSITO OktatasiAzonosito
|
||||
,munkakor.C_NAME Munkakor
|
||||
,dbo.fnGetDokumentumPedagogusOraszam(f.id, @isKlebersberg) KotelezoOraszam
|
||||
,ISNULL(CONVERT(NVARCHAR(MAX),m.C_MUNKAIDOKEDVEZMENYORASZAM),'-') MunkaidoKedvezmenyOraszam
|
||||
,ISNULL(munkaidoKedvezmenyOka.C_NAME,'-') MunkaidoKedvezmenyOka
|
||||
,ia.C_NEV + ' (' + ia.C_OMKOD +')' IntezmenyNeve
|
||||
,ia.C_IGAZGATONEVE Igazgato
|
||||
FROM T_FELHASZNALO_OSSZES f
|
||||
INNER JOIN T_MUNKAUGYIADATOK_OSSZES m ON m.C_ALKALMAZOTTID = f.Id
|
||||
LEFT JOIN T_DICTIONARYITEMBASE_OSSZES munkakor ON munkakor.Id = m.C_MUNKAKORTIPUSA AND munkakor.C_TANEVID = m.C_TANEVID
|
||||
LEFT JOIN T_DICTIONARYITEMBASE_OSSZES munkaidoKedvezmenyOka ON munkaidoKedvezmenyOka.Id = m.C_MUNKAIDOKEDVEZMENYOKA AND munkaidoKedvezmenyOka.C_TANEVID = m.C_TANEVID
|
||||
INNER JOIN T_INTEZMENYADATOK_OSSZES ia ON ia.C_TANEVID = f.C_TANEVID
|
||||
WHERE
|
||||
f.ID = @tanarId
|
||||
AND ia.TOROLT = 'F'
|
||||
AND m.TOROLT = 'F'
|
||||
|
||||
--===================================
|
||||
--MEGTARTOTT TANÓRÁK, HELYETTESÍTÉSEK
|
||||
--===================================
|
||||
SELECT
|
||||
OsztalyCsoportID
|
||||
,OsztalyCsoportNev
|
||||
,Honap
|
||||
,[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],
|
||||
[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] Ossz
|
||||
FROM
|
||||
(
|
||||
SELECT
|
||||
DATEPART(DAY, T_TANITASIORA_OSSZES.C_DATUM) Nap
|
||||
,DATEPART(Month, T_TANITASIORA_OSSZES.C_DATUM) Honap
|
||||
,T_OSZTALYCSOPORT_OSSZES.ID OsztalyCsoportID
|
||||
,T_OSZTALYCSOPORT_OSSZES.ID ocsId
|
||||
,T_OSZTALYCSOPORT_OSSZES.c_nev OsztalyCsoportNev
|
||||
FROM T_TANITASIORA_OSSZES
|
||||
INNER JOIN T_OSZTALYCSOPORT_OSSZES on T_TANITASIORA_OSSZES.C_OSZTALYCSOPORTID = T_OSZTALYCSOPORT_OSSZES.ID
|
||||
LEFT JOIN T_CSOPORT_OSSZES ON T_CSOPORT_OSSZES.Id = T_OSZTALYCSOPORT_OSSZES.ID
|
||||
WHERE
|
||||
T_TANITASIORA_OSSZES.C_ORATULAJDONOSID = @tanarid
|
||||
AND T_TANITASIORA_OSSZES.C_TANEVID = @tanevId
|
||||
AND DATEPART(MONTH, T_TANITASIORA_OSSZES.C_DATUM) = @Honap
|
||||
AND T_TANITASIORA_OSSZES.TOROLT = 'F'
|
||||
AND T_TANITASIORA_OSSZES.C_MEGTARTOTT = 'T'
|
||||
AND T_TANITASIORA_OSSZES.C_HELYETTESITOTANARID IS NULL
|
||||
AND (T_CSOPORT_OSSZES.Id IS NULL OR T_CSOPORT_OSSZES.C_TIPUSA = 1034)
|
||||
AND (T_TANITASIORA_OSSZES.C_PARHUZAMOSORA = 'F' OR T_TANITASIORA_OSSZES.C_PARHUZAMOSORA IS NULL)
|
||||
)a
|
||||
PIVOT
|
||||
(
|
||||
COUNT(ocsId)
|
||||
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])
|
||||
) OsszTanora
|
||||
|
||||
--szakszerű helyettesítés
|
||||
SELECT
|
||||
OsztalyCsoportID
|
||||
,OsztalyCsoportNev
|
||||
,Honap
|
||||
,[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],
|
||||
[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] Ossz
|
||||
FROM
|
||||
(
|
||||
SELECT
|
||||
DATEPART(DAY, tao.C_DATUM) Nap
|
||||
,DATEPART(MONTH,tao.C_DATUM) Honap
|
||||
,ocs.C_NEV OsztalyCsoportNev
|
||||
,tao.C_OSZTALYCSOPORTID oraid
|
||||
,tao.C_OSZTALYCSOPORTID OsztalyCsoportID
|
||||
FROM T_TANITASIORA_OSSZES tao
|
||||
INNER JOIN T_OSZTALYCSOPORT_OSSZES ocs on ocs.id=tao.C_OSZTALYCSOPORTID
|
||||
WHERE
|
||||
tao.C_HELYETTESITOTANARID = @tanarid
|
||||
AND DATEPART(MONTH, tao.C_DATUM) = @Honap
|
||||
AND tao.TOROLT = 'F'
|
||||
AND tao.C_HELYETTESITESTIPUSA = 1494
|
||||
AND tao.C_TANEVID = @tanevId
|
||||
AND (tao.C_PARHUZAMOSORA = 'F' OR tao.C_PARHUZAMOSORA IS NULL)
|
||||
)a
|
||||
PIVOT
|
||||
(
|
||||
COUNT(oraID)
|
||||
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])
|
||||
|
||||
) SzakszeruHelyettesites
|
||||
|
||||
--nem szakszerű helyettesítés
|
||||
SELECT
|
||||
OsztalyCsoportID
|
||||
,OsztalyCsoportNev
|
||||
,Honap
|
||||
,[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],
|
||||
[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] Ossz
|
||||
FROM
|
||||
(
|
||||
SELECT
|
||||
DATEPART(DAY, tao.C_DATUM) Nap
|
||||
,DATEPART(MONTH,tao.C_DATUM) Honap
|
||||
,ocs.C_NEV OsztalyCsoportNev
|
||||
,tao.C_OSZTALYCSOPORTID oraid
|
||||
,tao.C_OSZTALYCSOPORTID OsztalyCsoportID
|
||||
FROM T_TANITASIORA_OSSZES tao
|
||||
INNER JOIN T_OSZTALYCSOPORT_OSSZES ocs on ocs.id=tao.C_OSZTALYCSOPORTID
|
||||
WHERE
|
||||
tao.C_HELYETTESITOTANARID = @tanarid
|
||||
AND DATEPART(MONTH, tao.C_DATUM) = @Honap
|
||||
AND tao.TOROLT='F'
|
||||
AND tao.C_HELYETTESITESTIPUSA = 1495
|
||||
AND tao.C_TANEVID = @tanevId
|
||||
AND (tao.C_PARHUZAMOSORA = 'F' OR tao.C_PARHUZAMOSORA IS NULL)
|
||||
)a
|
||||
PIVOT
|
||||
(
|
||||
COUNT(oraID)
|
||||
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])
|
||||
|
||||
) NemSzakszeruHelyettesites
|
||||
|
||||
--óraösszevonás
|
||||
SELECT
|
||||
OsztalyCsoportID
|
||||
,OsztalyCsoportNev
|
||||
,Honap
|
||||
,[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],
|
||||
[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] Ossz
|
||||
FROM
|
||||
(
|
||||
SELECT
|
||||
DATEPART(DAY, tao.C_DATUM) Nap
|
||||
,DATEPART(MONTH,tao.C_DATUM) Honap
|
||||
,ocs.C_NEV OsztalyCsoportNev
|
||||
,tao.C_OSZTALYCSOPORTID oraid
|
||||
,tao.C_OSZTALYCSOPORTID OsztalyCsoportID
|
||||
FROM T_TANITASIORA_OSSZES tao
|
||||
INNER JOIN T_OSZTALYCSOPORT_OSSZES ocs on ocs.ID=tao.C_OSZTALYCSOPORTID
|
||||
WHERE tao.C_HELYETTESITOTANARID = @tanarid
|
||||
AND DATEPART(MONTH, tao.C_DATUM) = @Honap
|
||||
AND tao.TOROLT = 'F'
|
||||
AND tao.C_HELYETTESITESTIPUSA = 1496
|
||||
AND tao.C_TANEVID = @tanevId
|
||||
AND (tao.C_PARHUZAMOSORA = 'F' OR tao.C_PARHUZAMOSORA IS NULL)
|
||||
)a
|
||||
PIVOT
|
||||
(
|
||||
COUNT(oraID)
|
||||
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])
|
||||
|
||||
) Oraosszevonas
|
||||
|
||||
--tanóránkívüli
|
||||
SELECT
|
||||
OsztalyCsoportID
|
||||
,OsztalyCsoportNev
|
||||
,Honap
|
||||
,[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],
|
||||
[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] Ossz
|
||||
FROM
|
||||
(
|
||||
SELECT
|
||||
DATEPART(DAY, tao.C_DATUM) Nap
|
||||
,DATEPART(MONTH,tao.C_DATUM) Honap
|
||||
,ocs.C_NEV OsztalyCsoportNev
|
||||
,tao.C_OSZTALYCSOPORTID oraid
|
||||
,tao.C_OSZTALYCSOPORTID OsztalyCsoportID
|
||||
FROM T_TANITASIORA_OSSZES tao
|
||||
INNER JOIN T_OSZTALYCSOPORT_OSSZES ocs on ocs.id=tao.C_OSZTALYCSOPORTID
|
||||
INNER JOIN T_FOGLALKOZAS_OSSZES fog on fog.id=tao.C_FOGLALKOZASID
|
||||
INNER JOIN T_FOGLALKOZASOK_TANAROK ft on ft.C_FOGLALKOZASOKID=fog.ID AND ft.c_tanarokid=@tanarId
|
||||
INNER JOIN T_CSOPORT_OSSZES ON T_CSOPORT_OSSZES.Id = ocs.ID
|
||||
WHERE
|
||||
DATEPART(MONTH, tao.C_DATUM) = @Honap
|
||||
AND tao.TOROLT = 'F'
|
||||
AND tao.C_TANEVID = @tanevId
|
||||
AND T_CSOPORT_OSSZES.C_TIPUSA <> 1034
|
||||
AND (tao.C_PARHUZAMOSORA = 'F' OR tao.C_PARHUZAMOSORA IS NULL)
|
||||
)a
|
||||
PIVOT
|
||||
(
|
||||
COUNT(oraID)
|
||||
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])
|
||||
|
||||
) TanoranKivuli
|
||||
|
||||
--egyéni foglalkozas
|
||||
SELECT
|
||||
OsztalyCsoportID
|
||||
,OsztalyCsoportNev
|
||||
,Honap
|
||||
,[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],
|
||||
[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] Ossz
|
||||
FROM
|
||||
(
|
||||
SELECT
|
||||
DATEPART(DAY, tao.C_DATUM) Nap,
|
||||
DATEPART(MONTH,tao.C_DATUM) Honap,
|
||||
ocs.C_NEV OsztalyCsoportNev,
|
||||
tao.C_OSZTALYCSOPORTID oraid,
|
||||
tao.C_OSZTALYCSOPORTID OsztalyCsoportID
|
||||
FROM T_TANITASIORA_OSSZES tao
|
||||
INNER JOIN T_OSZTALYCSOPORT_OSSZES ocs on ocs.id=tao.C_OSZTALYCSOPORTID
|
||||
INNER JOIN T_FOGLALKOZAS_OSSZES fog on fog.id=tao.C_FOGLALKOZASID AND fog.C_FOGLALKOZASTIPUSA=1371
|
||||
INNER JOIN T_FOGLALKOZASOK_TANAROK ft on ft.C_FOGLALKOZASOKID=fog.ID AND ft.C_TANAROKID=@tanarId
|
||||
WHERE DATEPART(MONTH, tao.C_DATUM) = @Honap
|
||||
AND tao.TOROLT = 'F'
|
||||
AND tao.C_TANEVID = @tanevId
|
||||
AND (tao.C_PARHUZAMOSORA = 'F' OR tao.C_PARHUZAMOSORA IS NULL)
|
||||
)a
|
||||
PIVOT
|
||||
(
|
||||
COUNT(oraID)
|
||||
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])
|
||||
|
||||
) Oraosszevonas
|
||||
|
||||
--============================================
|
||||
--NEVELÉSSEL-OKTATÁSSAL LE NEM KÖTÖTT MUNKAIDŐ
|
||||
--============================================
|
||||
--ÖSSZESEN
|
||||
SELECT
|
||||
Honap
|
||||
,[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],
|
||||
ISNULL([1],0)+ISNULL([2],0)+ISNULL([3],0)+ISNULL([4],0)+ISNULL([5],0)+
|
||||
ISNULL([6],0)+ISNULL([7],0)+ISNULL([8],0)+ISNULL([9],0)+ISNULL([10],0)+
|
||||
ISNULL([11],0)+ISNULL([12],0)+ISNULL([13],0)+ISNULL([14],0)+ISNULL([15],0)+
|
||||
ISNULL([16],0)+ISNULL([17],0)+ISNULL([18],0)+ISNULL([19],0)+ISNULL([20],0)+
|
||||
ISNULL([21],0)+ISNULL([22],0)+ISNULL([23],0)+ISNULL([24],0)+ISNULL([25],0)+
|
||||
ISNULL([26],0)+ISNULL([27],0)+ISNULL([28],0)+ISNULL([29],0)+ISNULL([30],0)+ISNULL([31],0) Ossz
|
||||
FROM
|
||||
(
|
||||
SELECT
|
||||
DATEPART(DAY, C_KEZDETE) Nap
|
||||
,DATEPART(MONTH, C_KEZDETE) Honap
|
||||
,ROUND(DATEPART(HOUR,C_VEGE-C_KEZDETE)+CONVERT(FLOAT,DATEPART(MINUTE,C_VEGE-C_KEZDETE))/60,1) Oraszam
|
||||
FROM T_NEMKOTOTTMUNKAIDO_OSSZES
|
||||
WHERE
|
||||
C_MEGTARTOTT = 'T'
|
||||
AND C_TANARID = @tanarId
|
||||
AND TOROLT = 'F'
|
||||
AND DATEPART(MONTH, C_KEZDETE) = @Honap
|
||||
AND DATEPART(MONTH, C_VEGE) = @Honap
|
||||
) Orak
|
||||
PIVOT
|
||||
(
|
||||
SUM(Oraszam)
|
||||
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])
|
||||
) Tevekenyseg
|
||||
|
||||
--a hónapban előforduló típusok
|
||||
SELECT DISTINCT
|
||||
C_TEVEKENYSEGTIPUSA TipusId
|
||||
,d.C_NAME Tipus
|
||||
FROM T_NEMKOTOTTMUNKAIDO_OSSZES
|
||||
INNER JOIN (SELECT DISTINCT ID, C_NAME FROM T_DICTIONARYITEMBASE) d on d.ID=C_TEVEKENYSEGTIPUSA
|
||||
WHERE
|
||||
C_MEGTARTOTT = 'T'
|
||||
AND C_TANARID = @tanarId
|
||||
AND TOROLT = 'F'
|
||||
AND DATEPART(MONTH, C_KEZDETE) = @Honap
|
||||
AND DATEPART(MONTH, C_VEGE) = @Honap
|
||||
|
||||
--sorokra (tipusokra) lebontva
|
||||
SELECT
|
||||
Honap
|
||||
,Tipus TipusId
|
||||
,[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],
|
||||
ISNULL([1],0)+ISNULL([2],0)+ISNULL([3],0)+ISNULL([4],0)+ISNULL([5],0)+
|
||||
ISNULL([6],0)+ISNULL([7],0)+ISNULL([8],0)+ISNULL([9],0)+ISNULL([10],0)+
|
||||
ISNULL([11],0)+ISNULL([12],0)+ISNULL([13],0)+ISNULL([14],0)+ISNULL([15],0)+
|
||||
ISNULL([16],0)+ISNULL([17],0)+ISNULL([18],0)+ISNULL([19],0)+ISNULL([20],0)+
|
||||
ISNULL([21],0)+ISNULL([22],0)+ISNULL([23],0)+ISNULL([24],0)+ISNULL([25],0)+
|
||||
ISNULL([26],0)+ISNULL([27],0)+ISNULL([28],0)+ISNULL([29],0)+ISNULL([30],0)+ISNULL([31],0) Ossz
|
||||
FROM
|
||||
(
|
||||
SELECT
|
||||
C_TEVEKENYSEGTIPUSA Tipus
|
||||
,DATEPART(DAY, C_KEZDETE) Nap
|
||||
,DATEPART(MONTH, C_KEZDETE) Honap
|
||||
,ROUND(DATEPART(hour,C_VEGE-C_KEZDETE)+CONVERT(FLOAT,DATEPART(MINUTE,C_VEGE-C_KEZDETE))/60,1) Oraszam
|
||||
FROM T_NEMKOTOTTMUNKAIDO_OSSZES
|
||||
WHERE
|
||||
C_MEGTARTOTT='T'
|
||||
AND C_TANARID = @tanarId
|
||||
AND TOROLT = 'F'
|
||||
AND DATEPART(MONTH, C_KEZDETE) = @Honap
|
||||
AND DATEPART(MONTH, C_VEGE) = @Honap
|
||||
) Orak
|
||||
PIVOT
|
||||
(
|
||||
SUM(Oraszam)
|
||||
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])
|
||||
) Soronkent
|
||||
END
|
||||
|
||||
GO
|
@@ -0,0 +1,49 @@
|
||||
SET ANSI_NULLS ON
|
||||
GO
|
||||
SET QUOTED_IDENTIFIER ON
|
||||
GO
|
||||
|
||||
IF OBJECT_ID('[dbo].[sp_GetOsztalyTanuloinakHaviMulasztasaiOsszesitoje]') IS NOT NULL
|
||||
BEGIN
|
||||
DROP PROCEDURE [dbo].[sp_GetOsztalyTanuloinakHaviMulasztasaiOsszesitoje]
|
||||
END
|
||||
GO
|
||||
|
||||
CREATE PROCEDURE [dbo].[sp_GetOsztalyTanuloinakHaviMulasztasaiOsszesitoje]
|
||||
@pTanevId INT,
|
||||
@pIntezmenyId INT,
|
||||
@pOsztalyId INT,
|
||||
@pElmeletgyakorlat BIT = 0
|
||||
AS
|
||||
BEGIN
|
||||
DECLARE @honapok TABLE(honap INT, honapnev NVARCHAR(max));
|
||||
INSERT INTO @honapok
|
||||
SELECT DISTINCT (3 + d.c_value) % 12 + 1 AS c_value, d.c_name as Honap
|
||||
FROM T_DICTIONARYITEMBASE_OSSZES d
|
||||
WHERE c_type LIKE 'honap%'
|
||||
ORDER BY c_value;
|
||||
|
||||
SELECT honapnev FROM @honapok;
|
||||
|
||||
DECLARE honap_cursor CURSOR FOR
|
||||
SELECT DISTINCT (3 + d.c_value) % 12 + 1 AS honap_sorrend, d.c_value AS honap
|
||||
FROM T_DICTIONARYITEMBASE_OSSZES d
|
||||
WHERE c_type LIKE 'honap%'
|
||||
ORDER BY honap_sorrend;
|
||||
|
||||
DECLARE @honap_sorrend INT, @honap INT;
|
||||
OPEN honap_cursor
|
||||
FETCH NEXT FROM honap_cursor
|
||||
INTO @honap_sorrend, @honap;
|
||||
|
||||
WHILE @@FETCH_STATUS = 0
|
||||
BEGIN
|
||||
EXEC [sp_GetOsztalyTanuloinakHaviMulasztasaiOsszesitoje_honapra] @pTanevId, @pIntezmenyId, @pOsztalyId, @honap, @pElmeletgyakorlat
|
||||
FETCH NEXT FROM honap_cursor
|
||||
INTO @honap_sorrend, @honap
|
||||
END
|
||||
CLOSE honap_cursor
|
||||
DEALLOCATE honap_cursor
|
||||
END
|
||||
|
||||
GO
|
@@ -0,0 +1,156 @@
|
||||
SET ANSI_NULLS ON
|
||||
GO
|
||||
SET QUOTED_IDENTIFIER ON
|
||||
GO
|
||||
|
||||
IF OBJECT_ID('[dbo].[sp_GetOsztalyTanuloinakHaviMulasztasaiOsszesitoje_honapra]') IS NOT NULL
|
||||
BEGIN
|
||||
DROP PROCEDURE [dbo].[sp_GetOsztalyTanuloinakHaviMulasztasaiOsszesitoje_honapra]
|
||||
END
|
||||
GO
|
||||
|
||||
CREATE PROCEDURE [dbo].[sp_GetOsztalyTanuloinakHaviMulasztasaiOsszesitoje_honapra]
|
||||
@pTanevId INT,
|
||||
@pIntezmenyId INT,
|
||||
@pOsztalyId INT,
|
||||
@pHonap INT,
|
||||
@pElmeletgyakorlat BIT = 0
|
||||
AS
|
||||
BEGIN
|
||||
|
||||
--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))
|
||||
INSERT INTO #igazolas
|
||||
SELECT tm.c_oratanuloiid AS Tanulo, tm.c_igazolt AS IgazoltE, tm.c_igazolastipusa AS IgazolasTipus, IIF(@pElmeletgyakorlat=0, 'F', C_GYAKORLATI) AS Gyakorlati
|
||||
FROM T_TANULOMULASZTAS_OSSZES AS tm
|
||||
INNER JOIN T_TANITASIORA_OSSZES tao ON tao.id=tm.c_tanitasiorakid
|
||||
INNER JOIN T_TANTARGY_OSSZES ON T_TANTARGY_OSSZES.ID = tao.C_TANTARGYID AND T_TANTARGY_OSSZES.C_TANEVID = tao.C_TANEVID
|
||||
WHERE tao.c_intezmenyid=@pIntezmenyId AND tm.c_intezmenyid=@pIntezmenyId AND tm.c_tanevid=@pTanevId AND tao.c_tanevid=@pTanevId AND tm.torolt='F' AND tao.torolt='F' AND (CAST(MONTH(tao.c_datum) AS VARCHAR))=@pHonap;
|
||||
|
||||
--Mulasztások
|
||||
CREATE TABLE #mulasztas (Nap NVARCHAR(5), Tanulo INT, Osztaly INT)
|
||||
INSERT INTO #mulasztas
|
||||
SELECT CAST(CAST(DAY(tao.c_datum) AS INT) AS NVARCHAR) + (IIF(@pElmeletgyakorlat=0, '', IIF(C_GYAKORLATI = 'T', '_GY', '_E'))) AS Nap, tm.c_oratanuloiid AS Tanulo, tao.c_osztalycsoportid AS Osztaly
|
||||
FROM T_TANULOMULASZTAS_OSSZES tm
|
||||
INNER JOIN T_TANITASIORA_OSSZES tao ON tao.id=tm.c_tanitasiorakid
|
||||
INNER JOIN T_TANTARGY_OSSZES ON T_TANTARGY_OSSZES.ID = tao.C_TANTARGYID AND T_TANTARGY_OSSZES.C_TANEVID = tao.C_TANEVID
|
||||
WHERE tm.c_intezmenyid=@pIntezmenyId AND tm.c_tanevid=@pTanevId AND tao.c_tanevid=@pTanevId AND tao.c_intezmenyid=@pIntezmenyId AND tm.torolt='F' AND tao.torolt='F' AND (CAST(MONTH(tao.c_datum) AS VARCHAR))=@pHonap;
|
||||
|
||||
DECLARE @query AS NVARCHAR(MAX);
|
||||
IF @pElmeletgyakorlat=0
|
||||
BEGIN
|
||||
DECLARE @colsHeader AS NVARCHAR(MAX);
|
||||
DECLARE @cols AS NVARCHAR(MAX);
|
||||
SELECT @colsHeader = ISNULL(@colsHeader + ', ', '') + QUOTENAME(Id) + ' AS ' + QUOTENAME(Nev),
|
||||
@cols = ISNULL(@cols + ', ', '') + QUOTENAME(Id)
|
||||
FROM #igazolastipus AS Igazolastipus
|
||||
ORDER BY Sorrend, Nev;
|
||||
SET @query =
|
||||
'SELECT f.c_nyomtatasinev AS COLUMN108,
|
||||
IIF(m.[1]=0, NULL, m.[1]) AS [1], IIF(m.[2]=0, NULL, m.[2]) AS [2], IIF(m.[3]=0, NULL, m.[3]) AS [3], IIF(m.[4]=0, NULL, m.[4]) AS [4], IIF(m.[5]=0, NULL, m.[5]) AS [5], IIF(m.[6]=0, NULL, m.[6]) AS [6], IIF(m.[7]=0, NULL, m.[7]) AS [7],
|
||||
IIF(m.[8]=0, NULL, m.[8]) AS [8], IIF(m.[9]=0, NULL, m.[9]) AS [9], IIF(m.[10]=0, NULL, m.[10]) AS [10], IIF(m.[11]=0, NULL, m.[11]) AS [11], IIF(m.[12]=0, NULL, m.[12]) AS [12], IIF(m.[13]=0, NULL, m.[13]) AS [13], IIF(m.[14]=0, NULL, m.[14]) AS [14],
|
||||
IIF(m.[15]=0, NULL, m.[15]) AS [15], IIF(m.[16]=0, NULL, m.[16]) AS [16], IIF(m.[17]=0, NULL, m.[17]) AS [17], IIF(m.[18]=0, NULL, m.[18]) AS [18], IIF(m.[19]=0, NULL, m.[19]) AS [19], IIF(m.[20]=0, NULL, m.[20]) AS [20], IIF(m.[21]=0, NULL, m.[21]) AS [21],
|
||||
IIF(m.[22]=0, NULL, m.[22]) AS [22], IIF(m.[23]=0, NULL, m.[23]) AS [23], IIF(m.[24]=0, NULL, m.[24]) AS [24], IIF(m.[25]=0, NULL, m.[25]) AS [25], IIF(m.[26]=0, NULL, m.[26]) AS [26], IIF(m.[27]=0, NULL, m.[27]) AS [27], IIF(m.[28]=0, NULL, m.[28]) AS [28],
|
||||
IIF(m.[29]=0, NULL, m.[29]) AS [29], IIF(m.[30]=0, NULL, m.[30]) AS [30], IIF(m.[31]=0, NULL, m.[31]) AS [31],
|
||||
OSSZES.MULASZTASOKSZAMA AS COLUMN2672, IGAZOLT.IGAZOLTSZAMA AS COLUMN2568, ' + @colsHeader + ', IGAZOLATLAN.IGAZOLATLANSZAMA AS COLUMN1911
|
||||
FROM #tanulo AS tanulok
|
||||
LEFT JOIN (
|
||||
SELECT *
|
||||
FROM #igazolas AS igazolasok
|
||||
PIVOT ( COUNT(IgazoltE) FOR IgazolasTipus IN (' + @cols + ')) AS PIVOTTABLE
|
||||
) AS IGAZOLASTIPUSOKSZERINT ON IGAZOLASTIPUSOKSZERINT.Tanulo = tanulok.Id
|
||||
LEFT JOIN (
|
||||
SELECT *
|
||||
FROM #mulasztas AS m
|
||||
PIVOT (COUNT(Osztaly) 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
|
||||
) m ON m.Tanulo = tanulok.id
|
||||
LEFT JOIN (SELECT Tanulo, COUNT(Tanulo) AS MULASZTASOKSZAMA FROM #igazolas GROUP BY Tanulo) AS OSSZES ON OSSZES.Tanulo = tanulok.Id
|
||||
LEFT JOIN (SELECT Tanulo, COUNT(Tanulo) AS IGAZOLTSZAMA FROM #igazolas i WHERE i.IgazoltE=''T'' GROUP BY Tanulo) AS IGAZOLT ON IGAZOLT.Tanulo = tanulok.Id
|
||||
LEFT JOIN (SELECT Tanulo, COUNT(Tanulo) AS IGAZOLATLANSZAMA FROM #igazolas i WHERE i.IgazoltE=''F'' GROUP BY Tanulo) AS IGAZOLATLAN ON IGAZOLATLAN.Tanulo = tanulok.Id
|
||||
INNER JOIN T_FELHASZNALO_OSSZES f ON f.id = tanulok.Id
|
||||
ORDER BY f.c_nyomtatasinev';
|
||||
execute(@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);
|
||||
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)
|
||||
FROM #igazolastipus AS Igazolastipus
|
||||
ORDER BY Sorrend, Nev;
|
||||
|
||||
SET @query =
|
||||
'SELECT f.c_nyomtatasinev AS COLUMN108,
|
||||
IIF(m.[1_E]=0, NULL, m.[1_E]) AS [1 E], IIF(m.[1_GY]=0, NULL, m.[1_GY]) AS [1 GY], IIF(m.[2_E]=0, NULL, m.[2_E]) AS [2 E], IIF(m.[2_GY]=0, NULL, m.[2_GY]) AS [2 GY], IIF(m.[3_E]=0, NULL, m.[3_E]) AS [3 E], IIF(m.[3_GY]=0, NULL, m.[3_GY]) AS [3 GY],
|
||||
IIF(m.[4_E]=0, NULL, m.[4_E]) AS [4 E], IIF(m.[4_GY]=0, NULL, m.[4_GY]) AS [4 GY], IIF(m.[5_E]=0, NULL, m.[5_E]) AS [5 E], IIF(m.[5_GY]=0, NULL, m.[5_GY]) AS [5 GY], IIF(m.[6_E]=0, NULL, m.[6_E]) AS [6 E], IIF(m.[6_GY]=0, NULL, m.[6_GY]) AS [6 GY],
|
||||
IIF(m.[7_E]=0, NULL, m.[7_E]) AS [7 E], IIF(m.[7_GY]=0, NULL, m.[7_GY]) AS [7 GY], IIF(m.[8_E]=0, NULL, m.[8_E]) AS [8 E], IIF(m.[8_GY]=0, NULL, m.[8_GY]) AS [8 GY], IIF(m.[9_E]=0, NULL, m.[9_E]) AS [9 E], IIF(m.[9_GY]=0, NULL, m.[9_GY]) AS [9 GY],
|
||||
IIF(m.[10_E]=0, NULL, m.[10_E]) AS [10 E], IIF(m.[10_GY]=0, NULL, m.[10_GY]) AS [10 GY], IIF(m.[11_E]=0, NULL, m.[11_E]) AS [11 E], IIF(m.[11_GY]=0, NULL, m.[11_GY]) AS [11 GY], IIF(m.[12_E]=0, NULL, m.[12_E]) AS [12 E], IIF(m.[12_GY]=0, NULL, m.[12_GY]) AS [12 GY],
|
||||
IIF(m.[13_E]=0, NULL, m.[13_E]) AS [13 E], IIF(m.[13_GY]=0, NULL, m.[13_GY]) AS [13 GY], IIF(m.[14_E]=0, NULL, m.[14_E]) AS [14 E], IIF(m.[14_GY]=0, NULL, m.[14_GY]) AS [14 GY], IIF(m.[15_E]=0, NULL, m.[15_E]) AS [15 E], IIF(m.[15_GY]=0, NULL, m.[15_GY]) AS [15 GY],
|
||||
IIF(m.[16_E]=0, NULL, m.[16_E]) AS [16 E], IIF(m.[16_GY]=0, NULL, m.[16_GY]) AS [16 GY], IIF(m.[17_E]=0, NULL, m.[17_E]) AS [17 E], IIF(m.[17_GY]=0, NULL, m.[17_GY]) AS [17 GY], IIF(m.[18_E]=0, NULL, m.[18_E]) AS [18 E], IIF(m.[18_GY]=0, NULL, m.[18_GY]) AS [18 GY],
|
||||
IIF(m.[19_E]=0, NULL, m.[19_E]) AS [19 E], IIF(m.[19_GY]=0, NULL, m.[19_GY]) AS [19 GY], IIF(m.[20_E]=0, NULL, m.[20_E]) AS [20 E], IIF(m.[20_GY]=0, NULL, m.[20_GY]) AS [20 GY], IIF(m.[21_E]=0, NULL, m.[21_E]) AS [21 E], IIF(m.[21_GY]=0, NULL, m.[21_GY]) AS [21 GY],
|
||||
IIF(m.[22_E]=0, NULL, m.[22_E]) AS [22 E], IIF(m.[22_GY]=0, NULL, m.[22_GY]) AS [22 GY], IIF(m.[23_E]=0, NULL, m.[23_E]) AS [23 E], IIF(m.[23_GY]=0, NULL, m.[23_GY]) AS [23 GY], IIF(m.[24_E]=0, NULL, m.[24_E]) AS [24 E], IIF(m.[24_GY]=0, NULL, m.[24_GY]) AS [24 GY],
|
||||
IIF(m.[25_E]=0, NULL, m.[25_E]) AS [25 E], IIF(m.[25_GY]=0, NULL, m.[25_GY]) AS [25 GY], IIF(m.[26_E]=0, NULL, m.[26_E]) AS [26 E], IIF(m.[26_GY]=0, NULL, m.[26_GY]) AS [26 GY], IIF(m.[27_E]=0, NULL, m.[27_E]) AS [27 E], IIF(m.[27_GY]=0, NULL, m.[27_GY]) AS [27 GY],
|
||||
IIF(m.[28_E]=0, NULL, m.[28_E]) AS [28 E], IIF(m.[28_GY]=0, NULL, m.[28_GY]) AS [28 GY], IIF(m.[29_E]=0, NULL, m.[29_E]) AS [29 E], IIF(m.[29_GY]=0, NULL, m.[29_GY]) AS [29 GY], IIF(m.[30_E]=0, NULL, m.[30_E]) AS [30 E], IIF(m.[30_GY]=0, NULL, m.[30_GY]) AS [30 GY],
|
||||
IIF(m.[31_E]=0, NULL, m.[31_E]) AS [31 E], IIF(m.[31_GY]=0, NULL, m.[31_GY]) AS [31 GY],
|
||||
OSSZES_E.MULASZTASOKSZAMA AS COLUMN2672_E, IGAZOLT_E.IGAZOLTSZAMA AS COLUMN2568_E, ' + @colsHeader_E + ', IGAZOLATLAN_E.IGAZOLATLANSZAMA AS COLUMN1911_E,
|
||||
OSSZES_GY.MULASZTASOKSZAMA AS COLUMN2672_GY, IGAZOLT_GY.IGAZOLTSZAMA AS COLUMN2568_GY, ' + @colsHeader_GY + ', IGAZOLATLAN_GY.IGAZOLATLANSZAMA AS COLUMN1911_GY
|
||||
FROM #tanulo AS tanulok
|
||||
LEFT JOIN (
|
||||
SELECT * FROM (
|
||||
SELECT *
|
||||
FROM #igazolas AS igazolasok
|
||||
WHERE Gyakorlati = ''F'' OR Gyakorlati IS NULL
|
||||
) AS igazolasok
|
||||
PIVOT ( COUNT(IgazoltE) FOR IgazolasTipus IN (' + @cols_E + ')) AS PIVOTTABLE_E
|
||||
) AS IGAZOLASTIPUSOKSZERINT_E ON IGAZOLASTIPUSOKSZERINT_E.Tanulo = tanulok.Id
|
||||
LEFT JOIN (
|
||||
SELECT * FROM (
|
||||
SELECT Tanulo, IgazoltE, -IgazolasTipus AS IgazolasTipus, Gyakorlati
|
||||
FROM #igazolas AS igazolasok
|
||||
WHERE Gyakorlati = ''T''
|
||||
) AS igazolasok
|
||||
PIVOT ( COUNT(IgazoltE) FOR IgazolasTipus IN (' + @cols_GY + ')) AS PIVOTTABLE_GY
|
||||
) AS IGAZOLASTIPUSOKSZERINT_GY ON IGAZOLASTIPUSOKSZERINT_GY.Tanulo = tanulok.Id
|
||||
LEFT JOIN (
|
||||
SELECT * FROM #mulasztas AS m
|
||||
PIVOT (COUNT(Osztaly) 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) m ON m.Tanulo = tanulok.id
|
||||
LEFT JOIN (SELECT Tanulo, COUNT(Tanulo) 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, COUNT(Tanulo) 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, COUNT(Tanulo) 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, COUNT(Tanulo) AS MULASZTASOKSZAMA FROM #igazolas WHERE Gyakorlati = ''T'' GROUP BY Tanulo) AS OSSZES_GY ON OSSZES_GY.Tanulo = tanulok.Id
|
||||
LEFT JOIN (SELECT Tanulo, COUNT(Tanulo) 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, COUNT(Tanulo) AS IGAZOLATLANSZAMA FROM #igazolas i WHERE Gyakorlati = ''T'' AND i.IgazoltE=''F'' GROUP BY Tanulo) AS IGAZOLATLAN_GY ON IGAZOLATLAN_GY.Tanulo = tanulok.Id
|
||||
INNER JOIN T_FELHASZNALO_OSSZES f ON f.id = tanulok.Id
|
||||
ORDER BY f.c_nyomtatasinev';
|
||||
execute(@query);
|
||||
END
|
||||
DROP TABLE #mulasztas
|
||||
DROP TABLE #tanulo
|
||||
DROP TABLE #igazolas
|
||||
DROP TABLE #igazolastipus
|
||||
END
|
||||
|
||||
GO
|
Reference in New Issue
Block a user