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:
Marius
2025-08-08 16:55:07 +03:00
commit 82950b81a5
14 changed files with 994 additions and 0 deletions

View File

@@ -0,0 +1,78 @@
# System Instructions - ROMFASTSQL
Acest director contine instructiuni system si exemple pentru proiectul ROMFASTSQL - un sistem de migrare pentru baza de date ERP romaneasca Oracle.
## Structura
- `system_prompt.md` - Instructiuni principale pentru generarea scripturilor SQL
- `knowledge_base/` - Colectie de exemple si utilitare
- `PACK_MIGRARE.pck` - Package-ul central cu functii utilitare
- Multiple fisiere exemplu de scripturi (ff_*.sql, co_*.sql)
## Componente Principale
### PACK_MIGRARE Package
Package-ul central care ofera functii de verificare:
- `ColumnExist()` - Verifica daca o coloana exista
- `ObjectExist()` - Verifica daca un obiect exista
- `ConstraintExist()` - Verifica daca o restrictie exista
- `UpdateVersiune()` - Tracking versiuni pentru scripturi
### Exemple Scripturi Migrare
Directorul `knowledge_base/` contine exemple pentru:
- **ff_*.sql** - Scripturi de tip "Fast Forward" pentru modificari structurale
- **co_*.sql** - Scripturi pentru obiecte comune
## Conventii Obligatorii
### Formatare SQL
- **NU** folositi ghilimele in jurul numelor de tabele/coloane
- **NU** specificati numele schemei (ex: folositi `JV2007` nu `"SCHEMA"."JV2007"`)
- **MAJUSCULE** pentru toate cuvintele cheie SQL
- Comentarii in romana
### Structura Scripturi
1. Comentariu scurt in romana la inceput
2. Verificari existenta prin PACK_MIGRARE
3. Operatiuni DDL in blocuri PL/SQL
4. MERGE cu NOT MATCHED pentru inserari
5. COMMENT statements directe (nu EXECUTE IMMEDIATE)
6. `pack_migrare.UpdateVersiune()` la sfarsit
7. `commit;`
### Nomenclatura
- Fisiere: `ff_YYYY_MM_DD_NN_TYPE.sql` sau `co_YYYY_MM_DD_NN_TYPE.sql`
- Exemple: `ff_2024_08_28_02_COMUN_EFACTURA.sql`, `co_2024_03_04_01_OBIECTE.sql`
- **ff_** - Fast Forward, pentru modificari structurale si date
- **co_** - Common Objects, pentru obiecte si definitii sistem
## Tipuri Comune de Modificari
### 1. Adaugare Coloane
- Verificare existenta cu `PACK_MIGRARE.COLUMNEXIST()`
- Executie in bloc PL/SQL cu `EXECUTE IMMEDIATE`
- Adaugare `COMMENT ON COLUMN` pentru documentare
### 2. Inserare Date Configurare (OPTIUNI)
- `MERGE INTO` cu `USING DUAL`
- Doar clauza `WHEN NOT MATCHED` pentru idempotenta
- Tipuri: CHARACTER, NUMERIC
### 3. Inserare Obiecte Sistem (DEF_OBIECTE)
- MERGE pe `id_obiect` unic
- Include relatii parinte-copil (`id_tata`)
- Gestionare drepturi prin `DEF_GRUP_DREPT_OBIECTE`
### 4. Creare/Modificare View-uri
- `CREATE OR REPLACE VIEW`
- Join-uri complexe pentru agregare date
- Alias-uri descriptive in romana
### 5. Update-uri Simple
- UPDATE direct pentru corectii date
- TRIM pentru curatare spatii
- REPLACE pentru modificari cai/valori
## Utilizare
Aceste fisiere servesc ca ghid si exemple pentru crearea scripturilor SQL de migrare sigure si idempotente in cadrul proiectului ROMFASTSQL.

View 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;
/

View File

