DHLD#84268 Implementatie gemeente Den Helder, script tbv migratie van meldingen (via fac_imp_csv)

svn path=/Customer/; revision=67149
This commit is contained in:
Sander Schepers
2024-11-21 22:32:36 +00:00
parent f9817b0e9c
commit c072312b21

View File

@@ -0,0 +1,447 @@
/* Formatted on 21/11/2024 23:22:25 (QP5 v5.396) */
--
-- $Id$
--
-- Customer specific once-script ConversieMLD.sql.
DEFINE thisfile = 'ConversieMLD.sql'
DEFINE dbuser = '^DHLD_TEST'
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 &fcltcusttxt
---------------------------------------
SET DEFINE OFF
------ payload begin ------
--col01 col02 col03 col04 col05 col06 col07 col08 col09 xcol10 xcol11 xcol12 col13 col14 col15
--Referentienr Datum Naam Email Soort_melding Categorie Subcategorie Korte_omschrijving Status Behandelaarsgroep Behandelaar Datum_gereed Datum_afgemeld Verzoek Actie
DECLARE
v_aanduiding VARCHAR2 (200);
v_errorhint VARCHAR2 (1000);
v_errormsg VARCHAR2 (1000);
oracle_err_num NUMBER;
oracle_err_mes VARCHAR2 (200);
v_mldkey NUMBER (10);
CURSOR mld IS
SELECT x.*
FROM (SELECT 1
meldbron_key, -- Onbekend/Of Internet=5?
x.fac_imp_csv_col01
referentie,
1
alg_locatie_key, -- Willemsoord 66
fac.safe_to_date (x.fac_imp_csv_col02,
'yyyy-mm-dd hh24:mi')
datum,
SUBSTR (TRIM (x.fac_imp_csv_col08), 1, 200)
onderwerp, -- Onderwerp
SUBSTR (TRIM (x.fac_imp_csv_col14), 1, 4000)
omschrijving, -- Omschrijving
SUBSTR (TRIM (x.fac_imp_csv_col15), 1, 4000)
actie, -- Actie
fac_imp_csv_col05
Soort_melding,
DECODE (
(SELECT stdm.mld_stdmelding_key
FROM mld_stdmelding stdm, ins_tab_discipline d
WHERE d.ins_discipline_key =
stdm.mld_ins_discipline_key
AND d.ins_discipline_module = 'MLD'
AND d.ins_discipline_verwijder IS NULL
AND UPPER (d.ins_discipline_omschrijving) =
UPPER (x.fac_imp_csv_col06)
AND UPPER (
stdm.mld_stdmelding_omschrijving) =
UPPER (x.fac_imp_csv_col07)),
NULL, 2,
DECODE (fac_imp_csv_col05,
'Aanvraag', 1,
'Gebruikersvraag', 1,
'Storing', 2,
'Wens', 1))
vakgroeptype_key,
DECODE (
(SELECT stdm.mld_stdmelding_key
FROM mld_stdmelding stdm, ins_tab_discipline d
WHERE d.ins_discipline_key =
stdm.mld_ins_discipline_key
AND d.ins_discipline_module = 'MLD'
AND d.ins_discipline_verwijder IS NULL
AND UPPER (d.ins_discipline_omschrijving) =
UPPER (x.fac_imp_csv_col06)
AND UPPER (
stdm.mld_stdmelding_omschrijving) =
UPPER (x.fac_imp_csv_col07)),
NULL, 140,
(SELECT d.ins_discipline_key
FROM mld_stdmelding stdm, ins_tab_discipline d
WHERE d.ins_discipline_key =
stdm.mld_ins_discipline_key
AND d.ins_discipline_module = 'MLD'
AND d.ins_discipline_verwijder IS NULL
AND UPPER (d.ins_discipline_omschrijving) =
UPPER (x.fac_imp_csv_col06)
AND UPPER (
stdm.mld_stdmelding_omschrijving) =
UPPER (x.fac_imp_csv_col07)))
vakgroep_key,
DECODE (
(SELECT stdm.mld_stdmelding_key
FROM mld_stdmelding stdm, ins_tab_discipline d
WHERE d.ins_discipline_key =
stdm.mld_ins_discipline_key
AND d.ins_discipline_module = 'MLD'
AND d.ins_discipline_verwijder IS NULL
AND UPPER (d.ins_discipline_omschrijving) =
UPPER (x.fac_imp_csv_col06)
AND UPPER (
stdm.mld_stdmelding_omschrijving) =
UPPER (x.fac_imp_csv_col07)),
NULL, 167,
(SELECT stdm.mld_stdmelding_default_disc
FROM mld_stdmelding stdm, ins_tab_discipline d
WHERE d.ins_discipline_key =
stdm.mld_ins_discipline_key
AND d.ins_discipline_module = 'MLD'
AND d.ins_discipline_verwijder IS NULL
AND UPPER (d.ins_discipline_omschrijving) =
UPPER (x.fac_imp_csv_col06)
AND UPPER (
stdm.mld_stdmelding_omschrijving) =
UPPER (x.fac_imp_csv_col07)))
behandelteam_key,
COALESCE (
(SELECT stdm.mld_stdmelding_key
FROM mld_stdmelding stdm, ins_tab_discipline d
WHERE d.ins_discipline_key =
stdm.mld_ins_discipline_key
AND d.ins_discipline_module = 'MLD'
AND d.ins_discipline_verwijder IS NULL
AND UPPER (d.ins_discipline_omschrijving) =
UPPER (x.fac_imp_csv_col06)
AND UPPER (
stdm.mld_stdmelding_omschrijving) =
UPPER (x.fac_imp_csv_col07)),
381)
stdmelding_key,
x.fac_imp_csv_col07,
x.fac_imp_csv_col05
|| ' - '
|| x.fac_imp_csv_col06
|| ' - '
|| x.fac_imp_csv_col07
categorie_topdesk,
fac.safe_to_date (x.fac_imp_csv_col13,
'yyyy-mm-dd hh24:mi')
afgemeld,
TRIM (x.fac_imp_csv_col03)
aanvrager,
TRIM (x.fac_imp_csv_col04)
aanvrager_email,
COALESCE (pm1.max_perslid_key,
pm2.min_perslid_key,
12141)
melder_key, -- Persoon Onbekend = 12141
x.fac_imp_csv_col14
verzoek,
TRIM (x.fac_imp_csv_col11)
behandelaar,
COALESCE (pb1.max_perslid_key, pb2.min_perslid_key)
behandelaar_key, -- Nooit op persoon Onbekend
x.fac_imp_csv_col09
status, -- Status
DECODE (UPPER (TRIM (x.fac_imp_csv_col09)),
'GEREGISTREERD', 2, -- Nieuw
'IN BEHANDELING', 4, -- In behandeling
'REACTIE ONTVANGEN', 4, -- In behandeling
'GEANNULEERD', 1, -- Afgewezen
'WACHT OP LEVERANCIER', 4, -- In behandeling
'WACHT OP AANMELDER', 4, -- In behandeling
'AFGEMELD', 5, -- Afgemeld
'GEREED', 5, -- Afgemeld
5) -- Afgemeld=Behandeld of Voorlopig afgesloten in Topdesk?
melding_status,
TRIM (x.fac_imp_csv_col03)
aanmaker,
TRIM (x.fac_imp_csv_col04)
aanmaker_email
FROM fac_imp_csv x,
( SELECT SUBSTR (prs_perslid_email,
1,
INSTR (prs_perslid_email, '@') - 1)
prs_perslid_email,
COUNT (*)
aantal,
MAX (prs_perslid_key)
max_perslid_key
FROM prs_v_aanwezigperslid
GROUP BY SUBSTR (prs_perslid_email,
1,
INSTR (prs_perslid_email, '@') - 1))
pm1,
( SELECT UPPER (
TRIM (
prs_perslid_naam
|| ', '
|| prs_perslid_voornaam
|| ' '
|| prs_perslid_tussenvoegsel))
naam,
COUNT (*)
aantal,
MIN (prs_perslid_key)
min_perslid_key
FROM prs_v_aanwezigperslid
GROUP BY UPPER (
TRIM (
prs_perslid_naam
|| ', '
|| prs_perslid_voornaam
|| ' '
|| prs_perslid_tussenvoegsel))) pm2,
( SELECT SUBSTR (prs_perslid_email,
1,
INSTR (prs_perslid_email, '@') - 1)
prs_perslid_email,
COUNT (*)
aantal,
MAX (prs_perslid_key)
max_perslid_key
FROM prs_v_aanwezigperslid
GROUP BY SUBSTR (prs_perslid_email,
1,
INSTR (prs_perslid_email, '@') - 1))
pb1,
( SELECT UPPER (
TRIM (
prs_perslid_naam
|| ', '
|| prs_perslid_voornaam
|| ' '
|| prs_perslid_tussenvoegsel))
naam,
COUNT (*)
aantal,
MIN (prs_perslid_key)
min_perslid_key
FROM prs_v_aanwezigperslid
GROUP BY UPPER (
TRIM (
prs_perslid_naam
|| ', '
|| prs_perslid_voornaam
|| ' '
|| prs_perslid_tussenvoegsel))) pb2
WHERE fac_imp_csv_col01 != 'Meldingnummer'
AND fac_imp_csv_col01 = 'M2402 0160'
AND UPPER (
TRIM (
SUBSTR (
x.fac_imp_csv_col04,
1,
INSTR (x.fac_imp_csv_col04, '@') - 1))) =
UPPER (pm1.prs_perslid_email(+))
AND UPPER (TRIM (x.fac_imp_csv_col03)) =
UPPER (pm2.naam(+))
AND UPPER (
TRIM (
SUBSTR (
x.fac_imp_csv_col11,
1,
INSTR (x.fac_imp_csv_col11, '@') - 1))) =
UPPER (pb1.prs_perslid_email(+))
AND UPPER (TRIM (x.fac_imp_csv_col11)) =
UPPER (pb2.naam(+))) x
ORDER BY 2;
BEGIN
fac.writelog (
'MIGRATIE_MLD',
'S',
'Meldingen/INIT: ' || TO_CHAR (SYSDATE, 'DD-MM-YYYY HH24:MI:SS'),
'');
COMMIT;
FOR rec IN mld
LOOP
BEGIN
v_aanduiding :=
'[' || rec.referentie || '|' || rec.aanvrager_email || ']';
v_errormsg := 'Fout toevoegen melding.';
INSERT INTO mld_melding (mld_melding_module,
mld_meldbron_key,
mld_meldbron_nr,
mld_alg_locatie_key,
mld_alg_onroerendgoed_keys,
mld_melding_datum,
mld_melding_onderwerp,
mld_melding_omschrijving,
mld_melding_behandelaar_key,
mld_melding_behandelaar2_key,
mld_ins_discipline_key,
mld_stdmelding_key,
mld_melding_t_uitvoertijd,
mld_melding_einddatum,
prs_kostenplaats_key,
prs_perslid_key,
prs_perslid_key_voor,
mld_melding_status,
mld_melding_spoed,
mld_melding_opmerking)
VALUES (
'MLD',
rec.meldbron_key,
rec.referentie, -- Ook in Omschrijving?
rec.alg_locatie_key,
rec.alg_locatie_key,
rec.datum,
rec.onderwerp,
'['
|| rec.referentie
|| ']'
|| CHR (13)
|| CHR (10)
|| rec.omschrijving,
NULL, -- mld_melding_behandelaar_key
rec.behandelaar_key, -- mld_melding_behandelaar2_key
rec.behandelteam_key, -- mld_ins_discipline_key
rec.stdmelding_key,
NULL,
COALESCE (
rec.afgemeld,
DECODE (rec.melding_status,
5, TRUNC (SYSDATE),
NULL)),
NULL,
rec.melder_key,
rec.melder_key,
rec.melding_status,
3, -- TODO???
NULL)
RETURNING mld_melding_key
INTO v_mldkey;
v_errormsg := 'Fout toevoegen notitie';
INSERT INTO mld_melding_note (mld_melding_key,
mld_melding_note_aanmaak,
mld_melding_note_wijzigdatum,
prs_perslid_key,
mld_melding_note_omschrijving,
mld_melding_note_flag)
VALUES (
v_mldkey,
rec.datum,
SYSDATE,
NULL, -- Facilitor
'Aanvrager: '
|| rec.aanvrager
|| DECODE (
rec.behandelaar,
NULL, '',
CHR (13)
|| CHR (10)
|| 'Behandelaar: '
|| rec.behandelaar)
|| DECODE (
rec.status,
NULL, '',
CHR (13)
|| CHR (10)
|| 'Status: '
|| rec.status)
|| DECODE (
UPPER (rec.aanmaker_email),
UPPER (rec.aanvrager_email), '',
CHR (13)
|| CHR (10)
|| 'Melder: '
|| rec.aanmaker),
1);
INSERT INTO mld_melding_note (mld_melding_key,
mld_melding_note_aanmaak,
mld_melding_note_wijzigdatum,
prs_perslid_key,
mld_melding_note_omschrijving,
mld_melding_note_flag)
VALUES (v_mldkey,
rec.datum,
SYSDATE,
NULL, -- Facilitor
rec.actie,
1);
v_errormsg := 'Fout vullen kenmerk Categorie_migratie';
INSERT INTO mld_kenmerkmelding (mld_kenmerk_key,
mld_melding_key,
mld_kenmerkmelding_waarde)
VALUES (581, v_mldkey, rec.categorie_topdesk);
fac.trackaction ('MLDNEW',
v_mldkey,
NULL,
SYSDATE,
'Gemigreerd vanuit Topdesk');
EXCEPTION
WHEN OTHERS
THEN
oracle_err_num := SQLCODE;
oracle_err_mes := SUBSTR (SQLERRM, 1, 200);
v_errormsg :=
v_errormsg
|| ' ORACLE (error '
|| oracle_err_num
|| '/'
|| oracle_err_mes
|| ')';
fac.writelog ('MIGRATIE_MLD',
'E',
v_errormsg,
v_aanduiding);
END;
END LOOP;
fac.writelog (
'MIGRATIE_MLD',
'S',
'Meldingen/DONE: ' || TO_CHAR (SYSDATE, 'DD-MM-YYYY HH24:MI:SS'),
'');
COMMIT;
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