83 lines
3.3 KiB
Transact-SQL
83 lines
3.3 KiB
Transact-SQL
-- =============================================
|
|
-- Author: <Kelemen Attila>
|
|
-- Create date: <2016. 01. 25.>
|
|
-- Description: <Tanuló jegyei havi bontásban tantárgyanként>
|
|
-- =============================================
|
|
IF OBJECT_ID('[dbo].[sp_GetTanuloOsztalyzatai]') IS NOT NULL BEGIN
|
|
DROP PROCEDURE [dbo].[sp_GetTanuloOsztalyzatai]
|
|
END
|
|
GO
|
|
|
|
CREATE PROCEDURE [dbo].[sp_GetTanuloOsztalyzatai]
|
|
@tanuloID int
|
|
AS
|
|
BEGIN
|
|
SET NOCOUNT ON;
|
|
|
|
DECLARE @masodikFelev datetime
|
|
SELECT TOP (1) @masodikFelev = DATEADD(d, 1, C_DATUM)
|
|
FROM T_TANEVRENDJE
|
|
WHERE C_NAPTIPUSA= 1400 --Első félév vége
|
|
|
|
DECLARE @idoszak TABLE (
|
|
id int primary key,
|
|
period varchar(10),
|
|
startdate datetime,
|
|
enddate datetime
|
|
)
|
|
|
|
INSERT INTO @idoszak (id, period, startdate, enddate)
|
|
SELECT
|
|
ROW_NUMBER() OVER(ORDER BY (SELECT 1)) AS id
|
|
,IIF(MONTH(n.C_NAPDATUMA) <> 1, CAST(MONTH(n.C_NAPDATUMA) AS varchar(3)), '1/I') AS period
|
|
,DATEFROMPARTS ( YEAR(n.C_NAPDATUMA), MONTH(n.C_NAPDATUMA), 1 ) AS startdate
|
|
,IIF(MONTH(n.C_NAPDATUMA) = 1
|
|
,@masodikFelev
|
|
,DATEADD(m, 1, DATEFROMPARTS ( YEAR(n.C_NAPDATUMA), MONTH(n.C_NAPDATUMA), 1 ))
|
|
) AS enddate
|
|
FROM T_NAPTARINAP_OSSZES n
|
|
INNER JOIN T_TANEV_OSSZES te ON te.ID = n.C_TANEVID
|
|
WHERE te.C_AKTIV = 'T'
|
|
AND MONTH(n.C_NAPDATUMA) IN (1, 9, 10, 11, 12)
|
|
GROUP BY YEAR(n.C_NAPDATUMA), MONTH(n.C_NAPDATUMA)
|
|
ORDER BY YEAR(n.C_NAPDATUMA), MONTH(n.C_NAPDATUMA)
|
|
|
|
INSERT INTO @idoszak (id, period, startdate, enddate)
|
|
SELECT
|
|
5 + ROW_NUMBER() OVER(ORDER BY (SELECT 1)) AS id
|
|
,IIF(MONTH(n.C_NAPDATUMA) <> 1, CAST(MONTH(n.C_NAPDATUMA) AS varchar(3)), '1/II') AS period
|
|
,IIF(MONTH(n.C_NAPDATUMA) = 1, @masodikFelev, DATEFROMPARTS ( YEAR(n.C_NAPDATUMA), MONTH(n.C_NAPDATUMA), 1 )) AS startdate
|
|
,DATEADD(m, 1, DATEFROMPARTS ( YEAR(n.C_NAPDATUMA), MONTH(n.C_NAPDATUMA), 1 )) AS enddate
|
|
FROM T_NAPTARINAP_OSSZES n
|
|
INNER JOIN T_TANEV_OSSZES te ON te.ID = n.C_TANEVID
|
|
WHERE te.C_AKTIV = 'T'
|
|
AND MONTH(n.C_NAPDATUMA) BETWEEN 1 AND 6
|
|
GROUP BY YEAR(n.C_NAPDATUMA), MONTH(n.C_NAPDATUMA)
|
|
ORDER BY YEAR(n.C_NAPDATUMA), MONTH(n.C_NAPDATUMA)
|
|
|
|
|
|
SELECT * FROM (
|
|
SELECT period, e.C_TANTARGYID, t.C_NEV TantargyNev,-- e.C_OSZTALYZAT
|
|
STUFF((
|
|
SELECT ', ' + CAST(sd.C_VALUE AS varchar(2))
|
|
FROM @idoszak si
|
|
INNER JOIN T_TANULOERTEKELES se ON se.C_ERTEKELESDATUM >= si.startdate AND se.C_ERTEKELESDATUM < si.enddate
|
|
AND se.C_TANTARGYID = e.C_TANTARGYID
|
|
--AND se.C_ERTEKELESTIPUSA = e.C_ERTEKELESTIPUSA
|
|
--AND se.C_TANULOID = e.C_TANULOID
|
|
INNER JOIN T_DICTIONARYITEMBASE sd ON sd.ID = se.C_OSZTALYZAT AND sd.C_TANEVID = se.C_TANEVID AND se.C_INTEZMENYID = sd.C_INTEZMENYID
|
|
WHERE p.ID = si.ID AND se.C_TANULOID = @tanuloID
|
|
FOR XML PATH(''), TYPE).value('.', 'varchar(max)')
|
|
, 1, 2, '') AS Osztalyzat
|
|
FROM @idoszak p
|
|
LEFT JOIN T_TANULOERTEKELES e ON e.C_ERTEKELESDATUM >= p.startdate AND e.C_ERTEKELESDATUM < p.enddate
|
|
INNER JOIN T_TANTARGY t ON t.ID = e.C_TANTARGYID
|
|
WHERE e.C_ERTEKELESTIPUSA = 1518 AND e.C_TANULOID = @tanuloID
|
|
GROUP BY p.id, p.period, e.C_TANTARGYID, t.C_NEV
|
|
) AS tbl
|
|
pivot (
|
|
MAX(Osztalyzat)
|
|
FOR period IN ([1/I], [1/II],[2],[3],[4],[5],[6],[7],[8],[9],[10],[11],[12])
|
|
)p1
|
|
END
|
|
|