diff --git a/contrib/ivorysql_ora/Makefile b/contrib/ivorysql_ora/Makefile index f7d654bc8d2..7f6a7262d5a 100644 --- a/contrib/ivorysql_ora/Makefile +++ b/contrib/ivorysql_ora/Makefile @@ -27,7 +27,8 @@ OBJS = \ src/builtin_functions/misc_functions.o \ src/merge/ora_merge.o \ src/sysview/sysview_functions.o \ - src/xml_functions/ora_xml_functions.o + src/xml_functions/ora_xml_functions.o \ + src/builtin_packages/dbms_utility/dbms_utility.o EXTENSION = ivorysql_ora @@ -69,10 +70,14 @@ ORA_REGRESS = \ datatype_and_func_bugs \ ora_sysview \ ora_like_operator \ - ora_xml_functions + ora_xml_functions \ + dbms_utility SHLIB_LINK += -lxml2 +# Include path for plisql.h (needed by dbms_utility) +PG_CPPFLAGS += -I$(top_srcdir)/src/pl/plisql/src + ifdef USE_PGXS PG_CONFIG = pg_config PGXS := $(shell $(PG_CONFIG) --pgxs) diff --git a/contrib/ivorysql_ora/expected/dbms_utility.out b/contrib/ivorysql_ora/expected/dbms_utility.out new file mode 100644 index 00000000000..eb556714e92 --- /dev/null +++ b/contrib/ivorysql_ora/expected/dbms_utility.out @@ -0,0 +1,416 @@ +-- +-- Tests for DBMS_UTILITY package +-- +-- Test 1: FORMAT_ERROR_BACKTRACE - Basic exception in procedure +CREATE OR REPLACE PROCEDURE test_basic_error AS + v_backtrace VARCHAR2(4000); +BEGIN + RAISE EXCEPTION 'Test error'; +EXCEPTION + WHEN OTHERS THEN + v_backtrace := DBMS_UTILITY.FORMAT_ERROR_BACKTRACE; + RAISE INFO 'Backtrace: %', v_backtrace; +END; +/ +CALL test_basic_error(); +INFO: Backtrace: ORA-06512: at "PUBLIC.TEST_BASIC_ERROR", line 3 + +DROP PROCEDURE test_basic_error; +-- Test 2: FORMAT_ERROR_BACKTRACE - Nested procedure calls +CREATE OR REPLACE PROCEDURE test_level3 AS +BEGIN + RAISE EXCEPTION 'Error at level 3'; +END; +/ +CREATE OR REPLACE PROCEDURE test_level2 AS +BEGIN + test_level3(); +END; +/ +CREATE OR REPLACE PROCEDURE test_level1 AS + v_backtrace VARCHAR2(4000); +BEGIN + test_level2(); +EXCEPTION + WHEN OTHERS THEN + v_backtrace := DBMS_UTILITY.FORMAT_ERROR_BACKTRACE; + RAISE INFO 'Backtrace: %', v_backtrace; +END; +/ +CALL test_level1(); +INFO: Backtrace: ORA-06512: at "PUBLIC.TEST_LEVEL3", line 2 +ORA-06512: at "PUBLIC.TEST_LEVEL2", line 2 +ORA-06512: at "PUBLIC.TEST_LEVEL1", line 3 + +DROP PROCEDURE test_level1; +DROP PROCEDURE test_level2; +DROP PROCEDURE test_level3; +-- Test 3: FORMAT_ERROR_BACKTRACE - Deeply nested calls +CREATE OR REPLACE PROCEDURE test_deep5 AS +BEGIN + RAISE EXCEPTION 'Error at deepest level'; +END; +/ +CREATE OR REPLACE PROCEDURE test_deep4 AS +BEGIN + test_deep5(); +END; +/ +CREATE OR REPLACE PROCEDURE test_deep3 AS +BEGIN + test_deep4(); +END; +/ +CREATE OR REPLACE PROCEDURE test_deep2 AS +BEGIN + test_deep3(); +END; +/ +CREATE OR REPLACE PROCEDURE test_deep1 AS + v_backtrace VARCHAR2(4000); +BEGIN + test_deep2(); +EXCEPTION + WHEN OTHERS THEN + v_backtrace := DBMS_UTILITY.FORMAT_ERROR_BACKTRACE; + RAISE INFO 'Deep backtrace: %', v_backtrace; +END; +/ +CALL test_deep1(); +INFO: Deep backtrace: ORA-06512: at "PUBLIC.TEST_DEEP5", line 2 +ORA-06512: at "PUBLIC.TEST_DEEP4", line 2 +ORA-06512: at "PUBLIC.TEST_DEEP3", line 2 +ORA-06512: at "PUBLIC.TEST_DEEP2", line 2 +ORA-06512: at "PUBLIC.TEST_DEEP1", line 3 + +DROP PROCEDURE test_deep1; +DROP PROCEDURE test_deep2; +DROP PROCEDURE test_deep3; +DROP PROCEDURE test_deep4; +DROP PROCEDURE test_deep5; +-- Test 4: FORMAT_ERROR_BACKTRACE - Function calls +CREATE OR REPLACE FUNCTION test_func_error RETURN NUMBER AS +BEGIN + RAISE EXCEPTION 'Error in function'; + RETURN 1; +END; +/ +CREATE OR REPLACE PROCEDURE test_func_caller AS + v_result NUMBER; + v_backtrace VARCHAR2(4000); +BEGIN + v_result := test_func_error(); +EXCEPTION + WHEN OTHERS THEN + v_backtrace := DBMS_UTILITY.FORMAT_ERROR_BACKTRACE; + RAISE INFO 'Function backtrace: %', v_backtrace; +END; +/ +CALL test_func_caller(); +INFO: Function backtrace: ORA-06512: at "PUBLIC.TEST_FUNC_ERROR", line 2 +ORA-06512: at "PUBLIC.TEST_FUNC_CALLER", line 4 + +DROP PROCEDURE test_func_caller; +DROP FUNCTION test_func_error; +-- Test 5: FORMAT_ERROR_BACKTRACE - Anonymous block +DO $$ +DECLARE + v_backtrace VARCHAR2(4000); +BEGIN + RAISE EXCEPTION 'Error in anonymous block'; +EXCEPTION + WHEN OTHERS THEN + v_backtrace := DBMS_UTILITY.FORMAT_ERROR_BACKTRACE; + RAISE INFO 'Anonymous block backtrace: %', v_backtrace; +END; +$$; +INFO: Anonymous block backtrace: ORA-06512: at line 5 + +-- Test 6: FORMAT_ERROR_BACKTRACE - No exception (should return empty) +CREATE OR REPLACE PROCEDURE test_no_error AS + v_backtrace VARCHAR2(4000); +BEGIN + v_backtrace := DBMS_UTILITY.FORMAT_ERROR_BACKTRACE; + RAISE INFO 'No error - backtrace: [%]', v_backtrace; +END; +/ +CALL test_no_error(); +INFO: No error - backtrace: [] +DROP PROCEDURE test_no_error; +-- Test 7: FORMAT_ERROR_BACKTRACE - Multiple exception levels +CREATE OR REPLACE PROCEDURE test_multi_inner AS +BEGIN + RAISE EXCEPTION 'Inner error'; +END; +/ +CREATE OR REPLACE PROCEDURE test_multi_middle AS +BEGIN + BEGIN + test_multi_inner(); + EXCEPTION + WHEN OTHERS THEN + RAISE INFO 'Caught at middle level'; + RAISE; + END; +END; +/ +CREATE OR REPLACE PROCEDURE test_multi_outer AS + v_backtrace VARCHAR2(4000); +BEGIN + test_multi_middle(); +EXCEPTION + WHEN OTHERS THEN + v_backtrace := DBMS_UTILITY.FORMAT_ERROR_BACKTRACE; + RAISE INFO 'Outer backtrace: %', v_backtrace; +END; +/ +CALL test_multi_outer(); +INFO: Caught at middle level +INFO: Outer backtrace: ORA-06512: at "PUBLIC.TEST_MULTI_INNER", line 2 +ORA-06512: at "PUBLIC.TEST_MULTI_MIDDLE", line 3 +ORA-06512: at "PUBLIC.TEST_MULTI_OUTER", line 3 + +DROP PROCEDURE test_multi_outer; +DROP PROCEDURE test_multi_middle; +DROP PROCEDURE test_multi_inner; +-- Test 8: FORMAT_ERROR_BACKTRACE - Package procedure +CREATE OR REPLACE PACKAGE test_pkg IS + PROCEDURE pkg_error; + PROCEDURE pkg_caller; +END test_pkg; +/ +CREATE OR REPLACE PACKAGE BODY test_pkg IS + PROCEDURE pkg_error IS + BEGIN + RAISE EXCEPTION 'Error in package procedure'; + END pkg_error; + PROCEDURE pkg_caller IS + v_backtrace VARCHAR2(4000); + BEGIN + pkg_error(); + EXCEPTION + WHEN OTHERS THEN + v_backtrace := DBMS_UTILITY.FORMAT_ERROR_BACKTRACE; + RAISE INFO 'Package backtrace: %', v_backtrace; + END pkg_caller; +END test_pkg; +/ +CALL test_pkg.pkg_caller(); +INFO: Package backtrace: ORA-06512: at "PUBLIC.PKG_ERROR", line 3 +ORA-06512: at "PUBLIC.PKG_CALLER", line 8 + +DROP PACKAGE test_pkg; +-- Test 9: FORMAT_ERROR_BACKTRACE - Schema-qualified calls +CREATE SCHEMA test_schema; +CREATE OR REPLACE PROCEDURE test_schema.schema_error AS +BEGIN + RAISE EXCEPTION 'Error in schema procedure'; +END; +/ +CREATE OR REPLACE PROCEDURE test_schema.schema_caller AS + v_backtrace VARCHAR2(4000); +BEGIN + test_schema.schema_error(); +EXCEPTION + WHEN OTHERS THEN + v_backtrace := DBMS_UTILITY.FORMAT_ERROR_BACKTRACE; + RAISE INFO 'Schema-qualified backtrace: %', v_backtrace; +END; +/ +CALL test_schema.schema_caller(); +INFO: Schema-qualified backtrace: ORA-06512: at "PUBLIC.TEST_SCHEMA.SCHEMA_ERROR", line 2 +ORA-06512: at "PUBLIC.TEST_SCHEMA.SCHEMA_CALLER", line 3 + +DROP SCHEMA test_schema CASCADE; +NOTICE: drop cascades to 2 other objects +DETAIL: drop cascades to function test_schema.schema_error() +drop cascades to function test_schema.schema_caller() +-- Test 10: Nested exception handlers - outer context preserved after inner handler +-- This tests that when an exception handler calls a procedure that has its own +-- exception handler, the outer handler's backtrace is preserved. +CREATE OR REPLACE PROCEDURE test_nested_inner AS +BEGIN + RAISE EXCEPTION 'Inner error'; +EXCEPTION + WHEN OTHERS THEN + RAISE INFO 'Inner handler caught error'; +END; +/ +CREATE OR REPLACE PROCEDURE test_nested_outer AS + v_bt_before VARCHAR2(4000); + v_bt_after VARCHAR2(4000); +BEGIN + RAISE EXCEPTION 'Outer error'; +EXCEPTION + WHEN OTHERS THEN + v_bt_before := DBMS_UTILITY.FORMAT_ERROR_BACKTRACE; + RAISE INFO 'Outer backtrace before: %', v_bt_before; + test_nested_inner(); + v_bt_after := DBMS_UTILITY.FORMAT_ERROR_BACKTRACE; + RAISE INFO 'Outer backtrace after: %', v_bt_after; + IF v_bt_before = v_bt_after THEN + RAISE INFO 'SUCCESS: Outer backtrace preserved'; + ELSE + RAISE INFO 'FAILURE: Outer backtrace changed'; + END IF; +END; +/ +CALL test_nested_outer(); +INFO: Outer backtrace before: ORA-06512: at "PUBLIC.TEST_NESTED_OUTER", line 4 + +INFO: Inner handler caught error +INFO: Outer backtrace after: ORA-06512: at "PUBLIC.TEST_NESTED_OUTER", line 4 + +INFO: SUCCESS: Outer backtrace preserved +DROP PROCEDURE test_nested_outer; +DROP PROCEDURE test_nested_inner; +-- ============================================================ +-- Tests for FORMAT_ERROR_STACK +-- ============================================================ +-- Test 11: FORMAT_ERROR_STACK - Basic exception +CREATE OR REPLACE PROCEDURE test_error_stack_basic AS + v_stack VARCHAR2(4000); +BEGIN + RAISE EXCEPTION 'Test error message'; +EXCEPTION + WHEN OTHERS THEN + v_stack := DBMS_UTILITY.FORMAT_ERROR_STACK; + RAISE INFO 'Error stack: %', v_stack; +END; +/ +CALL test_error_stack_basic(); +INFO: Error stack: ORA-06510: Test error message + +DROP PROCEDURE test_error_stack_basic; +-- Test 12: FORMAT_ERROR_STACK - Division by zero +CREATE OR REPLACE PROCEDURE test_error_stack_divzero AS + v_stack VARCHAR2(4000); + v_num NUMBER; +BEGIN + v_num := 1 / 0; +EXCEPTION + WHEN OTHERS THEN + v_stack := DBMS_UTILITY.FORMAT_ERROR_STACK; + RAISE INFO 'Division error stack: %', v_stack; +END; +/ +CALL test_error_stack_divzero(); +INFO: Division error stack: ORA-01476: division by zero + +DROP PROCEDURE test_error_stack_divzero; +-- Test 13: FORMAT_ERROR_STACK - No exception (should return NULL) +CREATE OR REPLACE PROCEDURE test_error_stack_no_error AS + v_stack VARCHAR2(4000); +BEGIN + v_stack := DBMS_UTILITY.FORMAT_ERROR_STACK; + RAISE INFO 'No error - stack: [%]', v_stack; +END; +/ +CALL test_error_stack_no_error(); +INFO: No error - stack: [] +DROP PROCEDURE test_error_stack_no_error; +-- ============================================================ +-- Tests for FORMAT_CALL_STACK +-- ============================================================ +-- Test 14: FORMAT_CALL_STACK - Basic single procedure (verify structure) +-- Note: Addresses vary between runs, so we just verify the stack is not null +-- and contains the expected function name pattern +CREATE OR REPLACE PROCEDURE test_call_stack_basic AS + v_stack VARCHAR2(4000); +BEGIN + v_stack := DBMS_UTILITY.FORMAT_CALL_STACK; + IF v_stack IS NOT NULL AND v_stack LIKE '%----- PL/SQL Call Stack -----%' THEN + -- Extract just the function name part for verification + IF v_stack LIKE '%TEST_CALL_STACK_BASIC%' THEN + RAISE INFO 'Call stack contains expected function'; + END IF; + END IF; +END; +/ +CALL test_call_stack_basic(); +INFO: Call stack contains expected function +DROP PROCEDURE test_call_stack_basic; +-- Test 15: FORMAT_CALL_STACK - Nested procedure calls (verify count) +CREATE OR REPLACE PROCEDURE test_call_stack_level3 AS + v_stack VARCHAR2(4000); + v_count INTEGER; +BEGIN + v_stack := DBMS_UTILITY.FORMAT_CALL_STACK; + -- Count the number of function entries (look for 'function ' pattern) + v_count := (LENGTH(v_stack) - LENGTH(REPLACE(v_stack, 'function ', ''))) / 9; + RAISE INFO 'Call stack has % function entries', v_count; +END; +/ +CREATE OR REPLACE PROCEDURE test_call_stack_level2 AS +BEGIN + test_call_stack_level3(); +END; +/ +CREATE OR REPLACE PROCEDURE test_call_stack_level1 AS +BEGIN + test_call_stack_level2(); +END; +/ +CALL test_call_stack_level1(); +INFO: Call stack has 3 function entries +DROP PROCEDURE test_call_stack_level1; +DROP PROCEDURE test_call_stack_level2; +DROP PROCEDURE test_call_stack_level3; +-- Test 16: FORMAT_CALL_STACK - In exception handler +CREATE OR REPLACE PROCEDURE test_call_stack_exception AS + v_stack VARCHAR2(4000); +BEGIN + RAISE EXCEPTION 'Test error'; +EXCEPTION + WHEN OTHERS THEN + v_stack := DBMS_UTILITY.FORMAT_CALL_STACK; + IF v_stack IS NOT NULL AND v_stack LIKE '%TEST_CALL_STACK_EXCEPTION%' THEN + RAISE INFO 'Call stack in exception handler: OK'; + END IF; +END; +/ +CALL test_call_stack_exception(); +INFO: Call stack in exception handler: OK +DROP PROCEDURE test_call_stack_exception; +-- Test 17: All three functions together (verify they return expected content) +CREATE OR REPLACE PROCEDURE test_all_functions_inner AS +BEGIN + RAISE EXCEPTION 'Inner error for all functions test'; +END; +/ +CREATE OR REPLACE PROCEDURE test_all_functions_outer AS + v_backtrace VARCHAR2(4000); + v_error_stack VARCHAR2(4000); + v_call_stack VARCHAR2(4000); + v_all_ok BOOLEAN := TRUE; +BEGIN + test_all_functions_inner(); +EXCEPTION + WHEN OTHERS THEN + v_backtrace := DBMS_UTILITY.FORMAT_ERROR_BACKTRACE; + v_error_stack := DBMS_UTILITY.FORMAT_ERROR_STACK; + v_call_stack := DBMS_UTILITY.FORMAT_CALL_STACK; + -- Verify FORMAT_ERROR_BACKTRACE + IF v_backtrace IS NULL OR v_backtrace NOT LIKE '%ORA-06512%' THEN + v_all_ok := FALSE; + RAISE INFO 'FORMAT_ERROR_BACKTRACE: FAILED'; + END IF; + -- Verify FORMAT_ERROR_STACK + IF v_error_stack IS NULL OR v_error_stack NOT LIKE '%ORA-%' THEN + v_all_ok := FALSE; + RAISE INFO 'FORMAT_ERROR_STACK: FAILED'; + END IF; + -- Verify FORMAT_CALL_STACK + IF v_call_stack IS NULL OR v_call_stack NOT LIKE '%----- PL/SQL Call Stack -----%' THEN + v_all_ok := FALSE; + RAISE INFO 'FORMAT_CALL_STACK: FAILED'; + END IF; + IF v_all_ok THEN + RAISE INFO 'All three DBMS_UTILITY functions: OK'; + END IF; +END; +/ +CALL test_all_functions_outer(); +INFO: All three DBMS_UTILITY functions: OK +DROP PROCEDURE test_all_functions_outer; +DROP PROCEDURE test_all_functions_inner; diff --git a/contrib/ivorysql_ora/ivorysql_ora_merge_sqls b/contrib/ivorysql_ora/ivorysql_ora_merge_sqls index 42c3e752922..20b3f29ee08 100644 --- a/contrib/ivorysql_ora/ivorysql_ora_merge_sqls +++ b/contrib/ivorysql_ora/ivorysql_ora_merge_sqls @@ -2,3 +2,4 @@ src/datatype/datatype src/builtin_functions/builtin_functions src/sysview/sysview src/xml_functions/xml_functions +src/builtin_packages/dbms_utility/dbms_utility diff --git a/contrib/ivorysql_ora/meson.build b/contrib/ivorysql_ora/meson.build index d16cba8d7bd..47c6d2df4d0 100644 --- a/contrib/ivorysql_ora/meson.build +++ b/contrib/ivorysql_ora/meson.build @@ -26,6 +26,7 @@ ivorysql_ora_sources = files( 'src/merge/ora_merge.c', 'src/sysview/sysview_functions.c', 'src/xml_functions/ora_xml_functions.c', + 'src/builtin_packages/dbms_utility/dbms_utility.c', ) if host_system == 'windows' @@ -44,6 +45,7 @@ custom_target('ivorysql_ora--1.0.sql', ivorysql_ora = shared_module('ivorysql_ora', ivorysql_ora_sources, + include_directories: plisql_inc, kwargs: contrib_mod_args, ) contrib_targets += ivorysql_ora @@ -64,16 +66,29 @@ tests += { 'bd': meson.current_build_dir(), 'regress': { 'sql': [ - 'check', - 'check_btree', - 'check_heap', - ], - }, - 'tap': { - 'tests': [ - 't/001_verify_heapam.pl', - 't/002_cic.pl', - 't/003_cic_2pc.pl', + 'ora_character', + 'ora_datetime', + 'ora_interval', + 'ora_number', + 'ora_binary_float', + 'ora_binary_double', + 'ora_raw_long', + 'ora_character_datatype_functions', + 'ora_datetime_datatype_functions', + 'ora_misc_functions', + 'ora_merge', + 'datatype_and_func_bugs', + 'ora_sysview', + 'ora_like_operator', + 'ora_xml_functions', + 'dbms_utility', ], + 'tap': { + 'tests': [ + 't/001_verify_heapam.pl', + 't/002_cic.pl', + 't/003_cic_2pc.pl', + ] + }, }, } diff --git a/contrib/ivorysql_ora/sql/dbms_utility.sql b/contrib/ivorysql_ora/sql/dbms_utility.sql new file mode 100644 index 00000000000..f5500223e1c --- /dev/null +++ b/contrib/ivorysql_ora/sql/dbms_utility.sql @@ -0,0 +1,441 @@ +-- +-- Tests for DBMS_UTILITY package +-- + +-- Test 1: FORMAT_ERROR_BACKTRACE - Basic exception in procedure +CREATE OR REPLACE PROCEDURE test_basic_error AS + v_backtrace VARCHAR2(4000); +BEGIN + RAISE EXCEPTION 'Test error'; +EXCEPTION + WHEN OTHERS THEN + v_backtrace := DBMS_UTILITY.FORMAT_ERROR_BACKTRACE; + RAISE INFO 'Backtrace: %', v_backtrace; +END; +/ + +CALL test_basic_error(); + +DROP PROCEDURE test_basic_error; + +-- Test 2: FORMAT_ERROR_BACKTRACE - Nested procedure calls +CREATE OR REPLACE PROCEDURE test_level3 AS +BEGIN + RAISE EXCEPTION 'Error at level 3'; +END; +/ + +CREATE OR REPLACE PROCEDURE test_level2 AS +BEGIN + test_level3(); +END; +/ + +CREATE OR REPLACE PROCEDURE test_level1 AS + v_backtrace VARCHAR2(4000); +BEGIN + test_level2(); +EXCEPTION + WHEN OTHERS THEN + v_backtrace := DBMS_UTILITY.FORMAT_ERROR_BACKTRACE; + RAISE INFO 'Backtrace: %', v_backtrace; +END; +/ + +CALL test_level1(); + +DROP PROCEDURE test_level1; +DROP PROCEDURE test_level2; +DROP PROCEDURE test_level3; + +-- Test 3: FORMAT_ERROR_BACKTRACE - Deeply nested calls +CREATE OR REPLACE PROCEDURE test_deep5 AS +BEGIN + RAISE EXCEPTION 'Error at deepest level'; +END; +/ + +CREATE OR REPLACE PROCEDURE test_deep4 AS +BEGIN + test_deep5(); +END; +/ + +CREATE OR REPLACE PROCEDURE test_deep3 AS +BEGIN + test_deep4(); +END; +/ + +CREATE OR REPLACE PROCEDURE test_deep2 AS +BEGIN + test_deep3(); +END; +/ + +CREATE OR REPLACE PROCEDURE test_deep1 AS + v_backtrace VARCHAR2(4000); +BEGIN + test_deep2(); +EXCEPTION + WHEN OTHERS THEN + v_backtrace := DBMS_UTILITY.FORMAT_ERROR_BACKTRACE; + RAISE INFO 'Deep backtrace: %', v_backtrace; +END; +/ + +CALL test_deep1(); + +DROP PROCEDURE test_deep1; +DROP PROCEDURE test_deep2; +DROP PROCEDURE test_deep3; +DROP PROCEDURE test_deep4; +DROP PROCEDURE test_deep5; + +-- Test 4: FORMAT_ERROR_BACKTRACE - Function calls +CREATE OR REPLACE FUNCTION test_func_error RETURN NUMBER AS +BEGIN + RAISE EXCEPTION 'Error in function'; + RETURN 1; +END; +/ + +CREATE OR REPLACE PROCEDURE test_func_caller AS + v_result NUMBER; + v_backtrace VARCHAR2(4000); +BEGIN + v_result := test_func_error(); +EXCEPTION + WHEN OTHERS THEN + v_backtrace := DBMS_UTILITY.FORMAT_ERROR_BACKTRACE; + RAISE INFO 'Function backtrace: %', v_backtrace; +END; +/ + +CALL test_func_caller(); + +DROP PROCEDURE test_func_caller; +DROP FUNCTION test_func_error; + +-- Test 5: FORMAT_ERROR_BACKTRACE - Anonymous block +DO $$ +DECLARE + v_backtrace VARCHAR2(4000); +BEGIN + RAISE EXCEPTION 'Error in anonymous block'; +EXCEPTION + WHEN OTHERS THEN + v_backtrace := DBMS_UTILITY.FORMAT_ERROR_BACKTRACE; + RAISE INFO 'Anonymous block backtrace: %', v_backtrace; +END; +$$; + +-- Test 6: FORMAT_ERROR_BACKTRACE - No exception (should return empty) +CREATE OR REPLACE PROCEDURE test_no_error AS + v_backtrace VARCHAR2(4000); +BEGIN + v_backtrace := DBMS_UTILITY.FORMAT_ERROR_BACKTRACE; + RAISE INFO 'No error - backtrace: [%]', v_backtrace; +END; +/ + +CALL test_no_error(); + +DROP PROCEDURE test_no_error; + +-- Test 7: FORMAT_ERROR_BACKTRACE - Multiple exception levels +CREATE OR REPLACE PROCEDURE test_multi_inner AS +BEGIN + RAISE EXCEPTION 'Inner error'; +END; +/ + +CREATE OR REPLACE PROCEDURE test_multi_middle AS +BEGIN + BEGIN + test_multi_inner(); + EXCEPTION + WHEN OTHERS THEN + RAISE INFO 'Caught at middle level'; + RAISE; + END; +END; +/ + +CREATE OR REPLACE PROCEDURE test_multi_outer AS + v_backtrace VARCHAR2(4000); +BEGIN + test_multi_middle(); +EXCEPTION + WHEN OTHERS THEN + v_backtrace := DBMS_UTILITY.FORMAT_ERROR_BACKTRACE; + RAISE INFO 'Outer backtrace: %', v_backtrace; +END; +/ + +CALL test_multi_outer(); + +DROP PROCEDURE test_multi_outer; +DROP PROCEDURE test_multi_middle; +DROP PROCEDURE test_multi_inner; + +-- Test 8: FORMAT_ERROR_BACKTRACE - Package procedure +CREATE OR REPLACE PACKAGE test_pkg IS + PROCEDURE pkg_error; + PROCEDURE pkg_caller; +END test_pkg; +/ + +CREATE OR REPLACE PACKAGE BODY test_pkg IS + PROCEDURE pkg_error IS + BEGIN + RAISE EXCEPTION 'Error in package procedure'; + END pkg_error; + + PROCEDURE pkg_caller IS + v_backtrace VARCHAR2(4000); + BEGIN + pkg_error(); + EXCEPTION + WHEN OTHERS THEN + v_backtrace := DBMS_UTILITY.FORMAT_ERROR_BACKTRACE; + RAISE INFO 'Package backtrace: %', v_backtrace; + END pkg_caller; +END test_pkg; +/ + +CALL test_pkg.pkg_caller(); + +DROP PACKAGE test_pkg; + +-- Test 9: FORMAT_ERROR_BACKTRACE - Schema-qualified calls +CREATE SCHEMA test_schema; + +CREATE OR REPLACE PROCEDURE test_schema.schema_error AS +BEGIN + RAISE EXCEPTION 'Error in schema procedure'; +END; +/ + +CREATE OR REPLACE PROCEDURE test_schema.schema_caller AS + v_backtrace VARCHAR2(4000); +BEGIN + test_schema.schema_error(); +EXCEPTION + WHEN OTHERS THEN + v_backtrace := DBMS_UTILITY.FORMAT_ERROR_BACKTRACE; + RAISE INFO 'Schema-qualified backtrace: %', v_backtrace; +END; +/ + +CALL test_schema.schema_caller(); + +DROP SCHEMA test_schema CASCADE; + +-- Test 10: Nested exception handlers - outer context preserved after inner handler +-- This tests that when an exception handler calls a procedure that has its own +-- exception handler, the outer handler's backtrace is preserved. +CREATE OR REPLACE PROCEDURE test_nested_inner AS +BEGIN + RAISE EXCEPTION 'Inner error'; +EXCEPTION + WHEN OTHERS THEN + RAISE INFO 'Inner handler caught error'; +END; +/ + +CREATE OR REPLACE PROCEDURE test_nested_outer AS + v_bt_before VARCHAR2(4000); + v_bt_after VARCHAR2(4000); +BEGIN + RAISE EXCEPTION 'Outer error'; +EXCEPTION + WHEN OTHERS THEN + v_bt_before := DBMS_UTILITY.FORMAT_ERROR_BACKTRACE; + RAISE INFO 'Outer backtrace before: %', v_bt_before; + test_nested_inner(); + v_bt_after := DBMS_UTILITY.FORMAT_ERROR_BACKTRACE; + RAISE INFO 'Outer backtrace after: %', v_bt_after; + IF v_bt_before = v_bt_after THEN + RAISE INFO 'SUCCESS: Outer backtrace preserved'; + ELSE + RAISE INFO 'FAILURE: Outer backtrace changed'; + END IF; +END; +/ + +CALL test_nested_outer(); + +DROP PROCEDURE test_nested_outer; +DROP PROCEDURE test_nested_inner; + +-- ============================================================ +-- Tests for FORMAT_ERROR_STACK +-- ============================================================ + +-- Test 11: FORMAT_ERROR_STACK - Basic exception +CREATE OR REPLACE PROCEDURE test_error_stack_basic AS + v_stack VARCHAR2(4000); +BEGIN + RAISE EXCEPTION 'Test error message'; +EXCEPTION + WHEN OTHERS THEN + v_stack := DBMS_UTILITY.FORMAT_ERROR_STACK; + RAISE INFO 'Error stack: %', v_stack; +END; +/ + +CALL test_error_stack_basic(); + +DROP PROCEDURE test_error_stack_basic; + +-- Test 12: FORMAT_ERROR_STACK - Division by zero +CREATE OR REPLACE PROCEDURE test_error_stack_divzero AS + v_stack VARCHAR2(4000); + v_num NUMBER; +BEGIN + v_num := 1 / 0; +EXCEPTION + WHEN OTHERS THEN + v_stack := DBMS_UTILITY.FORMAT_ERROR_STACK; + RAISE INFO 'Division error stack: %', v_stack; +END; +/ + +CALL test_error_stack_divzero(); + +DROP PROCEDURE test_error_stack_divzero; + +-- Test 13: FORMAT_ERROR_STACK - No exception (should return NULL) +CREATE OR REPLACE PROCEDURE test_error_stack_no_error AS + v_stack VARCHAR2(4000); +BEGIN + v_stack := DBMS_UTILITY.FORMAT_ERROR_STACK; + RAISE INFO 'No error - stack: [%]', v_stack; +END; +/ + +CALL test_error_stack_no_error(); + +DROP PROCEDURE test_error_stack_no_error; + +-- ============================================================ +-- Tests for FORMAT_CALL_STACK +-- ============================================================ + +-- Test 14: FORMAT_CALL_STACK - Basic single procedure (verify structure) +-- Note: Addresses vary between runs, so we just verify the stack is not null +-- and contains the expected function name pattern +CREATE OR REPLACE PROCEDURE test_call_stack_basic AS + v_stack VARCHAR2(4000); +BEGIN + v_stack := DBMS_UTILITY.FORMAT_CALL_STACK; + IF v_stack IS NOT NULL AND v_stack LIKE '%----- PL/SQL Call Stack -----%' THEN + -- Extract just the function name part for verification + IF v_stack LIKE '%TEST_CALL_STACK_BASIC%' THEN + RAISE INFO 'Call stack contains expected function'; + END IF; + END IF; +END; +/ + +CALL test_call_stack_basic(); + +DROP PROCEDURE test_call_stack_basic; + +-- Test 15: FORMAT_CALL_STACK - Nested procedure calls (verify count) +CREATE OR REPLACE PROCEDURE test_call_stack_level3 AS + v_stack VARCHAR2(4000); + v_count INTEGER; +BEGIN + v_stack := DBMS_UTILITY.FORMAT_CALL_STACK; + -- Count the number of function entries (look for 'function ' pattern) + v_count := (LENGTH(v_stack) - LENGTH(REPLACE(v_stack, 'function ', ''))) / 9; + RAISE INFO 'Call stack has % function entries', v_count; +END; +/ + +CREATE OR REPLACE PROCEDURE test_call_stack_level2 AS +BEGIN + test_call_stack_level3(); +END; +/ + +CREATE OR REPLACE PROCEDURE test_call_stack_level1 AS +BEGIN + test_call_stack_level2(); +END; +/ + +CALL test_call_stack_level1(); + +DROP PROCEDURE test_call_stack_level1; +DROP PROCEDURE test_call_stack_level2; +DROP PROCEDURE test_call_stack_level3; + +-- Test 16: FORMAT_CALL_STACK - In exception handler +CREATE OR REPLACE PROCEDURE test_call_stack_exception AS + v_stack VARCHAR2(4000); +BEGIN + RAISE EXCEPTION 'Test error'; +EXCEPTION + WHEN OTHERS THEN + v_stack := DBMS_UTILITY.FORMAT_CALL_STACK; + IF v_stack IS NOT NULL AND v_stack LIKE '%TEST_CALL_STACK_EXCEPTION%' THEN + RAISE INFO 'Call stack in exception handler: OK'; + END IF; +END; +/ + +CALL test_call_stack_exception(); + +DROP PROCEDURE test_call_stack_exception; + +-- Test 17: All three functions together (verify they return expected content) +CREATE OR REPLACE PROCEDURE test_all_functions_inner AS +BEGIN + RAISE EXCEPTION 'Inner error for all functions test'; +END; +/ + +CREATE OR REPLACE PROCEDURE test_all_functions_outer AS + v_backtrace VARCHAR2(4000); + v_error_stack VARCHAR2(4000); + v_call_stack VARCHAR2(4000); + v_all_ok BOOLEAN := TRUE; +BEGIN + test_all_functions_inner(); +EXCEPTION + WHEN OTHERS THEN + v_backtrace := DBMS_UTILITY.FORMAT_ERROR_BACKTRACE; + v_error_stack := DBMS_UTILITY.FORMAT_ERROR_STACK; + v_call_stack := DBMS_UTILITY.FORMAT_CALL_STACK; + + -- Verify FORMAT_ERROR_BACKTRACE + IF v_backtrace IS NULL OR v_backtrace NOT LIKE '%ORA-06512%' THEN + v_all_ok := FALSE; + RAISE INFO 'FORMAT_ERROR_BACKTRACE: FAILED'; + END IF; + + -- Verify FORMAT_ERROR_STACK + IF v_error_stack IS NULL OR v_error_stack NOT LIKE '%ORA-%' THEN + v_all_ok := FALSE; + RAISE INFO 'FORMAT_ERROR_STACK: FAILED'; + END IF; + + -- Verify FORMAT_CALL_STACK + IF v_call_stack IS NULL OR v_call_stack NOT LIKE '%----- PL/SQL Call Stack -----%' THEN + v_all_ok := FALSE; + RAISE INFO 'FORMAT_CALL_STACK: FAILED'; + END IF; + + IF v_all_ok THEN + RAISE INFO 'All three DBMS_UTILITY functions: OK'; + END IF; +END; +/ + +CALL test_all_functions_outer(); + +DROP PROCEDURE test_all_functions_outer; +DROP PROCEDURE test_all_functions_inner; diff --git a/contrib/ivorysql_ora/src/builtin_packages/dbms_utility/dbms_utility--1.0.sql b/contrib/ivorysql_ora/src/builtin_packages/dbms_utility/dbms_utility--1.0.sql new file mode 100644 index 00000000000..e8bea76df74 --- /dev/null +++ b/contrib/ivorysql_ora/src/builtin_packages/dbms_utility/dbms_utility--1.0.sql @@ -0,0 +1,48 @@ +/*************************************************************** + * + * DBMS_UTILITY Package + * + * Oracle-compatible utility functions. + * + ***************************************************************/ + +-- C function wrappers +CREATE FUNCTION sys.ora_format_error_backtrace() RETURNS TEXT +AS 'MODULE_PATHNAME', 'ora_format_error_backtrace' +LANGUAGE C VOLATILE; + +CREATE FUNCTION sys.ora_format_error_stack() RETURNS TEXT +AS 'MODULE_PATHNAME', 'ora_format_error_stack' +LANGUAGE C VOLATILE; + +CREATE FUNCTION sys.ora_format_call_stack() RETURNS TEXT +AS 'MODULE_PATHNAME', 'ora_format_call_stack' +LANGUAGE C VOLATILE; + +COMMENT ON FUNCTION sys.ora_format_error_backtrace() IS 'Internal function for DBMS_UTILITY.FORMAT_ERROR_BACKTRACE'; +COMMENT ON FUNCTION sys.ora_format_error_stack() IS 'Internal function for DBMS_UTILITY.FORMAT_ERROR_STACK'; +COMMENT ON FUNCTION sys.ora_format_call_stack() IS 'Internal function for DBMS_UTILITY.FORMAT_CALL_STACK'; + +-- DBMS_UTILITY Package Definition +CREATE OR REPLACE PACKAGE dbms_utility IS + FUNCTION FORMAT_ERROR_BACKTRACE RETURN TEXT; + FUNCTION FORMAT_ERROR_STACK RETURN TEXT; + FUNCTION FORMAT_CALL_STACK RETURN TEXT; +END dbms_utility; + +CREATE OR REPLACE PACKAGE BODY dbms_utility IS + FUNCTION FORMAT_ERROR_BACKTRACE RETURN TEXT IS + BEGIN + RETURN sys.ora_format_error_backtrace(); + END; + + FUNCTION FORMAT_ERROR_STACK RETURN TEXT IS + BEGIN + RETURN sys.ora_format_error_stack(); + END; + + FUNCTION FORMAT_CALL_STACK RETURN TEXT IS + BEGIN + RETURN sys.ora_format_call_stack(); + END; +END dbms_utility; diff --git a/contrib/ivorysql_ora/src/builtin_packages/dbms_utility/dbms_utility.c b/contrib/ivorysql_ora/src/builtin_packages/dbms_utility/dbms_utility.c new file mode 100644 index 00000000000..a3c049adf92 --- /dev/null +++ b/contrib/ivorysql_ora/src/builtin_packages/dbms_utility/dbms_utility.c @@ -0,0 +1,466 @@ +/*------------------------------------------------------------------------- + * Copyright 2025 IvorySQL Global Development Team + * + * Licensed under the Apache License, Version 2.0 (the "License"); + * you may not use this file except in compliance with the License. + * You may obtain a copy of the License at + * + * http://www.apache.org/licenses/LICENSE-2.0 + * + * Unless required by applicable law or agreed to in writing, software + * distributed under the License is distributed on an "AS IS" BASIS, + * WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied. + * See the License for the specific language governing permissions and + * limitations under the License. + * + * dbms_utility.c + * + * Implementation of Oracle's DBMS_UTILITY package functions. + * This module is part of ivorysql_ora extension but calls the PL/iSQL + * API to access exception context information. + * + * Portions Copyright (c) 2025, IvorySQL Global Development Team + * + * contrib/ivorysql_ora/src/builtin_packages/dbms_utility/dbms_utility.c + * + *------------------------------------------------------------------------- + */ + +#include "postgres.h" +#include "fmgr.h" +#include "utils/builtins.h" +#include "utils/errcodes.h" +#include "mb/pg_wchar.h" + +#ifndef WIN32 +#include +#endif + +PG_FUNCTION_INFO_V1(ora_format_error_backtrace); +PG_FUNCTION_INFO_V1(ora_format_error_stack); +PG_FUNCTION_INFO_V1(ora_format_call_stack); + +/* + * Function pointer types for plisql API functions. + * We use dynamic lookup to avoid link-time dependency on plisql.so. + */ +typedef const char *(*plisql_get_context_fn)(void); +typedef const char *(*plisql_get_message_fn)(void); +typedef int (*plisql_get_sqlerrcode_fn)(void); +typedef char *(*plisql_get_call_stack_fn)(void); + +/* + * Cached function pointers for plisql functions. + * Looked up once on first use. + */ +static plisql_get_context_fn get_exception_context_fn = NULL; +static plisql_get_message_fn get_exception_message_fn = NULL; +static plisql_get_sqlerrcode_fn get_exception_sqlerrcode_fn = NULL; +static plisql_get_call_stack_fn get_call_stack_fn = NULL; +static bool lookup_attempted = false; + +/* + * Look up the plisql API functions dynamically. + * All lookups are attempted once and cached. + */ +static void +lookup_plisql_functions(void) +{ + if (lookup_attempted) + return; + + lookup_attempted = true; + +#ifndef WIN32 + /* + * Use RTLD_DEFAULT to search all loaded shared objects. + * plisql.so should already be loaded when these functions are called + * from within a PL/iSQL context. + */ + void *fn; + + fn = dlsym(RTLD_DEFAULT, "plisql_get_current_exception_context"); + if (fn != NULL) + get_exception_context_fn = (plisql_get_context_fn) fn; + + fn = dlsym(RTLD_DEFAULT, "plisql_get_current_exception_message"); + if (fn != NULL) + get_exception_message_fn = (plisql_get_message_fn) fn; + + fn = dlsym(RTLD_DEFAULT, "plisql_get_current_exception_sqlerrcode"); + if (fn != NULL) + get_exception_sqlerrcode_fn = (plisql_get_sqlerrcode_fn) fn; + + fn = dlsym(RTLD_DEFAULT, "plisql_get_call_stack"); + if (fn != NULL) + get_call_stack_fn = (plisql_get_call_stack_fn) fn; +#endif + /* On Windows, function pointers remain NULL - features require plisql */ +} + +/* + * Transform a single line from PostgreSQL error context format to Oracle format. + * + * PostgreSQL format examples: + * "PL/pgSQL function test_level3() line 3 at RAISE" + * "PL/iSQL function test_level3() line 3 at RAISE" + * "PL/iSQL function inline_code_block line 5 at CALL" + * "SQL statement \"CALL test_level3()\"" + * + * Oracle format: + * "ORA-06512: at \"SCHEMA.TEST_LEVEL3\", line 3" + * "ORA-06512: at line 5" + * + * Returns true if line was transformed and appended, false if line should be skipped. + */ +static bool +transform_and_append_line(StringInfo result, const char *line) +{ + const char *p = line; + const char *func_start; + const char *func_end; + const char *line_num_start; + const char *line_marker; + int line_num; + char *func_name; + char *schema_name; + char *func_upper; + char *schema_upper; + int i; + + /* Skip SQL statement lines */ + if (strncmp(line, "SQL statement", 13) == 0) + return false; + + /* Look for "PL/pgSQL function" or "PL/iSQL function" */ + if (strncmp(p, "PL/pgSQL function ", 18) == 0) + p += 18; + else if (strncmp(p, "PL/iSQL function ", 17) == 0) + p += 17; + else + return false; /* Unknown format, skip */ + + func_start = p; + + /* Find the end of the function name (before the opening parenthesis or space for inline blocks) */ + func_end = strchr(p, '('); + if (!func_end) + { + /* No parenthesis - might be inline_code_block which has format "inline_code_block line N" */ + func_end = strstr(p, " line "); + if (!func_end) + return false; + } + + /* Extract function name */ + func_name = pnstrdup(func_start, func_end - func_start); + + /* Check if this is an inline/anonymous block */ + if (strcmp(func_name, "inline_code_block") == 0) + { + /* For anonymous blocks, just show line number */ + /* Find " line " */ + line_marker = strstr(func_end, " line "); + if (!line_marker) + { + pfree(func_name); + return false; + } + + line_num_start = line_marker + 6; /* Skip " line " */ + line_num = atoi(line_num_start); + + appendStringInfo(result, "ORA-06512: at line %d\n", line_num); + pfree(func_name); + return true; + } + + /* For named functions/procedures, lookup schema */ + /* Find " line " */ + line_marker = strstr(func_end, " line "); + if (!line_marker) + { + pfree(func_name); + return false; + } + + line_num_start = line_marker + 6; /* Skip " line " */ + line_num = atoi(line_num_start); + + /* For now, just use PUBLIC as the default schema */ + /* TODO: Look up the actual schema from pg_proc catalog */ + schema_name = pstrdup("PUBLIC"); + + /* Convert function name to uppercase for Oracle compatibility */ + /* Use simple ASCII uppercase conversion */ + func_upper = pstrdup(func_name); + for (i = 0; func_upper[i]; i++) + func_upper[i] = pg_toupper((unsigned char) func_upper[i]); + + schema_upper = pstrdup(schema_name); + for (i = 0; schema_upper[i]; i++) + schema_upper[i] = pg_toupper((unsigned char) schema_upper[i]); + + /* Format: ORA-06512: at "SCHEMA.FUNCTION", line N */ + appendStringInfo(result, "ORA-06512: at \"%s.%s\", line %d\n", + schema_upper, func_upper, line_num); + + pfree(func_name); + pfree(func_upper); + pfree(schema_upper); + pfree(schema_name); + + return true; +} + +/* + * ora_format_error_backtrace - FORMAT_ERROR_BACKTRACE implementation + * + * Returns formatted error backtrace string in Oracle format. + * Returns NULL if not in exception handler context. + * + * This Oracle-compatible function retrieves the exception context from + * PL/iSQL via dynamic lookup of plisql_get_current_exception_context(). + */ +Datum +ora_format_error_backtrace(PG_FUNCTION_ARGS) +{ + const char *pg_context; + char *context_copy; + char *line; + char *saveptr; + StringInfoData result; + + /* Look up the PL/iSQL functions dynamically */ + lookup_plisql_functions(); + if (get_exception_context_fn == NULL) + { + /* plisql not loaded or function not found */ + PG_RETURN_NULL(); + } + + /* Get the current exception context from PL/iSQL */ + pg_context = get_exception_context_fn(); + + /* If no context available (not in exception handler), return NULL */ + if (pg_context == NULL || pg_context[0] == '\0') + PG_RETURN_NULL(); + + initStringInfo(&result); + + /* Make a copy since strtok_r modifies the string */ + context_copy = pstrdup(pg_context); + + /* Parse and transform each line */ + line = strtok_r(context_copy, "\n", &saveptr); + while (line != NULL) + { + /* Skip empty lines */ + if (line[0] != '\0') + transform_and_append_line(&result, line); + + line = strtok_r(NULL, "\n", &saveptr); + } + + pfree(context_copy); + + PG_RETURN_TEXT_P(cstring_to_text(result.data)); +} + +/* + * Convert SQLSTATE error code to Oracle error number string. + * Oracle uses "ORA-XXXXX" format for most errors. + * For PL/SQL user-defined errors, uses "ORA-06510" (user-defined exception). + */ +static const char * +sqlstate_to_ora_errnum(int sqlerrcode) +{ + /* + * Map some common PostgreSQL SQLSTATE codes to Oracle error numbers. + * For most cases, we use a generic error number. + */ + switch (sqlerrcode) + { + case ERRCODE_DIVISION_BY_ZERO: + return "ORA-01476"; /* divisor is equal to zero */ + case ERRCODE_NO_DATA_FOUND: + case ERRCODE_NO_DATA: + return "ORA-01403"; /* no data found */ + case ERRCODE_TOO_MANY_ROWS: + return "ORA-01422"; /* exact fetch returns more than requested number of rows */ + case ERRCODE_NULL_VALUE_NOT_ALLOWED: + return "ORA-06502"; /* PL/SQL: numeric or value error */ + case ERRCODE_INVALID_CURSOR_STATE: + return "ORA-01001"; /* invalid cursor */ + case ERRCODE_RAISE_EXCEPTION: + return "ORA-06510"; /* PL/SQL: unhandled user-defined exception */ + default: + return "ORA-06502"; /* PL/SQL: numeric or value error (generic) */ + } +} + +/* + * ora_format_error_stack - FORMAT_ERROR_STACK implementation + * + * Returns formatted error stack string in Oracle format. + * Returns NULL if not in exception handler context. + * + * Oracle format example: + * ORA-06510: PL/SQL: unhandled user-defined exception + * ORA-06512: at "SCOTT.TEST_PROC", line 5 + */ +Datum +ora_format_error_stack(PG_FUNCTION_ARGS) +{ + const char *message; + int sqlerrcode; + StringInfoData result; + + /* Look up the PL/iSQL functions dynamically */ + lookup_plisql_functions(); + if (get_exception_message_fn == NULL || get_exception_sqlerrcode_fn == NULL) + { + /* plisql not loaded or function not found */ + PG_RETURN_NULL(); + } + + /* Get the current exception message and code from PL/iSQL */ + message = get_exception_message_fn(); + sqlerrcode = get_exception_sqlerrcode_fn(); + + /* If no exception context (not in exception handler), return NULL */ + if (message == NULL || sqlerrcode == 0) + PG_RETURN_NULL(); + + initStringInfo(&result); + + /* Format: ORA-XXXXX: */ + appendStringInfo(&result, "%s: %s\n", sqlstate_to_ora_errnum(sqlerrcode), message); + + PG_RETURN_TEXT_P(cstring_to_text(result.data)); +} + +/* + * ora_format_call_stack - FORMAT_CALL_STACK implementation + * + * Returns formatted call stack string in Oracle format. + * Returns NULL if not in any PL/iSQL function. + * + * Oracle format example: + * ----- PL/SQL Call Stack ----- + * object line object + * handle number name + * 0x7f8b0c0 5 procedure SCOTT.INNER_PROC + * 0x7f8b0a0 3 procedure SCOTT.OUTER_PROC + * 0x7f8b080 2 anonymous block + */ +Datum +ora_format_call_stack(PG_FUNCTION_ARGS) +{ + char *raw_stack; + char *stack_copy; + char *line; + char *saveptr; + StringInfoData result; + int frame_count = 0; + bool found_any = false; + + /* Look up the PL/iSQL functions dynamically */ + lookup_plisql_functions(); + if (get_call_stack_fn == NULL) + { + /* plisql not loaded or function not found */ + PG_RETURN_NULL(); + } + + /* Get the current call stack from PL/iSQL */ + raw_stack = get_call_stack_fn(); + + /* If no call stack (not in any PL/iSQL function), return NULL */ + if (raw_stack == NULL) + PG_RETURN_NULL(); + + initStringInfo(&result); + + /* Add Oracle-style header */ + appendStringInfo(&result, "----- PL/SQL Call Stack -----\n"); + appendStringInfo(&result, " object line object\n"); + appendStringInfo(&result, " handle number name\n"); + + /* + * Parse the raw stack returned by plisql_get_call_stack. + * Format from plisql: "handle\tlineno\tsignature" per line + * + * Skip the first frame which is the FORMAT_CALL_STACK package function. + */ + stack_copy = pstrdup(raw_stack); + line = strtok_r(stack_copy, "\n", &saveptr); + + while (line != NULL) + { + char *handle_str; + char *lineno_str; + char *signature; + char *tab1; + char *tab2; + char *func_upper; + int i; + + frame_count++; + + /* Skip the first frame (FORMAT_CALL_STACK itself) */ + if (frame_count == 1) + { + line = strtok_r(NULL, "\n", &saveptr); + continue; + } + + /* Parse: handle\tlineno\tsignature */ + tab1 = strchr(line, '\t'); + if (!tab1) + { + line = strtok_r(NULL, "\n", &saveptr); + continue; + } + + handle_str = pnstrdup(line, tab1 - line); + tab2 = strchr(tab1 + 1, '\t'); + if (!tab2) + { + pfree(handle_str); + line = strtok_r(NULL, "\n", &saveptr); + continue; + } + + lineno_str = pnstrdup(tab1 + 1, tab2 - tab1 - 1); + signature = tab2 + 1; + + /* Convert function name to uppercase for Oracle compatibility */ + func_upper = pstrdup(signature); + for (i = 0; func_upper[i]; i++) + func_upper[i] = pg_toupper((unsigned char) func_upper[i]); + + /* Format each stack frame */ + appendStringInfo(&result, "%s %5s function %s\n", + handle_str, lineno_str, func_upper); + found_any = true; + + pfree(handle_str); + pfree(lineno_str); + pfree(func_upper); + + line = strtok_r(NULL, "\n", &saveptr); + } + + pfree(stack_copy); + pfree(raw_stack); + + /* If we only had the FORMAT_CALL_STACK frame, return NULL */ + if (!found_any) + { + pfree(result.data); + PG_RETURN_NULL(); + } + + PG_RETURN_TEXT_P(cstring_to_text(result.data)); +} diff --git a/design/dbms_utility/PROPOSAL.md b/design/dbms_utility/PROPOSAL.md new file mode 100644 index 00000000000..8ae46f812e3 --- /dev/null +++ b/design/dbms_utility/PROPOSAL.md @@ -0,0 +1,146 @@ +# DBMS_UTILITY Implementation Proposal + +## Summary + +This proposal describes an implementation approach for `DBMS_UTILITY.FORMAT_ERROR_BACKTRACE` that follows IvorySQL's built-in package convention while addressing the cross-module dependency challenge. + +## Background + +Oracle's `DBMS_UTILITY.FORMAT_ERROR_BACKTRACE` returns the call stack at the point where an exception was raised. This requires access to exception context information that is internal to PL/iSQL's execution state. + +## The Challenge + +IvorySQL has two independent modules: + +``` +src/pl/plisql/src/ → plisql.so (PL/iSQL language runtime) +contrib/ivorysql_ora/ → ivorysql_ora.so (Oracle compatibility extension) +``` + +The built-in package convention places packages in `contrib/ivorysql_ora/src/builtin_packages/`. However, `FORMAT_ERROR_BACKTRACE` needs access to PL/iSQL's exception context (`edata->context`), which is only available inside PL/iSQL's `exec_stmt_block()` during exception handling. + +## Proposed Solution + +Split the implementation between modules with a minimal API boundary: + +### 1. Minimal API in `plisql` (5-10 lines) + +Add a single accessor function to expose the exception context: + +```c +// src/pl/plisql/src/pl_exec.c + +static PLiSQL_execstate *exception_handling_estate = NULL; + +const char * +plisql_get_current_exception_context(void) +{ + if (exception_handling_estate != NULL && + exception_handling_estate->cur_error != NULL) + return exception_handling_estate->cur_error->context; + return NULL; +} +``` + +Track `exception_handling_estate` when entering/exiting exception handlers: + +```c +// In exec_stmt_block(), when entering exception handler: +exception_handling_estate = estate; +rc = exec_stmts(estate, exception->action); +exception_handling_estate = save_exception_handling_estate; +``` + +Export in header: + +```c +// src/pl/plisql/src/plisql.h +extern PGDLLEXPORT const char *plisql_get_current_exception_context(void); +``` + +### 2. DBMS_UTILITY Package in `ivorysql_ora` + +``` +contrib/ivorysql_ora/ +├── src/builtin_packages/ +│ └── dbms_utility/ +│ ├── dbms_utility.c ← C code (format transformation) +│ └── dbms_utility--1.0.sql ← Package definition +├── sql/dbms_utility.sql ← Regression tests +├── expected/dbms_utility.out +├── Makefile ← Add dbms_utility.o +└── ivorysql_ora_merge_sqls ← Add entry +``` + +The C code calls the plisql API and transforms the output: + +```c +// contrib/ivorysql_ora/src/builtin_packages/dbms_utility/dbms_utility.c + +#include "plisql.h" // For plisql_get_current_exception_context() + +Datum +ora_format_error_backtrace(PG_FUNCTION_ARGS) +{ + const char *pg_context = plisql_get_current_exception_context(); + if (pg_context == NULL) + PG_RETURN_NULL(); + + // Transform PostgreSQL format to Oracle format: + // "PL/iSQL function foo() line 3 at RAISE" + // → "ORA-06512: at \"PUBLIC.FOO\", line 3" + ... +} +``` + +## File Changes Summary + +### `plisql` Changes (Minimal) + +| File | Change | +|------|--------| +| `src/pl/plisql/src/pl_exec.c` | Add `exception_handling_estate` tracking + API function (~20 lines) | +| `src/pl/plisql/src/plisql.h` | Add API declaration (1 line) | + +### `ivorysql_ora` Changes (Main Implementation) + +| File | Change | +|------|--------| +| `contrib/ivorysql_ora/src/builtin_packages/dbms_utility/dbms_utility.c` | New - C implementation | +| `contrib/ivorysql_ora/src/builtin_packages/dbms_utility/dbms_utility--1.0.sql` | New - Package definition | +| `contrib/ivorysql_ora/sql/dbms_utility.sql` | New - Regression tests | +| `contrib/ivorysql_ora/expected/dbms_utility.out` | New - Expected output | +| `contrib/ivorysql_ora/Makefile` | Add `dbms_utility.o` | +| `contrib/ivorysql_ora/ivorysql_ora_merge_sqls` | Add entry | + +## Why This Approach? + +1. **Follows convention**: DBMS_UTILITY lives in `contrib/ivorysql_ora/src/builtin_packages/` +2. **Minimal plisql changes**: Only a small API (~20 lines), no package code +3. **Clean API boundary**: `plisql_get_current_exception_context()` is a stable interface +4. **Uses existing data**: Leverages `estate->cur_error` which PL/iSQL already maintains +5. **No new struct fields**: Uses existing `ErrorData.context` field + +## Alternative Considered + +Implement everything in `plisql`: +- Simpler (no cross-module coordination) +- But doesn't follow built-in package convention +- Future DBMS packages would be inconsistent + +## Questions for IvorySQL Team + +1. Is adding a minimal API to `plisql` acceptable for packages that need PL/iSQL internals? +2. Should this API pattern be documented as the standard approach for such packages? +3. Are there any concerns about the `PGDLLEXPORT` approach for cross-module calls? + +## References + +- [Oracle DBMS_UTILITY.FORMAT_ERROR_BACKTRACE](https://docs.oracle.com/en/database/oracle/oracle-database/23/arpls/DBMS_UTILITY.html#GUID-D72B928F-C353-461D-B098-83865F295C55) +- Existing IvorySQL built-in packages: `contrib/ivorysql_ora/src/builtin_functions/` + +--- + +**Author:** [Your Name] +**Date:** 2025-12-02 +**Status:** Proposal diff --git a/src/bin/initdb/initdb.c b/src/bin/initdb/initdb.c index 41f8c83307a..b1f8b834ee1 100644 --- a/src/bin/initdb/initdb.c +++ b/src/bin/initdb/initdb.c @@ -2091,7 +2091,10 @@ load_plpgsql(FILE *cmdfd) static void load_plisql(FILE *cmdfd) { + /* Switch to oracle mode to allow CREATE PACKAGE in extension SQL */ + PG_CMD_PUTS("set ivorysql.compatible_mode to oracle;\n\n"); PG_CMD_PUTS("CREATE EXTENSION plisql;\n\n"); + PG_CMD_PUTS("set ivorysql.compatible_mode to pg;\n\n"); } static void diff --git a/src/pl/plisql/src/Makefile b/src/pl/plisql/src/Makefile index 60cce6c41d1..a0a12dc9a1c 100755 --- a/src/pl/plisql/src/Makefile +++ b/src/pl/plisql/src/Makefile @@ -63,7 +63,7 @@ REGRESS = plisql_array plisql_call plisql_control plisql_copy plisql_domain \ plisql_record plisql_cache plisql_simple plisql_transaction \ plisql_trap plisql_trigger plisql_varprops plisql_nested_subproc \ plisql_nested_subproc2 plisql_out_parameter plisql_type_rowtype \ - plisql_exception plisql_autonomous + plisql_exception plisql_autonomous dbms_utility # where to find ora_gen_keywordlist.pl and subsidiary files TOOLSDIR = $(top_srcdir)/src/tools diff --git a/src/pl/plisql/src/meson.build b/src/pl/plisql/src/meson.build index b86d45b8238..f2095f33da2 100644 --- a/src/pl/plisql/src/meson.build +++ b/src/pl/plisql/src/meson.build @@ -53,10 +53,12 @@ if host_system == 'windows' '--FILEDESC', 'PL/iSQL - procedural language',]) endif +plisql_inc = include_directories('.') + plisql = shared_module('plisql', plisql_sources, c_pch: pch_postgres_h, - include_directories: include_directories('.'), + include_directories: plisql_inc, link_with: ora_parser, kwargs: pg_mod_args, ) diff --git a/src/pl/plisql/src/pl_exec.c b/src/pl/plisql/src/pl_exec.c index 3f593a639f8..295ef6f686b 100644 --- a/src/pl/plisql/src/pl_exec.c +++ b/src/pl/plisql/src/pl_exec.c @@ -115,6 +115,13 @@ static SimpleEcontextStackEntry *simple_econtext_stack = NULL; */ static ResourceOwner shared_simple_eval_resowner = NULL; +/* + * Pointer to the estate currently handling an exception. This is used by + * DBMS_UTILITY.FORMAT_ERROR_BACKTRACE to access the exception context from + * within the exception handler, even when nested function calls occur. + */ +static PLiSQL_execstate *exception_handling_estate = NULL; + /* * Memory management within a plisql function generally works with three * contexts: @@ -1978,6 +1985,7 @@ exec_stmt_block(PLiSQL_execstate * estate, PLiSQL_stmt_block * block) ResourceOwner oldowner = CurrentResourceOwner; ExprContext *old_eval_econtext = estate->eval_econtext; ErrorData *save_cur_error = estate->cur_error; + PLiSQL_execstate *save_exception_handling_estate = exception_handling_estate; MemoryContext stmt_mcontext; estate->err_text = gettext_noop("during statement block entry"); @@ -2129,8 +2137,20 @@ exec_stmt_block(PLiSQL_execstate * estate, PLiSQL_stmt_block * block) estate->err_text = NULL; + /* + * Set exception_handling_estate so that functions called + * from within the exception handler (like DBMS_UTILITY + * package functions) can access the exception context. + */ + exception_handling_estate = estate; + rc = exec_stmts(estate, exception->action); + /* + * Restore exception_handling_estate after handler execution. + */ + exception_handling_estate = save_exception_handling_estate; + break; } } @@ -10041,3 +10061,106 @@ plisql_anonymous_return_out_parameter(PLiSQL_execstate * estate, PLiSQL_function return; } + +/* + * plisql_get_current_exception_context + * + * Returns the current exception context string if we're in an exception handler, + * otherwise returns NULL. This is used by Oracle-compatible functions like + * DBMS_UTILITY.FORMAT_ERROR_BACKTRACE. + * + * The returned string is managed by PL/iSQL and should not be freed by the caller. + */ +const char * +plisql_get_current_exception_context(void) +{ + if (exception_handling_estate != NULL && + exception_handling_estate->cur_error != NULL) + return exception_handling_estate->cur_error->context; + return NULL; +} + +/* + * plisql_get_current_exception_message + * + * Returns the current exception message if we're in an exception handler, + * otherwise returns NULL. This is used by DBMS_UTILITY.FORMAT_ERROR_STACK. + */ +const char * +plisql_get_current_exception_message(void) +{ + if (exception_handling_estate != NULL && + exception_handling_estate->cur_error != NULL) + return exception_handling_estate->cur_error->message; + return NULL; +} + +/* + * plisql_get_current_exception_sqlerrcode + * + * Returns the current exception SQLSTATE error code if we're in an exception handler, + * otherwise returns 0. This is used by DBMS_UTILITY.FORMAT_ERROR_STACK. + */ +int +plisql_get_current_exception_sqlerrcode(void) +{ + if (exception_handling_estate != NULL && + exception_handling_estate->cur_error != NULL) + return exception_handling_estate->cur_error->sqlerrcode; + return 0; +} + +/* + * plisql_get_call_stack + * + * Returns the current PL/iSQL call stack as a formatted string. + * This walks the error_context_stack looking for PL/iSQL function contexts. + * Used by DBMS_UTILITY.FORMAT_CALL_STACK. + * + * Returns NULL if not inside any PL/iSQL function. + * The returned string is palloc'd in the current memory context. + */ +char * +plisql_get_call_stack(void) +{ + ErrorContextCallback *context; + StringInfoData buf; + bool found_any = false; + + initStringInfo(&buf); + + /* Walk the error context stack */ + for (context = error_context_stack; context != NULL; context = context->previous) + { + /* Check if this is a PL/iSQL execution context */ + if (context->callback == plisql_exec_error_callback) + { + PLiSQL_execstate *estate = (PLiSQL_execstate *) context->arg; + int lineno = 0; + + /* Get current line number */ + if (estate->err_stmt != NULL) + lineno = estate->err_stmt->lineno; + else if (estate->err_var != NULL) + lineno = estate->err_var->lineno; + + /* Add to stack output */ + if (found_any) + appendStringInfoChar(&buf, '\n'); + + appendStringInfo(&buf, "%p\t%d\t%s", + (void *) estate->func, + lineno, + estate->func->fn_signature); + found_any = true; + } + } + + if (!found_any) + { + pfree(buf.data); + return NULL; + } + + return buf.data; +} diff --git a/src/pl/plisql/src/plisql.h b/src/pl/plisql/src/plisql.h index 0804ed818da..e220f2493a8 100755 --- a/src/pl/plisql/src/plisql.h +++ b/src/pl/plisql/src/plisql.h @@ -1461,4 +1461,12 @@ extern void plisql_recover_yylex_global_proper(void *yylex_data); extern int plisql_yyparse(PLiSQL_stmt_block * *plisql_parse_result_p, yyscan_t yyscanner); +/* + * Externs in pl_exec.c for exception context access (used by DBMS_UTILITY) + */ +extern PGDLLEXPORT const char *plisql_get_current_exception_context(void); +extern PGDLLEXPORT const char *plisql_get_current_exception_message(void); +extern PGDLLEXPORT int plisql_get_current_exception_sqlerrcode(void); +extern PGDLLEXPORT char *plisql_get_call_stack(void); + #endif /* PLISQL_H */