@@ -0,0 +1,23 @@
prompt Importing table DEF_OBIECTE...
merge into def_obiecte a using dual b on (a.id_obiect = 6089)
when not matched then
insert (ID_OBIECT, ID_PROGRAM, DESCRIERE, ID_TATA, COD, ID_UTILOP, DATAORA, STERS)
values (6089, 2, 'Import eFactura primite', 6082, '02', -3, to_date('04-03-2024', 'dd-mm-yyyy'), 0);
merge into def_obiecte a using dual b on (a.id_obiect = 6090)
when not matched then
insert (ID_OBIECT, ID_PROGRAM, DESCRIERE, ID_TATA, COD, ID_UTILOP, DATAORA, STERS)
values (6090, 2, 'Import eFactura trimise', 6082, '03', -3, to_date('04-03-2024', 'dd-mm-yyyy'), 0);
merge into def_grup_drept_obiecte a using
(select decode(id_obiect, 2587, 6089, 2611, 6090) as id_obiect, id_grup, -3 as id_utilop, sysdate as dataora, 0 as sters from DEF_GRUP_DREPT_OBIECTE t where id_obiect in (2587, 2611) and sters = 0) b
on (a.id_obiect = b.id_obiect and a.id_grup = b.id_grup)
when not matched then
insert (id_obiect, id_grup, id_utilop, dataora, sters) values (b.id_obiect, b.id_grup, b.id_utilop, b.dataora, b.sters);
prompt Done.
exec pack_migrare.UpdateVersiune('co_2024_03_04_01_OBIECTE');
commit;

View File

@@ -0,0 +1,10 @@
MERGE INTO def_obiecte a using dual b on (a.id_obiect = 6091)
when not matched then
insert (id_obiect, id_program, descriere, id_tata, cod, id_utilop, dataora, sters)
values (6091, 2, 'Trimite xml eFactura', 6082, '02', -3, trunc(sysdate), 0);
update def_obiecte set cod = '03' where id_obiect = 6089;
update def_obiecte set cod = '04' where id_obiect = 6090;
exec pack_migrare.UpdateVersiune('co_2024_07_17_01_OBIECTE');
commit;

View File

@@ -0,0 +1,19 @@
prompt Importing table optiuni...
MERGE INTO OPTIUNI a using DUAL b on (a.varname = 'EFACTURA_SERVER_PATH')
when not matched then
insert (VARNAME, VARTYPE, VARVALUE, VARDESC)
values ('EFACTURA_SERVER_PATH', 'CHARACTER', '', 'Cale salvare zip eFactura pe server');
MERGE INTO OPTIUNI a using DUAL b on (a.varname = 'EFACTURA_NETWORK_PATH')
when not matched then
insert (VARNAME, VARTYPE, VARVALUE, VARDESC)
values ('EFACTURA_NETWORK_PATH', 'CHARACTER', '', 'Cale salvare zip eFactura director comun in retea, cand se descarca de pe client');
MERGE INTO OPTIUNI a using DUAL b on (a.varname = 'EFACTURA_ZIP_DATABASE')
when not matched then
insert (VARNAME, VARTYPE, VARVALUE, VARDESC)
values ('EFACTURA_ZIP_DATABASE', 'NUMERIC', '1', '1=SE SALVEAZA EFACTURA ZIP IN BAZA DE DATE');
exec pack_migrare.UpdateVersiune('ff_2024_07_11_01_COMUN_OPTIUNI');
commit;

View File

@@ -0,0 +1,10 @@
------------------------------------------------------
--
--
--
-- Creat de marius.mutu pe 07/08/2024
------------------------------------------------------
exec pack_migrare.UpdateVersiune('FF_2024_08_07_01_COMUN_SAFT.SQL');
commit;

View File

@@ -0,0 +1,6 @@
UPDATE OPTIUNI SET VARVALUE = '1' WHERE VARNAME IN ('EFACTURA_CONT_ART_EF', 'EFACTURA_CONT_ART_PF', 'EFACTURA_GEST_ART_EF', 'EFACTURA_GEST_ART_PF');
UPDATE ANAF_EFACTURA_DETALII SET ARTICOL = TRIM(ARTICOL);
exec pack_migrare.UpdateVersiune('ff_2024_08_13_05_COMUN_EFACTURA');
commit;

View File

