Initial commit: Romanian ERP database migration system
Complete project setup with: - PACK_MIGRARE utility package - Migration script examples and patterns - Comprehensive documentation in CLAUDE.md and README.md - System instructions for SQL generation 🤖 Generated with [Claude Code](https://claude.ai/code) Co-Authored-By: Claude <noreply@anthropic.com>
This commit is contained in:
407
system_instructions/knowledge_base/PACK_MIGRARE.pck
Normal file
407
system_instructions/knowledge_base/PACK_MIGRARE.pck
Normal file
@@ -0,0 +1,407 @@
|
||||
create or replace package PACK_MIGRARE is
|
||||
|
||||
-- Author : MARIUS.MUTU
|
||||
-- Created : 9/11/2006 8:44:23 AM
|
||||
-- Purpose :
|
||||
|
||||
-- Public FUNCTION and procedure declarations
|
||||
FUNCTION ObjectExist(tcObjectName IN USER_OBJECTS.OBJECT_NAME%TYPE)
|
||||
return NUMBER;
|
||||
|
||||
FUNCTION ObjectExist(tcObjectName IN USER_OBJECTS.OBJECT_NAME%TYPE,
|
||||
tcObjectType IN USER_OBJECTS.OBJECT_TYPE%TYPE)
|
||||
return NUMBER;
|
||||
|
||||
FUNCTION ColumnExist(tcTableName IN USER_TAB_COLUMNS.TABLE_NAME%TYPE,
|
||||
tcColumnName IN USER_TAB_COLUMNS.COLUMN_NAME%TYPE)
|
||||
return NUMBER;
|
||||
|
||||
FUNCTION ConstraintExist(tcConstraintName IN USER_CONSTRAINTS.CONSTRAINT_NAME%TYPE)
|
||||
return NUMBER;
|
||||
|
||||
FUNCTION MvLogExist(tcTableName IN USER_MVIEW_LOGS.MASTER%TYPE)
|
||||
return NUMBER;
|
||||
|
||||
function DirectoryExistOnDisk(tcDirectory varchar2) return number;
|
||||
|
||||
function DirectoryExist(tcDirectory varchar2) return number;
|
||||
|
||||
FUNCTION VerificaVersiune(tcNumeProgram versiune_programe.program%TYPE,
|
||||
tcVersiuneProgram varchar2,
|
||||
tcVersiuneDB versiune_programe.versiune%TYPE)
|
||||
return VARCHAR2;
|
||||
|
||||
PROCEDURE UpdateVersiune(tcScript versiune.script_final%type);
|
||||
|
||||
PROCEDURE UpdateVersiune(tcScript versiune.script_final%type,
|
||||
tcProgrameVersiuni varchar2);
|
||||
|
||||
PROCEDURE UpdateVersiune(tcScript versiune.script_final%type,
|
||||
tcProgrameVersiuni varchar2,
|
||||
tcSchema varchar2);
|
||||
|
||||
PROCEDURE DropObjects(V_LISTA_OBIECTE IN VARCHAR2);
|
||||
end PACK_MIGRARE;
|
||||
/
|
||||
create or replace package body PACK_MIGRARE is
|
||||
|
||||
/*
|
||||
|
||||
-- exemple
|
||||
begin
|
||||
if pack_migrare.ColumnExist('act','id_responsabil') = 0 then
|
||||
execute immediate 'alter table act add id_responsabil number(10)';
|
||||
end if;
|
||||
|
||||
if pack_migrare.ObjectExist('vact') = 1 then
|
||||
execute immediate 'drop view vact';
|
||||
end if;
|
||||
|
||||
if pack_migrare.ConstraintExist('uk_act_001') = 1 then
|
||||
execute immediate 'drop constraint uk_act_001 cascade';
|
||||
end if;
|
||||
|
||||
end;
|
||||
|
||||
*/
|
||||
|
||||
-- 27.05.2013
|
||||
-- marius.mutu
|
||||
-- + ExecutePlsqlBlock, WrapCode, Clob2Varchar2a, Varchar2a2Clob, ClobSubstr
|
||||
|
||||
-- INTOARCE 1 DACA OBIECTUL EXISTA, 0 ALTFEL
|
||||
-- DATABASE LINK,FUNCTION,INDEX,LOB,PACKAGE,PACKAGE BODY,PROCEDURE,SEQUENCE,TABLE,TRIGGER,VIEW
|
||||
FUNCTION ObjectExist(tcObjectName IN USER_OBJECTS.OBJECT_NAME%TYPE)
|
||||
return NUMBER IS
|
||||
lnExist NUMBER(1);
|
||||
BEGIN
|
||||
SELECT COUNT(*)
|
||||
INTO lnExist
|
||||
from USER_OBJECTS
|
||||
WHERE OBJECT_NAME = UPPER(TRIM(tcObjectName));
|
||||
|
||||
if lnExist >= 1 then
|
||||
return 1;
|
||||
else
|
||||
return 0;
|
||||
end if;
|
||||
|
||||
END ObjectExist;
|
||||
|
||||
FUNCTION ObjectExist(tcObjectName IN USER_OBJECTS.OBJECT_NAME%TYPE,
|
||||
tcObjectType IN USER_OBJECTS.OBJECT_TYPE%TYPE)
|
||||
return NUMBER IS
|
||||
lnExist NUMBER(1);
|
||||
BEGIN
|
||||
SELECT COUNT(*)
|
||||
INTO lnExist
|
||||
from USER_OBJECTS
|
||||
WHERE OBJECT_NAME = UPPER(TRIM(tcObjectName))
|
||||
AND OBJECT_TYPE = UPPER(TRIM(tcObjectType));
|
||||
|
||||
if lnExist >= 1 then
|
||||
return 1;
|
||||
else
|
||||
return 0;
|
||||
end if;
|
||||
|
||||
END ObjectExist;
|
||||
|
||||
-- INTOARCE 1 DACA EXISTA COLOANA, 0 ALTFEL
|
||||
FUNCTION ColumnExist(tcTableName IN USER_TAB_COLUMNS.TABLE_NAME%TYPE,
|
||||
tcColumnName IN USER_TAB_COLUMNS.COLUMN_NAME%TYPE)
|
||||
return NUMBER IS
|
||||
lnExist NUMBER(1);
|
||||
BEGIN
|
||||
SELECT COUNT(*)
|
||||
INTO lnExist
|
||||
from USER_TAB_COLUMNS
|
||||
WHERE TABLE_NAME = UPPER(TRIM(tcTableName))
|
||||
AND COLUMN_NAME = UPPER(TRIM(tcColumnName));
|
||||
|
||||
if lnExist >= 1 then
|
||||
return 1;
|
||||
else
|
||||
return 0;
|
||||
end if;
|
||||
|
||||
END ColumnExist;
|
||||
|
||||
-- INTOARCE 1 DACA EXISTA CONSTRANGEREA, 0 ALTFEL
|
||||
FUNCTION ConstraintExist(tcConstraintName IN USER_CONSTRAINTS.CONSTRAINT_NAME%TYPE)
|
||||
return NUMBER IS
|
||||
lnExist NUMBER(1);
|
||||
BEGIN
|
||||
SELECT COUNT(*)
|
||||
INTO lnExist
|
||||
from USER_CONSTRAINTS
|
||||
WHERE CONSTRAINT_NAME = UPPER(TRIM(tcConstraintName));
|
||||
|
||||
if lnExist >= 1 then
|
||||
return 1;
|
||||
else
|
||||
return 0;
|
||||
end if;
|
||||
|
||||
END ConstraintExist;
|
||||
|
||||
FUNCTION MvLogExist(tcTableName IN USER_MVIEW_LOGS.MASTER%TYPE)
|
||||
return NUMBER IS
|
||||
lnExist NUMBER(1);
|
||||
BEGIN
|
||||
SELECT COUNT(*)
|
||||
INTO lnExist
|
||||
from USER_MVIEW_LOGS
|
||||
WHERE MASTER = UPPER(TRIM(tcTableName));
|
||||
|
||||
if lnExist >= 1 then
|
||||
return 1;
|
||||
else
|
||||
return 0;
|
||||
end if;
|
||||
|
||||
END MVLOGExist;
|
||||
|
||||
function DirectoryExistOnDisk(tcDirectory varchar2) return number is
|
||||
l_fexists BOOLEAN;
|
||||
l_file_length NUMBER;
|
||||
l_block_size BINARY_INTEGER;
|
||||
l_return number(1) := 0;
|
||||
BEGIN
|
||||
|
||||
utl_file.fgetattr(tcDirectory,
|
||||
'.',
|
||||
l_fexists,
|
||||
l_file_length,
|
||||
l_block_size);
|
||||
IF l_fexists THEN
|
||||
l_return := 1;
|
||||
END IF;
|
||||
|
||||
return l_return;
|
||||
|
||||
end DirectoryExistOnDisk;
|
||||
|
||||
function DirectoryExist(tcDirectory varchar2) return number is
|
||||
lnNumar number(10);
|
||||
l_return number(1) := 0;
|
||||
BEGIN
|
||||
|
||||
SELECT count(*)
|
||||
into lnNumar
|
||||
FROM ALL_DIRECTORIES
|
||||
WHERE DIRECTORY_NAME = upper(trim(tcDirectory));
|
||||
|
||||
IF lnNumar > 0 THEN
|
||||
l_return := 1;
|
||||
END IF;
|
||||
|
||||
return l_return;
|
||||
|
||||
end DirectoryExist;
|
||||
|
||||
-- verifica daca este aplicat scriptul tcVersiuneDB (2007_06_16_03)
|
||||
FUNCTION VerificaVersiune(tcNumeProgram versiune_programe.program%TYPE,
|
||||
tcVersiuneProgram varchar2,
|
||||
tcVersiuneDB versiune_programe.versiune%TYPE)
|
||||
return VARCHAR2 IS
|
||||
lnNumVer number(10);
|
||||
lcMesaj varchar2(1000);
|
||||
lcVersiuneProgramDB versiune_programe.versiune%TYPE;
|
||||
lcMajorVerDB varchar2(10);
|
||||
lcMajorVerP varchar2(10);
|
||||
lcMinorVerDB varchar2(10);
|
||||
lcMinorVerP varchar2(10);
|
||||
lcPatchDB varchar2(10);
|
||||
lcPatchP varchar2(10);
|
||||
lcMaxVer varchar2(100);
|
||||
lnVDB number(10) := 0;
|
||||
lnVP number(10) := 0;
|
||||
BEGIN
|
||||
if tcVersiuneDB is not null then
|
||||
SELECT COUNT(*)
|
||||
INTO lnNumVer
|
||||
FROM versiune v
|
||||
WHERE to_char(data_script, 'YYYY_MM_DD') || '_' ||
|
||||
LPAD(v.seq_script, 2, '0') = tcVersiuneDB;
|
||||
|
||||
IF lnNumVer = 0 THEN
|
||||
SELECT MAX(to_char(data_script, 'YYYY_MM_DD') || '_' ||
|
||||
LPAD(v.seq_script, 2, '0'))
|
||||
INTO lcMaxVer
|
||||
from versiune v
|
||||
where data_script is not null
|
||||
and seq_script is not null;
|
||||
|
||||
lcMesaj := 'DB' || ':' || tcVersiuneDB || ':' || lcMaxVer;
|
||||
END IF;
|
||||
end if;
|
||||
|
||||
BEGIN
|
||||
SELECT versiune
|
||||
into lcVersiuneProgramDB
|
||||
FROM versiune_programe
|
||||
WHERE UPPER(PROGRAM) = UPPER(tcNumeProgram);
|
||||
|
||||
EXCEPTION
|
||||
WHEN NO_DATA_FOUND THEN
|
||||
lcVersiuneProgramDB := '';
|
||||
END;
|
||||
IF lcVersiuneProgramDB is not null THEN
|
||||
lcMajorVerDB := getwordnum(lcVersiuneProgramDB, 1, '.');
|
||||
lcMinorVerDB := getwordnum(lcVersiuneProgramDB, 2, '.');
|
||||
lcPatchDB := getwordnum(lcVersiuneProgramDB, 3, '.');
|
||||
|
||||
lcMajorVerP := getwordnum(tcVersiuneProgram, 1, '.');
|
||||
lcMinorVerP := getwordnum(tcVersiuneProgram, 2, '.');
|
||||
lcPatchP := getwordnum(tcVersiuneProgram, 3, '.');
|
||||
if TO_NUMBER(lcMajorVerDB) > TO_NUMBER(lcMajorVerP) then
|
||||
lnVDB := lnVDB + 4;
|
||||
elsif TO_NUMBER(lcMajorVerDB) <> TO_NUMBER(lcMajorVerP) then
|
||||
lnVP := lnVP + 4;
|
||||
end if;
|
||||
|
||||
if TO_NUMBER(lcMinorVerDB) > TO_NUMBER(lcMinorVerP) then
|
||||
lnVDB := lnVDB + 2;
|
||||
elsif TO_NUMBER(lcMinorVerDB) <> TO_NUMBER(lcMinorVerP) then
|
||||
lnVP := lnVP + 2;
|
||||
end if;
|
||||
|
||||
if TO_NUMBER(lcPatchDB) > TO_NUMBER(lcPatchP) then
|
||||
lnVDB := lnVDB + 1;
|
||||
elsif TO_NUMBER(lcPatchDB) <> TO_NUMBER(lcPatchP) then
|
||||
lnVP := lnVP + 1;
|
||||
end if;
|
||||
IF lnVDB > lnVP then
|
||||
lcMesaj := tcNumeProgram || ':' || lcVersiuneProgramDB || ':' ||
|
||||
tcVersiuneProgram;
|
||||
end if;
|
||||
end if;
|
||||
|
||||
RETURN lcMesaj;
|
||||
END VerificaVersiune;
|
||||
|
||||
-- apel UpdateVersiune fara programe
|
||||
-- ex: UpdateVersiune('ff_2007_06_16_03_GESTIUNE')
|
||||
-- ex: UpdateVersiune('ff_2007_06_16_03_GESTIUNE.sql')
|
||||
PROCEDURE UpdateVersiune(tcScript versiune.script_final%type) is
|
||||
begin
|
||||
UpdateVersiune(tcScript, '', USER);
|
||||
end UpdateVersiune;
|
||||
|
||||
-- adauga tcScript in tabelul versiune
|
||||
-- modifica versiunile de programe necesare pentru baza de date
|
||||
-- ex: UpdateVersiune('ff_2007_06_16_03_GESTIUNE','ROAGEST:1.0.68;ROAOBINV:1.0.6')
|
||||
-- ex: UpdateVersiune('ff_2007_06_16_03_GESTIUNE.sql','')
|
||||
PROCEDURE UpdateVersiune(tcScript versiune.script_final%type,
|
||||
tcProgrameVersiuni varchar2) is
|
||||
|
||||
begin
|
||||
UpdateVersiune(tcScript, tcProgrameVersiuni, USER);
|
||||
end UpdateVersiune;
|
||||
|
||||
-- apel UpdateVersiune fara programe
|
||||
-- ex: UpdateVersiune('ff_2007_06_16_03_GESTIUNE')
|
||||
-- ex: UpdateVersiune('ff_2007_06_16_03_GESTIUNE.sql')
|
||||
PROCEDURE UpdateVersiune(tcScript versiune.script_final%type,
|
||||
tcProgrameVersiuni varchar2,
|
||||
tcSchema varchar2) is
|
||||
|
||||
lcScript versiune.script_final%type;
|
||||
lcTipScript versiune.tip_script%type;
|
||||
ldDataScript versiune.data_script%type;
|
||||
lnSeqScript versiune.seq_script%type;
|
||||
lcVersiune varchar2(12);
|
||||
lcVersiuneMax varchar2(12);
|
||||
lcSchema varchar2(100) := UPPER(TRIM(tcSchema));
|
||||
begin
|
||||
-- TEST
|
||||
-- versiune
|
||||
IF UPPER(SUBSTR(tcScript, length(tcScript) - 3)) = '.SQL' THEN
|
||||
lcScript := tcScript;
|
||||
ELSE
|
||||
lcScript := tcScript || '.sql';
|
||||
END IF;
|
||||
|
||||
-- EX: JCS_2007_07_26_01_MIGRARE_PACK_FACTURARE.SQL
|
||||
-- TIPUL ESTE DUPA A 5-a APARITIE A "_"
|
||||
-- lcTipScript := substr(lcScript, INSTR(lcScript, '_', -1) + 1); -- FACTURARE.SQL
|
||||
lcTipScript := substr(lcScript, INSTR(lcScript, '_', 1, 5) + 1); -- MIGRARE_PACK_FACTURARE.SQL
|
||||
lcTipScript := substr(lcTipScript, 1, length(lcTipScript) - 4); -- MIGRARE_PACK_FACTURARE
|
||||
|
||||
-- 2007_07_26
|
||||
ldDataScript := to_date(substr(lcScript, INSTR(lcScript, '_') + 1, 10),
|
||||
'YYYY_MM_DD');
|
||||
-- 01
|
||||
lnSeqScript := to_number(substr(lcScript,
|
||||
INSTR(lcScript, '_', 1, 4) + 1,
|
||||
2));
|
||||
lcVersiune := to_char(ldDataScript, 'YYYYMMDD') ||
|
||||
LPAD(lnSeqScript, 4, '0');
|
||||
|
||||
execute immediate 'insert into ' || CASE lcSchema
|
||||
when 'SYS' THEN
|
||||
'CONTAFIN_ORACLE'
|
||||
ELSE
|
||||
lcSchema
|
||||
END ||
|
||||
'.versiune (script_final, data_final, tip_script, data_script, seq_script) ' ||
|
||||
' values (:1, :2, :3, :4, :5)'
|
||||
using lcScript, SYSDATE, lcTipScript, ldDataScript, lnSeqScript;
|
||||
|
||||
begin
|
||||
select value
|
||||
into lcVersiuneMax
|
||||
from SERVER_INFO
|
||||
WHERE name = 'VERSIUNE_' || lcSchema;
|
||||
EXCEPTION
|
||||
WHEN NO_DATA_FOUND THEN
|
||||
lcVersiuneMax := lcVersiune;
|
||||
END;
|
||||
if lcVersiuneMax < lcVersiune then
|
||||
lcVersiuneMax := lcVersiune;
|
||||
end if;
|
||||
|
||||
-- Actualizez versiunea maxima a schemei in CONTAFIN_ORACLE.SERVER_INFO
|
||||
MERGE INTO SERVER_INFO a
|
||||
USING dual b
|
||||
on (a.name = 'VERSIUNE_' || lcSchema)
|
||||
WHEN NOT MATCHED THEN
|
||||
INSERT (NAME, VALUE) VALUES ('VERSIUNE_' || lcSchema, lcVersiuneMax)
|
||||
WHEN MATCHED THEN
|
||||
UPDATE SET VALUE = lcVersiuneMax;
|
||||
|
||||
-- versiune programe
|
||||
IF tcProgrameVersiuni is not null then
|
||||
execute immediate 'merge into ' || lcSchema ||
|
||||
'.versiune_programe vp
|
||||
using (select UPPER(getwordnum(x, 1, '':'')) as program,
|
||||
getwordnum(x, 2, '':'') as versiune
|
||||
from table(cast(CHARC2COLLECTION(:1, '';'') as
|
||||
CHAR_TAB))) p
|
||||
on (UPPER(vp.program) = p.program)
|
||||
when matched then
|
||||
update set vp.versiune = p.versiune
|
||||
when not matched then
|
||||
insert (vp.program, vp.versiune) values (p.program, p.versiune)'
|
||||
using tcProgrameVersiuni;
|
||||
end if; -- tcProgrameVersiuni is not null
|
||||
end UpdateVersiune;
|
||||
|
||||
---------------------------
|
||||
PROCEDURE DropObjects(V_LISTA_OBIECTE IN VARCHAR2) is
|
||||
V_DELIMITATOR VARCHAR2(1) := ',';
|
||||
BEGIN
|
||||
for obiect in (SELECT A.X AS NUME, B.OBJECT_TYPE AS TIP
|
||||
FROM (SELECT X
|
||||
FROM TABLE(charc2collection(V_LISTA_OBIECTE,
|
||||
V_DELIMITATOR))) A
|
||||
LEFT JOIN USER_OBJECTS B
|
||||
ON UPPER(A.X) = UPPER(B.OBJECT_NAME)
|
||||
WHERE B.OBJECT_TYPE IS NOT NULL) loop
|
||||
execute immediate 'DROP ' || obiect.tip || ' ' || obiect.nume;
|
||||
end loop;
|
||||
END DropObjects;
|
||||
|
||||
end PACK_MIGRARE;
|
||||
/
|
||||
Reference in New Issue
Block a user