-- ==================================================================== -- P1-004: Package PACK_JSON pentru parsing JSON generic -- Sistem Import Comenzi Web → ROA -- ==================================================================== CREATE OR REPLACE PACKAGE PACK_JSON AS -- Tipuri pentru lucrul cu JSON TYPE t_json_array IS TABLE OF VARCHAR2(4000); TYPE t_json_key_value IS RECORD ( key_name VARCHAR2(100), key_value VARCHAR2(4000), key_type VARCHAR2(20) -- 'STRING', 'NUMBER', 'BOOLEAN', 'NULL' ); TYPE t_json_object IS TABLE OF t_json_key_value; -- Proprietate pentru tracking erori g_last_error VARCHAR2(4000); -- Functie pentru accesarea ultimei erori FUNCTION get_last_error RETURN VARCHAR2; -- Functie pentru resetarea erorii PROCEDURE clear_error; -- Main parsing functions FUNCTION parse_array(p_json_array IN CLOB) RETURN t_json_array PIPELINED; -- Parse [{"a":1},{"b":2}] FUNCTION get_string(p_json_object IN VARCHAR2, p_key_name IN VARCHAR2) RETURN VARCHAR2; -- Get "value" FUNCTION get_number(p_json_object IN VARCHAR2, p_key_name IN VARCHAR2) RETURN NUMBER; -- Get 123.45 FUNCTION get_boolean(p_json_object IN VARCHAR2, p_key_name IN VARCHAR2) RETURN BOOLEAN; -- Get true/false -- Advanced functions FUNCTION parse_object(p_json_object IN VARCHAR2) RETURN t_json_object PIPELINED; -- Parse to key-value pairs FUNCTION clean(p_json IN CLOB) RETURN CLOB; -- Remove whitespace/formatting -- Test functions PROCEDURE run_tests; -- Run all built-in tests FUNCTION test_basic_parsing RETURN VARCHAR2; -- Test basic JSON parsing FUNCTION test_array_parsing RETURN VARCHAR2; -- Test array parsing FUNCTION test_nested_objects RETURN VARCHAR2; -- Test nested JSON structures FUNCTION test_error_handling RETURN VARCHAR2; -- Test error conditions END PACK_JSON; / -- ==================================================================== -- Package Body - Implementarea functiilor -- ==================================================================== CREATE OR REPLACE PACKAGE BODY PACK_JSON AS /* PACK_JSON - Generic JSON Parser (Oracle 10g/11g/12c compatible) USAGE: -- Parse array: [{"key":"val"},{"key":"val2"}] FOR obj IN (SELECT * FROM TABLE(PACK_JSON.parse_array(json_clob))) LOOP v_val := PACK_JSON.get_string(obj.COLUMN_VALUE, 'key'); END LOOP; -- Get values from object: {"name":"John","age":25,"active":true} v_name := PACK_JSON.get_string(json_obj, 'name'); -- Returns: John v_age := PACK_JSON.get_number(json_obj, 'age'); -- Returns: 25 v_active := PACK_JSON.get_boolean(json_obj, 'active'); -- Returns: TRUE -- Error handling: IF PACK_JSON.get_last_error() IS NOT NULL THEN -- Handle error: PACK_JSON.get_last_error() PACK_JSON.clear_error(); END IF; FUNCTIONS: parse_array(clob) - Parse JSON array, returns table of objects get_string(obj,key) - Extract string value from JSON object get_number(obj,key) - Extract number value from JSON object get_boolean(obj,key) - Extract boolean value from JSON object get_last_error() - Get last parsing error (NULL if no error) clear_error() - Clear error state */ -- ================================================================ -- Functii 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; -- ================================================================ -- Functie utilitara pentru curatarea JSON -- ================================================================ FUNCTION clean( p_json IN CLOB ) RETURN CLOB IS v_clean CLOB; BEGIN -- Elimina spatii, tab-uri, newline-uri pentru parsing mai usor v_clean := REPLACE(REPLACE(REPLACE(REPLACE(p_json, CHR(10), ''), CHR(13), ''), CHR(9), ''), ' ', ''); RETURN v_clean; END clean; -- ================================================================ -- Parse JSON array si returneaza fiecare obiect -- ================================================================ FUNCTION parse_array( p_json_array IN CLOB ) RETURN t_json_array PIPELINED IS v_json_clean CLOB; v_articol_json VARCHAR2(4000); v_start_pos NUMBER := 1; v_end_pos NUMBER; v_bracket_count NUMBER; BEGIN -- Reset error g_last_error := NULL; -- Curata JSON-ul v_json_clean := clean(p_json_array); -- Elimina bracket-urile exterioare [ ] v_json_clean := TRIM(BOTH '[]' FROM v_json_clean); -- Parse fiecare obiect JSON din array LOOP -- Gaseste inceputul obiectului JSON { v_start_pos := INSTR(v_json_clean, '{', v_start_pos); EXIT WHEN v_start_pos = 0; -- Gaseste sfarsitul obiectului JSON } - ia in considerare nested objects v_bracket_count := 1; v_end_pos := v_start_pos; WHILE v_bracket_count > 0 AND v_end_pos < LENGTH(v_json_clean) LOOP v_end_pos := v_end_pos + 1; IF SUBSTR(v_json_clean, v_end_pos, 1) = '{' THEN v_bracket_count := v_bracket_count + 1; ELSIF SUBSTR(v_json_clean, v_end_pos, 1) = '}' THEN v_bracket_count := v_bracket_count - 1; END IF; END LOOP; -- Extrage obiectul JSON curent IF v_bracket_count = 0 THEN v_articol_json := SUBSTR(v_json_clean, v_start_pos, v_end_pos - v_start_pos + 1); PIPE ROW(v_articol_json); -- Trece la urmatorul articol v_start_pos := v_end_pos + 1; ELSE -- JSON malformat g_last_error := 'JSON malformat - bracket-uri neechilibrate'; EXIT; END IF; END LOOP; EXCEPTION WHEN OTHERS THEN g_last_error := 'Eroare la parsing array: ' || SQLERRM; END parse_array; -- ================================================================ -- Extrage valoare string din obiect JSON -- ================================================================ FUNCTION get_string( p_json_object IN VARCHAR2, p_key_name IN VARCHAR2 ) RETURN VARCHAR2 IS v_result VARCHAR2(4000); BEGIN -- Oracle 10g compatible: Extract string values v_result := REGEXP_SUBSTR(p_json_object, '"' || 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; EXCEPTION WHEN OTHERS THEN g_last_error := 'Eroare la extragere string pentru ' || p_key_name || ': ' || SQLERRM; RETURN NULL; END get_string; -- ================================================================ -- Extrage valoare numerica din obiect JSON -- ================================================================ FUNCTION get_number( p_json_object IN VARCHAR2, p_key_name IN VARCHAR2 ) RETURN NUMBER IS v_result_str VARCHAR2(100); v_result NUMBER; BEGIN -- 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]+\.?[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: "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]+\.?[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 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; EXCEPTION WHEN OTHERS THEN g_last_error := 'Eroare la extragere number pentru ' || p_key_name || ': ' || SQLERRM; RETURN NULL; END get_number; -- ================================================================ -- Extrage valoare boolean din obiect JSON -- ================================================================ FUNCTION get_boolean( p_json_object IN VARCHAR2, p_key_name IN VARCHAR2 ) RETURN BOOLEAN IS v_result_str VARCHAR2(100); BEGIN -- Oracle 10g compatible: Extract boolean values v_result_str := REGEXP_SUBSTR(p_json_object, '"' || 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; ELSIF v_result_str = 'false' THEN RETURN FALSE; ELSE RETURN NULL; END IF; EXCEPTION WHEN OTHERS THEN g_last_error := 'Eroare la extragere boolean pentru ' || p_key_name || ': ' || SQLERRM; RETURN NULL; END get_boolean; -- ================================================================ -- Parse complet obiect JSON in structura cheie-valoare -- ================================================================ FUNCTION parse_object( p_json_object IN VARCHAR2 ) RETURN t_json_object PIPELINED IS v_clean_json VARCHAR2(4000); v_key VARCHAR2(100); v_value VARCHAR2(4000); v_result t_json_key_value; v_pos NUMBER := 1; v_key_start NUMBER; v_key_end NUMBER; v_value_start NUMBER; v_value_end NUMBER; BEGIN -- Curata JSON-ul si elimina { } v_clean_json := TRIM(BOTH '{}' FROM REPLACE(p_json_object, ' ', '')); -- Parse fiecare pereche key:value WHILE v_pos < LENGTH(v_clean_json) LOOP -- Gaseste cheia v_key_start := INSTR(v_clean_json, '"', v_pos); EXIT WHEN v_key_start = 0; v_key_end := INSTR(v_clean_json, '"', v_key_start + 1); EXIT WHEN v_key_end = 0; v_key := SUBSTR(v_clean_json, v_key_start + 1, v_key_end - v_key_start - 1); -- Gaseste valoarea v_value_start := INSTR(v_clean_json, ':', v_key_end); EXIT WHEN v_value_start = 0; v_value_start := v_value_start + 1; -- Determina tipul si extrage valoarea IF SUBSTR(v_clean_json, v_value_start, 1) = '"' THEN -- String value v_value_end := INSTR(v_clean_json, '"', v_value_start + 1); v_value := SUBSTR(v_clean_json, v_value_start + 1, v_value_end - v_value_start - 1); v_result.key_type := 'STRING'; v_pos := v_value_end + 1; ELSE -- Number, boolean sau null v_value_end := NVL(INSTR(v_clean_json, ',', v_value_start), LENGTH(v_clean_json) + 1); v_value := SUBSTR(v_clean_json, v_value_start, v_value_end - v_value_start); IF v_value IN ('true', 'false') THEN v_result.key_type := 'BOOLEAN'; ELSIF v_value = 'null' THEN v_result.key_type := 'NULL'; ELSIF REGEXP_LIKE(v_value, '^[0-9.]+$') THEN v_result.key_type := 'NUMBER'; ELSE v_result.key_type := 'UNKNOWN'; END IF; v_pos := v_value_end + 1; END IF; v_result.key_name := v_key; v_result.key_value := v_value; PIPE ROW(v_result); END LOOP; EXCEPTION WHEN OTHERS THEN g_last_error := 'Eroare la parsing obiect: ' || SQLERRM; END parse_object; -- ================================================================ -- Functii de testare -- ================================================================ FUNCTION test_basic_parsing RETURN VARCHAR2 IS v_test_json VARCHAR2(1000) := '{"name":"John","age":25,"active":true,"score":98.5}'; v_name VARCHAR2(100); v_age NUMBER; v_active BOOLEAN; v_score NUMBER; v_result VARCHAR2(4000) := 'BASIC_PARSING: '; BEGIN clear_error(); v_name := get_string(v_test_json, 'name'); v_age := get_number(v_test_json, 'age'); v_active := get_boolean(v_test_json, 'active'); v_score := get_number(v_test_json, 'score'); -- Validate results IF v_name = 'John' AND v_age = 25 AND v_active = TRUE AND v_score = 98.5 THEN v_result := v_result || 'PASS - All values extracted correctly'; ELSE v_result := v_result || 'FAIL - Values: name=' || v_name || ', age=' || v_age || ', score=' || v_score; END IF; IF get_last_error() IS NOT NULL THEN v_result := v_result || ' ERROR: ' || get_last_error(); END IF; RETURN v_result; EXCEPTION WHEN OTHERS THEN RETURN 'BASIC_PARSING: EXCEPTION - ' || SQLERRM; END test_basic_parsing; FUNCTION test_array_parsing RETURN VARCHAR2 IS v_test_array CLOB := '[{"sku":"PROD1","price":10.5},{"sku":"PROD2","price":25.0}]'; v_count NUMBER := 0; v_sku VARCHAR2(100); v_price NUMBER; v_result VARCHAR2(4000) := 'ARRAY_PARSING: '; BEGIN clear_error(); FOR obj IN (SELECT * FROM TABLE(parse_array(v_test_array))) LOOP v_count := v_count + 1; v_sku := get_string(obj.COLUMN_VALUE, 'sku'); v_price := get_number(obj.COLUMN_VALUE, 'price'); IF v_count = 1 THEN IF v_sku != 'PROD1' OR v_price != 10.5 THEN RETURN v_result || 'FAIL - First object: sku=' || v_sku || ', price=' || v_price; END IF; ELSIF v_count = 2 THEN IF v_sku != 'PROD2' OR v_price != 25.0 THEN RETURN v_result || 'FAIL - Second object: sku=' || v_sku || ', price=' || v_price; END IF; END IF; END LOOP; IF v_count = 2 THEN v_result := v_result || 'PASS - Parsed ' || v_count || ' objects correctly'; ELSE v_result := v_result || 'FAIL - Expected 2 objects, got ' || v_count; END IF; IF get_last_error() IS NOT NULL THEN v_result := v_result || ' ERROR: ' || get_last_error(); END IF; RETURN v_result; EXCEPTION WHEN OTHERS THEN RETURN 'ARRAY_PARSING: EXCEPTION - ' || SQLERRM; END test_array_parsing; FUNCTION test_nested_objects RETURN VARCHAR2 IS v_test_nested CLOB := '[{"order":{"id":123,"items":[{"sku":"A1","qty":2}],"total":25.50}},{"order":{"id":124,"items":[{"sku":"B1","qty":1},{"sku":"C1","qty":3}],"total":45.00}}]'; v_count NUMBER := 0; v_object VARCHAR2(4000); v_order_id NUMBER; v_total NUMBER; v_result VARCHAR2(4000) := 'NESTED_OBJECTS: '; v_order_json VARCHAR2(2000); BEGIN clear_error(); -- Test parsing array cu nested objects FOR obj IN (SELECT * FROM TABLE(parse_array(v_test_nested))) LOOP v_count := v_count + 1; v_object := obj.COLUMN_VALUE; -- 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); -- Elimina "order": din fata v_order_json := REGEXP_REPLACE(v_order_json, '^"order":', ''); END IF; IF v_order_json IS NOT NULL THEN v_order_id := get_number(v_order_json, 'id'); v_total := get_number(v_order_json, 'total'); IF v_count = 1 THEN IF v_order_id != 123 OR v_total != 25.50 THEN RETURN v_result || 'FAIL - First nested: id=' || v_order_id || ', total=' || v_total; END IF; ELSIF v_count = 2 THEN IF v_order_id != 124 OR v_total != 45.00 THEN RETURN v_result || 'FAIL - Second nested: id=' || v_order_id || ', total=' || v_total; END IF; END IF; ELSE RETURN v_result || 'FAIL - Could not extract nested order object from: ' || SUBSTR(v_object, 1, 100); END IF; END LOOP; IF v_count = 2 THEN v_result := v_result || 'PASS - Parsed ' || v_count || ' nested objects correctly'; ELSE v_result := v_result || 'FAIL - Expected 2 nested objects, got ' || v_count; END IF; IF get_last_error() IS NOT NULL THEN v_result := v_result || ' ERROR: ' || get_last_error(); END IF; RETURN v_result; EXCEPTION WHEN OTHERS THEN RETURN 'NESTED_OBJECTS: EXCEPTION - ' || SQLERRM; END test_nested_objects; FUNCTION test_error_handling RETURN VARCHAR2 IS v_result VARCHAR2(4000) := 'ERROR_HANDLING: '; v_invalid_json VARCHAR2(1000) := '{"broken":}'; v_value VARCHAR2(100); BEGIN clear_error(); -- 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; -- 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); clear_error(); ELSE v_result := v_result || 'FAIL - No error captured for invalid operations'; END IF; -- Test error clearing IF get_last_error() IS NULL THEN v_result := v_result || ' - Error cleared successfully'; ELSE v_result := v_result || ' - Error not cleared properly'; END IF; RETURN v_result; EXCEPTION WHEN OTHERS THEN RETURN 'ERROR_HANDLING: EXCEPTION - ' || SQLERRM; END test_error_handling; PROCEDURE run_tests IS v_test_result VARCHAR2(4000); BEGIN DBMS_OUTPUT.PUT_LINE('=== PACK_JSON Test Suite ==='); DBMS_OUTPUT.PUT_LINE(''); -- Test 1: Basic parsing v_test_result := test_basic_parsing(); DBMS_OUTPUT.PUT_LINE(v_test_result); -- Test 2: Array parsing v_test_result := test_array_parsing(); DBMS_OUTPUT.PUT_LINE(v_test_result); -- Test 3: Nested objects v_test_result := test_nested_objects(); DBMS_OUTPUT.PUT_LINE(v_test_result); -- Test 4: Error handling v_test_result := test_error_handling(); DBMS_OUTPUT.PUT_LINE(v_test_result); DBMS_OUTPUT.PUT_LINE(''); DBMS_OUTPUT.PUT_LINE('=== Test Suite Complete ==='); EXCEPTION WHEN OTHERS THEN DBMS_OUTPUT.PUT_LINE('ERROR in run_tests: ' || SQLERRM); END run_tests; END PACK_JSON; / -- ==================================================================== -- Grant-uri pentru utilizarea package-ului -- ==================================================================== -- GRANT EXECUTE ON PACK_JSON TO PUBLIC;