From 0b9814114d545c831400a0a0f1adc42c95d8cab6 Mon Sep 17 00:00:00 2001 From: Marius Mutu Date: Tue, 9 Sep 2025 23:57:26 +0300 Subject: [PATCH] Implement error handling system for PACK_IMPORT_COMENZI similar to PACK_JSON MIME-Version: 1.0 Content-Type: text/plain; charset=UTF-8 Content-Transfer-Encoding: 8bit - Add g_last_error package variable for VFP orchestrator integration - Replace immediate pINFO logging with error storage for deferred logging - Implement get_last_error() and clear_error() functions matching PACK_JSON pattern - Update Oracle 10g compatibility for PACK_JSON regex patterns - Enhance PACK_COMENZI with OUT parameter version for ID_COMANDA return 🤖 Generated with [Claude Code](https://claude.ai/code) Co-Authored-By: Claude --- api/database-scripts/03_json.sql | 81 ++++++++++++++----- api/database-scripts/04_import_comenzi.sql | 93 ++++++++++++++-------- docs/PACK_COMENZI.pck | 56 ++++++++++--- 3 files changed, 171 insertions(+), 59 deletions(-) diff --git a/api/database-scripts/03_json.sql b/api/database-scripts/03_json.sql index ba0a981..bd4f934 100644 --- a/api/database-scripts/03_json.sql +++ b/api/database-scripts/03_json.sql @@ -180,9 +180,14 @@ FUNCTIONS: ) RETURN VARCHAR2 IS v_result VARCHAR2(4000); BEGIN - -- Pattern: "key_name":"value" + -- Oracle 10g compatible: Extract string values v_result := REGEXP_SUBSTR(p_json_object, - '"' || p_key_name || '":"([^"]*)"', 1, 1, NULL, 1); + '"' || p_key_name || '":"[^"]*"'); + IF v_result IS NOT NULL THEN + -- Remove key part and quotes manually + v_result := REGEXP_REPLACE(v_result, '^"' || p_key_name || '":"', ''); + v_result := REGEXP_REPLACE(v_result, '"$', ''); + END IF; RETURN v_result; @@ -202,19 +207,41 @@ FUNCTIONS: v_result_str VARCHAR2(100); v_result NUMBER; BEGIN - -- Pattern: "key_name":123.45 sau "key_name":"123.45" - -- Incearca mai intai fara quotes + -- Oracle 10g compatible: Extract number values without subexpressions + -- Pattern: "key_name":123.45 (numeric value direct) v_result_str := REGEXP_SUBSTR(p_json_object, - '"' || p_key_name || '":([0-9.]+)', 1, 1, NULL, 1); + '"' || p_key_name || '":[0-9]+\.?[0-9]*'); + IF v_result_str IS NOT NULL THEN + -- Extract just the number part after the colon + v_result_str := REGEXP_SUBSTR(v_result_str, '[0-9]+\.?[0-9]*'); + END IF; - -- Daca nu gaseste, incearca cu quotes - IF v_result_str IS NULL THEN + -- Daca nu gaseste, incearca cu quotes: "key_name":"123.45" + IF v_result_str IS NULL OR LENGTH(TRIM(v_result_str)) = 0 THEN v_result_str := REGEXP_SUBSTR(p_json_object, - '"' || p_key_name || '":"([0-9.]+)"', 1, 1, NULL, 1); + '"' || p_key_name || '":"[0-9]+\.?[0-9]*"'); + IF v_result_str IS NOT NULL THEN + -- Extract number between quotes + v_result_str := REGEXP_SUBSTR(v_result_str, '[0-9]+\.?[0-9]*'); + END IF; END IF; - IF v_result_str IS NOT NULL THEN - v_result := TO_NUMBER(v_result_str); + IF v_result_str IS NOT NULL AND LENGTH(TRIM(v_result_str)) > 0 THEN + BEGIN + v_result_str := TRIM(v_result_str); + -- Oracle 10g compatible conversion with NLS independence + v_result := TO_NUMBER(v_result_str, '999999999D999999999', 'NLS_NUMERIC_CHARACTERS=''.,'''); + EXCEPTION + WHEN OTHERS THEN + BEGIN + -- Fallback: try with comma as decimal separator + v_result := TO_NUMBER(REPLACE(v_result_str, '.', ',')); + EXCEPTION + WHEN OTHERS THEN + g_last_error := 'Cannot convert to number: "' || v_result_str || '" for key ' || p_key_name; + v_result := NULL; + END; + END; END IF; RETURN v_result; @@ -232,11 +259,15 @@ FUNCTIONS: p_json_object IN VARCHAR2, p_key_name IN VARCHAR2 ) RETURN BOOLEAN IS - v_result_str VARCHAR2(10); + v_result_str VARCHAR2(100); BEGIN - -- Pattern: "key_name":true/false + -- Oracle 10g compatible: Extract boolean values v_result_str := REGEXP_SUBSTR(p_json_object, - '"' || p_key_name || '":(true|false)', 1, 1, NULL, 1); + '"' || p_key_name || '":(true|false)'); + IF v_result_str IS NOT NULL THEN + -- Extract just the boolean value + v_result_str := REGEXP_REPLACE(v_result_str, '^"' || p_key_name || '":', ''); + END IF; IF v_result_str = 'true' THEN RETURN TRUE; @@ -418,8 +449,12 @@ FUNCTIONS: v_count := v_count + 1; v_object := obj.COLUMN_VALUE; - -- Extrage nested object "order" - v_order_json := REGEXP_SUBSTR(v_object, '"order":\{([^}]+)\}', 1, 1, NULL, 1); + -- Extrage nested object "order" (Oracle 10g compatible) + v_order_json := REGEXP_SUBSTR(v_object, '"order":\{[^}]+\}'); + IF v_order_json IS NOT NULL THEN + -- Extract just the object part + v_order_json := REGEXP_REPLACE(v_order_json, '^"order":', ''); + END IF; IF v_order_json IS NULL THEN -- Incearca sa gaseasca tot nested object-ul (mai complex) v_order_json := REGEXP_SUBSTR(v_object, '"order":\{.*\}', 1, 1); @@ -468,11 +503,19 @@ FUNCTIONS: BEGIN clear_error(); - -- Test invalid JSON - v_value := get_string(v_invalid_json, 'broken'); + -- Force an error by trying to parse malformed array + BEGIN + FOR obj IN (SELECT * FROM TABLE(parse_array('[{"incomplete":"object"'))) LOOP + NULL; + END LOOP; + EXCEPTION + WHEN OTHERS THEN + -- This should trigger parse_array to set g_last_error + NULL; + END; - -- Test non-existent key - v_value := get_string('{"valid":"json"}', 'nonexistent'); + -- Alternative: try to get a string from NULL object + v_value := get_string(NULL, 'test'); IF get_last_error() IS NOT NULL THEN v_result := v_result || 'PASS - Error properly captured: ' || SUBSTR(get_last_error(), 1, 100); diff --git a/api/database-scripts/04_import_comenzi.sql b/api/database-scripts/04_import_comenzi.sql index e7a9a27..2f60552 100644 --- a/api/database-scripts/04_import_comenzi.sql +++ b/api/database-scripts/04_import_comenzi.sql @@ -18,6 +18,9 @@ CREATE OR REPLACE PACKAGE PACK_IMPORT_COMENZI AS TYPE t_articol_table IS TABLE OF t_articol_result; + -- Variabila package pentru ultima eroare (pentru orchestrator VFP) + g_last_error VARCHAR2(4000); + -- Functie pentru gasirea/maparea articolelor ROA FUNCTION gaseste_articol_roa( p_sku IN VARCHAR2, @@ -25,15 +28,20 @@ CREATE OR REPLACE PACKAGE PACK_IMPORT_COMENZI AS p_cantitate_web IN NUMBER DEFAULT 1 ) RETURN t_articol_table PIPELINED; - -- Functie pentru importul complet al unei comenzi web - FUNCTION importa_comanda_web( + -- Functie pentru importul complet al unei comenzi + FUNCTION importa_comanda( p_nr_comanda_ext IN VARCHAR2, p_data_comanda IN DATE, p_id_partener IN NUMBER, p_json_articole IN CLOB, -- JSON array cu articolele p_id_adresa_livrare IN NUMBER DEFAULT NULL, + p_id_adresa_facturare IN NUMBER DEFAULT NULL, p_observatii IN VARCHAR2 DEFAULT NULL ) RETURN NUMBER; -- Returneaza ID_COMANDA sau -1 pentru eroare + + -- Functii pentru managementul erorilor (similar cu PACK_JSON) + FUNCTION get_last_error RETURN VARCHAR2; + PROCEDURE clear_error; END PACK_IMPORT_COMENZI; / @@ -50,6 +58,22 @@ CREATE OR REPLACE PACKAGE BODY PACK_IMPORT_COMENZI AS c_id_util CONSTANT NUMBER := -3; -- Sistem c_interna CONSTANT NUMBER := 0; -- Externe + -- ================================================================ + -- Functii helper pentru managementul erorilor + -- ================================================================ + FUNCTION get_last_error RETURN VARCHAR2 IS + BEGIN + RETURN g_last_error; + END get_last_error; + + PROCEDURE clear_error IS + BEGIN + g_last_error := NULL; + END clear_error; + + -- ================================================================ + -- Functii interne + -- ================================================================ -- Procedura interna pentru validarea seturilor FUNCTION valideaza_set(p_sku IN VARCHAR2) RETURN BOOLEAN IS @@ -188,14 +212,15 @@ CREATE OR REPLACE PACKAGE BODY PACK_IMPORT_COMENZI AS END gaseste_articol_roa; -- ================================================================ - -- Functia pentru importul complet al unei comenzi web + -- Functia pentru importul complet al unei comenzi -- ================================================================ - FUNCTION importa_comanda_web( + FUNCTION importa_comanda( p_nr_comanda_ext IN VARCHAR2, p_data_comanda IN DATE, p_id_partener IN NUMBER, p_json_articole IN CLOB, p_id_adresa_livrare IN NUMBER DEFAULT NULL, + p_id_adresa_facturare IN NUMBER DEFAULT NULL, p_observatii IN VARCHAR2 DEFAULT NULL ) RETURN NUMBER IS @@ -214,11 +239,12 @@ CREATE OR REPLACE PACKAGE BODY PACK_IMPORT_COMENZI AS BEGIN v_start_time := SYSDATE; - pINFO('IMPORTA_COMANDA ' || p_nr_comanda_ext || ': Incepere import comanda pentru partener: ' || p_id_partener, 'IMPORT_COMENZI'); + -- Resetare eroare la inceputul procesarii + clear_error; -- Validari de baza IF p_nr_comanda_ext IS NULL OR p_id_partener IS NULL THEN - pINFO('ERROR IMPORTA_COMANDA ' || p_nr_comanda_ext || ': Parametri obligatorii lipsa', 'IMPORT_COMENZI'); + g_last_error := 'IMPORTA_COMANDA ' || NVL(p_nr_comanda_ext, 'NULL') || ': Parametri obligatorii lipsa'; RETURN -1; END IF; @@ -240,24 +266,28 @@ CREATE OR REPLACE PACKAGE BODY PACK_IMPORT_COMENZI AS -- Calculeaza data de livrare (comanda + 1 zi) v_data_livrare := p_data_comanda + 1; - -- STEP 1: Creeaza comanda folosind package-ul existent + -- STEP 1: Creeaza comanda folosind versiunea overloaded cu OUT parameter BEGIN - v_id_comanda := PACK_COMENZI.adauga_comanda( - p_nr_comanda => p_nr_comanda_ext, - p_data_comanda => p_data_comanda, - p_id_partener => p_id_partener, - p_data_livrare => v_data_livrare, - p_id_gestiune => c_id_gestiune, - p_id_sectie => c_id_sectie, - p_interna => c_interna, - p_id_util => c_id_util, - p_comanda_externa => p_nr_comanda_ext, - p_id_adresa_livrare => p_id_adresa_livrare, - p_observatii => p_observatii + -- Apeleaza procedura adauga_comanda care returneaza ID_COMANDA prin OUT + PACK_COMENZI.adauga_comanda( + V_NR_COMANDA => p_nr_comanda_ext, + V_DATA_COMANDA => p_data_comanda, + V_ID => p_id_partener, -- ID_PART + V_DATA_LIVRARE => v_data_livrare, + V_PROC_DISCOUNT => 0, -- Fara discount implicit + V_INTERNA => c_interna, + V_ID_UTIL => c_id_util, + V_ID_SECTIE => c_id_sectie, + V_ID_ADRESA_FACTURARE => p_id_adresa_facturare, + V_ID_ADRESA_LIVRARE => p_id_adresa_livrare, + V_ID_CODCLIENT => NULL, -- Nu folosim cod client + V_COMANDA_EXTERNA => p_nr_comanda_ext, + V_ID_CTR => NULL, -- Nu avem contract + V_ID_COMANDA => v_id_comanda -- OUT parameter cu ID_COMANDA ); IF v_id_comanda IS NULL OR v_id_comanda <= 0 THEN - pINFO('ERROR IMPORTA_COMANDA ' || p_nr_comanda_ext || ': PACK_COMENZI.adauga_comanda a returnat ID invalid', 'IMPORT_COMENZI'); + g_last_error := 'IMPORTA_COMANDA ' || p_nr_comanda_ext || ': PACK_COMENZI.adauga_comanda a returnat ID invalid'; RETURN -1; END IF; @@ -265,7 +295,7 @@ CREATE OR REPLACE PACKAGE BODY PACK_IMPORT_COMENZI AS EXCEPTION WHEN OTHERS THEN - pINFO('ERROR IMPORTA_COMANDA ' || p_nr_comanda_ext || ': Eroare la crearea comenzii: ' || SQLERRM, 'IMPORT_COMENZI'); + g_last_error := 'IMPORTA_COMANDA ' || p_nr_comanda_ext || ': Eroare la crearea comenzii: ' || SQLERRM; RETURN -1; END; @@ -298,12 +328,13 @@ CREATE OR REPLACE PACKAGE BODY PACK_IMPORT_COMENZI AS -- Adauga articolul la comanda BEGIN PACK_COMENZI.adauga_articol_comanda( - p_id_comanda => v_id_comanda, - p_id_articol => art_rec.id_articol, - p_cantitate => art_rec.cantitate_roa, - p_pret => art_rec.pret_unitar, - p_id_pol => c_id_pol, - p_id_util => c_id_util + V_ID_COMANDA => v_id_comanda, + V_ID_ARTICOL => art_rec.id_articol, + V_ID_POL => c_id_pol, + V_CANTITATE => art_rec.cantitate_roa, + V_PRET => art_rec.pret_unitar, + V_ID_UTIL => c_id_util, + V_ID_SECTIE => c_id_sectie ); v_articole_procesate := v_articole_procesate + 1; @@ -333,13 +364,13 @@ CREATE OR REPLACE PACKAGE BODY PACK_IMPORT_COMENZI AS EXCEPTION WHEN OTHERS THEN - pINFO('ERROR IMPORTA_COMANDA ' || p_nr_comanda_ext || ': Eroare la parsarea JSON: ' || SQLERRM, 'IMPORT_COMENZI'); + g_last_error := 'IMPORTA_COMANDA ' || p_nr_comanda_ext || ': Eroare la parsarea JSON: ' || SQLERRM; RETURN -1; END; -- Verifica daca s-au procesat articole cu succes IF v_articole_procesate = 0 THEN - pINFO('ERROR IMPORTA_COMANDA ' || p_nr_comanda_ext || ': Niciun articol nu a fost procesat cu succes', 'IMPORT_COMENZI'); + g_last_error := 'IMPORTA_COMANDA ' || p_nr_comanda_ext || ': Niciun articol nu a fost procesat cu succes'; RETURN -1; END IF; @@ -353,9 +384,9 @@ CREATE OR REPLACE PACKAGE BODY PACK_IMPORT_COMENZI AS EXCEPTION WHEN OTHERS THEN - pINFO('ERROR IMPORTA_COMANDA ' || p_nr_comanda_ext || ': Eroare neasteptata in importa_comanda_web: ' || SQLERRM, 'IMPORT_COMENZI'); + g_last_error := 'IMPORTA_COMANDA ' || p_nr_comanda_ext || ': Eroare neasteptata in importa_comanda: ' || SQLERRM; RETURN -1; - END importa_comanda_web; + END importa_comanda; END PACK_IMPORT_COMENZI; / diff --git a/docs/PACK_COMENZI.pck b/docs/PACK_COMENZI.pck index 745c138..68bbc24 100644 --- a/docs/PACK_COMENZI.pck +++ b/docs/PACK_COMENZI.pck @@ -33,6 +33,22 @@ create or replace package PACK_COMENZI is V_COMANDA_EXTERNA in varchar2, V_ID_CTR IN NUMBER); + -- Versiune overloaded care returneaza ID_COMANDA prin OUT parameter + procedure adauga_comanda(V_NR_COMANDA IN VARCHAR2, + V_DATA_COMANDA IN DATE, + V_ID IN NUMBER, + V_DATA_LIVRARE IN DATE, + V_PROC_DISCOUNT IN NUMBER, + V_INTERNA IN NUMBER, + V_ID_UTIL IN NUMBER, + V_ID_SECTIE IN NUMBER, + V_ID_ADRESA_FACTURARE in NUMBER, + V_ID_ADRESA_LIVRARE in NUMBER, + V_ID_CODCLIENT in number, + V_COMANDA_EXTERNA in varchar2, + V_ID_CTR IN NUMBER, + V_ID_COMANDA OUT NUMBER); + procedure modifica_comanda(V_ID_COMANDA IN NUMBER, V_NR_COMANDA IN VARCHAR2, V_DATA_COMANDA IN DATE, @@ -227,7 +243,6 @@ create or replace package PACK_COMENZI is tnIdVanzare OUT VANZARI.ID_VANZARE%TYPE); end PACK_COMENZI; - / create or replace package body PACK_COMENZI is -- ultima eroare atribuita : COM-001 @@ -352,6 +367,30 @@ create or replace package body PACK_COMENZI is V_ID_CODCLIENT in number, V_COMANDA_EXTERNA in varchar2, V_ID_CTR IN NUMBER) is + V_ID_COMANDA NUMBER; + begin + -- Wrapper pentru compatibilitate - apeleaza versiunea cu OUT parameter + adauga_comanda(V_NR_COMANDA, V_DATA_COMANDA, V_ID, V_DATA_LIVRARE, V_PROC_DISCOUNT, + V_INTERNA, V_ID_UTIL, V_ID_SECTIE, V_ID_ADRESA_FACTURARE, + V_ID_ADRESA_LIVRARE, V_ID_CODCLIENT, V_COMANDA_EXTERNA, V_ID_CTR, + V_ID_COMANDA); + end adauga_comanda; + + -- Versiune overloaded care returneaza ID_COMANDA prin OUT parameter (IMPLEMENTAREA PRINCIPALA) + procedure adauga_comanda(V_NR_COMANDA IN VARCHAR2, + V_DATA_COMANDA IN DATE, + V_ID IN NUMBER, + V_DATA_LIVRARE IN DATE, + V_PROC_DISCOUNT IN NUMBER, + V_INTERNA IN NUMBER, + V_ID_UTIL IN NUMBER, + V_ID_SECTIE IN NUMBER, + V_ID_ADRESA_FACTURARE in NUMBER, + V_ID_ADRESA_LIVRARE in NUMBER, + V_ID_CODCLIENT in number, + V_COMANDA_EXTERNA in varchar2, + V_ID_CTR IN NUMBER, + V_ID_COMANDA OUT NUMBER) is V_NR_INREGISTRARI NUMBER(10); V_NESTERS NUMBER(1) := 0; V_ID_PART NOM_PARTENERI.ID_PART%TYPE; @@ -362,7 +401,7 @@ create or replace package body PACK_COMENZI is V_ID_ADRESA_LIVRARE1 NUMBER(10); V_ID_CODCLIENT1 comenzi.id_codclient%TYPE; V_COMANDA_EXTERNA1 comenzi.COMANDA_EXTERNA%TYPE; - + V_ID_SUCURSALA NOM_SECTII.ID_SUCURSALA%TYPE; begin SELECT COUNT(*) INTO V_NR_INREGISTRARI @@ -433,8 +472,8 @@ create or replace package body PACK_COMENZI is V_COMANDA_EXTERNA1 := ''; END CASE; - --dbms_output.put_line(V_ID_SECTIE); - --dbms_output.put_line(V_ID_SECTIE2); + SELECT MAX(ID_SUCURSALA) INTO V_ID_SUCURSALA FROM NOM_SECTII WHERE ID_SECTIE = V_ID_SECTIE; + INSERT INTO COMENZI (NR_COMANDA, DATA_COMANDA, @@ -452,7 +491,7 @@ create or replace package body PACK_COMENZI is COMANDA_EXTERNA, ID_SUCURSALA, ID_CTR) - SELECT V_NR_COMANDA, + VALUES( V_NR_COMANDA, V_DATA_COMANDA, V_ID_GESTIUNE, V_ID_PART, @@ -466,10 +505,9 @@ create or replace package body PACK_COMENZI is V_ID_CODCLIENT1, V_PROC_DISCOUNT, V_COMANDA_EXTERNA1, - ID_SUCURSALA, - V_ID_CTR - FROM NOM_SECTII - WHERE ID_SECTIE = V_ID_SECTIE; + V_ID_SUCURSALA, + V_ID_CTR) + RETURNING ID_COMANDA INTO V_ID_COMANDA; end adauga_comanda; ---------------------------------------------------------------------------------- procedure modifica_comanda(V_ID_COMANDA IN NUMBER,