init
This commit is contained in:
@@ -0,0 +1,49 @@
|
||||
|
||||
SET ANSI_NULLS ON
|
||||
GO
|
||||
|
||||
SET QUOTED_IDENTIFIER ON
|
||||
GO
|
||||
|
||||
DROP TABLE IF EXISTS [dbo].[T_ORARENDTELJES]
|
||||
GO
|
||||
|
||||
CREATE TABLE [dbo].[T_ORARENDTELJES](
|
||||
[C_INTEZMENYID] [int] NOT NULL,
|
||||
[C_TANEVID] [int] NOT NULL,
|
||||
[C_DATUM] [datetime] NOT NULL,
|
||||
[C_ORARENDIORAID] [int] NOT NULL,
|
||||
[C_ORARENDIORAGROUPID] [int] NULL,
|
||||
[C_OSZTALYCSOPORTID] [int] NULL,
|
||||
[C_FELADATKATEGORIAID] [int] NULL,
|
||||
[C_TANTARGYID] [int] NULL,
|
||||
[C_ISOSZTALYORARENDBENEMLATSZIK] [char](1) NULL,
|
||||
[C_TANARID] [int] NULL,
|
||||
[C_TEREMID] [int] NULL,
|
||||
[C_ORASZAM] [int] NULL,
|
||||
[C_CSENGETESIRENDID] [int] NULL,
|
||||
[C_BONTOTT] [char](1) NULL,
|
||||
[C_HETIREND] [int] NULL,
|
||||
[C_HETNAPJA] [int] NULL,
|
||||
[C_HETSORSZAMA] [int] NULL,
|
||||
[C_NAPDATUMA] [datetime] NULL,
|
||||
[C_ORAERVENYESSEGKEZDETE] [datetime] NULL,
|
||||
[C_ORAERVENYESSEGVEGE] [datetime] NULL,
|
||||
[C_ORAKEZDETE] [datetime] NULL,
|
||||
[C_ORAVEGE] [datetime] NULL,
|
||||
[C_EGYEDINAP] [char](1) NULL,
|
||||
[C_KOZPONTIORAGROUPID] [uniqueidentifier] NULL,
|
||||
[C_KOZPONTILAGTOROLTORAGROUPID] [uniqueidentifier] NULL,
|
||||
[C_HELYETTESTANAROKID] [int] NULL,
|
||||
[C_HELYETTESITESID] [int] NULL,
|
||||
CONSTRAINT PK_OrarendTeljes PRIMARY KEY CLUSTERED (
|
||||
[C_INTEZMENYID] ASC,
|
||||
[C_TANEVID] ASC,
|
||||
[C_DATUM] ASC,
|
||||
[C_ORARENDIORAID] ASC
|
||||
) WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON)
|
||||
)
|
||||
GO
|
||||
|
||||
EXEC dev.uspCreateSchemaViews 'T_ORARENDTELJES'
|
||||
GO
|
Binary file not shown.
@@ -0,0 +1,277 @@
|
||||
|
||||
SET ANSI_NULLS ON
|
||||
GO
|
||||
SET QUOTED_IDENTIFIER ON
|
||||
GO
|
||||
|
||||
DROP PROCEDURE IF EXISTS dbo.sp_GetOrarend
|
||||
GO
|
||||
|
||||
CREATE PROCEDURE dbo.sp_GetOrarend
|
||||
@pIntezmenyId int
|
||||
,@pTanevId int
|
||||
,@pIdoszakKezdete datetime
|
||||
,@pIdoszakVege datetime
|
||||
,@pTanarId int = NULL
|
||||
,@pIsHelyettesitesNelkul bit = 0
|
||||
,@pOsztalyCsoportId int = NULL
|
||||
,@pTanuloId int = NULL
|
||||
,@pTantargyId int = NULL
|
||||
,@pTeremId int = NULL
|
||||
,@pCsakOrarendiOrak bit
|
||||
,@pIsNapirend bit = 0
|
||||
,@pFeladatKategoriaId int = NULL
|
||||
,@pOrakezdete datetime = NULL
|
||||
,@pOravege datetime = NULL
|
||||
,@pHetnapja int = NULL
|
||||
,@pIsKozpontilagToroltOrak int = 0
|
||||
AS
|
||||
SET NOCOUNT ON;
|
||||
SET @pOrakezdete = CONVERT(datetime, CONVERT(TIME, @pOrakezdete));
|
||||
SET @pOravege = CONVERT(datetime, CONVERT(TIME, @pOravege));
|
||||
|
||||
-- DROP TABLE IF EXISTS #KapcsolodoCsoportok
|
||||
CREATE TABLE #KapcsolodoCsoportok(
|
||||
ID int NOT NULL,
|
||||
Kezdete datetime,
|
||||
Vege datetime,
|
||||
IsOsztaly bit,
|
||||
PRIMARY KEY CLUSTERED(ID)
|
||||
);
|
||||
|
||||
-- Összes osztályhoz vagy csoporthoz kapcsolódó további osztályok vagy csoportok megkeresése
|
||||
IF @pOsztalyCsoportId IS NOT NULL
|
||||
INSERT INTO #KapcsolodoCsoportok(ID, Kezdete, Vege, IsOsztaly)
|
||||
SELECT DISTINCT ID, Kezdete, Vege, 1 as IsOsztaly
|
||||
FROM dbo.fnGetKapcsolodoOsztalyCsoportokByDateRange(@pOsztalyCsoportId, @pIdoszakKezdete, @pIdoszakVege, @pIntezmenyId, @pTanevId) t;
|
||||
|
||||
-- Összes a tanulóhoz kapcsolódó további osztályok vagy csoportok megkeresése (amelyek még nincsenek meg)
|
||||
IF @pTanuloId IS NOT NULL
|
||||
INSERT INTO #KapcsolodoCsoportok(ID, Kezdete, Vege, IsOsztaly)
|
||||
SELECT DISTINCT tcs.C_OSZTALYCSOPORTID AS ID, tcs.C_BELEPESDATUM AS Kezdete, ISNULL(tcs.C_KILEPESDATUM, t.C_UTOLSONAP) AS Vege, 0 As IsOsztaly
|
||||
FROM T_TANULOCSOPORT_OSSZES tcs
|
||||
INNER JOIN T_TANEV_OSSZES t on t.ID = tcs.C_TANEVID
|
||||
WHERE t.TOROLT = 'F'
|
||||
AND tcs.C_INTEZMENYID = @pIntezmenyId
|
||||
AND tcs.C_TANEVID = @pTanevId
|
||||
AND tcs.C_TANULOID = @pTanuloId
|
||||
AND tcs.TOROLT = 'F'
|
||||
AND tcs.C_BELEPESDATUM <= @pIdoszakVege
|
||||
AND (tcs.C_KILEPESDATUM > @pIdoszakKezdete OR tcs.C_KILEPESDATUM IS NULL)
|
||||
AND NOT EXISTS(SELECT * FROM #KapcsolodoCsoportok k WHERE k.ID = tcs.C_OSZTALYCSOPORTID);
|
||||
|
||||
-- Fő lekérdezés
|
||||
SELECT
|
||||
ISNULL(tn.Id, oo.Id) AS Id
|
||||
,ISNULL(tn.ORARENDIID, oo.ORARENDIID) AS ORARENDIID
|
||||
,ISNULL(tn.Datum, oo.Datum) AS Datum
|
||||
,ISNULL(tn.Bontott, oo.Bontott) AS Bontott
|
||||
,ISNULL(tn.Hetirend, oo.Hetirend) AS Hetirend
|
||||
,ISNULL(tn.HetNapja, oo.HetNapja) AS HetNapja
|
||||
,ISNULL(tn.HetSorszam, oo.HetSorszam) AS HetSorszam
|
||||
,IIF(tn.Id IS NOT NULL, NULL, oo.ErvenyessegKezdete) AS ErvenyessegKezdete
|
||||
,IIF(tn.Id IS NOT NULL, NULL, oo.ErvenyessegVege) AS ErvenyessegVege
|
||||
,ISNULL(tn.OraKezdete, oo.OraKezdete) AS OraKezdete
|
||||
,ISNULL(tn.OraVege, oo.OraVege) AS OraVege
|
||||
,ISNULL(tn.Oraszam, oo.Oraszam) AS Oraszam
|
||||
,ISNULL(tantargy.C_ROVIDNEV, tantargy.C_NEV) AS TargyNev -- [3]: itt kellene javítani ISNULL helyett COALESCE
|
||||
,COALESCE(tantargy.C_ROVIDNEV, tantargy.C_NEV) AS TargyNevForMobile
|
||||
,tantargy.C_TARGYKATEGORIA AS TargykategoriaID
|
||||
,ISNULL(tn.Megtartott, oo.Megtartott) AS Megtartott
|
||||
,ISNULL(tn.CsengetesiRendOraID, oo.CsengetesiRendOraID) AS CsengetesiRendOraID
|
||||
,ISNULL(tn.CsengetesiRendID, oo.CsengetesiRendID) AS CsengetesiRendID
|
||||
,12 AS MaxNapiOraszam
|
||||
,osztaly.C_NEV AS OsztalyNev
|
||||
,ISNULL(tn.TanevRendOsztalyCsoportId, oo.TanevRendOsztalyCsoportId) AS TanevRendOsztalyCsoportId
|
||||
,ISNULL(tn.MegjelenesOka, oo.MegjelenesOka) AS MegjelenesOka
|
||||
,tanar.C_NYOMTATASINEV AS TanarNev
|
||||
,terem.C_NEV AS TeremNev
|
||||
,ISNULL(tn.TeremId, oo.TeremId) AS TeremId
|
||||
,ISNULL(tn.OraTipus, oo.OraTipus) AS OraTipus
|
||||
,ISNULL(tn.Hianyzas, oo.Hianyzas) AS Hianyzas
|
||||
,ISNULL(tn.Keses, oo.Keses) AS Keses
|
||||
,ISNULL(tn.Ures, oo.Ures) AS Ures
|
||||
,ISNULL(tn.HelyettesitoTanarID, oo.HelyettesitoTanarID) AS HelyettesitoTanarID
|
||||
,helyettes.C_NYOMTATASINEV AS HelyettesitoTanarNev
|
||||
,oo.HelyettesitesId AS HelyettesitesId
|
||||
,ISNULL(tn.TanarID, oo.TanarID) AS TanarID
|
||||
,ISNULL(tn.AdminAltalKiirt, oo.AdminAltalKiirt) AS AdminAltalKiirt
|
||||
,ISNULL(tn.GroupId, oo.GroupId) AS GroupId
|
||||
,tn.Tema AS Tema
|
||||
,ISNULL(tn.TantargyId, oo.TantargyId) AS TantargyId
|
||||
,ISNULL(tn.OsztCsopId, oo.OsztCsopId) AS OsztCsopId
|
||||
,csoport.C_OSZTALYBONTASID AS OsztalyBontasId
|
||||
,ISNULL(tn.IsEgyediNap, oo.IsEgyediNap) as IsEgyediNap
|
||||
,terem.C_TOBBORATLEHETTARTANI AS TeremTobbOratLehetTartani
|
||||
,oo.KozpontiOraGroupId
|
||||
,oo.KozpontilagToroltOraGroupId
|
||||
FROM (
|
||||
-- Órarendi órák + helyettesítések
|
||||
SELECT
|
||||
orr.C_ORARENDIORAID AS Id
|
||||
,orr.C_ORARENDIORAID AS ORARENDIID
|
||||
,orr.C_DATUM AS Datum
|
||||
,orr.C_BONTOTT AS Bontott
|
||||
,orr.C_HETIREND AS Hetirend
|
||||
,orr.C_HETNAPJA AS HetNapja
|
||||
,orr.C_HETSORSZAMA AS HetSorszam
|
||||
,orr.C_ORAERVENYESSEGKEZDETE AS ErvenyessegKezdete
|
||||
,orr.C_ORAERVENYESSEGVEGE AS ErvenyessegVege
|
||||
,CAST(orr.C_DATUM as datetime) + cast(orr.C_ORAKEZDETE as datetime) AS OraKezdete
|
||||
,cast(orr.C_DATUM as datetime) + cast(orr.C_ORAVEGE as datetime) AS OraVege
|
||||
,orr.C_ORASZAM AS Oraszam
|
||||
,'F' AS Megtartott
|
||||
,csro.ID AS CsengetesiRendOraID
|
||||
,csro.C_CSENGETESIRENDID AS CsengetesiRendID
|
||||
,orr.C_OSZTALYCSOPORTID AS TanevRendOsztalyCsoportId
|
||||
,'' AS MegjelenesOka
|
||||
,orr.C_TEREMID AS TeremId
|
||||
,'OrarendiOra' AS OraTipus
|
||||
,'F' AS Hianyzas
|
||||
,'F' AS Keses
|
||||
,'F' AS Ures
|
||||
,orr.C_HELYETTESTANAROKID AS HelyettesitoTanarID
|
||||
,orr.C_HELYETTESITESID AS HelyettesitesId
|
||||
,orr.C_TANARID AS TanarID
|
||||
,NULL AS AdminAltalKiirt
|
||||
,orr.C_ORARENDIORAGROUPID AS GroupId
|
||||
,NULL AS Tema
|
||||
,orr.C_TANTARGYID AS TantargyId
|
||||
,orr.C_OSZTALYCSOPORTID AS OsztCsopId
|
||||
,orr.C_EGYEDINAP as IsEgyediNap
|
||||
,orr.C_KOZPONTIORAGROUPID as KozpontiOraGroupId
|
||||
,orr.C_KOZPONTILAGTOROLTORAGROUPID as KozpontilagToroltOraGroupId
|
||||
FROM T_ORARENDTELJES_OSSZES orr
|
||||
LEFT JOIN T_CSENGETESIRENDORA_OSSZES csro ON csro.C_CSENGETESIRENDID = orr.C_CSENGETESIRENDID AND csro.C_ORASZAM = orr.C_ORASZAM AND csro.TOROLT = 'F'
|
||||
LEFT JOIN #KapcsolodoCsoportok kocs ON orr.C_OSZTALYCSOPORTID = kocs.Id AND orr.C_DATUM >= kocs.Kezdete AND orr.C_DATUM < kocs.Vege
|
||||
WHERE 0 = 0
|
||||
AND orr.C_INTEZMENYID = @pIntezmenyId
|
||||
AND orr.C_TANEVID = @pTanevId
|
||||
AND orr.C_DATUM >= @pIdoszakKezdete
|
||||
AND orr.C_DATUM < @pIdoszakVege
|
||||
AND ((@pIsNapirend = 1 OR @pIsNapirend IS NULL) OR csro.ID IS NOT NULL)
|
||||
AND ((@pIsNapirend = 0 OR @pIsNapirend IS NULL) OR orr.C_CSENGETESIRENDID IS NULL)
|
||||
AND ((@pIsNapirend = 0 OR @pIsNapirend = 1) OR ((orr.C_CSENGETESIRENDID IS NOT NULL AND csro.C_CSENGETESIRENDID IS NOT NULL) OR (orr.C_CSENGETESIRENDID IS NULL AND csro.C_CSENGETESIRENDID IS NULL)))
|
||||
AND (@pTantargyId IS NULL OR orr.C_TANTARGYID = @pTantargyId)
|
||||
AND ((@pOravege IS NULL OR @pOrakezdete IS NULL) OR (orr.C_ORAVEGE > @pOrakezdete AND orr.C_ORAKEZDETE < @pOravege))
|
||||
AND (@pHetnapja IS NULL OR orr.C_HETNAPJA = @pHetnapja)
|
||||
AND (@pTeremId IS NULL OR orr.C_TEREMID = @pTeremId)
|
||||
AND (@pOsztalyCsoportId IS NULL OR kocs.Id IS NOT NULL)
|
||||
AND (@pTanuloId IS NULL OR kocs.Id IS NOT NULL)
|
||||
AND (@pFeladatKategoriaId IS NULL OR orr.C_FELADATKATEGORIAID = @pFeladatKategoriaId)
|
||||
AND ((@pOsztalyCsoportId IS NULL AND @pTanuloId IS NULL) OR orr.C_ISOSZTALYORARENDBENEMLATSZIK = 'F')
|
||||
AND (
|
||||
((@pTanarId IS NULL AND @pIsHelyettesitesNelkul = 1) AND (orr.C_TANARID IS NOT NULL OR orr.C_HELYETTESTANAROKID IS NULL))
|
||||
OR
|
||||
((@pTanarId IS NULL AND @pIsHelyettesitesNelkul = 0) AND (orr.C_TANARID IS NOT NULL OR orr.C_HELYETTESTANAROKID IS NOT NULL))
|
||||
OR
|
||||
((@pTanarId IS NOT NULL AND @pIsHelyettesitesNelkul = 1) AND orr.C_TANARID = @pTanarId)
|
||||
OR
|
||||
((@pTanarId IS NOT NULL AND @pIsHelyettesitesNelkul = 0) AND (orr.C_TANARID = @pTanarId OR orr.C_HELYETTESTANAROKID = @pTanarId))
|
||||
)
|
||||
|
||||
) oo
|
||||
FULL JOIN (
|
||||
-- Tanítási órák + helyettesítések
|
||||
SELECT
|
||||
tao.ID AS Id
|
||||
,NULL AS ORARENDIID
|
||||
,tao.C_DATUM AS Datum
|
||||
,tao.C_BONTOTT AS Bontott
|
||||
,1554 AS Hetirend
|
||||
,tao.C_HETNAPJA AS HetNapja
|
||||
,tao.C_HETSORSZAMA AS HetSorszam
|
||||
,tao.C_ORAKEZDETE AS OraKezdete
|
||||
,tao.C_ORAVEGE AS OraVege
|
||||
,tao.C_ORASZAM AS Oraszam
|
||||
,tao.C_MEGTARTOTT AS Megtartott
|
||||
,tao.C_CSENGETESIRENDORAID AS CsengetesiRendOraID
|
||||
,tao.C_CSENGETESIRENDID AS CsengetesiRendID
|
||||
,tao.C_OSZTALYCSOPORTID AS TanevRendOsztalyCsoportId
|
||||
,'' AS MegjelenesOka
|
||||
,tao.C_TEREMID as TeremId
|
||||
,'TanitasiOra' AS OraTipus
|
||||
,IIF(mh.ID IS NULL, 'F', 'T') AS Hianyzas
|
||||
,IIF(mk.ID IS NULL, 'F', 'T') AS Keses
|
||||
,IIF(mu.ID IS NULL, 'F', 'T') AS Ures
|
||||
,tao.C_HELYETTESITOTANARID AS HelyettesitoTanarID
|
||||
,tao.C_TANARID AS TanarID
|
||||
,tao.C_ADMINALTALKIIRT AS AdminAltalKiirt
|
||||
,tao.C_ORARENDIORAGROUPID AS GroupId
|
||||
,tao.C_TEMA AS Tema
|
||||
,tao.C_TANTARGYID AS TantargyId
|
||||
,tao.C_OSZTALYCSOPORTID AS OsztCsopId
|
||||
,tao.C_EGYEDINAP as IsEgyediNap
|
||||
FROM T_TANITASIORA_OSSZES tao
|
||||
INNER JOIN T_OSZTALYCSOPORT_OSSZES ocs ON ocs.ID = tao.C_OSZTALYCSOPORTID AND ocs.TOROLT = 'F' AND ocs.C_INTEZMENYID = @pIntezmenyId AND ocs.C_TANEVID = @pTanevId
|
||||
INNER JOIN T_TANTARGY_OSSZES tt ON tao.C_TANTARGYID = tt.ID AND tt.C_INTEZMENYID = @pIntezmenyId AND tt.C_TANEVID = @pTanevId
|
||||
LEFT JOIN #KapcsolodoCsoportok kocs ON tao.C_OSZTALYCSOPORTID = kocs.Id AND tao.C_DATUM >= kocs.Kezdete AND tao.C_DATUM < kocs.Vege
|
||||
LEFT JOIN T_TANULOMULASZTAS_OSSZES mh ON mh.C_TANITASIORAKID = tao.ID AND mh.C_ORATANULOIID = @pTanuloId AND mh.C_TIPUS = 1500 AND mh.TOROLT = 'F'
|
||||
LEFT JOIN T_TANULOMULASZTAS_OSSZES mk ON mk.C_TANITASIORAKID = tao.ID AND mk.C_ORATANULOIID = @pTanuloId AND mk.C_TIPUS = 1499 AND mk.TOROLT = 'F'
|
||||
LEFT JOIN T_TANULOMULASZTAS_OSSZES mu ON mu.C_TANITASIORAKID = tao.ID AND mu.C_ORATANULOIID = @pTanuloId AND mu.C_TIPUS = 1817 AND mu.TOROLT = 'F'
|
||||
WHERE 0 = 0
|
||||
AND (@pCsakOrarendiOrak = 0)
|
||||
AND tao.TOROLT = 'F'
|
||||
AND tao.C_INTEZMENYID = @pIntezmenyId
|
||||
AND tao.C_TANEVID = @pTanevId
|
||||
AND tao.C_DATUM >= @pIdoszakKezdete
|
||||
AND tao.C_DATUM < @pIdoszakVege
|
||||
AND (@pOsztalyCsoportId IS NULL OR kocs.Id IS NOT NULL)
|
||||
--AND ((NOT (@pOsztalyCsoportId IS NOT NULL AND @pTanuloId IS NOT NULL)) OR tao.C_OSZTALYCSOPORTID = @pOsztalyCsoportId) -- lásd a [1]-es módosítást lenn, ezt is el kell távolítani
|
||||
AND (@pTanuloId IS NULL OR kocs.Id IS NOT NULL)
|
||||
AND ((@pIsNapirend = 0 OR @pIsNapirend IS NULL) OR tao.C_CSENGETESIRENDID IS NULL)
|
||||
AND ((@pIsNapirend = 1 OR @pIsNapirend IS NULL) OR tao.C_CSENGETESIRENDID IS NOT NULL)
|
||||
AND ((@pTanarId IS NULL OR @pIsHelyettesitesNelkul = 1) OR (tao.C_TANARID = @pTanarId OR tao.C_HELYETTESITOTANARID = @pTanarId))
|
||||
AND ((@pTanarId IS NULL OR @pIsHelyettesitesNelkul = 0) OR (tao.C_TANARID = @pTanarId))
|
||||
-- [2]: enélkül is jó volt a teszt, de így a biztos
|
||||
--AND (
|
||||
-- ((@pTanarId IS NULL AND @pIsHelyettesitesNelkul = 1) AND (tao.C_TANARID IS NOT NULL OR tao.C_HELYETTESITOTANARID IS NULL))
|
||||
-- OR
|
||||
-- ((@pTanarId IS NULL AND @pIsHelyettesitesNelkul = 0) AND (tao.C_TANARID IS NOT NULL OR tao.C_HELYETTESITOTANARID IS NOT NULL))
|
||||
-- OR
|
||||
-- ((@pTanarId IS NOT NULL AND @pIsHelyettesitesNelkul = 1) AND tao.C_TANARID = @pTanarId)
|
||||
-- OR
|
||||
-- ((@pTanarId IS NOT NULL AND @pIsHelyettesitesNelkul = 0) AND (tao.C_TANARID = @pTanarId OR tao.C_HELYETTESITOTANARID = @pTanarId))
|
||||
--)
|
||||
AND (@pTantargyId IS NULL OR tao.C_TANTARGYID = @pTantargyId)
|
||||
AND ((@pOravege IS NULL OR @pOrakezdete IS NULL) OR (tao.C_ORAVEGE > @pOrakezdete AND tao.C_ORAKEZDETE < @pOravege))
|
||||
AND (@pHetnapja IS NULL OR tao.C_HETNAPJA = @pHetnapja)
|
||||
AND (@pTeremId IS NULL OR tao.C_TEREMID = @pTeremId)
|
||||
AND (@pFeladatKategoriaId IS NULL OR ocs.C_FELADATKATEGORIAID = @pFeladatKategoriaId)
|
||||
AND (@pTanuloId IS NULL OR ((mu.C_TIPUS <> 1817 OR mu.C_TIPUS IS NULL) OR (tt.C_ISOSZTALYORARENDBENEMLATSZIK = 'F')))
|
||||
--AND (@pTanuloId IS NULL OR EXISTS( -- [1]: ezt a részt ki kell venni, mert csak azért van itt, hogy a tesztelés során
|
||||
-- SELECT * FROM T_TANULOCSOPORT tcs -- pontosan ugyanazt az eredményt adja a régi és az új sp
|
||||
-- WHERE 1 = 1 -- de logikailag az exists álltal kiszűrt soroknak is benne kellene lenniük
|
||||
-- AND tcs.TOROLT = 'F' -- vagy ha nem, akkor az órarendi órában sem kellene benne lenniük
|
||||
-- AND tcs.C_INTEZMENYID = @pIntezmenyId
|
||||
-- AND tcs.C_TANEVID = @pTanevId
|
||||
-- AND tcs.C_TANULOID = @pTanuloID
|
||||
-- AND tcs.C_OSZTALYCSOPORTID = tao.C_OSZTALYCSOPORTID
|
||||
-- AND tao.C_DATUM >= tcs.C_BELEPESDATUM
|
||||
-- AND (tao.C_DATUM < tcs.C_KILEPESDATUM OR tcs.C_KILEPESDATUM IS NULL)
|
||||
-- )
|
||||
--)
|
||||
|
||||
) tn ON 0 = 0
|
||||
AND tn.Datum = oo.Datum
|
||||
AND tn.HetNapja = oo.HetNapja
|
||||
AND ((@pIsNapirend IS NULL OR @pIsNapirend = 0) OR (tn.OraKezdete = oo.OraKezdete AND tn.OraVege = oo.OraVege))
|
||||
AND ((@pIsNapirend IS NULL OR @pIsNapirend = 1) OR (tn.Oraszam = oo.Oraszam))
|
||||
AND (@pIsNapirend IS NOT NULL OR ((tn.CsengetesiRendID IS NULL AND tn.OraKezdete = oo.OraKezdete AND tn.OraVege = oo.OraVege) OR (tn.CsengetesiRendID IS NOT NULL AND tn.Oraszam = oo.Oraszam)))
|
||||
AND tn.TanevRendOsztalyCsoportId = oo.TanevRendOsztalyCsoportId
|
||||
AND tn.TantargyId = oo.TantargyId
|
||||
AND tn.TanarID = oo.TanarID
|
||||
|
||||
LEFT JOIN T_TANTARGY_OSSZES tantargy ON tantargy.ID = ISNULL(tn.TantargyId, oo.TantargyId) AND (@pOsztalyCsoportId IS NULL OR tantargy.C_ISOSZTALYORARENDBENEMLATSZIK = 'F') AND tantargy.C_INTEZMENYID = @pIntezmenyId AND tantargy.C_TANEVID = @pTanevId
|
||||
LEFT JOIN T_FELHASZNALO_OSSZES tanar ON tanar.ID = ISNULL(tn.TanarID, oo.TanarID) AND tanar.C_INTEZMENYID = @pIntezmenyId AND tanar.C_TANEVID = @pTanevId
|
||||
LEFT JOIN T_TEREM_OSSZES terem ON terem.ID = ISNULL(tn.TeremId, oo.TeremId) AND terem.C_INTEZMENYID = @pIntezmenyId AND terem.C_TANEVID = @pTanevId
|
||||
-- [3]: itt is T_CSOPORT_OSSZES kellene, de az eredeti sp-ben csak T_CSOPORT-van véletlenül, ezért az eredmények nem egyeznek és persze a tanév szűrés is kell
|
||||
LEFT JOIN T_CSOPORT_OSSZES csoport ON csoport.ID = ISNULL(tn.OsztCsopId, oo.OsztCsopId) AND csoport.C_ALINTEZMENYID = @pIntezmenyId AND csoport.C_ALTANEVID = @pTanevId
|
||||
LEFT JOIN T_FELHASZNALO_OSSZES helyettes ON helyettes.ID = ISNULL(tn.HelyettesitoTanarID, oo.HelyettesitoTanarID) AND helyettes.C_INTEZMENYID = @pIntezmenyId AND helyettes.C_TANEVID = @pTanevId
|
||||
LEFT JOIN T_OSZTALYCSOPORT_OSSZES osztaly ON osztaly.ID = ISNULL(tn.OsztCsopId, oo.OsztCsopId) AND (@pFeladatKategoriaId IS NULL OR osztaly.C_FELADATKATEGORIAID = @pFeladatKategoriaId) AND osztaly.C_INTEZMENYID = @pIntezmenyId AND osztaly.C_TANEVID = @pTanevId
|
||||
OPTION (OPTIMIZE FOR UNKNOWN)
|
||||
GO
|
||||
|
||||
exec dev.uspRegisterSPFN 'sp_GetOrarend', 1
|
||||
exec dev.uspCreateSchemaSPFN 'sp_GetOrarend'
|
||||
GO
|
@@ -0,0 +1,315 @@
|
||||
DROP PROCEDURE IF EXISTS uspGenerateOrarend
|
||||
GO
|
||||
|
||||
CREATE PROCEDURE uspGenerateOrarend
|
||||
@pIntezmenyId int
|
||||
,@pTanevId int
|
||||
,@pIdoszakKezdete datetime = NULL
|
||||
,@pIdoszakVege datetime = NULL
|
||||
,@pOrarendiOraId int = NULL
|
||||
,@pOsztalycsoportId int = NULL
|
||||
AS
|
||||
BEGIN
|
||||
SET NOCOUNT ON;
|
||||
|
||||
DECLARE
|
||||
@sql nvarchar(max) = N''
|
||||
,@aktivCsengetesirend int;
|
||||
|
||||
SELECT
|
||||
@pIdoszakKezdete = ISNULL(@pIdoszakKezdete, C_KEZDONAP)
|
||||
,@pIdoszakVege = ISNULL(@pIdoszakVege, C_UTOLSONAP)
|
||||
FROM T_TANEV
|
||||
WHERE ID = @pTanevId
|
||||
|
||||
SELECT @aktivCsengetesirend = ID
|
||||
FROM T_CSENGETESIREND
|
||||
WHERE C_TANEVID = @pTanevId
|
||||
AND TOROLT = 'F'
|
||||
AND C_AKTIV = 'T'
|
||||
|
||||
IF @pOrarendiOraId IS NOT NULL BEGIN
|
||||
IF (SELECT TOROLT FROM T_ORARENDIORA_OSSZES WHERE ID = @pOrarendiOraId) = 'T' BEGIN
|
||||
DELETE orr
|
||||
FROM T_ORAREND_OSSZES orr
|
||||
WHERE orr.C_ORARENDIORAID = @pOrarendiOraId
|
||||
END
|
||||
ELSE BEGIN
|
||||
DELETE orr
|
||||
FROM T_ORAREND_OSSZES orr
|
||||
WHERE orr.C_ORARENDIORAID = @pOrarendiOraId
|
||||
AND (C_DATUM < @pIdoszakKezdete OR C_DATUM >= @pIdoszakVege)
|
||||
END
|
||||
END
|
||||
ELSE BEGIN
|
||||
DELETE orr
|
||||
FROM T_ORAREND_OSSZES orr
|
||||
INNER JOIN T_ORARENDIORA_OSSZES oo ON oo.ID = orr.C_ORARENDIORAID
|
||||
WHERE oo.TOROLT = 'T' AND oo.C_TANEVID = @pTanevId
|
||||
END
|
||||
|
||||
SET @sql += N'
|
||||
|
||||
CREATE TABLE #Osztalycsoport (
|
||||
Id int
|
||||
,IdoszakVege datetime
|
||||
,TanevId int
|
||||
,IsVegzos char(1)
|
||||
)
|
||||
|
||||
DECLARE @VegzosUtolsoTanitasiNap datetime;
|
||||
SELECT @VegzosUtolsoTanitasiNap = MIN(C_DATUM)
|
||||
FROM T_TANEVRENDJE_OSSZES
|
||||
WHERE TOROLT = ''F''
|
||||
AND C_TANEVID = @pTanevId
|
||||
AND C_NAPTIPUSA IN (1402, 7600, 7601, 7602, 7603, 1395)
|
||||
AND C_OSSZESCSOPORTRAVONATKOZIK = ''T''
|
||||
|
||||
--PRINT ''Oszt<EFBFBD>lycsoport insert''
|
||||
|
||||
INSERT INTO #Osztalycsoport (Id, IdoszakVege, TanevId, IsVegzos)
|
||||
SELECT ocs.ID, IIF(C_VEGZOSEVFOLYAM = ''T'', @VegzosUtolsoTanitasiNap, @pIdoszakVege), ocs.C_TANEVID, C_VEGZOSEVFOLYAM
|
||||
FROM T_OSZTALYCSOPORT_OSSZES ocs
|
||||
' + IIF(@pOrarendiOraId IS NULL, '', 'INNER JOIN T_ORARENDIORA_OSSZES oo ON oo.C_OSZTALYCSOPORTID = ocs.ID AND (oo.TOROLT = ''F'' OR (oo.TOROLT = ''T'' AND oo.C_KOZPONTILAGTOROLTORAGROUPID IS NOT NULL)) AND oo.ID = @pOrarendiOraId') + '
|
||||
WHERE ocs.TOROLT = ''F'' ' + IIF(@pOsztalycsoportId IS NULL, '', 'AND ocs.ID = @pOsztalycsoportId') + '
|
||||
|
||||
--PRINT ''Oszt<EFBFBD>lycsoport update''
|
||||
|
||||
UPDATE ocs SET
|
||||
ocs.IdoszakVege = NewVegeDatum
|
||||
FROM #OsztalyCsoport ocs
|
||||
INNER JOIN (
|
||||
SELECT MIN(tr.C_DATUM) AS NewVegeDatum, ocstr.C_OSZTALYCSOPORTID
|
||||
FROM T_TANEVRENDJE_OSSZES tr
|
||||
INNER JOIN T_OSZTALYCSOPORT_TANEVRENDJE ocstr ON ocstr.C_TANEVRENDJEID = tr.ID
|
||||
WHERE tr.C_OSSZESCSOPORTRAVONATKOZIK = ''F''
|
||||
AND tr.TOROLT = ''F''
|
||||
AND tr.C_NAPTIPUSA IN (1402, 7600, 7601, 7602, 7603)
|
||||
AND tr.C_TANEVID = @pTanevId
|
||||
GROUP BY ocstr.C_OSZTALYCSOPORTID
|
||||
) x ON x.C_OSZTALYCSOPORTID = ocs.Id
|
||||
WHERE ocs.IsVegzos = ''T'''
|
||||
|
||||
IF @pOsztalycsoportId IS NOT NULL OR @pOrarendiOraId IS NOT NULL BEGIN
|
||||
SET @sql += N'
|
||||
CREATE TABLE #OrarendiOra (
|
||||
Id int primary key
|
||||
);
|
||||
|
||||
--PRINT ''OrarendiOraTemp insert''
|
||||
INSERT INTO #OrarendiOra (id)
|
||||
SELECT ID
|
||||
FROM T_ORARENDIORA_OSSZES oo
|
||||
WHERE (oo.TOROLT = ''F'' OR (oo.TOROLT = ''T'' AND oo.C_KOZPONTILAGTOROLTORAGROUPID IS NOT NULL))
|
||||
' + IIF(@pOsztalycsoportId IS NULL, '', 'AND oo.C_OSZTALYCSOPORTID = @pOsztalycsoportId')
|
||||
+ IIF(@pOrarendiOraId IS NULL, '', 'AND ID = @pOrarendiOraId') + '
|
||||
'
|
||||
END
|
||||
SET @sql += N'
|
||||
CREATE TABLE #NaptariNap (
|
||||
C_TANEVID int
|
||||
,C_INTEZMENYID int
|
||||
,C_NAPDATUMA datetime
|
||||
,C_HETNAPJA int
|
||||
,C_HETIREND int
|
||||
,C_EGYEDINAP char(1) COLLATE Hungarian_CI_AI
|
||||
,C_CSENGETESIRENDID int
|
||||
,INDEX IX_001 CLUSTERED (C_TANEVID, C_HETNAPJA, C_INTEZMENYID, C_NAPDATUMA)
|
||||
)
|
||||
|
||||
INSERT INTO #NaptariNap (
|
||||
C_TANEVID
|
||||
,C_INTEZMENYID
|
||||
,C_NAPDATUMA
|
||||
,C_HETNAPJA
|
||||
,C_HETIREND
|
||||
,C_EGYEDINAP
|
||||
,C_CSENGETESIRENDID
|
||||
) SELECT
|
||||
nn.C_TANEVID
|
||||
,nn.C_INTEZMENYID
|
||||
,nn.C_NAPDATUMA
|
||||
,nn.C_HETNAPJA
|
||||
,IIF(nn.C_HETIREND = 1554, nh.C_HETIREND, nn.C_HETIREND)
|
||||
,ISNULL(tr.C_EGYEDINAP, ''F'')
|
||||
,nn.C_AKTIVCSENGETESIRENDID
|
||||
FROM T_NAPTARINAP_OSSZES nn
|
||||
LEFT JOIN T_TANEVRENDJE_OSSZES tr ON tr.C_DATUM = nn.C_NAPDATUMA AND tr.C_TANEVID = nn.C_TANEVID AND tr.C_OSSZESCSOPORTRAVONATKOZIK = ''T'' AND tr.TOROLT = ''F''
|
||||
INNER JOIN T_NAPTARIHET_OSSZES nh ON nn.C_NAPDATUMA BETWEEN C_HETKEZDONAPJA AND C_HETUTOLSONAPJA AND nn.C_TANEVID = nh.C_TANEVID
|
||||
WHERE nn.C_TANEVID = @pTanevId AND nn.TOROLT = ''F''
|
||||
AND nn.C_ORARENDINAP = ''T''
|
||||
AND nn.C_NAPDATUMA BETWEEN @pIdoszakKezdete AND @pIdoszakVege
|
||||
' + IIF(@pOrarendiOraId IS NULL, '', 'AND nn.C_HETNAPJA = (SELECT C_HETNAPJA FROM T_ORARENDIORA_OSSZES WHERE ID = @pOrarendiOraId)') + '
|
||||
|
||||
CREATE TABLE #NaptariNapOsztalycsoport (
|
||||
C_TANEVID int
|
||||
,C_INTEZMENYID int
|
||||
,C_NAPDATUMA datetime
|
||||
,C_HETNAPJA int
|
||||
,C_HETIREND int
|
||||
,C_EGYEDINAP char(1) COLLATE Hungarian_CI_AI
|
||||
,C_OSZTALYCSOPORTID int
|
||||
,C_CSENGETESIRENDID int
|
||||
,INDEX IX_001 CLUSTERED (C_TANEVID, C_HETNAPJA, C_INTEZMENYID, C_NAPDATUMA, C_OSZTALYCSOPORTID)
|
||||
)
|
||||
INSERT INTO #NaptariNapOsztalycsoport (
|
||||
C_TANEVID
|
||||
,C_INTEZMENYID
|
||||
,C_NAPDATUMA
|
||||
,C_HETNAPJA
|
||||
,C_HETIREND
|
||||
,C_EGYEDINAP
|
||||
,C_OSZTALYCSOPORTID
|
||||
,C_CSENGETESIRENDID
|
||||
) SELECT
|
||||
tr.C_TANEVID
|
||||
,tr.C_INTEZMENYID
|
||||
,tr.C_DATUM
|
||||
,tr.C_HETNAPJA
|
||||
,IIF(tr.C_HETIREND = 1554, nh.C_HETIREND, tr.C_HETIREND)
|
||||
,tr.C_EGYEDINAP
|
||||
,ocstr.C_OSZTALYCSOPORTID
|
||||
,tr.C_CSENGETESIRENDID
|
||||
FROM T_TANEVRENDJE_OSSZES tr
|
||||
INNER JOIN T_OSZTALYCSOPORT_TANEVRENDJE ocstr ON ocstr.C_TANEVRENDJEID = tr.ID
|
||||
INNER JOIN T_NAPTARIHET_OSSZES nh ON tr.C_DATUM BETWEEN C_HETKEZDONAPJA AND C_HETUTOLSONAPJA AND tr.C_TANEVID = nh.C_TANEVID
|
||||
WHERE tr.C_TANEVID = @pTanevId
|
||||
AND tr.TOROLT = ''F''
|
||||
AND tr.C_ORARENDINAP = ''T''
|
||||
AND tr.C_OSSZESCSOPORTRAVONATKOZIK = ''F''
|
||||
AND tr.C_DATUM BETWEEN @pIdoszakKezdete AND @pIdoszakVege
|
||||
' + IIF(@pOsztalycsoportId IS NULL, '', 'AND ocstr.C_OSZTALYCSOPORTID = @pOsztalycsoportId' )
|
||||
|
||||
SET @sql += N'
|
||||
CREATE TABLE #Orarend (
|
||||
Datum datetime
|
||||
,OrarendiOraId int
|
||||
,PRIMARY KEY CLUSTERED (Datum, OrarendioraId)
|
||||
);
|
||||
|
||||
--PRINT ''Napt<EFBFBD>rinapTemp insert''
|
||||
INSERT INTO #Orarend (
|
||||
Datum
|
||||
,OrarendiOraId
|
||||
)'
|
||||
SET @sql += N'
|
||||
SELECT nn.C_NAPDATUMA, oo.ID
|
||||
FROM #NaptariNap nn
|
||||
INNER JOIN T_ORARENDIORA_OSSZES oo ON oo.C_HETNAPJA = nn.C_HETNAPJA
|
||||
AND (oo.C_HETIREND = 1554 OR oo.C_HETIREND = nn.C_HETIREND)
|
||||
AND nn.C_EGYEDINAP = oo.C_EGYEDINAP
|
||||
AND (oo.TOROLT = ''F'' OR (oo.TOROLT = ''T'' AND oo.C_KOZPONTILAGTOROLTORAGROUPID IS NOT NULL))
|
||||
AND oo.C_TANEVID = nn.C_TANEVID
|
||||
AND oo.C_INTEZMENYID = nn.C_INTEZMENYID
|
||||
AND oo.C_ORAERVENYESSEGKEZDETE <= nn.C_NAPDATUMA AND oo.C_ORAERVENYESSEGVEGE > nn.C_NAPDATUMA
|
||||
INNER JOIN #Osztalycsoport ocs ON ocs.Id = oo.C_OSZTALYCSOPORTID AND ocs.IdoszakVege >= nn.C_NAPDATUMA
|
||||
'+IIF(@pOrarendiOraId IS NULL AND @pOsztalyCsoportId IS NULL, '', 'INNER JOIN #OrarendiOra oo2 ON oo2.Id = oo.ID') + '
|
||||
WHERE NOT EXISTS (
|
||||
SELECT 1 FROM T_TANEVRENDJE_OSSZES tr2
|
||||
INNER JOIN T_OSZTALYCSOPORT_TANEVRENDJE ocstr ON tr2.ID = ocstr.C_TANEVRENDJEID
|
||||
WHERE tr2.C_OSSZESCSOPORTRAVONATKOZIK = ''F'' AND tr2.TOROLT = ''F''
|
||||
AND ocs.Id = ocstr.C_OSZTALYCSOPORTID AND nn.C_NAPDATUMA = tr2.C_DATUM)
|
||||
AND (EXISTS (SELECT 1 FROM T_CSENGETESIRENDORA_OSSZES csro WHERE csro.C_CSENGETESIRENDID = ISNULL(nn.C_CSENGETESIRENDID, oo.C_CSENGETESIRENDID) AND oo.C_ORASZAM = csro.C_ORASZAM AND csro.TOROLT = ''F'') OR oo.C_CSENGETESIRENDID IS NULL)
|
||||
|
||||
UNION ALL
|
||||
|
||||
SELECT nn.C_NAPDATUMA, oo.ID
|
||||
FROM #NaptariNap nn
|
||||
INNER JOIN T_ORARENDIORA_OSSZES oo ON oo.C_HETNAPJA = nn.C_HETNAPJA
|
||||
AND (oo.C_HETIREND = 1554 OR oo.C_HETIREND = nn.C_HETIREND)
|
||||
AND nn.C_EGYEDINAP = oo.C_EGYEDINAP
|
||||
AND (oo.TOROLT = ''F'' OR (oo.TOROLT = ''T'' AND oo.C_KOZPONTILAGTOROLTORAGROUPID IS NOT NULL))
|
||||
AND oo.C_TANEVID = nn.C_TANEVID
|
||||
AND oo.C_INTEZMENYID = nn.C_INTEZMENYID
|
||||
AND oo.C_ORAERVENYESSEGKEZDETE = nn.C_NAPDATUMA AND oo.C_ORAERVENYESSEGVEGE = nn.C_NAPDATUMA
|
||||
INNER JOIN #Osztalycsoport ocs ON ocs.Id = oo.C_OSZTALYCSOPORTID AND ocs.IdoszakVege >= nn.C_NAPDATUMA
|
||||
'+IIF(@pOrarendiOraId IS NULL AND @pOsztalyCsoportId IS NULL, '', 'INNER JOIN #OrarendiOra oo2 ON oo2.Id = oo.ID') + '
|
||||
WHERE NOT EXISTS (
|
||||
SELECT 1 FROM T_TANEVRENDJE_OSSZES tr2
|
||||
INNER JOIN T_OSZTALYCSOPORT_TANEVRENDJE ocstr ON tr2.ID = ocstr.C_TANEVRENDJEID
|
||||
WHERE tr2.C_OSSZESCSOPORTRAVONATKOZIK = ''F'' AND tr2.TOROLT = ''F''
|
||||
AND ocs.Id = ocstr.C_OSZTALYCSOPORTID AND nn.C_NAPDATUMA = tr2.C_DATUM)
|
||||
AND (EXISTS (SELECT 1 FROM T_CSENGETESIRENDORA_OSSZES csro WHERE csro.C_CSENGETESIRENDID = ISNULL(nn.C_CSENGETESIRENDID, oo.C_CSENGETESIRENDID) AND oo.C_ORASZAM = csro.C_ORASZAM AND csro.TOROLT = ''F'') OR oo.C_CSENGETESIRENDID IS NULL)
|
||||
|
||||
UNION ALL'
|
||||
|
||||
SET @sql += N'
|
||||
SELECT nn.C_NAPDATUMA, oo.ID
|
||||
FROM #NaptariNapOsztalycsoport nn
|
||||
INNER JOIN T_ORARENDIORA_OSSZES oo ON oo.C_HETNAPJA = nn.C_HETNAPJA
|
||||
AND (oo.C_HETIREND = 1554 OR oo.C_HETIREND = nn.C_HETIREND)
|
||||
AND nn.C_EGYEDINAP = oo.C_EGYEDINAP
|
||||
AND (oo.TOROLT = ''F'' OR (oo.TOROLT = ''T'' AND oo.C_KOZPONTILAGTOROLTORAGROUPID IS NOT NULL))
|
||||
AND oo.C_TANEVID = nn.C_TANEVID
|
||||
AND oo.C_INTEZMENYID = nn.C_INTEZMENYID
|
||||
AND oo.C_ORAERVENYESSEGKEZDETE <= nn.C_NAPDATUMA AND oo.C_ORAERVENYESSEGVEGE > nn.C_NAPDATUMA
|
||||
AND oo.C_OSZTALYCSOPORTID = nn.C_OSZTALYCSOPORTID
|
||||
INNER JOIN #Osztalycsoport ocs ON ocs.Id = nn.C_OSZTALYCSOPORTID AND ocs.IdoszakVege >= nn.C_NAPDATUMA
|
||||
'+IIF(@pOrarendiOraId IS NULL AND @pOsztalyCsoportId IS NULL, '', 'INNER JOIN #OrarendiOra oo2 ON oo2.Id = oo.ID') + '
|
||||
WHERE (EXISTS (SELECT 1 FROM T_CSENGETESIRENDORA_OSSZES csro WHERE csro.C_CSENGETESIRENDID = ISNULL(nn.C_CSENGETESIRENDID, oo.C_CSENGETESIRENDID) AND oo.C_ORASZAM = csro.C_ORASZAM AND csro.TOROLT = ''F'') OR oo.C_CSENGETESIRENDID IS NULL)
|
||||
|
||||
UNION ALL
|
||||
|
||||
SELECT nn.C_NAPDATUMA, oo.ID
|
||||
FROM #NaptariNapOsztalycsoport nn
|
||||
INNER JOIN T_ORARENDIORA_OSSZES oo ON oo.C_HETNAPJA = nn.C_HETNAPJA
|
||||
AND (oo.C_HETIREND = 1554 OR oo.C_HETIREND = nn.C_HETIREND)
|
||||
AND nn.C_EGYEDINAP = oo.C_EGYEDINAP
|
||||
AND (oo.TOROLT = ''F'' OR (oo.TOROLT = ''T'' AND oo.C_KOZPONTILAGTOROLTORAGROUPID IS NOT NULL))
|
||||
AND oo.C_TANEVID = nn.C_TANEVID
|
||||
AND oo.C_INTEZMENYID = nn.C_INTEZMENYID
|
||||
AND oo.C_ORAERVENYESSEGKEZDETE = nn.C_NAPDATUMA AND oo.C_ORAERVENYESSEGVEGE = nn.C_NAPDATUMA
|
||||
AND oo.C_OSZTALYCSOPORTID = nn.C_OSZTALYCSOPORTID
|
||||
INNER JOIN #Osztalycsoport ocs ON ocs.Id = nn.C_OSZTALYCSOPORTID AND ocs.IdoszakVege >= nn.C_NAPDATUMA
|
||||
'+IIF(@pOrarendiOraId IS NULL AND @pOsztalyCsoportId IS NULL, '', 'INNER JOIN #OrarendiOra oo2 ON oo2.Id = oo.ID') + '
|
||||
WHERE (EXISTS (SELECT 1 FROM T_CSENGETESIRENDORA_OSSZES csro WHERE csro.C_CSENGETESIRENDID = ISNULL(nn.C_CSENGETESIRENDID, oo.C_CSENGETESIRENDID) AND oo.C_ORASZAM = csro.C_ORASZAM AND csro.TOROLT = ''F'') OR oo.C_CSENGETESIRENDID IS NULL)
|
||||
'
|
||||
|
||||
SET @sql += N'
|
||||
--PRINT ''MERGE''
|
||||
MERGE T_ORAREND_OSSZES trg
|
||||
USING #Orarend src ON
|
||||
trg.C_ORARENDIORAID = src.OrarendioraId AND src.Datum = trg.C_DATUM
|
||||
WHEN NOT MATCHED BY TARGET THEN
|
||||
INSERT (
|
||||
C_ORARENDIORAID
|
||||
,C_DATUM
|
||||
,C_TANEVID
|
||||
,C_INTEZMENYID
|
||||
) VALUES (
|
||||
src.OrarendiOraId
|
||||
,src.Datum
|
||||
,@pTanevId
|
||||
,@pIntezmenyId
|
||||
)
|
||||
WHEN NOT MATCHED BY SOURCE AND trg.C_TANEVID = @pTanevId AND trg.C_DATUM BETWEEN @pIdoszakKezdete AND @pIdoszakVege
|
||||
' + IIF(@pOrarendiOraId IS NULL AND @pOsztalyCsoportId IS NULL, '', 'AND trg.C_ORARENDIORAID IN (SELECT Id FROM #OrarendiOra)') + '
|
||||
THEN
|
||||
DELETE
|
||||
--OUTPUT $action, DELETED.C_DATUM, DELETED.C_ORARENDIORAID, INSERTED.C_DATUM, INSERTED.C_ORARENDIORAID
|
||||
;
|
||||
'
|
||||
--select @sql
|
||||
EXEC sp_executesql @sql,N'
|
||||
@pIntezmenyId int
|
||||
,@pTanevId int
|
||||
,@pIdoszakKezdete datetime
|
||||
,@pIdoszakVege datetime
|
||||
,@pOrarendiOraId int
|
||||
,@pOsztalycsoportId int
|
||||
,@aktivCsengetesirend int'
|
||||
,@pIntezmenyId = @pIntezmenyId
|
||||
,@pTanevId = @pTanevId
|
||||
,@pIdoszakKezdete = @pIdoszakKezdete
|
||||
,@pIdoszakVege = @pIdoszakVege
|
||||
,@pOrarendiOraId = @pOrarendiOraId
|
||||
,@pOsztalycsoportId = @pOsztalycsoportId
|
||||
,@aktivCsengetesirend = @aktivCsengetesirend;
|
||||
|
||||
EXEC dbo.uspGenerateTeljesOrarend @pIntezmenyId, @pTanevId;
|
||||
END
|
||||
GO
|
||||
|
||||
exec dev.uspRegisterSPFN 'uspGenerateOrarend', 1;
|
||||
exec dev.uspCreateSchemaSPFN 'uspGenerateOrarend';
|
||||
GO
|
@@ -0,0 +1,62 @@
|
||||
DROP PROCEDURE IF EXISTS dev.sp_Global_GenerateAsyncAuditTriggerAll
|
||||
GO
|
||||
|
||||
CREATE PROCEDURE dev.sp_Global_GenerateAsyncAuditTriggerAll
|
||||
@disabled bit = 0
|
||||
AS
|
||||
BEGIN
|
||||
DECLARE tableCursor CURSOR LOCAL FOR
|
||||
SELECT DISTINCT TABLE_NAME
|
||||
FROM INFORMATION_SCHEMA.COLUMNS
|
||||
WHERE COLUMN_NAME IN ('CREATOR', 'MODIFIER')
|
||||
AND TABLE_NAME NOT IN (
|
||||
'T_ENTITYHISTORY'
|
||||
,'T_ENTITYATTRIBUTEHISTORY'
|
||||
,'T_ENTITYATTRIBUTEHISTORY_ARCHIVE'
|
||||
,'T_LOG'
|
||||
,'T_GLOBALLOCK'
|
||||
,'T_OLDALLATOGATOTTSAG'
|
||||
,'T_FELHASZNALOBELEPESTORTENET'
|
||||
,'T_EVFOLYAMTIPUS_OKTATASINEVELE'
|
||||
,'T_TELEPULES'
|
||||
,'T_TANTARGYNEVHEZKATEGORIA'
|
||||
,'T_MOBILDBINFO'
|
||||
,'T_LOGLEVELTYPE'
|
||||
,'T_FENNTARTO'
|
||||
,'T_LOGEVENTTYPE'
|
||||
,'T_DASHBOARDUZENET'
|
||||
,'T_DASHBOARDUZENETKATEGORIA'
|
||||
,'T_AMITANTARGYSABLON'
|
||||
,'T_AMITTFSABLON'
|
||||
,'T_ADATTISZTITASINDIKATOR'
|
||||
,'T_DASHBOARDUZENETINTEZMENY'
|
||||
,'T_ORAREND'
|
||||
,'T_TANULOTANTARGYATLAG'
|
||||
,'T_CONFIGTIPUS'
|
||||
,'T_INTEZMENYCONFIG'
|
||||
,'T_SZIRSTATKONYVTARKATEGORIA'
|
||||
,'T_ORARENDTELJES'
|
||||
)
|
||||
AND TABLE_NAME IN (
|
||||
SELECT t.name
|
||||
FROM sys.tables t
|
||||
INNER JOIN sys.schemas s ON s.schema_id = t.schema_id
|
||||
WHERE s.name ='dbo'
|
||||
)
|
||||
|
||||
DECLARE @tableName nvarchar(50)
|
||||
|
||||
OPEN tableCursor
|
||||
FETCH NEXT FROM tableCursor INTO @tableName
|
||||
|
||||
WHILE @@FETCH_STATUS = 0 BEGIN
|
||||
|
||||
EXEC dev.sp_Global_GenerateAsyncAuditTrigger @tableName, @disabled
|
||||
|
||||
FETCH NEXT FROM tableCursor INTO @tableName
|
||||
END
|
||||
CLOSE tableCursor
|
||||
DEALLOCATE tableCursor
|
||||
END
|
||||
GO
|
||||
|
Reference in New Issue
Block a user