- 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>
348 lines
13 KiB
SQL
348 lines
13 KiB
SQL
-- ============================================================================
|
|
-- ROA UNINSTALL SCRIPT
|
|
-- ============================================================================
|
|
-- Removes all ROA application objects from Oracle database:
|
|
-- - Company users (schemas using ROA tablespace or CONTAFIN_ORACLE synonyms)
|
|
-- - CONTAFIN_ORACLE user and all objects
|
|
-- - Public synonyms pointing to CONTAFIN_ORACLE
|
|
-- - SYS custom objects (AUTH_PACK, AUTH_SERII, etc.)
|
|
-- - Application context SESIUNE
|
|
-- - Tablespace ROA
|
|
--
|
|
-- Usage:
|
|
-- sqlplus sys/password@service as sysdba @uninstall-roa.sql
|
|
--
|
|
-- WARNING: This script PERMANENTLY DELETES all ROA data!
|
|
-- ============================================================================
|
|
|
|
SET ECHO OFF
|
|
SET FEEDBACK ON
|
|
SET SERVEROUTPUT ON SIZE UNLIMITED
|
|
WHENEVER SQLERROR CONTINUE
|
|
|
|
PROMPT
|
|
PROMPT ============================================================
|
|
PROMPT ROA UNINSTALL - REMOVING ALL ROA OBJECTS
|
|
PROMPT ============================================================
|
|
PROMPT
|
|
PROMPT WARNING: This will permanently delete all ROA data!
|
|
PROMPT Press Ctrl+C within 5 seconds to abort...
|
|
PROMPT
|
|
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
|
|
-- ============================================================================
|
|
PROMPT
|
|
PROMPT [1/6] Dropping company users...
|
|
PROMPT ============================================================
|
|
|
|
DECLARE
|
|
CURSOR c_users IS
|
|
SELECT DISTINCT username
|
|
FROM dba_users
|
|
WHERE username NOT IN (
|
|
-- Oracle internal users
|
|
'SYS', 'SYSTEM', 'OUTLN', 'DIP', 'ORACLE_OCM', 'DBSNMP', 'APPQOSSYS',
|
|
'WMSYS', 'EXFSYS', 'CTXSYS', 'ANONYMOUS', 'XDB', 'ORDPLUGINS',
|
|
'ORDSYS', 'SI_INFORMTN_SCHEMA', 'MDSYS', 'OLAPSYS', 'MDDATA',
|
|
'SPATIAL_WFS_ADMIN_USR', 'SPATIAL_CSW_ADMIN_USR', 'SYSMAN',
|
|
'MGMT_VIEW', 'APEX_PUBLIC_USER', 'APEX_040000', 'APEX_040200',
|
|
'FLOWS_FILES', 'OWBSYS', 'OWBSYS_AUDIT', 'SCOTT', 'HR', 'OE',
|
|
'SH', 'PM', 'IX', 'BI', 'XS$NULL', 'GSMADMIN_INTERNAL',
|
|
'GSMUSER', 'GSMCATUSER', 'SYSBACKUP', 'SYSDG', 'SYSKM',
|
|
'SYSRAC', 'SYS$UMF', 'DBSFWUSER', 'REMOTE_SCHEDULER_AGENT',
|
|
'PDBADMIN', 'GGSHAREDCAP', 'LBACSYS', 'DVF', 'DVSYS',
|
|
'AUDSYS', 'DGPDB_INT', 'GGSYS', 'OJVMSYS', 'ORDDATA',
|
|
-- ROA main user (dropped separately)
|
|
'CONTAFIN_ORACLE'
|
|
)
|
|
AND username NOT LIKE 'APEX%'
|
|
AND username NOT LIKE 'FLOWS%'
|
|
AND username NOT LIKE 'OWB%'
|
|
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;
|
|
v_count NUMBER := 0;
|
|
BEGIN
|
|
FOR r IN c_users LOOP
|
|
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';
|
|
DBMS_OUTPUT.PUT_LINE(' Dropped user: ' || r.username);
|
|
v_count := v_count + 1;
|
|
EXCEPTION
|
|
WHEN OTHERS THEN
|
|
DBMS_OUTPUT.PUT_LINE(' ERROR: ' || SQLERRM);
|
|
END;
|
|
END LOOP;
|
|
DBMS_OUTPUT.PUT_LINE('Total company users dropped: ' || v_count);
|
|
END;
|
|
/
|
|
|
|
-- ============================================================================
|
|
-- SECTION 2: DROP CONTAFIN_ORACLE USER
|
|
-- ============================================================================
|
|
PROMPT
|
|
PROMPT [2/6] Dropping CONTAFIN_ORACLE user...
|
|
PROMPT ============================================================
|
|
|
|
DECLARE
|
|
v_count NUMBER;
|
|
BEGIN
|
|
SELECT COUNT(*) INTO v_count FROM dba_users WHERE username = 'CONTAFIN_ORACLE';
|
|
IF v_count > 0 THEN
|
|
-- Kill all sessions first
|
|
roa_kill_user_sessions('CONTAFIN_ORACLE');
|
|
|
|
-- Drop the private synonym (if exists)
|
|
BEGIN
|
|
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;
|
|
END;
|
|
|
|
-- Now drop the user
|
|
EXECUTE IMMEDIATE 'DROP USER CONTAFIN_ORACLE CASCADE';
|
|
DBMS_OUTPUT.PUT_LINE(' User CONTAFIN_ORACLE dropped successfully.');
|
|
ELSE
|
|
DBMS_OUTPUT.PUT_LINE(' User CONTAFIN_ORACLE does not exist.');
|
|
END IF;
|
|
EXCEPTION
|
|
WHEN OTHERS THEN
|
|
DBMS_OUTPUT.PUT_LINE(' ERROR dropping CONTAFIN_ORACLE: ' || SQLERRM);
|
|
END;
|
|
/
|
|
|
|
-- ============================================================================
|
|
-- SECTION 3: DROP PUBLIC SYNONYMS
|
|
-- ============================================================================
|
|
PROMPT
|
|
PROMPT [3/6] Dropping public synonyms...
|
|
PROMPT ============================================================
|
|
|
|
DECLARE
|
|
CURSOR c_synonyms IS
|
|
SELECT synonym_name
|
|
FROM dba_synonyms
|
|
WHERE owner = 'PUBLIC'
|
|
AND (table_owner = 'CONTAFIN_ORACLE'
|
|
OR synonym_name IN (
|
|
'STRINGAGG', 'CHAR_ROW', 'CHAR_TAB', 'NUM_ROW', 'NUM_TAB',
|
|
'UW_SEL_ROW', 'UW_SEL_TAB', 'GETWORDCOUNT', 'GETWORDNUM',
|
|
'CHARC2COLLECTION', 'CHARN2COLLECTION', 'VALOARETAG',
|
|
'SAL_CONTRACT_M', 'CONTRACT_M', 'SAL_RED', 'SAL_CAMPURI_RED',
|
|
'TABSTERS', 'SAL_TABELESTERS', 'PACK_UPDATE', 'PACK_UTILS',
|
|
'PACK_UTILS_FILE', 'PACK_ROARTVAI', 'RTVAI_AGENTI', 'RTVAI_ISTORIC',
|
|
'FF_SUME', 'FF_PERSINTRET', 'VANZARI_DETALII_TAB', 'PIVOT_TABLE',
|
|
'PIVOT_ROW', 'TABINCHIDERETVA', 'TABELAVALORITAGURI',
|
|
'RANDINCHIDERETVA', 'SERVER_INFO'
|
|
)
|
|
OR synonym_name LIKE 'SYN_%');
|
|
v_count NUMBER := 0;
|
|
BEGIN
|
|
FOR r IN c_synonyms LOOP
|
|
BEGIN
|
|
EXECUTE IMMEDIATE 'DROP PUBLIC SYNONYM ' || r.synonym_name;
|
|
v_count := v_count + 1;
|
|
EXCEPTION
|
|
WHEN OTHERS THEN NULL;
|
|
END;
|
|
END LOOP;
|
|
DBMS_OUTPUT.PUT_LINE(' Dropped ' || v_count || ' public synonyms.');
|
|
END;
|
|
/
|
|
|
|
-- ============================================================================
|
|
-- SECTION 4: DROP APPLICATION CONTEXT
|
|
-- ============================================================================
|
|
PROMPT
|
|
PROMPT [4/6] Dropping application context...
|
|
PROMPT ============================================================
|
|
|
|
BEGIN
|
|
EXECUTE IMMEDIATE 'DROP CONTEXT SESIUNE';
|
|
DBMS_OUTPUT.PUT_LINE(' Context SESIUNE dropped.');
|
|
EXCEPTION
|
|
WHEN OTHERS THEN
|
|
DBMS_OUTPUT.PUT_LINE(' Context SESIUNE not found or already dropped.');
|
|
END;
|
|
/
|
|
|
|
-- ============================================================================
|
|
-- SECTION 5: DROP SYS CUSTOM OBJECTS
|
|
-- ============================================================================
|
|
PROMPT
|
|
PROMPT [5/6] Dropping SYS custom objects...
|
|
PROMPT ============================================================
|
|
|
|
-- Drop view first (depends on package)
|
|
BEGIN EXECUTE IMMEDIATE 'DROP VIEW SYS.VAUTH_SERII';
|
|
DBMS_OUTPUT.PUT_LINE(' Dropped SYS.VAUTH_SERII');
|
|
EXCEPTION WHEN OTHERS THEN NULL; END;
|
|
/
|
|
|
|
-- Drop procedures
|
|
BEGIN EXECUTE IMMEDIATE 'DROP PROCEDURE SYS.UPDATESQLPLUS';
|
|
DBMS_OUTPUT.PUT_LINE(' Dropped SYS.UPDATESQLPLUS');
|
|
EXCEPTION WHEN OTHERS THEN NULL; END;
|
|
/
|
|
BEGIN EXECUTE IMMEDIATE 'DROP PROCEDURE SYS.NEWSCHEMAJOB';
|
|
DBMS_OUTPUT.PUT_LINE(' Dropped SYS.NEWSCHEMAJOB');
|
|
EXCEPTION WHEN OTHERS THEN NULL; END;
|
|
/
|
|
BEGIN EXECUTE IMMEDIATE 'DROP PROCEDURE SYS.NEWSCHEMA';
|
|
DBMS_OUTPUT.PUT_LINE(' Dropped SYS.NEWSCHEMA');
|
|
EXCEPTION WHEN OTHERS THEN NULL; END;
|
|
/
|
|
BEGIN EXECUTE IMMEDIATE 'DROP PROCEDURE SYS.EXECUTESCRIPTOS';
|
|
DBMS_OUTPUT.PUT_LINE(' Dropped SYS.EXECUTESCRIPTOS');
|
|
EXCEPTION WHEN OTHERS THEN NULL; END;
|
|
/
|
|
BEGIN EXECUTE IMMEDIATE 'DROP PROCEDURE SYS.PINFO';
|
|
DBMS_OUTPUT.PUT_LINE(' Dropped SYS.PINFO');
|
|
EXCEPTION WHEN OTHERS THEN NULL; END;
|
|
/
|
|
|
|
-- Drop package
|
|
BEGIN EXECUTE IMMEDIATE 'DROP PACKAGE SYS.AUTH_PACK';
|
|
DBMS_OUTPUT.PUT_LINE(' Dropped SYS.AUTH_PACK');
|
|
EXCEPTION WHEN OTHERS THEN NULL; END;
|
|
/
|
|
|
|
-- Drop sequence
|
|
BEGIN EXECUTE IMMEDIATE 'DROP SEQUENCE SYS.SEQ_AUTH_SERII';
|
|
DBMS_OUTPUT.PUT_LINE(' Dropped SYS.SEQ_AUTH_SERII');
|
|
EXCEPTION WHEN OTHERS THEN NULL; END;
|
|
/
|
|
|
|
-- Drop tables
|
|
BEGIN EXECUTE IMMEDIATE 'DROP TABLE SYS.AUTH_SERII PURGE';
|
|
DBMS_OUTPUT.PUT_LINE(' Dropped SYS.AUTH_SERII');
|
|
EXCEPTION WHEN OTHERS THEN NULL; END;
|
|
/
|
|
BEGIN EXECUTE IMMEDIATE 'DROP TABLE SYS.AUTH_DETALII PURGE';
|
|
DBMS_OUTPUT.PUT_LINE(' Dropped SYS.AUTH_DETALII');
|
|
EXCEPTION WHEN OTHERS THEN NULL; END;
|
|
/
|
|
BEGIN EXECUTE IMMEDIATE 'DROP TABLE SYS.INFO PURGE';
|
|
DBMS_OUTPUT.PUT_LINE(' Dropped SYS.INFO');
|
|
EXCEPTION WHEN OTHERS THEN NULL; END;
|
|
/
|
|
|
|
-- ============================================================================
|
|
-- SECTION 6: DROP TABLESPACE ROA
|
|
-- ============================================================================
|
|
PROMPT
|
|
PROMPT [6/6] Dropping tablespace ROA...
|
|
PROMPT ============================================================
|
|
|
|
DECLARE
|
|
v_count NUMBER;
|
|
BEGIN
|
|
SELECT COUNT(*) INTO v_count FROM dba_tablespaces WHERE tablespace_name = 'ROA';
|
|
IF v_count > 0 THEN
|
|
-- Check for any remaining objects
|
|
SELECT COUNT(*) INTO v_count FROM dba_segments WHERE tablespace_name = 'ROA';
|
|
|
|
IF v_count > 0 THEN
|
|
DBMS_OUTPUT.PUT_LINE(' WARNING: Tablespace ROA still has ' || v_count || ' segments.');
|
|
DBMS_OUTPUT.PUT_LINE(' Dropping tablespace with INCLUDING CONTENTS...');
|
|
END IF;
|
|
|
|
EXECUTE IMMEDIATE 'DROP TABLESPACE ROA INCLUDING CONTENTS AND DATAFILES';
|
|
DBMS_OUTPUT.PUT_LINE(' Tablespace ROA dropped successfully.');
|
|
ELSE
|
|
DBMS_OUTPUT.PUT_LINE(' Tablespace ROA does not exist.');
|
|
END IF;
|
|
EXCEPTION
|
|
WHEN OTHERS THEN
|
|
DBMS_OUTPUT.PUT_LINE(' ERROR dropping tablespace: ' || SQLERRM);
|
|
END;
|
|
/
|
|
|
|
-- ============================================================================
|
|
-- CLEANUP: Drop helper procedure
|
|
-- ============================================================================
|
|
DROP PROCEDURE roa_kill_user_sessions;
|
|
|
|
-- ============================================================================
|
|
-- VERIFICATION
|
|
-- ============================================================================
|
|
PROMPT
|
|
PROMPT ============================================================
|
|
PROMPT VERIFICATION - Remaining ROA Objects (should be empty)
|
|
PROMPT ============================================================
|
|
PROMPT
|
|
|
|
PROMPT Users with 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 SYS custom objects:
|
|
SELECT object_name, object_type, status
|
|
FROM dba_objects
|
|
WHERE owner = 'SYS'
|
|
AND object_name IN (
|
|
'AUTH_PACK', 'AUTH_DETALII', 'AUTH_SERII', 'VAUTH_SERII',
|
|
'EXECUTESCRIPTOS', 'NEWSCHEMA', 'NEWSCHEMAJOB', 'UPDATESQLPLUS',
|
|
'PINFO', 'INFO', 'SEQ_AUTH_SERII'
|
|
);
|
|
|
|
PROMPT
|
|
PROMPT Public synonyms pointing to CONTAFIN_ORACLE:
|
|
SELECT COUNT(*) AS remaining_synonyms
|
|
FROM dba_synonyms
|
|
WHERE owner = 'PUBLIC'
|
|
AND table_owner = 'CONTAFIN_ORACLE';
|
|
|
|
PROMPT
|
|
PROMPT Tablespace ROA:
|
|
SELECT tablespace_name, status FROM dba_tablespaces WHERE tablespace_name = 'ROA';
|
|
|
|
PROMPT
|
|
PROMPT ============================================================
|
|
PROMPT ROA UNINSTALL COMPLETE
|
|
PROMPT ============================================================
|
|
PROMPT
|
|
PROMPT Database is now clean. You can re-run the setup scripts.
|
|
PROMPT
|