Files
ROMFASTSQL/proxmox/lxc108-oracle/roa-windows-setup/sql/sys-objects.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

953 lines
34 KiB
MySQL

-- ============================================================================
-- SYS CUSTOM OBJECTS FOR ROA APPLICATION
-- ============================================================================
-- Oracle 21c/18c Compatible Version
-- Updated: January 2026
--
-- This file contains all custom SYS objects required by the ROA application:
-- - Tables: AUTH_DETALII, AUTH_SERII, INFO
-- - View: VAUTH_SERII
-- - Sequence: SEQ_AUTH_SERII
-- - Package: AUTH_PACK (uses DBMS_CRYPTO for Oracle 21c compatibility)
-- - Procedures: EXECUTESCRIPTOS, NEWSCHEMA, NEWSCHEMAJOB, UPDATESQLPLUS, pINFO
--
-- IMPORTANT: Run this script as SYS with SYSDBA privileges
--
-- Usage:
-- sqlplus sys/password@service as sysdba @sys-objects.sql
--
-- ============================================================================
SET SERVEROUTPUT ON
SET FEEDBACK ON
WHENEVER SQLERROR CONTINUE
PROMPT
PROMPT ========================================
PROMPT Installing SYS Custom Objects
PROMPT ========================================
PROMPT
-- ============================================================================
-- SECTION 1: TABLES
-- ============================================================================
PROMPT [1/11] Creating SYS.AUTH_DETALII table...
DECLARE
v_count NUMBER;
BEGIN
SELECT COUNT(*) INTO v_count FROM dba_tables
WHERE owner = 'SYS' AND table_name = 'AUTH_DETALII';
IF v_count > 0 THEN
DBMS_OUTPUT.PUT_LINE(' Table AUTH_DETALII already exists, skipping.');
ELSE
EXECUTE IMMEDIATE '
CREATE TABLE SYS.AUTH_DETALII (
DETALII VARCHAR2(15) NOT NULL
) TABLESPACE SYSTEM';
DBMS_OUTPUT.PUT_LINE(' Table AUTH_DETALII created.');
END IF;
END;
/
PROMPT [2/11] Creating SYS.AUTH_SERII table...
DECLARE
v_count NUMBER;
BEGIN
SELECT COUNT(*) INTO v_count FROM dba_tables
WHERE owner = 'SYS' AND table_name = 'AUTH_SERII';
IF v_count > 0 THEN
DBMS_OUTPUT.PUT_LINE(' Table AUTH_SERII already exists, skipping.');
ELSE
EXECUTE IMMEDIATE '
CREATE TABLE SYS.AUTH_SERII (
ID_SERIE NUMBER(5,0) NOT NULL,
ID_PROGRAM NUMBER(5,0) NOT NULL,
SERIE RAW(128) NOT NULL,
STERS NUMBER(1,0) DEFAULT 0 NOT NULL,
DATAORA DATE DEFAULT SYSDATE NOT NULL,
ID_UTIL NUMBER(5,0) NOT NULL,
DATAORAS DATE,
ID_UTILS NUMBER(5,0),
CONSTRAINT PK_AUTH_SERII PRIMARY KEY (ID_SERIE)
) TABLESPACE SYSTEM';
DBMS_OUTPUT.PUT_LINE(' Table AUTH_SERII created.');
END IF;
END;
/
PROMPT [3/11] Creating SYS.INFO table (logging)...
DECLARE
v_count NUMBER;
BEGIN
SELECT COUNT(*) INTO v_count FROM dba_tables
WHERE owner = 'SYS' AND table_name = 'INFO';
IF v_count > 0 THEN
DBMS_OUTPUT.PUT_LINE(' Table INFO already exists, skipping.');
ELSE
EXECUTE IMMEDIATE '
CREATE TABLE SYS.INFO (
INFO CLOB,
DATAORA TIMESTAMP(6) DEFAULT SYSTIMESTAMP,
LOCATIA VARCHAR2(200) NULL
) TABLESPACE SYSTEM';
DBMS_OUTPUT.PUT_LINE(' Table INFO created.');
END IF;
END;
/
-- ============================================================================
-- SECTION 2: SEQUENCE
-- ============================================================================
PROMPT [4/11] Creating SYS.SEQ_AUTH_SERII sequence...
DECLARE
v_count NUMBER;
BEGIN
SELECT COUNT(*) INTO v_count FROM dba_sequences
WHERE sequence_owner = 'SYS' AND sequence_name = 'SEQ_AUTH_SERII';
IF v_count > 0 THEN
DBMS_OUTPUT.PUT_LINE(' Sequence SEQ_AUTH_SERII already exists, skipping.');
ELSE
EXECUTE IMMEDIATE '
CREATE SEQUENCE SYS.SEQ_AUTH_SERII
MINVALUE 1
MAXVALUE 99999
INCREMENT BY 1
START WITH 1
NOCACHE
NOORDER
NOCYCLE';
DBMS_OUTPUT.PUT_LINE(' Sequence SEQ_AUTH_SERII created.');
END IF;
END;
/
-- ============================================================================
-- SECTION 3: LOGGING PROCEDURE (pINFO)
-- ============================================================================
PROMPT [5/11] Creating SYS.pINFO procedure (logging)...
CREATE OR REPLACE PROCEDURE SYS.pINFO(
p_info IN CLOB,
p_locatia IN VARCHAR2 DEFAULT NULL
) IS
PRAGMA AUTONOMOUS_TRANSACTION;
BEGIN
INSERT INTO SYS.INFO (INFO, DATAORA, LOCATIA)
VALUES (p_info, SYSTIMESTAMP, p_locatia);
COMMIT;
EXCEPTION
WHEN OTHERS THEN
-- Silently fail to avoid breaking caller
ROLLBACK;
END pINFO;
/
-- ============================================================================
-- SECTION 4: AUTH_PACK PACKAGE (Oracle 21c compatible with DBMS_CRYPTO)
-- ============================================================================
PROMPT [6/11] Creating SYS.AUTH_PACK package specification...
CREATE OR REPLACE PACKAGE SYS.AUTH_PACK IS
-- ========================================================================
-- AUTH_PACK - License and Authentication Management
-- ========================================================================
-- Author : MARIUS.ATANASIU
-- Created : 11/5/2005
-- Updated : 2026-01-14 - Migrated to Oracle 21c with DBMS_CRYPTO
--
-- Purpose:
-- Manages ROA application licensing, including:
-- - Program license verification on login
-- - User count verification per program
-- - License expiration checks
-- - Company count limits
-- ========================================================================
PROCEDURE verifica_program;
PROCEDURE verifica_licenta(v_sid IN NUMBER, v_program IN VARCHAR2);
PROCEDURE verifica_licenta_luna(
v_an IN NUMBER,
v_luna IN NUMBER,
v_tip IN NUMBER
);
PROCEDURE verifica_numar_firme;
PROCEDURE adauga_serie(
V_ID_PROGRAM IN NUMBER,
V_SERIE IN VARCHAR2,
V_ID_UTILAD IN NUMBER
);
PROCEDURE sterge_serie(V_ID_PROGRAM IN NUMBER, V_ID_UTILS IN NUMBER);
PROCEDURE verifica_serie(V_ID_PROGRAM IN NUMBER, V_SERIE IN RAW);
FUNCTION selecteaza_serie(V_ID_PROGRAM IN NUMBER) RETURN VARCHAR2;
FUNCTION selecteaza_nr_util(V_ID_PROGRAM IN NUMBER) RETURN NUMBER;
FUNCTION selecteaza_data_val(V_ID_PROGRAM IN NUMBER) RETURN DATE;
FUNCTION decripteaza_serie(
V_ID_PROGRAM IN NUMBER,
V_SERIE IN RAW,
V_DATAORA IN DATE
) RETURN VARCHAR2;
FUNCTION decripteaza_nr_util(V_SERIEC IN VARCHAR2) RETURN NUMBER;
FUNCTION decripteaza_data_val(
V_SERIEC IN VARCHAR2,
V_ZI IN VARCHAR2
) RETURN DATE;
FUNCTION hextodec(V_HEXA IN VARCHAR2) RETURN NUMBER;
FUNCTION dectohex(V_NUMAR IN NUMBER) RETURN VARCHAR2;
END AUTH_PACK;
/
PROMPT [7/11] Creating SYS.AUTH_PACK package body...
CREATE OR REPLACE PACKAGE BODY SYS.AUTH_PACK IS
-- ========================================================================
-- MODIFICATION HISTORY:
-- 2026-01-14: Migration Oracle 10g -> Oracle 21c
-- - Replaced DBMS_OBFUSCATION_TOOLKIT.DES3Decrypt with DBMS_CRYPTO.DECRYPT
-- - Using ENCRYPT_3DES_2KEY (16-byte key) + CHAIN_CBC + PAD_ZERO
-- - Added PINFO logging calls for debugging
-- ========================================================================
---------------------------------------------------------------------------
-- VERIFICA_PROGRAM
-- Called on database login (via LOGON trigger) to verify license
---------------------------------------------------------------------------
PROCEDURE verifica_program IS
v_program VARCHAR2(256);
v_modul VARCHAR2(256);
v_sid NUMBER(16);
BEGIN
BEGIN
SELECT sid, UPPER(TRIM(program)), UPPER(TRIM(module))
INTO v_sid, v_program, v_modul
FROM v$session
WHERE audsid = USERENV('SESSIONID')
AND audsid != 0
AND ROWNUM = 1
AND STATUS <> 'KILLED';
PINFO('1 LOGIN ' || V_PROGRAM || ' USER ' || USER, 'SYS.AUTH');
IF v_program NOT IN (
'ROASTART.EXE',
'PLSQLDEV.EXE',
'ROAGEN.EXE',
'ROASUPORT.EXE',
'EXPDP.EXE',
'IMPDP.EXE',
'APSNET_WP.EXE',
'W3WP.EXE',
'RUBY.EXE',
'SQLPLUS.EXE',
'TASKS.EXE',
'VFP9.EXE',
'ROAEFACTURA.EXE',
'WEBDEV.WEBSERVER.EXE',
'ROA2COCACOLA.EXE',
'GENERARESCRIPT.EXE',
'ROAACTUALIZARI.EXE',
'EXP.EXE',
'IMP.EXE'
) AND USER NOT IN (
'SYS',
'SYSTEM',
'DBSNMP',
'CTXSYS',
'MDSYS',
'DIP',
'SYSMAN',
'WMSYS'
) THEN
PINFO('2 LOGIN ' || V_PROGRAM || ' USER ' || USER, 'SYS.AUTH');
IF v_program <> v_modul THEN
RAISE_APPLICATION_ERROR(-20000, 'Acces interzis!');
END IF;
PINFO('3 LOGIN ' || V_PROGRAM || ' USER ' || USER, 'SYS.AUTH');
IF NOT V_PROGRAM LIKE 'ORACLE%' THEN
auth_pack.verifica_licenta(v_sid, v_program);
END IF;
PINFO('4 LOGIN ' || V_PROGRAM || ' USER ' || USER, 'SYS.AUTH');
END IF;
EXCEPTION
WHEN NO_DATA_FOUND THEN
v_program := NULL;
END;
END verifica_program;
---------------------------------------------------------------------------
-- VERIFICA_LICENTA
-- Verifies license exists for program and checks user count by IP
---------------------------------------------------------------------------
PROCEDURE verifica_licenta(v_sid IN NUMBER, v_program IN VARCHAR2) IS
v_serie VARCHAR2(256);
v_seriec VARCHAR2(256);
v_nr_util NUMBER(5);
v_utilizatori NUMBER(5);
v_nume_program SYN_NOM_PROGRAME.DENUMIRE%TYPE;
v_id_program CONTAFIN_ORACLE.NOM_PROGRAME.ID_PROGRAM%TYPE;
v_dataora DATE;
v_data_val DATE;
v_zi VARCHAR2(2);
BEGIN
V_NUME_PROGRAM := TRIM(REPLACE(v_program, '.EXE'));
BEGIN
SELECT A.ID_PROGRAM, B.SERIE, B.DATAORA
INTO V_ID_PROGRAM, V_SERIE, V_DATAORA
FROM SYN_NOM_PROGRAME A
LEFT JOIN AUTH_SERII B ON A.ID_PROGRAM = B.ID_PROGRAM
WHERE UPPER(TRIM(A.DENUMIRE)) = V_NUME_PROGRAM
AND B.STERS = 0;
EXCEPTION
WHEN NO_DATA_FOUND THEN
PINFO('1 LOGIN ' || V_PROGRAM || ' USER ' || USER, 'SYS.AUTH2');
RAISE_APPLICATION_ERROR(-20000,
'Nu aveti licenta pentru ' || V_NUME_PROGRAM || '!' ||
CHR(13) || CHR(10) ||
' Licenta poate fi introdusa prin programul ROASUPORT!');
END;
PINFO('2 LOGIN ' || V_PROGRAM || ' USER ' || USER, 'SYS.AUTH2');
v_zi := LPAD(EXTRACT(DAY FROM v_dataora), 2, '0');
v_seriec := auth_pack.decripteaza_serie(v_id_program, v_serie, v_dataora);
v_utilizatori := auth_pack.decripteaza_nr_util(v_seriec);
v_data_val := auth_pack.decripteaza_data_val(v_seriec, v_zi);
IF v_utilizatori > 0 THEN
-- Count distinct IPs (client_info) connected with same program
-- excluding current session's IP
SELECT COUNT(DISTINCT client_info)
INTO v_nr_util
FROM v$session
WHERE UPPER(TRIM(PROGRAM)) = v_program
AND SID != v_sid
AND STATUS <> 'KILLED'
AND NVL(client_info, 'x') <> SYS_CONTEXT('userenv', 'ip_address');
IF v_nr_util >= v_utilizatori THEN
RAISE_APPLICATION_ERROR(-20000,
'Ati depasit numarul de licente (' || v_utilizatori ||
') pentru programul ' || v_nume_program || ' !' ||
CHR(13) || CHR(10) ||
' Licenta poate fi reinnoita prin programul ROASUPORT!');
END IF;
ELSE
RAISE_APPLICATION_ERROR(-20000,
'Seria introdusa pentru acest program nu este corecta!' ||
CHR(13) || CHR(10) ||
' Licenta poate fi modificata prin programul ROASUPORT!');
END IF;
PINFO('3 LOGIN ' || V_PROGRAM || ' USER ' || USER, 'SYS.AUTH2');
END verifica_licenta;
---------------------------------------------------------------------------
-- VERIFICA_LICENTA_LUNA
-- Verifies license for opening a new month (triggered on CALENDAR insert)
---------------------------------------------------------------------------
PROCEDURE verifica_licenta_luna(
v_an IN NUMBER,
v_luna IN NUMBER,
v_tip IN NUMBER
) IS
v_serie VARCHAR2(256);
v_seriec VARCHAR2(256);
v_nume_program1 SYN_NOM_PROGRAME.DENUMIRE%TYPE := 'ROASTART';
v_nume_program2 SYN_NOM_PROGRAME.DENUMIRE%TYPE := 'ROASAL';
v_id_program CONTAFIN_ORACLE.NOM_PROGRAME.ID_PROGRAM%TYPE;
v_dataora DATE;
v_data_val DATE;
v_zi VARCHAR2(2);
BEGIN
BEGIN
SELECT A.ID_PROGRAM, B.SERIE, B.DATAORA
INTO V_ID_PROGRAM, V_SERIE, V_DATAORA
FROM SYN_NOM_PROGRAME A
LEFT JOIN AUTH_SERII B ON A.ID_PROGRAM = B.ID_PROGRAM
WHERE UPPER(TRIM(A.DENUMIRE)) =
DECODE(V_TIP, 1, V_NUME_PROGRAM1, 2, V_NUME_PROGRAM2, 'XYZ')
AND B.STERS = 0;
EXCEPTION
WHEN NO_DATA_FOUND THEN
RAISE_APPLICATION_ERROR(-20000,
'Nu aveti licenta pentru deschiderea de luna noua!' ||
CHR(13) || CHR(10) ||
' Licenta poate fi introdusa prin programul ROASUPORT!');
END;
v_zi := LPAD(EXTRACT(DAY FROM v_dataora), 2, '0');
v_seriec := auth_pack.decripteaza_serie(v_id_program, v_serie, v_dataora);
v_data_val := auth_pack.decripteaza_data_val(v_seriec, v_zi);
IF v_data_val < TO_DATE(v_an || v_luna, 'YYYYMM') THEN
RAISE_APPLICATION_ERROR(-20000,
'Licenta pentru acest program a expirat!' ||
CHR(13) || CHR(10) ||
' Licenta poate fi reinnoita prin programul ROASUPORT!');
END IF;
END verifica_licenta_luna;
---------------------------------------------------------------------------
-- VERIFICA_NUMAR_FIRME
-- Verifies company count doesn't exceed license limit
---------------------------------------------------------------------------
PROCEDURE verifica_numar_firme IS
v_serie VARCHAR2(256);
v_seriec VARCHAR2(256);
v_nume_program SYN_NOM_PROGRAME.DENUMIRE%TYPE := 'ROASTART';
v_id_program CONTAFIN_ORACLE.NOM_PROGRAME.ID_PROGRAM%TYPE;
v_dataora DATE;
V_NR_MAX_FIRME NUMBER(10) := 0;
V_NR_FIRME NUMBER(10) := 0;
BEGIN
BEGIN
SELECT A.ID_PROGRAM, B.SERIE, B.DATAORA
INTO V_ID_PROGRAM, V_SERIE, V_DATAORA
FROM SYN_NOM_PROGRAME A
LEFT JOIN AUTH_SERII B ON A.ID_PROGRAM = B.ID_PROGRAM
WHERE UPPER(TRIM(A.DENUMIRE)) = V_NUME_PROGRAM
AND B.STERS = 0;
EXCEPTION
WHEN NO_DATA_FOUND THEN
RAISE_APPLICATION_ERROR(-20000,
'Nu aveti licenta pentru deschiderea unei firme noi!' ||
CHR(13) || CHR(10) ||
' Licenta poate fi introdusa prin programul ROASUPORT!');
END;
v_seriec := auth_pack.decripteaza_serie(v_id_program, v_serie, v_dataora);
V_NR_MAX_FIRME := auth_pack.decripteaza_nr_util(V_SERIEC);
SELECT COUNT(*)
INTO V_NR_FIRME
FROM SYN_NOM_FIRME
WHERE STERS = 0
AND NVL(ID_MAMA, 0) = 0;
IF V_NR_FIRME >= V_NR_MAX_FIRME THEN
RAISE_APPLICATION_ERROR(-20000,
'Aveti licenta pentru maxim ' || V_NR_MAX_FIRME ||
' firme (' || V_NR_FIRME || ' firme deja definite)!' ||
CHR(13) || CHR(10) ||
' Licenta poate fi introdusa prin programul ROASUPORT!');
END IF;
END verifica_numar_firme;
---------------------------------------------------------------------------
-- ADAUGA_SERIE
-- Adds a new license serial number for a program
---------------------------------------------------------------------------
PROCEDURE adauga_serie(
V_ID_PROGRAM IN NUMBER,
V_SERIE IN VARCHAR2,
V_ID_UTILAD IN NUMBER
) IS
V_ID_SERIE AUTH_SERII.ID_SERIE%TYPE;
V_SERIER AUTH_SERII.SERIE%TYPE;
eroare_de_conversie EXCEPTION;
PRAGMA EXCEPTION_INIT(eroare_de_conversie, -6502);
BEGIN
BEGIN
V_SERIER := HEXTORAW(V_SERIE);
EXCEPTION
WHEN eroare_de_conversie THEN
RAISE_APPLICATION_ERROR(-20000, 'Aceasta serie nu este valida!');
END;
auth_pack.verifica_serie(V_ID_PROGRAM, V_SERIER);
SELECT SEQ_AUTH_SERII.NEXTVAL INTO V_ID_SERIE FROM DUAL;
INSERT INTO AUTH_SERII (ID_SERIE, ID_PROGRAM, SERIE, ID_UTIL)
VALUES (V_ID_SERIE, V_ID_PROGRAM, V_SERIER, V_ID_UTILAD);
END adauga_serie;
---------------------------------------------------------------------------
-- STERGE_SERIE
-- Marks a license serial as deleted (soft delete)
---------------------------------------------------------------------------
PROCEDURE sterge_serie(V_ID_PROGRAM IN NUMBER, V_ID_UTILS IN NUMBER) IS
BEGIN
UPDATE AUTH_SERII
SET STERS = 1, ID_UTILS = V_ID_UTILS, DATAORAS = SYSDATE
WHERE ID_PROGRAM = V_ID_PROGRAM
AND STERS = 0;
END sterge_serie;
---------------------------------------------------------------------------
-- SELECTEAZA_SERIE
-- Returns the hex-encoded serial for a program
---------------------------------------------------------------------------
FUNCTION selecteaza_serie(V_ID_PROGRAM IN NUMBER) RETURN VARCHAR2 IS
V_SERIE AUTH_SERII.SERIE%TYPE;
V_SERIEC VARCHAR2(256);
eroare_de_conversie EXCEPTION;
PRAGMA EXCEPTION_INIT(eroare_de_conversie, -6502);
BEGIN
BEGIN
SELECT SERIE
INTO V_SERIE
FROM AUTH_SERII
WHERE ID_PROGRAM = V_ID_PROGRAM
AND STERS = 0;
EXCEPTION
WHEN NO_DATA_FOUND THEN
V_SERIE := NULL;
END;
BEGIN
V_SERIEC := TRIM(RAWTOHEX(V_SERIE));
EXCEPTION
WHEN eroare_de_conversie THEN
V_SERIEC := NULL;
END;
RETURN V_SERIEC;
END selecteaza_serie;
---------------------------------------------------------------------------
-- SELECTEAZA_NR_UTIL
-- Returns the number of licensed users for a program
---------------------------------------------------------------------------
FUNCTION selecteaza_nr_util(V_ID_PROGRAM IN NUMBER) RETURN NUMBER IS
V_SERIE AUTH_SERII.SERIE%TYPE;
V_DATAORA DATE;
V_NR_UTILIZATORI NUMBER(4);
V_SERIEC VARCHAR2(64);
BEGIN
BEGIN
SELECT SERIE, DATAORA
INTO V_SERIE, V_DATAORA
FROM AUTH_SERII
WHERE ID_PROGRAM = V_ID_PROGRAM
AND STERS = 0;
V_SERIEC := auth_pack.decripteaza_serie(V_ID_PROGRAM, V_SERIE, V_DATAORA);
V_NR_UTILIZATORI := auth_pack.decripteaza_nr_util(V_SERIEC);
EXCEPTION
WHEN NO_DATA_FOUND THEN
V_NR_UTILIZATORI := 0;
END;
RETURN V_NR_UTILIZATORI;
END selecteaza_nr_util;
---------------------------------------------------------------------------
-- SELECTEAZA_DATA_VAL
-- Returns the license expiration date for a program
---------------------------------------------------------------------------
FUNCTION selecteaza_data_val(V_ID_PROGRAM IN NUMBER) RETURN DATE IS
V_SERIE AUTH_SERII.SERIE%TYPE;
V_DATAORA DATE;
V_DATA_VAL DATE;
V_SERIEC VARCHAR2(64);
V_ZI VARCHAR2(2);
BEGIN
BEGIN
SELECT SERIE, DATAORA
INTO V_SERIE, V_DATAORA
FROM AUTH_SERII
WHERE ID_PROGRAM = V_ID_PROGRAM
AND STERS = 0;
V_SERIEC := auth_pack.decripteaza_serie(V_ID_PROGRAM, V_SERIE, V_DATAORA);
V_ZI := LPAD(EXTRACT(DAY FROM V_DATAORA), 2, '0');
V_DATA_VAL := auth_pack.decripteaza_data_val(V_SERIEC, V_ZI);
EXCEPTION
WHEN NO_DATA_FOUND THEN
V_DATA_VAL := NULL;
END;
RETURN V_DATA_VAL;
END selecteaza_data_val;
---------------------------------------------------------------------------
-- VERIFICA_SERIE
-- Validates a license serial checksum
---------------------------------------------------------------------------
PROCEDURE verifica_serie(V_ID_PROGRAM IN NUMBER, V_SERIE IN RAW) IS
v_seriedec VARCHAR2(256);
v_checksum NUMBER(2);
v_suma NUMBER(2) := 0;
BEGIN
v_seriedec := auth_pack.decripteaza_serie(V_ID_PROGRAM, V_SERIE, SYSDATE);
v_checksum := auth_pack.hextodec(SUBSTR(v_seriedec, LENGTH(v_seriedec), 1));
FOR i IN 1 .. LENGTH(v_seriedec) - 1 LOOP
v_suma := v_suma + auth_pack.hextodec(SUBSTR(v_seriedec, i, 1));
END LOOP;
IF MOD(v_suma + v_checksum, 16) <> 0 THEN
RAISE_APPLICATION_ERROR(-20000, 'Seria introdusa nu este valida!');
END IF;
END verifica_serie;
---------------------------------------------------------------------------
-- DECRIPTEAZA_SERIE
-- Decrypts a license serial using DBMS_CRYPTO (Oracle 21c compatible)
-- Replaced DBMS_OBFUSCATION_TOOLKIT.DES3Decrypt
---------------------------------------------------------------------------
FUNCTION decripteaza_serie(
V_ID_PROGRAM IN NUMBER,
V_SERIE IN RAW,
V_DATAORA IN DATE
) RETURN VARCHAR2 IS
v_denumire CONTAFIN_ORACLE.NOM_PROGRAME.DENUMIRE%TYPE;
v_id_client NUMBER(4);
v_cheie RAW(16);
v_serieval RAW(256);
v_seriedec VARCHAR2(32);
v_valoare NUMBER(2);
eroare_de_conversie EXCEPTION;
PRAGMA EXCEPTION_INIT(eroare_de_conversie, -6502);
BEGIN
IF V_SERIE IS NOT NULL THEN
SELECT SUBSTR(a.denumire, 4, 5)
INTO V_DENUMIRE
FROM SYN_NOM_PROGRAME A
WHERE A.ID_PROGRAM = V_ID_PROGRAM;
SELECT TO_NUMBER(DETALII) INTO V_ID_CLIENT FROM AUTH_DETALII;
-- Build 16-byte key for 3DES-2KEY
v_cheie := UTL_RAW.CAST_TO_RAW(
RPAD(
LPAD(v_id_program, 3, '0') ||
LPAD(v_id_client, 4, '0') ||
RPAD(v_denumire, 5, CHR(4)) ||
LPAD(TO_CHAR(v_dataora, 'IWYY'), 4, '0'),
16,
'X'
)
);
-- Use DBMS_CRYPTO instead of DBMS_OBFUSCATION_TOOLKIT
-- ENCRYPT_3DES_2KEY for 16-byte keys, PAD_ZERO for compatibility
v_serieval := DBMS_CRYPTO.DECRYPT(
src => v_serie,
typ => DBMS_CRYPTO.ENCRYPT_3DES_2KEY +
DBMS_CRYPTO.CHAIN_CBC +
DBMS_CRYPTO.PAD_ZERO,
key => v_cheie
);
BEGIN
FOR i IN 1 .. LENGTH(v_serieval) / 2 LOOP
v_valoare := TO_NUMBER(SUBSTR(v_serieval, 2 * i - 1, 2));
IF v_valoare > 40 THEN
v_seriedec := v_seriedec || auth_pack.dectohex(v_valoare - 31);
ELSE
v_seriedec := v_seriedec || (v_valoare - 30);
END IF;
END LOOP;
EXCEPTION
WHEN eroare_de_conversie THEN
RAISE_APPLICATION_ERROR(-20100, 'Seria introdusa nu este valida!');
END;
ELSE
v_seriedec := NULL;
END IF;
RETURN v_seriedec;
END decripteaza_serie;
---------------------------------------------------------------------------
-- DECRIPTEAZA_NR_UTIL
-- Extracts user count from decrypted serial
---------------------------------------------------------------------------
FUNCTION decripteaza_nr_util(V_SERIEC IN VARCHAR2) RETURN NUMBER IS
BEGIN
IF V_SERIEC IS NOT NULL THEN
RETURN TO_NUMBER(SUBSTR(v_seriec, 1, 4));
ELSE
RETURN 0;
END IF;
END decripteaza_nr_util;
---------------------------------------------------------------------------
-- DECRIPTEAZA_DATA_VAL
-- Extracts expiration date from decrypted serial
---------------------------------------------------------------------------
FUNCTION decripteaza_data_val(
V_SERIEC IN VARCHAR2,
V_ZI IN VARCHAR2
) RETURN DATE IS
v_luna VARCHAR2(2);
BEGIN
IF V_SERIEC IS NOT NULL THEN
v_luna := LPAD(auth_pack.hextodec(SUBSTR(v_seriec, 5, 1)), 2, '0');
RETURN LAST_DAY(TO_DATE(v_luna || SUBSTR(v_seriec, 6, 2), 'MMYY'));
ELSE
RETURN NULL;
END IF;
END decripteaza_data_val;
---------------------------------------------------------------------------
-- HEXTODEC
-- Converts a hex character to decimal
---------------------------------------------------------------------------
FUNCTION hextodec(V_HEXA IN VARCHAR2) RETURN NUMBER IS
v_numar NUMBER(2);
BEGIN
IF ASCII(UPPER(TRIM(V_HEXA))) BETWEEN 48 AND 57 OR
ASCII(UPPER(TRIM(V_HEXA))) BETWEEN 65 AND 70 THEN
CASE UPPER(TRIM(V_HEXA))
WHEN 'A' THEN v_numar := 10;
WHEN 'B' THEN v_numar := 11;
WHEN 'C' THEN v_numar := 12;
WHEN 'D' THEN v_numar := 13;
WHEN 'E' THEN v_numar := 14;
WHEN 'F' THEN v_numar := 15;
ELSE v_numar := TO_NUMBER(V_HEXA);
END CASE;
ELSE
RAISE_APPLICATION_ERROR(-20000, 'Caracterul nu este valid!');
END IF;
RETURN v_numar;
END hextodec;
---------------------------------------------------------------------------
-- DECTOHEX
-- Converts a decimal to hex character
---------------------------------------------------------------------------
FUNCTION dectohex(V_NUMAR IN NUMBER) RETURN VARCHAR2 IS
v_hexa VARCHAR2(1);
BEGIN
CASE v_numar
WHEN 10 THEN v_hexa := 'A';
WHEN 11 THEN v_hexa := 'B';
WHEN 12 THEN v_hexa := 'C';
WHEN 13 THEN v_hexa := 'D';
WHEN 14 THEN v_hexa := 'E';
WHEN 15 THEN v_hexa := 'F';
ELSE v_hexa := TO_CHAR(V_NUMAR);
END CASE;
RETURN v_hexa;
END dectohex;
END AUTH_PACK;
/
-- ============================================================================
-- SECTION 5: VIEW
-- ============================================================================
PROMPT [8/11] Creating SYS.VAUTH_SERII view...
CREATE OR REPLACE VIEW SYS.VAUTH_SERII (
ID_PROGRAM,
NUME,
SERIE,
NR_UTIL,
DATA_VAL
) 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;
-- ============================================================================
-- SECTION 6: ADDITIONAL PROCEDURES
-- ============================================================================
PROMPT [9/11] Creating SYS.EXECUTESCRIPTOS procedure...
CREATE OR REPLACE PROCEDURE SYS.EXECUTESCRIPTOS(
p_nume_script IN VARCHAR2,
p_param IN VARCHAR2,
p_wait IN VARCHAR2,
p_result OUT NUMBER
) IS
v_job_name VARCHAR2(100);
v_state VARCHAR2(30);
BEGIN
v_job_name := 'EXECUTESCRIPTOS_' || TO_CHAR(SYSDATE, 'YYYYMMDD_HH24MISS');
DBMS_SCHEDULER.CREATE_JOB(
job_name => v_job_name,
job_type => 'EXECUTABLE',
job_action => p_nume_script,
number_of_arguments => 1,
start_date => SYSTIMESTAMP,
enabled => FALSE,
auto_drop => TRUE
);
DBMS_SCHEDULER.SET_JOB_ARGUMENT_VALUE(
job_name => v_job_name,
argument_position => 1,
argument_value => p_param
);
DBMS_SCHEDULER.ENABLE(v_job_name);
IF p_wait = 'Y' THEN
LOOP
BEGIN
SELECT state INTO v_state
FROM dba_scheduler_jobs
WHERE job_name = v_job_name;
EXIT WHEN v_state NOT IN ('SCHEDULED', 'RUNNING');
EXCEPTION
WHEN NO_DATA_FOUND THEN
EXIT; -- Job completed and was auto-dropped
END;
DBMS_LOCK.SLEEP(1);
END LOOP;
END IF;
p_result := 0;
EXCEPTION
WHEN OTHERS THEN
p_result := -1;
END EXECUTESCRIPTOS;
/
PROMPT [10/11] Creating SYS.NEWSCHEMA procedure...
CREATE OR REPLACE PROCEDURE SYS.NEWSCHEMA(
p_schema_name IN VARCHAR2,
p_password IN VARCHAR2,
p_result OUT NUMBER
) IS
BEGIN
EXECUTE IMMEDIATE 'CREATE USER ' || p_schema_name ||
' IDENTIFIED BY ' || p_password ||
' DEFAULT TABLESPACE ROA' ||
' TEMPORARY TABLESPACE TEMP' ||
' QUOTA UNLIMITED ON ROA';
EXECUTE IMMEDIATE 'GRANT CONNECT, RESOURCE TO ' || p_schema_name;
EXECUTE IMMEDIATE 'GRANT CREATE SESSION TO ' || p_schema_name;
EXECUTE IMMEDIATE 'GRANT CREATE TABLE TO ' || p_schema_name;
EXECUTE IMMEDIATE 'GRANT CREATE VIEW TO ' || p_schema_name;
EXECUTE IMMEDIATE 'GRANT CREATE SEQUENCE TO ' || p_schema_name;
EXECUTE IMMEDIATE 'GRANT CREATE PROCEDURE TO ' || p_schema_name;
EXECUTE IMMEDIATE 'GRANT CREATE TRIGGER TO ' || p_schema_name;
EXECUTE IMMEDIATE 'GRANT CREATE TYPE TO ' || p_schema_name;
EXECUTE IMMEDIATE 'GRANT CREATE SYNONYM TO ' || p_schema_name;
EXECUTE IMMEDIATE 'GRANT CREATE DATABASE LINK TO ' || p_schema_name;
EXECUTE IMMEDIATE 'GRANT CREATE JOB TO ' || p_schema_name;
DBMS_OUTPUT.PUT_LINE('Schema ' || p_schema_name || ' created successfully!');
p_result := 0;
EXCEPTION
WHEN OTHERS THEN
DBMS_OUTPUT.PUT_LINE('Error creating schema: ' || SQLERRM);
p_result := -1;
END NEWSCHEMA;
/
PROMPT [11/11] Creating SYS.NEWSCHEMAJOB and SYS.UPDATESQLPLUS procedures...
CREATE OR REPLACE PROCEDURE SYS.NEWSCHEMAJOB(
p_schema_name IN VARCHAR2,
p_password IN VARCHAR2
) IS
v_job_name VARCHAR2(100);
BEGIN
v_job_name := 'NEWSCHEMA_' || p_schema_name;
DBMS_SCHEDULER.CREATE_JOB(
job_name => v_job_name,
job_type => 'STORED_PROCEDURE',
job_action => 'SYS.NEWSCHEMA',
number_of_arguments => 3,
start_date => SYSTIMESTAMP,
enabled => FALSE,
auto_drop => TRUE
);
DBMS_SCHEDULER.SET_JOB_ARGUMENT_VALUE(
job_name => v_job_name,
argument_position => 1,
argument_value => p_schema_name
);
DBMS_SCHEDULER.SET_JOB_ARGUMENT_VALUE(
job_name => v_job_name,
argument_position => 2,
argument_value => p_password
);
DBMS_SCHEDULER.SET_JOB_ARGUMENT_VALUE(
job_name => v_job_name,
argument_position => 3,
argument_value => '0'
);
DBMS_SCHEDULER.ENABLE(v_job_name);
END NEWSCHEMAJOB;
/
CREATE OR REPLACE PROCEDURE SYS.UPDATESQLPLUS IS
v_result NUMBER;
BEGIN
-- Path may need to be adjusted for your Windows installation
EXECUTESCRIPTOS('D:\ROMFAST\UPDATE\UPDATE_SQLPLUS.BAT', '', 'N', v_result);
END UPDATESQLPLUS;
/
-- ============================================================================
-- VERIFICATION
-- ============================================================================
PROMPT
PROMPT ========================================
PROMPT Verifying SYS Custom Objects
PROMPT ========================================
PROMPT
PROMPT SYS custom objects status:
SELECT object_name, object_type, status
FROM dba_objects
WHERE owner = 'SYS'
AND object_name IN (
'AUTH_PACK', 'AUTH_DETALII', 'AUTH_SERII', 'VAUTH_SERII',
'EXECUTESCRIPTOS', 'NEWSCHEMA', 'NEWSCHEMAJOB', 'UPDATESQLPLUS',
'PINFO', 'INFO', 'SEQ_AUTH_SERII'
)
ORDER BY object_type, object_name;
PROMPT
PROMPT Invalid objects (should be empty):
SELECT object_name, object_type, status
FROM dba_objects
WHERE owner = 'SYS'
AND object_name IN (
'AUTH_PACK', 'AUTH_DETALII', 'AUTH_SERII', 'VAUTH_SERII',
'EXECUTESCRIPTOS', 'NEWSCHEMA', 'NEWSCHEMAJOB', 'UPDATESQLPLUS',
'PINFO', 'INFO', 'SEQ_AUTH_SERII'
)
AND status != 'VALID';
PROMPT
PROMPT ========================================
PROMPT SYS Custom Objects Installation Complete
PROMPT ========================================
PROMPT