1199 lines
45 KiB
SQL
1199 lines
45 KiB
SQL
--
|
|
-- $Id$
|
|
--
|
|
-- Script containing customer specific sql statements for the FACILITOR database
|
|
|
|
DEFINE thisfile = 'STAM.SQL'
|
|
DEFINE dbuser = '^STAM'
|
|
DEFINE custid = 'STAM'
|
|
|
|
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 STAM_V_PROJECTKOSTENPLAATSEN
|
|
(
|
|
KOSTENPLAATS_KEY,
|
|
KOSTENPLAATS,
|
|
KOSTENPLAATS_VERWIJDER
|
|
)
|
|
AS
|
|
SELECT prs_kostenplaats_key,
|
|
prs_kostenplaats_upper,
|
|
prs_kostenplaats_verwijder
|
|
FROM prs_kostenplaats k
|
|
WHERE k.prs_kostenplaats_module = 'PRJ';
|
|
|
|
CREATE OR REPLACE VIEW STAM_V_PROJECTMANAGERS
|
|
(
|
|
PRS_PERSLID_KEY,
|
|
PROJECTMANAGER
|
|
)
|
|
AS
|
|
SELECT p.prs_perslid_key, n.prs_perslid_naam_full
|
|
FROM prs_perslid p, prs_v_perslid_fullnames n
|
|
WHERE p.prs_srtperslid_key = 157
|
|
AND n.prs_perslid_key = p.prs_perslid_key;
|
|
|
|
|
|
|
|
-- BASISVIEW VOOR ALLE QR CODES!
|
|
-- Onderscheid word gedefineerd in de 3 onderliggende VIEWS
|
|
CREATE OR REPLACE VIEW STAM_V_INS_QRC_alg
|
|
(
|
|
HIDE_F_SORT,
|
|
LOCATIE_CODE,
|
|
FCLT_F_LOCATIE,
|
|
FCLT_F_GEBOUW,
|
|
FCLT_F_PLAATS,
|
|
RUIMTENR,
|
|
naam,
|
|
FCLT_F_DISCIPLINE,
|
|
FCLT_F_OBJECTGROEP,
|
|
FCLT_F_OBJECTSOORT,
|
|
FCLT_F_IDENTIFICATIE,
|
|
FCLT_F_BOOKMARK,
|
|
INS_DEEL_KEY,
|
|
INS_SRTDEEL_KEY,
|
|
FCLT_3D_DISCIPLINE_KEY,
|
|
FCLT_3D_LOCATIE_KEY,
|
|
INS_ALG_RUIMTE_TYPE,
|
|
INS_ALG_RUIMTE_KEY,
|
|
BRAND,
|
|
OBJ_TYPE,
|
|
BOOKMARK_ID,
|
|
SERIENUMMER,
|
|
Gekoppeld_aan,
|
|
uitleenbaar
|
|
)
|
|
AS
|
|
SELECT i.ins_deel_omschrijving
|
|
hide_f_sort,
|
|
l.alg_locatie_code,
|
|
l.alg_locatie_code || ' ' || l.alg_locatie_omschrijving
|
|
fclt_f_locatie,
|
|
o.alg_gebouw_omschrijving
|
|
fclt_f_gebouw,
|
|
SUBSTR (o.alg_plaatsaanduiding, 13)
|
|
fclt_f_plaats,
|
|
o.alg_ruimte_nr,
|
|
NULL
|
|
prs_perslid_naam,
|
|
d.ins_discipline_omschrijving
|
|
fclt_f_discipline,
|
|
g.ins_srtgroep_omschrijving
|
|
fclt_f_objectgroep,
|
|
s.ins_srtdeel_omschrijving
|
|
fclt_f_objectsoort,
|
|
i.ins_deel_omschrijving
|
|
fclt_f_identificatie,
|
|
b.fac_bookmark_naam
|
|
fclt_f_bookmark,
|
|
i.ins_deel_key,
|
|
s.ins_srtdeel_key,
|
|
i.ins_discipline_key
|
|
fclt_3d_discipline_key,
|
|
l.alg_locatie_key
|
|
fclt_3d_locatie_key,
|
|
i.ins_alg_ruimte_type,
|
|
i.ins_alg_ruimte_key,
|
|
brand.ins_kenmerkdeel_waarde,
|
|
obj_type.ins_kenmerkdeel_waarde,
|
|
b.fac_bookmark_id
|
|
hide_f_bookmark_id,
|
|
(SELECT ins_kenmerkdeel_waarde
|
|
FROM ins_kenmerkdeel kd, ins_kenmerk k
|
|
WHERE k.ins_kenmerk_key = kd.ins_kenmerk_key
|
|
AND ins_srtkenmerk_key = 25
|
|
AND i.ins_deel_key = kd.ins_deel_key)
|
|
serienummer,
|
|
'Ruimte'
|
|
Gekoppeld_aan,
|
|
s.INS_SRTDEEL_UITLEENBAAR
|
|
FROM ins_deel i,
|
|
ins_v_alg_overzicht o,
|
|
ins_srtdeel s,
|
|
ins_srtgroep g,
|
|
ins_discipline d,
|
|
alg_locatie l,
|
|
fac_bookmark b,
|
|
(SELECT kd.ins_deel_key, kd.ins_kenmerkdeel_waarde
|
|
FROM ins_kenmerk k, ins_kenmerkdeel kd
|
|
WHERE k.ins_srtkenmerk_key = 41
|
|
AND kd.ins_kenmerk_key = k.ins_kenmerk_key
|
|
AND k.ins_kenmerk_verwijder IS NULL
|
|
AND kd.ins_kenmerkdeel_verwijder IS NULL) brand,
|
|
(SELECT kd.ins_deel_key, kd.ins_kenmerkdeel_waarde
|
|
FROM ins_kenmerk k, ins_kenmerkdeel kd
|
|
WHERE k.ins_srtkenmerk_key = 42
|
|
AND kd.ins_kenmerk_key = k.ins_kenmerk_key
|
|
AND k.ins_kenmerk_verwijder IS NULL
|
|
AND kd.ins_kenmerkdeel_verwijder IS NULL) obj_type
|
|
WHERE UPPER (b.fac_bookmark_naam) IN
|
|
('QRC_UITLEEN_OBJ',
|
|
'QRC_OBJECT_MELDING',
|
|
'QRC NAAR OBJECT')
|
|
AND COALESCE (b.fac_bookmark_expire, SYSDATE + 1) > SYSDATE
|
|
AND ins_deel_verwijder IS NULL
|
|
AND COALESCE (i.ins_deel_vervaldatum, SYSDATE + 1) > SYSDATE
|
|
AND i.ins_deel_module = 'INS'
|
|
AND i.ins_deel_parent_key IS NULL
|
|
AND s.ins_srtdeel_key = i.ins_srtdeel_key
|
|
AND g.ins_srtgroep_key = s.ins_srtgroep_key
|
|
AND d.ins_discipline_key = g.ins_discipline_key
|
|
AND o.alg_onroerendgoed_keys =
|
|
COALESCE (i.ins_alg_ruimte_key_org, i.ins_alg_ruimte_key)
|
|
AND o.alg_onroerendgoed_type =
|
|
COALESCE (i.ins_alg_ruimte_type_org, i.ins_alg_ruimte_type)
|
|
AND COALESCE (i.ins_alg_ruimte_type_org, i.ins_alg_ruimte_type) IN
|
|
('T', 'R', 'W')
|
|
AND o.alg_locatie_key = i.ins_alg_locatie_key
|
|
AND l.alg_locatie_key = i.ins_alg_locatie_key
|
|
AND i.ins_deel_key = brand.ins_deel_key(+)
|
|
AND i.ins_deel_key = obj_type.ins_deel_key(+)
|
|
UNION ALL
|
|
SELECT i.ins_deel_omschrijving
|
|
hide_f_sort,
|
|
NULL,
|
|
NULL
|
|
fclt_f_locatie,
|
|
NULL
|
|
fclt_f_gebouw,
|
|
NULL
|
|
fclt_f_plaats,
|
|
NULL,
|
|
p.prs_perslid_naam,
|
|
d.ins_discipline_omschrijving
|
|
fclt_f_discipline,
|
|
g.ins_srtgroep_omschrijving
|
|
fclt_f_objectgroep,
|
|
s.ins_srtdeel_omschrijving
|
|
fclt_f_objectsoort,
|
|
i.ins_deel_omschrijving
|
|
fclt_f_identificatie,
|
|
b.fac_bookmark_naam
|
|
fclt_f_bookmark,
|
|
i.ins_deel_key,
|
|
s.ins_srtdeel_key,
|
|
i.ins_discipline_key
|
|
fclt_3d_discipline_key,
|
|
NULL
|
|
fclt_3d_locatie_key,
|
|
i.ins_alg_ruimte_type,
|
|
i.ins_alg_ruimte_key,
|
|
brand.ins_kenmerkdeel_waarde,
|
|
obj_type.ins_kenmerkdeel_waarde,
|
|
b.fac_bookmark_id
|
|
hide_f_bookmark_id,
|
|
(SELECT ins_kenmerkdeel_waarde
|
|
FROM ins_kenmerkdeel kd, ins_kenmerk k
|
|
WHERE k.ins_kenmerk_key = kd.ins_kenmerk_key
|
|
AND ins_srtkenmerk_key = 25
|
|
AND i.ins_deel_key = kd.ins_deel_key)
|
|
serienummer,
|
|
'Persoon',
|
|
s.INS_SRTDEEL_UITLEENBAAR
|
|
uitleenbaar
|
|
FROM ins_deel i,
|
|
ins_srtdeel s,
|
|
ins_srtgroep g,
|
|
prs_perslid p,
|
|
ins_discipline d,
|
|
fac_bookmark b,
|
|
(SELECT kd.ins_deel_key, kd.ins_kenmerkdeel_waarde
|
|
FROM ins_kenmerk k, ins_kenmerkdeel kd
|
|
WHERE k.ins_srtkenmerk_key = 41
|
|
AND kd.ins_kenmerk_key = k.ins_kenmerk_key
|
|
AND k.ins_kenmerk_verwijder IS NULL
|
|
AND kd.ins_kenmerkdeel_verwijder IS NULL) brand,
|
|
(SELECT kd.ins_deel_key, kd.ins_kenmerkdeel_waarde
|
|
FROM ins_kenmerk k, ins_kenmerkdeel kd
|
|
WHERE k.ins_srtkenmerk_key = 42
|
|
AND kd.ins_kenmerk_key = k.ins_kenmerk_key
|
|
AND k.ins_kenmerk_verwijder IS NULL
|
|
AND kd.ins_kenmerkdeel_verwijder IS NULL) obj_type
|
|
WHERE UPPER (b.fac_bookmark_naam) IN
|
|
('QRC_UITLEEN_OBJ',
|
|
'QRC_OBJECT_MELDING',
|
|
'QRC NAAR OBJECT')
|
|
AND COALESCE (b.fac_bookmark_expire, SYSDATE + 1) > SYSDATE
|
|
AND ins_deel_verwijder IS NULL
|
|
AND COALESCE (i.ins_deel_vervaldatum, SYSDATE + 1) > SYSDATE
|
|
AND i.ins_deel_module = 'INS'
|
|
AND i.ins_deel_parent_key IS NULL
|
|
AND s.ins_srtdeel_key = i.ins_srtdeel_key
|
|
AND g.ins_srtgroep_key = s.ins_srtgroep_key
|
|
AND d.ins_discipline_key = g.ins_discipline_key
|
|
AND p.prs_perslid_key =
|
|
COALESCE (i.ins_alg_ruimte_key_org, i.ins_alg_ruimte_key)
|
|
AND COALESCE (i.ins_alg_ruimte_type_org, i.ins_alg_ruimte_type) =
|
|
'P'
|
|
AND i.ins_deel_key = brand.ins_deel_key(+)
|
|
AND i.ins_deel_key = obj_type.ins_deel_key(+);
|
|
|
|
create or replace view STAM_V_INS_QRC_UITLEEN
|
|
as
|
|
select * from STAM_V_INS_QRC_alg
|
|
where uitleenbaar = 1 and upper(fclt_f_bookmark) = 'QRC_UITLEEN_OBJ';
|
|
|
|
create or replace view STAM_V_INS_QRC_OBJECT_MELDING
|
|
as
|
|
select * from STAM_V_INS_QRC_alg
|
|
where ins_deel_key IN
|
|
(SELECT ins_deel_key FROM mld_v_mld_stdmelding_srtinst)
|
|
AND upper(fclt_f_bookmark) = 'QRC_OBJECT_MELDING';
|
|
|
|
create or replace view STAM_V_INS_QRC_OBJECTBEHEER
|
|
as
|
|
select * from STAM_V_INS_QRC_alg
|
|
where upper(fclt_f_bookmark) = 'QRC NAAR OBJECT';
|
|
|
|
|
|
CREATE OR REPLACE VIEW STAM_V_INS_QRC_RUIMTE
|
|
(
|
|
FCLT_3D_LOCATIE_KEY,
|
|
FCLT_F_LOCATIE,
|
|
FCLT_F_GEBOUW,
|
|
PLAATS,
|
|
SOORTRUIMTE,
|
|
INS_ALG_RUIMTE_TYPE,
|
|
ALG_DISTRICT_KEY,
|
|
ALG_RUIMTE_KEY,
|
|
HIDE_F_BOOKMARK_ID
|
|
)
|
|
AS
|
|
SELECT l.alg_locatie_key,
|
|
l.alg_locatie_omschrijving,
|
|
x.alg_gebouw_naam,
|
|
SUBSTR (x.alg_plaatsaanduiding, 7) plaats,
|
|
x.alg_ruimte_omschrijving soortruimte,
|
|
SR.ALG_SRTRUIMTE_OMSCHRIJVING,
|
|
l.alg_district_key,
|
|
x.alg_ruimte_key,
|
|
b.fac_bookmark_id
|
|
FROM ALG_V_ALLONRGOED_GEGEVENS x,
|
|
alg_locatie l,
|
|
alg_district di,
|
|
fac_bookmark b,
|
|
alg_ruimte r,
|
|
alg_srtruimte sr
|
|
WHERE b.fac_bookmark_naam = 'QRC naar ruimte'
|
|
AND X.ALG_RUIMTE_KEY = R.ALG_RUIMTE_KEY
|
|
AND R.ALG_SRTRUIMTE_KEY = SR.ALG_SRTRUIMTE_KEY
|
|
AND x.alg_locatie_key = L.ALG_LOCATIE_KEY
|
|
AND l.alg_district_key = di.alg_district_key;
|
|
|
|
CREATE OR REPLACE VIEW STAM_V_CATERING_RUIMTE
|
|
(
|
|
RUIMTENR,
|
|
RUIMTEOMSCHR
|
|
)
|
|
AS
|
|
SELECT ALG_RUIMTE_KEY RUIMTE,
|
|
ALG_RUIMTE_NR || '/' || ALG_RUIMTE_OMSCHRIJVING
|
|
FROM ALG_RUIMTE R, ALG_ONRGOEDKENMERK K
|
|
WHERE K.ALG_ONRGOED_KEY = R.ALG_RUIMTE_KEY;
|
|
|
|
|
|
CREATE OR REPLACE PROCEDURE stam_set_mldkenmerk (
|
|
p_kenmerk_key IN NUMBER,
|
|
p_mld_key IN NUMBER,
|
|
p_kenmerk_waarde IN VARCHAR2)
|
|
AS
|
|
|
|
v_count NUMBER;
|
|
v_niveau VARCHAR2 (1);
|
|
BEGIN
|
|
SELECT mld_kenmerk_niveau
|
|
INTO v_niveau
|
|
FROM mld_kenmerk
|
|
WHERE mld_kenmerk_key = p_kenmerk_key;
|
|
|
|
CASE v_niveau
|
|
WHEN 'O'
|
|
THEN
|
|
SELECT COUNT (*)
|
|
INTO v_count
|
|
FROM mld_kenmerkopdr
|
|
WHERE mld_opdr_key = p_mld_key
|
|
AND mld_kenmerk_key = p_kenmerk_key
|
|
AND mld_kenmerkopdr_verwijder IS NULL;
|
|
|
|
IF v_count = 1
|
|
THEN
|
|
IF p_kenmerk_waarde IS NULL
|
|
THEN
|
|
DELETE mld_kenmerkopdr
|
|
WHERE mld_opdr_key = p_mld_key
|
|
AND mld_kenmerk_key = p_kenmerk_key
|
|
AND mld_kenmerkopdr_verwijder IS NULL;
|
|
ELSE
|
|
UPDATE mld_kenmerkopdr
|
|
SET mld_kenmerkopdr_waarde = p_kenmerk_waarde
|
|
WHERE mld_opdr_key = p_mld_key
|
|
AND mld_kenmerk_key = p_kenmerk_key
|
|
AND mld_kenmerkopdr_verwijder IS NULL;
|
|
END IF;
|
|
ELSE
|
|
IF p_kenmerk_key IS NOT NULL AND p_kenmerk_waarde IS NOT NULL
|
|
THEN
|
|
INSERT INTO mld_kenmerkopdr (mld_kenmerk_key,
|
|
mld_opdr_key,
|
|
mld_kenmerkopdr_waarde)
|
|
VALUES (p_kenmerk_key, p_mld_key, p_kenmerk_waarde);
|
|
END IF;
|
|
END IF;
|
|
WHEN 'S'
|
|
THEN
|
|
SELECT COUNT (*)
|
|
INTO v_count
|
|
FROM mld_kenmerkmelding
|
|
WHERE mld_melding_key = p_mld_key
|
|
AND mld_kenmerk_key = p_kenmerk_key
|
|
AND mld_kenmerkmelding_verwijder IS NULL;
|
|
|
|
IF v_count = 1
|
|
THEN
|
|
IF p_kenmerk_waarde IS NULL
|
|
THEN
|
|
DELETE mld_kenmerkmelding
|
|
WHERE mld_melding_key = p_mld_key
|
|
AND mld_kenmerk_key = p_kenmerk_key
|
|
AND mld_kenmerkmelding_verwijder IS NULL;
|
|
ELSE
|
|
UPDATE mld_kenmerkmelding
|
|
SET mld_kenmerkmelding_waarde = p_kenmerk_waarde
|
|
WHERE mld_melding_key = p_mld_key
|
|
AND mld_kenmerk_key = p_kenmerk_key
|
|
AND mld_kenmerkmelding_verwijder IS NULL;
|
|
END IF;
|
|
ELSE
|
|
IF p_kenmerk_key IS NOT NULL AND p_kenmerk_waarde IS NOT NULL
|
|
THEN
|
|
INSERT INTO mld_kenmerkmelding (
|
|
mld_kenmerk_key,
|
|
mld_melding_key,
|
|
mld_kenmerkmelding_waarde)
|
|
VALUES (p_kenmerk_key, p_mld_key, p_kenmerk_waarde);
|
|
END IF;
|
|
END IF;
|
|
END CASE;
|
|
END;
|
|
/
|
|
|
|
CREATE OR REPLACE PROCEDURE STAM_STARTWF_EMPLOYEE (p_import_key IN NUMBER)
|
|
AS
|
|
v_count NUMBER;
|
|
melder prs_perslid.prs_perslid_key%TYPE;
|
|
kostenplaats prs_afdeling.prs_kostenplaats_key%TYPE;
|
|
newkey mld_melding.mld_melding_key%TYPE;
|
|
defaultstdmelding fac_setting.fac_setting_default%TYPE;
|
|
errormsg fac_result.fac_result_waarde%TYPE;
|
|
|
|
|
|
CURSOR c_new IS
|
|
SELECT i.*,
|
|
prs_perslid_naam
|
|
|| DECODE (prs_perslid_voorletters,
|
|
NULL, '',
|
|
', ' || prs_perslid_voorletters)
|
|
|| DECODE (prs_perslid_tussenvoegsel,
|
|
NULL, '',
|
|
' ' || prs_perslid_tussenvoegsel)
|
|
|| DECODE (prs_perslid_voornaam,
|
|
NULL, '',
|
|
' (' || prs_perslid_voornaam || ')') AS new_employee
|
|
FROM fac_imp_perslid i
|
|
WHERE NOT EXISTS
|
|
(SELECT *
|
|
FROM prs_perslid p
|
|
WHERE p.prs_perslid_nr = i.prs_perslid_nr);
|
|
BEGIN
|
|
--- De eerste melding van deze workflow is 'New employee' , key = 681
|
|
defaultstdmelding := '681';
|
|
|
|
FOR rc IN c_new
|
|
LOOP
|
|
BEGIN
|
|
--- Stamicarbon kent een dummy gebruiker voor het aanvragen van een nieuwe medewerker
|
|
--- Van deze medewerker halen we ook even de kostenplaats op
|
|
SELECT p.prs_perslid_key, a.prs_kostenplaats_key
|
|
INTO melder, kostenplaats
|
|
FROM prs_perslid p, prs_afdeling a
|
|
WHERE p.prs_perslid_upper = '_NEW EMPLOYEE'
|
|
AND p.prs_afdeling_key = a.prs_afdeling_key;
|
|
|
|
INSERT INTO mld_melding (mld_melding_module,
|
|
mld_meldbron_key,
|
|
mld_melding_datum,
|
|
mld_melding_onderwerp,
|
|
mld_melding_status,
|
|
mld_stdmelding_key,
|
|
prs_perslid_key,
|
|
prs_perslid_key_voor,
|
|
prs_kostenplaats_key,
|
|
mld_melding_spoed)
|
|
VALUES ('MLD',
|
|
2, -- email
|
|
SYSDATE,
|
|
'Nieuwe medewerker aangemeld vanuit AD',
|
|
4,
|
|
defaultstdmelding,
|
|
melder,
|
|
melder,
|
|
kostenplaats,
|
|
3)
|
|
RETURNING mld_melding_key
|
|
INTO newkey;
|
|
|
|
-- Kenmerkvelden vullen
|
|
--- 1601 Name employee
|
|
stam_set_mldkenmerk (1601, newkey, rc.new_employee);
|
|
|
|
-- 1602 Employee group ID (pers_nr)
|
|
stam_set_mldkenmerk (1602, newkey, rc.prs_perslid_nr);
|
|
|
|
-- 1603 Position (functie)
|
|
stam_set_mldkenmerk (1603,
|
|
newkey,
|
|
rc.prs_srtperslid_omschrijving);
|
|
|
|
-- 1604 Costcenter
|
|
stam_set_mldkenmerk (1604, newkey, rc.prs_afdeling_naam);
|
|
|
|
|
|
-- de startmelding krijgt status 5 en de volgende stap kan opgestart worden
|
|
-- mld.setmeldingstatus (newkey, 4 , melder);
|
|
mld.mld_nextworkflowstep (newkey, -1); -- 1=Completed
|
|
|
|
|
|
EXCEPTION
|
|
WHEN OTHERS
|
|
THEN
|
|
fac.writelog (
|
|
'PROCES NEW EMPLOYEE',
|
|
'W',
|
|
'Melding new employee kon niet aangemaakt worden: '
|
|
|| '['
|
|
|| errormsg
|
|
|| ']',
|
|
'OTHERS (error '
|
|
|| SQLCODE
|
|
|| '/'
|
|
|| SUBSTR (SQLERRM, 1, 100)
|
|
|| ')');
|
|
END;
|
|
END LOOP;
|
|
END STAM_STARTWF_EMPLOYEE;
|
|
/
|
|
|
|
CREATE OR REPLACE PROCEDURE stam_import_perslid (p_import_key IN NUMBER)
|
|
AS
|
|
oracle_err_num NUMBER;
|
|
oracle_err_mes VARCHAR2 (200);
|
|
v_errormsg VARCHAR2 (400);
|
|
v_errorhint VARCHAR2 (400);
|
|
v_aantal_in_FCLT NUMBER;
|
|
BEGIN
|
|
v_errorhint := 'Generieke update';
|
|
-- de sequence array staat beschreven in PRS_PAC.SRC bij de prs.import_perslid proc
|
|
prs.import_perslid (
|
|
p_import_key,
|
|
'0;0;0;0;0;0;12;4;0;3;'
|
|
|| '0;0;0;0;0;7;8;1;0;5;'
|
|
|| '6;2;0;0;0;0;9;12;13;10;'
|
|
|| '0;0;0;0;0;0;0;0;0;0;'
|
|
|| '0;0;0;0;0;0',
|
|
'"mail";"samAccountName";"givenName";"sn";"employeeID";"title";"telephoneNumber";"mobile";"physicalDeliveryOfficeName";"department";"departmentNumber";"extensionAttribute1";"manager"%');
|
|
|
|
COMMIT;
|
|
|
|
|
|
-- Uit kenmerk3 kan de manager gehaald worden
|
|
UPDATE fac_imp_perslid o
|
|
SET o.prs_kenmerk5 =
|
|
(SELECT p.prs_perslid_key
|
|
FROM fac_imp_perslid n, prs_perslid p
|
|
WHERE UPPER (SUBSTR (n.prs_kenmerk3,
|
|
( INSTR (n.PRS_KENMERK3,
|
|
'=',
|
|
1,
|
|
1)
|
|
+ 1),
|
|
( INSTR (n.PRS_KENMERK3,
|
|
',',
|
|
1,
|
|
1)
|
|
- INSTR (n.PRS_KENMERK3,
|
|
'=',
|
|
1,
|
|
1)
|
|
- 1))) =
|
|
UPPER (p.PRS_PERSLID_OSLOGIN)
|
|
AND n.PRS_PERSLID_NR = o.PRS_PERSLID_NR);
|
|
|
|
COMMIT;
|
|
EXCEPTION
|
|
WHEN OTHERS
|
|
THEN
|
|
oracle_err_num := SQLCODE;
|
|
oracle_err_mes := SUBSTR (SQLERRM, 1, 100);
|
|
v_errormsg := 'Error ' || oracle_err_num || '/' || oracle_err_mes;
|
|
fac.imp_writelog (p_import_key,
|
|
'E',
|
|
v_errormsg,
|
|
v_errorhint);
|
|
END stam_import_perslid;
|
|
/
|
|
|
|
--VIEW voor qrcodes per object STAM#56182
|
|
|
|
|
|
--VIEW voor qrcodes UITLENEN OBJECT STAM#56182
|
|
|
|
|
|
CREATE OR REPLACE PROCEDURE stam_update_perslid (p_import_key IN NUMBER)
|
|
IS
|
|
-- Alle personen verwijderen die niet meer in import bestand voorkomen.
|
|
-- Match bij STAM is personeelnummer, hieronder de query om alle personen te verwijderen die:
|
|
-- a) niet meer in het importbestand staan, wel in Facilitor, en
|
|
-- b) waarvan de persoon in Facilitor een gevulde personeelsnummer heeft (leeg personeelsnummer van af blijven, dit handmatig ingevoerde persleden)
|
|
-- c) waarvan de persoon in Facilitor niet begint met een _ in de loginnaam (ook van af blijven)
|
|
|
|
CURSOR c_mgr IS
|
|
SELECT *
|
|
FROM FAC_IMP_PERSLID p
|
|
WHERE p.PRS_PERSLID_KEY IS NOT NULL AND p.PRS_KENMERK5 IS NOT NULL;
|
|
|
|
CURSOR c_dep IS
|
|
SELECT *
|
|
FROM FAC_IMP_PERSLID p
|
|
WHERE p.PRS_PERSLID_KEY IS NOT NULL AND p.PRS_KENMERK4 IS NOT NULL;
|
|
|
|
CURSOR c_del IS
|
|
SELECT p.prs_perslid_key, p.prs_perslid_nr, pf.prs_perslid_naam_full
|
|
FROM fac_imp_perslid i,
|
|
prs_perslid p,
|
|
prs_v_perslid_fullnames_all pf
|
|
WHERE UPPER (p.prs_perslid_nr) = UPPER (i.prs_perslid_nr(+))
|
|
AND p.prs_perslid_verwijder IS NULL
|
|
AND SUBSTR (p.prs_perslid_oslogin, 1, 1) <> '_'
|
|
AND p.prs_perslid_nr IS NOT NULL
|
|
AND pf.prs_perslid_key = p.prs_perslid_key
|
|
AND i.prs_perslid_nr IS NULL
|
|
ORDER BY 2;
|
|
|
|
v_count NUMBER;
|
|
BEGIN
|
|
|
|
-- Voor alle nieuwe medewerkers moet eerst de workflow in dienst opgestart worden
|
|
stam_startwf_employee (p_import_key);
|
|
|
|
-- generic update
|
|
-- 'NR' betekent dat op basis van Personeelsnummer wordt gematched.
|
|
prs.update_perslid (p_import_key, 'NR', NULL);
|
|
|
|
-- zet de managerkey uit kenmerk 5 in het kenmerk veld manager (1042) bij de persoon
|
|
FOR rec IN c_mgr
|
|
LOOP
|
|
BEGIN
|
|
prs.upsertkenmerk (1061, rec.prs_perslid_key, rec.prs_kenmerk5);
|
|
END;
|
|
END LOOP;
|
|
|
|
-- zet de department uit kenmerk 4 in het kenmerk veld department (1060) bij de persoon
|
|
FOR rec IN c_dep
|
|
LOOP
|
|
BEGIN
|
|
prs.upsertkenmerk (1060, rec.prs_perslid_key, rec.prs_kenmerk4);
|
|
END;
|
|
END LOOP;
|
|
|
|
-- Verwijder personen die niet meer in de import voorkomen.
|
|
FOR rec IN c_del
|
|
LOOP
|
|
BEGIN
|
|
prs.delete_perslid (p_import_key, rec.prs_perslid_key);
|
|
END;
|
|
END LOOP;
|
|
END stam_update_perslid;
|
|
/
|
|
|
|
CREATE OR REPLACE VIEW STAM_V_RAP_SEARCHRESULT
|
|
(
|
|
FCLT_F_DATUM,
|
|
FCLT_F_PERSOON,
|
|
FCLT_F_ZOEKTERM,
|
|
RESULTAAT,
|
|
FCLT_F_KEUZE_TYPE,
|
|
KEUZE_URL,
|
|
KEUZE_OMSCHRIJVING
|
|
)
|
|
AS
|
|
SELECT fac_gui_counter_date datum,
|
|
prs_perslid_naam_full persoon,
|
|
fgc.fac_gui_counter_info zoekterm,
|
|
COALESCE (result.result, 'Geen') resultaat,
|
|
COALESCE (choice.TYPE, 'Geen') keuze_type,
|
|
choice.url keuze_url,
|
|
choice.oms keuze_omschrijving
|
|
FROM fac_gui_counter fgc,
|
|
prs_v_perslid_fullnames pf,
|
|
(SELECT fac_gui_counter_refkey,
|
|
fac_gui_counter_info url,
|
|
'Reserveerbaar artikel' TYPE,
|
|
res_artikel_omschrijving oms
|
|
FROM fac_gui_counter fgc, res_artikel ra
|
|
WHERE fac_gui_counter_info IS NOT NULL
|
|
AND fac_gui_counter_group = 'searchchoice'
|
|
AND fac_gui_counter_info LIKE '%res_artikel%'
|
|
AND ra.res_artikel_key(+) =
|
|
fac.safe_to_number (
|
|
SUBSTR (
|
|
fac_gui_counter_info,
|
|
(INSTR (fac_gui_counter_info, 'key=') + 4)))
|
|
UNION
|
|
SELECT fac_gui_counter_refkey,
|
|
fac_gui_counter_info,
|
|
'Reserveerbaar object',
|
|
res_deel_omschrijving
|
|
FROM fac_gui_counter fgc, res_deel rd
|
|
WHERE fac_gui_counter_info IS NOT NULL
|
|
AND fac_gui_counter_group = 'searchchoice'
|
|
AND fac_gui_counter_info LIKE '%res_deel%'
|
|
AND rd.res_deel_key(+) =
|
|
fac.safe_to_number (
|
|
SUBSTR (
|
|
fac_gui_counter_info,
|
|
(INSTR (fac_gui_counter_info, 'key=') + 4)))
|
|
UNION
|
|
SELECT fac_gui_counter_refkey,
|
|
fac_gui_counter_info,
|
|
'Melding',
|
|
std.mld_stdmelding_omschrijving oms
|
|
FROM fac_gui_counter fgc, mld_stdmelding std
|
|
WHERE fac_gui_counter_info IS NOT NULL
|
|
AND fac_gui_counter_group = 'searchchoice'
|
|
AND fac_gui_counter_info LIKE '%stdm%'
|
|
AND std.mld_stdmelding_key(+) =
|
|
fac.safe_to_number (
|
|
SUBSTR (fac_gui_counter_info,
|
|
(INSTR (fac_gui_counter_info, '=') + 1)))
|
|
UNION
|
|
SELECT fac_gui_counter_refkey,
|
|
fac_gui_counter_info,
|
|
'Kennisbank',
|
|
fac_faq_question oms
|
|
FROM fac_gui_counter fgc, fac_faq faq
|
|
WHERE fac_gui_counter_info IS NOT NULL
|
|
AND fac_gui_counter_group = 'searchchoice'
|
|
AND fac_gui_counter_info LIKE '%faq%'
|
|
AND fac_faq_key(+) =
|
|
fac.safe_to_number (
|
|
SUBSTR (fac_gui_counter_info,
|
|
(INSTR (fac_gui_counter_info, '=') + 1)))
|
|
UNION
|
|
SELECT fac_gui_counter_refkey,
|
|
fac_gui_counter_info,
|
|
'Reserveerbare ruimte',
|
|
res_ruimte_nr oms
|
|
FROM fac_gui_counter fgc, res_ruimte
|
|
WHERE fac_gui_counter_info IS NOT NULL
|
|
AND fac_gui_counter_group = 'searchchoice'
|
|
AND fac_gui_counter_info LIKE '%res_ruimte%'
|
|
AND res_ruimte_key(+) =
|
|
fac.safe_to_number (
|
|
SUBSTR (fac_gui_counter_info,
|
|
(INSTR (fac_gui_counter_info, '=') + 1)))
|
|
UNION
|
|
SELECT fac_gui_counter_refkey,
|
|
fac_gui_counter_info,
|
|
'Bestelling',
|
|
ins_discipline_omschrijving
|
|
FROM fac_gui_counter fgc, bes_discipline
|
|
WHERE fac_gui_counter_info IS NOT NULL
|
|
AND fac_gui_counter_group = 'searchchoice'
|
|
AND fac_gui_counter_info LIKE '%bes%'
|
|
AND ins_discipline_key(+) =
|
|
fac.safe_to_number (
|
|
SUBSTR (
|
|
fac_gui_counter_info,
|
|
(INSTR (fac_gui_counter_info, 'dis_key=') + 8)))
|
|
UNION
|
|
SELECT fac_gui_counter_refkey,
|
|
fac_gui_counter_info,
|
|
'Telefoonboek',
|
|
prs_perslid_naam_full
|
|
FROM fac_gui_counter fgc, prs_v_perslid_fullnames pf
|
|
WHERE fac_gui_counter_info IS NOT NULL
|
|
AND fac_gui_counter_group = 'searchchoice'
|
|
AND fac_gui_counter_info LIKE '%phone%'
|
|
AND pf.prs_perslid_key(+) =
|
|
fac.safe_to_number (
|
|
SUBSTR (fac_gui_counter_info,
|
|
(INSTR (fac_gui_counter_info, '=') + 1))))
|
|
choice,
|
|
(SELECT fac_gui_counter_refkey,
|
|
REPLACE (REPLACE (fac_gui_counter_info, '{', ''), '}', '') result
|
|
FROM fac_gui_counter fgc
|
|
WHERE fac_gui_counter_info IS NOT NULL
|
|
AND fac_gui_counter_group = 'searchresult') result
|
|
WHERE fac_gui_counter_group = 'search'
|
|
AND fgc.fac_gui_counter_info IS NOT NULL
|
|
AND fgc.prs_perslid_key = pf.prs_perslid_key
|
|
AND choice.fac_gui_counter_refkey(+) = fgc.fac_gui_counter_key
|
|
AND result.fac_gui_counter_refkey(+) = fgc.fac_gui_counter_key;
|
|
|
|
CREATE OR REPLACE FORCE VIEW stam_v_noti_mutatie_res
|
|
(
|
|
sender,
|
|
receiver,
|
|
text,
|
|
code,
|
|
fac_srtnotificatie_key,
|
|
key,
|
|
xkey,
|
|
xemail,
|
|
xmobile
|
|
)
|
|
AS
|
|
SELECT DISTINCT
|
|
NULL
|
|
sender,
|
|
NULL
|
|
receiver,
|
|
REPLACE (
|
|
n.fac_srtnotificatie_oms,
|
|
'##RES##',
|
|
r.res_reservering_key || '/' || r.res_rsv_ruimte_volgnr)
|
|
|| ' adjusted',
|
|
fac_srtnotificatie_code,
|
|
n.fac_srtnotificatie_key,
|
|
r.res_reservering_key,
|
|
NULL
|
|
xkey,
|
|
'secretariat@stamicarbon.com'
|
|
xemail,
|
|
NULL
|
|
xmobile
|
|
FROM fac_tracking t, res_rsv_ruimte r, fac_srtnotificatie n
|
|
WHERE t.fac_tracking_refkey = r.res_rsv_ruimte_key
|
|
AND t.fac_srtnotificatie_key = 83 ---reservering is aangepast
|
|
AND r.res_activiteit_key <> 30
|
|
AND n.fac_srtnotificatie_code = 'CUST01'
|
|
AND t.fac_tracking_datum >
|
|
(SELECT fac_notificatie_job_nextrun
|
|
- fac_notificatie_job_interval / 24
|
|
FROM fac_notificatie_job
|
|
WHERE UPPER (fac_notificatie_job_view) =
|
|
'STAM_V_NOTI_MUTATIE_RES')
|
|
AND t.fac_tracking_datum <
|
|
(SELECT fac_notificatie_job_nextrun
|
|
FROM fac_notificatie_job
|
|
WHERE UPPER (fac_notificatie_job_view) =
|
|
'STAM_V_NOTI_MUTATIE_RES')
|
|
UNION ALL
|
|
SELECT DISTINCT
|
|
NULL
|
|
sender,
|
|
NULL
|
|
receiver,
|
|
REPLACE (
|
|
n.fac_srtnotificatie_oms,
|
|
'##RES##',
|
|
r.res_reservering_key || '/' || r.res_rsv_ruimte_volgnr)
|
|
|| ' deleted',
|
|
fac_srtnotificatie_code,
|
|
n.fac_srtnotificatie_key,
|
|
r.res_reservering_key,
|
|
NULL
|
|
xkey,
|
|
'secretariat@stamicarbon.com'
|
|
xemail,
|
|
NULL
|
|
xmobile
|
|
FROM fac_tracking t, res_rsv_ruimte r, fac_srtnotificatie n
|
|
WHERE t.fac_tracking_refkey = r.res_rsv_ruimte_key
|
|
AND t.fac_srtnotificatie_key = 87 --- reservering is verwijderd
|
|
AND r.res_activiteit_key <> 30
|
|
AND n.fac_srtnotificatie_code = 'CUST01'
|
|
AND t.fac_tracking_datum >
|
|
(SELECT fac_notificatie_job_nextrun
|
|
- fac_notificatie_job_interval / 24
|
|
FROM fac_notificatie_job
|
|
WHERE UPPER (fac_notificatie_job_view) =
|
|
'STAM_V_NOTI_MUTATIE_RES')
|
|
AND t.fac_tracking_datum <
|
|
(SELECT fac_notificatie_job_nextrun
|
|
FROM fac_notificatie_job
|
|
WHERE UPPER (fac_notificatie_job_view) =
|
|
'STAM_V_NOTI_MUTATIE_RES')
|
|
UNION ALL
|
|
SELECT DISTINCT
|
|
NULL sender,
|
|
NULL receiver,
|
|
'Recurrence ' || r.res_reservering_key || ' has been adjusted',
|
|
fac_srtnotificatie_code,
|
|
n.fac_srtnotificatie_key,
|
|
r.res_reservering_key,
|
|
NULL xkey,
|
|
'secretariat@stamicarbon.com' xemail,
|
|
NULL xmobile
|
|
FROM fac_tracking t, res_rsv_ruimte r, fac_srtnotificatie n
|
|
WHERE t.fac_tracking_refkey = r.res_rsv_ruimte_key
|
|
AND t.fac_srtnotificatie_key = 94 --- reeks is gewijzigd
|
|
AND r.res_activiteit_key <> 30
|
|
AND n.fac_srtnotificatie_code = 'CUST01'
|
|
AND t.fac_tracking_datum >
|
|
(SELECT fac_notificatie_job_nextrun
|
|
- fac_notificatie_job_interval / 24
|
|
FROM fac_notificatie_job
|
|
WHERE UPPER (fac_notificatie_job_view) =
|
|
'STAM_V_NOTI_MUTATIE_RES')
|
|
AND t.fac_tracking_datum <
|
|
(SELECT fac_notificatie_job_nextrun
|
|
FROM fac_notificatie_job
|
|
WHERE UPPER (fac_notificatie_job_view) =
|
|
'STAM_V_NOTI_MUTATIE_RES');
|
|
|
|
CREATE OR REPLACE VIEW STAM_V_RAP_NSBUSINESSCARD
|
|
(
|
|
hide_f_refkey,
|
|
hide_f_fac_tracking_datum,
|
|
ins_deel_key,
|
|
ins_deel_omschrijving,
|
|
uitgeleend_aan,
|
|
costcenter,
|
|
destination,
|
|
handout_date,
|
|
expected_return,
|
|
in_uit,
|
|
tracking_datum
|
|
)
|
|
AS
|
|
SELECT t.fac_tracking_refkey sort_refkey,
|
|
t.fac_tracking_datum sort_datum,
|
|
d.ins_deel_key,
|
|
d.ins_deel_omschrijving,
|
|
DECODE (
|
|
fac_srtnotificatie_key,
|
|
101, SUBSTR (fac_tracking_oms,
|
|
((INSTR (fac_tracking_oms, 'lent out to')) + 12)),
|
|
'') uitgeleend_aan,
|
|
costcenter.costcenter,
|
|
destination.destination,
|
|
handout_date.handout_date,
|
|
expected_return.expected_return,
|
|
DECODE (fac_srtnotificatie_key,
|
|
101, 'Uitgifte datum: ',
|
|
'Inname datum: ') In_uit,
|
|
fac_tracking_datum
|
|
FROM fac_tracking t,
|
|
ins_deel d,
|
|
(SELECT ins_deel_key, ins_kenmerkdeel_waarde costcenter
|
|
FROM ins_kenmerkdeel kd
|
|
WHERE kd.ins_kenmerk_key = 788) costcenter,
|
|
(SELECT ins_deel_key, ud.fac_usrdata_omschr destination
|
|
FROM ins_kenmerkdeel kd, fac_usrdata ud
|
|
WHERE kd.ins_kenmerk_key = 781
|
|
AND ud.fac_usrtab_key = 481
|
|
AND kd.ins_kenmerkdeel_waarde = ud.fac_usrdata_key)
|
|
destination,
|
|
(SELECT ins_deel_key, ins_kenmerkdeel_waarde handout_date
|
|
FROM ins_kenmerkdeel kd
|
|
WHERE kd.ins_kenmerk_key = 783) handout_date,
|
|
(SELECT ins_deel_key, ins_kenmerkdeel_waarde expected_return
|
|
FROM ins_kenmerkdeel kd
|
|
WHERE kd.ins_kenmerk_key = 786) expected_return
|
|
WHERE fac_srtnotificatie_key IN (101, 102)
|
|
AND d.ins_srtdeel_key = 67
|
|
AND t.fac_tracking_refkey = d.ins_deel_key
|
|
AND d.ins_deel_key = costcenter.ins_deel_key(+)
|
|
AND d.ins_deel_key = destination.ins_deel_key(+)
|
|
AND d.ins_deel_key = handout_date.ins_deel_key(+)
|
|
AND d.ins_deel_key = expected_return.ins_deel_key(+);
|
|
|
|
CREATE OR REPLACE PACKAGE stam
|
|
AS
|
|
FUNCTION find_str (p_string IN VARCHAR2, p_search IN VARCHAR2)
|
|
RETURN VARCHAR2;
|
|
END;
|
|
/
|
|
|
|
|
|
CREATE OR REPLACE PACKAGE BODY stam
|
|
AS
|
|
FUNCTION find_str (p_string IN VARCHAR2, p_search IN VARCHAR2)
|
|
RETURN VARCHAR2
|
|
AS
|
|
v_index NUMBER;
|
|
v_van NUMBER;
|
|
v_tot NUMBER;
|
|
BEGIN
|
|
v_index := INSTR (p_string, p_search);
|
|
|
|
IF v_index > 0
|
|
THEN
|
|
v_van := v_index + LENGTH (p_search);
|
|
v_tot := INSTR (p_string, CHR (10), v_index + LENGTH (p_search));
|
|
|
|
-- dbms_output.put_line ('van:' || to_char(v_van));
|
|
-- dbms_output.put_line ('tot:' || to_char(v_tot));
|
|
|
|
-- als v_tot gelijk is aan 0 dan zitten we op het einde van de string. Geef
|
|
-- dan alles maar terug tot het einde van de string (maar even op 1000 gezet.
|
|
IF v_tot = 0
|
|
THEN
|
|
v_tot := 1000;
|
|
END IF;
|
|
|
|
RETURN SUBSTR (p_string, v_van + 1, v_tot - v_van - 1);
|
|
ELSE
|
|
RETURN NULL;
|
|
END IF;
|
|
END;
|
|
END;
|
|
/
|
|
|
|
CREATE OR REPLACE PROCEDURE stam_export_ns_cards (p_applname IN VARCHAR2,
|
|
p_applrun IN VARCHAR2,
|
|
p_filedir IN VARCHAR2,
|
|
p_filename IN VARCHAR2)
|
|
AS
|
|
CURSOR c IS
|
|
SELECT *
|
|
FROM fac_tracking t, ins_deel d
|
|
WHERE fac_tracking_refkey = d.ins_deel_key
|
|
AND d.ins_srtdeel_key = 67 -- NS Business Cards
|
|
AND fac_srtnotificatie_key IN (101, 102) -- uitgifte (insout) en inname (insinn)
|
|
ORDER BY t.fac_tracking_refkey, t.fac_tracking_datum;
|
|
|
|
v_uitgeleend_aan VARCHAR2 (60);
|
|
v_uitgifte DATE;
|
|
v_inname DATE;
|
|
v_cost_center VARCHAR2 (100);
|
|
v_destination VARCHAR2 (100);
|
|
v_dest_description VARCHAR2 (100);
|
|
v_handout_date VARCHAR2 (100);
|
|
v_expected_return VARCHAR2 (100);
|
|
v_fac_tracking_uitgifte_key NUMBER (10);
|
|
v_fac_tracking_inname_key NUMBER (10);
|
|
v_dummy VARCHAR2 (1000);
|
|
v_search VARCHAR2 (1000);
|
|
BEGIN
|
|
DELETE STAM_NS_BUSINESS_CARDS;
|
|
|
|
FOR rec IN c
|
|
LOOP
|
|
v_search := 'Cost center:';
|
|
v_dummy := stam.find_str (rec.fac_tracking_oms, v_search);
|
|
v_cost_center := v_dummy;
|
|
|
|
v_search := 'Destination station:';
|
|
v_dummy := stam.find_str (rec.fac_tracking_oms, v_search);
|
|
v_destination := v_dummy;
|
|
|
|
v_search := 'Date of hand out:';
|
|
v_dummy := stam.find_str (rec.fac_tracking_oms, v_search);
|
|
v_handout_date := v_dummy;
|
|
|
|
v_search := 'Date of (expected) return:';
|
|
v_dummy := stam.find_str (rec.fac_tracking_oms, v_search);
|
|
v_expected_return := v_dummy;
|
|
|
|
v_search := 'lent out to';
|
|
v_dummy :=
|
|
SUBSTR (stam.find_str (rec.fac_tracking_oms, v_search), 0, 60);
|
|
v_uitgeleend_aan := v_dummy;
|
|
|
|
BEGIN
|
|
IF rec.fac_srtnotificatie_key = 101
|
|
THEN
|
|
-- Uitgifte
|
|
v_uitgifte := rec.fac_tracking_datum;
|
|
|
|
INSERT INTO STAM_NS_BUSINESS_CARDS (
|
|
ins_deel_key,
|
|
uitgeleend_aan,
|
|
uitgifte,
|
|
cost_center,
|
|
destination,
|
|
handout_date,
|
|
expected_return,
|
|
fac_tracking_uitgifte_key)
|
|
VALUES (
|
|
rec.fac_tracking_refkey,
|
|
v_uitgeleend_aan,
|
|
v_uitgifte,
|
|
TRIM (
|
|
REPLACE (
|
|
(REPLACE (
|
|
(REPLACE (v_cost_center, '-->')),
|
|
'(empty)')),
|
|
'(Empty)')),
|
|
TRIM (
|
|
REPLACE (
|
|
(REPLACE (
|
|
(REPLACE (v_destination, '-->')),
|
|
'(empty)')),
|
|
'(Empty)')),
|
|
TRIM (
|
|
REPLACE (
|
|
(REPLACE (
|
|
(REPLACE (v_handout_date, '-->')),
|
|
'(empty)')),
|
|
'(Empty)')),
|
|
TRIM (
|
|
REPLACE (
|
|
(REPLACE (
|
|
(REPLACE (v_expected_return, '-->')),
|
|
'(empty)')),
|
|
'(Empty)')),
|
|
rec.fac_tracking_key);
|
|
|
|
v_fac_tracking_uitgifte_key := rec.fac_tracking_key;
|
|
ELSE
|
|
v_inname := rec.fac_tracking_datum;
|
|
|
|
UPDATE STAM_NS_BUSINESS_CARDS
|
|
SET inname = v_inname,
|
|
uitgifte = v_uitgifte,
|
|
cost_center =
|
|
TRIM (
|
|
REPLACE (
|
|
(REPLACE (
|
|
(REPLACE (v_cost_center, '-->')),
|
|
'(empty)')),
|
|
'(Empty)')),
|
|
destination =
|
|
TRIM (
|
|
REPLACE (
|
|
(REPLACE (
|
|
(REPLACE (v_destination, '-->')),
|
|
'(empty)')),
|
|
'(Empty)')),
|
|
handout_date =
|
|
TRIM (
|
|
REPLACE (
|
|
(REPLACE (
|
|
(REPLACE (v_handout_date, '-->')),
|
|
'(empty)')),
|
|
'(Empty)')),
|
|
expected_return =
|
|
TRIM (
|
|
REPLACE (
|
|
(REPLACE (
|
|
(REPLACE (v_expected_return, '-->')),
|
|
'(empty)')),
|
|
'(Empty)')),
|
|
fac_tracking_inname_key = rec.fac_tracking_key
|
|
WHERE fac_tracking_uitgifte_key =
|
|
v_fac_tracking_uitgifte_key;
|
|
END IF;
|
|
END;
|
|
END LOOP;
|
|
|
|
COMMIT;
|
|
END;
|
|
/
|
|
|
|
CREATE OR REPLACE VIEW STAM_V_RAP_NS_CARDS
|
|
(
|
|
INS_DEEL_KEY,
|
|
INS_DEEL_OMSCHRIJVING,
|
|
UITGIFTE,
|
|
INNAME,
|
|
UITGELEEND_AAN,
|
|
COST_CENTER,
|
|
DESTINATION,
|
|
HAND_OUT_DATE,
|
|
EXPECTED_RETURN
|
|
)
|
|
AS
|
|
SELECT d.ins_deel_key,
|
|
d.ins_deel_omschrijving,
|
|
bc.uitgifte,
|
|
bc.inname,
|
|
bc.uitgeleend_aan,
|
|
bc.cost_center,
|
|
COALESCE (station.fac_usrdata_code, bc.destination)
|
|
destination,
|
|
bc.handout_date,
|
|
bc.expected_return
|
|
FROM stam_ns_business_cards bc,
|
|
ins_deel d,
|
|
(SELECT fac_usrdata_key, fac_usrdata_code
|
|
FROM fac_usrdata ud
|
|
WHERE ud.fac_usrtab_key = 481) station
|
|
WHERE bc.ins_deel_key = d.ins_deel_key
|
|
AND bc.destination = TO_CHAR (station.fac_usrdata_key(+));
|
|
|
|
CREATE OR REPLACE VIEW STAM_V_RAP_ANONYMIZE
|
|
(
|
|
datum,
|
|
module,
|
|
aantal
|
|
)
|
|
AS
|
|
SELECT TRUNC (ft.fac_tracking_datum),
|
|
sn.fac_srtnotificatie_xmlnode,
|
|
COUNT (ft.fac_tracking_refkey) aantal
|
|
FROM fac_tracking ft, fac_srtnotificatie sn
|
|
WHERE ft.fac_srtnotificatie_key = sn.fac_srtnotificatie_key
|
|
AND ft.fac_srtnotificatie_key IN
|
|
(SELECT fac_srtnotificatie_key
|
|
FROM fac_srtnotificatie
|
|
WHERE fac_srtnotificatie_code LIKE ('%ANO'))
|
|
GROUP BY TRUNC (ft.fac_tracking_datum), sn.fac_srtnotificatie_xmlnode;
|
|
|
|
CREATE OR REPLACE VIEW STAM_V_MDW_KENNISBANK
|
|
(
|
|
PRS_PERSLID_KEY,
|
|
NAAM
|
|
)
|
|
AS
|
|
SELECT DISTINCT p.prs_perslid_key, N.PRS_PERSLID_NAAM_FRIENDLY
|
|
FROM fac_gebruikersgroep gg,
|
|
prs_v_aanwezigperslid p,
|
|
fac_groep gr,
|
|
fac_groeprechten grr,
|
|
prs_v_perslid_fullnames n
|
|
WHERE p.prs_perslid_key = gg.prs_perslid_key
|
|
AND gg.fac_groep_key = gr.fac_groep_key
|
|
AND gr.FAC_GROEP_KEY = grr.fac_groep_key
|
|
AND n.prs_perslid_key = p.prs_perslid_key
|
|
AND gr.fac_groep_key = 121;
|
|
|
|
COMMIT;
|
|
|
|
BEGIN
|
|
DBMS_UTILITY.COMPILE_SCHEMA (USER, FALSE);
|
|
END;
|
|
/
|
|
|
|
COMMIT;
|
|
------ 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 |