|
| 1 | +#!/usr/bin/env bash |
| 2 | +set -Eeuo pipefail |
| 3 | + |
| 4 | +# Config |
| 5 | +ORACLE_CONTAINER="${ORACLE_CONTAINER:-oracle-free}" |
| 6 | +ORACLE_IMAGE="${ORACLE_IMAGE:-container-registry.oracle.com/database/free:latest-lite}" |
| 7 | +ORACLE_PORT="${ORACLE_PORT:-1521}" |
| 8 | +ORACLE_PWD="${ORACLE_PWD:?export ORACLE_PWD for SYS}" |
| 9 | +ORACLE_SID="${ORACLE_SID:-FREEPDB1}" |
| 10 | + |
| 11 | +# Dependencies |
| 12 | +command -v docker >/dev/null || { echo "Docker not installed" >&2; exit 2; } |
| 13 | + |
| 14 | +# Image present? |
| 15 | +docker image inspect "${ORACLE_IMAGE}" >/dev/null 2>&1 || docker pull "${ORACLE_IMAGE}" |
| 16 | + |
| 17 | +# Start container if needed |
| 18 | +if docker ps --format '{{.Names}}' | grep -qx "${ORACLE_CONTAINER}"; then |
| 19 | + : |
| 20 | +elif docker ps -a --format '{{.Names}}' | grep -qx "${ORACLE_CONTAINER}"; then |
| 21 | + docker start "${ORACLE_CONTAINER}" >/dev/null |
| 22 | +else |
| 23 | + docker run --name "${ORACLE_CONTAINER}" \ |
| 24 | + -p "${ORACLE_PORT}:1521" \ |
| 25 | + -e ORACLE_PWD="${ORACLE_PWD}" \ |
| 26 | + -d "${ORACLE_IMAGE}" >/dev/null |
| 27 | + echo "Starting Oracle container..." |
| 28 | +fi |
| 29 | + |
| 30 | +echo "Waiting up to 5 minutes for Oracle to be healthy..." |
| 31 | +MAX_WAIT=300; WAIT_INTERVAL=5; waited=0 |
| 32 | +while :; do |
| 33 | + state="$(docker inspect -f '{{.State.Health.Status}}' "${ORACLE_CONTAINER}" 2>/dev/null || true)" |
| 34 | + echo "health=${state:-unknown} waited=${waited}s" |
| 35 | + [[ "$state" == "healthy" ]] && break |
| 36 | + (( waited >= MAX_WAIT )) && { echo "ERROR: Oracle not healthy in 300s" >&2; exit 1; } |
| 37 | + sleep "$WAIT_INTERVAL"; waited=$((waited + WAIT_INTERVAL)) |
| 38 | +done |
| 39 | +echo "Oracle is fully started." |
| 40 | + |
| 41 | +# SQL bootstrap as SYSDBA, target SYSTEM schema |
| 42 | +docker exec -i "${ORACLE_CONTAINER}" bash -lc \ |
| 43 | +"sqlplus -L -s 'sys/${ORACLE_PWD}@localhost:${ORACLE_PORT}/${ORACLE_SID} as sysdba'" <<'SQL' |
| 44 | +WHENEVER SQLERROR EXIT SQL.SQLCODE |
| 45 | +SET ECHO ON FEEDBACK ON PAGESIZE 200 LINESIZE 32767 SERVEROUTPUT ON |
| 46 | +
|
| 47 | +-- reconcile queries executes DBMS_CRYPTO |
| 48 | +GRANT EXECUTE ON DBMS_CRYPTO TO SYSTEM; |
| 49 | +
|
| 50 | +-- work in SYSTEM, not SYS |
| 51 | +ALTER SESSION SET CURRENT_SCHEMA=SYSTEM; |
| 52 | +
|
| 53 | +-- create table if not exists (guard ORA-00955) |
| 54 | +BEGIN |
| 55 | + EXECUTE IMMEDIATE q'[ |
| 56 | + CREATE TABLE SOURCE_TABLE ( |
| 57 | + ID NUMBER(15,0), |
| 58 | + DESCR CHAR(30 CHAR), |
| 59 | + YEAR NUMBER(4,0), |
| 60 | + DATEE DATE, |
| 61 | + CONSTRAINT PK_SOURCE_TABLE PRIMARY KEY (ID) |
| 62 | + ) |
| 63 | + ]'; |
| 64 | +EXCEPTION |
| 65 | + WHEN OTHERS THEN |
| 66 | + IF SQLCODE != -955 THEN RAISE; END IF; |
| 67 | +END; |
| 68 | +/ |
| 69 | +
|
| 70 | +-- truncate if exists |
| 71 | +DECLARE n INTEGER; |
| 72 | +BEGIN |
| 73 | + SELECT COUNT(*) INTO n FROM USER_TABLES WHERE TABLE_NAME='SOURCE_TABLE'; |
| 74 | + IF n=1 THEN EXECUTE IMMEDIATE 'TRUNCATE TABLE SOURCE_TABLE'; END IF; |
| 75 | +END; |
| 76 | +/ |
| 77 | +
|
| 78 | +-- idempotent load |
| 79 | +MERGE INTO SOURCE_TABLE t |
| 80 | +USING ( |
| 81 | + SELECT 1001 ID, 'Cycle 1' DESCR, 2025 YEAR, DATE '2025-01-01' DATEE FROM DUAL UNION ALL |
| 82 | + SELECT 1002, 'Cycle 2', 2025, DATE '2025-02-01' FROM DUAL UNION ALL |
| 83 | + SELECT 1003, 'Cycle 3', 2025, DATE '2025-03-01' FROM DUAL UNION ALL |
| 84 | + SELECT 1004, 'Cycle 4', 2025, DATE '2025-04-15' FROM DUAL UNION ALL |
| 85 | + SELECT 1005, 'Cycle 5', 2025, DATE '2025-05-01' FROM DUAL |
| 86 | +) s |
| 87 | +ON (t.ID = s.ID) |
| 88 | +WHEN MATCHED THEN UPDATE SET t.DESCR = RPAD(s.DESCR,30), t.YEAR = s.YEAR, t.DATEE = s.DATEE |
| 89 | +WHEN NOT MATCHED THEN INSERT (ID, DESCR, YEAR, DATEE) |
| 90 | + VALUES (s.ID, RPAD(s.DESCR,30), s.YEAR, s.DATEE); |
| 91 | +
|
| 92 | +COMMIT; |
| 93 | +SQL |
| 94 | + |
| 95 | +echo "Oracle DDL/DML completed." |
0 commit comments