oracle migrare

This commit is contained in:
Marius
2025-10-01 16:08:13 +03:00
parent b414b3c338
commit 02ef8775ab
19 changed files with 4832 additions and 1864 deletions

View File

@@ -0,0 +1,754 @@
-- ============================================================================
-- OBIECTE SYS CUSTOM - PRE-GENERAT
-- Oracle 10g Migration → Oracle 21c XE
-- Data: 30 Septembrie 2025
-- Sursa: Oracle 10g @ 10.0.20.122:1521/ROA
-- ============================================================================
--
-- Acest fisier contine DDL pentru toate obiectele custom din SYS:
-- - 2 TABLES: AUTH_DETALII, AUTH_SERII
-- - 1 VIEW: VAUTH_SERII
-- - 1 PACKAGE: AUTH_PACK (spec + body)
-- - 4 PROCEDURES: EXECUTESCRIPTOS, NEWSCHEMA, NEWSCHEMAJOB, UPDATESQLPLUS
--
-- IMPORT: Ruleaza acest script ca SYS in PDB ROA (NU in CDB!)
--
-- Conexiune test:
-- sqlplus sys/OraclePass123@localhost:1521/roa as sysdba
-- SELECT name, cdb FROM v$database; -- Trebuie sa fie: ROA, NO
--
-- ============================================================================
SET SERVEROUTPUT ON
WHENEVER SQLERROR CONTINUE
PROMPT ========================================
PROMPT Import Obiecte Custom SYS
PROMPT ========================================
PROMPT
-- 1. TABELE
PROMPT [1/9] Creating SYS.AUTH_DETALII (TABLE)...
CREATE TABLE "SYS"."AUTH_DETALII"
( "DETALII" VARCHAR2(15) NOT NULL ENABLE
) PCTFREE 10 PCTUSED 40 INITRANS 1 MAXTRANS 255 NOCOMPRESS LOGGING
STORAGE(INITIAL 16384 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT)
TABLESPACE "SYSTEM";
PROMPT [2/9] Creating SYS.AUTH_SERII (TABLE)...
CREATE TABLE "SYS"."AUTH_SERII"
( "ID_SERIE" NUMBER(5,0) NOT NULL ENABLE,
"ID_PROGRAM" NUMBER(5,0) NOT NULL ENABLE,
"SERIE" RAW(128) NOT NULL ENABLE,
"STERS" NUMBER(1,0) DEFAULT 0 NOT NULL ENABLE,
"DATAORA" DATE DEFAULT sysdate NOT NULL ENABLE,
"ID_UTIL" NUMBER(5,0) NOT NULL ENABLE,
"DATAORAS" DATE,
"ID_UTILS" NUMBER(5,0),
CONSTRAINT "PK_AUTH_SERII" PRIMARY KEY ("ID_SERIE")
USING INDEX PCTFREE 10 INITRANS 2 MAXTRANS 255 COMPUTE STATISTICS
STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT)
TABLESPACE "SYSTEM" ENABLE
) PCTFREE 10 PCTUSED 40 INITRANS 1 MAXTRANS 255 NOCOMPRESS LOGGING
STORAGE(INITIAL 16384 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645
PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT)
TABLESPACE "SYSTEM";
-- 2. VIEW
PROMPT [3/9] Creating SYS.VAUTH_SERII (VIEW)...
CREATE OR REPLACE FORCE 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;
-- 3. PACKAGE SPEC
PROMPT [4/9] Creating SYS.AUTH_PACK (PACKAGE SPEC)...
CREATE OR REPLACE PACKAGE "SYS"."AUTH_PACK" is
-- Author : MARIUS.ATANASIU
-- Created : 11/5/2005 9:58:27 AM
-- Purpose : License and authentication management
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;
/
-- 4. PACKAGE BODY
PROMPT [5/9] Creating SYS.AUTH_PACK (PACKAGE BODY)...
CREATE OR REPLACE PACKAGE BODY "SYS"."AUTH_PACK" is
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';
IF v_program not in ('PLSQLDEV.EXE',
'ROASTART.EXE',
'GENERARESCRIPT.EXE',
'SQLPLUS.EXE',
'ROAGEN.EXE',
'ROASUPORT.EXE',
'EXP.EXE',
'EXPDP.EXE',
'IMP.EXE',
'IMPDP.EXE',
'APSNET_WP.EXE',
'WEBDEV.WEBSERVER.EXE',
'VFP9.EXE',
'TASKS.EXE',
'ROAACTUALIZARI.EXE',
'ROA2COCACOLA.EXE') and
user not in ('SYS',
'SYSTEM',
'DBSNMP',
'CTXSYS',
'MDSYS',
'DIP',
'SYSMAN',
'WMSYS') THEN
IF v_program <> v_modul THEN
RAISE_APPLICATION_ERROR(-20000, 'Acces interzis!');
END IF;
auth_pack.verifica_licenta(v_sid, v_program);
END IF;
exception
when NO_DATA_FOUND then
v_program := Null;
end;
end;
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
RAISE_APPLICATION_ERROR(-20000,
'Nu aveti licenta pentru ' ||
V_NUME_PROGRAM || '!' || 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_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
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;
end;
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;
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;
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;
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;
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;
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;
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;
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;
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 VARCHAR2(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;
v_cheie := 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');
dbms_obfuscation_toolkit.DES3Decrypt(input => v_serie,
key => utl_raw.cast_to_raw(v_cheie),
decrypted_data => v_serieval);
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;
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;
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;
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;
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;
end AUTH_PACK;
/
-- 5. PROCEDURES
PROMPT [6/9] 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_os_process_id number;
begin
dbms_scheduler.create_job(job_name => 'EXECUTESCRIPTOS_' ||
to_char(sysdate,
'yyyymmdd_hh24miss'),
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 => 'EXECUTESCRIPTOS_' ||
to_char(sysdate,
'yyyymmdd_hh24miss'),
argument_position => 1,
argument_value => p_param);
dbms_scheduler.enable('EXECUTESCRIPTOS_' ||
to_char(sysdate, 'yyyymmdd_hh24miss'));
if p_wait = 'Y' then
loop
select STATE
into p_result
from dba_scheduler_jobs
where JOB_NAME = 'EXECUTESCRIPTOS_' ||
to_char(sysdate, 'yyyymmdd_hh24miss');
exit when p_result <> 'RUNNING';
dbms_lock.sleep(1);
end loop;
end if;
p_result := 0;
exception
when others then
p_result := -1;
end EXECUTESCRIPTOS;
/
PROMPT [7/9] 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 [8/9] Creating SYS.NEWSCHEMAJOB (PROCEDURE)...
CREATE OR REPLACE PROCEDURE "SYS"."NEWSCHEMAJOB"(p_schema_name in varchar2,
p_password in varchar2) IS
v_result number;
begin
dbms_scheduler.create_job(job_name => 'NEWSCHEMA_' || p_schema_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 => 'NEWSCHEMA_' ||
p_schema_name,
argument_position => 1,
argument_value => p_schema_name);
dbms_scheduler.set_job_argument_value(job_name => 'NEWSCHEMA_' ||
p_schema_name,
argument_position => 2,
argument_value => p_password);
dbms_scheduler.set_job_argument_value(job_name => 'NEWSCHEMA_' ||
p_schema_name,
argument_position => 3,
argument_value => v_result);
dbms_scheduler.enable('NEWSCHEMA_' || p_schema_name);
end NEWSCHEMAJOB;
/
PROMPT [9/9] Creating SYS.UPDATESQLPLUS (PROCEDURE)...
CREATE OR REPLACE PROCEDURE "SYS"."UPDATESQLPLUS" IS
v_result number;
begin
executescriptos('D:\ROMFAST\UPDATE\UPDATE_SQLPLUS.BAT', '', 'N', v_result);
end UPDATESQLPLUS;
/
PROMPT
PROMPT ========================================
PROMPT Import Complet Obiecte SYS!
PROMPT ========================================
PROMPT
PROMPT Obiecte create:
PROMPT [1] SYS.AUTH_DETALII (TABLE)
PROMPT [2] SYS.AUTH_SERII (TABLE)
PROMPT [3] SYS.VAUTH_SERII (VIEW)
PROMPT [4] SYS.AUTH_PACK (PACKAGE SPEC)
PROMPT [5] SYS.AUTH_PACK (PACKAGE BODY)
PROMPT [6] SYS.EXECUTESCRIPTOS (PROCEDURE)
PROMPT [7] SYS.NEWSCHEMA (PROCEDURE)
PROMPT [8] SYS.NEWSCHEMAJOB (PROCEDURE)
PROMPT [9] SYS.UPDATESQLPLUS (PROCEDURE)
PROMPT
PROMPT Verificare obiecte:
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',
'EXECUTESCRIPTOS','NEWSCHEMA','NEWSCHEMAJOB','UPDATESQLPLUS')
ORDER BY object_type, object_name;
PROMPT
EXIT;