-- ============================================================================ -- COMPANY SCHEMA USER CREATION (Template) -- ============================================================================ -- Creates a company schema user for ROA application -- Each company in ROA has its own schema with identical structure -- -- Usage: -- @create-user-company.sql "SCHEMA_NAME" "Password123" -- -- Parameters: -- &1 - Schema/User name (e.g., FIRMA1, TESTFIRMA, ROMCONSTRUCT) -- &2 - Password for the schema user -- -- Privileges granted: -- - CONNECT, RESOURCE roles -- - CREATE SESSION, TABLE, VIEW, SEQUENCE, PROCEDURE, TRIGGER, TYPE, SYNONYM -- - CREATE MATERIALIZED VIEW, DATABASE LINK, JOB -- - DEBUG CONNECT SESSION -- - SELECT ANY TABLE (for cross-schema queries) -- - UNLIMITED TABLESPACE -- -- Connect as: SYSDBA or SYSTEM -- ============================================================================ SET ECHO OFF SET FEEDBACK ON SET SERVEROUTPUT ON WHENEVER SQLERROR CONTINUE PROMPT PROMPT ======================================== PROMPT Creating Company Schema User PROMPT ======================================== PROMPT -- Define parameters DEFINE schema_name = "&1" DEFINE schema_password = "&2" PROMPT Schema name: &schema_name -- Check if user already exists DECLARE v_count NUMBER; BEGIN SELECT COUNT(*) INTO v_count FROM dba_users WHERE username = UPPER('&schema_name'); IF v_count > 0 THEN DBMS_OUTPUT.PUT_LINE('WARNING: User &schema_name already exists.'); DBMS_OUTPUT.PUT_LINE('Use DROP USER &schema_name CASCADE to remove if needed.'); ELSE DBMS_OUTPUT.PUT_LINE('User &schema_name does not exist. Proceeding with creation.'); END IF; END; / -- Create user PROMPT Creating user &schema_name... CREATE USER &schema_name IDENTIFIED BY "&schema_password" DEFAULT TABLESPACE ROA TEMPORARY TABLESPACE TEMP QUOTA UNLIMITED ON ROA; -- Grant roles PROMPT Granting roles... GRANT CONNECT TO &schema_name; GRANT RESOURCE TO &schema_name; -- Grant session and object creation privileges PROMPT Granting system privileges... GRANT CREATE SESSION TO &schema_name; GRANT CREATE TABLE TO &schema_name; GRANT CREATE VIEW TO &schema_name; GRANT CREATE SEQUENCE TO &schema_name; GRANT CREATE PROCEDURE TO &schema_name; GRANT CREATE TRIGGER TO &schema_name; GRANT CREATE TYPE TO &schema_name; GRANT CREATE SYNONYM TO &schema_name; GRANT CREATE MATERIALIZED VIEW TO &schema_name; GRANT CREATE DATABASE LINK TO &schema_name; GRANT CREATE JOB TO &schema_name; -- Grant debug capability GRANT DEBUG CONNECT SESSION TO &schema_name; -- Grant select any table for cross-schema reporting GRANT SELECT ANY TABLE TO &schema_name; -- Grant unlimited tablespace GRANT UNLIMITED TABLESPACE TO &schema_name; PROMPT PROMPT ======================================== PROMPT Verifying User Creation PROMPT ======================================== PROMPT -- Verify user creation SELECT username, default_tablespace, temporary_tablespace, account_status FROM dba_users WHERE username = UPPER('&schema_name'); -- Verify roles PROMPT PROMPT Granted roles: SELECT granted_role FROM dba_role_privs WHERE grantee = UPPER('&schema_name'); -- Verify tablespace quota PROMPT PROMPT Tablespace quotas: SELECT tablespace_name, CASE WHEN max_bytes = -1 THEN 'UNLIMITED' ELSE TO_CHAR(max_bytes/1024/1024) || ' MB' END AS quota FROM dba_ts_quotas WHERE username = UPPER('&schema_name'); PROMPT PROMPT ======================================== PROMPT Company Schema &schema_name Created PROMPT ======================================== PROMPT PROMPT Next steps: PROMPT 1. Import schema data from FIRMANOUA.dmp or existing backup PROMPT 2. Run schema update scripts via PACK_UPDATE PROMPT