@@ -0,0 +1,121 @@
-- + auto_validare_comenzi, auto_istoric_comenzi.series, kmint, cilindree, puterecp, puterekw
create or replace view auto_validare_comenzi as
select a.id_ordl,
a.id_lucrare,
a.id_masiniclient,
a.id_tip,
a.nr_dosar,
a.datai,
nvl(a.validat, 0) as validat,
a.dataoravalid,
a.util_valid,
a.nrord,
a.proc_tvav,
nvl(b.manopera, 0) as manopera,
nvl(b1.materiale, 0) as materiale,
nvl(c.facturat, 0) as facturat,
c.dataact as datafact,
nvl(c.nract, 0) as nrfact,
c.valctva,
d.id_partener,
d.nrinmat,
d.series,
d.cilindree,
d.puterecp,
d.puterekw,
e.denumire as nume,
g.id_part as id_part_asig,
g1.denumire as asigurator,
h.inspector,
i.denumire as tip_comanda,
i.inch_validare,
a.kmint,
a.ore_functionare,
nvl(a.inchis_fortat, 0) as inchis_fortat,
a.dataorainchis,
a.util_inchis,
a.id_part_ref,
j.denumire as part_ref
from auto_comenzi_validate a
left join auto_vordl_man b
on a.id_ordl = b.id_ordl
left join auto_vordl_mat b1
on a.id_lucrare = b1.id_lucrare
left join auto_vordl_facturi c
on a.id_lucrare = c.id_lucrare
left join dev_masiniclienti d
on a.id_masiniclient = d.id_masiniclient
left join nom_parteneri e
on d.id_partener = e.id_part
left join dev_nom_asiguratori g
on a.id_asigurator = g.id_asigurator
left join nom_parteneri g1
on g.id_part = g1.id_part
left join dev_nom_inspectori h
on a.id_inspector = h.id_inspector
left join dev_tip_deviz i
on a.id_tip = i.id_tip
left join nom_parteneri j
on a.id_part_ref = j.id_part
order by a.datai, a.nrord;
create or replace view auto_istoric_comenzi as
select a.id_ordl,
a.id_lucrare,
a.id_masiniclient,
a.id_tip,
a.datai,
a.nr_dosar,
nvl(a.validat, 0) as validat,
a.dataoravalid,
a.util_valid,
a.nrord,
a.proc_tvav,
nvl(c.facturat, 0) as facturat,
c.dataact as datafact,
nvl(c.nract, 0) as nrfact,
d.id_partener,
d.nrinmat,
d.series,
d.cilindree,
d.puterecp,
d.puterekw,
b.masina,
b1.marca,
e.denumire as nume,
g1.denumire as asigurator,
h.inspector,
i.denumire as tip_comanda,
a.kmint,
a.ore_functionare,
a.inchis_fortat,
a.dataorainchis,
a.util_inchis,
a.id_part_ref,
j.denumire as part_ref
from auto_comenzi_validate a
left join auto_vordl_facturi c
on a.id_lucrare = c.id_lucrare
left join dev_masiniclienti d
on a.id_masiniclient = d.id_masiniclient
left join dev_nom_masini b
on d.id_masina = b.id_masina
left join dev_nom_marci b1
on b.id_marca = b1.id_marca
left join nom_parteneri e
on d.id_partener = e.id_part
left join dev_nom_asiguratori g
on a.id_asigurator = g.id_asigurator
left join nom_parteneri g1
on g.id_part = g1.id_part
left join dev_nom_inspectori h
on a.id_inspector = h.id_inspector
left join dev_tip_deviz i
on a.id_tip = i.id_tip
left join nom_parteneri j
on a.id_part_ref = j.id_part;
exec pack_migrare.UpdateVersiune('ff_2024_08_15_01_AUTO');
commit;

View File

@@ -0,0 +1,5 @@
UPDATE OPTIUNI SET VARVALUE = 'C:\ROA-EFACTURA' WHERE VARNAME = 'EFACTURA_SERVER_PATH' AND VARVALUE IS NULL;
UPDATE OPTIUNI SET VARVALUE = REPLACE(VARVALUE, 'C:\ROA-EFACTURA', '<path>') WHERE VARNAME in ('EFACTURA_SENDPATH', 'EFACTURA_SAVE_FURNIZORI_PATH', 'EFACTURA_SAVE_CLIENTI_PATH', 'EFACTURA_RESPONSESPATH');
exec pack_migrare.UpdateVersiune('ff_2024_08_16_01_COMUN_EFACTURA');
commit;

