Fix uninstall script: kill sessions before dropping users

- Added roa_kill_user_sessions helper procedure
- Kill all active sessions BEFORE attempting DROP USER
- Improved company user detection (also checks for synonyms to CONTAFIN_ORACLE)
- Added more Oracle 21c internal users to exclusion list
- Better error handling and output messages
- Helper procedure auto-cleanup at end

Co-Authored-By: Claude Opus 4.5 <noreply@anthropic.com>
This commit is contained in:
Marius
2026-01-28 17:45:33 +02:00
parent 33a3581823
commit a74d93f3ac

View File

@@ -2,7 +2,7 @@
-- ROA UNINSTALL SCRIPT -- ROA UNINSTALL SCRIPT
-- ============================================================================ -- ============================================================================
-- Removes all ROA application objects from Oracle database: -- Removes all ROA application objects from Oracle database:
-- - Company users (schemas starting with company patterns) -- - Company users (schemas using ROA tablespace or CONTAFIN_ORACLE synonyms)
-- - CONTAFIN_ORACLE user and all objects -- - CONTAFIN_ORACLE user and all objects
-- - Public synonyms pointing to CONTAFIN_ORACLE -- - Public synonyms pointing to CONTAFIN_ORACLE
-- - SYS custom objects (AUTH_PACK, AUTH_SERII, etc.) -- - SYS custom objects (AUTH_PACK, AUTH_SERII, etc.)
@@ -30,6 +30,27 @@ PROMPT Press Ctrl+C within 5 seconds to abort...
PROMPT PROMPT
EXEC DBMS_SESSION.SLEEP(5); EXEC DBMS_SESSION.SLEEP(5);
-- ============================================================================
-- HELPER: Kill all sessions for a given username
-- ============================================================================
CREATE OR REPLACE PROCEDURE roa_kill_user_sessions(p_username IN VARCHAR2) IS
v_count NUMBER := 0;
BEGIN
FOR r IN (SELECT sid, serial# FROM v$session WHERE username = UPPER(p_username)) LOOP
BEGIN
EXECUTE IMMEDIATE 'ALTER SYSTEM KILL SESSION ''' || r.sid || ',' || r.serial# || ''' IMMEDIATE';
v_count := v_count + 1;
EXCEPTION
WHEN OTHERS THEN NULL;
END;
END LOOP;
IF v_count > 0 THEN
DBMS_OUTPUT.PUT_LINE(' Killed ' || v_count || ' session(s) for ' || p_username);
DBMS_SESSION.SLEEP(1); -- Wait for sessions to terminate
END IF;
END;
/
-- ============================================================================ -- ============================================================================
-- SECTION 1: DROP COMPANY USERS -- SECTION 1: DROP COMPANY USERS
-- ============================================================================ -- ============================================================================
@@ -39,9 +60,10 @@ PROMPT ============================================================
DECLARE DECLARE
CURSOR c_users IS CURSOR c_users IS
SELECT username SELECT DISTINCT username
FROM dba_users FROM dba_users
WHERE username NOT IN ( WHERE username NOT IN (
-- Oracle internal users
'SYS', 'SYSTEM', 'OUTLN', 'DIP', 'ORACLE_OCM', 'DBSNMP', 'APPQOSSYS', 'SYS', 'SYSTEM', 'OUTLN', 'DIP', 'ORACLE_OCM', 'DBSNMP', 'APPQOSSYS',
'WMSYS', 'EXFSYS', 'CTXSYS', 'ANONYMOUS', 'XDB', 'ORDPLUGINS', 'WMSYS', 'EXFSYS', 'CTXSYS', 'ANONYMOUS', 'XDB', 'ORDPLUGINS',
'ORDSYS', 'SI_INFORMTN_SCHEMA', 'MDSYS', 'OLAPSYS', 'MDDATA', 'ORDSYS', 'SI_INFORMTN_SCHEMA', 'MDSYS', 'OLAPSYS', 'MDDATA',
@@ -52,23 +74,40 @@ DECLARE
'GSMUSER', 'GSMCATUSER', 'SYSBACKUP', 'SYSDG', 'SYSKM', 'GSMUSER', 'GSMCATUSER', 'SYSBACKUP', 'SYSDG', 'SYSKM',
'SYSRAC', 'SYS$UMF', 'DBSFWUSER', 'REMOTE_SCHEDULER_AGENT', 'SYSRAC', 'SYS$UMF', 'DBSFWUSER', 'REMOTE_SCHEDULER_AGENT',
'PDBADMIN', 'GGSHAREDCAP', 'LBACSYS', 'DVF', 'DVSYS', 'PDBADMIN', 'GGSHAREDCAP', 'LBACSYS', 'DVF', 'DVSYS',
'AUDSYS', 'DGPDB_INT', 'GGSYS', 'CONTAFIN_ORACLE' 'AUDSYS', 'DGPDB_INT', 'GGSYS', 'OJVMSYS', 'ORDDATA',
-- ROA main user (dropped separately)
'CONTAFIN_ORACLE'
) )
AND username NOT LIKE 'APEX%' AND username NOT LIKE 'APEX%'
AND username NOT LIKE 'FLOWS%' AND username NOT LIKE 'FLOWS%'
AND username NOT LIKE 'OWB%' AND username NOT LIKE 'OWB%'
AND default_tablespace = 'ROA' AND username NOT LIKE 'C##%'
AND (
-- Users with ROA tablespace
default_tablespace = 'ROA'
-- OR users that have synonyms pointing to CONTAFIN_ORACLE (company schemas)
OR username IN (
SELECT DISTINCT owner
FROM dba_synonyms
WHERE table_owner = 'CONTAFIN_ORACLE'
AND owner NOT IN ('PUBLIC', 'SYS', 'SYSTEM')
)
)
ORDER BY username; ORDER BY username;
v_count NUMBER := 0; v_count NUMBER := 0;
BEGIN BEGIN
FOR r IN c_users LOOP FOR r IN c_users LOOP
BEGIN BEGIN
DBMS_OUTPUT.PUT_LINE(' Processing: ' || r.username);
-- Kill sessions first
roa_kill_user_sessions(r.username);
-- Drop user
EXECUTE IMMEDIATE 'DROP USER ' || r.username || ' CASCADE'; EXECUTE IMMEDIATE 'DROP USER ' || r.username || ' CASCADE';
DBMS_OUTPUT.PUT_LINE(' Dropped user: ' || r.username); DBMS_OUTPUT.PUT_LINE(' Dropped user: ' || r.username);
v_count := v_count + 1; v_count := v_count + 1;
EXCEPTION EXCEPTION
WHEN OTHERS THEN WHEN OTHERS THEN
DBMS_OUTPUT.PUT_LINE(' ERROR dropping ' || r.username || ': ' || SQLERRM); DBMS_OUTPUT.PUT_LINE(' ERROR: ' || SQLERRM);
END; END;
END LOOP; END LOOP;
DBMS_OUTPUT.PUT_LINE('Total company users dropped: ' || v_count); DBMS_OUTPUT.PUT_LINE('Total company users dropped: ' || v_count);
@@ -87,9 +126,13 @@ DECLARE
BEGIN BEGIN
SELECT COUNT(*) INTO v_count FROM dba_users WHERE username = 'CONTAFIN_ORACLE'; SELECT COUNT(*) INTO v_count FROM dba_users WHERE username = 'CONTAFIN_ORACLE';
IF v_count > 0 THEN IF v_count > 0 THEN
-- First drop the private synonym -- Kill all sessions first
roa_kill_user_sessions('CONTAFIN_ORACLE');
-- Drop the private synonym (if exists)
BEGIN BEGIN
EXECUTE IMMEDIATE 'DROP SYNONYM CONTAFIN_ORACLE.VDEF_PROGRAME_SERII'; EXECUTE IMMEDIATE 'DROP SYNONYM CONTAFIN_ORACLE.VDEF_PROGRAME_SERII';
DBMS_OUTPUT.PUT_LINE(' Dropped synonym CONTAFIN_ORACLE.VDEF_PROGRAME_SERII');
EXCEPTION WHEN OTHERS THEN NULL; EXCEPTION WHEN OTHERS THEN NULL;
END; END;
@@ -99,6 +142,9 @@ BEGIN
ELSE ELSE
DBMS_OUTPUT.PUT_LINE(' User CONTAFIN_ORACLE does not exist.'); DBMS_OUTPUT.PUT_LINE(' User CONTAFIN_ORACLE does not exist.');
END IF; END IF;
EXCEPTION
WHEN OTHERS THEN
DBMS_OUTPUT.PUT_LINE(' ERROR dropping CONTAFIN_ORACLE: ' || SQLERRM);
END; END;
/ /
@@ -134,7 +180,7 @@ BEGIN
EXECUTE IMMEDIATE 'DROP PUBLIC SYNONYM ' || r.synonym_name; EXECUTE IMMEDIATE 'DROP PUBLIC SYNONYM ' || r.synonym_name;
v_count := v_count + 1; v_count := v_count + 1;
EXCEPTION EXCEPTION
WHEN OTHERS THEN NULL; -- Ignore if doesn't exist WHEN OTHERS THEN NULL;
END; END;
END LOOP; END LOOP;
DBMS_OUTPUT.PUT_LINE(' Dropped ' || v_count || ' public synonyms.'); DBMS_OUTPUT.PUT_LINE(' Dropped ' || v_count || ' public synonyms.');
@@ -231,9 +277,7 @@ BEGIN
SELECT COUNT(*) INTO v_count FROM dba_tablespaces WHERE tablespace_name = 'ROA'; SELECT COUNT(*) INTO v_count FROM dba_tablespaces WHERE tablespace_name = 'ROA';
IF v_count > 0 THEN IF v_count > 0 THEN
-- Check for any remaining objects -- Check for any remaining objects
SELECT COUNT(*) INTO v_count SELECT COUNT(*) INTO v_count FROM dba_segments WHERE tablespace_name = 'ROA';
FROM dba_segments
WHERE tablespace_name = 'ROA';
IF v_count > 0 THEN IF v_count > 0 THEN
DBMS_OUTPUT.PUT_LINE(' WARNING: Tablespace ROA still has ' || v_count || ' segments.'); DBMS_OUTPUT.PUT_LINE(' WARNING: Tablespace ROA still has ' || v_count || ' segments.');
@@ -245,9 +289,17 @@ BEGIN
ELSE ELSE
DBMS_OUTPUT.PUT_LINE(' Tablespace ROA does not exist.'); DBMS_OUTPUT.PUT_LINE(' Tablespace ROA does not exist.');
END IF; END IF;
EXCEPTION
WHEN OTHERS THEN
DBMS_OUTPUT.PUT_LINE(' ERROR dropping tablespace: ' || SQLERRM);
END; END;
/ /
-- ============================================================================
-- CLEANUP: Drop helper procedure
-- ============================================================================
DROP PROCEDURE roa_kill_user_sessions;
-- ============================================================================ -- ============================================================================
-- VERIFICATION -- VERIFICATION
-- ============================================================================ -- ============================================================================
@@ -260,6 +312,10 @@ PROMPT
PROMPT Users with default tablespace ROA: PROMPT Users with default tablespace ROA:
SELECT username, default_tablespace FROM dba_users WHERE default_tablespace = 'ROA'; SELECT username, default_tablespace FROM dba_users WHERE default_tablespace = 'ROA';
PROMPT
PROMPT CONTAFIN_ORACLE user:
SELECT username FROM dba_users WHERE username = 'CONTAFIN_ORACLE';
PROMPT PROMPT
PROMPT SYS custom objects: PROMPT SYS custom objects:
SELECT object_name, object_type, status SELECT object_name, object_type, status