85 lines
No EOL
3.3 KiB
Transact-SQL
85 lines
No EOL
3.3 KiB
Transact-SQL
|
|
CREATE OR ALTER PROCEDURE dbo.uspApaczaiMentorAdatok(
|
|
@IntezmenyGUID uniqueidentifier,
|
|
@MentorIDPEgyediAzonosito uniqueidentifier,
|
|
@TanevSorszam int = null
|
|
)
|
|
AS
|
|
DECLARE @IntezmenyID int;
|
|
DECLARE @TanevID int;
|
|
|
|
SELECT @IntezmenyID = i.ID, @TanevID = t.ID
|
|
FROM T_INTEZMENY i
|
|
INNER JOIN T_TANEV t ON t.C_INTEZMENYID = i.ID AND t.TOROLT = 'F'
|
|
WHERE i.TOROLT = 'F'
|
|
AND i.C_GUID = @IntezmenyGUID
|
|
AND (t.C_AKTIV = 'T' OR t.C_SORSZAM = @TanevSorszam);
|
|
|
|
IF @@ROWCOUNT = 0 THROW 50001, N'Intézmény, tanév nem található vagy a tanév nem aktív', 0;
|
|
|
|
SELECT
|
|
cim.C_VAROS AS AllandoLakcim_Telepules,
|
|
cim.C_IRANYITOSZAM AS AllandoLakcim_Iranyitoszam,
|
|
CONCAT(cim.C_KOZTERULET, ' ', cim.C_KOZTERULETJELLEGENEV + ' ', cim.C_HAZSZAM, ' ' + cim.C_LEPCSOHAZ, ' ' + cim.C_EMELET, ' ' + cim.C_AJTO) AS AllandoLakcim_Cim,
|
|
email.C_EMAILCIM AS EmailCim,
|
|
tel.C_TELEFONSZAM AS TelefonSzam,
|
|
a.C_BANKSZAMLASZAM AS Bankszamlaszam,
|
|
a.C_BANKSZAMLATULAJNEVE AS BankszamlaTulajdonos,
|
|
d1.C_NAME AS BankszamlaTulajdonosTipus,
|
|
IIF(m.C_NYUGDIJAS = 'T', 1, 0) AS Nyudijas,
|
|
m.C_NYUGDIJKEZDET AS NyugdijKezdet,
|
|
d2.C_NAME AS NyugdijTipus
|
|
FROM T_FELHASZNALO f
|
|
INNER JOIN T_ALKALMAZOTT a on a.ID = f.ID
|
|
INNER JOIN T_MUNKAUGYIADATOK m on m.C_ALKALMAZOTTID = a.ID AND m.TOROLT = 'F'
|
|
LEFT JOIN T_DICTIONARYITEMBASE d1 on d1.ID = a.C_BANKSZAMLATULAJDONOSTIPUS AND d1.C_TANEVID = a.C_ALTANEVID AND d1.C_TYPE = 'BankszamlaTulajdonosTipus' AND d1.TOROLT = 'F'
|
|
LEFT JOIN T_DICTIONARYITEMBASE d2 on d2.ID = m.C_NYUGDIJTIPUS AND d2.C_TANEVID = a.C_ALTANEVID AND d2.C_TYPE = 'NyugdijTipus' AND d2.TOROLT = 'F'
|
|
OUTER APPLY (
|
|
SELECT TOP 1 *,
|
|
CASE WHEN c.C_CIMTIPUSA = 907 AND c.C_ALAPERTELMEZETT = 'T' THEN 1 -- Állandó lakcím, alapértelemezett
|
|
WHEN c.C_CIMTIPUSA = 907 AND c.C_ALAPERTELMEZETT = 'F' THEN 2 -- Állandó lakcím, nem alapértelemezett
|
|
WHEN c.C_ALAPERTELMEZETT = 'T' THEN 3 -- Bármilyen cím, alapértelemezett
|
|
WHEN c.C_ALAPERTELMEZETT = 'F' THEN 4 -- Bármilyen cím, nem alapértelemezett
|
|
ELSE 5
|
|
END AS Prioritas
|
|
FROM T_CIM c
|
|
WHERE c.C_INTEZMENYID = f.C_INTEZMENYID
|
|
AND c.C_TANEVID = f.C_TANEVID
|
|
AND c.C_FELHASZNALOID = f.ID
|
|
AND c.C_GONDVISELOID IS NULL
|
|
AND c.TOROLT = 'F'
|
|
ORDER BY Prioritas
|
|
) cim
|
|
OUTER APPLY (
|
|
SELECT TOP 1 *,
|
|
CASE WHEN e.C_EMAILTIPUSA = 1025 AND e.C_ALAPERTELMEZETT = 'T' THEN 1 -- Hivatalos, alapértelmezett
|
|
WHEN e.C_EMAILTIPUSA = 1025 AND e.C_ALAPERTELMEZETT = 'F' THEN 2 -- Hivatalos, nem alapértelmezett
|
|
WHEN e.C_ALAPERTELMEZETT = 'T' THEN 3
|
|
WHEN e.C_ALAPERTELMEZETT = 'F' THEN 4
|
|
ELSE 5
|
|
END AS Prioritas
|
|
FROM T_EMAIL e
|
|
WHERE e.C_INTEZMENYID = f.C_INTEZMENYID
|
|
AND e.C_TANEVID = f.C_TANEVID
|
|
AND e.C_FELHASZNALOID = f.ID
|
|
AND e.C_GONDVISELOID IS NULL
|
|
AND e.TOROLT = 'F'
|
|
ORDER BY Prioritas
|
|
) email
|
|
OUTER APPLY (
|
|
SELECT TOP 1 *
|
|
FROM T_TELEFON t
|
|
WHERE t.C_INTEZMENYID = f.C_INTEZMENYID
|
|
AND t.C_TANEVID = f.C_TANEVID
|
|
AND t.C_FELHASZNALOID = f.ID
|
|
AND t.C_GONDVISELOID IS NULL
|
|
AND t.TOROLT = 'F'
|
|
ORDER BY t.C_ALAPERTELMEZETT DESC
|
|
) tel
|
|
WHERE f.C_INTEZMENYID = @IntezmenyID
|
|
AND f.C_TANEVID = @TanevID
|
|
AND f.C_IDPEGYEDIAZONOSITO = @MentorIDPEgyediAzonosito
|
|
AND f.TOROLT = 'F';
|
|
|
|
IF @@ROWCOUNT = 0 THROW 50002, N'Felhasználó nem található', 0;
|
|
GO |