2312 lines
95 KiB
SQL
2312 lines
95 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;
|
|
/
|
|
|
|
-- import nieuwe versie die ook dag en medewerker registreert (SAP versie)
|
|
CREATE OR REPLACE PROCEDURE logc_import_uren_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);
|
|
v_field VARCHAR2(100);
|
|
v_index NUMBER (2);
|
|
v_maxdate DATE;
|
|
v_mindate DATE;
|
|
-- De importvelden:
|
|
v_transactietekst VARCHAR2 (1000);
|
|
v_project VARCHAR2 (100);
|
|
v_project_oms VARCHAR2 (100);
|
|
v_uren VARCHAR2 (25);
|
|
v_datum_txt VARCHAR2 (20);
|
|
v_categorie VARCHAR2 (100);
|
|
v_werknemer NUMBER (10);
|
|
|
|
i_transactietekst NUMBER(2);
|
|
i_project NUMBER(2);
|
|
i_project_oms NUMBER(2);
|
|
i_uren NUMBER(2);
|
|
i_datum_txt NUMBER(2);
|
|
i_categorie NUMBER(2);
|
|
i_werknemer NUMBER(2);
|
|
|
|
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_uren_besteding WHERE datum IS NULL;
|
|
|
|
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;
|
|
|
|
IF rec1.fac_imp_file_index = 1
|
|
THEN
|
|
v_index := 0;
|
|
v_field := 'QueQeLeQue';
|
|
WHILE v_field IS NOT NULL AND v_index < 30
|
|
LOOP
|
|
fac.imp_getfield (v_newline, c_delim, v_field);
|
|
v_index := v_index + 1;
|
|
CASE UPPER(v_field)
|
|
WHEN 'DATUM' THEN i_datum_txt := v_index;
|
|
WHEN 'ALGEMENE ONTVANGER' THEN i_project := v_index;
|
|
WHEN 'RUBRICERINGSOMS.' THEN i_project_oms := v_index;
|
|
WHEN 'PRESTATIESOORT' THEN i_categorie := v_index;
|
|
WHEN 'PERSONEELSNUMMER' THEN i_werknemer := v_index;
|
|
WHEN 'AANTAL (MAATEENHEID)' THEN i_uren := v_index;
|
|
WHEN 'K. TEKST' THEN i_transactietekst := v_index;
|
|
ELSE
|
|
NULL;
|
|
END CASE;
|
|
|
|
END LOOP;
|
|
IF i_datum_txt > 0
|
|
AND i_project > 0
|
|
AND i_project_oms > 0
|
|
AND i_categorie > 0
|
|
AND i_werknemer > 0
|
|
AND i_uren > 0
|
|
AND i_transactietekst > 0
|
|
THEN
|
|
header_is_valid := 1;
|
|
END IF;
|
|
ELSIF v_newline LIKE ';;;;;;%'
|
|
THEN
|
|
NULL; -- Lege regels slaan we over
|
|
ELSE
|
|
-- Lees alle veldwaarden
|
|
fac.imp_getfield_nr (v_newline, c_delim, i_transactietekst, v_transactietekst);
|
|
fac.imp_getfield_nr (v_newline, c_delim, i_project, v_project);
|
|
fac.imp_getfield_nr (v_newline, c_delim, i_project_oms, v_project_oms);
|
|
fac.imp_getfield_nr (v_newline, c_delim, i_uren, v_uren);
|
|
fac.imp_getfield_nr (v_newline, c_delim, i_datum_txt, v_datum_txt);
|
|
fac.imp_getfield_nr (v_newline, c_delim, i_categorie, v_categorie);
|
|
fac.imp_getfield_nr (v_newline, c_delim, i_werknemer, v_werknemer);
|
|
|
|
IF (header_is_valid = 1)
|
|
THEN
|
|
v_count_tot := v_count_tot + 1;
|
|
v_aanduiding := SUBSTR(v_transactietekst || ' ' || v_datum_txt || ' ' || v_categorie, 1, 200);
|
|
|
|
-- Controleer alle veldwaarden
|
|
--
|
|
v_errormsg := 'Categorie ongeldig';
|
|
v_categorie := TRIM (v_categorie);
|
|
|
|
IF (v_categorie IS NOT NULL AND LENGTH(v_categorie) > 10)
|
|
THEN
|
|
v_ongeldig := 1;
|
|
fac.imp_writelog (p_import_key,
|
|
'E',
|
|
v_aanduiding || v_errormsg,
|
|
'Regel wordt overgeslagen!');
|
|
END IF;
|
|
|
|
v_errormsg := 'Transactietekst (logcentrenummer) ongeldig/ongedefinieerd of te lang';
|
|
v_transactietekst := TRIM (v_transactietekst);
|
|
|
|
v_transactietekst := REPLACE (v_transactietekst, '# ', '#');
|
|
|
|
IF v_transactietekst IS NOT NULL AND INSTR(v_transactietekst, '#') > 0
|
|
THEN
|
|
v_transactietekst := REGEXP_SUBSTR (v_transactietekst , '[[:alpha:]]{0,}#[[:digit:]]{5,}', 1, 1, 'i');
|
|
IF v_transactietekst IS NULL
|
|
THEN
|
|
--v_ongeldig := 1;
|
|
fac.imp_writelog (p_import_key,
|
|
'W',
|
|
v_aanduiding || v_errormsg,
|
|
'');
|
|
END IF;
|
|
ELSE
|
|
v_transactietekst := NULL;
|
|
END IF;
|
|
|
|
--
|
|
v_errormsg := 'Project ongeldig/ongedefinieerd of te lang';
|
|
v_project := TRIM (v_project);
|
|
|
|
IF v_project IS NULL OR LENGTH (v_project) > 100
|
|
THEN
|
|
v_ongeldig := 1;
|
|
fac.imp_writelog (p_import_key,
|
|
'E',
|
|
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,
|
|
'E',
|
|
v_aanduiding || v_errormsg,
|
|
'Regel wordt overgeslagen!');
|
|
END IF;
|
|
|
|
--
|
|
v_errormsg := 'Datum ongeldig';
|
|
v_datum_txt := TRIM (v_datum_txt);
|
|
|
|
IF (v_datum_txt IS NOT NULL AND fac.safe_to_date (v_datum_txt,'dd-mm-yyyy') IS NULL)
|
|
THEN
|
|
v_ongeldig := 1;
|
|
fac.imp_writelog (p_import_key,
|
|
'E',
|
|
v_aanduiding || v_errormsg,
|
|
'Regel wordt overgeslagen!');
|
|
END IF;
|
|
|
|
|
|
--
|
|
v_errormsg := 'Werknemer ongeldig';
|
|
v_werknemer := TRIM (v_werknemer);
|
|
|
|
IF (v_werknemer IS NOT NULL AND fac.safe_to_number (v_werknemer) IS NULL)
|
|
THEN
|
|
v_ongeldig := 1;
|
|
fac.imp_writelog (p_import_key,
|
|
'E',
|
|
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_uren_besteding (transactietekst, project, project_oms, uren, datum_txt, categorie, werknemer)
|
|
VALUES (v_transactietekst, v_project, v_project_oms, fac.safe_to_number (replace(v_uren,',','.')), v_datum_txt, v_categorie, v_werknemer);
|
|
|
|
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 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!' || '(' ||
|
|
i_datum_txt || '-' ||
|
|
i_project || '-' ||
|
|
i_project_oms || '-' ||
|
|
i_categorie || '-' ||
|
|
i_werknemer || '-' ||
|
|
i_uren || '-' ||
|
|
i_transactietekst || ')');
|
|
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;
|
|
|
|
SELECT MAX (TO_DATE (datum_txt, 'dd-mm-yyyy')) maxdate,
|
|
MIN (TO_DATE (datum_txt, 'dd-mm-yyyy')) mindate,
|
|
COUNT(*)
|
|
INTO v_maxdate, v_mindate, v_count_import
|
|
FROM logc_imp_uren_besteding
|
|
WHERE datum IS NULL;
|
|
|
|
SELECT count(*)
|
|
INTO v_count_tot
|
|
FROM logc_imp_uren_besteding
|
|
WHERE datum IS NOT NULL
|
|
AND datum >= v_mindate
|
|
AND datum <= v_maxdate;
|
|
|
|
fac.imp_writelog (p_import_key,
|
|
'S',
|
|
'Besteding: #ingelezen importregels = ' || TO_CHAR (v_count_import) || ' vervangt #regels uit import = ' || TO_CHAR (v_count_tot),
|
|
'');
|
|
|
|
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_uren_besteding;
|
|
/
|
|
|
|
|
|
CREATE OR REPLACE PROCEDURE logc_update_uren_besteding (p_import_key IN NUMBER)
|
|
AS
|
|
|
|
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
|
|
v_maxdate DATE;
|
|
v_mindate DATE;
|
|
BEGIN
|
|
v_count_tot := 0;
|
|
v_count_upd := 0;
|
|
|
|
SELECT MAX (TO_DATE (datum_txt, 'dd-mm-yyyy')) maxdate,
|
|
MIN (TO_DATE (datum_txt, 'dd-mm-yyyy')) mindate
|
|
INTO v_maxdate, v_mindate
|
|
FROM logc_imp_uren_besteding
|
|
WHERE datum IS NULL;
|
|
|
|
-- We verwijderen de data die we nu (opnieuw) ontvangen hebben. Misschien zit er een correctieregel bij.
|
|
DELETE logc_imp_uren_besteding
|
|
WHERE datum IS NOT NULL
|
|
AND datum >= v_mindate
|
|
AND datum <= v_maxdate;
|
|
|
|
-- Voeg de keys van de meldingen toe.
|
|
UPDATE logc_imp_uren_besteding i
|
|
SET mld_melding_key = (SELECT mld_melding_key
|
|
FROM mld_melding m
|
|
WHERE m.mld_melding_key = fac.safe_to_number(SUBSTR(i.transactietekst, instr(transactietekst, '#')+1,100)))
|
|
WHERE datum IS NULL;
|
|
|
|
-- En set de datum om naar een echt datumveld. Dat maakt de rapportages makkelijker.
|
|
UPDATE logc_imp_uren_besteding i
|
|
SET datum = TO_DATE (datum_txt, 'dd-mm-yyyy')
|
|
WHERE datum IS NULL;
|
|
|
|
|
|
|
|
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_uren_besteding;
|
|
/
|
|
|
|
|
|
CREATE OR REPLACE VIEW logc_v_uren_bron
|
|
AS
|
|
SELECT u.project,
|
|
categorie,
|
|
uren,
|
|
m.mld_melding_key,
|
|
datum,
|
|
prs_perslid_naam,
|
|
project_oms,
|
|
COALESCE (
|
|
(SELECT fac.safe_to_number (prs_kenmerklink_waarde)
|
|
FROM prs_kenmerklink kl
|
|
WHERE kl.prs_kenmerk_key = 1280
|
|
AND kl.prs_link_key = p.prs_perslid_key),
|
|
40) upw,
|
|
ud.fac_usrdata_omschr afdeling,
|
|
COALESCE (
|
|
SUBSTR (su.fac_usrdata_omschr,
|
|
1,
|
|
INSTR (su.fac_usrdata_omschr, ' -- ') - 1),
|
|
'Onbekend') srturen,
|
|
DECODE (project_oms, 'Compensatie', 1, 0) compensatie,
|
|
p.prs_perslid_key,
|
|
a.prs_afdeling_naam,
|
|
COALESCE(a1.prs_afdeling_naam, a.prs_afdeling_naam) prs_afdeling_parent_naam,
|
|
COALESCE(a1.prs_afdeling_key, a.prs_afdeling_key) fclt_3d_afdeling_key
|
|
FROM logc_imp_uren_besteding u,
|
|
prs_perslid p,
|
|
prs_kenmerklink kl,
|
|
fac_usrdata ud,
|
|
prs_afdeling a,
|
|
prs_afdeling a1,
|
|
mld_melding m,
|
|
(SELECT distinct u2.project, ud.fac_usrdata_omschr
|
|
FROM fac_usrdata ud, logc_imp_uren_besteding u2
|
|
WHERE fac_usrtab_key = 281
|
|
AND u2.project LIKE ud.fac_usrdata_code) su
|
|
WHERE u.werknemer = p.prs_perslid_nr
|
|
AND u.project = su.project(+)
|
|
AND kl.prs_link_key = p.prs_perslid_key
|
|
AND kl.prs_kenmerk_key = 1300 -- Afdeling
|
|
AND FAC.safe_to_number(kl.prs_kenmerklink_waarde) = ud.fac_usrdata_key
|
|
AND u.mld_melding_key = m.mld_melding_key(+)
|
|
AND m.prs_afdeling_key = a.prs_afdeling_key(+)
|
|
and a.prs_afdeling_parentkey = a1.prs_afdeling_key(+)
|
|
AND datum > TO_DATE ('20200101', 'yyyymmdd');
|
|
|
|
CREATE OR REPLACE PROCEDURE logc_import_projecten (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);
|
|
v_field VARCHAR2 (100);
|
|
v_index NUMBER (2);
|
|
v_maxdate DATE;
|
|
v_mindate DATE;
|
|
-- De importvelden:
|
|
v_KlantOmschrijving VARCHAR2 (100);
|
|
v_WBSelement VARCHAR2 (100);
|
|
v_Projectsoort VARCHAR2 (100);
|
|
v_Omschrijving VARCHAR2 (100);
|
|
v_Status VARCHAR2 (100);
|
|
v_Debiteur VARCHAR2 (100);
|
|
v_PlanWorktime VARCHAR2 (100);
|
|
v_ActualWorktime VARCHAR2 (100);
|
|
v_ActualWorkCosts VARCHAR2 (100);
|
|
v_PlanWorkCosts VARCHAR2 (100);
|
|
v_InvoiceReceived VARCHAR2 (100);
|
|
v_InvoicePosted VARCHAR2 (100);
|
|
v_ProjektManagerLogin VARCHAR2 (100);
|
|
v_SalesPersonNr VARCHAR2 (100);
|
|
v_NameSalesPerson VARCHAR2 (100);
|
|
v_prs_kostenplaats_key NUMBER (10);
|
|
|
|
v_budgethouder_key NUMBER (10);
|
|
v_kostenplaats_key NUMBER (10);
|
|
v_kostenplaatsgrp_key NUMBER (10);
|
|
|
|
CURSOR c1 IS
|
|
SELECT *
|
|
FROM fac_imp_file
|
|
WHERE fac_import_key = p_import_key
|
|
ORDER BY fac_imp_file_index;
|
|
BEGIN
|
|
FOR rec1 IN c1
|
|
LOOP
|
|
BEGIN
|
|
v_newline := rec1.fac_imp_file_line;
|
|
v_errormsg := 'Fout bij opvragen importregel';
|
|
v_aanduiding := '';
|
|
v_ongeldig := 0;
|
|
|
|
IF v_newline LIKE ';;;;;;%'
|
|
THEN
|
|
NULL; -- Lege regels slaan we over
|
|
ELSE
|
|
-- Lees alle veldwaarden
|
|
fac.imp_getfield_nr (v_newline,
|
|
c_delim,
|
|
2,
|
|
v_KlantOmschrijving);
|
|
fac.imp_getfield_nr (v_newline,
|
|
c_delim,
|
|
3,
|
|
v_WBSelement);
|
|
fac.imp_getfield_nr (v_newline,
|
|
c_delim,
|
|
4,
|
|
v_Projectsoort);
|
|
fac.imp_getfield_nr (v_newline,
|
|
c_delim,
|
|
5,
|
|
v_Omschrijving);
|
|
fac.imp_getfield_nr (v_newline,
|
|
c_delim,
|
|
6,
|
|
v_Status);
|
|
fac.imp_getfield_nr (v_newline,
|
|
c_delim,
|
|
7,
|
|
v_Debiteur);
|
|
fac.imp_getfield_nr (v_newline,
|
|
c_delim,
|
|
10,
|
|
v_PlanWorktime);
|
|
fac.imp_getfield_nr (v_newline,
|
|
c_delim,
|
|
11,
|
|
v_ActualWorktime);
|
|
fac.imp_getfield_nr (v_newline,
|
|
c_delim,
|
|
12,
|
|
v_ActualWorkCosts);
|
|
fac.imp_getfield_nr (v_newline,
|
|
c_delim,
|
|
13,
|
|
v_PlanWorkCosts);
|
|
fac.imp_getfield_nr (v_newline,
|
|
c_delim,
|
|
14,
|
|
v_InvoiceReceived);
|
|
fac.imp_getfield_nr (v_newline,
|
|
c_delim,
|
|
15,
|
|
v_InvoicePosted);
|
|
fac.imp_getfield_nr (v_newline,
|
|
c_delim,
|
|
16,
|
|
v_ProjektManagerLogin);
|
|
fac.imp_getfield_nr (v_newline,
|
|
c_delim,
|
|
17,
|
|
v_SalesPersonNr);
|
|
fac.imp_getfield_nr (v_newline,
|
|
c_delim,
|
|
18,
|
|
v_NameSalesPerson);
|
|
|
|
IF (header_is_valid = 0)
|
|
THEN
|
|
IF UPPER (v_KlantOmschrijving) = 'OMSCHRIJVING'
|
|
AND UPPER (v_WBSelement) = 'WBS-ELEMENT'
|
|
AND UPPER (v_Projectsoort) = 'PROJECTSOORT'
|
|
AND UPPER (v_Omschrijving) = 'OMSCHRIJVING'
|
|
AND UPPER (v_Status) = 'STATUS'
|
|
AND UPPER (v_Debiteur) = 'DEBITEUR'
|
|
AND UPPER (v_PlanWorktime) = 'PLAN WORKTIME'
|
|
AND UPPER (v_ActualWorktime) = 'ACTUAL WORKTIME'
|
|
AND UPPER (v_ActualWorkCosts) = 'ACTUAL WORK COSTS'
|
|
AND UPPER (v_PlanWorkCosts) = 'PLAN WORK COSTS'
|
|
AND UPPER (v_InvoiceReceived) = 'INVOICE RECEIVED'
|
|
AND UPPER (v_InvoicePosted) = 'INVOICE POSTED'
|
|
AND UPPER (v_ProjektManagerLogin) = 'PROJEKTLEITER'
|
|
AND UPPER (v_SalesPersonNr) = 'SALES PERSON'
|
|
AND UPPER (v_NameSalesPerson) = 'NAME SALES REPRESEN'
|
|
THEN
|
|
header_is_valid := 1;
|
|
END IF;
|
|
ELSE
|
|
v_count_tot := v_count_tot + 1;
|
|
v_aanduiding := v_WBSelement || ' - ';
|
|
|
|
-- We gaan duizendtal tekens verwijderen en vervolgens de komma als scheidingsteken vervangen
|
|
-- door een punt
|
|
v_PlanWorktime := REPLACE(REPLACE(v_PlanWorktime, '.'), ',', '.');
|
|
v_ActualWorktime := REPLACE(REPLACE(v_ActualWorktime, '.'), ',', '.');
|
|
v_ActualWorkCosts := REPLACE(REPLACE(v_ActualWorkCosts, '.'), ',', '.');
|
|
v_PlanWorkCosts := REPLACE(REPLACE(v_PlanWorkCosts, '.'), ',', '.');
|
|
v_InvoiceReceived := REPLACE(REPLACE(v_InvoiceReceived, '.'), ',', '.');
|
|
v_InvoicePosted := REPLACE(REPLACE(v_InvoicePosted, '.'), ',', '.');
|
|
|
|
-- Controleer alle veldwaarden
|
|
--
|
|
v_errormsg := 'Projectsoort ongeldig ' || v_Projectsoort;
|
|
|
|
IF v_Projectsoort NOT IN ('WF', 'DA')
|
|
THEN
|
|
fac.imp_writelog (p_import_key,
|
|
'E',
|
|
v_aanduiding || v_errormsg,
|
|
'Regel wordt overgeslagen!');
|
|
ELSIF v_Projectsoort IS NULL
|
|
THEN
|
|
v_ongeldig := 1;
|
|
ELSE
|
|
BEGIN
|
|
SELECT prs_kostenplaatsgrp_key
|
|
INTO v_kostenplaatsgrp_key
|
|
FROM prs_kostenplaatsgrp
|
|
WHERE prs_kostenplaatsgrp_nr =
|
|
DECODE (v_Projectsoort,
|
|
'WF', 'F',
|
|
'DA', 'N');
|
|
EXCEPTION
|
|
WHEN NO_DATA_FOUND
|
|
THEN
|
|
v_ongeldig := 1;
|
|
fac.imp_writelog (
|
|
p_import_key,
|
|
'E',
|
|
v_aanduiding || v_errormsg,
|
|
'Regel wordt overgeslagen!');
|
|
END;
|
|
END IF;
|
|
|
|
IF v_Status <> 'R'
|
|
THEN
|
|
v_ongeldig := 1;
|
|
END IF;
|
|
|
|
v_errormsg :=
|
|
'v_PlanWorktime ongeldig ' || v_PlanWorktime;
|
|
|
|
IF FAC.safe_to_number (v_PlanWorktime) IS NULL
|
|
THEN
|
|
v_ongeldig := 1;
|
|
fac.imp_writelog (p_import_key,
|
|
'E',
|
|
v_aanduiding || v_errormsg,
|
|
'Regel wordt overgeslagen!');
|
|
END IF;
|
|
|
|
v_errormsg :=
|
|
'v_ActualWorktime ongeldig ' || v_ActualWorktime;
|
|
|
|
IF FAC.safe_to_number (v_ActualWorktime) IS NULL
|
|
THEN
|
|
v_ongeldig := 1;
|
|
fac.imp_writelog (p_import_key,
|
|
'E',
|
|
v_aanduiding || v_errormsg,
|
|
'Regel wordt overgeslagen!');
|
|
END IF;
|
|
|
|
v_errormsg :=
|
|
'v_ActualWorkCosts ongeldig ' || v_ActualWorkCosts;
|
|
|
|
IF FAC.safe_to_number (v_ActualWorkCosts) IS NULL
|
|
THEN
|
|
v_ongeldig := 1;
|
|
fac.imp_writelog (p_import_key,
|
|
'E',
|
|
v_aanduiding || v_errormsg,
|
|
'Regel wordt overgeslagen!');
|
|
END IF;
|
|
|
|
v_errormsg :=
|
|
'v_PlanWorkCosts ongeldig ' || v_PlanWorkCosts;
|
|
|
|
IF FAC.safe_to_number (v_PlanWorkCosts) IS NULL
|
|
THEN
|
|
v_ongeldig := 1;
|
|
fac.imp_writelog (p_import_key,
|
|
'E',
|
|
v_aanduiding || v_errormsg,
|
|
'Regel wordt overgeslagen!');
|
|
END IF;
|
|
|
|
v_errormsg :=
|
|
'v_InvoiceReceived ongeldig ' || v_InvoiceReceived;
|
|
|
|
IF FAC.safe_to_number (v_InvoiceReceived) IS NULL
|
|
THEN
|
|
v_ongeldig := 1;
|
|
fac.imp_writelog (p_import_key,
|
|
'E',
|
|
v_aanduiding || v_errormsg,
|
|
'Regel wordt overgeslagen!');
|
|
END IF;
|
|
|
|
v_errormsg :=
|
|
'v_InvoicePosted ongeldig ' || v_InvoicePosted;
|
|
|
|
IF FAC.safe_to_number (v_InvoicePosted) IS NULL
|
|
THEN
|
|
v_ongeldig := 1;
|
|
fac.imp_writelog (p_import_key,
|
|
'E',
|
|
v_aanduiding || v_errormsg,
|
|
'Regel wordt overgeslagen!');
|
|
END IF;
|
|
|
|
v_errormsg :=
|
|
'v_ProjektManagerLogin ongeldig '
|
|
|| v_ProjektManagerLogin;
|
|
|
|
BEGIN
|
|
SELECT prs_perslid_key
|
|
INTO v_budgethouder_key
|
|
FROM prs_perslid
|
|
WHERE prs_perslid_oslogin = v_ProjektManagerLogin;
|
|
EXCEPTION
|
|
WHEN NO_DATA_FOUND
|
|
THEN
|
|
v_ongeldig := 1;
|
|
END;
|
|
|
|
-- We gaan eerst de kostenplaats aanpassen
|
|
IF v_ongeldig = 0
|
|
THEN
|
|
BEGIN
|
|
v_errormsg :=
|
|
'Kijken of de kostenplaats al bestaat';
|
|
|
|
BEGIN
|
|
SELECT prs_kostenplaats_key
|
|
INTO v_kostenplaats_key
|
|
FROM prs_kostenplaats
|
|
WHERE prs_kostenplaats_nr = v_WBSelement;
|
|
EXCEPTION
|
|
WHEN NO_DATA_FOUND
|
|
THEN
|
|
INSERT INTO prs_kostenplaats (
|
|
prs_kostenplaats_nr,
|
|
prs_kostenplaats_omschrijving,
|
|
prs_kostenplaatsgrp_key,
|
|
prs_kostenplaats_module)
|
|
VALUES (
|
|
SUBSTR (v_WBSelement, 1, 30),
|
|
SUBSTR (v_Omschrijving, 1, 60),
|
|
v_kostenplaatsgrp_key,
|
|
'PRS')
|
|
RETURNING prs_kostenplaats_key
|
|
INTO v_kostenplaats_key;
|
|
|
|
END;
|
|
|
|
BEGIN
|
|
SELECT prs_kostenplaats_key
|
|
INTO v_kostenplaats_key
|
|
FROM logc_imp_projecten
|
|
WHERE prs_kostenplaats_key = v_kostenplaats_key;
|
|
EXCEPTION WHEN NO_DATA_FOUND
|
|
THEN
|
|
INSERT INTO logc_imp_projecten (
|
|
prs_kostenplaats_key)
|
|
VALUES (v_kostenplaats_key);
|
|
END;
|
|
|
|
UPDATE prs_kostenplaats
|
|
SET prs_kostenplaats_omschrijving =
|
|
SUBSTR (v_Omschrijving, 1, 60),
|
|
prs_kostenplaatsgrp_key =
|
|
v_kostenplaatsgrp_key,
|
|
prs_kostenplaats_module = 'PRS',
|
|
prs_kostenplaats_eind = NULL,
|
|
prs_perslid_key = v_budgethouder_key
|
|
WHERE prs_kostenplaats_key = v_kostenplaats_key;
|
|
|
|
UPDATE logc_imp_projecten
|
|
SET KlantOmschrijving =
|
|
SUBSTR (v_KlantOmschrijving, 1, 100),
|
|
WBSelement = SUBSTR (v_WBSelement, 1, 30),
|
|
Projectsoort =
|
|
SUBSTR (v_Projectsoort, 1, 2),
|
|
Omschrijving =
|
|
SUBSTR (v_Omschrijving, 1, 100),
|
|
Status = SUBSTR (v_Status, 1, 1),
|
|
Debiteur = SUBSTR (v_Debiteur, 1, 10),
|
|
PlanWorktime =
|
|
FAC.safe_to_number (v_PlanWorktime),
|
|
ActualWorktime =
|
|
FAC.safe_to_number (v_ActualWorktime),
|
|
ActualWorkCosts =
|
|
FAC.safe_to_number (v_ActualWorkCosts),
|
|
PlanWorkCosts =
|
|
FAC.safe_to_number (v_PlanWorkCosts),
|
|
InvoiceReceived =
|
|
FAC.safe_to_number (v_InvoiceReceived),
|
|
InvoicePosted =
|
|
FAC.safe_to_number (v_InvoicePosted),
|
|
ProjektManagerLogin =
|
|
SUBSTR (v_ProjektManagerLogin, 1, 10),
|
|
SalesPersonNr =
|
|
SUBSTR (v_SalesPersonNr, 1, 10),
|
|
NameSalesPerson =
|
|
SUBSTR (v_NameSalesPerson, 1, 40),
|
|
fac_import_key = p_import_key
|
|
WHERE prs_kostenplaats_key = v_kostenplaats_key;
|
|
|
|
|
|
COMMIT;
|
|
END;
|
|
END IF;
|
|
END IF;
|
|
END IF;
|
|
END;
|
|
END LOOP;
|
|
|
|
UPDATE prs_kostenplaats
|
|
SET prs_kostenplaats_eind = SYSDATE
|
|
WHERE prs_kostenplaats_key NOT IN (SELECT prs_kostenplaats_key
|
|
FROM logc_imp_projecten
|
|
WHERE fac_import_key = p_import_key)
|
|
AND prs_kostenplaatsgrp_key IN (22, 23) -- Nacalculatie, Fixed budget
|
|
AND prs_kostenplaats_eind IS NULL;
|
|
|
|
IF header_is_valid = 0
|
|
THEN
|
|
fac.imp_writelog (
|
|
p_import_key,
|
|
'E',
|
|
'Ongeldig importbestand',
|
|
'Geen header of header niet volgens specificatie!'
|
|
|| '('
|
|
|| v_KlantOmschrijving
|
|
|| '-'
|
|
|| v_WBSelement
|
|
|| '-'
|
|
|| v_Projectsoort
|
|
|| '-'
|
|
|| v_Omschrijving
|
|
|| '-'
|
|
|| v_Status
|
|
|| '-'
|
|
|| v_Debiteur
|
|
|| '-'
|
|
|| v_ActualWorktime
|
|
|| '-'
|
|
|| v_ActualWorkCosts
|
|
|| '-'
|
|
|| v_PlanWorkCosts
|
|
|| '-'
|
|
|| v_InvoiceReceived
|
|
|| '-'
|
|
|| v_InvoicePosted
|
|
|| '-'
|
|
|| v_ProjektManagerLogin
|
|
|| '-'
|
|
|| v_SalesPersonNr
|
|
|| '-'
|
|
|| v_NameSalesPerson
|
|
|| ')');
|
|
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 projecten afgebroken!');
|
|
END logc_import_projecten;
|
|
/
|
|
|
|
CREATE OR REPLACE VIEW logc_v_rap_projecten
|
|
AS
|
|
SELECT d.prs_afdeling_key
|
|
fclt_3d_afdeling_key,
|
|
k.prs_kostenplaats_nr,
|
|
k.prs_kostenplaats_omschrijving,
|
|
k.prs_kostenplaats_begin,
|
|
k.prs_kostenplaats_eind,
|
|
kg.prs_kostenplaatsgrp_oms,
|
|
p.klantomschrijving,
|
|
p.debiteur,
|
|
p.planworktime,
|
|
p.actualworktime,
|
|
DECODE (p.planworktime,
|
|
1, TO_NUMBER (NULL),
|
|
0, TO_NUMBER (NULL),
|
|
p.planworktime - p.actualworktime)
|
|
remainingworktime,
|
|
p.planworkcosts,
|
|
p.actualworkcosts,
|
|
DECODE (p.planworkcosts,
|
|
1, TO_NUMBER (NULL),
|
|
0, TO_NUMBER (NULL),
|
|
p.planworkcosts - p.actualworkcosts)
|
|
remainingworkcosts,
|
|
p.invoiceposted,
|
|
p.invoicereceived,
|
|
pf.prs_perslid_naam_full
|
|
projectmanager,
|
|
p.namesalesperson
|
|
salesconctact,
|
|
i.fac_import_datum_gelezen
|
|
syncdate,
|
|
1 dummy
|
|
FROM prs_kostenplaats k,
|
|
prs_kostenplaatsgrp kg,
|
|
logc_imp_projecten p,
|
|
fac_import i,
|
|
(SELECT prs_link_key prs_afdeling_key,
|
|
prs_kenmerklink_waarde debiteur
|
|
FROM prs_kenmerklink
|
|
WHERE prs_kenmerklink_verwijder IS NULL
|
|
AND prs_kenmerk_key = 1320) d, -- debiteurnummer
|
|
prs_v_perslid_fullnames_all pf
|
|
WHERE k.prs_kostenplaats_key = p.prs_kostenplaats_key
|
|
AND k.prs_kostenplaatsgrp_key = kg.prs_kostenplaatsgrp_key
|
|
AND p.fac_import_key = i.fac_import_key(+)
|
|
AND k.prs_perslid_key = pf.prs_perslid_key(+)
|
|
AND p.debiteur = d.debiteur(+);
|
|
|
|
|
|
-- View voor standaard kwartaalrapportage aan klanten (zie ticket 57657)
|
|
CREATE OR REPLACE VIEW logc_v_rap_klantoverzicht_mld
|
|
(
|
|
koptekst,
|
|
bedrijf,
|
|
hoofdklant,
|
|
extra_key,
|
|
fclt_3d_afdeling_key,
|
|
klantcode_melding,
|
|
aanvrager,
|
|
prs_perslid_key,
|
|
aanvrager_afdeling,
|
|
aanvrager_kp,
|
|
melding_datum,
|
|
melding_datum_tekst,
|
|
melding_key,
|
|
melding_nr,
|
|
onderwerp,
|
|
omschrijving,
|
|
samenvatting,
|
|
soort_melding,
|
|
vakgroep,
|
|
vakgroep_type,
|
|
huidige_status,
|
|
actie_status,
|
|
aanspreekpunt_facilitor,
|
|
behandelteam_actief,
|
|
streefdatum_gereed,
|
|
datum_afgemeld,
|
|
laatste_actiedatum,
|
|
laatste_notitie,
|
|
doorlooptijd_werkdagen,
|
|
klantreferentie,
|
|
planning,
|
|
raming,
|
|
gekoppeld_aan
|
|
)
|
|
AS
|
|
SELECT (CASE
|
|
WHEN m.mld_melding_datum >= TRUNC (SYSDATE, 'Q') -- Alle meldingen dit kwartaal
|
|
THEN
|
|
'0' -- 'Alle meldingen dit kwartaal'
|
|
WHEN m.mld_melding_datum >=
|
|
ADD_MONTHS (TRUNC (SYSDATE, 'Q'), -3)
|
|
AND m.mld_melding_datum <= TRUNC (SYSDATE, 'Q') - 1
|
|
THEN
|
|
'1' -- Alle meldingen afgelopen kwartaal'
|
|
WHEN m.mld_melding_datum <
|
|
ADD_MONTHS (TRUNC (SYSDATE, 'Q'), -3)
|
|
AND m.mld_melding_status IN (0, 2, 3, 4, 7, 99)
|
|
THEN
|
|
'3' -- Alle LOPENDE meldingen die ouder zijn dan afgelopen kwartaal'
|
|
ELSE
|
|
'1' -- 'Alle meldingen die OUDER zijn dan afgelopen kwartaal, maar die wel afgelopen kwartaal zijn behandeld en afgemeld'
|
|
END)
|
|
koptekst,
|
|
b.prs_bedrijf_naam bedrijf,
|
|
(SELECT prs_afdeling_naam
|
|
FROM prs_afdeling
|
|
WHERE prs_afdeling_key =
|
|
COALESCE (am.prs_afdeling_parentkey,
|
|
am.prs_afdeling_key))
|
|
hoofdklant,
|
|
COALESCE (am.prs_afdeling_parentkey, am.prs_afdeling_key)
|
|
hoofdklant_key,
|
|
COALESCE (am.prs_afdeling_parentkey, am.prs_afdeling_key)
|
|
fclt_3d_afdeling_key,
|
|
am.prs_afdeling_naam klantcode_melding,
|
|
melder.naam,
|
|
melder.prs_perslid_key,
|
|
melder.afdeling,
|
|
melder.prs_kostenplaats_upper,
|
|
m.mld_melding_datum,
|
|
TO_CHAR (m.mld_melding_datum, 'DD-MM-YYYY'),
|
|
m.mld_melding_key,
|
|
sd.ins_srtdiscipline_prefix || m.mld_melding_key meldingsnr,
|
|
m.mld_melding_onderwerp,
|
|
m.mld_melding_omschrijving,
|
|
m.mld_melding_opmerking,
|
|
s.mld_stdmelding_omschrijving,
|
|
md.ins_discipline_omschrijving,
|
|
sd.ins_srtdiscipline_omschrijving,
|
|
(SELECT sta.mld_statuses_omschrijving
|
|
FROM mld_statuses sta
|
|
WHERE m.mld_melding_status = sta.mld_statuses_key)
|
|
status,
|
|
CASE
|
|
WHEN m.mld_melding_actiecode = 1 AND m.mld_melding_flag = 0
|
|
THEN
|
|
''
|
|
WHEN m.mld_melding_actiecode = 1 AND m.mld_melding_flag > 0
|
|
THEN
|
|
lcl.l ('lcl_mld_flag' || m.mld_melding_flag)
|
|
WHEN m.mld_melding_actiecode = 2 AND m.mld_melding_flag = 0
|
|
THEN
|
|
'Uw actie gevraagd'
|
|
WHEN m.mld_melding_actiecode = 2 AND m.mld_melding_flag > 0
|
|
THEN
|
|
'Uw actie gevraagd - '
|
|
|| lcl.l ('lcl_mld_flag' || m.mld_melding_flag)
|
|
WHEN m.mld_melding_actiecode = 129 AND m.mld_melding_flag = 0
|
|
THEN
|
|
''
|
|
WHEN m.mld_melding_actiecode = 129 AND m.mld_melding_flag > 0
|
|
THEN
|
|
lcl.l ('lcl_mld_flag' || m.mld_melding_flag)
|
|
ELSE
|
|
''
|
|
END
|
|
actiecode,
|
|
(SELECT p.prs_perslid_naam || ' (' || p.prs_perslid_voornaam || ')'
|
|
FROM prs_perslid p
|
|
WHERE m.mld_melding_behandelaar_key = p.prs_perslid_key)
|
|
aanspreekpunt_facilitor,
|
|
(SELECT d.ins_discipline_omschrijving
|
|
FROM ins_tab_discipline d
|
|
WHERE d.ins_discipline_key = m.mld_ins_discipline_key)
|
|
actiefbehandelteam,
|
|
TO_CHAR (m.mld_melding_einddatum, 'DD-MM-YYYY') streefdatumgereed,
|
|
(SELECT TO_CHAR (MAX (ft.fac_tracking_datum), 'DD-MM-YYYY')
|
|
FROM fac_tracking ft, fac_srtnotificatie srt
|
|
WHERE ft.fac_tracking_refkey = m.mld_melding_key
|
|
AND ft.fac_srtnotificatie_key = srt.fac_srtnotificatie_key
|
|
AND srt.fac_srtnotificatie_xmlnode = 'melding'
|
|
AND ft.fac_srtnotificatie_key = 39 -- MLDAFM
|
|
)
|
|
datum_afgemeld,
|
|
(SELECT TO_CHAR (MAX (ft.fac_tracking_datum), 'DD-MM-YYYY')
|
|
FROM fac_tracking ft, fac_srtnotificatie srt
|
|
WHERE ft.fac_tracking_refkey = mld_melding_key
|
|
AND ft.fac_srtnotificatie_key = srt.fac_srtnotificatie_key
|
|
AND srt.fac_srtnotificatie_xmlnode = 'melding')
|
|
laatsteactiedatum,
|
|
(SELECT CASE
|
|
WHEN MAX (mn.mld_melding_note_omschrijving) IS NOT NULL
|
|
AND LENGTH (MAX (mn.mld_melding_note_omschrijving)) <
|
|
400
|
|
THEN
|
|
MAX (mn.mld_melding_note_omschrijving)
|
|
WHEN MAX (mn.mld_melding_note_omschrijving) IS NULL
|
|
THEN
|
|
'<nog geen notities>'
|
|
ELSE
|
|
SUBSTR (MAX (mn.mld_melding_note_omschrijving),
|
|
1,
|
|
400)
|
|
|| ' ...... (zie Facilitor)'
|
|
END
|
|
omschrijving
|
|
FROM mld_melding_note mn
|
|
WHERE mn.mld_melding_key = m.mld_melding_key
|
|
AND mld_melding_note_flag = 1)
|
|
laatstenotitie,
|
|
(CASE
|
|
WHEN m.mld_melding_status IN (0, 2, 3, 4, 7, 99) -- Lopend, is ook uitgegeven en 99 niet opgelost...
|
|
THEN
|
|
fac.count_work_days (m.mld_melding_datum, SYSDATE)
|
|
WHEN m.mld_melding_status IN (5, 6) -- Verwerkt
|
|
THEN
|
|
fac.count_work_days (
|
|
m.mld_melding_datum,
|
|
(SELECT MAX (ft.fac_tracking_datum)
|
|
FROM fac_tracking ft
|
|
WHERE ft.fac_tracking_refkey = m.mld_melding_key
|
|
AND ft.fac_srtnotificatie_key = 39)) -- MLDAFM
|
|
ELSE -- Vervallen
|
|
0
|
|
END)
|
|
doorlooptijd,
|
|
(SELECT km.mld_kenmerkmelding_waarde
|
|
FROM mld_kenmerkmelding km
|
|
WHERE km.mld_melding_key = m.mld_melding_key
|
|
AND km.mld_kenmerk_key = 61)
|
|
klantreferentie,
|
|
(SELECT km.mld_kenmerkmelding_waarde
|
|
FROM mld_kenmerkmelding km
|
|
WHERE km.mld_melding_key = m.mld_melding_key
|
|
AND km.mld_kenmerk_key = 25)
|
|
planning_releaseuitgifte,
|
|
(SELECT km.mld_kenmerkmelding_waarde
|
|
FROM mld_kenmerkmelding km
|
|
WHERE km.mld_melding_key = m.mld_melding_key
|
|
AND km.mld_kenmerk_key = 26)
|
|
raming_uren,
|
|
(CASE
|
|
WHEN mld_melding_parentkey IS NOT NULL
|
|
THEN
|
|
'Wordt behandeld in ' || TO_CHAR (mld_melding_parentkey)
|
|
ELSE
|
|
''
|
|
END)
|
|
gekoppeldaan
|
|
FROM mld_melding m,
|
|
mld_stdmelding s,
|
|
mld_discipline md,
|
|
ins_srtdiscipline sd,
|
|
prs_kostenplaats pk,
|
|
prs_perslid p,
|
|
prs_v_aanwezigafdeling a,
|
|
prs_afdeling am,
|
|
prs_bedrijf b,
|
|
(SELECT p.prs_perslid_key,
|
|
p.prs_perslid_naam || ' (' || p.prs_perslid_voornaam || ')'
|
|
naam,
|
|
prs_afdeling_naam afdeling,
|
|
kp.prs_kostenplaats_key,
|
|
kp.prs_kostenplaats_upper
|
|
FROM prs_perslid p, prs_afdeling a, prs_kostenplaats kp
|
|
WHERE p.prs_afdeling_key = a.prs_afdeling_key
|
|
AND a.prs_kostenplaats_key = kp.prs_kostenplaats_key)
|
|
melder
|
|
WHERE m.prs_perslid_key = melder.prs_perslid_key
|
|
AND m.mld_stdmelding_key = s.mld_stdmelding_key
|
|
AND s.mld_ins_discipline_key = md.ins_discipline_key
|
|
AND md.ins_srtdiscipline_key = sd.ins_srtdiscipline_key
|
|
AND am.prs_afdeling_key = m.prs_afdeling_key
|
|
AND p.prs_perslid_key = m.prs_perslid_key
|
|
AND p.prs_afdeling_key = a.prs_afdeling_key
|
|
AND b.prs_bedrijf_key = a.prs_bedrijf_key
|
|
AND pk.prs_kostenplaats_key = m.prs_kostenplaats_key
|
|
AND ( -- Alle meldingen dit kwartaal
|
|
(m.mld_melding_datum >= TRUNC (SYSDATE, 'Q'))
|
|
OR -- Alle meldingen afgelopen kwartaal
|
|
(m.mld_melding_datum >=
|
|
ADD_MONTHS (TRUNC (SYSDATE, 'Q'), -3)
|
|
AND m.mld_melding_datum <= TRUNC (SYSDATE, 'Q') - 1)
|
|
OR -- Alle LOPENDE meldingen die ouder zijn dan afgelopen kwartaal
|
|
(m.mld_melding_datum <
|
|
ADD_MONTHS (TRUNC (SYSDATE, 'Q'), -3)
|
|
AND m.mld_melding_status IN (0, 2, 3, 4, 7, 99))
|
|
OR -- Alle meldingen die OUDER zijn dan afgelopen kwartaal, maar die wel afgelopen kwartaal zijn behandeld en afgemeld)
|
|
(m.mld_melding_key IN
|
|
(SELECT mm.mld_melding_key
|
|
FROM mld_melding mm,
|
|
fac_tracking ft,
|
|
fac_srtnotificatie srt
|
|
WHERE mm.mld_melding_datum <
|
|
ADD_MONTHS (TRUNC (SYSDATE, 'Q'), -3)
|
|
AND mm.mld_melding_key =
|
|
ft.fac_tracking_refkey
|
|
AND ft.fac_srtnotificatie_key =
|
|
srt.fac_srtnotificatie_key
|
|
AND srt.fac_srtnotificatie_xmlnode =
|
|
'melding'
|
|
AND ft.fac_srtnotificatie_key = 39 -- MLDAFM
|
|
AND ft.fac_tracking_datum >=
|
|
ADD_MONTHS (TRUNC (SYSDATE, 'Q'), -3))));
|
|
|
|
-- VIEW voor Notificatiejob Kwartaaloverzicht openstaande tickets opsturen naar klanten die hebben aangegeven dat ze dat willen
|
|
CREATE OR REPLACE VIEW LOGC_V_NOTI_KLANTOVERZICHT
|
|
(
|
|
SENDER,
|
|
RECEIVER,
|
|
TEXT,
|
|
CODE,
|
|
FAC_SRTNOTIFICATIE_KEY,
|
|
KEY,
|
|
XKEY
|
|
)
|
|
AS
|
|
SELECT NULL
|
|
sender,
|
|
v.prs_perslid_key
|
|
receiver,
|
|
'Overzicht meldingen ' || v.hoofdklant
|
|
text,
|
|
'CUST01'
|
|
code,
|
|
(SELECT fac_srtnotificatie_key
|
|
FROM fac_srtnotificatie
|
|
WHERE fac_srtnotificatie_code = 'CUST01')
|
|
fac_srtnotificatie_key,
|
|
741 key,
|
|
v.extra_key -- Hoofdklant_key = afdeling_key
|
|
xkey
|
|
FROM (SELECT a.PRS_AFDELING_UPPER AS HOOFDKLANT,
|
|
a.prs_afdeling_key AS extra_key, -- HOOFDKLANT_KEY
|
|
p.prs_perslid_key,
|
|
p.prs_perslid_email AS EMAIL
|
|
FROM prs_perslid p, prs_kenmerklink km, prs_afdeling a
|
|
WHERE p.prs_perslid_key = km.prs_link_key
|
|
AND km.prs_kenmerk_key = 1020
|
|
AND km.prs_kenmerklink_waarde = 1
|
|
AND p.prs_afdeling_key = a.prs_afdeling_key
|
|
AND p.prs_perslid_email IS NOT NULL
|
|
AND p.prs_perslid_verwijder IS NULL
|
|
AND a.prs_afdeling_verwijder IS NULL -- and p.prs_perslid_login is not null
|
|
) v,
|
|
(SELECT ADD_MONTHS (TRUNC (SYSDATE - 1, 'Q'), +3) AS NextRun -- Begin_VolgendeKwartaal
|
|
FROM DUAL) d
|
|
WHERE d.NextRun = TRUNC (SYSDATE) -- Om de job altijd de 1e van elk kwartaal te laten lopen.
|
|
;
|
|
|
|
|
|
CREATE OR REPLACE VIEW logc_v_kostenplaats_klant
|
|
AS
|
|
SELECT prs_kostenplaats_key,
|
|
prs_kostenplaats_nr || ' - ' || prs_kostenplaats_omschrijving
|
|
prs_kostenplaats_omschrijving,
|
|
COALESCE (prs_kostenplaats_verwijder, prs_kostenplaats_eind)
|
|
prs_kostenplaats_eind
|
|
FROM prs_kostenplaats;
|
|
|
|
CREATE OR REPLACE VIEW logc_v_rap_urenbesteding
|
|
AS
|
|
SELECT d.prs_afdeling_key fclt_3d_afdeling_key,
|
|
a1.prs_afdeling_naam parent_afdeling,
|
|
COALESCE(a2.prs_afdeling_naam, a1.prs_afdeling_naam) afdeling,
|
|
i.project,
|
|
pr.omschrijving,
|
|
i.categorie,
|
|
i.werknemer,
|
|
i.uren,
|
|
(SELECT FAC.safe_to_number (mld_kenmerkmelding_waarde)
|
|
FROM mld_kenmerkmelding km, mld_kenmerk mk
|
|
WHERE km.mld_kenmerk_key = mk.mld_kenmerk_key
|
|
AND mk.mld_srtkenmerk_key = 261
|
|
AND km.mld_melding_key = m.mld_melding_key) raming,
|
|
(SELECT SUM (i2.uren)
|
|
FROM logc_imp_uren_besteding i2
|
|
WHERE i.transactietekst = i2.transactietekst) urencum,
|
|
i.transactietekst,
|
|
pf.prs_perslid_naam_full,
|
|
i.datum,
|
|
m.mld_melding_onderwerp,
|
|
(SELECT mld_kenmerkmelding_waarde
|
|
FROM mld_kenmerkmelding km, mld_kenmerk mk
|
|
WHERE km.mld_kenmerk_key = mk.mld_kenmerk_key
|
|
AND mk.mld_srtkenmerk_key = 25
|
|
AND km.mld_melding_key = m.mld_melding_key) custref,
|
|
m.mld_melding_externnr,
|
|
m.mld_melding_key
|
|
FROM logc_imp_uren_besteding i,
|
|
logc_imp_projecten pr,
|
|
mld_melding m,
|
|
prs_v_afdeling_boom ab,
|
|
prs_afdeling a1,
|
|
prs_afdeling a2,
|
|
prs_perslid p,
|
|
prs_v_perslid_fullnames_all pf,
|
|
(SELECT prs_link_key prs_afdeling_key,
|
|
prs_kenmerklink_waarde debiteur
|
|
FROM prs_kenmerklink
|
|
WHERE prs_kenmerklink_verwijder IS NULL
|
|
AND prs_kenmerk_key = 1320) d -- debiteurnummer
|
|
WHERE i.mld_melding_key = m.mld_melding_key(+)
|
|
AND m.prs_afdeling_key = ab.prs_afdeling_key(+)
|
|
AND ab.prs_afdeling_key1 = a1.prs_afdeling_key(+)
|
|
AND ab.prs_afdeling_key2 = a2.prs_afdeling_key(+)
|
|
AND i.werknemer = p.prs_perslid_nr(+)
|
|
AND p.prs_perslid_key = pf.prs_perslid_key(+)
|
|
AND i.project = pr.wbselement(+)
|
|
AND pr.debiteur = d.debiteur(+);
|
|
|
|
CREATE OR REPLACE VIEW logc_v_rap_mld_sleeping
|
|
AS
|
|
SELECT MAX (actiedatum) laatste_actie,
|
|
TRUNC (SYSDATE) - TRUNC (MAX (actiedatum)) dagen_stil,
|
|
p.prs_perslid_naam_full melder,
|
|
m.mld_melding_key,
|
|
a.prs_afdeling_naam || '#' || m.mld_melding_key meldingnr,
|
|
m.mld_melding_datum geregistreerd,
|
|
md.ins_discipline_omschrijving behandelgroep,
|
|
mld_stdmelding_omschrijving melding,
|
|
mld_melding_onderwerp,
|
|
pb.prs_perslid_naam_full behandelaar,
|
|
bhg.ins_discipline_omschrijving behandelteam,
|
|
abh.prs_perslid_naam_full actieve_behandelaar,
|
|
m.mld_melding_behandelaar2_key actieve_behandelaar_key,
|
|
a.prs_afdeling_omschrijving klant,
|
|
DECODE (BITAND (m.mld_melding_actiecode, 1), 1, 'Behandelaar', 'Klant') actie_bij,
|
|
CASE
|
|
WHEN mld_melding_flag > 0
|
|
THEN
|
|
lcl.l ('lcl_mld_flag' || mld_melding_flag)
|
|
END
|
|
status
|
|
FROM mld_melding m,
|
|
mld_stdmelding ms,
|
|
mld_discipline md,
|
|
prs_v_perslid_fullnames pb,
|
|
prs_v_perslid_fullnames p,
|
|
mld_discipline bhg,
|
|
prs_v_perslid_fullnames abh,
|
|
prs_afdeling a,
|
|
(SELECT n.mld_melding_key, n.mld_melding_note_aanmaak actiedatum
|
|
FROM mld_melding_note n
|
|
UNION ALL
|
|
SELECT fac_tracking_refkey, tr.fac_tracking_datum
|
|
FROM fac_tracking tr, fac_srtnotificatie str
|
|
WHERE tr.fac_srtnotificatie_key = str.fac_srtnotificatie_key
|
|
AND str.fac_srtnotificatie_xmlnode IN ('melding')) d
|
|
WHERE m.mld_melding_key = d.mld_melding_key
|
|
AND ms.mld_stdmelding_key = m.mld_stdmelding_key
|
|
AND md.ins_discipline_key = ms.mld_ins_discipline_key
|
|
AND mld_melding_behandelaar_key = pb.prs_perslid_key(+)
|
|
AND m.prs_perslid_key = p.prs_perslid_key
|
|
AND mld_melding_status NOT IN (1, 5, 6)
|
|
AND fac_activiteit_key IS NULL
|
|
AND m.mld_ins_discipline_key = bhg.ins_discipline_key(+)
|
|
AND m.mld_melding_behandelaar2_key = abh.prs_perslid_key(+)
|
|
AND m.prs_afdeling_key = a.prs_afdeling_key(+)
|
|
GROUP BY m.mld_melding_key,
|
|
m.prs_kostenplaats_key,
|
|
p.prs_perslid_naam_full,
|
|
m.prs_perslid_key,
|
|
mld_melding_datum,
|
|
md.ins_discipline_omschrijving,
|
|
bhg.ins_discipline_omschrijving,
|
|
mld_stdmelding_omschrijving,
|
|
mld_melding_onderwerp,
|
|
pb.prs_perslid_naam_full,
|
|
abh.prs_perslid_naam_full,
|
|
m.mld_melding_behandelaar2_key,
|
|
mld_melding_flag,
|
|
m.mld_melding_actiecode,
|
|
a.prs_afdeling_naam,
|
|
a.prs_afdeling_omschrijving
|
|
ORDER BY MAX (actiedatum);
|
|
|
|
CREATE OR REPLACE VIEW logc_v_rap_mldsaldo
|
|
(
|
|
week,
|
|
opened,
|
|
closed,
|
|
netto,
|
|
backlog
|
|
)
|
|
AS WITH
|
|
ticket
|
|
AS
|
|
(SELECT *
|
|
FROM mld_melding mm, mld_stdmelding ms, mld_discipline md
|
|
WHERE mld_melding_status <> 1
|
|
AND mm.mld_stdmelding_key = ms.mld_stdmelding_key
|
|
AND ms.mld_ins_discipline_key = md.ins_discipline_key
|
|
AND ins_srtdiscipline_key = 1),
|
|
uniqueafmelding
|
|
AS
|
|
( SELECT fac_tracking_refkey, MAX (fac_tracking_datum) fac_tracking_datum
|
|
FROM fac_tracking
|
|
WHERE fac_srtnotificatie_key = 39 /* MLDAFM */
|
|
GROUP BY fac_tracking_refkey),
|
|
afmelding
|
|
AS
|
|
( SELECT TRUNC (fac_tracking_datum, 'IW') week, COUNT (DISTINCT mld_melding_key) afgemeld
|
|
FROM uniqueafmelding, ticket mm
|
|
WHERE fac_tracking_refkey = mm.mld_melding_key
|
|
GROUP BY TRUNC (fac_tracking_datum, 'IW')),
|
|
nieuw
|
|
AS
|
|
( SELECT TRUNC (mld_melding_datum, 'IW') week, COUNT (*) nieuw
|
|
FROM ticket mm
|
|
GROUP BY TRUNC (mld_melding_datum, 'IW'))
|
|
SELECT week,
|
|
nieuw,
|
|
afgemeld,
|
|
nieuw - afgemeld netto,
|
|
SUM (nieuw - afgemeld) OVER (ORDER BY week) backlog
|
|
FROM (SELECT nieuw.week, nieuw, afgemeld
|
|
FROM nieuw, afmelding
|
|
WHERE nieuw.week = afmelding.week);
|
|
|
|
CREATE OR REPLACE VIEW logc_v_rap_melding_note
|
|
AS
|
|
SELECT SYSDATE - mld_melding_note_aanmaak hide_f_sort,
|
|
m.mld_melding_key,
|
|
CASE
|
|
WHEN mld_melding_note_aanmaak > SYSDATE - 4 / 24 / 60
|
|
THEN
|
|
'updated'
|
|
WHEN mld_melding_note_aanmaak > SYSDATE - 1 / 24
|
|
THEN
|
|
'updated10'
|
|
ELSE
|
|
''
|
|
END
|
|
hide_f_rowclass,
|
|
mld_melding_note_aanmaak datum,
|
|
TO_CHAR (mld_melding_note_aanmaak, 'HH24:MI') tijd,
|
|
p.prs_perslid_naam_friendly door,
|
|
COALESCE (a.prs_afdeling_naam, prs_kostenplaats_nr)
|
|
|| '#'
|
|
|| m.mld_melding_key
|
|
nummer,
|
|
std.mld_stdmelding_omschrijving melding,
|
|
d.ins_discipline_key fclt_3d_discipline_key,
|
|
d.ins_discipline_omschrijving vakgroep,
|
|
sd.ins_srtdiscipline_omschrijving vakgroeptype,
|
|
p4.prs_perslid_naam_friendly melder,
|
|
p2.prs_perslid_naam_friendly behandelaar,
|
|
d2.ins_discipline_omschrijving team,
|
|
p3.prs_perslid_naam_friendly actieve_behandelaar,
|
|
mld_melding_note_omschrijving notitie,
|
|
m.mld_melding_onderwerp,
|
|
m.mld_melding_omschrijving,
|
|
COALESCE (a.prs_afdeling_naam, prs_kostenplaats_nr) klantcode,
|
|
COALESCE (a.prs_afdeling_omschrijving,
|
|
prs_kostenplaats_omschrijving)
|
|
klant,
|
|
COALESCE (a.prs_afdeling_naam, prs_kostenplaats_nr) || ' ('
|
|
|| COALESCE (a.prs_afdeling_omschrijving,
|
|
prs_kostenplaats_omschrijving)
|
|
|| ')'
|
|
klantcode2,
|
|
DECODE (m.prs_kostenplaats_key,
|
|
4, 'Intern',
|
|
127, 'Intern',
|
|
'Klant')
|
|
melding_klant,
|
|
DECODE (mn.mld_melding_note_flag, 1, 'Ja', 2, 'Nvt', 'Nee')
|
|
zichtbaar_fe,
|
|
(SELECT pf.prs_perslid_naam_full pf
|
|
FROM prs_kenmerklink pk, prs_v_perslid_fullnames_all pf
|
|
WHERE pk.prs_kenmerklink_niveau = 'B'
|
|
AND pk.prs_kenmerk_key = 1060 -- accountmanager
|
|
AND prs_kenmerklink_verwijder IS NULL
|
|
AND pf.prs_perslid_key =
|
|
fac.safe_to_number (pk.prs_kenmerklink_waarde)
|
|
AND a.prs_bedrijf_key = pk.prs_link_key)
|
|
accnt_mgr
|
|
FROM (SELECT mld_melding_note_key,
|
|
mld_melding_key,
|
|
mld_melding_note_aanmaak,
|
|
prs_perslid_key,
|
|
mld_melding_note_omschrijving,
|
|
mld_melding_note_flag
|
|
FROM mld_melding_note
|
|
UNION ALL
|
|
SELECT mld_melding_key,
|
|
mld_melding_key,
|
|
ft.fac_tracking_datum, -- mld_melding_datum,
|
|
ft.prs_perslid_key,
|
|
'Nieuw: '
|
|
|| mld_melding_onderwerp
|
|
|| CHR (13)
|
|
|| SUBSTR (mld_melding_omschrijving, 1, 4000 - 80 - 10),
|
|
2
|
|
FROM mld_melding, fac_tracking ft
|
|
WHERE ft.fac_tracking_refkey = mld_melding_key
|
|
AND ft.fac_srtnotificatie_key =
|
|
(SELECT fac_srtnotificatie_key
|
|
FROM fac_srtnotificatie
|
|
WHERE fac_srtnotificatie_code = 'MLDNEW')) mn,
|
|
mld_melding m,
|
|
prs_v_perslid_fullnames_all p,
|
|
prs_kostenplaats k,
|
|
mld_stdmelding std,
|
|
mld_discipline d,
|
|
ins_srtdiscipline sd,
|
|
mld_discipline d2,
|
|
prs_v_perslid_fullnames_all p2,
|
|
prs_v_perslid_fullnames_all p3,
|
|
prs_v_perslid_fullnames_all p4,
|
|
prs_afdeling a
|
|
WHERE mld_melding_note_aanmaak > SYSDATE - 548
|
|
AND m.mld_melding_key = mn.mld_melding_key
|
|
AND mn.prs_perslid_key = p.prs_perslid_key
|
|
AND m.prs_perslid_key = p4.prs_perslid_key
|
|
AND m.prs_kostenplaats_key = k.prs_kostenplaats_key(+)
|
|
AND m.mld_stdmelding_key = std.mld_stdmelding_key
|
|
AND std.mld_ins_discipline_key = d.ins_discipline_key
|
|
AND d.ins_srtdiscipline_key = sd.ins_srtdiscipline_key
|
|
AND m.fac_activiteit_key IS NULL
|
|
AND m.mld_ins_discipline_key = d2.ins_discipline_key(+)
|
|
AND m.mld_melding_behandelaar_key = p2.prs_perslid_key(+)
|
|
AND m.mld_melding_behandelaar2_key = p3.prs_perslid_key(+)
|
|
AND m.prs_afdeling_key = a.prs_afdeling_key(+);
|
|
|
|
CREATE OR REPLACE VIEW logc_v_rap_releasenotes2
|
|
(
|
|
mld_melding_key,
|
|
notenummer,
|
|
onderwerp,
|
|
omschrijving,
|
|
melding,
|
|
vakgroep,
|
|
status_key,
|
|
status,
|
|
module,
|
|
planning,
|
|
releasenote,
|
|
note,
|
|
tech_note
|
|
)
|
|
AS
|
|
SELECT m.mld_melding_key,
|
|
TO_CHAR (m.mld_melding_key),
|
|
mld_melding_onderwerp,
|
|
mld_melding_omschrijving,
|
|
std.mld_stdmelding_omschrijving,
|
|
md.ins_discipline_omschrijving,
|
|
m.mld_melding_status,
|
|
st.mld_statuses_omschrijving,
|
|
(SELECT fac_usrdata_omschr
|
|
FROM mld_kenmerkmelding km, mld_kenmerk k, fac_usrdata fu
|
|
WHERE mld_srtkenmerk_key = 22
|
|
AND fu.fac_usrtab_key = 1
|
|
AND km.mld_kenmerk_key = k.mld_kenmerk_key
|
|
AND mld_kenmerkmelding_waarde = TO_CHAR (fac_usrdata_key)
|
|
AND km.mld_melding_key = m.mld_melding_key)
|
|
module,
|
|
(SELECT mld_kenmerkmelding_waarde
|
|
FROM mld_kenmerkmelding km, mld_kenmerk k
|
|
WHERE mld_srtkenmerk_key = 1
|
|
AND km.mld_kenmerk_key = k.mld_kenmerk_key
|
|
AND km.mld_melding_key = m.mld_melding_key)
|
|
planning,
|
|
(SELECT fac_usrdata_omschr
|
|
FROM mld_kenmerkmelding km, mld_kenmerk k, fac_usrdata fu
|
|
WHERE mld_srtkenmerk_key = 321
|
|
AND fu.fac_usrtab_key = 122
|
|
AND km.mld_kenmerk_key = k.mld_kenmerk_key
|
|
AND mld_kenmerkmelding_waarde = TO_CHAR (fac_usrdata_key)
|
|
AND km.mld_melding_key = m.mld_melding_key)
|
|
releasenote,
|
|
(SELECT mld_kenmerkmelding_waarde
|
|
FROM mld_kenmerkmelding km, mld_kenmerk k
|
|
WHERE mld_srtkenmerk_key = 281
|
|
AND km.mld_kenmerk_key = k.mld_kenmerk_key
|
|
AND km.mld_melding_key = m.mld_melding_key)
|
|
note,
|
|
(SELECT mld_kenmerkmelding_waarde
|
|
FROM mld_kenmerkmelding km, mld_kenmerk k
|
|
WHERE mld_srtkenmerk_key = 341
|
|
AND km.mld_kenmerk_key = k.mld_kenmerk_key
|
|
AND km.mld_melding_key = m.mld_melding_key)
|
|
tech_note
|
|
FROM mld_melding m,
|
|
mld_kenmerkmelding kmr,
|
|
mld_kenmerk mr,
|
|
mld_stdmelding std,
|
|
mld_discipline md,
|
|
mld_statuses st
|
|
WHERE kmr.mld_melding_key = m.mld_melding_key
|
|
AND kmr.mld_kenmerk_key = mr.mld_kenmerk_key
|
|
AND mr.mld_srtkenmerk_key = 1 ---- planning
|
|
AND kmr.mld_kenmerkmelding_waarde LIKE '20%'
|
|
AND m.mld_stdmelding_key = std.mld_stdmelding_key
|
|
AND std.mld_ins_discipline_key = md.ins_discipline_key
|
|
AND m.mld_melding_status = st.mld_statuses_key
|
|
AND m.mld_melding_status != 1 --- vervallen
|
|
AND fac_activiteit_key IS NULL;
|
|
|
|
-- De menselijke versie van de urenbesteding, tevens basis voor de SAP-exportview
|
|
CREATE OR REPLACE VIEW logc_v_urenoverzicht
|
|
AS
|
|
SELECT TO_CHAR (mou.mld_opdr_uren_datum, 'IYYY-IW') weeknr,
|
|
p_aareon.prs_perslid_nr personeelsnr,
|
|
k.prs_kostenplaats_nr projectnr,
|
|
mou.mld_opdr_uren_datum datum,
|
|
mou.mld_opdr_uren_besteed uren,
|
|
d.prs_afdeling_naam || '#' || o.mld_melding_key logcentrenr,
|
|
pf.prs_perslid_naam_friendly medewerker,
|
|
d.prs_afdeling_naam account,
|
|
m.mld_melding_onderwerp betreft,
|
|
b.prs_bedrijf_naam klant,
|
|
o.mld_melding_key melding_key
|
|
FROM mld_opdr_uren mou,
|
|
mld_opdr o,
|
|
prs_perslid p_aareon,
|
|
prs_kostenplaats k,
|
|
mld_melding m,
|
|
prs_v_perslid_fullnames_all pf,
|
|
prs_afdeling d,
|
|
prs_bedrijf b,
|
|
prs_perslid p_klant
|
|
WHERE mou.mld_opdr_key = o.mld_opdr_key
|
|
AND m.mld_melding_key = o.mld_melding_key
|
|
AND COALESCE (m.prs_afdeling_key, p_klant.prs_afdeling_key) = d.prs_afdeling_key
|
|
AND p_klant.prs_perslid_key = m.prs_perslid_key
|
|
AND d.prs_bedrijf_key = b.prs_bedrijf_key
|
|
AND mou.prs_perslid_key = p_aareon.prs_perslid_key
|
|
AND k.prs_kostenplaats_key = o.prs_kostenplaats_key
|
|
AND pf.prs_perslid_key = p_aareon.prs_perslid_key;
|
|
|
|
-- Voor de Export van de urenbesteding naar SAP/CATS ==concept==
|
|
CREATE OR REPLACE VIEW logc_v_urenexport2cats
|
|
AS
|
|
SELECT weeknr,
|
|
personeelsnr
|
|
employeenumber,
|
|
TO_CHAR (datum, 'fmDD-MMfm-YYYY')
|
|
workdate,
|
|
projectnr
|
|
wbs_element,
|
|
ROUND (uren, 2)
|
|
catshours,
|
|
'H'
|
|
unit,
|
|
'CONS01'
|
|
acttype,
|
|
NULL
|
|
statkeyfig01,
|
|
NULL
|
|
statkeyfig02,
|
|
logcentrenr
|
|
|| ' '
|
|
|| (CASE
|
|
WHEN LENGTH (betreft) + 11 > 40 THEN SUBSTR (betreft, 1, 38 - 11) || '..'
|
|
ELSE betreft
|
|
END)
|
|
shorttext
|
|
FROM logc_v_urenoverzicht;
|
|
|
|
CREATE OR REPLACE VIEW logc_v_rap_prj_jaareffect
|
|
AS
|
|
SELECT m.mld_melding_key,
|
|
std.mld_stdmelding_omschrijving soort,
|
|
TO_CHAR (m.mld_melding_key) meldingnr,
|
|
m.mld_melding_onderwerp onderwerp,
|
|
mld_statuses_omschrijving status,
|
|
PF.PRS_PERSLID_NAAM_FRIENDLY melder,
|
|
fac.safe_to_number (km1.mld_kenmerkmelding_waarde) jaareffect,
|
|
fac.safe_to_date (km2.mld_kenmerkmelding_waarde, 'DD-MM-YYYY')
|
|
ingangsdatum,
|
|
( (fac.safe_to_number (km1.mld_kenmerkmelding_waarde / 12))
|
|
* (13
|
|
- (EXTRACT (
|
|
MONTH FROM fac.safe_to_date (
|
|
km2.mld_kenmerkmelding_waarde,
|
|
'DD-MM-YYYY')))))
|
|
jaareffect_rest,
|
|
COALESCE (
|
|
a.afdoms,
|
|
(SELECT lkp.PRS_KOSTENPLAATS_OMSCHRIJVING
|
|
FROM mld_kenmerkmelding km3, LOGC_V_KOSTENPLAATS_KLANT lkp
|
|
WHERE km3.mld_melding_key = m.mld_melding_key
|
|
AND km3.mld_kenmerk_key = 201
|
|
AND km3.mld_kenmerkmelding_waarde =
|
|
TO_CHAR (lkp.prs_kostenplaats_key)),
|
|
(SELECT mld_kenmerkmelding_waarde
|
|
FROM mld_kenmerkmelding km4
|
|
WHERE km4.mld_melding_key = m.mld_melding_key
|
|
AND km4.mld_kenmerk_key = 165))
|
|
Klant
|
|
FROM mld_kenmerkmelding km1,
|
|
mld_kenmerkmelding km2,
|
|
mld_melding m,
|
|
mld_statuses ms,
|
|
(SELECT prs_afdeling_key,
|
|
prs_afdeling_naam || ' - ' || prs_afdeling_omschrijving
|
|
afdoms
|
|
FROM prs_afdeling
|
|
WHERE prs_afdeling_key != 104) a, --- FCLT doet niet mee
|
|
mld_stdmelding std,
|
|
prs_v_perslid_fullnames_all pf
|
|
WHERE km1.mld_kenmerk_key = 171 --- Jaareffect
|
|
AND km2.mld_kenmerk_key = 167 --- Ingangsdatum
|
|
AND m.mld_melding_key = km1.mld_melding_key
|
|
AND m.prs_afdeling_key = a.prs_afdeling_key(+)
|
|
AND m.mld_stdmelding_key = std.mld_stdmelding_key
|
|
AND km2.mld_melding_key = m.mld_melding_key
|
|
AND m.mld_melding_status != 1 --- afgewezen
|
|
AND m.mld_melding_status = ms.mld_statuses_key
|
|
AND pf.prs_perslid_key = m.prs_perslid_key;
|
|
|
|
|
|
CREATE OR REPLACE VIEW logc_v_rap_crm_gespreksverslag
|
|
(
|
|
mld_melding_key,
|
|
melding_datum,
|
|
melding_einddatum,
|
|
melder,
|
|
behandelaar,
|
|
actieve_behandelaar,
|
|
omschrijving,
|
|
onderwerp,
|
|
omgevingscode,
|
|
actief,
|
|
mld_statuses_key,
|
|
mld_statuses_omschrijving,
|
|
beslisdatum,
|
|
maandbedrag,
|
|
implementatie,
|
|
training,
|
|
kans
|
|
)
|
|
AS
|
|
SELECT mld_melding_key,
|
|
mld_melding_datum melding_datum,
|
|
mld_melding_einddatum melding_einddatum,
|
|
pf1.prs_perslid_naam_full melder,
|
|
pf2.prs_perslid_naam_full behandelaar,
|
|
pf3.prs_perslid_naam_full actieve_behandelaar,
|
|
mld_melding_omschrijving,
|
|
mld_melding_onderwerp,
|
|
prs_afdeling_naam omgevingscode,
|
|
DECODE (mld_statuses_key,
|
|
1, 'Gesloten',
|
|
6, 'Gesloten',
|
|
5, 'Gesloten',
|
|
'Open')
|
|
actief,
|
|
ms.mld_statuses_key,
|
|
ms.mld_statuses_omschrijving,
|
|
(SELECT TO_DATE(mld_kenmerkmelding_waarde, 'DD-MM-YYYY')
|
|
FROM mld_kenmerkmelding km
|
|
WHERE mld_kenmerk_key = 642
|
|
AND km.mld_melding_key = m.mld_melding_key)
|
|
beslisdatum,
|
|
(SELECT fac.safe_to_number(mld_kenmerkmelding_waarde)
|
|
FROM mld_kenmerkmelding km
|
|
WHERE mld_kenmerk_key = 643
|
|
AND km.mld_melding_key = m.mld_melding_key)
|
|
maandbedrag,
|
|
(SELECT fac.safe_to_number(mld_kenmerkmelding_waarde)
|
|
FROM mld_kenmerkmelding km
|
|
WHERE mld_kenmerk_key = 644
|
|
AND km.mld_melding_key = m.mld_melding_key)
|
|
implementatie,
|
|
(SELECT fac.safe_to_number(mld_kenmerkmelding_waarde)
|
|
FROM mld_kenmerkmelding km
|
|
WHERE mld_kenmerk_key = 645
|
|
AND km.mld_melding_key = m.mld_melding_key)
|
|
training,
|
|
(SELECT fac.safe_to_number(mld_kenmerkmelding_waarde)
|
|
FROM mld_kenmerkmelding km
|
|
WHERE mld_kenmerk_key = 646
|
|
AND km.mld_melding_key = m.mld_melding_key)
|
|
kans
|
|
FROM mld_melding m,
|
|
prs_v_perslid_fullnames_all pf1,
|
|
prs_v_perslid_fullnames_all pf2,
|
|
prs_v_perslid_fullnames_all pf3,
|
|
mld_statuses ms,
|
|
prs_afdeling a
|
|
WHERE mld_stdmelding_key = 281 -- gespreksverslag
|
|
AND fac_activiteit_key IS NULL
|
|
AND pf1.prs_perslid_key = m.prs_perslid_key
|
|
AND pf2.prs_perslid_key(+) = m.mld_melding_behandelaar_key
|
|
AND pf3.prs_perslid_key(+) = m.mld_melding_behandelaar2_key
|
|
AND m.mld_melding_status = ms.mld_statuses_key
|
|
AND m.prs_afdeling_key = a.prs_afdeling_key;
|
|
|
|
|
|
CREATE OR REPLACE VIEW logc_v_rap_crm_prospects
|
|
(
|
|
mld_melding_key,
|
|
melding_datum,
|
|
melding_einddatum,
|
|
behandelaar,
|
|
omschrijving,
|
|
onderwerp,
|
|
actief,
|
|
mld_statuses_key,
|
|
mld_statuses_omschrijving,
|
|
leadbron,
|
|
bedrijfsnaam,
|
|
contactpersoon,
|
|
telefoon,
|
|
email,
|
|
contactpersoon_overig,
|
|
actietrigger,
|
|
documentatie,
|
|
proeftuin,
|
|
demo_gegeven,
|
|
offerte_verstuurd,
|
|
inschatting,
|
|
beslisdatum,
|
|
maandbedrag,
|
|
implementatie,
|
|
training,
|
|
contractjaren,
|
|
kans,
|
|
contractwaarde,
|
|
project_fase
|
|
)
|
|
AS
|
|
SELECT mld_melding_key,
|
|
mld_melding_datum
|
|
melding_datum,
|
|
mld_melding_einddatum
|
|
melding_einddatum,
|
|
pf.prs_perslid_naam_friendly
|
|
behandelaar,
|
|
mld_melding_omschrijving,
|
|
mld_melding_onderwerp,
|
|
DECODE (mld_statuses_key,
|
|
1, 'Gesloten',
|
|
6, 'Gesloten',
|
|
5, 'Gesloten',
|
|
'Open')
|
|
actief,
|
|
ms.mld_statuses_key,
|
|
ms.mld_statuses_omschrijving,
|
|
(SELECT fac_usrdata_omschr
|
|
FROM mld_kenmerkmelding km, fac_usrdata ud
|
|
WHERE mld_kenmerk_key = 401
|
|
AND km.mld_melding_key = m.mld_melding_key
|
|
AND km.mld_kenmerkmelding_waarde = ud.fac_usrdata_key
|
|
AND fac_usrtab_key = 221)
|
|
leadbron,
|
|
(SELECT mld_kenmerkmelding_waarde
|
|
FROM mld_kenmerkmelding km
|
|
WHERE mld_kenmerk_key = 463
|
|
AND km.mld_melding_key = m.mld_melding_key)
|
|
bedrijfsnaam,
|
|
(SELECT mld_kenmerkmelding_waarde
|
|
FROM mld_kenmerkmelding km
|
|
WHERE mld_kenmerk_key = 470
|
|
AND km.mld_melding_key = m.mld_melding_key)
|
|
contactpersoon,
|
|
(SELECT mld_kenmerkmelding_waarde
|
|
FROM mld_kenmerkmelding km
|
|
WHERE mld_kenmerk_key = 474
|
|
AND km.mld_melding_key = m.mld_melding_key)
|
|
telefoon,
|
|
(SELECT mld_kenmerkmelding_waarde
|
|
FROM mld_kenmerkmelding km
|
|
WHERE mld_kenmerk_key = 469
|
|
AND km.mld_melding_key = m.mld_melding_key)
|
|
email,
|
|
(SELECT mld_kenmerkmelding_waarde
|
|
FROM mld_kenmerkmelding km
|
|
WHERE mld_kenmerk_key = 472
|
|
AND km.mld_melding_key = m.mld_melding_key)
|
|
contactpersoon_overig,
|
|
CASE
|
|
WHEN TRUNC (mld_melding_einddatum) < TRUNC (SYSDATE)
|
|
THEN
|
|
'!! '
|
|
|| (SELECT mld_kenmerkmelding_waarde
|
|
FROM mld_kenmerkmelding km
|
|
WHERE mld_kenmerk_key = 461
|
|
AND km.mld_melding_key = m.mld_melding_key)
|
|
ELSE
|
|
(SELECT mld_kenmerkmelding_waarde
|
|
FROM mld_kenmerkmelding km
|
|
WHERE mld_kenmerk_key = 461
|
|
AND km.mld_melding_key = m.mld_melding_key)
|
|
END
|
|
actietrigger,
|
|
(SELECT DECODE (mld_kenmerkmelding_waarde, 1, 'Ja')
|
|
FROM mld_kenmerkmelding km
|
|
WHERE mld_kenmerk_key = 468
|
|
AND km.mld_melding_key = m.mld_melding_key)
|
|
documentatie,
|
|
(SELECT DECODE (mld_kenmerkmelding_waarde, 1, 'Ja')
|
|
FROM mld_kenmerkmelding km
|
|
WHERE mld_kenmerk_key = 473
|
|
AND km.mld_melding_key = m.mld_melding_key)
|
|
proeftuin,
|
|
(SELECT DECODE (mld_kenmerkmelding_waarde, 1, 'Ja')
|
|
FROM mld_kenmerkmelding km
|
|
WHERE mld_kenmerk_key = 467
|
|
AND km.mld_melding_key = m.mld_melding_key)
|
|
demo_gegeven,
|
|
(SELECT DECODE (mld_kenmerkmelding_waarde, 1, 'Ja')
|
|
FROM mld_kenmerkmelding km
|
|
WHERE mld_kenmerk_key = 471
|
|
AND km.mld_melding_key = m.mld_melding_key)
|
|
offerte_verstuurd,
|
|
(SELECT fac.safe_to_number (mld_kenmerkmelding_waarde)
|
|
FROM mld_kenmerkmelding km
|
|
WHERE mld_kenmerk_key = 542
|
|
AND km.mld_melding_key = m.mld_melding_key)
|
|
inschatting,
|
|
(SELECT TO_DATE (mld_kenmerkmelding_waarde, 'DD-MM-YYYY')
|
|
FROM mld_kenmerkmelding km
|
|
WHERE mld_kenmerk_key = 626
|
|
AND km.mld_melding_key = m.mld_melding_key)
|
|
beslisdatum,
|
|
(SELECT fac.safe_to_number (mld_kenmerkmelding_waarde)
|
|
FROM mld_kenmerkmelding km
|
|
WHERE mld_kenmerk_key = 623
|
|
AND km.mld_melding_key = m.mld_melding_key)
|
|
maandbedrag,
|
|
(SELECT fac.safe_to_number (mld_kenmerkmelding_waarde)
|
|
FROM mld_kenmerkmelding km
|
|
WHERE mld_kenmerk_key = 624
|
|
AND km.mld_melding_key = m.mld_melding_key)
|
|
implementatie,
|
|
(SELECT fac.safe_to_number (mld_kenmerkmelding_waarde)
|
|
FROM mld_kenmerkmelding km
|
|
WHERE mld_kenmerk_key = 625
|
|
AND km.mld_melding_key = m.mld_melding_key)
|
|
training,
|
|
(SELECT fac.safe_to_number (mld_kenmerkmelding_waarde)
|
|
FROM mld_kenmerkmelding km
|
|
WHERE mld_kenmerk_key = 628
|
|
AND km.mld_melding_key = m.mld_melding_key)
|
|
contractjaren,
|
|
(SELECT fac.safe_to_number (mld_kenmerkmelding_waarde)
|
|
FROM mld_kenmerkmelding km
|
|
WHERE mld_kenmerk_key = 542
|
|
AND km.mld_melding_key = m.mld_melding_key)
|
|
kans,
|
|
(SELECT fac.safe_to_number (mld_kenmerkmelding_waarde)
|
|
FROM mld_kenmerkmelding km
|
|
WHERE mld_kenmerk_key = 629
|
|
AND km.mld_melding_key = m.mld_melding_key)
|
|
contractwaarde,
|
|
(SELECT fu.fac_usrdata_omschr
|
|
FROM mld_kenmerkmelding km, mld_kenmerk k, fac_usrdata fu
|
|
WHERE mld_srtkenmerk_key = 661
|
|
AND k.mld_kenmerk_key = km.mld_kenmerk_key
|
|
AND km.mld_melding_key = m.mld_melding_key
|
|
AND fac.safe_to_number (mld_kenmerkmelding_waarde) =
|
|
fu.fac_usrdata_key)
|
|
project_fase
|
|
FROM mld_melding m, prs_v_perslid_fullnames_all pf, mld_statuses ms
|
|
WHERE mld_stdmelding_key = 341 -- Prospects
|
|
AND fac_activiteit_key IS NULL
|
|
AND pf.prs_perslid_key =
|
|
COALESCE (m.mld_melding_behandelaar2_key,
|
|
m.mld_melding_behandelaar_key,
|
|
m.prs_perslid_key)
|
|
AND m.mld_melding_status = ms.mld_statuses_key;
|
|
|
|
|
|
|
|
CREATE OR REPLACE VIEW logc_v_crm_contactxbedrijf
|
|
AS
|
|
SELECT prs_contactpersoon_key,
|
|
prs_contactpersoon_naam,
|
|
prs_contactpersoon_tussenv,
|
|
prs_contactpersoon_voornaam,
|
|
cp.prs_contactpersoon_naam
|
|
|| NVL2 (cp.prs_contactpersoon_voorletters,
|
|
', ' || cp.prs_contactpersoon_voorletters,
|
|
'')
|
|
|| NVL2 (cp.prs_contactpersoon_tussenv,
|
|
' ' || cp.prs_contactpersoon_tussenv,
|
|
'')
|
|
|| NVL2 (cp.prs_contactpersoon_voornaam,
|
|
' (' || cp.prs_contactpersoon_voornaam || ')',
|
|
'')
|
|
naam_full,
|
|
prs_contactpersoon_telefoon_1,
|
|
prs_contactpersoon_telefoon_2,
|
|
prs_contactpersoon_email,
|
|
prs_bedrijf_naam,
|
|
prs_bedrijf_post_adres,
|
|
prs_bedrijf_post_postcode,
|
|
prs_bedrijf_post_plaats,
|
|
prs_bedrijf_post_land,
|
|
prs_bedrijf_bezoek_adres,
|
|
prs_bedrijf_bezoek_postcode,
|
|
prs_bedrijf_bezoek_plaats,
|
|
prs_bedrijf_bezoek_land,
|
|
prs_leverancier_nr,
|
|
prs_overeenkomst_nr,
|
|
(SELECT DECODE (prs_kenmerklink_waarde, 1, 'Ja', 'Nee')
|
|
FROM prs_kenmerklink pk
|
|
WHERE prs_kenmerklink_niveau = 'C'
|
|
AND prs_kenmerk_key = 1240
|
|
AND pk.prs_link_key = cp.prs_contactpersoon_key)
|
|
Magazine,
|
|
(SELECT DECODE (prs_kenmerklink_waarde, 1, 'Ja', 'Nee')
|
|
FROM prs_kenmerklink pk
|
|
WHERE prs_kenmerklink_niveau = 'C'
|
|
AND prs_kenmerk_key = 1180
|
|
AND pk.prs_link_key = cp.prs_contactpersoon_key)
|
|
Uitnodigen_FUN
|
|
FROM prs_contactpersoon cp, prs_bedrijf b
|
|
WHERE cp.prs_bedrijf_key = b.prs_bedrijf_key(+)
|
|
AND prs_bedrijf_verwijder IS NULL
|
|
AND prs_contactpersoon_verwijder IS NULL;
|
|
|
|
CREATE OR REPLACE VIEW logc_v_rap_releasemanagement
|
|
AS
|
|
SELECT m.mld_melding_key,
|
|
m.mld_melding_key melding,
|
|
ms.mld_statuses_omschrijving status,
|
|
mld_melding_datum datum,
|
|
a.prs_afdeling_naam klantcode,
|
|
prs_kostenplaats_nr kostenplaats,
|
|
pfpb.prs_perslid_naam_full behandelaar,
|
|
std.mld_stdmelding_omschrijving std_melding,
|
|
d.ins_discipline_omschrijving vakgroep,
|
|
mld_melding_onderwerp onderwerp,
|
|
mld_melding_omschrijving omschrijving,
|
|
pfm.prs_perslid_naam_full melder,
|
|
pfab.prs_perslid_naam_full actieve_behandelaar,
|
|
dbg.ins_discipline_omschrijving behandelgroep,
|
|
CASE dbg.ins_discipline_key
|
|
WHEN 41
|
|
THEN
|
|
CASE
|
|
WHEN pfab.prs_perslid_key IS NOT NULL
|
|
THEN
|
|
'Dev assigned'
|
|
ELSE
|
|
'Dev ToDo'
|
|
END
|
|
ELSE
|
|
dbg.ins_discipline_omschrijving
|
|
END
|
|
behandelgroepx,
|
|
km.mld_kenmerkmelding_waarde planning,
|
|
(SELECT ud.fac_usrdata_volgnr || '. ' || ud.fac_usrdata_omschr
|
|
FROM mld_kenmerkmelding mk, mld_kenmerk K, fac_usrdata ud
|
|
WHERE mk.mld_kenmerk_key = k.mld_kenmerk_key
|
|
AND k.mld_srtkenmerk_key = 24
|
|
AND mk.mld_melding_key = m.mld_melding_key
|
|
AND fac.safe_to_number (mk.mld_kenmerkmelding_waarde) =
|
|
ud.fac_usrdata_key
|
|
AND ud.fac_usrtab_key = 22)
|
|
moscow,
|
|
(SELECT fac.safe_to_number (mld_kenmerkmelding_waarde)
|
|
FROM mld_kenmerkmelding mk, mld_kenmerk K
|
|
WHERE mk.mld_kenmerk_key = k.mld_kenmerk_key
|
|
AND k.mld_srtkenmerk_key = 2
|
|
AND mk.mld_melding_key = m.mld_melding_key)
|
|
raming
|
|
FROM mld_melding M,
|
|
mld_stdmelding std,
|
|
mld_discipline d,
|
|
mld_statuses ms,
|
|
prs_afdeling a,
|
|
prs_kostenplaats pk,
|
|
prs_v_perslid_fullnames_all pfpb,
|
|
prs_v_perslid_fullnames_all pfm,
|
|
prs_v_perslid_fullnames_all pfab,
|
|
mld_discipline dbg,
|
|
mld_kenmerk k,
|
|
mld_kenmerkmelding km
|
|
WHERE mld_melding_status NOT IN (1, 5, 6)
|
|
AND m.mld_stdmelding_key = std.mld_stdmelding_key
|
|
AND std.mld_ins_discipline_key = d.ins_discipline_key
|
|
AND d.ins_srtdiscipline_key = 1
|
|
AND m.mld_melding_status = ms.mld_statuses_key
|
|
AND m.prs_afdeling_key = a.prs_afdeling_key
|
|
AND m.prs_kostenplaats_key = pk.prs_kostenplaats_key(+)
|
|
AND m.mld_melding_behandelaar_key = pfpb.prs_perslid_key(+)
|
|
AND m.prs_perslid_key_voor = pfm.prs_perslid_key
|
|
AND m.mld_melding_behandelaar2_key = pfab.prs_perslid_key(+)
|
|
AND m.mld_ins_discipline_key = dbg.ins_discipline_key(+)
|
|
AND m.mld_melding_key = km.mld_melding_key
|
|
AND km.mld_kenmerk_key = k.mld_kenmerk_key
|
|
AND k.mld_srtkenmerk_key = 1
|
|
AND km.mld_kenmerkmelding_waarde LIKE '2%';
|
|
|
|
------ 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 |