100 lines
No EOL
4.7 KiB
SQL
100 lines
No EOL
4.7 KiB
SQL
DROP TABLE IF EXISTS #allAddresses
|
|
CREATE TABLE #allAddresses (GenericRn int,TipusRn int,CreatedRn int,C_FELHASZNALOID int,CREATED datetime,C_CIMTIPUSA int,C_CIMID int)
|
|
INSERT INTO #allAddresses
|
|
SELECT
|
|
ROW_NUMBER() OVER (PARTITION BY C_FELHASZNALOID ORDER BY c.CREATED DESC) as GenericRn
|
|
,ROW_NUMBER() OVER (PARTITION BY C_FELHASZNALOID,c.C_CIMTIPUSA ORDER BY c.CREATED DESC) as TipusRn
|
|
,ROW_NUMBER() OVER (PARTITION BY C_FELHASZNALOID ORDER BY c.CREATED DESC) as CreatedRn
|
|
,C_FELHASZNALOID
|
|
,c.CREATED
|
|
,c.C_CIMTIPUSA
|
|
,c.ID as C_CIMID
|
|
FROM T_TANULO t
|
|
INNER JOIN T_CIM c ON c.C_FELHASZNALOID = t.ID AND c.TOROLT='F' AND c.C_GONDVISELOID IS NULL
|
|
WHERE t.TOROLT='F'
|
|
AND NOT EXISTS(SELECT 1 FROM T_CIM WHERE C_FELHASZNALOID = t.ID AND TOROLT='F' AND C_ALAPERTELMEZETT='T' AND C_GONDVISELOID IS NULL)
|
|
ORDER BY C_FELHASZNALOID,c.CREATED
|
|
/*==================================================================
|
|
--Ha valakinek egy címe van tanulónál, akkor legyen alapértelmezett.
|
|
====================================================================*/
|
|
DROP TABLE IF EXISTS #onlyOneAddress
|
|
CREATE TABLE #onlyOneAddress (C_CIMID int,C_FELHASZNALOID int)
|
|
INSERT INTO #onlyOneAddress
|
|
SELECT C_CIMID,C_FELHASZNALOID from #allAddresses a
|
|
WHERE NOT EXISTS (SELECT 1 FROM #allAddresses WHERE C_FELHASZNALOID = a.C_FELHASZNALOID AND GenericRn>1)
|
|
DELETE FROM #allAddresses WHERE C_CIMID IN (SELECT C_CIMID FROM #onlyOneAddress)
|
|
/*==================================================================
|
|
--Ha több van, akkor a tartózkodási helye legyen az alapértelmezett.
|
|
--909 Tartózkodási hely
|
|
--907 Állandó lakcím
|
|
====================================================================*/
|
|
DROP TABLE IF EXISTS #haveTartHely
|
|
CREATE TABLE #haveTartHely (C_CIMID int,C_FELHASZNALOID int)
|
|
INSERT INTO #haveTartHely
|
|
select C_CIMID,C_FELHASZNALOID from #allAddresses a
|
|
WHERE a.C_CIMTIPUSA = 909 AND a.TipusRn = 1
|
|
DELETE FROM #allAddresses WHERE C_FELHASZNALOID IN (SELECT C_FELHASZNALOID FROM #haveTartHely)
|
|
/*==================================================================
|
|
--Ha nincs tartózkodási helye, akkor az állandó lakcíme.
|
|
====================================================================*/
|
|
DROP TABLE IF EXISTS #haveAllando
|
|
CREATE TABLE #haveAllando (C_CIMID int,C_FELHASZNALOID int)
|
|
INSERT INTO #haveAllando
|
|
SELECT C_CIMID,C_FELHASZNALOID from #allAddresses a
|
|
WHERE a.C_CIMTIPUSA = 907 AND a.TipusRn = 1
|
|
DELETE FROM #allAddresses WHERE C_FELHASZNALOID IN (SELECT C_FELHASZNALOID FROM #haveAllando)
|
|
/*==================================================================
|
|
--Ha ez sincs, akkor pedig a legújabb.
|
|
====================================================================*/
|
|
DROP TABLE IF EXISTS #newest
|
|
CREATE TABLE #newest (C_CIMID int,C_FELHASZNALOID int)
|
|
INSERT INTO #newest
|
|
SELECT C_CIMID,C_FELHASZNALOID from #allAddresses a
|
|
WHERE CreatedRn = 1
|
|
DELETE FROM #allAddresses WHERE C_FELHASZNALOID IN (SELECT C_FELHASZNALOID FROM #newest)
|
|
/*============================UPDATE================================
|
|
--Ha valakinek egy címe van tanulónál, akkor legyen alapértelmezett.
|
|
====================================================================*/
|
|
UPDATE c SET C_ALAPERTELMEZETT='F'
|
|
FROM T_CIM c
|
|
INNER JOIN #onlyOneAddress a ON a.C_FELHASZNALOID = c.C_FELHASZNALOID
|
|
|
|
UPDATE c SET C_ALAPERTELMEZETT='T'
|
|
FROM T_CIM c
|
|
INNER JOIN #onlyOneAddress a ON a.C_FELHASZNALOID = c.C_FELHASZNALOID AND a.C_CIMID = c.ID
|
|
/*============================UPDATE================================
|
|
--Ha több van, akkor a tartózkodási helye legyen az alapértelmezett.
|
|
--909 Tartózkodási hely
|
|
--907 Állandó lakcím
|
|
====================================================================*/
|
|
UPDATE c SET C_ALAPERTELMEZETT='F'
|
|
FROM T_CIM c
|
|
INNER JOIN #haveTartHely a ON a.C_FELHASZNALOID = c.C_FELHASZNALOID
|
|
|
|
UPDATE c SET C_ALAPERTELMEZETT='T'
|
|
FROM T_CIM c
|
|
INNER JOIN #haveTartHely a ON a.C_FELHASZNALOID = c.C_FELHASZNALOID AND a.C_CIMID = c.ID
|
|
/*============================UPDATE================================
|
|
--Ha nincs tartózkodási helye, akkor az állandó lakcíme.
|
|
====================================================================*/
|
|
UPDATE c SET C_ALAPERTELMEZETT='F'
|
|
FROM T_CIM c
|
|
INNER JOIN #haveAllando a ON a.C_FELHASZNALOID = c.C_FELHASZNALOID
|
|
|
|
UPDATE c SET C_ALAPERTELMEZETT='T'
|
|
FROM T_CIM c
|
|
INNER JOIN #haveAllando a ON a.C_FELHASZNALOID = c.C_FELHASZNALOID AND a.C_CIMID = c.ID
|
|
/*============================UPDATE================================
|
|
--Ha ez sincs, akkor pedig a legújabb.
|
|
====================================================================*/
|
|
UPDATE c SET C_ALAPERTELMEZETT='F'
|
|
FROM T_CIM c
|
|
INNER JOIN #newest a ON a.C_FELHASZNALOID = c.C_FELHASZNALOID
|
|
|
|
UPDATE c SET C_ALAPERTELMEZETT='T'
|
|
FROM T_CIM c
|
|
INNER JOIN #newest a ON a.C_FELHASZNALOID = c.C_FELHASZNALOID AND a.C_CIMID = c.ID
|
|
|
|
|
|
|
|
|