View File

@@ -0,0 +1,161 @@
BEGIN
IF PACK_MIGRARE.COLUMNEXIST('ANAF_EFACTURA_DETALII', 'TIPTVA') = 0 THEN
EXECUTE IMMEDIATE 'alter table ANAF_EFACTURA_DETALII add tiptva varchar2(2)';
END IF;
END;
/
comment on column ANAF_EFACTURA_DETALII.tiptva is 'nomenclator 5305: S=Standard rate,Z=Zero rated goods,E=Exempt from tax,AE=VAT Reverse charge,K=VAT exempt for EEA intra-community supply of goods and services,G=Free export item, tax not charged,O=Service outside scope of tax,L=Canary Islands general indirect tax,M=Tax for production, services and importation in Ceuta and Melilla';
create or replace view anaf_vefactura_detalii as
select d.id,
d.id_efactura,
d.nr,
d.articol,
d.detalii,
d.cantitate,
d.um,
u.um_iso,
(select max(id) from vnom_um where id in (select last_value(id) over (order by id RANGE BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING) from vnom_um where cod_um_iso = d.um)) as id_um,
(select max(um) from vnom_um where id in (select last_value(id) over (order by id RANGE BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING) from vnom_um where cod_um_iso = d.um)) as um_roa,
d.pret,
d.proctva,
d.tiptva,
d.descriere,
d.valoarefaratva,
d.discountfaratva,
d.id_articol,
a.denumire as articol_roa,
a.codmat as codmat_roa,
a.codmatf as codmatf_roa,
a.cont as cont_roa,
a.acont as acont_roa,
a.in_stoc,
a.in_crm,
d.codbare,
d.codclient,
d.codfurnizor,
d.codcpv,
d.codnc8,
d.id_gestiune,
g.nume_gestiune,
g.cgest,
d.cont,
d.acont
from anaf_efactura_detalii d
left join syn_vnom_um_iso u
on TRIM(d.um) = u.cod_um_iso
left join nom_articole a on d.id_articol = a.id_articol
left join nom_gestiuni g on d.id_gestiune = g.id_gestiune;
create or replace view anaf_vefactura_emis_detaliu as
select f.xdata_act as data_act,
f.xnumar_act as numar_act,
f.xdata_scad as data_scad,
f.xclient,
f.cod_fiscal_emitent,
f.xtotal_fara_tva as total_fara_tva,
f.xtotal_tva as total_tva,
f.xtotal_cu_tva as total_cu_tva,
f.xdiscount_fara_tva as discount_fara_tva,
f.xtaxe_fara_tva as taxe_fara_tva,
f.xvaloare_fara_tva as valoare_fara_tva,
f.xtotal_de_plata as total_de_plata,
f.xnume_valuta as nume_valuta,
f.xdescriere,
f.xdetalii_plata as detalii_plata,
d.id,
d.id_efactura,
d.nr,
d.articol,
d.detalii,
d.cantitate,
d.um,
d.pret,
d.proctva,
d.tiptva,
d.descriere,
d.valoarefaratva,
d.discountfaratva
from anaf_vefactura_emis f
join anaf_efactura_detalii d
on f.id = d.id_efactura;
create or replace view anaf_vefactura_primit_detaliu as
select f.data_act,
f.numar_act,
f.data_scad,
f.xclient,
f.cod_fiscal_beneficiar,
f.xfurnizor,
f.cod_fiscal_emitent,
f.total_fara_tva,
f.total_tva,
f.total_cu_tva,
f.discount_fara_tva,
f.taxe_fara_tva,
f.valoare_fara_tva,
f.total_de_plata,
f.nume_valuta,
f.descriere as xdescriere,
f.detalii_plata,
f.id_incarcare,
f.id_descarcare,
f.creditnote,
d.id,
d.id_efactura,
d.nr,
d.articol,
d.detalii,
d.cantitate,
d.um,
d.pret,
d.proctva,
d.tiptva,
d.descriere,
d.valoarefaratva,
d.discountfaratva
from anaf_vefactura_primit f
join anaf_efactura_detalii d
on f.id = d.id_efactura;
create or replace view anaf_vefactura_trimis_detaliu as
select f.data_act,
f.numar_act,
f.data_scad,
f.xclient,
f.cod_fiscal_beneficiar,
f.xfurnizor,
f.cod_fiscal_emitent,
f.total_fara_tva,
f.total_tva,
f.total_cu_tva,
f.discount_fara_tva,
f.taxe_fara_tva,
f.valoare_fara_tva,
f.total_de_plata,
f.nume_valuta,
f.descriere as xdescriere,
f.detalii_plata,
f.id_incarcare,
f.id_descarcare,
f.creditnote,
d.id,
d.id_efactura,
d.nr,
d.articol,
d.detalii,
d.cantitate,
d.um,
d.pret,
d.proctva,
d.tiptva,
d.descriere,
d.valoarefaratva,
d.discountfaratva
from anaf_vefactura_trimis f
join anaf_efactura_detalii d
on f.id = d.id_efactura;
exec pack_migrare.UpdateVersiune('ff_2024_08_28_02_COMUN_EFACTURA');
commit;

