kreta/Kreta.DataAccess.Migrations/DBScripts/Database/dbo/Stored procedures/uspListFeladatIdByOraId.sql
2024-03-13 00:33:46 +01:00

62 lines
2.6 KiB
Transact-SQL

DROP PROCEDURE IF EXISTS [dbo].[uspListFeladatIdByOraId]
GO
CREATE PROCEDURE [dbo].[uspListFeladatIdByOraId]
@pOrarendiOraItemsListString nvarchar(max) = NULL -- JSON
,@pTanitasiOraIdsListString nvarchar(max) = NULL -- CSV
,@pFeladatFilter int = NULL -- NULL - Összes feladat, 0 - Házi Feladat, 1 - Órai feladat, 2 - E-learning feladat, 3 - Nyelvi feladat
AS
BEGIN
SET NOCOUNT ON;
DROP TABLE IF EXISTS #TanitasiOra
CREATE TABLE #TanitasiOra (TanitasiOraId INT NOT NULL PRIMARY KEY CLUSTERED);
INSERT INTO #TanitasiOra(TanitasiOraId)
SELECT DISTINCT CAST(VALUE AS INT)
FROM STRING_SPLIT(@pTanitasiOraIdsListString, ',') list
SELECT
feladat.ID AS FeladatId
,feladat.C_TANITASIORAID AS TanitasiOraId
,NULL AS OrarendiOraId
,feladat.C_DATUM AS OraDatuma
,feladat.C_LATHATOSAGIDOPONT AS LathatosagIdopont
,feladat.C_FELADATTIPUSID AS FeladatTipus
,feladat.C_GROUPID AS GroupId
FROM T_DKT_FELADAT AS feladat
INNER JOIN #TanitasiOra t ON t.TanitasiOraId = feladat.C_TANITASIORAID
WHERE feladat.TOROLT = 'F'
AND feladat.C_FELADATTIPUSID = CASE WHEN @pFeladatFilter > 0 THEN @pFeladatFilter ELSE feladat.C_FELADATTIPUSID END
UNION ALL
SELECT
feladat.ID AS FeladatId
,NULL AS TanitasiOraId
,orarendiOra.ID AS OrarendiOraId
,feladat.C_DATUM AS OraDatuma
,feladat.C_LATHATOSAGIDOPONT AS LathatosagIdopont
,feladat.C_FELADATTIPUSID AS FeladatTipus
,feladat.C_GROUPID AS GroupId
FROM T_DKT_FELADAT feladat
INNER JOIN T_ORARENDIORA orarendiOra ON orarendiOra.C_TANTARGYID = feladat.C_TANTARGYID
AND orarendiOra.C_OSZTALYCSOPORTID = feladat.C_OSZTALYCSOPORTID
AND orarendiOra.C_TANARID = feladat.C_ALKALMAZOTTID
AND feladat.C_DATUM >= orarendiOra.C_ORAERVENYESSEGKEZDETE
AND (feladat.C_DATUM < orarendiOra.C_ORAERVENYESSEGVEGE OR (feladat.C_DATUM = orarendiOra.C_ORAERVENYESSEGVEGE AND feladat.C_DATUM = orarendiOra.C_ORAERVENYESSEGKEZDETE))
AND (feladat.C_ORASZAM = orarendiOra.C_ORASZAM OR CONVERT(time(0), feladat.C_IDOPONT) = CONVERT(time(0), orarendiOra.C_ORAKEZDETE))
AND orarendiOra.TOROLT = 'F'
INNER JOIN (
SELECT OrarendiOraId, FeladatDatum
FROM OPENJSON(@pOrarendiOraItemsListString)
WITH (
OrarendiOraId INT '$.orarendiOra_ID',
FeladatDatum DATE '$.feladat_C_DATUM'
)
) j ON j.OrarendiOraId = orarendiOra.ID AND j.FeladatDatum = feladat.C_DATUM
WHERE feladat.TOROLT = 'F'
AND feladat.C_FELADATTIPUSID = CASE WHEN @pFeladatFilter > 0 THEN @pFeladatFilter ELSE feladat.C_FELADATTIPUSID END
AND feladat.C_TANITASIORAID IS NULL
END
GO