564 lines
21 KiB
Transact-SQL
564 lines
21 KiB
Transact-SQL
EXEC sp_change_users_login 'Update_One', 'kreta_tech_user', 'kreta_tech_user'
|
|
GO
|
|
|
|
EXEC dev.uspIntezmenyDisableObjects
|
|
@pIsIndex = 0
|
|
,@pIsConstraint = 0
|
|
,@pIsTrigger = 1
|
|
GO
|
|
|
|
-- ================================================ --
|
|
-- Adatbázis, intézmények anonimizlása --
|
|
-- ================================================ --
|
|
DROP TABLE IF EXISTS #Intezmeny
|
|
GO
|
|
|
|
CREATE TABLE #Intezmeny (id int)
|
|
GO
|
|
|
|
INSERT INTO #Intezmeny (id)
|
|
SELECT
|
|
ID
|
|
FROM T_INTEZMENY
|
|
WHERE TOROLT = 'F'
|
|
AND C_AZONOSITO IN ('') -- Kommenteld ki, ha az összes intézményre le szeretnéd futtatni vagy írd be az intézmények azonosítóit
|
|
GO
|
|
/*
|
|
TANULÓK NEVE ÉS NEME
|
|
*/
|
|
|
|
IF NOT EXISTS (SELECT 1 FROM sys.indexes WHERE name = 'IDX_FELHASZNALO_OKTATASIAZONOSITO') BEGIN
|
|
CREATE INDEX IDX_FELHASZNALO_OKTATASIAZONOSITO ON T_FELHASZNALO (C_OKTATASIAZONOSITO)
|
|
END
|
|
GO
|
|
|
|
PRINT 'Tanulók neveinek felcserélése'
|
|
|
|
DECLARE @Anonim TABLE (
|
|
oktAzon nvarchar(20) COLLATE Hungarian_CI_AI PRIMARY KEY
|
|
,gender int
|
|
,rowNumberOriginal int INDEX IX1 NONCLUSTERED
|
|
,rowNumberOriginalByGender int INDEX IX2 NONCLUSTERED
|
|
,rowNumberSurName int INDEX IX3 NONCLUSTERED
|
|
,rowNumberFirstName int INDEX IX4 NONCLUSTERED
|
|
,rowNumberMotherSurName int INDEX IX5 NONCLUSTERED
|
|
,rowNumberMotherFirstName int INDEX IX6 NONCLUSTERED
|
|
,rowNumberBirthSurName int INDEX IX7 NONCLUSTERED
|
|
,rowNumberBirthFirstName int INDEX IX8 NONCLUSTERED
|
|
,randomSurName int INDEX IX9 NONCLUSTERED
|
|
,randomFirstName int INDEX IX10 NONCLUSTERED
|
|
,randomMotherSurName int INDEX IX11 NONCLUSTERED
|
|
,randomMotherFirstName int INDEX IX12 NONCLUSTERED
|
|
,randomBirthSurName int INDEX IX13 NONCLUSTERED
|
|
,randomBirthFirstName int INDEX IX14 NONCLUSTERED
|
|
)
|
|
|
|
UPDATE fh SET
|
|
C_OKTATASIAZONOSITO = '5' + RIGHT(CONCAT('0000000000', ID), 10)
|
|
FROM T_FELHASZNALO fh
|
|
WHERE C_OKTATASIAZONOSITO IS NULL
|
|
|
|
INSERT INTO @Anonim (oktAzon, gender, rowNumberOriginal, rowNumberOriginalByGender, randomSurName, randomFirstName, randomMotherSurName, randomMotherFirstName, randomBirthSurName, randomBirthFirstName)
|
|
SELECT
|
|
fh.C_OKTATASIAZONOSITO AS oktAzon
|
|
,MIN(fh.C_NEME) AS gender
|
|
,ROW_NUMBER() OVER (ORDER BY fh.C_OKTATASIAZONOSITO) AS rowNumberOriginal
|
|
,ROW_NUMBER() OVER (PARTITION BY MIN(fh.C_NEME) ORDER BY fh.C_OKTATASIAZONOSITO) AS rowNumberOriginalByGender
|
|
,(SELECT FLOOR(RandomNumber * 1000000) FROM dev.vGetRand) AS randomSurName
|
|
,(SELECT FLOOR(RandomNumber * 1000000) FROM dev.vGetRand) AS randomFirstName
|
|
,(SELECT FLOOR(RandomNumber * 1000000) FROM dev.vGetRand) AS randomMotherSurName
|
|
,(SELECT FLOOR(RandomNumber * 1000000) FROM dev.vGetRand) AS randomMotherFirstName
|
|
,(SELECT FLOOR(RandomNumber * 1000000) FROM dev.vGetRand) AS randomBirthSurName
|
|
,(SELECT FLOOR(RandomNumber * 1000000) FROM dev.vGetRand) AS randomBirthFirstName
|
|
FROM T_FELHASZNALO fh
|
|
INNER JOIN T_TANULO t ON fh.ID = t.ID
|
|
WHERE fh.C_INTEZMENYID IN (SELECT id FROM #Intezmeny)
|
|
GROUP BY fh.C_OKTATASIAZONOSITO
|
|
|
|
UPDATE trg
|
|
SET
|
|
trg.rowNumberSurName = src.rowNumberSurName
|
|
,trg.rowNumberFirstName = src.rowNumberFirstName
|
|
,trg.rowNumberMotherSurName = src.rowNumberMotherSurName
|
|
,trg.rowNumberMotherFirstName = src.rowNumberMotherFirstName
|
|
,trg.rowNumberBirthSurName = src.rowNumberBirthSurName
|
|
,trg.rowNumberBirthFirstName = src.rowNumberBirthFirstName
|
|
FROM @Anonim trg
|
|
INNER JOIN (
|
|
SELECT
|
|
oktAzon
|
|
,ROW_NUMBER() OVER(ORDER BY randomSurName) as rowNumberSurName
|
|
,ROW_NUMBER() OVER(PARTITION BY gender ORDER BY randomFirstName) as rowNumberFirstName
|
|
,ROW_NUMBER() OVER(ORDER BY randomMotherSurName) as rowNumberMotherSurName
|
|
,ROW_NUMBER() OVER(ORDER BY randomMotherFirstName) as rowNumberMotherFirstName
|
|
,ROW_NUMBER() OVER(ORDER BY randomBirthSurName) as rowNumberBirthSurName
|
|
,ROW_NUMBER() OVER(ORDER BY randomBirthFirstName) as rowNumberBirthFirstName
|
|
FROM @Anonim
|
|
) src ON src.oktAzon = trg.oktAzon
|
|
|
|
UPDATE fh
|
|
SET
|
|
fh.C_VEZETEKNEV = surname.newName
|
|
,fh.C_UTONEV = firstname.newName
|
|
,fh.C_ANYJANEVE = motherSurname.newName + ' ' + motherFirstname.newName
|
|
,fh.C_NYOMTATASINEV = surname.newName + ' ' + firstname.newName
|
|
,fh.C_SZULETESINEV = birthSurname.newName + ' ' + birthFirstname.newName
|
|
,fh.C_ANYJAVEZETEKNEVE = motherSurname.newName
|
|
,fh.C_ANYJAUTONEVE =motherFirstname.newName
|
|
,fh.C_SZULETESIVEZETEKNEV =birthSurname.newName
|
|
,fh.C_SZULETESIUTONEV = birthFirstname.newName
|
|
FROM T_FELHASZNALO fh
|
|
INNER JOIN @Anonim orig ON orig.oktAzon = fh.C_OKTATASIAZONOSITO
|
|
INNER JOIN (
|
|
SELECT a.rowNumberSurName, f.C_VEZETEKNEV AS newName
|
|
FROM @Anonim a
|
|
INNER JOIN T_FELHASZNALO f ON f.C_OKTATASIAZONOSITO COLLATE Hungarian_CI_AI = a.oktAzon COLLATE Hungarian_CI_AI
|
|
) surname ON surname.rowNumberSurName = orig.rowNumberOriginal
|
|
INNER JOIN (
|
|
SELECT a.rowNumberFirstName, f.C_UTONEV newName, f.C_NEME
|
|
FROM @Anonim a
|
|
INNER JOIN T_FELHASZNALO f ON f.C_OKTATASIAZONOSITO COLLATE Hungarian_CI_AI = a.oktAzon COLLATE Hungarian_CI_AI
|
|
) firstname ON firstname.rowNumberFirstName = orig.rowNumberOriginalByGender AND firstname.C_NEME = orig.gender
|
|
INNER JOIN (
|
|
SELECT a.rowNumberMotherSurName, f.C_ANYJAVEZETEKNEVE AS newName
|
|
FROM @Anonim a
|
|
INNER JOIN T_FELHASZNALO f ON f.C_OKTATASIAZONOSITO COLLATE Hungarian_CI_AI = a.oktAzon COLLATE Hungarian_CI_AI
|
|
) motherSurname ON motherSurname.rowNumberMotherSurName = orig.rowNumberOriginal
|
|
INNER JOIN (
|
|
SELECT a.rowNumberMotherFirstName, f.C_ANYJAUTONEVE AS newName
|
|
FROM @Anonim a
|
|
INNER JOIN T_FELHASZNALO f ON f.C_OKTATASIAZONOSITO COLLATE Hungarian_CI_AI = a.oktAzon COLLATE Hungarian_CI_AI
|
|
) motherFirstname ON motherFirstname.rowNumberMotherFirstName = orig.rowNumberOriginal
|
|
INNER JOIN (
|
|
SELECT a.rowNumberBirthSurName, f.C_SZULETESIVEZETEKNEV AS newName
|
|
FROM @Anonim a
|
|
INNER JOIN T_FELHASZNALO f ON f.C_OKTATASIAZONOSITO COLLATE Hungarian_CI_AI = a.oktAzon COLLATE Hungarian_CI_AI
|
|
) birthSurname ON birthSurname.rowNumberBirthSurName = orig.rowNumberOriginal
|
|
INNER JOIN (
|
|
SELECT a.rowNumberBirthFirstName, f.C_SZULETESIUTONEV AS newName
|
|
FROM @Anonim a
|
|
INNER JOIN T_FELHASZNALO f ON f.C_OKTATASIAZONOSITO COLLATE Hungarian_CI_AI = a.oktAzon COLLATE Hungarian_CI_AI
|
|
) birthFirstname ON birthFirstname.rowNumberBirthFirstName = orig.rowNumberOriginal
|
|
WHERE EXISTS (SELECT 1 FROM T_TANULO t WHERE t.ID = fh.ID)
|
|
AND fh.C_INTEZMENYID IN (SELECT id FROM #Intezmeny)
|
|
GO
|
|
|
|
|
|
/*
|
|
ALKALMAZOTTAK NEVE ÉS NEME
|
|
*/
|
|
PRINT 'Alkalmazottak neveinek felcserélése'
|
|
|
|
DECLARE @Anonim TABLE (
|
|
oktAzon nvarchar(20) PRIMARY KEY
|
|
,gender int
|
|
,rowNumberOriginal int INDEX IX1 NONCLUSTERED
|
|
,rowNumberOriginalByGender int INDEX IX2 NONCLUSTERED
|
|
,rowNumberSurName int INDEX IX3 NONCLUSTERED
|
|
,rowNumberFirstName int INDEX IX4 NONCLUSTERED
|
|
,rowNumberMotherSurName int INDEX IX5 NONCLUSTERED
|
|
,rowNumberMotherFirstName int INDEX IX6 NONCLUSTERED
|
|
,rowNumberBirthSurName int INDEX IX7 NONCLUSTERED
|
|
,rowNumberBirthFirstName int INDEX IX8 NONCLUSTERED
|
|
,randomSurName int INDEX IX9 NONCLUSTERED
|
|
,randomFirstName int INDEX IX10 NONCLUSTERED
|
|
,randomMotherSurName int INDEX IX11 NONCLUSTERED
|
|
,randomMotherFirstName int INDEX IX12 NONCLUSTERED
|
|
,randomBirthSurName int INDEX IX13 NONCLUSTERED
|
|
,randomBirthFirstName int INDEX IX14 NONCLUSTERED
|
|
)
|
|
|
|
|
|
|
|
INSERT INTO @Anonim (oktAzon, gender, rowNumberOriginal, rowNumberOriginalByGender, randomSurName, randomFirstName, randomMotherSurName,randomMotherFirstName,randomBirthSurName,randomBirthFirstName)
|
|
SELECT
|
|
fh.C_OKTATASIAZONOSITO AS oktAzon
|
|
,MIN(fh.C_NEME) AS gender
|
|
,ROW_NUMBER() OVER (ORDER BY fh.C_OKTATASIAZONOSITO) AS rowNumberOriginal
|
|
,ROW_NUMBER() OVER (PARTITION BY MIN(fh.C_NEME) ORDER BY fh.C_OKTATASIAZONOSITO) AS rowNumberOriginalByGender
|
|
,(SELECT FLOOR(RandomNumber * 1000000) FROM dev.vGetRand) AS randomSurName
|
|
,(SELECT FLOOR(RandomNumber * 1000000) FROM dev.vGetRand) AS randomFirstName
|
|
,(SELECT FLOOR(RandomNumber * 1000000) FROM dev.vGetRand) AS randomMotherSurName
|
|
,(SELECT FLOOR(RandomNumber * 1000000) FROM dev.vGetRand) AS randomMotherFirstName
|
|
,(SELECT FLOOR(RandomNumber * 1000000) FROM dev.vGetRand) AS randomBirthSurName
|
|
,(SELECT FLOOR(RandomNumber * 1000000) FROM dev.vGetRand) AS randomBirthFirstName
|
|
FROM T_FELHASZNALO fh
|
|
INNER JOIN T_ALKALMAZOTT a ON fh.ID = a.ID
|
|
WHERE fh.C_OKTATASIAZONOSITO IS NOT NULL
|
|
AND fh.C_INTEZMENYID IN (SELECT id FROM #Intezmeny)
|
|
GROUP BY fh.C_OKTATASIAZONOSITO
|
|
|
|
UPDATE trg
|
|
SET
|
|
trg.rowNumberSurName = src.rowNumberSurName
|
|
,trg.rowNumberFirstName = src.rowNumberFirstName
|
|
,trg.rowNumberMotherSurName = src.rowNumberMotherSurName
|
|
,trg.rowNumberMotherFirstName = src.rowNumberMotherFirstName
|
|
,trg.rowNumberBirthSurName = src.rowNumberBirthSurName
|
|
,trg.rowNumberBirthFirstName = src.rowNumberBirthFirstName
|
|
FROM @Anonim trg
|
|
INNER JOIN (
|
|
SELECT
|
|
oktAzon
|
|
,ROW_NUMBER() OVER(ORDER BY randomSurName) as rowNumberSurName
|
|
,ROW_NUMBER() OVER(PARTITION BY gender ORDER BY randomFirstName) as rowNumberFirstName
|
|
,ROW_NUMBER() OVER(ORDER BY randomMotherSurName) as rowNumberMotherSurName
|
|
,ROW_NUMBER() OVER(ORDER BY randomMotherFirstName) as rowNumberMotherFirstName
|
|
,ROW_NUMBER() OVER(ORDER BY randomBirthSurName) as rowNumberBirthSurName
|
|
,ROW_NUMBER() OVER(ORDER BY randomBirthFirstName) as rowNumberBirthFirstName
|
|
FROM @Anonim
|
|
) src ON src.oktAzon = trg.oktAzon
|
|
|
|
|
|
UPDATE fh
|
|
SET
|
|
fh.C_VEZETEKNEV = surname.newName
|
|
,fh.C_UTONEV = firstname.newName
|
|
,fh.C_ANYJANEVE = MotherSurname.newName + ' ' + MotherFirstname.newName
|
|
,fh.C_NYOMTATASINEV = surname.newName + ' ' + firstname.newName
|
|
,fh.C_SZULETESINEV = birthSurname.newName + ' ' + BirthFirstname.newName
|
|
,fh.C_ANYJAVEZETEKNEVE = motherSurname.newName
|
|
,fh.C_ANYJAUTONEVE =motherFirstname.newName
|
|
,fh.C_SZULETESIVEZETEKNEV =birthSurname.newName
|
|
,fh.C_SZULETESIUTONEV = birthFirstname.newName
|
|
FROM T_FELHASZNALO fh
|
|
INNER JOIN @Anonim orig ON orig.oktAzon COLLATE Hungarian_CI_AI = fh.C_OKTATASIAZONOSITO COLLATE Hungarian_CI_AI
|
|
INNER JOIN (
|
|
SELECT a.rowNumberSurName, f.C_VEZETEKNEV AS newName
|
|
FROM @Anonim a
|
|
INNER JOIN T_FELHASZNALO f ON f.C_OKTATASIAZONOSITO COLLATE Hungarian_CI_AI = a.oktAzon COLLATE Hungarian_CI_AI
|
|
) surname ON surname.rowNumberSurName = orig.rowNumberOriginal
|
|
INNER JOIN (
|
|
SELECT a.rowNumberFirstName, f.C_UTONEV newName, f.C_NEME
|
|
FROM @Anonim a
|
|
INNER JOIN T_FELHASZNALO f ON f.C_OKTATASIAZONOSITO COLLATE Hungarian_CI_AI = a.oktAzon COLLATE Hungarian_CI_AI
|
|
) firstname ON firstname.rowNumberFirstName = orig.rowNumberOriginalByGender AND firstname.C_NEME = orig.gender
|
|
INNER JOIN (
|
|
SELECT a.rowNumberMotherSurName, f.C_ANYJAVEZETEKNEVE AS newName
|
|
FROM @Anonim a
|
|
INNER JOIN T_FELHASZNALO f ON f.C_OKTATASIAZONOSITO COLLATE Hungarian_CI_AI = a.oktAzon COLLATE Hungarian_CI_AI
|
|
) motherSurname ON motherSurname.rowNumberMotherSurName = orig.rowNumberOriginal
|
|
INNER JOIN (
|
|
SELECT a.rowNumberMotherFirstName, f.C_ANYJAUTONEVE AS newName
|
|
FROM @Anonim a
|
|
INNER JOIN T_FELHASZNALO f ON f.C_OKTATASIAZONOSITO COLLATE Hungarian_CI_AI = a.oktAzon COLLATE Hungarian_CI_AI
|
|
) motherFirstname ON motherFirstname.rowNumberMotherFirstName = orig.rowNumberOriginal
|
|
INNER JOIN (
|
|
SELECT a.rowNumberBirthSurName, f.C_SZULETESIVEZETEKNEV AS newName
|
|
FROM @Anonim a
|
|
INNER JOIN T_FELHASZNALO f ON f.C_OKTATASIAZONOSITO COLLATE Hungarian_CI_AI = a.oktAzon COLLATE Hungarian_CI_AI
|
|
) birthSurname ON birthSurname.rowNumberBirthSurName = orig.rowNumberOriginal
|
|
INNER JOIN (
|
|
SELECT a.rowNumberBirthFirstName, f.C_SZULETESIUTONEV AS newName
|
|
FROM @Anonim a
|
|
INNER JOIN T_FELHASZNALO f ON f.C_OKTATASIAZONOSITO COLLATE Hungarian_CI_AI = a.oktAzon COLLATE Hungarian_CI_AI
|
|
) birthFirstname ON birthFirstname.rowNumberBirthFirstName = orig.rowNumberOriginal
|
|
WHERE EXISTS (SELECT 1 FROM T_ALKALMAZOTT t WHERE t.ID = fh.ID)
|
|
AND fh.C_INTEZMENYID IN (SELECT id FROM #Intezmeny)
|
|
GO
|
|
|
|
DROP INDEX IDX_FELHASZNALO_OKTATASIAZONOSITO ON T_FELHASZNALO
|
|
GO
|
|
/*
|
|
-- SZÜLETÉSI DÁTUM RANDOMIZÁLÁS
|
|
*/
|
|
PRINT 'Születési dátum megváltoztatása'
|
|
|
|
UPDATE T_FELHASZNALO
|
|
SET C_SZULETESIDATUM = C_SZULETESIDATUM + (SELECT FLOOR(RandomNumber * 30) + 1 FROM dev.vGetRand) - (SELECT FLOOR(RandomNumber * 30) + 1 FROM dev.vGetRand)
|
|
WHERE C_INTEZMENYID IN (SELECT id FROM #Intezmeny)
|
|
GO
|
|
|
|
/*
|
|
SEGÉDFÜGGVÉNY AZ AZONOSÍTÓKHOZ
|
|
*/
|
|
IF OBJECT_ID('dev.fnGenerateId') IS NOT NULL BEGIN
|
|
DROP FUNCTION dev.fnGenerateId
|
|
END
|
|
GO
|
|
|
|
CREATE FUNCTION dev.fnGenerateId(
|
|
@pFormat nvarchar(50)
|
|
)
|
|
RETURNS nvarchar(50)
|
|
BEGIN
|
|
DECLARE
|
|
@i int = 1
|
|
,@char char(1)
|
|
,@d nvarchar(10) = '0123456789'
|
|
,@u nvarchar(26) = 'ABCDEFGHIJKLMNOPQRSTUVWXYZ'
|
|
,@l nvarchar(26) = 'abcdefghijklmnopqrstuvwxyz'
|
|
,@w nvarchar(52) = 'abcdefghijklmnopqrstuvwxyzABCDEFGHIJKLMNOPQRSTUVWXYZ'
|
|
,@c nvarchar(62) = 'abcdefghijklmnopqrstuvwxyz0123456789ABCDEFGHIJKLMNOPQRSTUVWXYZ'
|
|
,@return nvarchar(50) = ''
|
|
|
|
WHILE @i <= LEN(@pFormat) BEGIN
|
|
SET @char = SUBSTRING (@pFormat, @i, 1)
|
|
SET @return +=
|
|
CASE @char
|
|
WHEN 'D' THEN SUBSTRING (@d, (SELECT CAST(FLOOR(RandomNumber * (LEN(@d) - 1) + 1) AS int) FROM dev.vGetRand), 1)
|
|
WHEN 'U' THEN SUBSTRING (@u, (SELECT CAST(FLOOR(RandomNumber * (LEN(@u) - 1) + 1) AS int) FROM dev.vGetRand), 1)
|
|
WHEN 'L' THEN SUBSTRING (@l, (SELECT CAST(FLOOR(RandomNumber * (LEN(@l) - 1) + 1) AS int) FROM dev.vGetRand), 1)
|
|
WHEN 'W' THEN SUBSTRING (@w, (SELECT CAST(FLOOR(RandomNumber * (LEN(@w) - 1) + 1) AS int) FROM dev.vGetRand), 1)
|
|
WHEN 'C' THEN SUBSTRING (@c, (SELECT CAST(FLOOR(RandomNumber * (LEN(@c) - 1) + 1) AS int) FROM dev.vGetRand), 1)
|
|
ELSE @char
|
|
END
|
|
SET @i += 1
|
|
END
|
|
RETURN @return
|
|
END
|
|
GO
|
|
|
|
|
|
/*
|
|
Új azonosítók, telefonszámok generálása
|
|
*/
|
|
|
|
|
|
PRINT 'Új TAJ-szám generálása'
|
|
|
|
UPDATE f
|
|
SET f.C_TAJSZAM = x.new
|
|
FROM T_FELHASZNALO f
|
|
INNER JOIN (
|
|
SELECT C_OKTATASIAZONOSITO, dev.fnGenerateId('DDDDDDDDD') AS new
|
|
FROM T_FELHASZNALO
|
|
WHERE C_TAJSZAM IS NOT NULL
|
|
GROUP BY C_OKTATASIAZONOSITO
|
|
) x ON f.C_OKTATASIAZONOSITO = x.C_OKTATASIAZONOSITO
|
|
WHERE f.C_TAJSZAM IS NOT NULL
|
|
AND f.C_INTEZMENYID IN (SELECT id FROM #Intezmeny)
|
|
|
|
PRINT 'Új igazolványszám generálása'
|
|
|
|
UPDATE f
|
|
SET f.C_IGAZOLVANYSZAM = x.new
|
|
FROM T_FELHASZNALO f
|
|
INNER JOIN (
|
|
SELECT C_OKTATASIAZONOSITO, dev.fnGenerateId('DDDDDD UU') AS new
|
|
FROM T_FELHASZNALO
|
|
WHERE C_IGAZOLVANYSZAM IS NOT NULL
|
|
GROUP BY C_OKTATASIAZONOSITO
|
|
) x ON f.C_OKTATASIAZONOSITO = x.C_OKTATASIAZONOSITO
|
|
WHERE f.C_IGAZOLVANYSZAM IS NOT NULL
|
|
AND f.C_INTEZMENYID IN (SELECT id FROM #Intezmeny)
|
|
|
|
PRINT 'Új oktatási azonosító generálása'
|
|
|
|
UPDATE f
|
|
SET f.C_OKTATASIAZONOSITO = x.new
|
|
FROM T_FELHASZNALO f
|
|
INNER JOIN (
|
|
SELECT C_OKTATASIAZONOSITO, dev.fnGenerateId('7DDDDDDDDDD') AS new
|
|
FROM T_FELHASZNALO
|
|
WHERE C_OKTATASIAZONOSITO IS NOT NULL
|
|
GROUP BY C_OKTATASIAZONOSITO
|
|
) x ON f.C_OKTATASIAZONOSITO = x.C_OKTATASIAZONOSITO
|
|
AND f.C_INTEZMENYID IN (SELECT id FROM #Intezmeny)
|
|
|
|
PRINT 'Új diákigazolványszám generálása'
|
|
|
|
UPDATE t
|
|
SET t.C_DIAKIGAZOLVANYSZAM = x.new
|
|
FROM T_FELHASZNALO f
|
|
INNER JOIN T_TANULO t ON t.ID = f.ID
|
|
INNER JOIN (
|
|
SELECT C_OKTATASIAZONOSITO, dev.fnGenerateId('12DDDDDDDD') AS new
|
|
FROM T_FELHASZNALO
|
|
WHERE C_OKTATASIAZONOSITO IS NOT NULL
|
|
GROUP BY C_OKTATASIAZONOSITO
|
|
) x ON f.C_OKTATASIAZONOSITO = x.C_OKTATASIAZONOSITO
|
|
WHERE t.C_DIAKIGAZOLVANYSZAM IS NOT NULL
|
|
AND t.C_ALINTEZMENYID IN (SELECT id FROM #Intezmeny)
|
|
|
|
PRINT 'Új telefonszám generálása'
|
|
|
|
UPDATE tf
|
|
SET tf.C_TELEFONSZAM = x.new
|
|
FROM T_FELHASZNALO f
|
|
INNER JOIN (
|
|
SELECT C_OKTATASIAZONOSITO, dev.fnGenerateId('06DDDDDDDDD') AS new
|
|
FROM T_FELHASZNALO
|
|
WHERE C_OKTATASIAZONOSITO IS NOT NULL
|
|
GROUP BY C_OKTATASIAZONOSITO
|
|
) x ON f.C_OKTATASIAZONOSITO = x.C_OKTATASIAZONOSITO
|
|
INNER JOIN T_TELEFON tf ON tf.C_FELHASZNALOID = f.ID
|
|
WHERE C_GONDVISELOID IS NULL
|
|
AND f.C_INTEZMENYID IN (SELECT id FROM #Intezmeny)
|
|
|
|
PRINT 'Új telefonszám generálása gondviselőknek'
|
|
|
|
UPDATE T_TELEFON
|
|
SET C_TELEFONSZAM = dev.fnGenerateId('+36DD DDD DDDD')
|
|
WHERE C_GONDVISELOID IS NOT NULL
|
|
AND C_INTEZMENYID IN (SELECT id FROM #Intezmeny)
|
|
GO
|
|
|
|
/*
|
|
Segédfüggvény törlése
|
|
*/
|
|
IF OBJECT_ID('dev.fnGenerateId') IS NOT NULL BEGIN
|
|
DROP FUNCTION dev.fnGenerateId
|
|
END
|
|
GO
|
|
|
|
|
|
/*
|
|
EMAIL CÍMEK átírása
|
|
*/
|
|
|
|
|
|
PRINT 'E-mail címek átírása kretateszt@gmail.comra'
|
|
|
|
UPDATE dbo.T_INTEZMENYADATOK set C_EMAILCIM ='kretateszt@gmail.com' where C_EMAILCIM > '' AND C_INTEZMENYID IN (SELECT id FROM #Intezmeny)
|
|
UPDATE dbo.T_INTEZMENYADATOK set C_ADMINEMAILCIM ='kretateszt@gmail.com' where C_ADMINEMAILCIM > '' AND C_INTEZMENYID IN (SELECT id FROM #Intezmeny)
|
|
UPDATE dbo.T_MUKODESIHELY set C_EMAILCIM ='kretateszt@gmail.com' where C_EMAILCIM > '' AND C_INTEZMENYID IN (SELECT id FROM #Intezmeny)
|
|
UPDATE dbo.T_EMAIL set C_EMAILCIM = CONCAT('kretateszt', ID, '@gmail.com') where C_EMAILCIM > '' AND C_INTEZMENYID IN (SELECT id FROM #Intezmeny)
|
|
UPDATE dbo.T_INTEZMENY set C_FENNTARTOEMAILCIM ='kretateszt@gmail.com' where C_FENNTARTOEMAILCIM > '' AND ID IN (SELECT id FROM #Intezmeny)
|
|
UPDATE dbo.T_NEBULO set C_TKEMAILCIM ='kretateszt@gmail.com' where C_TKEMAILCIM > '' AND C_INTEZMENYID IN (SELECT id FROM #Intezmeny)
|
|
UPDATE dbo.T_NEBULO set C_TKEMAILCIM2 ='kretateszt@gmail.com' where C_TKEMAILCIM2 > '' AND C_INTEZMENYID IN (SELECT id FROM #Intezmeny)
|
|
GO
|
|
|
|
|
|
/*
|
|
FOGLALKOZÁSOK NEVE
|
|
*/
|
|
|
|
PRINT 'Foglalkozások neveinek generálása'
|
|
|
|
UPDATE f
|
|
SET C_NEV = ocs.C_NEV + ' - ' + tt.C_ROVIDNEV + ' (' + fh.C_NYOMTATASINEV + ')'
|
|
FROM T_FOGLALKOZAS f
|
|
INNER JOIN T_OSZTALYCSOPORT ocs ON ocs.ID = f.C_OSZTALYCSOPORTID
|
|
INNER JOIN T_FELHASZNALO fh ON fh.ID = f.C_TANARID
|
|
INNER JOIN T_TANTARGY tt ON tt.ID = f.C_TANTARGYID
|
|
WHERE f.C_INTEZMENYID IN (SELECT id FROM #Intezmeny)
|
|
GO
|
|
|
|
|
|
/*
|
|
CIM (CSAK KÖZTERÜLET NEVE)
|
|
*/
|
|
|
|
PRINT 'Közterület neveinek felcserélése'
|
|
|
|
DECLARE @Anonim TABLE (
|
|
id int PRIMARY KEY
|
|
,rowNumber int INDEX IX1 NONCLUSTERED
|
|
,rand float(53) INDEX IX2 NONCLUSTERED
|
|
,kozterulet nvarchar(100)
|
|
)
|
|
|
|
INSERT INTO @Anonim (id, rowNumber, rand, kozterulet)
|
|
SELECT ID, ROW_NUMBER() OVER(ORDER BY ID), (SELECT RandomNumber FROM dev.vGetRand), C_KOZTERULET
|
|
FROM T_CIM
|
|
WHERE C_INTEZMENYID IN (SELECT id FROM #Intezmeny)
|
|
|
|
UPDATE trg
|
|
SET trg.kozterulet = src.kozterulet
|
|
FROM @Anonim trg
|
|
INNER JOIN (
|
|
SELECT ROW_NUMBER() OVER(ORDER BY rand) AS randRowNumber, kozterulet
|
|
FROM @Anonim
|
|
) src ON src.randRowNumber = trg.rowNumber
|
|
|
|
UPDATE c
|
|
SET c.C_KOZTERULET = a.kozterulet
|
|
FROM T_CIM c
|
|
INNER JOIN @Anonim a ON a.id = c.ID
|
|
WHERE c.C_INTEZMENYID IN (SELECT id FROM #Intezmeny)
|
|
GO
|
|
|
|
|
|
|
|
/*
|
|
GONDVISELO NEVE
|
|
*/
|
|
|
|
|
|
PRINT 'Gondviselő neveinek felcserélése'
|
|
|
|
DECLARE @Anonim TABLE (
|
|
id int PRIMARY KEY
|
|
,rowNumber int
|
|
,rand float(53) INDEX IX2 NONCLUSTERED
|
|
,nev nvarchar(100)
|
|
,rokonsag int INDEX IX3 NONCLUSTERED (rokonsag, rowNumber)
|
|
)
|
|
|
|
INSERT INTO @Anonim (id, rowNumber, rand, nev, rokonsag)
|
|
SELECT ID, ROW_NUMBER() OVER(PARTITION BY C_ROKONSAGFOKA ORDER BY ID), (SELECT RandomNumber FROM dev.vGetRand), C_NEV, C_ROKONSAGFOKA
|
|
FROM T_GONDVISELO
|
|
WHERE C_INTEZMENYID IN (SELECT id FROM #Intezmeny)
|
|
|
|
UPDATE trg
|
|
SET trg.nev = src.nev
|
|
FROM @Anonim trg
|
|
INNER JOIN (
|
|
SELECT ROW_NUMBER() OVER(PARTITION BY rokonsag ORDER BY rand) AS randRowNumber, nev, rokonsag
|
|
FROM @Anonim
|
|
) src ON src.randRowNumber = trg.rowNumber AND src.rokonsag = trg.rokonsag
|
|
|
|
UPDATE g
|
|
SET g.C_NEV = a.nev
|
|
FROM T_GONDVISELO g
|
|
INNER JOIN @Anonim a ON a.id = g.ID
|
|
WHERE C_INTEZMENYID IN (SELECT id FROM #Intezmeny)
|
|
GO
|
|
|
|
PRINT 'Felhasználónevek generálása'
|
|
|
|
UPDATE fb SET fb.C_BEJELENTKEZESINEV = IIF(x.userName = 'Admin', 'Admin1', x.userName) + IIF(rn = 1, '', CAST(rn AS nvarchar(5)))
|
|
--SELECT fb.C_BEJELENTKEZESINEV, IIF(x.userName = 'Admin', 'Admin1', x.userName) + IIF(rn = 1, '', CAST(rn AS nvarchar(5)))
|
|
FROM T_FELHASZNALOBELEPES fb
|
|
INNER JOIN (
|
|
SELECT fb.ID --fh.C_NYOMTATASINEV, g.C_NEV, g.ID, fb.C_TANEVID,
|
|
,IIF(g.ID IS NULL, REPLACE(REPLACE(REPLACE(fh.C_NYOMTATASINEV, ' ', ''), '.', ''), '-', ''), REPLACE(REPLACE(REPLACE(g.C_NEV, ' ', ''), '.', ''), '-', '')) userName
|
|
,ROW_NUMBER() OVER (PARTITION BY fb.C_TANEVID, IIF(g.ID IS NULL, REPLACE(REPLACE(REPLACE(fh.C_NYOMTATASINEV, ' ', ''), '.', ''), '-', ''), REPLACE(REPLACE(REPLACE(g.C_NEV, ' ', ''), '.', ''), '-', '')) ORDER BY fb.ID) rn
|
|
FROM T_FELHASZNALOBELEPES fb
|
|
INNER JOIN T_FELHASZNALO fh ON fh.ID = fb.C_FELHASZNALOID
|
|
LEFT JOIN T_GONDVISELO g ON g.ID = fb.C_GONDVISELOID
|
|
) x ON x.ID = fb.ID
|
|
WHERE C_BEJELENTKEZESINEV NOT IN (N'fenntarto', N'Admin')
|
|
AND fb.C_INTEZMENYID IN (SELECT id FROM #Intezmeny)
|
|
GO
|
|
|
|
|
|
PRINT 'Jelszavak átírása az intézmény azonosítójára'
|
|
DECLARE
|
|
@so nvarchar(64)
|
|
|
|
SET @so = CAST((SELECT * FROM dev.vGetRand) AS nvarchar(64))
|
|
|
|
UPDATE fb SET
|
|
fb.C_JELSZO = dev.fnConvertBase64(HASHBYTES('SHA1', CONVERT(VARBINARY(MAX), CONVERT(NVARCHAR(MAX), i2.C_AZONOSITO + @so))))
|
|
,fb.C_SO = @so
|
|
FROM T_FELHASZNALOBELEPES AS fb
|
|
INNER JOIN #Intezmeny i ON i.id = fb.C_INTEZMENYID
|
|
INNER JOIN T_INTEZMENY i2 ON i2.ID = fb.C_INTEZMENYID
|
|
|
|
PRINT 'Felhasználók születési név és anyja név elválasztó beállítása'
|
|
update T_FELHASZNALO
|
|
set
|
|
C_SZULETESINEVELVALASZTO = (CHARINDEX(' ', C_SZULETESINEV,0)),C_ANYJANEVEELVALASZTO = (CHARINDEX(' ', C_ANYJANEVE,0))
|
|
WHERE C_INTEZMENYID IN (SELECT id FROM #Intezmeny)
|
|
|
|
PRINT 'Profilképek törlése'
|
|
|
|
UPDATE T_FELHASZNALO SET C_PROFILKEP = NULL
|
|
WHERE C_PROFILKEP IS NOT NULL
|
|
AND C_INTEZMENYID IN (SELECT id FROM #Intezmeny)
|
|
GO
|
|
|
|
IF OBJECT_ID('tempdb..#Intezmeny') IS NOT NULL BEGIN
|
|
DROP TABLE #Intezmeny
|
|
END;
|
|
|
|
EXEC dev.uspIntezmenyEnableObjects
|
|
@pIsIndex = 0
|
|
,@pIsConstraint = 0
|
|
,@pIsTrigger = 1
|
|
GO
|
|
|
|
PRINT '!DONE!'
|
|
|