View File

@@ -0,0 +1,4 @@
-- trebuia co_ in loc de ff_
exec pack_migrare.UpdateVersiune('ff_2024_09_13_01_COMUN_OBIECTE');
commit;

View File

@@ -0,0 +1,37 @@
# Instructiuni System - ROMFASTSQL
## Context Proiect
Acest proiect contine scripturi SQL pentru gestionarea unei bazei de date ERP cu server Oracle.
## Reguli Obligatorii pentru Generarea Scripturilor SQL
### 1. Formatare SQL
- **NU folositi ghilimele** in jurul numelor de tabele si coloane
- **NU specificati numele schemei** (folositi `JV2007` nu `"MARIUSM_AUTO"."JV2007"`)
- **Folositi majuscule** pentru toate cuvintele cheie SQL (ALTER, TABLE, ADD, NUMBER, etc.)
- **Adaugati comentarii** in romana pentru a explica scopul scriptului
## PROMPT SISTEM
Esti un programator SQL Oracle. Scrii scripturi SQL. Iti dau comenzi DDL sau DML pentru care trebuie sa creezi scripturi de migrare baza de date.
Comenzile de adaugare coloana trebuie sa fie impachetate in apeluri la Pack_migrare (ColumnExist, ObjectExist etc) ca sa verifice intai daca obiectul nu este deja adaugat in baza de date. Vezi fisierul PACK_MIGRARE.pck.
Adaugarea de inregistrari intr-un tabel trebuie sa fie intr-o instructiune merge doar cu ramura NOT MATCHED ca sa nu se adauge inregistrarile daca exista deja, in cazul executiei de doua ori a aceluiasi script.
Intr-o instructiune INSERT / MERGE nu mai adauga valorile NULL sau CLOB
Ai exemple de scripturi in directorul "knowledge_base"
La sfarsitul scripturilor trebuie adaugat apel la pack_migrare.UpdateVersiune cu numele fisierului sql, de forma ff_2024_08_28_02_COMUN_EFACTURA, unde "ff" este prefix fix, 2024_08_28 este anul, luna si ziua scriptului, 02 este numarul scriptului din ziua scriptului, COMUN_EFACTURA este tipul scriptului.
Numele fisierului script trebuie sa fie dinamic, in functie de anul, luna si ziua curenta.
Adauga la inceputul scriptului si un comentariu extrem de scurt cu descrierea modificarilor din script.
Ex: -- adaugare coloana nom_firme.caen_revizie
Nu explica ce faci, doar creeaza scriptul.
Instructiunile COMMENT, pune-le direct ca DDL, nu ca EXECUTE IMMEDIATE.
Numele scriptului sql sa fie tot de forma ff_aaaa_ll_zz_secventa_COMUN_EFACTURA.sql