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

72 lines
No EOL
3.5 KiB
Transact-SQL

DROP FUNCTION IF EXISTS fnGetDokumentumTanuloOrGondviseloCim
GO
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE FUNCTION fnGetDokumentumTanuloOrGondviseloCim (@TanuloOrGondviselo BIT, @pTanevId INT, @pOsztalyId INT, @isAlapertelmezettTanuloCim BIT = NULL, @isAlapertelmezettGondviseloCim BIT = NULL)
RETURNS @result TABLE
(
TanuloId INT,
Cim NVARCHAR(MAX),
CimTipusa INT,
GondviseloId INT,
IsAlapertelmezett CHAR
)
AS
BEGIN
DECLARE @Magyarorszagmegnevezes NVARCHAR(20) = (SELECT dib_MO.C_NAME FROM T_DICTIONARYITEMBASE_OSSZES dib_MO WHERE dib_MO.ID = 765 AND dib_MO.C_TANEVID = @pTanevId AND dib_MO.TOROLT = 'F')
IF @TanuloOrGondviselo = 0
BEGIN
INSERT INTO @result(TanuloId, Cim, CimTipusa, GondviseloId, IsAlapertelmezett)
SELECT
Tanulo.C_TANULOID AS TanuloId
,ISNULL(dib_orszag.C_NAME,@Magyarorszagmegnevezes) + ', '
+ cim.C_IRANYITOSZAM + ' ' + cim.C_VAROS + ', ' + cim.C_KOZTERULET + ' ' + cim.C_KOZTERULETJELLEGENEV + ' ' + cim.C_HAZSZAM + IIF(RIGHT(C_HAZSZAM, 1) = '.', '', '.') + ' ' + ISNULL(cim.C_EMELET + '/', '') + ISNULL(cim.C_AJTO, '') AS Cim
,cim.C_CIMTIPUSA AS CimTipusa
,cim.C_GONDVISELOID AS GondviseloId
,cim.C_ALAPERTELMEZETT
FROM T_TANULOCSOPORT_OSSZES Tanulo
INNER JOIN T_CIM_OSSZES cim on cim.C_FELHASZNALOID = Tanulo.C_TANULOID AND cim.C_GONDVISELOID IS NULL AND cim.TOROLT = 'F'
INNER JOIN T_DICTIONARYITEMBASE_OSSZES cimTipusa on cimTipusa.ID = cim.C_CIMTIPUSA AND cimTipusa.C_TANEVID = @pTanevId
LEFT JOIN T_DICTIONARYITEMBASE_OSSZES dib_orszag on dib_orszag.ID = cim.C_ORSZAG AND dib_orszag.C_TANEVID = @pTanevId AND dib_orszag.TOROLT = 'F'
WHERE Tanulo.C_TANEVID = @pTanevId
AND Tanulo.C_OSZTALYCSOPORTID = @pOsztalyId
AND Tanulo.TOROLT = 'F'
AND (@isAlapertelmezettTanuloCim IS NULL OR (@isAlapertelmezettTanuloCim = 0 AND cim.C_ALAPERTELMEZETT = 'F') OR (@isAlapertelmezettTanuloCim = 1 AND cim.C_ALAPERTELMEZETT = 'T'))
ORDER BY cimTipusa.C_NAME ASC, cim.C_ALAPERTELMEZETT DESC
END
ELSE IF @TanuloOrGondviselo = 1
BEGIN
INSERT INTO @result(TanuloId, Cim, CimTipusa, GondviseloId, IsAlapertelmezett)
SELECT
Tanulo.C_TANULOID AS TanuloId
,ISNULL(dib_orszag.C_NAME,@Magyarorszagmegnevezes) + ', '
+ cim.C_IRANYITOSZAM + ' ' + cim.C_VAROS + ', ' + cim.C_KOZTERULET + ' ' + cim.C_KOZTERULETJELLEGENEV + ' ' + cim.C_HAZSZAM + IIF(RIGHT(C_HAZSZAM, 1) = '.', '', '.') + ' ' + ISNULL(cim.C_EMELET + '/', '') + ISNULL(cim.C_AJTO, '') AS Cim
,cim.C_CIMTIPUSA AS CimTipusa
,cim.C_GONDVISELOID AS GondviseloId
,cim.C_ALAPERTELMEZETT
FROM T_TANULOCSOPORT_OSSZES Tanulo
INNER JOIN T_GONDVISELO_OSSZES Gondviselo ON Gondviselo.C_TANULOID = Tanulo.C_TANULOID
INNER JOIN T_CIM_OSSZES cim ON cim.C_GONDVISELOID = Gondviselo.ID AND cim.TOROLT = 'F'
INNER JOIN T_DICTIONARYITEMBASE_OSSZES cimTipusa on cimTipusa.ID = cim.C_CIMTIPUSA AND cimTipusa.C_TANEVID = @pTanevId
LEFT JOIN T_DICTIONARYITEMBASE_OSSZES dib_orszag on dib_orszag.ID = cim.C_ORSZAG AND dib_orszag.C_TANEVID = @pTanevId AND dib_orszag.TOROLT = 'F'
WHERE Tanulo.C_TANEVID = @pTanevId
AND Tanulo.C_OSZTALYCSOPORTID = @pOsztalyId
AND Tanulo.TOROLT = 'F'
AND (@isAlapertelmezettGondviseloCim IS NULL OR (@isAlapertelmezettGondviseloCim = 0 AND cim.C_ALAPERTELMEZETT = 'F') OR (@isAlapertelmezettGondviseloCim = 1 AND cim.C_ALAPERTELMEZETT = 'T'))
ORDER BY cimTipusa.C_NAME ASC, cim.C_ALAPERTELMEZETT DESC
END
RETURN
END