Files
Database/_UP/epilogue.inc
Jos Groot Lipman 085c03371f Te lange kolomnamen direct bij de upgrade al vermelden zodat we vroeg kunnen ingrijpen.
svn path=/Database/trunk/; revision=47867
2020-08-20 08:51:59 +00:00

121 lines
4.3 KiB
SQL

/* _up/epilogue.inc
* Epiloog van update script van Facilitor, to be included in every schema update
*
* $Revision$
* $Id$
*/
COMMIT;
DELETE FROM fac_session WHERE fac_session_expire < SYSDATE - 2;
DELETE FROM aut_client_perslid WHERE aut_client_perslid_login < SYSDATE - 60;
DELETE FROM fac_bookmark WHERE fac_bookmark_expire < SYSDATE - 2;
DELETE FROM web_user_messages WHERE web_user_mess_action_datum < SYSDATE - 60;
DELETE FROM fac_notificatie WHERE fac_notificatie_status=0
AND fac_notificatie_systeemadres IS NULL;
COMMIT;
-- Dialect/terminologie items die niet meer bestaan
DELETE FROM fac_localeitems
WHERE fac_localeitems_lcl NOT IN
(SELECT fac_locale_xsl_label FROM fac_locale_xsl);
-- Bij een DROP TABLE wordt nogal eens de PURGE vergeten
PURGE RECYCLEBIN;
-- Schema-naam uit MLD_T_UITVOERTIJD verwijderen.
--
-- data_default is van het datatype LONG. Daarop kan geen string-bewerking als INSTR(), SUBSTR() en REPLACE() worden gedaan.
-- Daarom moeten de benodigde gegevens eerst in een tijdelijke tabel ingelezen worden zodat het datatype VARCHAR2 wordt. Voor
-- het huidige doel (de owner van MLD_T_UITVOERTIJD verwijderen) is de stringlengte van 1000 voldoende.
-- Met FETCH .. BULK COLLECT INTO .. worden alle records die volgen uit de query in 1 keer opgehaald. Dit is sneller dan een fetch in een loop.
--
DECLARE
TYPE ut_row IS RECORD
( tab_name VARCHAR2(100)
, col_name VARCHAR2(100)
, data_default VARCHAR2(1000)
);
TYPE ut_tab IS TABLE OF ut_row
INDEX BY PLS_INTEGER;
qry_txt VARCHAR2(1000);
upd_txt VARCHAR2(1000);
l_table ut_tab;
l_cursor SYS_REFCURSOR;
l_pos INTEGER;
l_default VARCHAR2(1000);
BEGIN
qry_txt := 'SELECT table_name, column_name, data_default'
|| ' FROM user_tab_columns'
|| ' WHERE data_type = ''MLD_T_UITVOERTIJD''';
OPEN l_cursor FOR qry_txt;
FETCH l_cursor BULK COLLECT INTO l_table;
CLOSE l_cursor;
FOR indx IN 1 .. l_table.COUNT
LOOP
l_pos := INSTR(l_table(indx).data_default, '"."');
IF (l_pos > 0)
THEN
l_default := REPLACE(REPLACE(SUBSTR(l_table(indx).data_default, l_pos+3, 100), '"', ''),'''','');
upd_txt := 'ALTER TABLE '|| l_table(indx).tab_name ||' MODIFY '|| l_table(indx).col_name ||' DEFAULT '|| l_default;
dbms_output.put_line(upd_txt);
EXECUTE IMMEDIATE upd_txt;
END IF;
END LOOP;
END;
/
///////////////////////////// now recreate all views, triggers etc acc to the latest state ///////
#include "recreate.inc"
#ifdef POST_RECREATE
#include POST_RECREATE
#endif
INSERT INTO adm_tracking
(adm_tracking_name, adm_tracking_revision)
VALUES
('Database upgraded', 'DB' || _DBV_STRING);
COMMIT;
select 'Upgrade has completed in ' || ROUND(( dbms_utility.get_time - :update_start )/100) || ' seconds.' from dual;
/* Report invalid objects, if any */
SET ECHO OFF
SET HEADING OFF
SET LINESIZE 132
PROMPT List of all too long objectnames (max 30)
SELECT 'OR'||'A-'||'DB'||_DBV_STRING||' Name too long: ' || TABLE_NAME || '.' ||COLUMN_NAME|| ' ' || DATA_TYPE
FROM USER_TAB_COLUMNS
WHERE LENGTH(column_name) > 30;
PROMPT List of all invalid objects after Facilitor upgrade.
PROMPT Some errors may resolve by running the customer specific script next.
SELECT 'OR'||'A-'||'DB'||_DBV_STRING||' 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;
SET HEADING ON
column name format a32
column text format a60
column line format 9999
column pos format 9999
SET HEADING ON
SELECT TYPE, NAME, LINE, POSITION POS, TEXT
FROM USER_ERRORS
ORDER BY NAME, TYPE, SEQUENCE;
SET ECHO OFF
SET FEEDBACK OFF
PROMPT ======================================================================
SELECT 'Schema Facilitor@' || USER || ' is now ' || fac.getdbversion() FROM DUAL;
PROMPT
PROMPT Your schema upgrade is ready. Please check the logfile for errors.
PROMPT If in doubt please contact: Facilitor Helpdesk +31 53 4800 700
SET DEFINE ON
PROMPT Logfile of this upgrade is: &fcltlogfile
SPOOL OFF