247 lines
9.6 KiB
MySQL
247 lines
9.6 KiB
MySQL
--/* 5002to3.sql
|
|
-- * Update script van Facilitor versie 5.00.3 naar 5.00.4
|
|
-- * $Revision$
|
|
-- * $Id$
|
|
-- */
|
|
SPOOL OFF
|
|
SET HEADING OFF
|
|
SET TERMOUT ON
|
|
SET FEEDBACK OFF
|
|
SET ECHO OFF
|
|
SET PAGESIZE 0
|
|
PROMPT ************************************************************************
|
|
PROMPT UPGRADE SCRIPT van Facilitor versie 5.0.3 naar 5.0.4
|
|
PROMPT Copyright (c) 1996-2010 SG|facilitor bv. All rights reserved.
|
|
PROMPT $Revision$
|
|
PROMPT
|
|
SELECT 'Facilitor/' || USER || ' is now ' || fac.getdbversion() FROM DUAL;
|
|
PROMPT
|
|
PROMPT INDIEN DE HUIDIGE VERSIE NIET DE VERWACHTE VERSIE IS
|
|
PROMPT MAG DIT SCRIPT NIET WORDEN UITGEVOERD! In dat geval moet
|
|
PROMPT u het script NU middels CONTROL-C afbreken.
|
|
PROMPT
|
|
PROMPT Deze upgrade moet worden uitgevoerd op een moment dat er
|
|
PROMPT geen gebruikers of processen bezig zijn met Facilitor.
|
|
PROMPT
|
|
PROMPT ************************************************************************
|
|
PROMPT
|
|
PROMPT Als de versies overeenkomen dient nu ENTER te worden gedrukt
|
|
PROMPT &&1
|
|
SET DEFINE OFF
|
|
PROMPT
|
|
PROMPT De upgrade wordt vervolgd. Even geduld a.u.b...
|
|
PROMPT
|
|
|
|
SET HEADING OFF
|
|
SET FEEDBACK ON
|
|
SET VERIFY OFF
|
|
SET LINESIZE 1000
|
|
SET TIME ON
|
|
SET SERVEROUTPUT ON;
|
|
ALTER SESSION SET nls_territory='america';
|
|
|
|
SPOOL x5003to4.lst
|
|
SELECT 'Facilitor/' || USER || ' is now ' || fac.getdbversion() FROM DUAL;
|
|
SET ECHO ON
|
|
|
|
--FSN#17456 (fac_ini.src;437)
|
|
UPDATE fac_srtnotificatie
|
|
SET fac_srtnotificatie_url = 'mld/mld_opdr.asp?opdr_key='
|
|
WHERE fac_srtnotificatie_code = 'MLDAP1'
|
|
AND fac_srtnotificatie_url IS NOT NULL;
|
|
|
|
--HPJI#17522 (fac_ini.src;438)
|
|
INSERT INTO fac_srtnotificatie (fac_srtnotificatie_code, fac_srtnotificatie_mode, fac_srtnotificatie_oms,
|
|
fac_srtnotificatie_url, fac_srtnotificatie_groep, fac_srtnotificatie_xmlnode)
|
|
VALUES ('ORDUPD', 0, 'Opdracht ##KEY## is gewijzigd', 'mld/mld_opdr.asp?opdr_key=', '0', 'opdracht');
|
|
|
|
INSERT INTO fac_srtnotificatie (fac_srtnotificatie_code, fac_srtnotificatie_mode, fac_srtnotificatie_oms,
|
|
fac_srtnotificatie_url, fac_srtnotificatie_groep, fac_srtnotificatie_xmlnode)
|
|
VALUES ('BES2SN', 0, 'Bestelopdracht ##KEY## is verzonden', '', '0', 'bestelopdr');
|
|
|
|
INSERT INTO fac_srtnotificatie (fac_srtnotificatie_code, fac_srtnotificatie_mode, fac_srtnotificatie_oms,
|
|
fac_srtnotificatie_url, fac_srtnotificatie_groep, fac_srtnotificatie_xmlnode)
|
|
VALUES ('BES2SX', 0, 'Bestelopdracht ##KEY## is NIET verzonden', '', '0', 'bestelopdr');
|
|
|
|
|
|
|
|
-- FSN#17630
|
|
CREATE TABLE mld_impropdr
|
|
(
|
|
mld_impropdr_key
|
|
NUMBER (10) PRIMARY KEY,
|
|
mld_impropdr_omschrijving
|
|
VARCHAR2 (60) NOT NULL,
|
|
mld_impropdr_code
|
|
VARCHAR2 (10),
|
|
mld_impropdr_onkosten
|
|
NUMBER (1), -- 1=mag onkosten bij worden geboekt
|
|
mld_impropdr_aanmaak
|
|
DATE
|
|
DEFAULT SYSDATE,
|
|
mld_impropdr_verwijder
|
|
DATE
|
|
);
|
|
|
|
CREATE SEQUENCE mld_s_mld_impropdr_key MINVALUE 1;
|
|
|
|
CREATE OR REPLACE TRIGGER mld_t_mld_impropdr_b_iu
|
|
BEFORE INSERT OR UPDATE ON mld_impropdr
|
|
FOR EACH ROW
|
|
BEGIN
|
|
IF :new.mld_impropdr_key IS NULL THEN SELECT mld_s_mld_impropdr_key.nextval INTO :new.mld_impropdr_key FROM DUAL; END IF;
|
|
END;
|
|
/
|
|
|
|
ALTER TABLE mld_opdr_uren ADD
|
|
mld_impropdr_key
|
|
NUMBER(10) CONSTRAINT mld_r_mld_impropdr_key1 REFERENCES mld_impropdr(mld_impropdr_key);
|
|
|
|
ALTER TABLE mld_opdr_uren MODIFY mld_opdr_key NULL;
|
|
|
|
ALTER TABLE mld_opdr_uren DROP CONSTRAINT mld_r_mld_opdr_key1;
|
|
ALTER TABLE mld_opdr_uren MODIFY mld_opdr_key CONSTRAINT mld_r_mld_opdr_key1 REFERENCES mld_opdr(mld_opdr_key);
|
|
|
|
ALTER TABLE mld_opdr_uren
|
|
ADD (CONSTRAINT mld_c_mld_opdr_uren1
|
|
CHECK ((mld_opdr_key IS NULL AND mld_impropdr_key IS NOT NULL) OR (mld_opdr_key IS NOT NULL AND mld_impropdr_key IS NULL)));
|
|
|
|
|
|
CREATE TABLE mld_kosten
|
|
(
|
|
mld_kosten_key
|
|
NUMBER (10) PRIMARY KEY,
|
|
mld_kosten_omschrijving
|
|
VARCHAR2 (60) NOT NULL,
|
|
mld_kosten_code
|
|
VARCHAR2 (10),
|
|
mld_kosten_type
|
|
NUMBER (1) NOT NULL, -- 1=boolean, 2=aantalveld, 3=float
|
|
mld_kosten_eenheid
|
|
VARCHAR2 (15),
|
|
mld_kosten_kosten
|
|
NUMBER (8,2), -- prijs per eenheid, optioneel
|
|
mld_kosten_aanmaak
|
|
DATE
|
|
DEFAULT SYSDATE,
|
|
mld_kosten_verwijder
|
|
DATE
|
|
);
|
|
|
|
CREATE SEQUENCE mld_s_mld_kosten_key MINVALUE 1;
|
|
|
|
CREATE OR REPLACE TRIGGER mld_t_mld_kosten_b_iu
|
|
BEFORE INSERT OR UPDATE ON mld_kosten
|
|
FOR EACH ROW
|
|
BEGIN
|
|
IF :new.mld_kosten_key IS NULL THEN SELECT mld_s_mld_kosten_key.nextval INTO :new.mld_kosten_key FROM DUAL; END IF;
|
|
END;
|
|
/
|
|
|
|
|
|
CREATE TABLE mld_opdruren_kosten
|
|
(
|
|
mld_opdruren_kosten_key
|
|
NUMBER (10) PRIMARY KEY,
|
|
mld_opdr_uren_key
|
|
NUMBER(10) NOT NULL CONSTRAINT mld_r_mld_opdr_uren_key1 REFERENCES mld_opdr_uren(mld_opdr_uren_key) ON DELETE CASCADE,
|
|
mld_kosten_key
|
|
NUMBER(10) NOT NULL CONSTRAINT mld_r_mld_kosten_key1 REFERENCES mld_kosten(mld_kosten_key),
|
|
mld_opdruren_kosten_besteed
|
|
NUMBER(5,2) NOT NULL
|
|
);
|
|
|
|
CREATE SEQUENCE mld_s_mld_opdruren_kosten_key MINVALUE 1;
|
|
|
|
CREATE OR REPLACE TRIGGER mld_t_mld_opdruren_kosten_b_iu
|
|
BEFORE INSERT OR UPDATE ON mld_opdruren_kosten
|
|
FOR EACH ROW
|
|
BEGIN
|
|
IF :new.mld_opdruren_kosten_key IS NULL THEN SELECT mld_s_mld_opdruren_kosten_key.nextval INTO :new.mld_opdruren_kosten_key FROM DUAL; END IF;
|
|
END;
|
|
/
|
|
|
|
CREATE UNIQUE INDEX mld_i_mld_opdruren_kosten1 ON mld_opdruren_kosten(mld_opdr_uren_key,mld_kosten_key);
|
|
CREATE UNIQUE INDEX mld_i_mld_opdr_uren1 ON mld_opdr_uren(mld_opdr_uren_datum,mld_opdr_key,mld_impropdr_key,prs_perslid_key);
|
|
|
|
INSERT INTO fac_menuitems (fac_menuitems_groep, fac_menuitems_label, fac_menuitems_oms, fac_menuitems_module, fac_menuitems_url, fac_menuitems_srtdisc, fac_menuitems_disc, fac_functie_key, fac_menuitems_rw, fac_menuitems_default)
|
|
SELECT 2, 'lcl_menu_mld_improdopdr', '', 'MLD', 'appl/facmgtVB/mld_impropdrgrid.asp', 0, 0, fac_functie_key, 'W', '1'
|
|
FROM fac_functie WHERE fac_functie_code='WEB_MLDMGT';
|
|
|
|
-- Default-optie, dus toevoegen na lcl_menu_mld_opdrachttypes
|
|
INSERT INTO fac_menu (fac_menuitems_key, fac_menu_volgnr
|
|
)
|
|
SELECT i.fac_menuitems_key, m.fac_menu_volgnr + 5
|
|
FROM fac_menuitems i, fac_menu m
|
|
WHERE i.fac_menuitems_key = (SELECT mmi.fac_menuitems_key
|
|
FROM fac_menuitems mmi
|
|
WHERE mmi.fac_menuitems_label = 'lcl_menu_mld_improdopdr')
|
|
AND m.fac_menuitems_key =
|
|
(SELECT mm.fac_menuitems_key
|
|
FROM fac_menu mm, fac_menuitems mmi
|
|
WHERE mm.fac_menuitems_key = mmi.fac_menuitems_key
|
|
AND mmi.fac_menuitems_label = 'lcl_menu_mld_opdrachttypes');
|
|
|
|
INSERT INTO fac_menuitems (fac_menuitems_groep, fac_menuitems_label, fac_menuitems_oms, fac_menuitems_module, fac_menuitems_url, fac_menuitems_srtdisc, fac_menuitems_disc, fac_functie_key, fac_menuitems_rw, fac_menuitems_default)
|
|
SELECT 2, 'lcl_menu_mld_opdrkosten', '', 'MLD', 'appl/facmgtVB/mld_kostengrid.asp', 0, 0, fac_functie_key, 'W', '1'
|
|
FROM fac_functie WHERE fac_functie_code='WEB_MLDMGT';
|
|
|
|
-- Default-optie, dus toevoegen daarna na lcl_menu_mld_opdrachttypes
|
|
INSERT INTO fac_menu (fac_menuitems_key, fac_menu_volgnr
|
|
)
|
|
SELECT i.fac_menuitems_key, m.fac_menu_volgnr + 7
|
|
FROM fac_menuitems i, fac_menu m
|
|
WHERE i.fac_menuitems_key = (SELECT mmi.fac_menuitems_key
|
|
FROM fac_menuitems mmi
|
|
WHERE mmi.fac_menuitems_label = 'lcl_menu_mld_opdrkosten')
|
|
AND m.fac_menuitems_key =
|
|
(SELECT mm.fac_menuitems_key
|
|
FROM fac_menu mm, fac_menuitems mmi
|
|
WHERE mm.fac_menuitems_key = mmi.fac_menuitems_key
|
|
AND mmi.fac_menuitems_label = 'lcl_menu_mld_opdrachttypes');
|
|
|
|
-- CONN#14635
|
|
INSERT INTO fac_functie (fac_functie_code, fac_functie_omschrijving,fac_functie_module,fac_functie_min_level,
|
|
fac_functie_discipline, fac_functie_info)
|
|
VALUES('WEB_ORDUSE', 'Frontend:Opdrachten', 'MLD', 15, 1, 'Om zelf direct opdrachten uit te kunnen geven');
|
|
|
|
-- FSN#17626
|
|
ALTER TABLE mld_stdmelding ADD mld_stdmelding_regime NUMBER(2);
|
|
ALTER TABLE mld_stdmelding ADD mld_stdmelding_malus NUMBER(8,2);
|
|
|
|
-- LIBR#17757
|
|
BEGIN
|
|
FOR r1 IN (SELECT res_rsv_ruimte_key
|
|
FROM res_rsv_deel
|
|
WHERE res_rsv_deel_verwijder IS NULL AND res_rsv_deel_van > SYSDATE)
|
|
LOOP
|
|
res.set_delen_dirty (r1.res_rsv_ruimte_key);
|
|
END LOOP;
|
|
END;
|
|
/
|
|
|
|
|
|
COMMIT;
|
|
--///////////////////////////// now recreate all views, triggers etc acc to the latest state ///////
|
|
START recre5004.sql
|
|
--///////////////////////////// now compile all views, triggers etc acc to the latest state ///////
|
|
PROMPT Recompiling invalid objects...
|
|
BEGIN DBMS_UTILITY.COMPILE_SCHEMA(USER, FALSE); END;
|
|
/
|
|
BEGIN fac.registerversion(5, 00, 4, '$Revision$', NULL); END;
|
|
/
|
|
COMMIT;
|
|
--///////////////////////////// Report invalid objects, if any ///////
|
|
SPOOL xsummary.lst
|
|
SET ECHO OFF
|
|
PROMPT List of all invalid objects after Facilitor upgrade:
|
|
SELECT ' Warning: ' || object_type || ' ' || object_name || ' is ' || status
|
|
FROM user_objects
|
|
WHERE object_type IN ('VIEW', 'TRIGGER', 'PACKAGE', 'PROCEDURE', 'FUNCTION', 'PACKAGE BODY')
|
|
AND status <> 'VALID'
|
|
ORDER BY object_name;
|
|
|
|
SELECT 'Facilitor/' || USER || ' is now ' || fac.getdbversion() FROM DUAL;
|
|
PROMPT De upgrade is gereed, controleer de LST-files.
|
|
PROMPT Neem bij vragen, twijfels of problemen contact op met Facilitor.
|