316 lines
12 KiB
SQL
316 lines
12 KiB
SQL
--
|
|
-- $Id$
|
|
--
|
|
-- Script containing customer specific db-configuration for LOGC.
|
|
DEFINE thisfile = 'LOGC.SQL'
|
|
DEFINE dbuser = '^LOGC'
|
|
|
|
SET ECHO ON
|
|
SET DEFINE ON
|
|
COLUMN fcltlogfile NEW_VALUE fcltlogfile NOPRINT;
|
|
WHENEVER SQLERROR EXIT;
|
|
SELECT adm.scriptspoolfile('&dbuser', '&thisfile') AS fcltlogfile FROM DUAL;
|
|
WHENEVER SQLERROR CONTINUE;
|
|
SPOOL &fcltlogfile
|
|
SET DEFINE OFF
|
|
|
|
------ payload begin ------
|
|
|
|
CREATE OR REPLACE VIEW logc_v_my_activity
|
|
AS
|
|
SELECT to_date('1900-01-01', 'YYYY-MM-DD') - mld_melding_note_aanmaak HIDE_F_SORT,
|
|
n.prs_perslid_key,
|
|
n.mld_melding_note_aanmaak,
|
|
mld_melding_onderwerp,
|
|
n.mld_melding_note_omschrijving,
|
|
n.mld_melding_key
|
|
FROM mld_melding_note n, mld_melding m
|
|
WHERE n.mld_melding_key = m.mld_melding_key
|
|
UNION ALL
|
|
SELECT to_date('1900-01-01', 'YYYY-MM-DD') - fac_tracking_datum HIDE_F_SORT,
|
|
tr.prs_perslid_key,
|
|
tr.fac_tracking_datum,
|
|
mld_melding_onderwerp,
|
|
COALESCE (tr.fac_tracking_oms, LCL.L ('lcl_mld_is_' || LOWER (fac_srtnotificatie_code), 1)),
|
|
fac_tracking_refkey mld_melding_key
|
|
FROM fac_tracking tr, fac_srtnotificatie str, mld_melding m
|
|
WHERE tr.fac_tracking_refkey = m.mld_melding_key
|
|
AND tr.fac_srtnotificatie_key = str.fac_srtnotificatie_key
|
|
AND str.fac_srtnotificatie_code <> 'MLDNOT' -- beetje dubbelop
|
|
AND str.fac_srtnotificatie_xmlnode IN ('melding')
|
|
ORDER BY mld_melding_note_aanmaak DESC;
|
|
|
|
CREATE OR REPLACE VIEW logc_v_rap_releasenotes
|
|
AS
|
|
SELECT m.mld_melding_key,
|
|
TRIM(NVL (
|
|
SUBSTR (mld_melding_opmerking,
|
|
0,
|
|
INSTR (mld_melding_opmerking, '*') - 1),
|
|
mld_melding_opmerking)
|
|
|| ' ('
|
|
|| m.mld_melding_key
|
|
|| ')')
|
|
onderwerp,
|
|
NVL (
|
|
SUBSTR (mld_melding_opmerking,
|
|
INSTR (mld_melding_opmerking, '*') + 2),
|
|
mld_melding_opmerking)
|
|
omchrijving,
|
|
st.mld_statuses_omschrijving status,
|
|
mld_kenmerkmelding_waarde fixversie,
|
|
CASE WHEN mld_melding_opmerking LIKE '--%' THEN 'Ja' ELSE 'Nee' END
|
|
intern
|
|
FROM mld_melding m, mld_kenmerkmelding mk, mld_statuses st
|
|
WHERE m.mld_melding_key = mk.mld_melding_key
|
|
AND mld_kenmerk_key = 25
|
|
AND m.mld_melding_status = st.mld_statuses_key;
|
|
|
|
|
|
--- IMPORT VAN URENBESTEDING FSN#51729
|
|
-- Requires
|
|
-- een flexkenmerk (op vakgroeptypeniveau) voor registratie van de bestede uren. De key is constante l_bestedingsflexkey
|
|
-- type iets van 8,2 en geen relevante min/max. Alleen lezen is goed genoeg
|
|
|
|
CREATE OR REPLACE PROCEDURE logc_import_besteding (p_import_key IN NUMBER)
|
|
IS
|
|
c_delim VARCHAR2 (1) := ';';
|
|
v_newline fac_imp_file.fac_imp_file_line%TYPE; -- Input line
|
|
v_errormsg VARCHAR2 (1000);
|
|
oracle_err_num NUMBER;
|
|
oracle_err_mes VARCHAR2 (200);
|
|
v_aanduiding VARCHAR2 (200) := '';
|
|
header_is_valid NUMBER := 0;
|
|
v_count_tot NUMBER (10) := 0;
|
|
v_count_import NUMBER (10) := 0;
|
|
v_ongeldig NUMBER (1);
|
|
-- De importvelden:
|
|
v_transactietekst VARCHAR2 (100);
|
|
v_projectnummer VARCHAR2 (100);
|
|
v_uren VARCHAR2 (25);
|
|
|
|
CURSOR c1
|
|
IS
|
|
SELECT *
|
|
FROM fac_imp_file
|
|
WHERE fac_import_key = p_import_key
|
|
ORDER BY fac_imp_file_index;
|
|
BEGIN
|
|
DELETE FROM logc_imp_besteding;
|
|
|
|
COMMIT;
|
|
|
|
FOR rec1 IN c1
|
|
LOOP
|
|
BEGIN
|
|
v_newline := rec1.fac_imp_file_line;
|
|
v_errormsg := 'Fout bij opvragen importregel';
|
|
v_aanduiding := '';
|
|
v_ongeldig := 0;
|
|
|
|
-- Lees alle veldwaarden
|
|
fac.imp_getfield (v_newline, c_delim, v_transactietekst);
|
|
fac.imp_getfield (v_newline, c_delim, v_projectnummer);
|
|
fac.imp_getfield (v_newline, c_delim, v_uren);
|
|
v_aanduiding := '[' || v_transactietekst || '] ';
|
|
|
|
-- Ik controleer of ik een geldige header heb, dat is: in de juiste kolommen
|
|
-- de juiste kolomkop. Ik controleer daarbij ALLE kolommen!
|
|
-- Ik negeer alles totdat ik een geldige header ben gepasseerd.
|
|
-- Transactietekst;MaxString(Project);Sum(Uren)
|
|
IF (header_is_valid = 0)
|
|
THEN
|
|
IF UPPER (v_transactietekst) = 'TRANSACTIETEKST'
|
|
AND UPPER (v_projectnummer) = 'MAXSTRING(PROJECT)'
|
|
AND UPPER (v_uren) = 'SUM(UREN)'
|
|
THEN
|
|
header_is_valid := 1;
|
|
END IF;
|
|
ELSE
|
|
v_count_tot := v_count_tot + 1;
|
|
|
|
-- Controleer alle veldwaarden
|
|
v_errormsg := 'Transactietekst (logcentrenummer) ongeldig/ongedefinieerd of te lang';
|
|
v_transactietekst := TRIM (v_transactietekst);
|
|
|
|
IF v_transactietekst IS NULL OR LENGTH (v_transactietekst) > 20 OR INSTR (v_transactietekst, '#') = 0
|
|
THEN
|
|
v_ongeldig := 1;
|
|
fac.imp_writelog (p_import_key,
|
|
'W',
|
|
v_aanduiding || v_errormsg,
|
|
'Regel wordt overgeslagen!');
|
|
END IF;
|
|
|
|
--
|
|
v_errormsg := 'Projectnummer ongeldig/ongedefinieerd of te lang';
|
|
v_projectnummer := TRIM (v_projectnummer);
|
|
|
|
IF v_projectnummer IS NULL OR LENGTH (v_projectnummer) > 100
|
|
THEN
|
|
v_ongeldig := 1;
|
|
fac.imp_writelog (p_import_key,
|
|
'W',
|
|
v_aanduiding || v_errormsg,
|
|
'Regel wordt overgeslagen!');
|
|
END IF;
|
|
|
|
--
|
|
v_errormsg := 'Uren ongeldig';
|
|
v_uren := TRIM (v_uren);
|
|
|
|
IF (v_uren IS NOT NULL AND fac.safe_to_number (replace(v_uren,',','.')) IS NULL)
|
|
THEN
|
|
v_ongeldig := 1;
|
|
fac.imp_writelog (p_import_key,
|
|
'W',
|
|
v_aanduiding || v_errormsg,
|
|
'Regel wordt overgeslagen!');
|
|
END IF;
|
|
|
|
-- Insert geformatteerde import record
|
|
IF v_ongeldig = 0
|
|
THEN
|
|
BEGIN
|
|
v_errormsg := 'Fout bij wegschrijven importregel';
|
|
|
|
INSERT INTO logc_imp_besteding (transactietekst, projectnummer, uren)
|
|
VALUES (v_transactietekst, v_projectnummer, fac.safe_to_number (replace(v_uren,',','.')));
|
|
|
|
v_count_import := v_count_import + 1;
|
|
EXCEPTION
|
|
WHEN OTHERS
|
|
THEN
|
|
oracle_err_num := SQLCODE;
|
|
oracle_err_mes := SUBSTR (SQLERRM, 1, 200);
|
|
v_errormsg := v_errormsg || oracle_err_num || '/' || oracle_err_mes || ')';
|
|
fac.imp_writelog (p_import_key,
|
|
'E',
|
|
v_aanduiding || v_errormsg,
|
|
'');
|
|
END;
|
|
|
|
COMMIT;
|
|
END IF;
|
|
END IF;
|
|
END;
|
|
END LOOP;
|
|
|
|
IF (header_is_valid = 0)
|
|
THEN
|
|
fac.imp_writelog (p_import_key,
|
|
'E',
|
|
'Ongeldig importbestand',
|
|
'Geen header of header niet volgens specificatie!');
|
|
ELSE
|
|
fac.imp_writelog (p_import_key,
|
|
'S',
|
|
'Besteding: #ingelezen importregels = ' || TO_CHAR (v_count_tot),
|
|
'');
|
|
fac.imp_writelog (p_import_key,
|
|
'S',
|
|
'Besteding: #ongeldige importregels = ' || TO_CHAR (v_count_tot - v_count_import),
|
|
'');
|
|
END IF;
|
|
|
|
COMMIT;
|
|
EXCEPTION
|
|
WHEN OTHERS
|
|
THEN
|
|
oracle_err_num := SQLCODE;
|
|
oracle_err_mes := SUBSTR (SQLERRM, 1, 200);
|
|
v_errormsg := v_errormsg || oracle_err_num || '/' || oracle_err_mes || ')';
|
|
fac.imp_writelog (p_import_key,
|
|
'E',
|
|
v_aanduiding || v_errormsg,
|
|
'Inleesproces besteding afgebroken!');
|
|
END logc_import_besteding;
|
|
/
|
|
|
|
CREATE OR REPLACE PROCEDURE logc_update_besteding (p_import_key IN NUMBER)
|
|
AS
|
|
CURSOR c1
|
|
IS
|
|
SELECT * FROM logc_imp_besteding;
|
|
|
|
v_errormsg VARCHAR2 (1000) := '';
|
|
oracle_err_num NUMBER;
|
|
oracle_err_mes VARCHAR2 (200);
|
|
v_count NUMBER (10);
|
|
v_count_tot NUMBER (10);
|
|
v_count_upd NUMBER (10);
|
|
l_meldingnr NUMBER (10);
|
|
l_bestedingsflexkey NUMBER (10) := 141; -- constante
|
|
BEGIN
|
|
v_count_tot := 0;
|
|
v_count_upd := 0;
|
|
|
|
FOR rec IN c1
|
|
LOOP
|
|
BEGIN
|
|
v_count_tot := v_count_tot + 1;
|
|
v_errormsg := 'Fout bij bepalen bestaan transactietekst [' || rec.transactietekst || '] ';
|
|
|
|
l_meldingnr := SUBSTR (rec.transactietekst, INSTR (rec.transactietekst, '#') + 1);
|
|
|
|
SELECT COUNT ( * )
|
|
INTO v_count
|
|
FROM mld_melding
|
|
WHERE mld_melding_key = l_meldingnr;
|
|
|
|
IF (v_count = 1)
|
|
THEN
|
|
v_errormsg := 'Fout bij bijwerken besteding [' || rec.transactietekst || ' (' || l_meldingnr || ')] ';
|
|
mld.upsertmeldingkenmerk (l_bestedingsflexkey, l_meldingnr, rec.uren);
|
|
-- jammer dat de upsert geen tracking doet
|
|
END IF;
|
|
|
|
v_count_upd := v_count_upd + 1;
|
|
EXCEPTION
|
|
WHEN OTHERS
|
|
THEN
|
|
oracle_err_num := SQLCODE;
|
|
oracle_err_mes := SUBSTR (SQLERRM, 1, 200);
|
|
v_errormsg := v_errormsg || oracle_err_num || '/' || oracle_err_mes || ')';
|
|
fac.imp_writelog (p_import_key,
|
|
'E',
|
|
v_errormsg,
|
|
'');
|
|
COMMIT;
|
|
END;
|
|
END LOOP;
|
|
|
|
fac.imp_writelog (p_import_key,
|
|
'S',
|
|
'Besteding: #ingelezen = ' || TO_CHAR (v_count_tot),
|
|
'');
|
|
fac.imp_writelog (p_import_key,
|
|
'S',
|
|
'Besteding: #toegevoegd/bijgewerkt = ' || TO_CHAR (v_count_upd),
|
|
'');
|
|
COMMIT;
|
|
EXCEPTION
|
|
WHEN OTHERS
|
|
THEN
|
|
oracle_err_num := SQLCODE;
|
|
oracle_err_mes := SUBSTR (SQLERRM, 1, 200);
|
|
v_errormsg := v_errormsg || oracle_err_num || '/' || oracle_err_mes || ')';
|
|
fac.imp_writelog (p_import_key,
|
|
'E',
|
|
v_errormsg,
|
|
'Importproces Besteding afgebroken!');
|
|
END logc_update_besteding;
|
|
/
|
|
|
|
------ 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
|