#Requires -Version 5.1 <# .SYNOPSIS Install SYS objects for ROA Oracle. .DESCRIPTION Executes SQL scripts to create required SYS-owned objects including: - AUTH_PACK package - AUTH_DETALII, AUTH_SERII tables - NEWSCHEMA, NEWSCHEMAPOST procedures - NEWSCHEMAPROGRESS function - PACK_UPDATE, PACK_UTILS packages - Public synonyms and grants .PARAMETER OracleHome Oracle home directory. If not specified, auto-detects. .PARAMETER ServiceName Database service name. Default: XEPDB1 .PARAMETER SystemPassword SYSTEM/SYS user password. Default: romfastsoft .PARAMETER SqlScriptsDir Directory containing SYS SQL scripts. Default: ..\sql .EXAMPLE .\02-create-sys-objects.ps1 .EXAMPLE .\02-create-sys-objects.ps1 -ServiceName "ROA" -SystemPassword "mypassword" .NOTES File Name : 02-create-sys-objects.ps1 Prerequisite : Run 01-setup-database.ps1 first Copyright 2024 : ROMFAST #> [CmdletBinding()] param( [Parameter(Mandatory = $false)] [string]$OracleHome, [Parameter(Mandatory = $false)] [string]$ServiceName = "XEPDB1", [Parameter(Mandatory = $false)] [string]$SystemPassword = "romfastsoft", [Parameter(Mandatory = $false)] [string]$SqlScriptsDir ) $ErrorActionPreference = 'Stop' # Source library functions . "$PSScriptRoot\lib\logging-functions.ps1" . "$PSScriptRoot\lib\oracle-functions.ps1" # Initialize logging $logPath = Join-Path $PSScriptRoot "..\logs\02-create-sys-objects_$(Get-Date -Format 'yyyyMMdd_HHmmss').log" Initialize-LogFile -LogPath $logPath -ScriptName "02-create-sys-objects.ps1" try { Write-LogSection "Installing SYS Objects" # Validate Oracle installation $oraHome = Get-OracleHome -OracleHome $OracleHome Write-LogSuccess "Oracle Home: $oraHome" # Test connection Write-Log "Testing database connection..." if (-not (Test-OracleConnection -OracleHome $oraHome -ServiceName $ServiceName ` -Username "SYS" -Password $SystemPassword -AsSysdba)) { throw "Cannot connect to database as SYS. Please verify ServiceName and SystemPassword." } Write-LogSuccess "Database connection successful" # Determine SQL scripts directory if (-not $SqlScriptsDir) { $SqlScriptsDir = Join-Path $PSScriptRoot "..\sql" } $sysObjectsScript = Join-Path $SqlScriptsDir "sys-objects.sql" if (-not (Test-Path -Path $sysObjectsScript)) { Write-LogWarning "sys-objects.sql not found at $sysObjectsScript" Write-Log "Creating sys-objects.sql from embedded SQL..." # Create the sql directory if it doesn't exist if (-not (Test-Path -Path $SqlScriptsDir)) { New-Item -ItemType Directory -Path $SqlScriptsDir -Force | Out-Null } # Embedded SYS objects SQL - minimal set for ROA $sysObjectsSql = @" -- sys-objects.sql -- SYS objects required for ROA Oracle -- Run as SYS with SYSDBA privilege SET ECHO ON FEEDBACK ON VERIFY OFF SERVEROUTPUT ON PROMPT PROMPT ============================================= PROMPT Creating SYS objects for ROA PROMPT ============================================= PROMPT -- Create DMPDIR if not exists PROMPT Creating directory DMPDIR... CREATE OR REPLACE DIRECTORY DMPDIR AS 'C:\DMPDIR'; GRANT READ, WRITE ON DIRECTORY DMPDIR TO PUBLIC; -- AUTH_DETALII table PROMPT Creating table AUTH_DETALII... BEGIN EXECUTE IMMEDIATE 'DROP TABLE SYS.AUTH_DETALII CASCADE CONSTRAINTS'; EXCEPTION WHEN OTHERS THEN NULL; END; / CREATE TABLE SYS.AUTH_DETALII ( ID_DETALIU NUMBER NOT NULL, ID_PROGRAM NUMBER NOT NULL, CAMP_DETALIU VARCHAR2(100), VAL_DETALIU VARCHAR2(500), CONSTRAINT PK_AUTH_DETALII PRIMARY KEY (ID_DETALIU) ); GRANT SELECT, INSERT, UPDATE, DELETE ON SYS.AUTH_DETALII TO PUBLIC; CREATE PUBLIC SYNONYM AUTH_DETALII FOR SYS.AUTH_DETALII; -- AUTH_SERII table PROMPT Creating table AUTH_SERII... BEGIN EXECUTE IMMEDIATE 'DROP TABLE SYS.AUTH_SERII CASCADE CONSTRAINTS'; EXCEPTION WHEN OTHERS THEN NULL; END; / CREATE TABLE SYS.AUTH_SERII ( ID_PROGRAM NUMBER NOT NULL, SERIE VARCHAR2(50), NR_UTIL NUMBER, DATA_VAL DATE, CONSTRAINT PK_AUTH_SERII PRIMARY KEY (ID_PROGRAM) ); GRANT SELECT, INSERT, UPDATE, DELETE ON SYS.AUTH_SERII TO PUBLIC; CREATE PUBLIC SYNONYM AUTH_SERII FOR SYS.AUTH_SERII; -- AUTH_PACK package specification PROMPT Creating package AUTH_PACK... CREATE OR REPLACE PACKAGE SYS.AUTH_PACK AS FUNCTION selecteaza_serie(p_id_program NUMBER) RETURN VARCHAR2; FUNCTION selecteaza_nr_util(p_id_program NUMBER) RETURN NUMBER; FUNCTION selecteaza_data_val(p_id_program NUMBER) RETURN DATE; PROCEDURE actualizeaza_serie(p_id_program NUMBER, p_serie VARCHAR2, p_nr_util NUMBER, p_data_val DATE); END AUTH_PACK; / -- AUTH_PACK package body CREATE OR REPLACE PACKAGE BODY SYS.AUTH_PACK AS FUNCTION selecteaza_serie(p_id_program NUMBER) RETURN VARCHAR2 IS v_serie VARCHAR2(50); BEGIN SELECT serie INTO v_serie FROM SYS.AUTH_SERII WHERE id_program = p_id_program; RETURN v_serie; EXCEPTION WHEN NO_DATA_FOUND THEN RETURN NULL; END; FUNCTION selecteaza_nr_util(p_id_program NUMBER) RETURN NUMBER IS v_nr_util NUMBER; BEGIN SELECT nr_util INTO v_nr_util FROM SYS.AUTH_SERII WHERE id_program = p_id_program; RETURN v_nr_util; EXCEPTION WHEN NO_DATA_FOUND THEN RETURN NULL; END; FUNCTION selecteaza_data_val(p_id_program NUMBER) RETURN DATE IS v_data_val DATE; BEGIN SELECT data_val INTO v_data_val FROM SYS.AUTH_SERII WHERE id_program = p_id_program; RETURN v_data_val; EXCEPTION WHEN NO_DATA_FOUND THEN RETURN NULL; END; PROCEDURE actualizeaza_serie(p_id_program NUMBER, p_serie VARCHAR2, p_nr_util NUMBER, p_data_val DATE) IS BEGIN MERGE INTO SYS.AUTH_SERII t USING (SELECT p_id_program AS id_program FROM dual) s ON (t.id_program = s.id_program) WHEN MATCHED THEN UPDATE SET serie = p_serie, nr_util = p_nr_util, data_val = p_data_val WHEN NOT MATCHED THEN INSERT (id_program, serie, nr_util, data_val) VALUES (p_id_program, p_serie, p_nr_util, p_data_val); COMMIT; END; END AUTH_PACK; / GRANT EXECUTE ON SYS.AUTH_PACK TO PUBLIC; CREATE OR REPLACE PUBLIC SYNONYM AUTH_PACK FOR SYS.AUTH_PACK; -- VAUTH_SERII view PROMPT Creating view VAUTH_SERII... CREATE OR REPLACE VIEW SYS.VAUTH_SERII AS SELECT a.id_program, a.denumire AS nume, auth_pack.selecteaza_serie(a.id_program) AS serie, auth_pack.selecteaza_nr_util(a.id_program) AS nr_util, auth_pack.selecteaza_data_val(a.id_program) AS data_val FROM syn_nom_programe a LEFT JOIN syn_def_programe b ON a.id_program = b.ide_program WHERE b.sters = 0 AND b.instalat = 1; GRANT SELECT ON SYS.VAUTH_SERII TO PUBLIC; CREATE OR REPLACE PUBLIC SYNONYM VAUTH_SERII FOR SYS.VAUTH_SERII; -- PACK_UPDATE package (minimal version) PROMPT Creating package PACK_UPDATE... CREATE OR REPLACE PACKAGE SYS.PACK_UPDATE AS FUNCTION get_version RETURN VARCHAR2; PROCEDURE execute_sql(p_sql VARCHAR2); END PACK_UPDATE; / CREATE OR REPLACE PACKAGE BODY SYS.PACK_UPDATE AS FUNCTION get_version RETURN VARCHAR2 IS BEGIN RETURN '1.0.0'; END; PROCEDURE execute_sql(p_sql VARCHAR2) IS BEGIN EXECUTE IMMEDIATE p_sql; EXCEPTION WHEN OTHERS THEN RAISE; END; END PACK_UPDATE; / GRANT EXECUTE ON SYS.PACK_UPDATE TO PUBLIC; CREATE OR REPLACE PUBLIC SYNONYM PACK_UPDATE FOR SYS.PACK_UPDATE; -- PACK_UTILS package (minimal version) PROMPT Creating package PACK_UTILS... CREATE OR REPLACE PACKAGE SYS.PACK_UTILS AS FUNCTION get_db_version RETURN VARCHAR2; FUNCTION get_instance_name RETURN VARCHAR2; END PACK_UTILS; / CREATE OR REPLACE PACKAGE BODY SYS.PACK_UTILS AS FUNCTION get_db_version RETURN VARCHAR2 IS v_version VARCHAR2(100); BEGIN SELECT version_full INTO v_version FROM v`$instance; RETURN v_version; EXCEPTION WHEN OTHERS THEN RETURN NULL; END; FUNCTION get_instance_name RETURN VARCHAR2 IS v_instance VARCHAR2(100); BEGIN SELECT instance_name INTO v_instance FROM v`$instance; RETURN v_instance; EXCEPTION WHEN OTHERS THEN RETURN NULL; END; END PACK_UTILS; / GRANT EXECUTE ON SYS.PACK_UTILS TO PUBLIC; CREATE OR REPLACE PUBLIC SYNONYM PACK_UTILS FOR SYS.PACK_UTILS; -- Grant UTL packages to PUBLIC PROMPT Granting UTL packages... GRANT EXECUTE ON UTL_FILE TO PUBLIC; GRANT EXECUTE ON DBMS_LOCK TO PUBLIC; -- Grant UTL packages to CONTAFIN_ORACLE specifically GRANT EXECUTE ON UTL_INADDR TO CONTAFIN_ORACLE; GRANT EXECUTE ON UTL_TCP TO CONTAFIN_ORACLE; GRANT EXECUTE ON UTL_SMTP TO CONTAFIN_ORACLE; GRANT EXECUTE ON UTL_HTTP TO CONTAFIN_ORACLE; COMMIT; PROMPT PROMPT ============================================= PROMPT SYS objects created successfully PROMPT ============================================= PROMPT SELECT 'SYS_OBJECTS_COMPLETE' FROM dual; EXIT; "@ Set-Content -Path $sysObjectsScript -Value $sysObjectsSql -Encoding ASCII Write-Log "Created sys-objects.sql" } # Execute SYS objects script Write-LogSection "Executing sys-objects.sql" $result = Invoke-SqlPlus -OracleHome $oraHome -ServiceName $ServiceName ` -Username "SYS" -Password $SystemPassword -SqlFile $sysObjectsScript -AsSysdba if ($result -match "SYS_OBJECTS_COMPLETE") { Write-LogSuccess "SYS objects created successfully" } else { Write-LogWarning "Script completed but could not verify success" Write-LogDebug $result } # Verify created objects Write-LogSection "Verifying SYS Objects" $verifySql = @" SET PAGESIZE 100 FEEDBACK OFF VERIFY OFF HEADING ON ECHO OFF LINESIZE 200 PROMPT PROMPT === SYS Objects Status === PROMPT SELECT object_name, object_type, status FROM dba_objects WHERE owner = 'SYS' AND object_name IN ('AUTH_PACK', 'AUTH_DETALII', 'AUTH_SERII', 'VAUTH_SERII', 'PACK_UPDATE', 'PACK_UTILS', 'NEWSCHEMA', 'NEWSCHEMAPOST', 'NEWSCHEMAPROGRESS') ORDER BY object_type, object_name; PROMPT PROMPT === Public Synonyms === PROMPT SELECT synonym_name, table_owner, table_name FROM dba_synonyms WHERE owner = 'PUBLIC' AND table_name IN ('AUTH_PACK', 'AUTH_DETALII', 'AUTH_SERII', 'VAUTH_SERII', 'PACK_UPDATE', 'PACK_UTILS', 'NEWSCHEMA', 'NEWSCHEMAPOST', 'NEWSCHEMAPROGRESS') ORDER BY synonym_name; EXIT; "@ $verifyResult = Invoke-SqlPlus -OracleHome $oraHome -ServiceName $ServiceName ` -Username "SYS" -Password $SystemPassword -SqlCommand $verifySql -AsSysdba Write-Host $verifyResult # Count invalid objects $invalidSql = @" SET PAGESIZE 0 FEEDBACK OFF VERIFY OFF HEADING OFF ECHO OFF SELECT 'INVALID_COUNT:' || COUNT(*) FROM dba_objects WHERE owner = 'SYS' AND object_name IN ('AUTH_PACK', 'AUTH_DETALII', 'AUTH_SERII', 'VAUTH_SERII', 'PACK_UPDATE', 'PACK_UTILS', 'NEWSCHEMA', 'NEWSCHEMAPOST', 'NEWSCHEMAPROGRESS') AND status = 'INVALID'; EXIT; "@ $invalidResult = Invoke-SqlPlus -OracleHome $oraHome -ServiceName $ServiceName ` -Username "SYS" -Password $SystemPassword -SqlCommand $invalidSql -AsSysdba -Silent $invalidCount = 0 if ($invalidResult -match "INVALID_COUNT:(\d+)") { $invalidCount = [int]$Matches[1] } if ($invalidCount -gt 0) { Write-LogWarning "$invalidCount invalid SYS objects found" Write-Log "Attempting to recompile invalid objects..." $recompileSql = @" SET SERVEROUTPUT ON BEGIN DBMS_UTILITY.COMPILE_SCHEMA('SYS', FALSE); END; / EXIT; "@ Invoke-SqlPlus -OracleHome $oraHome -ServiceName $ServiceName ` -Username "SYS" -Password $SystemPassword -SqlCommand $recompileSql -AsSysdba -Silent } else { Write-LogSuccess "All SYS objects are valid" } # Summary Write-LogSection "Setup Complete" Write-LogSuccess "SYS objects installation completed!" Write-Log "" Write-Log "Objects created:" Write-Log " - AUTH_PACK package" Write-Log " - AUTH_DETALII table" Write-Log " - AUTH_SERII table" Write-Log " - VAUTH_SERII view" Write-Log " - PACK_UPDATE package" Write-Log " - PACK_UTILS package" Write-Log " - Public synonyms and grants" Write-Log "" Write-Log "Next steps:" Write-Log " 1. Run 03-import-contafin.ps1 to import CONTAFIN_ORACLE schema" Close-LogFile -Success $true exit 0 } catch { Write-LogError "Setup failed: $_" Write-LogError $_.ScriptStackTrace Close-LogFile -Success $false exit 1 }