Files
ROMFASTSQL/proxmox/lxc108-oracle/roa-windows-setup/sql/create-user-contafin.sql
Marius 989477f7a4 Add ROA Oracle Database Windows setup scripts with old client support
PowerShell scripts for setting up Oracle 21c/XE with ROA application:
- Automated tablespace, user creation and imports
- sqlnet.ora config for Instant Client 11g/ODBC compatibility
- Oracle 21c read-only Home path handling (homes/OraDB21Home1)
- Listener restart + 10G password verifier for legacy auth
- Tested on VM 302 with CONTAFIN_ORACLE schema import

Co-Authored-By: Claude Opus 4.5 <noreply@anthropic.com>
2026-01-28 17:08:02 +02:00

132 lines
4.0 KiB
SQL

-- ============================================================================
-- CONTAFIN_ORACLE USER CREATION
-- ============================================================================
-- Creates CONTAFIN_ORACLE user with DBA-like privileges
-- This is the main administrative user for the ROA application
--
-- Usage:
-- @create-user-contafin.sql "YourSecurePassword"
--
-- Parameters:
-- &1 - Password for CONTAFIN_ORACLE user
--
-- Privileges granted:
-- - CONNECT, RESOURCE roles
-- - CREATE ANY CONTEXT, DROP ANY CONTEXT
-- - EXECUTE ANY PROCEDURE
-- - SELECT ANY TABLE/DICTIONARY/SEQUENCE
-- - INSERT/UPDATE/DELETE ANY TABLE
-- - UNLIMITED TABLESPACE
-- - CREATE/DROP PUBLIC SYNONYM
-- - CREATE VIEW, CREATE SESSION
--
-- Connect as: SYSDBA or SYSTEM
-- ============================================================================
SET ECHO OFF
SET FEEDBACK ON
SET SERVEROUTPUT ON
WHENEVER SQLERROR CONTINUE
PROMPT
PROMPT ========================================
PROMPT Creating CONTAFIN_ORACLE User
PROMPT ========================================
PROMPT
-- Define password
DEFINE co_password = "&1"
-- Drop user if exists (optional, comment out if you want to preserve data)
PROMPT Checking for existing CONTAFIN_ORACLE user...
DECLARE
v_count NUMBER;
BEGIN
SELECT COUNT(*) INTO v_count
FROM dba_users
WHERE username = 'CONTAFIN_ORACLE';
IF v_count > 0 THEN
DBMS_OUTPUT.PUT_LINE('WARNING: User CONTAFIN_ORACLE already exists.');
DBMS_OUTPUT.PUT_LINE('Use DROP USER CONTAFIN_ORACLE CASCADE to remove if needed.');
ELSE
DBMS_OUTPUT.PUT_LINE('User CONTAFIN_ORACLE does not exist. Proceeding with creation.');
END IF;
END;
/
-- Create user
PROMPT Creating user CONTAFIN_ORACLE...
CREATE USER CONTAFIN_ORACLE
IDENTIFIED BY "&co_password"
DEFAULT TABLESPACE ROA
TEMPORARY TABLESPACE TEMP
PROFILE DEFAULT;
-- Grant roles
PROMPT Granting roles...
GRANT CONNECT TO CONTAFIN_ORACLE;
GRANT RESOURCE TO CONTAFIN_ORACLE;
-- Grant system privileges
PROMPT Granting system privileges...
GRANT CREATE ANY CONTEXT TO CONTAFIN_ORACLE;
GRANT DROP ANY CONTEXT TO CONTAFIN_ORACLE;
GRANT CREATE SESSION TO CONTAFIN_ORACLE;
GRANT CREATE VIEW TO CONTAFIN_ORACLE;
GRANT CREATE TABLE TO CONTAFIN_ORACLE;
GRANT CREATE SEQUENCE TO CONTAFIN_ORACLE;
GRANT CREATE PROCEDURE TO CONTAFIN_ORACLE;
GRANT CREATE TRIGGER TO CONTAFIN_ORACLE;
GRANT CREATE TYPE TO CONTAFIN_ORACLE;
GRANT CREATE SYNONYM TO CONTAFIN_ORACLE;
GRANT CREATE MATERIALIZED VIEW TO CONTAFIN_ORACLE;
GRANT CREATE DATABASE LINK TO CONTAFIN_ORACLE;
GRANT CREATE JOB TO CONTAFIN_ORACLE;
-- Grant ANY privileges for application management
GRANT EXECUTE ANY PROCEDURE TO CONTAFIN_ORACLE;
GRANT SELECT ANY DICTIONARY TO CONTAFIN_ORACLE;
GRANT SELECT ANY SEQUENCE TO CONTAFIN_ORACLE;
GRANT SELECT ANY TABLE TO CONTAFIN_ORACLE;
GRANT INSERT ANY TABLE TO CONTAFIN_ORACLE;
GRANT UPDATE ANY TABLE TO CONTAFIN_ORACLE;
GRANT DELETE ANY TABLE TO CONTAFIN_ORACLE;
-- Grant tablespace and synonym privileges
GRANT UNLIMITED TABLESPACE TO CONTAFIN_ORACLE;
GRANT CREATE PUBLIC SYNONYM TO CONTAFIN_ORACLE;
GRANT DROP PUBLIC SYNONYM TO CONTAFIN_ORACLE;
PROMPT
PROMPT ========================================
PROMPT Verifying User Creation
PROMPT ========================================
PROMPT
-- Verify user creation
SELECT username, default_tablespace, temporary_tablespace, account_status, profile
FROM dba_users
WHERE username = 'CONTAFIN_ORACLE';
-- Verify roles
PROMPT
PROMPT Granted roles:
SELECT granted_role, admin_option, default_role
FROM dba_role_privs
WHERE grantee = 'CONTAFIN_ORACLE';
-- Verify system privileges
PROMPT
PROMPT Granted system privileges:
SELECT privilege, admin_option
FROM dba_sys_privs
WHERE grantee = 'CONTAFIN_ORACLE'
ORDER BY privilege;
PROMPT
PROMPT ========================================
PROMPT CONTAFIN_ORACLE User Creation Complete
PROMPT ========================================
PROMPT