WRTH#87183 -- View tbv kalender rapport TD opdrachten
svn path=/Customer/trunk/; revision=68908
This commit is contained in:
318
WRTH/wrth.sql
Normal file
318
WRTH/wrth.sql
Normal file
@@ -0,0 +1,318 @@
|
||||
--
|
||||
-- $Id$
|
||||
--
|
||||
-- Script containing customer specific db-configuration for WRTH.
|
||||
DEFINE thisfile = 'WRTH.SQL'
|
||||
DEFINE dbuser = '^WRTH'
|
||||
|
||||
SET ECHO ON
|
||||
SET DEFINE ON
|
||||
COLUMN fcltlogfile NEW_VALUE fcltlogfile NOPRINT;
|
||||
COLUMN fcltcusttxt NEW_VALUE fcltcusttxt NOPRINT;
|
||||
WHENEVER SQLERROR CONTINUE;
|
||||
SELECT adm.getscriptspoolfile('&thisfile') AS fcltlogfile FROM DUAL;
|
||||
SPOOL &fcltlogfile
|
||||
WHENEVER SQLERROR EXIT;
|
||||
SELECT adm.checkscriptcust('&dbuser') AS fcltcusttxt FROM DUAL;
|
||||
WHENEVER SQLERROR CONTINUE;
|
||||
---------------------------------------
|
||||
PROMPT &fcltcusttxt
|
||||
---------------------------------------
|
||||
SET DEFINE OFF
|
||||
|
||||
------ payload begin ------
|
||||
|
||||
CREATE OR REPLACE VIEW wrth_v_rap_opdrkalender
|
||||
AS
|
||||
SELECT o.mld_opdr_key opdrkey,
|
||||
COALESCE (mld_opdr_plandatum, mld_opdr_einddatum)
|
||||
plan_einddatum,
|
||||
so.mld_statusopdr_omschrijving
|
||||
status,
|
||||
p.prs_perslid_naam_friendly
|
||||
uitvoerder,
|
||||
o.mld_opdr_omschrijving
|
||||
omschrijving,
|
||||
m.mld_melding_key || '/' || o.mld_opdr_bedrijfopdr_volgnr
|
||||
opdrachtnummer,
|
||||
m.mld_melding_key
|
||||
|| '/'
|
||||
|| o.mld_opdr_bedrijfopdr_volgnr
|
||||
|| ' - '
|
||||
|| so.mld_statusopdr_omschrijving
|
||||
|| ' - '
|
||||
|| p.prs_perslid_naam_friendly
|
||||
|| ' - '
|
||||
|| substr (o.mld_opdr_omschrijving, 1, 60) || '...'
|
||||
kalenderinhoud
|
||||
FROM mld_opdr o,
|
||||
mld_melding m,
|
||||
prs_v_perslid_fullnames p,
|
||||
mld_statusopdr so
|
||||
WHERE o.mld_uitvoerende_keys = p.prs_perslid_key
|
||||
AND o.mld_melding_key = m.mld_melding_key
|
||||
AND o.mld_statusopdr_key = so.mld_statusopdr_key;
|
||||
|
||||
--Mail2Melding procedure
|
||||
CREATE OR REPLACE PROCEDURE WRTH_processemail (pfrom IN VARCHAR2,
|
||||
pto IN VARCHAR2,
|
||||
psubject IN VARCHAR2,
|
||||
pbody IN VARCHAR2,
|
||||
psessionid IN VARCHAR2,
|
||||
pemailkey IN NUMBER)
|
||||
AS
|
||||
c_onbekend_key NUMBER (10) := 4; -- TODO:API-user tbv. hMail-koppeling?
|
||||
v_errormsg VARCHAR2 (1000);
|
||||
oracle_err_num NUMBER;
|
||||
oracle_err_mes VARCHAR2 (200);
|
||||
v_perslid_key NUMBER (10);
|
||||
v_kostenplaats_key NUMBER (10);
|
||||
v_locatie_key NUMBER (10);
|
||||
v_exists_id VARCHAR2 (255);
|
||||
v_melding_key NUMBER (10);
|
||||
v_melder_key NUMBER (10);
|
||||
v_opdracht_key NUMBER (10);
|
||||
v_typeopdr_key NUMBER (10);
|
||||
v_discipline_key NUMBER (10);
|
||||
v_stdmelding_key NUMBER (10);
|
||||
v_folder_kkey NUMBER (10);
|
||||
subject_regexp VARCHAR2 (1000);
|
||||
v_mldnum VARCHAR2 (1000);
|
||||
v_count NUMBER (10);
|
||||
BEGIN
|
||||
CASE
|
||||
WHEN UPPER (pto) LIKE 'SERVICEDESK@%' OR UPPER (pto) LIKE 'MELDING@WURTH.NL'
|
||||
THEN
|
||||
-- Bepaal de mailer op basis van e-mail adres zoals in pfrom?
|
||||
v_errormsg := 'Fout bepalen mailer';
|
||||
SELECT COUNT ( * )
|
||||
INTO v_count
|
||||
FROM prs_v_aanwezigperslid
|
||||
WHERE UPPER (prs_perslid_email) LIKE UPPER (pfrom) || '%';
|
||||
|
||||
IF v_count = 1
|
||||
THEN
|
||||
SELECT p.prs_perslid_key, a.prs_kostenplaats_key
|
||||
INTO v_perslid_key, v_kostenplaats_key
|
||||
FROM prs_v_aanwezigperslid p, prs_afdeling a,
|
||||
(SELECT pw.prs_perslid_key, pw.prs_werkplek_key
|
||||
FROM prs_perslidwerkplek pw
|
||||
WHERE NOT EXISTS
|
||||
(SELECT 1
|
||||
FROM prs_perslidwerkplek
|
||||
WHERE prs_perslid_key = pw.prs_perslid_key
|
||||
AND prs_perslidwerkplek_key > pw.prs_perslidwerkplek_key)) pw,
|
||||
prs_v_werkplekperslid_gegevens wpg
|
||||
WHERE p.prs_afdeling_key = a.prs_afdeling_key
|
||||
AND UPPER (p.prs_perslid_email) LIKE UPPER (pfrom) || '%'
|
||||
AND p.prs_perslid_key = pw.prs_perslid_key(+)
|
||||
AND pw.prs_werkplek_key = wpg.prs_werkplek_key(+)
|
||||
GROUP BY p.prs_perslid_key, a.prs_kostenplaats_key;
|
||||
ELSE -- Melder kan niet 1-duidig worden bepaald, dus Onbekend (hmailuser)
|
||||
SELECT p.prs_perslid_key, a.prs_kostenplaats_key
|
||||
INTO v_perslid_key, v_kostenplaats_key
|
||||
FROM prs_v_aanwezigperslid p, prs_afdeling a
|
||||
WHERE p.prs_afdeling_key = a.prs_afdeling_key
|
||||
AND p.prs_perslid_key = c_onbekend_key;
|
||||
END IF;
|
||||
|
||||
-- 1) Eerst meldingnr 123 of opdrachtnr 123/1 gevolgd door spatie uit
|
||||
-- onderwerp proberen te bepalen.
|
||||
-- 2) Het eerste voorkomen beginnend met een cijfer wordt gezien als
|
||||
-- meldingnr of opdrachtnr en evt. andere voorkomens (verder naar
|
||||
-- rechts) worden genegeerd.
|
||||
v_errormsg := 'Fout bepalen melding/opdracht';
|
||||
v_exists_id := psubject;
|
||||
IF REGEXP_INSTR (v_exists_id, '\d') > 0
|
||||
THEN
|
||||
v_exists_id := SUBSTR (v_exists_id, REGEXP_INSTR (v_exists_id, '\d')) || ' '; -- Gedeelte vanaf eerste cijfer in v_exists_id plus ' '!
|
||||
v_exists_id := SUBSTR (v_exists_id, 1, REGEXP_INSTR (v_exists_id, '\s') - 1); -- Gedeelte tot eerste white space in v_exists_id!
|
||||
END IF;
|
||||
|
||||
IF INSTR (v_exists_id, '/') = 0 -- Slash in eerste voorkomen beginnend met een cijfer?
|
||||
THEN -- Melding
|
||||
v_errormsg := 'Fout bepalen melding ' || v_exists_id;
|
||||
SELECT MAX (mld_melding_key), MAX (prs_perslid_key) -- MAX() om te zorgen dat v_melding_key=NULL als meldingnr niet bestaat!
|
||||
INTO v_melding_key, v_melder_key
|
||||
FROM mld_melding
|
||||
WHERE mld_melding_key = fac.safe_to_number (v_exists_id);
|
||||
|
||||
IF v_melding_key IS NOT NULL
|
||||
THEN
|
||||
v_errormsg := 'Fout toevoegen notitie';
|
||||
INSERT INTO mld_melding_note (mld_melding_key,
|
||||
mld_melding_note_omschrijving,
|
||||
prs_perslid_key,
|
||||
mld_melding_note_flag)
|
||||
VALUES (v_melding_key,
|
||||
SUBSTR (psubject || CHR (13) || CHR (10) || SUBSTR (pbody, 1, 4000 - (LENGTH (psubject) + 2)), 1, 4000),
|
||||
v_perslid_key,
|
||||
DECODE (v_perslid_key, -- Notitie open=1 als mailer=melder, anders gesloten=0!
|
||||
v_melder_key, 1,
|
||||
0));
|
||||
|
||||
-- Default tracking is even goed genoeg.
|
||||
fac.trackaction ('MLDNOT', v_melding_key, v_perslid_key, NULL, '#Notitie toegevoegd vanuit e-mail'); -- # voorkomt notificatie
|
||||
|
||||
INSERT INTO fac_result (fac_result_sessionid, fac_result_naam, fac_result_waarde)
|
||||
VALUES (psessionid, 'maillog', 'Als notitie toegevoegd aan melding ' || TO_CHAR (v_melding_key));
|
||||
ELSE
|
||||
-- Bepaal de afgesproken soortmelding met key=281=intake melding
|
||||
v_errormsg := 'Fout bepalen soortmelding';
|
||||
SELECT mld_ins_discipline_key, mld_stdmelding_key
|
||||
INTO v_discipline_key, v_stdmelding_key
|
||||
FROM mld_stdmelding
|
||||
WHERE mld_stdmelding_key = 281;
|
||||
|
||||
-- Suggested extensions:
|
||||
-- - Check for MLDUSE-write autorisations
|
||||
-- - Parse the subject to find the appropriate stdmelding, if uniquely possible
|
||||
-- - Append (as a note?) to an existing melding if #key is found in the subject
|
||||
v_errormsg := 'Fout toevoegen melding';
|
||||
INSERT INTO mld_melding (mld_melding_module,
|
||||
mld_meldbron_key,
|
||||
mld_alg_locatie_key,
|
||||
mld_alg_onroerendgoed_keys,
|
||||
mld_melding_datum,
|
||||
mld_melding_omschrijving,
|
||||
mld_stdmelding_key,
|
||||
mld_melding_t_uitvoertijd,
|
||||
prs_kostenplaats_key,
|
||||
prs_perslid_key,
|
||||
prs_perslid_key_voor,
|
||||
mld_melding_status,
|
||||
mld_melding_spoed,
|
||||
mld_melding_onderwerp,
|
||||
mld_melding_behandelaar2_key,
|
||||
mld_ins_discipline_key)
|
||||
VALUES ('MLD',
|
||||
4, -- Email
|
||||
COALESCE (v_locatie_key, 49), -- Fallback op 49 HQ Den Bosch
|
||||
NULL, --v_onrgoed_keys,
|
||||
SYSDATE,
|
||||
SUBSTR (pbody, 1, 2000),
|
||||
v_stdmelding_key,
|
||||
NULL,
|
||||
v_kostenplaats_key,
|
||||
v_perslid_key,
|
||||
v_perslid_key,
|
||||
NULL,
|
||||
3, -- Prio normaal
|
||||
SUBSTR (psubject, 1, 80),
|
||||
NULL,
|
||||
NULL)
|
||||
RETURNING mld_melding_key
|
||||
INTO v_melding_key;
|
||||
|
||||
mld.setmeldingstatus (v_melding_key, 2, v_perslid_key);
|
||||
|
||||
INSERT INTO fac_result (fac_result_sessionid, fac_result_naam, fac_result_waarde)
|
||||
VALUES (psessionid, 'maillog', 'Geregistreerd onder melding ' || TO_CHAR (v_melding_key));
|
||||
END IF;
|
||||
|
||||
-- Find the lowest volgnummer of the Folder-flexfield.
|
||||
-- PAS OP: 'Alle vakgroeptypen'-kenmerken hier niet beschouwd en dat bijt
|
||||
-- dus nooit met kenmerk hieronder tbv. Originele mail!
|
||||
v_errormsg := 'Fout toevoegen melding-bijlage';
|
||||
SELECT MIN (k1.mld_kenmerk_key)
|
||||
INTO v_folder_kkey
|
||||
FROM mld_stdmelding sm1, ins_tab_discipline td1, mld_kenmerk k1, mld_srtkenmerk sk1
|
||||
WHERE sm1.mld_stdmelding_key = v_stdmelding_key
|
||||
AND sm1.mld_ins_discipline_key = td1.ins_discipline_key
|
||||
AND k1.mld_kenmerk_verwijder IS NULL
|
||||
AND k1.mld_srtkenmerk_key = sk1.mld_srtkenmerk_key
|
||||
AND sk1.mld_srtkenmerk_kenmerktype = 'M'
|
||||
AND (k1.mld_kenmerk_niveau = 'A'
|
||||
OR (k1.mld_stdmelding_key = sm1.mld_stdmelding_key AND k1.mld_kenmerk_niveau = 'S')
|
||||
OR (k1.mld_stdmelding_key = td1.ins_discipline_key AND k1.mld_kenmerk_niveau = 'D')
|
||||
OR (k1.mld_stdmelding_key = td1.ins_srtdiscipline_key AND k1.mld_kenmerk_niveau = 'T'))
|
||||
AND NOT EXISTS
|
||||
(SELECT 1
|
||||
FROM mld_stdmelding sm2, ins_tab_discipline td2, mld_kenmerk k2, mld_srtkenmerk sk2
|
||||
WHERE sm2.mld_stdmelding_key = v_stdmelding_key
|
||||
AND sm2.mld_ins_discipline_key = td2.ins_discipline_key
|
||||
AND k2.mld_kenmerk_verwijder IS NULL
|
||||
AND k2.mld_srtkenmerk_key = sk2.mld_srtkenmerk_key
|
||||
AND sk2.mld_srtkenmerk_kenmerktype = 'M'
|
||||
AND (k2.mld_kenmerk_niveau = 'A'
|
||||
OR (k2.mld_stdmelding_key = sm2.mld_stdmelding_key AND k2.mld_kenmerk_niveau = 'S')
|
||||
OR (k2.mld_stdmelding_key = td2.ins_discipline_key AND k2.mld_kenmerk_niveau = 'D')
|
||||
OR (k2.mld_stdmelding_key = td2.ins_srtdiscipline_key AND k2.mld_kenmerk_niveau = 'T'))
|
||||
AND k2.mld_kenmerk_volgnummer < k1.mld_kenmerk_volgnummer);
|
||||
|
||||
IF v_folder_kkey IS NOT NULL
|
||||
THEN
|
||||
INSERT INTO fac_result (fac_result_sessionid, fac_result_naam, fac_result_waarde)
|
||||
VALUES (psessionid, 'kenmerkpath', 'MLD\M' || TO_CHAR (TRUNC (v_melding_key / 1000), 'FM0000') || '___\M' || v_melding_key || '\' || v_folder_kkey || '\');
|
||||
END IF;
|
||||
ELSE -- Opdracht
|
||||
v_errormsg := 'Fout bepalen opdracht ' || v_exists_id;
|
||||
SELECT mld_opdr_key, mld_typeopdr_key
|
||||
INTO v_opdracht_key, v_typeopdr_key
|
||||
FROM mld_opdr
|
||||
WHERE TO_CHAR (mld_melding_key) || '/' || TO_CHAR (mld_opdr_bedrijfopdr_volgnr) = SUBSTR (v_exists_id, REGEXP_INSTR (v_exists_id, '\d'));
|
||||
|
||||
v_errormsg := 'Fout toevoegen opdracht-notitie';
|
||||
INSERT INTO mld_opdr_note (mld_opdr_key,
|
||||
prs_perslid_key,
|
||||
mld_opdr_note_omschrijving)
|
||||
VALUES (v_opdracht_key,
|
||||
v_perslid_key,
|
||||
pfrom || CHR (13) || CHR (10) || psubject || CHR (13) || CHR (10) || SUBSTR (pbody, 1, 2000));
|
||||
|
||||
v_errormsg := 'Fout bijwerken opdracht-kleurbolletje';
|
||||
UPDATE mld_opdr
|
||||
SET mld_opdr_flag = 1 -- Zwart
|
||||
WHERE mld_opdr_key = v_opdracht_key;
|
||||
|
||||
-- Find the lowest volgnummer of the Folder-flexfield.
|
||||
v_errormsg := 'Fout toevoegen opdracht-bijlage';
|
||||
SELECT MIN (k1.mld_kenmerk_key)
|
||||
INTO v_folder_kkey
|
||||
FROM mld_kenmerk k1, mld_srtkenmerk sk1
|
||||
WHERE k1.mld_typeopdr_key = v_typeopdr_key
|
||||
AND k1.mld_kenmerk_verwijder IS NULL
|
||||
AND k1.mld_kenmerk_niveau = 'O'
|
||||
AND k1.mld_srtkenmerk_key = sk1.mld_srtkenmerk_key
|
||||
AND sk1.mld_srtkenmerk_kenmerktype = 'M'
|
||||
AND NOT EXISTS
|
||||
(SELECT 1
|
||||
FROM mld_kenmerk k2, mld_srtkenmerk sk2
|
||||
WHERE k2.mld_typeopdr_key = v_typeopdr_key
|
||||
AND k2.mld_kenmerk_verwijder IS NULL
|
||||
AND k2.mld_kenmerk_niveau = 'O'
|
||||
AND k2.mld_srtkenmerk_key = sk2.mld_srtkenmerk_key
|
||||
AND sk2.mld_srtkenmerk_kenmerktype = 'M'
|
||||
AND k2.mld_kenmerk_volgnummer < k1.mld_kenmerk_volgnummer);
|
||||
|
||||
IF v_folder_kkey IS NOT NULL
|
||||
THEN
|
||||
INSERT INTO fac_result (fac_result_sessionid, fac_result_naam, fac_result_waarde)
|
||||
VALUES (psessionid, 'kenmerkpath', 'MLD\O' || TO_CHAR (TRUNC (v_opdracht_key / 1000), 'FM0000') || '___\O' || v_opdracht_key || '\' || v_folder_kkey || '\');
|
||||
END IF;
|
||||
END IF;
|
||||
END CASE;
|
||||
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 ('PROCESSEMAIL', 'E', 'WRTH_processemail afgebroken!', '[' || pfrom || '] ' || v_errormsg);
|
||||
INSERT INTO fac_result (fac_result_sessionid, fac_result_naam, fac_result_waarde)
|
||||
VALUES (psessionid, 'errormsg', 'Database fout - Neem contact op met uw systeembeheerder ');
|
||||
COMMIT;
|
||||
END;
|
||||
/
|
||||
|
||||
------ payload end ------
|
||||
|
||||
SET DEFINE OFF
|
||||
BEGIN adm.systrackscriptId ('$Id$', 0); END;
|
||||
/
|
||||
|
||||
COMMIT;
|
||||
SET ECHO OFF
|
||||
SPOOL OFF
|
||||
SET DEFINE ON
|
||||
PROMPT Logfile of this upgrade is: &fcltlogfile
|
||||
Reference in New Issue
Block a user