136 lines
5.3 KiB
Transact-SQL
136 lines
5.3 KiB
Transact-SQL
GO
|
|
SET ANSI_NULLS ON
|
|
GO
|
|
SET QUOTED_IDENTIFIER ON
|
|
GO
|
|
|
|
IF OBJECT_ID('sp_GetOralatogatasok') IS NOT NULL BEGIN
|
|
DROP PROCEDURE sp_GetOralatogatasok
|
|
END
|
|
GO
|
|
|
|
CREATE PROCEDURE [dbo].[sp_GetOralatogatasok]
|
|
@IntezmenyId int,
|
|
@TanevId int,
|
|
@IdoszakKezdete datetime,
|
|
@IdoszakVege datetime,
|
|
@TanarId int
|
|
AS
|
|
BEGIN
|
|
-- SET NOCOUNT ON added to prevent extra result sets from
|
|
-- interfering with SELECT statements.
|
|
SET NOCOUNT ON;
|
|
|
|
DECLARE @KezdoHet int = DATEPART( ISO_WEEK, @IdoszakKezdete);
|
|
DECLARE @ZaroHet int = DATEPART( ISO_WEEK, @IdoszakVege);
|
|
|
|
SELECT
|
|
Datum,
|
|
CASE
|
|
WHEN TanevHetirend is null THEN NapHetirend
|
|
ELSE TanevHetirend
|
|
END Hetirend,
|
|
CASE
|
|
WHEN TanevHetNapja is null THEN NapHetNapja
|
|
ELSE TanevHetNapja
|
|
END HetNapja
|
|
INTO
|
|
#TEMPORARENDINAPOK
|
|
from(
|
|
SELECT
|
|
NAPTARINAP.Datum Datum,
|
|
napHetirend.C_HETIREND NapHetirend,
|
|
napHetirend.C_HETNAPJA NapHetNapja,
|
|
tanevRendHetirend.C_HETIREND TanevHetirend,
|
|
tanevRendHetirend.C_HETNAPJA TanevHetNapja
|
|
FROM /*ÁTÍRANDÓÓÓ*/
|
|
(
|
|
/*Minden naptári nap, ami az időintervallumba beleesik.*/
|
|
(SELECT C_NAPDATUMA Datum FROM T_NAPTARINAP_OSSZES NAPTARINAP WHERE (TOROLT = 'F' AND C_NAPDATUMA BETWEEN @IdoszakKezdete AND @IdoszakVege AND C_INTEZMENYID = @IntezmenyId AND C_TANEVID=@TanevId))
|
|
EXCEPT /*Kivéve, ha van aznap kiemelt típusú tanévrendje esemény, vagy olyan esemény, aminél C_ORARENDINAP = 'F'.*/
|
|
(SELECT C_DATUM Datum FROM T_TANEVRENDJE_OSSZES TANEVRENDJE WHERE (TOROLT = 'F' AND (C_NAPTIPUSA IN (1386,1387,1389,1391,1392,1396,1397,1398,1399,1401) OR C_ORARENDINAP = 'F') AND C_INTEZMENYID = @IntezmenyId AND C_TANEVID=@TanevId))
|
|
UNION /*Azokat a dátumokat vegyük hozzá, amely napokon van C_ORARENDINAP = 'T' és C_ORARENDINAP = 'F' esemény is felvéve.*/
|
|
(
|
|
SELECT
|
|
Datum
|
|
FROM
|
|
(
|
|
SELECT
|
|
C_DATUM Datum,
|
|
COUNT (C_DATUM) DatumCounter
|
|
FROM
|
|
(SELECT C_DATUM, C_ORARENDINAP FROM T_TANEVRENDJE_OSSZES TANEVRENDJE WHERE (TOROLT = 'F') AND C_INTEZMENYID = @IntezmenyId AND C_TANEVID=@TanevId) TANEVRENDJE1
|
|
GROUP BY
|
|
C_ORARENDINAP,
|
|
C_DATUM
|
|
) TANEVRENDJE2
|
|
GROUP BY
|
|
Datum
|
|
HAVING
|
|
COUNT(Datum) = 2
|
|
)
|
|
) NAPTARINAP
|
|
left join (select C_NAPDATUMA, C_HETIREND, C_HETNAPJA from T_NAPTARINAP_OSSZES WHERE TOROLT = 'F') napHetirend on napHetirend.C_NAPDATUMA = NAPTARINAP.Datum
|
|
left join (select C_DATUM, C_HETIREND, C_HETNAPJA from T_TANEVRENDJE_OSSZES WHERE TOROLT = 'F') tanevRendHetirend on tanevRendHetirend.C_DATUM = NAPTARINAP.Datum
|
|
) NapokHetirenddel
|
|
|
|
-- Vegzosok utolso tanitasi napja
|
|
DECLARE @VegzosUtolsoTanitasiNap_spGetOrarend DATETIME;
|
|
SELECT
|
|
@VegzosUtolsoTanitasiNap_spGetOrarend = C_DATUM
|
|
FROM
|
|
T_TANEVRENDJE_OSSZES
|
|
WHERE
|
|
TOROLT = 'F'
|
|
AND C_TANEVID = (SELECT ID FROM T_TANEV_OSSZES WHERE TOROLT = 'F' AND C_AKTIV = 'T' AND C_INTEZMENYID = @IntezmenyId)
|
|
AND C_NAPTIPUSA = 1402 AND C_INTEZMENYID = @IntezmenyId AND C_TANEVID=@TanevId
|
|
|
|
|
|
-- Tanítási órák
|
|
SELECT
|
|
TANITASIORA.ID Id,
|
|
TANITASIORA.C_ORARENDIORAID ORARENDIID,
|
|
TANITASIORA.C_BONTOTT Bontott,
|
|
( SELECT
|
|
T_NAPTARINAP_OSSZES.C_HETIREND
|
|
FROM
|
|
T_NAPTARINAP_OSSZES
|
|
WHERE
|
|
T_NAPTARINAP_OSSZES.ID = TANITASIORA.C_NAPTARINAPID
|
|
) Hetirend,
|
|
TANITASIORA.C_HETNAPJA HetNapja,
|
|
'' ErvenyessegKezdete,
|
|
'' ErvenyessegVege,
|
|
TANITASIORA.C_ORAKEZDETE OraKezdete,
|
|
TANITASIORA.C_ORAVEGE OraVege,
|
|
TANITASIORA.C_ORASZAM Oraszam,
|
|
TARGY.C_ROVIDNEV TargyNev,
|
|
TANITASIORA.C_MEGTARTOTT Megtartott,
|
|
TANITASIORA.C_CSENGETESIRENDORAID CsengetesiRendOraID,
|
|
OSZTALY.C_NEV OsztalyNev,
|
|
TANAR.C_NYOMTATASINEV TanarNev,
|
|
TEREM.C_NEV TeremNev,
|
|
'TanitasiOra' OraTipus,
|
|
TANITASIORA.C_HELYETTESITOTANARID HelyettesitoTanarID,
|
|
TANAR.ID TanarID
|
|
INTO #TEMPORAK
|
|
FROM
|
|
T_TANITASIORA_OSSZES TANITASIORA
|
|
LEFT JOIN T_TANTARGY_OSSZES TARGY ON (TARGY.ID = TANITASIORA.C_TANTARGYID AND TARGY.C_INTEZMENYID = @IntezmenyId AND TARGY.C_TANEVID=@TanevId)
|
|
LEFT JOIN T_ORAK_TANAROK ON TANITASIORA.ID = T_ORAK_TANAROK.C_ORAKID
|
|
LEFT JOIN T_FELHASZNALO_OSSZES TANAR on T_ORAK_TANAROK.C_TANAROKID = TANAR.ID
|
|
LEFT JOIN T_OSZTALYCSOPORT_OSSZES OSZTALY on (TANITASIORA.C_OSZTALYCSOPORTID = OSZTALY.ID AND OSZTALY.C_INTEZMENYID = @IntezmenyId AND OSZTALY.C_TANEVID=@TanevId)
|
|
LEFT JOIN T_TEREM_OSSZES TEREM on (TEREM.id = TANITASIORA.C_TEREMID AND TEREM.C_INTEZMENYID = @IntezmenyId AND TEREM.C_TANEVID=@TanevId)
|
|
WHERE
|
|
TANITASIORA.TOROLT='F' AND TANITASIORA.C_INTEZMENYID = @IntezmenyId AND TANITASIORA.C_TANEVID=@TanevId
|
|
AND TANITASIORA.C_CSENGETESIRENDORAID IS NOT NULL
|
|
AND TANITASIORA.C_MEGTARTOTT = 'T'
|
|
AND (TANITASIORA.C_ORAKEZDETE >= @IdoszakKezdete
|
|
AND TANITASIORA.C_ORAVEGE <= (CASE WHEN OSZTALY.C_VEGZOSEVFOLYAM = 'T' AND @VegzosUtolsoTanitasiNap_spGetOrarend IS NOT NULL AND @IdoszakVege > @VegzosUtolsoTanitasiNap_spGetOrarend THEN @VegzosUtolsoTanitasiNap_spGetOrarend ELSE @IdoszakVege END))
|
|
AND (@TanarId IS NULL OR ( TANITASIORA.C_HELYETTESITOTANARID = @TanarId OR TANITASIORA.C_ORATULAJDONOSID = @TanarId OR T_ORAK_TANAROK.C_TANAROKID = @TanarId ))
|
|
|
|
SELECT * FROM #TEMPORAK order by orakezdete
|
|
|
|
DROP TABLE #TEMPORAK
|
|
DROP TABLE #TEMPORARENDINAPOK
|
|
END
|