113 lines
5.1 KiB
Transact-SQL
113 lines
5.1 KiB
Transact-SQL
-- ===================================================================================================
|
|
-- KIRSTAT Tanuló - (Gondviselő) lakóhely
|
|
-- ===================================================================================================
|
|
-- 7. MUNKALAP - A04T23 - A GYERMEKEK, TANULÓK SZÁMÁNAK NYITÓADATAI A SZÜLŐ (GONDVISELŐ) LAKÓHELYE SZERINT
|
|
DROP PROCEDURE IF EXISTS uspKIRstat_TanuloLakohely
|
|
GO
|
|
|
|
CREATE PROCEDURE uspKIRstat_TanuloLakohely
|
|
@pFeladatellatasiHelyId int
|
|
,@pTanevId int
|
|
,@pIsKirstat bit = 1
|
|
AS
|
|
BEGIN
|
|
SET NOCOUNT ON;
|
|
|
|
DECLARE @statDatum datetime
|
|
SET @statDatum = (SELECT LEFT(C_NEV, 4) FROM T_TANEV WHERE ID = @pTanevId) + IIF(@pIsKirstat = 1, '1001', '1008')
|
|
|
|
SELECT
|
|
xx.Id AS TanuloId
|
|
,xx.TanuloNev
|
|
,IIF(xx.Megye = N'Főváros', N'Budapest', xx.Megye) AS Megye
|
|
,xx.KettosMagyarAllampolgar
|
|
,xx.MagyarTartozkodasiHely
|
|
,ocs.C_EVFOLYAMTIPUSA
|
|
,d.C_NAME_4 AS Evfolyam
|
|
FROM (
|
|
|
|
-- Kiskorú
|
|
SELECT
|
|
fh.ID AS Id
|
|
,fh.C_NYOMTATASINEV AS TanuloNev
|
|
,IIF(COALESCE(gCim.C_ORSZAG, tCim.C_ORSZAG, 765) = 765, ISNULL(gCim.C_MEGYE, tCim.C_MEGYE), 'Külföldi') AS Megye
|
|
,IIF((fh.C_ALLAMPOLGARSAGA = 217 OR fh.C_ALLAMPOLGARSAGA2 = 217) AND fh.C_ALLAMPOLGARSAGA2 IS NOT NULL, 1, 0) AS KettosMagyarAllampolgar
|
|
,IIF(COALESCE(gCim.C_ORSZAG, tCim.C_ORSZAG, 765) = 765, NULL, IIF(gCim.C_GONDVISELOID IS NOT NULL, ISNULL(gCim.MO, 0), ISNULL(tCim.MO, 0))) AS MagyarTartozkodasiHely
|
|
,gCim.ID AS gCim
|
|
,tCim.ID AS tCim
|
|
FROM T_FELHASZNALO_OSSZES fh
|
|
INNER JOIN T_TANULO_OSSZES t ON fh.ID = t.ID
|
|
OUTER APPLY (
|
|
|
|
SELECT TOP(1) c.C_GONDVISELOID, g.C_TANULOID, c.C_ORSZAG, v.C_MEGYE, v.C_TELEPULESNEV, c.C_IRANYITOSZAM, TartHely.MO, c.ID
|
|
FROM T_GONDVISELO_OSSZES g
|
|
INNER JOIN T_CIM_OSSZES c ON g.ID = c.C_GONDVISELOID AND g.C_TANULOID = fh.ID
|
|
LEFT JOIN T_TELEPULES v ON v.C_IRANYITOSZAM = c.C_IRANYITOSZAM
|
|
OUTER APPLY (SELECT TOP(1) 1 AS MO FROM T_CIM_OSSZES x WHERE x.C_GONDVISELOID = g.ID AND x.C_CIMTIPUSA = 909 AND x.TOROLT = 'F' AND x.C_ORSZAG = 765) TartHely
|
|
WHERE g.C_ISCSOKKENTETTGONDVISELO = 'F'
|
|
AND c.TOROLT = 'F'
|
|
AND g.TOROLT = 'F'
|
|
ORDER BY
|
|
g.C_ISTORVENYESKEPVISELO DESC
|
|
,CASE g.C_ROKONSAGFOKA WHEN 973 THEN 1 WHEN 974 THEN 2 ELSE 3 END
|
|
,g.CREATED DESC
|
|
,c.C_ALAPERTELMEZETT DESC
|
|
,IIF(c.C_VAROS = v.C_TELEPULESNEV, 1, 2)
|
|
|
|
) gCim
|
|
OUTER APPLY (
|
|
|
|
SELECT TOP(1) c.C_FELHASZNALOID AS C_TANULOID, c.C_ORSZAG, v.C_MEGYE, v.C_TELEPULESNEV, c.C_IRANYITOSZAM, TartHely.MO, c.ID
|
|
FROM T_CIM_OSSZES c
|
|
LEFT JOIN T_TELEPULES v ON v.C_IRANYITOSZAM = c.C_IRANYITOSZAM
|
|
OUTER APPLY (SELECT TOP(1) 1 AS MO FROM T_CIM_OSSZES x WHERE x.C_FELHASZNALOID = c.C_FELHASZNALOID AND x.C_GONDVISELOID IS NULL AND x.C_CIMTIPUSA = 909 AND x.TOROLT = 'F' AND x.C_ORSZAG = 765) TartHely
|
|
WHERE c.C_FELHASZNALOID = fh.ID
|
|
AND c.C_GONDVISELOID IS NULL
|
|
AND c.C_ALAPERTELMEZETT = 'T'
|
|
|
|
) tCim
|
|
WHERE fh.C_TANEVID = @pTanevId
|
|
AND fh.TOROLT = 'F'
|
|
AND fh.C_SZULETESIDATUM >= DATEADD(year, -18, @statDatum)
|
|
|
|
UNION ALL
|
|
|
|
-- Nagykorú
|
|
SELECT
|
|
fh.ID AS Id
|
|
,fh.C_NYOMTATASINEV AS TanuloNev
|
|
,IIF(tCim.C_ORSZAG = 765, tCim.C_MEGYE, IIF(tCim.C_ORSZAG IS NULL, NULL, 'Külföldi')) AS Megye
|
|
,IIF((fh.C_ALLAMPOLGARSAGA = 217 OR fh.C_ALLAMPOLGARSAGA2 = 217) AND fh.C_ALLAMPOLGARSAGA2 IS NOT NULL, 1, 0) AS KettosMagyarAllampolgar
|
|
,IIF(ISNULL(tCim.C_ORSZAG, 765) = 765, NULL, ISNULL(tCim.MO, 0)) AS MagyarTartozkodasiHely
|
|
,NULL AS gCim
|
|
,tCim.ID AS tCim
|
|
FROM T_FELHASZNALO_OSSZES fh
|
|
INNER JOIN T_TANULO_OSSZES t ON fh.ID = t.ID
|
|
OUTER APPLY (
|
|
SELECT TOP(1) c.C_FELHASZNALOID AS C_TANULOID, c.C_ORSZAG, v.C_MEGYE, v.C_TELEPULESNEV, c.C_IRANYITOSZAM, TartHely.MO, c.ID
|
|
FROM T_CIM c
|
|
INNER JOIN T_TELEPULES v ON v.C_IRANYITOSZAM = c.C_IRANYITOSZAM
|
|
OUTER APPLY (SELECT TOP(1) 1 AS MO FROM T_CIM_OSSZES x WHERE x.C_FELHASZNALOID = c.C_FELHASZNALOID AND x.C_GONDVISELOID IS NULL AND x.C_CIMTIPUSA = 909 AND x.TOROLT = 'F' AND x.C_ORSZAG = 765) TartHely
|
|
WHERE c.C_FELHASZNALOID = fh.ID
|
|
AND c.C_GONDVISELOID IS NULL
|
|
AND c.C_ALAPERTELMEZETT = 'T'
|
|
) tCim
|
|
WHERE fh.C_TANEVID = @pTanevId
|
|
AND fh.TOROLT = 'F'
|
|
AND fh.C_SZULETESIDATUM < DATEADD(year, -18, @statDatum)
|
|
|
|
) xx
|
|
INNER JOIN T_TANULOCSOPORT_OSSZES tcs ON tcs.C_TANULOID = xx.ID AND tcs.C_BELEPESDATUM <= @statDatum AND (tcs.C_KILEPESDATUM > @statDatum OR tcs.C_KILEPESDATUM IS NULL)
|
|
INNER JOIN T_OSZTALYCSOPORT_OSSZES ocs ON ocs.ID = tcs.C_OSZTALYCSOPORTID AND ocs.C_FELADATELLATASIHELYID = @pFeladatellatasiHelyId
|
|
INNER JOIN T_TANULOTANUGYIADATOK_OSSZES tta ON tta.C_TANULOCSOPORTID = tcs.ID
|
|
INNER JOIN T_DICTIONARYITEMBASE_OSSZES d ON d.ID = ocs.C_EVFOLYAMTIPUSA AND d.C_TANEVID = ocs.C_TANEVID
|
|
WHERE tta.C_JOGVISZONYATSZUNETELTETO = 'F'
|
|
AND tta.C_VENDEG = 'F'
|
|
AND tcs.TOROLT = 'F'
|
|
AND tta.TOROLT = 'F'
|
|
AND ocs.TOROLT = 'F'
|
|
AND d.TOROLT = 'F'
|
|
ORDER BY xx.Megye DESC
|
|
END
|
|
GO
|
|
|