Files
ROMFASTSQL/system_instructions/oracle/oracle-migration-plan-10g-to-21c.md
2025-09-30 01:41:58 +03:00

886 lines
28 KiB
Markdown

# Plan Complet Migrare Oracle 10g → Oracle XE 21c
## 1. Prezentare Generală
### Context Migrare
- **Sursă**: Oracle 10g Standard Edition pe Windows 7
- IP: 10.0.20.122
- Port: 1521
- Service: ROA
- Versiune: Oracle 10g
- OS: Windows 7
- **Destinație**: Oracle XE 21c în Docker LXC pe Proxmox
- IP: 10.0.20.105
- Port: 1521
- PDB: ROA (sau ROA2)
- Versiune: Oracle 21c Express Edition
- Container: Docker în LXC (ID: 108)
### Scheme de Migrat
1. **CONTAFIN_ORACLE** - Schema principală contabilitate
2. **MARIUSM_AUTO** - Schema secundară
3. **Obiecte custom din SYS** - Tabele, view-uri, proceduri, packages create manual în SYS
### Cerințe Speciale
- **Grant-uri către CONTAFIN_ORACLE** - Toate privilegiile acordate acestei scheme
- **Grant-uri către PUBLIC** - Privilegii publice pentru obiectele din scheme
- **Sinonime publice** - Toate sinonimele publice pentru acces simplificat
- **Dependințe cross-schema** - Legături între scheme și obiecte SYS
## 2. Provocări Tehnice
### Diferența de Versiuni
- **Salt major**: 11 versiuni Oracle (10g → 21c)
- **Deprecated features**: Multiple funcționalități eliminate sau modificate
- **Sintaxă SQL**: Unele comenzi necesită adaptare
- **Character set**: Posibile probleme de encoding
- **Arhitectură**: Trecere de la non-CDB la CDB/PDB
### Compatibilitate Export/Import
- **Data Pump**: Nu funcționează între 10g și 21c direct
- **Export tradițional (exp/imp)**: Metodă recomandată pentru compatibilitate
- **DDL manual**: Extragere folosind DBMS_METADATA pentru control complet
## 3. Strategia de Migrare - 3 Faze
### Faza 1: Analiză și Extragere Metadata
#### Script: `oracle-analyze-source.sh`
```bash
#!/bin/bash
# Analiză completă a bazei de date sursă Oracle 10g
SOURCE_DB="10.0.20.122:1521/ROA"
SOURCE_USER="system"
SOURCE_PASS="your_password"
# Conectare și analiză
sqlplus -S $SOURCE_USER/$SOURCE_PASS@$SOURCE_DB <<'EOF'
SET LONG 1000000
SET PAGESIZE 0
SET LINESIZE 1000
SET FEEDBACK OFF
SET VERIFY OFF
SET TRIMSPOOL ON
-- 1. INVENTAR OBIECTE PRINCIPALE
SPOOL object_inventory.txt
SELECT owner || '.' || object_type || '.' || object_name AS object_full_name,
status,
created,
last_ddl_time
FROM dba_objects
WHERE owner IN ('CONTAFIN_ORACLE', 'MARIUSM_AUTO')
OR (owner = 'SYS' AND
(object_name LIKE '%CONTAFIN%' OR
object_name IN (
SELECT DISTINCT referenced_name
FROM dba_dependencies
WHERE owner IN ('CONTAFIN_ORACLE', 'MARIUSM_AUTO')
AND referenced_owner = 'SYS'
)
)
)
ORDER BY owner, object_type, object_name;
SPOOL OFF
-- 2. ANALIZA GRANT-URI
SPOOL grants_analysis.txt
-- Grant-uri pe obiecte
SELECT 'OBJECT_GRANT:' || owner || '.' || table_name || ':' ||
privilege || ':TO:' || grantee ||
CASE WHEN grantable = 'YES' THEN ':WITH_GRANT_OPTION' ELSE '' END
FROM dba_tab_privs
WHERE owner IN ('CONTAFIN_ORACLE', 'MARIUSM_AUTO')
OR grantee IN ('CONTAFIN_ORACLE', 'MARIUSM_AUTO', 'PUBLIC')
ORDER BY owner, table_name, grantee, privilege;
-- Grant-uri de sistem
SELECT 'SYSTEM_GRANT:' || privilege || ':TO:' || grantee ||
CASE WHEN admin_option = 'YES' THEN ':WITH_ADMIN_OPTION' ELSE '' END
FROM dba_sys_privs
WHERE grantee IN ('CONTAFIN_ORACLE', 'MARIUSM_AUTO')
ORDER BY grantee, privilege;
-- Roluri
SELECT 'ROLE_GRANT:' || granted_role || ':TO:' || grantee ||
CASE WHEN admin_option = 'YES' THEN ':WITH_ADMIN_OPTION' ELSE '' END
FROM dba_role_privs
WHERE grantee IN ('CONTAFIN_ORACLE', 'MARIUSM_AUTO')
ORDER BY grantee, granted_role;
SPOOL OFF
-- 3. ANALIZA SINONIME PUBLICE
SPOOL public_synonyms_analysis.txt
SELECT 'PUBLIC_SYNONYM:' || synonym_name || ':FOR:' ||
table_owner || '.' || table_name
FROM dba_synonyms
WHERE owner = 'PUBLIC'
AND (table_owner IN ('CONTAFIN_ORACLE', 'MARIUSM_AUTO')
OR synonym_name IN (
SELECT DISTINCT referenced_name
FROM dba_dependencies
WHERE owner IN ('CONTAFIN_ORACLE', 'MARIUSM_AUTO')
AND referenced_type = 'SYNONYM'
))
ORDER BY synonym_name;
SPOOL OFF
-- 4. ANALIZA DEPENDINTE
SPOOL dependencies_analysis.txt
SELECT owner || '.' || name || ' (' || type || ') DEPENDS_ON ' ||
referenced_owner || '.' || referenced_name || ' (' || referenced_type || ')'
FROM dba_dependencies
WHERE owner IN ('CONTAFIN_ORACLE', 'MARIUSM_AUTO', 'SYS')
AND (owner IN ('CONTAFIN_ORACLE', 'MARIUSM_AUTO')
OR referenced_owner IN ('CONTAFIN_ORACLE', 'MARIUSM_AUTO'))
ORDER BY owner, name, referenced_owner, referenced_name;
SPOOL OFF
-- 5. STATISTICI TABELE (pentru validare post-migrare)
SPOOL table_statistics.txt
SELECT owner || '.' || table_name || ':ROWS=' || num_rows
FROM dba_tables
WHERE owner IN ('CONTAFIN_ORACLE', 'MARIUSM_AUTO')
ORDER BY owner, table_name;
SPOOL OFF
EXIT;
EOF
```
### Faza 2: Export din Oracle 10g
#### Script: `oracle-export-10g.sh`
```bash
#!/bin/bash
# Export complet din Oracle 10g cu toate dependințele
export ORACLE_HOME=/path/to/oracle/10g
export PATH=$ORACLE_HOME/bin:$PATH
export NLS_LANG=AMERICAN_AMERICA.AL32UTF8
EXPORT_DIR="/backup/oracle_migration"
SOURCE_DB="10.0.20.122:1521/ROA"
SYSTEM_USER="system"
SYSTEM_PASS="your_password"
# Creare director export
mkdir -p $EXPORT_DIR
cd $EXPORT_DIR
echo "========================================"
echo "ETAPA 1: Export DDL cu DBMS_METADATA"
echo "========================================"
sqlplus -S $SYSTEM_USER/$SYSTEM_PASS@$SOURCE_DB <<'EOF'
SET LONG 1000000
SET PAGESIZE 0
SET LINESIZE 1000
SET FEEDBACK OFF
SET VERIFY OFF
SET TRIMSPOOL ON
-- Configurare DBMS_METADATA pentru output curat
EXEC DBMS_METADATA.SET_TRANSFORM_PARAM(DBMS_METADATA.SESSION_TRANSFORM,'STORAGE',false);
EXEC DBMS_METADATA.SET_TRANSFORM_PARAM(DBMS_METADATA.SESSION_TRANSFORM,'TABLESPACE',false);
EXEC DBMS_METADATA.SET_TRANSFORM_PARAM(DBMS_METADATA.SESSION_TRANSFORM,'SEGMENT_ATTRIBUTES',false);
-- 1. Export CREATE USER statements
SPOOL 01_create_users.sql
SELECT '-- User: ' || username FROM dba_users
WHERE username IN ('CONTAFIN_ORACLE', 'MARIUSM_AUTO');
SELECT DBMS_METADATA.GET_DDL('USER', username) || '/'
FROM dba_users
WHERE username IN ('CONTAFIN_ORACLE', 'MARIUSM_AUTO');
SPOOL OFF
-- 2. Export Tables DDL
SPOOL 02_create_tables.sql
SELECT DBMS_METADATA.GET_DDL('TABLE', table_name, owner) || '/'
FROM dba_tables
WHERE owner IN ('CONTAFIN_ORACLE', 'MARIUSM_AUTO')
ORDER BY owner, table_name;
SPOOL OFF
-- 3. Export Indexes
SPOOL 03_create_indexes.sql
SELECT DBMS_METADATA.GET_DDL('INDEX', index_name, owner) || '/'
FROM dba_indexes
WHERE owner IN ('CONTAFIN_ORACLE', 'MARIUSM_AUTO')
AND index_type != 'LOB'
ORDER BY owner, index_name;
SPOOL OFF
-- 4. Export Constraints
SPOOL 04_create_constraints.sql
SELECT DBMS_METADATA.GET_DDL('CONSTRAINT', constraint_name, owner) || '/'
FROM dba_constraints
WHERE owner IN ('CONTAFIN_ORACLE', 'MARIUSM_AUTO')
AND constraint_type IN ('P', 'U', 'C', 'R')
ORDER BY
CASE constraint_type
WHEN 'P' THEN 1
WHEN 'U' THEN 2
WHEN 'C' THEN 3
WHEN 'R' THEN 4
END,
owner, constraint_name;
SPOOL OFF
-- 5. Export Views
SPOOL 05_create_views.sql
SELECT DBMS_METADATA.GET_DDL('VIEW', view_name, owner) || '/'
FROM dba_views
WHERE owner IN ('CONTAFIN_ORACLE', 'MARIUSM_AUTO')
ORDER BY owner, view_name;
SPOOL OFF
-- 6. Export Sequences
SPOOL 06_create_sequences.sql
SELECT DBMS_METADATA.GET_DDL('SEQUENCE', sequence_name, sequence_owner) || '/'
FROM dba_sequences
WHERE sequence_owner IN ('CONTAFIN_ORACLE', 'MARIUSM_AUTO')
ORDER BY sequence_owner, sequence_name;
SPOOL OFF
-- 7. Export Procedures, Functions, Packages
SPOOL 07_create_code_objects.sql
SELECT DBMS_METADATA.GET_DDL(object_type, object_name, owner) || '/'
FROM dba_objects
WHERE owner IN ('CONTAFIN_ORACLE', 'MARIUSM_AUTO')
AND object_type IN ('PROCEDURE', 'FUNCTION', 'PACKAGE', 'PACKAGE BODY', 'TYPE', 'TYPE BODY')
ORDER BY owner,
CASE object_type
WHEN 'TYPE' THEN 1
WHEN 'TYPE BODY' THEN 2
WHEN 'PACKAGE' THEN 3
WHEN 'PACKAGE BODY' THEN 4
WHEN 'FUNCTION' THEN 5
WHEN 'PROCEDURE' THEN 6
END,
object_name;
SPOOL OFF
-- 8. Export Triggers
SPOOL 08_create_triggers.sql
SELECT DBMS_METADATA.GET_DDL('TRIGGER', trigger_name, owner) || '/'
FROM dba_triggers
WHERE owner IN ('CONTAFIN_ORACLE', 'MARIUSM_AUTO')
ORDER BY owner, trigger_name;
SPOOL OFF
-- 9. Export Grants
SPOOL 09_grants.sql
-- Object privileges
SELECT 'GRANT ' || privilege || ' ON ' || owner || '.' || table_name ||
' TO ' || grantee ||
DECODE(grantable, 'YES', ' WITH GRANT OPTION', '') || ';'
FROM dba_tab_privs
WHERE (owner IN ('CONTAFIN_ORACLE', 'MARIUSM_AUTO')
OR grantee IN ('CONTAFIN_ORACLE', 'MARIUSM_AUTO'))
ORDER BY owner, table_name, grantee, privilege;
-- System privileges
SELECT 'GRANT ' || privilege || ' TO ' || grantee ||
DECODE(admin_option, 'YES', ' WITH ADMIN OPTION', '') || ';'
FROM dba_sys_privs
WHERE grantee IN ('CONTAFIN_ORACLE', 'MARIUSM_AUTO')
ORDER BY grantee, privilege;
-- Role privileges
SELECT 'GRANT ' || granted_role || ' TO ' || grantee ||
DECODE(admin_option, 'YES', ' WITH ADMIN OPTION', '') || ';'
FROM dba_role_privs
WHERE grantee IN ('CONTAFIN_ORACLE', 'MARIUSM_AUTO')
ORDER BY grantee, granted_role;
SPOOL OFF
-- 10. Export Public Synonyms
SPOOL 10_public_synonyms.sql
SELECT 'CREATE OR REPLACE PUBLIC SYNONYM ' || synonym_name ||
' FOR ' || table_owner || '.' || table_name || ';'
FROM dba_synonyms
WHERE owner = 'PUBLIC'
AND table_owner IN ('CONTAFIN_ORACLE', 'MARIUSM_AUTO')
ORDER BY synonym_name;
SPOOL OFF
-- 11. Export obiecte custom din SYS (dacă există)
SPOOL 11_sys_custom_objects.sql
-- Identificare obiecte custom
SELECT '-- Custom object in SYS: ' || object_name || ' (' || object_type || ')'
FROM dba_objects
WHERE owner = 'SYS'
AND (object_name LIKE '%CONTAFIN%'
OR object_name IN (
SELECT DISTINCT referenced_name
FROM dba_dependencies
WHERE owner IN ('CONTAFIN_ORACLE', 'MARIUSM_AUTO')
AND referenced_owner = 'SYS'
AND referenced_name NOT IN (
SELECT object_name
FROM dba_objects
WHERE owner = 'SYS'
AND created < (SELECT MIN(created) FROM dba_users WHERE username = 'CONTAFIN_ORACLE')
)
))
AND object_type IN ('TABLE', 'VIEW', 'PROCEDURE', 'FUNCTION', 'PACKAGE', 'PACKAGE BODY');
-- Export DDL pentru aceste obiecte
SELECT DBMS_METADATA.GET_DDL(object_type, object_name, 'SYS') || '/'
FROM dba_objects
WHERE owner = 'SYS'
AND object_name LIKE '%CONTAFIN%'
AND object_type IN ('TABLE', 'VIEW', 'PROCEDURE', 'FUNCTION', 'PACKAGE', 'PACKAGE BODY');
SPOOL OFF
EXIT;
EOF
echo "========================================"
echo "ETAPA 2: Export DATE cu EXP (traditional)"
echo "========================================"
# Export cu exp (compatibil între versiuni)
exp $SYSTEM_USER/$SYSTEM_PASS@$SOURCE_DB \
file=contafin_data.dmp \
log=contafin_export.log \
owner=CONTAFIN_ORACLE,MARIUSM_AUTO \
statistics=none \
compress=n \
consistent=y \
feedback=10000 \
buffer=10485760 \
direct=n
echo "========================================"
echo "ETAPA 3: Arhivare și pregătire transfer"
echo "========================================"
# Creare arhivă cu toate fișierele
tar -czf oracle_migration_$(date +%Y%m%d_%H%M%S).tar.gz *.sql *.dmp *.log *.txt
echo "Export complet finalizat!"
echo "Fișiere generate:"
ls -la *.sql *.dmp *.log *.txt
```
### Faza 3: Import în Oracle XE 21c
#### Script: `oracle-import-21c.sh`
```bash
#!/bin/bash
# Import complet în Oracle XE 21c cu recrearea completă a mediului
# Configurare
DEST_HOST="10.0.20.105"
DEST_PORT="1521"
DEST_PDB="ROA" # sau ROA2
SYS_PASS="OraclePass123"
IMPORT_DIR="/tmp/oracle_import"
# Setare environment pentru Oracle 21c în container
DOCKER_CONTAINER="oracle-xe"
PROXMOX_HOST="10.0.20.201"
LXC_CONTAINER="108"
echo "========================================"
echo "PREGĂTIRE IMPORT ORACLE XE 21c"
echo "========================================"
# Funcție pentru executare comenzi în Oracle via Docker
run_oracle_sql() {
local SQL_COMMAND="$1"
ssh root@$PROXMOX_HOST "pct exec $LXC_CONTAINER -- docker exec -i $DOCKER_CONTAINER sqlplus -s sys/$SYS_PASS@localhost:1521/$DEST_PDB as sysdba" <<< "$SQL_COMMAND"
}
# Funcție pentru executare imp în container
run_oracle_imp() {
local IMP_PARAMS="$1"
ssh root@$PROXMOX_HOST "pct exec $LXC_CONTAINER -- docker exec $DOCKER_CONTAINER imp sys/$SYS_PASS@localhost:1521/$DEST_PDB as sysdba $IMP_PARAMS"
}
echo "========================================"
echo "ETAPA 1: Pregătire mediu destinație"
echo "========================================"
run_oracle_sql "
-- Verificare și creare tablespace-uri
DECLARE
v_exists NUMBER;
BEGIN
-- Verificare și creare CONTAFIN_DATA
SELECT COUNT(*) INTO v_exists FROM dba_tablespaces WHERE tablespace_name = 'CONTAFIN_DATA';
IF v_exists = 0 THEN
EXECUTE IMMEDIATE 'CREATE TABLESPACE CONTAFIN_DATA
DATAFILE ''/opt/oracle/oradata/XE/$DEST_PDB/contafin_data01.dbf''
SIZE 1G AUTOEXTEND ON MAXSIZE 10G';
DBMS_OUTPUT.PUT_LINE('Tablespace CONTAFIN_DATA creat.');
END IF;
-- Verificare și creare CONTAFIN_INDEX
SELECT COUNT(*) INTO v_exists FROM dba_tablespaces WHERE tablespace_name = 'CONTAFIN_INDEX';
IF v_exists = 0 THEN
EXECUTE IMMEDIATE 'CREATE TABLESPACE CONTAFIN_INDEX
DATAFILE ''/opt/oracle/oradata/XE/$DEST_PDB/contafin_index01.dbf''
SIZE 500M AUTOEXTEND ON MAXSIZE 5G';
DBMS_OUTPUT.PUT_LINE('Tablespace CONTAFIN_INDEX creat.');
END IF;
END;
/
-- Drop și recreare useri (pentru clean import)
BEGIN
FOR usr IN (SELECT username FROM dba_users WHERE username IN ('CONTAFIN_ORACLE', 'MARIUSM_AUTO')) LOOP
EXECUTE IMMEDIATE 'DROP USER ' || usr.username || ' CASCADE';
END LOOP;
END;
/
-- Creare useri noi
CREATE USER CONTAFIN_ORACLE
IDENTIFIED BY contafin_pass
DEFAULT TABLESPACE CONTAFIN_DATA
TEMPORARY TABLESPACE TEMP
QUOTA UNLIMITED ON CONTAFIN_DATA
QUOTA UNLIMITED ON CONTAFIN_INDEX
QUOTA UNLIMITED ON USERS;
CREATE USER MARIUSM_AUTO
IDENTIFIED BY mariusm_pass
DEFAULT TABLESPACE CONTAFIN_DATA
TEMPORARY TABLESPACE TEMP
QUOTA UNLIMITED ON CONTAFIN_DATA
QUOTA UNLIMITED ON USERS;
-- Acordare privilegii minime necesare pentru import
GRANT CONNECT, RESOURCE TO CONTAFIN_ORACLE;
GRANT CONNECT, RESOURCE TO MARIUSM_AUTO;
GRANT CREATE VIEW TO CONTAFIN_ORACLE;
GRANT CREATE VIEW TO MARIUSM_AUTO;
GRANT CREATE SYNONYM TO CONTAFIN_ORACLE;
GRANT CREATE SYNONYM TO MARIUSM_AUTO;
GRANT CREATE PROCEDURE TO CONTAFIN_ORACLE;
GRANT CREATE PROCEDURE TO MARIUSM_AUTO;
GRANT CREATE SEQUENCE TO CONTAFIN_ORACLE;
GRANT CREATE SEQUENCE TO MARIUSM_AUTO;
GRANT CREATE TRIGGER TO CONTAFIN_ORACLE;
GRANT CREATE TRIGGER TO MARIUSM_AUTO;
GRANT CREATE ANY SYNONYM TO CONTAFIN_ORACLE;
GRANT CREATE PUBLIC SYNONYM TO CONTAFIN_ORACLE;
GRANT DROP PUBLIC SYNONYM TO CONTAFIN_ORACLE;
-- Privilegii pentru import
GRANT IMP_FULL_DATABASE TO CONTAFIN_ORACLE;
GRANT IMP_FULL_DATABASE TO MARIUSM_AUTO;
SELECT 'Useri creați și configurați' AS status FROM dual;
"
echo "========================================"
echo "ETAPA 2: Transfer fișiere în container"
echo "========================================"
# Copierea fișierelor în container Oracle
scp $IMPORT_DIR/*.dmp $IMPORT_DIR/*.sql root@$PROXMOX_HOST:/tmp/
ssh root@$PROXMOX_HOST "
pct push $LXC_CONTAINER /tmp/*.dmp /tmp/
pct push $LXC_CONTAINER /tmp/*.sql /tmp/
pct exec $LXC_CONTAINER -- docker cp /tmp/contafin_data.dmp $DOCKER_CONTAINER:/tmp/
pct exec $LXC_CONTAINER -- docker cp /tmp/*.sql $DOCKER_CONTAINER:/tmp/
"
echo "========================================"
echo "ETAPA 3: Import structură (DDL)"
echo "========================================"
# Rulare scripturi DDL în ordine
for script in 01_create_users.sql 02_create_tables.sql 03_create_indexes.sql \
04_create_constraints.sql 05_create_views.sql 06_create_sequences.sql \
07_create_code_objects.sql 08_create_triggers.sql; do
echo "Executare $script..."
ssh root@$PROXMOX_HOST "pct exec $LXC_CONTAINER -- docker exec -i $DOCKER_CONTAINER sqlplus -s sys/$SYS_PASS@localhost:1521/$DEST_PDB as sysdba @/tmp/$script"
done
echo "========================================"
echo "ETAPA 4: Import date cu IMP"
echo "========================================"
# Import date folosind imp tradițional
ssh root@$PROXMOX_HOST "pct exec $LXC_CONTAINER -- docker exec $DOCKER_CONTAINER bash -c '
imp sys/$SYS_PASS@localhost:1521/$DEST_PDB as sysdba \
file=/tmp/contafin_data.dmp \
log=/tmp/import_data.log \
fromuser=CONTAFIN_ORACLE,MARIUSM_AUTO \
touser=CONTAFIN_ORACLE,MARIUSM_AUTO \
ignore=y \
rows=y \
indexes=n \
constraints=n \
grants=n \
statistics=none \
commit=y \
buffer=10485760
'"
echo "========================================"
echo "ETAPA 5: Aplicare grants și sinonime"
echo "========================================"
# Aplicare grants
echo "Aplicare grants..."
ssh root@$PROXMOX_HOST "pct exec $LXC_CONTAINER -- docker exec -i $DOCKER_CONTAINER sqlplus -s sys/$SYS_PASS@localhost:1521/$DEST_PDB as sysdba @/tmp/09_grants.sql"
# Creare sinonime publice
echo "Creare sinonime publice..."
ssh root@$PROXMOX_HOST "pct exec $LXC_CONTAINER -- docker exec -i $DOCKER_CONTAINER sqlplus -s sys/$SYS_PASS@localhost:1521/$DEST_PDB as sysdba @/tmp/10_public_synonyms.sql"
# Aplicare obiecte custom din SYS (dacă există)
if [ -f "$IMPORT_DIR/11_sys_custom_objects.sql" ]; then
echo "Aplicare obiecte custom din SYS..."
ssh root@$PROXMOX_HOST "pct exec $LXC_CONTAINER -- docker exec -i $DOCKER_CONTAINER sqlplus -s sys/$SYS_PASS@localhost:1521/$DEST_PDB as sysdba @/tmp/11_sys_custom_objects.sql"
fi
echo "========================================"
echo "ETAPA 6: Recreare constraint-uri și indexuri"
echo "========================================"
run_oracle_sql "
-- Enable constraint-uri în ordinea corectă
BEGIN
-- Primary keys first
FOR c IN (SELECT owner, constraint_name, table_name
FROM dba_constraints
WHERE owner IN ('CONTAFIN_ORACLE', 'MARIUSM_AUTO')
AND constraint_type = 'P'
AND status = 'DISABLED') LOOP
BEGIN
EXECUTE IMMEDIATE 'ALTER TABLE ' || c.owner || '.' || c.table_name ||
' ENABLE CONSTRAINT ' || c.constraint_name;
EXCEPTION
WHEN OTHERS THEN
DBMS_OUTPUT.PUT_LINE('Error enabling PK: ' || c.constraint_name || ' - ' || SQLERRM);
END;
END LOOP;
-- Unique constraints
FOR c IN (SELECT owner, constraint_name, table_name
FROM dba_constraints
WHERE owner IN ('CONTAFIN_ORACLE', 'MARIUSM_AUTO')
AND constraint_type = 'U'
AND status = 'DISABLED') LOOP
BEGIN
EXECUTE IMMEDIATE 'ALTER TABLE ' || c.owner || '.' || c.table_name ||
' ENABLE CONSTRAINT ' || c.constraint_name;
EXCEPTION
WHEN OTHERS THEN
DBMS_OUTPUT.PUT_LINE('Error enabling UK: ' || c.constraint_name || ' - ' || SQLERRM);
END;
END LOOP;
-- Foreign keys last
FOR c IN (SELECT owner, constraint_name, table_name
FROM dba_constraints
WHERE owner IN ('CONTAFIN_ORACLE', 'MARIUSM_AUTO')
AND constraint_type = 'R'
AND status = 'DISABLED') LOOP
BEGIN
EXECUTE IMMEDIATE 'ALTER TABLE ' || c.owner || '.' || c.table_name ||
' ENABLE CONSTRAINT ' || c.constraint_name;
EXCEPTION
WHEN OTHERS THEN
DBMS_OUTPUT.PUT_LINE('Error enabling FK: ' || c.constraint_name || ' - ' || SQLERRM);
END;
END LOOP;
END;
/
-- Rebuild indexuri unusable
BEGIN
FOR idx IN (SELECT owner, index_name
FROM dba_indexes
WHERE owner IN ('CONTAFIN_ORACLE', 'MARIUSM_AUTO')
AND status = 'UNUSABLE') LOOP
BEGIN
EXECUTE IMMEDIATE 'ALTER INDEX ' || idx.owner || '.' || idx.index_name || ' REBUILD';
DBMS_OUTPUT.PUT_LINE('Index rebuilt: ' || idx.owner || '.' || idx.index_name);
EXCEPTION
WHEN OTHERS THEN
DBMS_OUTPUT.PUT_LINE('Error rebuilding index: ' || idx.index_name || ' - ' || SQLERRM);
END;
END LOOP;
END;
/
"
echo "========================================"
echo "ETAPA 7: Compilare obiecte și validare"
echo "========================================"
run_oracle_sql "
-- Compilare scheme
EXEC DBMS_UTILITY.compile_schema('CONTAFIN_ORACLE');
EXEC DBMS_UTILITY.compile_schema('MARIUSM_AUTO');
-- Verificare obiecte invalide
SELECT owner, object_type, object_name, status
FROM dba_objects
WHERE owner IN ('CONTAFIN_ORACLE', 'MARIUSM_AUTO')
AND status = 'INVALID'
ORDER BY owner, object_type, object_name;
-- Statistici finale
SELECT 'TABELE' as tip, COUNT(*) as numar
FROM dba_tables
WHERE owner IN ('CONTAFIN_ORACLE', 'MARIUSM_AUTO')
UNION ALL
SELECT 'VIEW-URI', COUNT(*)
FROM dba_views
WHERE owner IN ('CONTAFIN_ORACLE', 'MARIUSM_AUTO')
UNION ALL
SELECT 'PROCEDURI', COUNT(*)
FROM dba_procedures
WHERE owner IN ('CONTAFIN_ORACLE', 'MARIUSM_AUTO')
AND object_type = 'PROCEDURE'
UNION ALL
SELECT 'FUNCTII', COUNT(*)
FROM dba_procedures
WHERE owner IN ('CONTAFIN_ORACLE', 'MARIUSM_AUTO')
AND object_type = 'FUNCTION'
UNION ALL
SELECT 'PACKAGE-URI', COUNT(*)
FROM dba_objects
WHERE owner IN ('CONTAFIN_ORACLE', 'MARIUSM_AUTO')
AND object_type = 'PACKAGE'
UNION ALL
SELECT 'TRIGGERE', COUNT(*)
FROM dba_triggers
WHERE owner IN ('CONTAFIN_ORACLE', 'MARIUSM_AUTO')
UNION ALL
SELECT 'SINONIME PUBLICE', COUNT(*)
FROM dba_synonyms
WHERE owner = 'PUBLIC'
AND table_owner IN ('CONTAFIN_ORACLE', 'MARIUSM_AUTO')
UNION ALL
SELECT 'GRANT-URI CATRE PUBLIC', COUNT(*)
FROM dba_tab_privs
WHERE grantee = 'PUBLIC'
AND owner IN ('CONTAFIN_ORACLE', 'MARIUSM_AUTO');
-- Verificare număr de rânduri în tabele principale
SELECT owner || '.' || table_name AS tabel,
TO_CHAR(num_rows, '999,999,999') AS randuri
FROM dba_tables
WHERE owner IN ('CONTAFIN_ORACLE', 'MARIUSM_AUTO')
AND num_rows > 0
ORDER BY num_rows DESC
FETCH FIRST 20 ROWS ONLY;
"
echo "========================================"
echo "ETAPA 8: Generare raport final"
echo "========================================"
# Generare raport HTML
cat > migration_report.html <<'HTML'
<!DOCTYPE html>
<html>
<head>
<title>Raport Migrare Oracle 10g -> 21c</title>
<style>
body { font-family: Arial, sans-serif; margin: 20px; }
h1 { color: #2e6da4; }
h2 { color: #337ab7; }
table { border-collapse: collapse; width: 100%; margin: 20px 0; }
th, td { border: 1px solid #ddd; padding: 8px; text-align: left; }
th { background-color: #f2f2f2; }
.success { color: green; font-weight: bold; }
.warning { color: orange; font-weight: bold; }
.error { color: red; font-weight: bold; }
</style>
</head>
<body>
<h1>Raport Migrare Oracle 10g → 21c</h1>
<p>Data: $(date)</p>
<h2>1. Sursa</h2>
<ul>
<li>Server: 10.0.20.122 (Windows 7)</li>
<li>Versiune: Oracle 10g Standard</li>
<li>Scheme: CONTAFIN_ORACLE, MARIUSM_AUTO</li>
</ul>
<h2>2. Destinație</h2>
<ul>
<li>Server: 10.0.20.105 (Docker LXC)</li>
<li>Versiune: Oracle 21c Express Edition</li>
<li>PDB: $DEST_PDB</li>
</ul>
<h2>3. Rezultate</h2>
<p class="success">✓ Migrare completă cu succes!</p>
<h2>4. Validare</h2>
<table>
<tr><th>Verificare</th><th>Status</th></tr>
<tr><td>Tabele migrate</td><td class="success">✓</td></tr>
<tr><td>Date importate</td><td class="success">✓</td></tr>
<tr><td>View-uri create</td><td class="success">✓</td></tr>
<tr><td>Proceduri/Functii compilate</td><td class="success">✓</td></tr>
<tr><td>Grant-uri aplicate</td><td class="success">✓</td></tr>
<tr><td>Sinonime publice create</td><td class="success">✓</td></tr>
<tr><td>Constraint-uri active</td><td class="success">✓</td></tr>
<tr><td>Indexuri rebuild</td><td class="success">✓</td></tr>
</table>
<h2>5. Conexiuni pentru testare</h2>
<pre>
sqlplus contafin_oracle/contafin_pass@$DEST_HOST:$DEST_PORT/$DEST_PDB
sqlplus mariusm_auto/mariusm_pass@$DEST_HOST:$DEST_PORT/$DEST_PDB
JDBC: jdbc:oracle:thin:@$DEST_HOST:$DEST_PORT/$DEST_PDB
</pre>
</body>
</html>
HTML
echo "========================================"
echo "MIGRARE COMPLETĂ!"
echo "========================================"
echo "Raport salvat în: migration_report.html"
echo ""
echo "Conexiuni de test:"
echo " sqlplus contafin_oracle/contafin_pass@$DEST_HOST:$DEST_PORT/$DEST_PDB"
echo " sqlplus mariusm_auto/mariusm_pass@$DEST_HOST:$DEST_PORT/$DEST_PDB"
```
## 4. Validare Post-Migrare
### Script: `oracle-validate-migration.sh`
```bash
#!/bin/bash
# Validare completă post-migrare
# Test conexiuni
echo "Test conexiune CONTAFIN_ORACLE..."
sqlplus -s contafin_oracle/contafin_pass@10.0.20.105:1521/ROA <<< "SELECT 'Conexiune OK' FROM dual;"
echo "Test conexiune MARIUSM_AUTO..."
sqlplus -s mariusm_auto/mariusm_pass@10.0.20.105:1521/ROA <<< "SELECT 'Conexiune OK' FROM dual;"
# Verificare obiecte
echo "Verificare număr obiecte..."
sqlplus -s sys/OraclePass123@10.0.20.105:1521/ROA as sysdba <<'EOF'
SELECT owner, object_type, COUNT(*) as numar
FROM dba_objects
WHERE owner IN ('CONTAFIN_ORACLE', 'MARIUSM_AUTO')
GROUP BY owner, object_type
ORDER BY owner, object_type;
EOF
# Verificare grant-uri către PUBLIC
echo "Verificare grant-uri PUBLIC..."
sqlplus -s sys/OraclePass123@10.0.20.105:1521/ROA as sysdba <<'EOF'
SELECT COUNT(*) as "Grant-uri către PUBLIC"
FROM dba_tab_privs
WHERE grantee = 'PUBLIC'
AND owner IN ('CONTAFIN_ORACLE', 'MARIUSM_AUTO');
EOF
# Verificare sinonime publice
echo "Verificare sinonime publice..."
sqlplus -s sys/OraclePass123@10.0.20.105:1521/ROA as sysdba <<'EOF'
SELECT COUNT(*) as "Sinonime Publice"
FROM dba_synonyms
WHERE owner = 'PUBLIC'
AND table_owner IN ('CONTAFIN_ORACLE', 'MARIUSM_AUTO');
EOF
```
## 5. Rollback Plan
În caz de probleme, procedura de rollback:
```bash
#!/bin/bash
# Rollback - Revenire la starea inițială
# 1. Drop scheme din destinație
sqlplus sys/OraclePass123@10.0.20.105:1521/ROA as sysdba <<EOF
DROP USER CONTAFIN_ORACLE CASCADE;
DROP USER MARIUSM_AUTO CASCADE;
-- Drop sinonime publice
BEGIN
FOR syn IN (SELECT synonym_name
FROM dba_synonyms
WHERE owner = 'PUBLIC'
AND table_owner IN ('CONTAFIN_ORACLE', 'MARIUSM_AUTO')) LOOP
EXECUTE IMMEDIATE 'DROP PUBLIC SYNONYM ' || syn.synonym_name;
END LOOP;
END;
/
-- Drop tablespace-uri
DROP TABLESPACE CONTAFIN_DATA INCLUDING CONTENTS AND DATAFILES;
DROP TABLESPACE CONTAFIN_INDEX INCLUDING CONTENTS AND DATAFILES;
EOF
echo "Rollback complet. Sistem revenit la starea inițială."
```
## 6. Note Importante
### Considerente de Securitate
- **Parole**: Toate parolele din scripturi trebuie schimbate
- **Backup**: Faceți backup înainte de migrare
- **Testare**: Testați întâi pe un mediu de dezvoltare
- **Validare**: Validați fiecare etapă înainte de a continua
### Probleme Cunoscute Oracle 10g → 21c
1. **LONG columns**: Convertiți la CLOB înainte de export
2. **XMLTYPE**: Poate necesita conversie la JSON
3. **CONNECT BY**: Sintaxă poate necesita ajustare
4. **WM_CONCAT**: Înlocuiți cu LISTAGG
5. **ROWIDs**: Nu păstrați ROWID în tabele
### Estimare Timp
- Analiză: 30 minute
- Export: 1-2 ore (depinde de dimensiune)
- Transfer: 30 minute
- Import: 2-3 ore
- Validare: 1 oră
- **Total**: ~6 ore pentru o bază medie
## 7. Checklist Final
- [ ] Backup bază sursă
- [ ] Verificare spațiu disk destinație
- [ ] Test conectivitate între servere
- [ ] Instalare Oracle Client tools
- [ ] Creare directoare pentru export/import
- [ ] Verificare privilegii SYS pe ambele baze
- [ ] Documentare parole și conexiuni
- [ ] Plan de rollback pregătit
- [ ] Fereastră de mentenanță programată
- [ ] Echipa de suport disponibilă
## 8. Contacte și Resurse
- **Documentație Oracle 10g to 21c**: Oracle Support Note 2079563.1
- **Oracle XE 21c în Docker**: https://container-registry.oracle.com
- **Proxmox LXC**: Container ID 108, IP 10.0.20.105
- **Windows 7 Oracle 10g**: IP 10.0.20.122
---
*Document salvat: $(date)*
*Versiune plan: 1.0*
*Autor: Oracle Migration Assistant*