init
This commit is contained in:
@@ -0,0 +1,245 @@
|
||||
SET ANSI_NULLS ON
|
||||
GO
|
||||
SET QUOTED_IDENTIFIER ON
|
||||
GO
|
||||
|
||||
IF OBJECT_ID('[dbo].[sp_GenerateErtekelesekTempTabla]') IS NOT NULL
|
||||
BEGIN
|
||||
DROP PROCEDURE [dbo].[sp_GenerateErtekelesekTempTabla]
|
||||
END
|
||||
GO
|
||||
|
||||
-- =============================================
|
||||
-- Description: <El<45>szedi az <20>rt<72>kel<65>seket, havi bont<6E>sban tant<6E>rgy <20>s oszt<7A>lycsoport alapj<70>n>
|
||||
-- NOTE: EZT A H<>ROM T<>ROLT ELJ<4C>R<EFBFBD>ST EGYBEN KELL KEZELNI, HA M<>DOS<4F>TJUK!!!
|
||||
-- - sp_GenerateErtekelesekTempTabla
|
||||
-- - sp_GenerateErtekelesekMagatartasSzorgalomTempTabla
|
||||
-- - sp_GenerateErtekelesekTempTablaByTanulo
|
||||
-- =============================================
|
||||
|
||||
CREATE PROCEDURE [dbo].[sp_GenerateErtekelesekTempTabla]
|
||||
-- Add the parameters for the stored procedure here
|
||||
@pTantargyId INT,
|
||||
@pOsztalyId INT,
|
||||
@pFelevVege DATE,
|
||||
@pEvkozi INT,
|
||||
@pFelevi INT,
|
||||
@pEvvegi INT,
|
||||
@pErtekelesDatum DATE = NULL
|
||||
AS
|
||||
BEGIN
|
||||
|
||||
-- SET NOCOUNT ON added to prevent extra result sets from
|
||||
-- interfering with SELECT statements.
|
||||
SET NOCOUNT ON;
|
||||
|
||||
IF @pErtekelesDatum IS NULL
|
||||
SET @pErtekelesDatum = GETDATE()
|
||||
|
||||
DECLARE @TempErtekeles TABLE (
|
||||
ID INT,
|
||||
ErtekelesDatuma NVARCHAR(255),
|
||||
ErtekelesTipusa INT,
|
||||
ErtekelesSzoveg NVARCHAR(MAX),
|
||||
SzovegRovidNev NVARCHAR(3),
|
||||
Honap NVARCHAR(2),
|
||||
TanuloId INT,
|
||||
Nev NVARCHAR(255),
|
||||
Osztalyzat INT,
|
||||
Szazalek INT,
|
||||
Suly INT
|
||||
)
|
||||
|
||||
INSERT INTO @TempErtekeles
|
||||
SELECT DISTINCT *
|
||||
FROM (
|
||||
SELECT
|
||||
tanuloErtekeles.ID ID,
|
||||
tanuloErtekeles.C_ERTEKELESDATUM ErtekelesDatuma,
|
||||
tanuloErtekeles.C_ERTEKELESTIPUSA ErtekelesTipusa,
|
||||
tanuloErtekeles.C_ERTEKELESSZOVEG ErtekelesSzoveg,
|
||||
tanuloErtekeles.C_SZOVEGROVIDNEV SzovegRovidNev,
|
||||
CASE WHEN tanuloErtekeles.C_ERTEKELESTIPUSA = @pFelevi
|
||||
THEN 'I'
|
||||
WHEN tanuloErtekeles.C_ERTEKELESTIPUSA = @pEvvegi
|
||||
THEN 'II'
|
||||
ELSE
|
||||
CASE
|
||||
WHEN CAST(tanuloErtekeles.C_ERTEKELESDATUM AS DATE) > @pFelevVege
|
||||
THEN CAST(MONTH(tanuloErtekeles.C_ERTEKELESDATUM) + 1 AS NVARCHAR(2))
|
||||
ELSE CAST(MONTH(tanuloErtekeles.C_ERTEKELESDATUM) AS NVARCHAR(2))
|
||||
END
|
||||
END Honap,
|
||||
tanuloCsoport.C_TANULOID TanuloId,
|
||||
felhasznalo.C_NYOMTATASINEV Nev,
|
||||
osztalyzat.C_VALUE Osztalyzat,
|
||||
osztalyzatErtekeles.C_SZAZALEK Szazalek,
|
||||
tanariAtlagSuly.C_SULY Suly
|
||||
FROM (
|
||||
SELECT
|
||||
[C_TANULOID]
|
||||
FROM
|
||||
[T_TANULOCSOPORT]
|
||||
WHERE
|
||||
[TOROLT] = 'F' AND
|
||||
[C_BELEPESDATUM] <= @pErtekelesDatum AND
|
||||
([C_KILEPESDATUM] IS NULL OR [C_KILEPESDATUM] >= @pErtekelesDatum) AND
|
||||
[C_OSZTALYCSOPORTID] = @pOsztalyId
|
||||
) AS tanuloCsoport
|
||||
INNER JOIN (
|
||||
SELECT
|
||||
[ID],
|
||||
[C_NYOMTATASINEV]
|
||||
FROM
|
||||
[T_FELHASZNALO]
|
||||
WHERE
|
||||
[TOROLT] = 'F'
|
||||
) AS felhasznalo
|
||||
ON felhasznalo.ID = tanuloCsoport.C_TANULOID
|
||||
LEFT JOIN (
|
||||
SELECT
|
||||
[ID],
|
||||
[C_ERTEKELESDATUM],
|
||||
[C_ERTEKELESTIPUSA],
|
||||
[C_OSZTALYZAT],
|
||||
[C_ERTEKELESSZOVEG],
|
||||
[C_SZOVEGROVIDNEV],
|
||||
[C_TANULOID]
|
||||
FROM
|
||||
[T_TANULOERTEKELES]
|
||||
WHERE
|
||||
[TOROLT] = 'F' AND
|
||||
[C_TANTARGYID] = @pTantargyId
|
||||
) AS tanuloErtekeles
|
||||
ON tanuloErtekeles.C_TANULOID = tanuloCsoport.C_TANULOID
|
||||
LEFT JOIN (
|
||||
SELECT
|
||||
[ID],
|
||||
[C_SZAZALEK],
|
||||
[C_ERTEKELESMODJA]
|
||||
FROM
|
||||
[T_OSZTALYZATERTEKELES]
|
||||
WHERE
|
||||
[TOROLT] = 'F'
|
||||
) AS osztalyzatErtekeles
|
||||
ON osztalyzatErtekeles.ID = tanuloErtekeles.ID
|
||||
LEFT JOIN (
|
||||
SELECT
|
||||
[ID],
|
||||
[C_VALUE]
|
||||
FROM
|
||||
[T_DICTIONARYITEMBASE]
|
||||
WHERE
|
||||
[TOROLT] = 'F'
|
||||
) AS osztalyzat
|
||||
ON osztalyzat.ID = tanuloErtekeles.C_OSZTALYZAT
|
||||
LEFT JOIN T_TANARIATLAGSULY tanariAtlagSuly
|
||||
ON tanariAtlagSuly.C_ERTEKELESMODJA = osztalyzatErtekeles.C_ERTEKELESMODJA AND
|
||||
tanuloErtekeles.C_OSZTALYZAT IS NOT NULL AND
|
||||
tanariAtlagSuly.TOROLT = 'F'
|
||||
) AS temp
|
||||
|
||||
SELECT
|
||||
result.*
|
||||
,result2.ErtkelesMentesseg
|
||||
,result2.SzovegesenErtekelheto
|
||||
FROM (
|
||||
SELECT
|
||||
pivotErtekelesek.TanuloId ID,
|
||||
Nev Nev,
|
||||
[9] [09],
|
||||
[10] [10],
|
||||
[11] [11],
|
||||
[12] [12],
|
||||
[1] [01I],
|
||||
[2] [01II],
|
||||
[3] [02],
|
||||
[4] [03],
|
||||
[5] [04],
|
||||
[6] [05],
|
||||
[7] [06],
|
||||
[I] [I],
|
||||
[II] [II],
|
||||
atlag.Jegy Atlag,
|
||||
'' Ertekeles,
|
||||
'' ErtekelesSzoveg,
|
||||
'' SzovegRovidNev,
|
||||
'' Szazalekos,
|
||||
@pTantargyId TantargyId
|
||||
FROM (
|
||||
SELECT DISTINCT
|
||||
tempErtekeles1.Nev,
|
||||
STUFF (
|
||||
(SELECT
|
||||
',' +
|
||||
ISNULL(CAST(tempErtekeles2.Osztalyzat AS VARCHAR(1)), '') +
|
||||
ISNULL(CAST(tempErtekeles2.Szazalek AS VARCHAR(2)), '') +
|
||||
ISNULL(CAST(
|
||||
CASE
|
||||
WHEN tempErtekeles2.ErtekelesSzoveg IS NULL OR LTRIM(RTRIM(REPLACE(REPLACE(REPLACE(tempErtekeles2.ErtekelesSzoveg, CHAR(9), ''), CHAR(10), ''), CHAR(13), ''))) = ''
|
||||
THEN NULL
|
||||
ELSE
|
||||
ISNULL(tempErtekeles2.SzovegRovidNev, 'sz')
|
||||
END AS VARCHAR(2)), '')
|
||||
FROM
|
||||
@TempErtekeles tempErtekeles2
|
||||
WHERE
|
||||
tempErtekeles1.TanuloId = tempErtekeles2.TanuloId AND
|
||||
tempErtekeles1.Honap = tempErtekeles2.Honap
|
||||
FOR XML PATH ('')
|
||||
), 1, 1, ''
|
||||
) Ertekelesek,
|
||||
tempErtekeles1.Honap,
|
||||
tempErtekeles1.TanuloId
|
||||
FROM
|
||||
@TempErtekeles tempErtekeles1
|
||||
) AS erdemjegyek
|
||||
PIVOT (
|
||||
MAX(Ertekelesek)
|
||||
FOR Honap
|
||||
IN ([I], [II], [9] ,[10] ,[11] ,[12] ,[1] ,[2] ,[3] ,[4] ,[5] ,[6], [7])
|
||||
) AS pivotErtekelesek
|
||||
LEFT JOIN (
|
||||
SELECT
|
||||
TanuloId TanuloId,
|
||||
ROUND(
|
||||
SUM(CAST(Osztalyzat AS FLOAT) * CAST(ISNULL(Suly, 100) AS FLOAT) / 100) / SUM(CAST(ISNULL(Suly, 100) AS FLOAT) / 100)
|
||||
, 2) Jegy
|
||||
FROM
|
||||
@TempErtekeles
|
||||
WHERE
|
||||
ErtekelesTipusa = @pEvkozi AND
|
||||
Osztalyzat IS NOT NULL
|
||||
GROUP BY
|
||||
TanuloId
|
||||
) AS atlag
|
||||
ON pivotErtekelesek.TanuloId = atlag.TanuloId
|
||||
) AS result
|
||||
JOIN (
|
||||
SELECT DISTINCT
|
||||
felhasznalo.ID ID,
|
||||
tanuloMentesseg.C_ERTEKELESMENTESITES ErtkelesMentesseg,
|
||||
tanuloMentesseg.C_SZOVEGESENERTEKELHETO SzovegesenErtekelheto
|
||||
FROM
|
||||
T_TANULOCSOPORT AS tanuloCsoport
|
||||
INNER JOIN T_FELHASZNALO felhasznalo ON
|
||||
felhasznalo.ID = tanuloCsoport.C_TANULOID
|
||||
LEFT JOIN T_TANULOMENTESSEG tanuloMentesseg ON
|
||||
tanuloMentesseg.C_TANULOID = felhasznalo.ID AND
|
||||
tanuloMentesseg.TOROLT = 'F' AND
|
||||
tanuloMentesseg.C_TANTARGYID = @pTantargyId AND
|
||||
(tanuloMentesseg.C_KEZDETE IS NULL OR tanuloMentesseg.C_KEZDETE <= @pErtekelesDatum) AND
|
||||
(tanuloMentesseg.C_VEGE IS NULL OR tanuloMentesseg.C_VEGE >= @pErtekelesDatum)
|
||||
WHERE
|
||||
tanuloCsoport.TOROLT = 'F' AND
|
||||
tanuloCsoport.C_OSZTALYCSOPORTID = @pOsztalyId AND
|
||||
tanuloCsoport.C_BELEPESDATUM <= @pErtekelesDatum AND
|
||||
(tanuloCsoport.C_KILEPESDATUM IS NULL OR tanuloCsoport.C_KILEPESDATUM >= @pErtekelesDatum)
|
||||
) AS result2
|
||||
ON result2.ID = result.ID
|
||||
|
||||
IF OBJECT_ID('tempdb..#TempErtekeles') IS NOT NULL DROP TABLE #TempErtekeles
|
||||
|
||||
END
|
||||
GO
|
||||
|
@@ -0,0 +1,208 @@
|
||||
IF OBJECT_ID('[dbo].[sp_GetTanulokMulasztasaiKesesei]') IS NOT NULL BEGIN
|
||||
DROP PROCEDURE [dbo].[sp_GetTanulokMulasztasaiKesesei]
|
||||
END
|
||||
GO
|
||||
|
||||
-- ==========================================================================================
|
||||
-- Description: <Az osztoly/csoport tanulóinak vagy egy adott tanulónak a mulasztásai>
|
||||
-- ==========================================================================================
|
||||
CREATE PROCEDURE [dbo].[sp_GetTanulokMulasztasaiKesesei]
|
||||
@pIntezmenyId INT
|
||||
,@pTanevId INT
|
||||
,@pOsztalyCsoportId INT = NULL
|
||||
,@pTanuloId INT = NULL
|
||||
AS
|
||||
BEGIN
|
||||
SET NOCOUNT ON;
|
||||
|
||||
DECLARE
|
||||
@elmeletiOraPercben INT = 45
|
||||
,@gyakorlatiOraPercben INT = 60
|
||||
,@osztalyCsoportNev NVARCHAR(200)
|
||||
|
||||
SELECT @osztalyCsoportNev = C_NEV
|
||||
FROM T_OSZTALYCSOPORT
|
||||
WHERE ID = @pOsztalyCsoportId
|
||||
|
||||
DECLARE @Tanulok TABLE (Id INT PRIMARY KEY)
|
||||
|
||||
IF @pTanuloId IS NOT NULL
|
||||
BEGIN
|
||||
INSERT INTO @Tanulok (Id) VALUES (@pTanuloId)
|
||||
END
|
||||
ELSE BEGIN
|
||||
INSERT INTO
|
||||
@Tanulok (Id)
|
||||
SELECT
|
||||
C_TANULOID
|
||||
FROM
|
||||
T_TANULOCSOPORT_OSSZES tcs
|
||||
WHERE
|
||||
tcs.C_OSZTALYCSOPORTID = @pOsztalyCsoportId
|
||||
AND tcs.C_BELEPESDATUM <= GETDATE()
|
||||
AND (tcs.C_KILEPESDATUM > GETDATE() OR tcs.C_KILEPESDATUM IS NULL)
|
||||
END
|
||||
|
||||
SELECT
|
||||
fh.ID TanuloId
|
||||
,fh.C_NYOMTATASINEV TanuloNev
|
||||
,fh.C_SZULETESIDATUM SzuletesiIdo
|
||||
,fh.C_ANYJANEVE AnyjaNeve
|
||||
,@osztalyCsoportNev OsztCsopNev
|
||||
,ISNULL(m.[hianyzasIgazolandoTanorai], 0) TanoraiHianyzasIgazolando
|
||||
,ISNULL(m.[hianyzasIgazolandoTanoranKivuli], 0) TanoranKivuliHianyzasIgazolando
|
||||
,ISNULL(m.[hianyzasIgazoltTanorai], 0) TanoraiHianyzasIgazolt
|
||||
,ISNULL(m.[hianyzasIgazoltTanoranKivuli], 0) TanoranKivuliHianyzasIgazolt
|
||||
,ISNULL(m.[hianyzasIgazolatlanTanorai], 0) TanoraiHianyzasIgazolatlan
|
||||
,ISNULL(m.[hianyzasIgazolatlanTanoranKivuli], 0) TanoranKivuliHianyzasIgazolatlan
|
||||
,ISNULL(m.[kesesIgazolandoTanorai], 0) TanoraiKesesDarabszamIgazolando
|
||||
,ISNULL(m.[kesesIgazoltTanorai], 0) TanoraiKesesDarabszamIgazolt
|
||||
,ISNULL(m.[kesesIgazolatlanTanorai], 0) TanoraiKesesDarabszamIgazolatlan
|
||||
,ISNULL(k.[kesesIgazolandoTanoraiPerc], 0) TanoraiKesesIgazolandoPerc
|
||||
,ISNULL(k.[kesesIgazoltTanoraiPerc], 0) TanoraiKesesIgazoltPerc
|
||||
,ISNULL(k.[kesesIgazolatlanTanoraiPerc], 0) TanoraiKesesIgazolatlanPerc
|
||||
,ISNULL(kp.[kesesIgazolandoTanoraiPluszOra], 0) SzamitottKesesIgazolando
|
||||
,ISNULL(kp.[kesesIgazoltTanoraiPluszOra], 0) SzamitottKesesIgazolt
|
||||
,ISNULL(kp.[kesesIgazolatlanTanoraiPluszOra], 0) SzamitottKesesIgazolatlan
|
||||
FROM (
|
||||
SELECT
|
||||
ID
|
||||
,C_NYOMTATASINEV
|
||||
,C_SZULETESIDATUM
|
||||
,C_ANYJANEVE
|
||||
FROM
|
||||
T_FELHASZNALO_OSSZES fh
|
||||
WHERE
|
||||
EXISTS (SELECT 1 FROM @Tanulok tk WHERE tk.Id = fh.ID)
|
||||
) fh
|
||||
LEFT JOIN (
|
||||
SELECT
|
||||
tanuloId
|
||||
,[hianyzasIgazolandoTanorai]
|
||||
,[hianyzasIgazolandoTanoranKivuli]
|
||||
,[hianyzasIgazoltTanorai]
|
||||
,[hianyzasIgazoltTanoranKivuli]
|
||||
,[hianyzasIgazolatlanTanorai]
|
||||
,[hianyzasIgazolatlanTanoranKivuli]
|
||||
,[kesesIgazolandoTanorai]
|
||||
,[kesesIgazoltTanorai]
|
||||
,[kesesIgazolatlanTanorai]
|
||||
FROM (
|
||||
SELECT
|
||||
x.tanuloId
|
||||
,CASE mulasztasTipus WHEN 1500 THEN 'Hianyzas' WHEN 1499 THEN 'Keses' END +
|
||||
CASE WHEN isIgazolt IS NULL THEN 'Igazolando' WHEN isIgazolt = 'T' THEN 'Igazolt' WHEN isIgazolt = 'F' THEN 'Igazolatlan' END +
|
||||
CASE isTanorai WHEN 'T' THEN 'Tanorai' WHEN 'F' THEN 'TanoranKivuli' END AS piv
|
||||
,cnt
|
||||
FROM (
|
||||
SELECT
|
||||
m.C_ORATANULOIID AS tanuloId
|
||||
,m.C_TIPUS mulasztasTipus
|
||||
,m.C_IGAZOLT isIgazolt
|
||||
,IIF(cs.ID IS NULL OR cs.C_TIPUSA = 1034, 'T', 'F') AS isTanorai
|
||||
,COUNT(1) AS cnt
|
||||
FROM T_TANULOMULASZTAS_OSSZES m
|
||||
INNER JOIN T_TANITASIORA_OSSZES tn ON tn.ID = m.C_TANITASIORAKID
|
||||
LEFT JOIN T_CSOPORT_OSSZES cs ON tn.C_OSZTALYCSOPORTID = cs.ID
|
||||
WHERE
|
||||
m.C_INTEZMENYID = @pIntezmenyId
|
||||
AND m.C_TANEVID = @pTanevId
|
||||
AND m.Torolt ='F'
|
||||
AND EXISTS (SELECT 1 FROM @Tanulok tk WHERE tk.Id = m.C_ORATANULOIID)
|
||||
GROUP BY m.C_ORATANULOIID, m.C_TIPUS, m.C_IGAZOLT, IIF(cs.ID IS NULL OR cs.C_TIPUSA = 1034, 'T', 'F')
|
||||
) x
|
||||
) p
|
||||
PIVOT (
|
||||
MAX(cnt)
|
||||
FOR piv IN ([hianyzasIgazolandoTanorai], [hianyzasIgazolandoTanoranKivuli], [hianyzasIgazoltTanorai], [hianyzasIgazoltTanoranKivuli], [hianyzasIgazolatlanTanorai], [hianyzasIgazolatlanTanoranKivuli], [kesesIgazolandoTanorai], [kesesIgazoltTanorai], [kesesIgazolatlanTanorai])
|
||||
) AS pvt
|
||||
) m ON fh.ID = m.tanuloId
|
||||
LEFT JOIN (
|
||||
SELECT
|
||||
tanuloId
|
||||
,[kesesIgazolandoTanoraiPerc]
|
||||
,[kesesIgazoltTanoraiPerc]
|
||||
,[kesesIgazolatlanTanoraiPerc]
|
||||
FROM (
|
||||
SELECT
|
||||
x.tanuloId
|
||||
,'Keses' +
|
||||
CASE WHEN isIgazolt IS NULL THEN 'Igazolando' WHEN isIgazolt = 'T' THEN 'Igazolt' WHEN isIgazolt = 'F' THEN 'Igazolatlan' END +
|
||||
'TanoraiPerc' AS piv
|
||||
,kesesPercben
|
||||
FROM (
|
||||
SELECT
|
||||
m.C_ORATANULOIID AS tanuloId
|
||||
,m.C_IGAZOLT isIgazolt
|
||||
,SUM(m.C_KESESPERCBEN) AS kesesPercben
|
||||
FROM T_TANULOMULASZTAS_OSSZES m
|
||||
INNER JOIN T_TANITASIORA_OSSZES tn ON tn.ID = m.C_TANITASIORAKID
|
||||
LEFT JOIN T_CSOPORT_OSSZES cs ON tn.C_OSZTALYCSOPORTID = cs.ID
|
||||
WHERE m.C_INTEZMENYID = @pIntezmenyId
|
||||
AND m.C_TANEVID = @pTanevId
|
||||
AND m.Torolt ='F'
|
||||
AND EXISTS (SELECT 1 FROM @Tanulok tk WHERE tk.Id = m.C_ORATANULOIID)
|
||||
AND (cs.ID IS NULL OR cs.C_TIPUSA = 1034)
|
||||
AND m.C_TIPUS = 1499
|
||||
GROUP BY m.C_ORATANULOIID, m.C_IGAZOLT
|
||||
) x
|
||||
) p
|
||||
PIVOT (
|
||||
MAX(kesesPercben)
|
||||
FOR piv IN ([kesesIgazolandoTanoraiPerc], [kesesIgazoltTanoraiPerc], [kesesIgazolatlanTanoraiPerc])
|
||||
) AS pvt
|
||||
) k ON k.tanuloId = m.tanuloId
|
||||
LEFT JOIN (
|
||||
SELECT
|
||||
tanuloId
|
||||
,[kesesIgazolandoTanoraiPluszOra]
|
||||
,[kesesIgazoltTanoraiPluszOra]
|
||||
,[kesesIgazolatlanTanoraiPluszOra]
|
||||
FROM (
|
||||
SELECT
|
||||
x.tanuloId
|
||||
,'Keses' +
|
||||
CASE WHEN isIgazolt IS NULL THEN 'Igazolando' WHEN isIgazolt = 'T' THEN 'Igazolt' WHEN isIgazolt = 'F' THEN 'Igazolatlan' END +
|
||||
'TanoraiPluszOra' AS piv
|
||||
,kesesOraban
|
||||
FROM (
|
||||
SELECT
|
||||
xx.tanuloId
|
||||
,xx.isIgazolt
|
||||
,SUM(xx.keses / (CASE WHEN isGyakorlati = 'F' THEN @elmeletiOraPercben ELSE @gyakorlatiOraPercben END)) AS kesesOraban
|
||||
FROM (
|
||||
SELECT
|
||||
m.C_ORATANULOIID AS tanuloId
|
||||
,m.C_IGAZOLT isIgazolt
|
||||
,t.C_GYAKORLATI AS isGyakorlati
|
||||
,SUM(m.C_KESESPERCBEN) AS keses
|
||||
FROM T_TANULOMULASZTAS_OSSZES m
|
||||
INNER JOIN T_TANITASIORA_OSSZES tn ON tn.ID = m.C_TANITASIORAKID
|
||||
INNER JOIN T_TANTARGY_OSSZES t ON t.ID = tn.C_TANTARGYID
|
||||
LEFT JOIN T_CSOPORT_OSSZES cs ON tn.C_OSZTALYCSOPORTID = cs.ID
|
||||
WHERE
|
||||
m.C_INTEZMENYID = @pIntezmenyId
|
||||
AND m.C_TANEVID = @pTanevId
|
||||
AND EXISTS (SELECT 1 FROM @Tanulok tk WHERE tk.Id = m.C_ORATANULOIID)
|
||||
AND (cs.ID IS NULL OR cs.C_TIPUSA = 1034)
|
||||
AND m.C_TIPUS = 1499
|
||||
AND m.TOROLT = 'F'
|
||||
GROUP BY
|
||||
m.C_ORATANULOIID
|
||||
,m.C_IGAZOLT
|
||||
,t.C_GYAKORLATI
|
||||
) xx
|
||||
GROUP BY tanuloId, xx.isIgazolt
|
||||
) x
|
||||
) p
|
||||
PIVOT (
|
||||
MAX(kesesOraban)
|
||||
FOR piv IN ([kesesIgazolandoTanoraiPluszOra], [kesesIgazoltTanoraiPluszOra], [kesesIgazolatlanTanoraiPluszOra])
|
||||
) AS pvt
|
||||
) kp ON m.tanuloId = kp.tanuloId
|
||||
|
||||
END
|
||||
|
||||
|
||||
GO
|
||||
|
Reference in New Issue
Block a user