424 lines
14 KiB
MySQL
424 lines
14 KiB
MySQL
SET TERMOUT ON
|
|
SET FEEDBACK OFF
|
|
SET VERIFY OFF
|
|
SET HEADING OFF
|
|
SET ECHO OFF
|
|
SET LINES 3000
|
|
SPOOL OFF
|
|
CLEAR SCREEN
|
|
|
|
CREATE TABLE ins_ol_kamerhub
|
|
( ins_ol_kamerhub_key
|
|
NUMBER(10)
|
|
CONSTRAINT ins_k_ins_ol_kamerhub_key PRIMARY KEY
|
|
, ins_ol_kamerhub_naam
|
|
VARCHAR2(16)
|
|
CONSTRAINT ins_c_ins_ol_kamerhub_naam CHECK(ins_ol_kamerhub_naam IS NOT NULL)
|
|
, ins_ol_kamerhub_upper
|
|
VARCHAR2(16)
|
|
, ins_ol_kamerhub_prijs
|
|
NUMBER(6,2)
|
|
CONSTRAINT ins_c_ins_ol_kamerhub_prijs CHECK(ins_ol_kamerhub_prijs IS NOT NULL)
|
|
, ins_ol_kamerhub_aanmaak
|
|
DATE
|
|
DEFAULT SYSDATE
|
|
, ins_ol_kamerhub_verwijder
|
|
DATE
|
|
DEFAULT NULL
|
|
);
|
|
|
|
CREATE OR REPLACE VIEW ins_v_aanwezigol_kamerhub AS
|
|
SELECT * FROM ins_ol_kamerhub WHERE ins_ol_kamerhub_verwijder IS NULL;
|
|
|
|
CREATE SEQUENCE ins_s_ins_ol_kamerhub_key START WITH 1 MINVALUE 1 CACHE 2;
|
|
|
|
INSERT INTO fac_privilege (object_name,security_level) VALUES('INS_OL_KAMERHUB' ,13);
|
|
INSERT INTO fac_privilege (object_name,security_level) VALUES('INS_V_AANWEZIGOL_KAMERHUB',11);
|
|
|
|
CREATE OR REPLACE TRIGGER ins_t_ins_ol_kamerhub_B_IU
|
|
BEFORE INSERT OR UPDATE ON ins_ol_kamerhub
|
|
FOR EACH ROW
|
|
BEGIN
|
|
IF :new.ins_ol_kamerhub_key IS NULL
|
|
THEN
|
|
SELECT ins_s_ins_ol_kamerhub_key.nextval
|
|
INTO :new.ins_ol_kamerhub_key
|
|
FROM DUAL;
|
|
END IF;
|
|
:new.ins_ol_kamerhub_upper := UPPER(:new.ins_ol_kamerhub_naam);
|
|
END;
|
|
/
|
|
|
|
INSERT
|
|
INTO ins_refsrtkenmerk
|
|
( ins_refsrtkenmerk_omschrijving
|
|
, ins_refsrtkenmerk_objectnaam
|
|
, ins_refsrtkenmerk_kolomnaam
|
|
, ins_refsrtkenmerk_kolomtxt
|
|
, fac_usrtab_key)
|
|
VALUES('KamerHUB'
|
|
, 'INS_V_AANWEZIGOL_KAMERHUB'
|
|
, 'INS_OL_KAMERHUB_KEY'
|
|
, 'INS_OL_KAMERHUB_NAAM'
|
|
, null);
|
|
|
|
INSERT
|
|
INTO ins_ol_kenmerk
|
|
SELECT 'REF_KAMERHUB'
|
|
, ins_refsrtkenmerk_KEY
|
|
FROM ins_refsrtkenmerk
|
|
WHERE ins_refsrtkenmerk_upper = 'KAMERHUB';
|
|
|
|
INSERT
|
|
INTO ins_srtkenmerk
|
|
( ins_srtkenmerk_omschrijving
|
|
, ins_srtkenmerk_kenmerktype
|
|
, ins_srtkenmerk_systeem
|
|
, ins_srtkenmerk_lengte
|
|
, ins_refsrtkenmerk_key)
|
|
SELECT 'KamerHUB'
|
|
, 'R'
|
|
, 1
|
|
, null
|
|
, ins_ol_kenmerk_key
|
|
FROM ins_ol_kenmerk
|
|
WHERE ins_ol_kenmerk_naam = 'REF_KAMERHUB';
|
|
|
|
INSERT
|
|
INTO ins_ol_kenmerk
|
|
SELECT 'SRT_KAMERHUB'
|
|
, ins_srtkenmerk_key
|
|
FROM ins_srtkenmerk
|
|
WHERE ins_srtkenmerk_upper = 'KAMERHUB';
|
|
|
|
DELETE FROM ins_kenmerkdeel WHERE ins_kenmerk_key = 42;
|
|
DELETE FROM ins_kenmerkdeel WHERE ins_kenmerk_key = 49;
|
|
DELETE FROM ins_kenmerkdeel WHERE ins_kenmerk_key = 54;
|
|
DELETE FROM ins_kenmerk WHERE ins_kenmerk_key = 42;
|
|
DELETE FROM ins_kenmerk WHERE ins_kenmerk_key = 49;
|
|
DELETE FROM ins_kenmerk WHERE ins_kenmerk_key = 54;
|
|
|
|
UPDATE ins_srtkenmerk
|
|
SET ins_srtkenmerk_systeem = null
|
|
WHERE ins_srtkenmerk_key IN (SELECT ins_ol_kenmerk_key
|
|
FROM ins_ol_kenmerk
|
|
WHERE ins_ol_kenmerk_naam IN ('SRT_LIJNTYPE','SRT_DOCUMENT'));
|
|
DELETE
|
|
FROM ins_srtkenmerk
|
|
WHERE ins_srtkenmerk_key IN (SELECT ins_ol_kenmerk_key
|
|
FROM ins_ol_kenmerk
|
|
WHERE ins_ol_kenmerk_naam IN ('SRT_LIJNTYPE','SRT_DOCUMENT'));
|
|
DELETE
|
|
FROM ins_refsrtkenmerk
|
|
WHERE ins_refsrtkenmerk_key IN (SELECT ins_ol_kenmerk_key
|
|
FROM ins_ol_kenmerk
|
|
WHERE ins_ol_kenmerk_naam = 'REF_LIJNTYPE');
|
|
INSERT
|
|
INTO ins_kenmerk
|
|
( ins_kenmerk_key
|
|
, ins_srtkenmerk_key
|
|
, ins_srtinstallatie_key
|
|
, ins_kenmerk_niveau
|
|
, ins_kenmerk_toonbaar
|
|
, ins_kenmerk_volgnummer
|
|
, ins_kenmerk_locatiekolom
|
|
, ins_kenmerk_uniek)
|
|
SELECT 54
|
|
, S.ins_ol_kenmerk_key
|
|
, D.ins_ol_kenmerk_key
|
|
, 'S'
|
|
, 1
|
|
, 5
|
|
, null
|
|
, null
|
|
FROM ins_ol_kenmerk S
|
|
, ins_ol_kenmerk D
|
|
WHERE S.ins_ol_kenmerk_naam = 'SRT_KAMERHUB'
|
|
AND D.ins_ol_kenmerk_naam = 'SRTDEEL_OUTLET';
|
|
|
|
INSERT
|
|
INTO fac_usrtab
|
|
( fac_usrtab_naam
|
|
, fac_usrtab_object
|
|
, fac_usrtab_omschrijving
|
|
, fac_usrtab_view)
|
|
VALUES('inserttype'
|
|
, 'USR_INSERTTYPE'
|
|
, 'Insert type'
|
|
, 'T');
|
|
|
|
INSERT
|
|
INTO ins_ol_kenmerk
|
|
SELECT 'TAB_INSERTTYPE'
|
|
, fac_usrtab_key
|
|
FROM fac_usrtab
|
|
WHERE fac_usrtab_object = 'USR_INSERTTYPE';
|
|
|
|
DECLARE
|
|
--
|
|
-- Het tekstveld inserttype omzetten naar een referentietabel.
|
|
--
|
|
CURSOR c_soort_types IS
|
|
SELECT distinct ins_kenmerkdeel_waarde
|
|
FROM ins_kenmerkdeel
|
|
WHERE ins_kenmerk_key = 45;
|
|
|
|
CURSOR c_inserttypes IS
|
|
SELECT fac_usrdata_key
|
|
, fac_usrdata_code
|
|
, fac_usrdata_omschr
|
|
FROM fac_usrdata
|
|
WHERE fac_usrtab_key = (SELECT ins_ol_kenmerk_key
|
|
FROM ins_ol_kenmerk
|
|
WHERE ins_ol_kenmerk_naam = 'TAB_INSERTTYPE');
|
|
BEGIN
|
|
--
|
|
-- Vul eerst de referentietabel met alle
|
|
-- mogelijke waarden voor inserttype.
|
|
--
|
|
FOR r_soort_types IN c_soort_types
|
|
LOOP
|
|
INSERT INTO fac_usrdata
|
|
( fac_usrtab_key
|
|
, fac_usrdata_code
|
|
, fac_usrdata_omschr)
|
|
SELECT ins_ol_kenmerk_key
|
|
, r_soort_types.ins_kenmerkdeel_waarde
|
|
, 'omschrijving'|| r_soort_types.ins_kenmerkdeel_waarde
|
|
FROM ins_ol_kenmerk
|
|
WHERE ins_ol_kenmerk_naam = 'TAB_INSERTTYPE';
|
|
END LOOP;
|
|
--
|
|
-- Vervang nu de tekstwaarde van het kenmerk
|
|
-- voor de key naar de referentietabel.
|
|
--
|
|
FOR r_inserttypes IN c_inserttypes
|
|
LOOP
|
|
UPDATE ins_kenmerkdeel
|
|
SET ins_kenmerkdeel_waarde = to_char(r_inserttypes.fac_usrdata_key)
|
|
WHERE ins_kenmerkdeel_waarde = r_inserttypes.fac_usrdata_code
|
|
AND ins_kenmerk_key = 45;
|
|
END LOOP;
|
|
END;
|
|
/
|
|
|
|
INSERT
|
|
INTO ins_refsrtkenmerk
|
|
( ins_refsrtkenmerk_omschrijving
|
|
, ins_refsrtkenmerk_objectnaam
|
|
, ins_refsrtkenmerk_kolomnaam
|
|
, ins_refsrtkenmerk_kolomtxt
|
|
, fac_usrtab_key)
|
|
SELECT 'Insert type'
|
|
, 'FAC_USRDATA'
|
|
, 'FAC_USRDATA_KEY'
|
|
, 'FAC_USRDATA_CODE'
|
|
, ins_ol_kenmerk_key
|
|
FROM ins_ol_kenmerk
|
|
WHERE ins_ol_kenmerk_naam = 'TAB_INSERTTYPE';
|
|
|
|
INSERT
|
|
INTO ins_ol_kenmerk
|
|
SELECT 'REF_INSERTTYPE'
|
|
, ins_refsrtkenmerk_key
|
|
FROM ins_refsrtkenmerk
|
|
WHERE ins_refsrtkenmerk_upper = 'INSERT TYPE';
|
|
|
|
UPDATE ins_srtkenmerk
|
|
SET ins_srtkenmerk_kenmerktype = 'R'
|
|
, ins_srtkenmerk_lengte = null
|
|
, ins_refsrtkenmerk_key = (SELECT ins_ol_kenmerk_key
|
|
FROM ins_ol_kenmerk
|
|
WHERE ins_ol_kenmerk_naam = 'REF_INSERTTYPE')
|
|
WHERE ins_srtkenmerk_upper = 'INSERT TYPE';
|
|
|
|
DECLARE
|
|
--
|
|
-- Samenvoegen van de entries client10SH en client10SW tot Desktop
|
|
-- en de entries server100SH en server100SW tot Server.
|
|
--
|
|
client10sh_key VARCHAR2(10);
|
|
client10sw_key VARCHAR2(10);
|
|
server10sw_key VARCHAR2(10);
|
|
server100sw_key VARCHAR2(10);
|
|
FUNCTION haal_key(p_naam IN VARCHAR2) RETURN VARCHAR2 IS
|
|
ReturnVal VARCHAR2(16);
|
|
BEGIN
|
|
BEGIN
|
|
SELECT to_char(ins_ol_aansluiting_key)
|
|
INTO ReturnVal
|
|
FROM ins_v_aanwezigol_aansluiting
|
|
WHERE ins_ol_aansluiting_upper = p_naam;
|
|
EXCEPTION
|
|
WHEN NO_DATA_FOUND THEN ReturnVal := '0';
|
|
WHEN TOO_MANY_ROWS THEN ReturnVal := '0';
|
|
END;
|
|
RETURN ReturnVal;
|
|
END;
|
|
BEGIN
|
|
client10sh_key := haal_key('CLIENT10SH');
|
|
client10sw_key := haal_key('CLIENT10SW');
|
|
server10sw_key := haal_key('SERVER10SW');
|
|
server100sw_key := haal_key('SERVER100SW');
|
|
--
|
|
UPDATE ins_kenmerkdeel
|
|
SET ins_kenmerkdeel_waarde = client10sh_key
|
|
WHERE ins_kenmerkdeel_waarde = client10sw_key
|
|
AND ins_kenmerk_key = 48;
|
|
--
|
|
UPDATE ins_kenmerkdeel
|
|
SET ins_kenmerkdeel_waarde = server10sw_key
|
|
WHERE ins_kenmerkdeel_waarde = server100sw_key
|
|
AND ins_kenmerk_key = 48;
|
|
--
|
|
UPDATE ins_ol_aansluiting
|
|
SET ins_ol_aansluiting_naam = 'Desktop'
|
|
WHERE ins_ol_aansluiting_upper = 'CLIENT10SH';
|
|
--
|
|
UPDATE ins_ol_aansluiting
|
|
SET ins_ol_aansluiting_naam = 'Server'
|
|
WHERE ins_ol_aansluiting_upper = 'SERVER10SW';
|
|
--
|
|
UPDATE ins_ol_aansluiting
|
|
SET ins_ol_aansluiting_verwijder = sysdate
|
|
WHERE ins_ol_aansluiting_upper like '%10%';
|
|
END;
|
|
/
|
|
commit
|
|
/
|
|
|
|
declare
|
|
--
|
|
-- Zet voor alle outlets het kenmerk doorbelasten op JA.
|
|
--
|
|
v_ins_srtkenmerk_key number(9,0);
|
|
v_ins_refsrtkenmerk_key number(9,0);
|
|
v_ins_srtdeel_key number(9,0);
|
|
v_ins_kenmerk_key number(9,0);
|
|
v_fac_usrtab_key number(9,0);
|
|
doorbelasten_ja_key number(9,0);
|
|
begin
|
|
select ins_srtkenmerk_key, ins_refsrtkenmerk_key
|
|
into v_ins_srtkenmerk_key, v_ins_refsrtkenmerk_key
|
|
from ins_srtkenmerk
|
|
where ins_srtkenmerk_upper='DOORBELASTEN';
|
|
|
|
select ins_srtdeel_key
|
|
into v_ins_srtdeel_key
|
|
from ins_srtdeel
|
|
where ins_srtdeel_upper='OUTLET';
|
|
|
|
select ins_kenmerk_key
|
|
into v_ins_kenmerk_key
|
|
from ins_kenmerk
|
|
where ins_srtkenmerk_key=v_ins_srtkenmerk_key
|
|
and ins_srtinstallatie_key=v_ins_srtdeel_key;
|
|
|
|
select fac_usrtab_key
|
|
into v_fac_usrtab_key
|
|
from ins_refsrtkenmerk
|
|
where ins_refsrtkenmerk_key=v_ins_refsrtkenmerk_key;
|
|
|
|
select fac_usrdata_key
|
|
into doorbelasten_ja_key
|
|
from fac_usrdata
|
|
where fac_usrtab_key=v_fac_usrtab_key
|
|
and fac_usrdata_upper='JA';
|
|
|
|
update ins_kenmerkdeel
|
|
set ins_kenmerkdeel_waarde=doorbelasten_ja_key
|
|
where ins_kenmerk_key=v_ins_kenmerk_key;
|
|
end;
|
|
/
|
|
commit
|
|
/
|
|
|
|
spool $lan_views.sql
|
|
PROMPT SET ECHO OFF
|
|
SELECT 'CREATE OR REPLACE VIEW ins_v_ins_poorten '
|
|
|| '( ins_deel_hub_key '
|
|
|| ', ins_deel_key '
|
|
|| ', ins_deel_omschrijving '
|
|
|| ', ins_deel_hub '
|
|
|| ', ins_deel_poort '
|
|
|| ', alg_locatie_key) AS '
|
|
|| 'SELECT D.ins_deel_key '
|
|
|| ', O.ins_deel_key '
|
|
|| ', D.ins_deel_upper ||'' - ''|| O.ins_deel_upper '
|
|
|| ', D.ins_deel_upper '
|
|
|| ', O.ins_deel_upper '
|
|
|| ', O.ins_alg_locatie_key '
|
|
|| 'FROM ins_deel O '
|
|
|| ', ins_deel D '
|
|
|| 'WHERE O.ins_deel_parent_key = D.ins_deel_key '
|
|
|| 'AND O.ins_deel_verwijder IS NULL '
|
|
|| 'AND D.ins_deel_verwijder IS NULL '
|
|
|| 'AND O.ins_srtdeel_key = ' || to_char(A.ins_ol_kenmerk_key) ||' '
|
|
|| 'AND D.ins_srtdeel_key = ' || to_char(B.ins_ol_kenmerk_key) ||';'
|
|
FROM ins_ol_kenmerk A
|
|
, ins_ol_kenmerk B
|
|
WHERE A.ins_ol_kenmerk_naam = 'SRTDEEL_POORT'
|
|
AND B.ins_ol_kenmerk_naam = 'SRTDEEL_HUB';
|
|
|
|
PROMPT commit;;
|
|
spool off
|
|
START $lan_views.sql
|
|
|
|
UPDATE ins_refsrtkenmerk
|
|
SET ins_refsrtkenmerk_kolomnaam = 'INS_DEEL_KEY'
|
|
WHERE ins_refsrtkenmerk_kolomnaam = 'INS_DEEL_POORT_KEY';
|
|
|
|
|
|
SET TERMOUT OFF
|
|
SET HEADING OFF
|
|
SET FEEDBACK OFF
|
|
SET ECHO OFF
|
|
SET VERIFY OFF
|
|
SET LINESIZE 1000
|
|
SPOOL $LANGRTS.SQL
|
|
/* we SPOOLen ook binnen het gegenereerde script */
|
|
PROMPT SPOOL $LANgrts.lst
|
|
PROMPT SET ECHO OFF
|
|
/* Tables */
|
|
SELECT 'GRANT select ON ' || UT.table_name ||' TO '||USER||'_INS_SMALL_ROLE;' FROM user_tables UT, fac_privilege FP
|
|
WHERE UT.table_name = UPPER(FP.object_name) AND UT.table_name IN ('INS_OL_KAMERHUB')
|
|
AND FP.security_level IN (11,12,13) ORDER BY UT.table_name;
|
|
|
|
SELECT 'GRANT insert,delete,update ON ' || UT.table_name ||' TO '||USER||'_INS_SMALL_ROLE;' FROM user_tables UT, fac_privilege FP
|
|
WHERE UT.table_name = UPPER(FP.object_name) AND UT.table_name IN ('INS_OL_KAMERHUB')
|
|
AND FP.security_level = 11 ORDER BY UT.table_name;
|
|
|
|
SELECT 'GRANT insert,delete,update ON ' || UT.table_name ||' TO '||USER||'_INS_FULL_ROLE;' FROM user_tables UT, fac_privilege FP
|
|
WHERE UT.table_name = UPPER(FP.object_name) AND UT.table_name IN ('INS_OL_KAMERHUB')
|
|
AND FP.security_level = 12 ORDER BY UT.table_name;
|
|
|
|
SELECT 'GRANT insert,delete,update ON ' || UT.table_name ||' TO '||USER||'_INS_ARCHIVE_ROLE;' FROM user_tables UT, fac_privilege FP
|
|
WHERE UT.table_name = UPPER(FP.object_name) AND UT.table_name IN ('INS_OL_KAMERHUB')
|
|
AND FP.security_level = 13 ORDER BY UT.table_name;
|
|
/* Views */
|
|
SELECT 'GRANT select ON ' || UV.view_name ||' TO '||USER||'_INS_SMALL_ROLE;' FROM user_views UV, fac_privilege FP
|
|
WHERE UV.view_name = UPPER(FP.object_name) AND UV.view_name IN ('INS_V_AANWEZIGOL_KAMERHUB')
|
|
AND FP.security_level IN (11,12,13) ORDER BY UV.view_name;
|
|
PROMPT commit;;
|
|
PROMPT SPOOL OFF /* binnen het gegenereerde script */
|
|
SPOOL OFF
|
|
START $LANGRTS.sql
|
|
|
|
update fac_message set fac_message_text='Deze poort wordt al bezet door outlet %1%.' where fac_message_code='INS_OL_M026';
|
|
update fac_message set fac_message_text='Er zijn geen modules die voldoen aan deze naam.' where fac_message_code='INS_OL_M020';
|
|
insert into fac_entity_name values('INS_OL_KAMERHUB' ,'KamerHUB' ,null,null);
|
|
insert into fac_entity_name values('MENU_INS_OL_KAMERHUB' ,'KamerHUB' ,null,null);
|
|
insert into fac_message values('INS_OL_M028','De outlet wordt zonder Module/Poort bewaard.');
|
|
insert into fac_message values('INS_OL_M029','Verwijderen netwerk');
|
|
insert into fac_message values('INS_OL_M030','Verwijderen kamerHUB');
|
|
insert into fac_message values('INS_OL_M031','Module wijkt af van gebouw!');
|
|
insert into fac_message values('INS_OL_M032','Type aansluiting %1% is nog in gebruik.');
|
|
insert into fac_message values('INS_OL_M033','Netwerk %1% is nog in gebruik.');
|
|
insert into fac_message values('INS_OL_M034','Optie %1% is nog in gebruik.');
|
|
insert into fac_message values('INS_OL_M035','KamerHUB %1% is nog in gebruik.');
|
|
insert into fac_message values('INS_OL_M036','Object %1% wordt nog als referentie gebruikt in %2%.');
|
|
insert into fac_message values('INS_OL_M037','meerdere objecten');
|
|
|
|
commit
|
|
/
|