From 16f8de457705ddd34ccf1655284084500033afaa Mon Sep 17 00:00:00 2001 From: Sander Schepers Date: Wed, 11 Jan 2023 14:05:09 +0000 Subject: [PATCH] VEBE#75918 Bulk personeelsnummers wijzigen svn path=/Customer/; revision=58624 --- onces/VEBE/VEBE#75918.sql | 144 ++++++++++++++++++++++++++++++++++++++ 1 file changed, 144 insertions(+) create mode 100644 onces/VEBE/VEBE#75918.sql diff --git a/onces/VEBE/VEBE#75918.sql b/onces/VEBE/VEBE#75918.sql new file mode 100644 index 000000000..f79e105e6 --- /dev/null +++ b/onces/VEBE/VEBE#75918.sql @@ -0,0 +1,144 @@ +-- +-- $Id$ +-- +-- In dit script worden obv een importbestand (fac_imp_perslid) gegevens aangepast in bulk. +-- Er wordt daarbij obv het oude personeelsnummer een nieuw personeelsnummer bepaalt (was-wordt) en tevens worden emailadres aangepast en een kenmerk (Indirect) gevuld. +-- Dat wordt dan in bulk voor 406 personen gedaan, ipv handmatig. +-- Update: nog eens 75 personen erbij, dus 481 personen +-- +-- +DEFINE thisfile = 'VEBE#75918.SQL' +DEFINE dbuser = '^VEBE' + +SET ECHO ON +SET DEFINE ON +COLUMN fcltlogfile NEW_VALUE fcltlogfile NOPRINT; +COLUMN fcltcusterr NEW_VALUE fcltcusterr NOPRINT; +WHENEVER SQLERROR CONTINUE; +SELECT adm.getscriptspoolfile('&thisfile') AS fcltlogfile FROM DUAL; +SPOOL &fcltlogfile +WHENEVER SQLERROR EXIT; +SELECT adm.checkscriptcust('&dbuser') AS fcltcusterr FROM DUAL; +WHENEVER SQLERROR CONTINUE; +PROMPT &fcltcusterr +SET DEFINE OFF + +------ payload begin ------ + +DECLARE + CURSOR c IS + SELECT p.prs_perslid_key, + p.prs_perslid_email + AS email_oud, + p.prs_perslid_oslogin, + i.prs_perslid_nr + AS nr_oud, + i.prs_perslid_email + AS email_nieuw, + i.prs_kenmerk1 + AS nr_nieuw, + i.prs_kenmerk2, + UPPER (SUBSTR (i.prs_perslid_email, 0, 30)), + DECODE ( + (SELECT TO_NUMBER (prs_kenmerklink_waarde) + FROM prs_kenmerklink + WHERE prs_link_key = p.prs_perslid_key + AND prs_kenmerk_key = 1000 + AND prs_kenmerklink_verwijder IS NULL + AND prs_kenmerklink_niveau = 'P'), + 1, 1, + 0) + AS indirect_oud, + (DECODE (UPPER (prs_kenmerk2), 'INDIRECT', 1, 0)) + AS indirect_nieuw, + (SELECT TO_NUMBER (prs_kenmerklink_key) + FROM prs_kenmerklink + WHERE prs_link_key = p.prs_perslid_key + AND prs_kenmerk_key = 1000 + AND prs_kenmerklink_verwijder IS NULL + AND prs_kenmerklink_niveau = 'P') + AS indirect_key + FROM fac_imp_perslid i, prs_perslid p + WHERE p.prs_perslid_nr = i.prs_perslid_nr; +BEGIN + FOR rec IN c + LOOP + BEGIN + UPDATE prs_perslid + SET prs_perslid_nr = rec.nr_nieuw, + prs_perslid_email = rec.email_nieuw, + prs_perslid_oslogin = + UPPER (SUBSTR (rec.email_nieuw, 0, 30)) + WHERE prs_perslid_key = rec.prs_perslid_key; + + fac.trackaction ( + 'PRSUPD', + rec.prs_perslid_key, + NULL, + NULL, + 'E-mail: ' + || rec.email_oud + || ' --> ' + || rec.email_nieuw + || CHR (10) + || 'Login: ' + || rec.prs_perslid_oslogin + || ' --> ' + || UPPER (SUBSTR (rec.email_nieuw, 0, 30)) + || CHR (10) + || 'NR: ' + || rec.nr_oud + || ' --> ' + || rec.nr_nieuw); + + --Indien nu indirect, maar beoogd direct, dan kenmerk verwijderen + IF rec.indirect_oud = 1 AND rec.indirect_nieuw = 0 + THEN + UPDATE prs_kenmerklink + SET prs_kenmerklink_verwijder = SYSDATE + WHERE prs_kenmerklink_key = rec.indirect_key; + + fac.trackaction ('PRSUPD', + rec.prs_perslid_key, + NULL, + NULL, + 'Persoon gewijzigd: Indirect --> Direct'); + END IF; + + --Indien nu direct, maar beoogd indirect, dan kenmerk toevoegen + IF rec.indirect_oud = 0 AND rec.indirect_nieuw = 1 + THEN + INSERT INTO prs_kenmerklink (prs_link_key, + prs_kenmerklink_niveau, + prs_kenmerk_key, + prs_kenmerklink_waarde, + prs_kenmerklink_aanmaak) + VALUES (rec.prs_perslid_key, + 'P', + 1000, + 1, + SYSDATE); + + fac.trackaction ('PRSUPD', + rec.prs_perslid_key, + NULL, + NULL, + 'Persoon gewijzigd: Direct --> Indirect'); + END IF; + END; + END LOOP; +END; +/ + + +------ payload end ------ + +SET DEFINE OFF +BEGIN adm.systrackscriptId ('$Id$', 1); END; +/ + +COMMIT; +SET ECHO OFF +SPOOL OFF +SET DEFINE ON +PROMPT Logfile of this upgrade is: &fcltlogfile