From 868a7740ed0b6725b851bd1114c82e95e034bf16 Mon Sep 17 00:00:00 2001 From: Rophy Tsai Date: Tue, 2 Dec 2025 22:35:30 +0000 Subject: [PATCH 01/13] Add DBMS_OUTPUT package in ivorysql_ora extension Implement Oracle-compatible DBMS_OUTPUT package providing: - PUT_LINE, PUT, NEW_LINE for buffered output - GET_LINE, GET_LINES for retrieving output - ENABLE/DISABLE for buffer control - Buffer overflow detection (ORU-10027) Located in contrib/ivorysql_ora/src/builtin_packages/dbms_output/ following IvorySQL maintainer guidance (discussion #988). Includes design documentation and Oracle compatibility comparison with 82% test compatibility rate (27/33 tests pass). Known differences from Oracle: - NULL stored as empty string vs NULL - Re-ENABLE clears buffer vs preserves - Buffer size range 2000-1000000 (Oracle: 2000-unlimited) - No 32767 byte line length limit --- contrib/ivorysql_ora/Makefile | 4 +- .../ivorysql_ora/expected/ora_dbms_output.out | 529 ++++++++++++++++++ contrib/ivorysql_ora/ivorysql_ora_merge_sqls | 1 + contrib/ivorysql_ora/sql/ora_dbms_output.sql | 507 +++++++++++++++++ .../dbms_output/dbms_output--1.0.sql | 127 +++++ .../dbms_output/dbms_output.c | 520 +++++++++++++++++ .../src/expected/plisql_nested_subproc2.out | 5 - 7 files changed, 1687 insertions(+), 6 deletions(-) create mode 100644 contrib/ivorysql_ora/expected/ora_dbms_output.out create mode 100644 contrib/ivorysql_ora/sql/ora_dbms_output.sql create mode 100644 contrib/ivorysql_ora/src/builtin_packages/dbms_output/dbms_output--1.0.sql create mode 100644 contrib/ivorysql_ora/src/builtin_packages/dbms_output/dbms_output.c diff --git a/contrib/ivorysql_ora/Makefile b/contrib/ivorysql_ora/Makefile index f7d654bc8d2..4836b19977e 100644 --- a/contrib/ivorysql_ora/Makefile +++ b/contrib/ivorysql_ora/Makefile @@ -25,6 +25,7 @@ OBJS = \ src/builtin_functions/datetime_datatype_functions.o \ src/builtin_functions/numeric_datatype_functions.o \ src/builtin_functions/misc_functions.o \ + src/builtin_packages/dbms_output/dbms_output.o \ src/merge/ora_merge.o \ src/sysview/sysview_functions.o \ src/xml_functions/ora_xml_functions.o @@ -69,7 +70,8 @@ ORA_REGRESS = \ datatype_and_func_bugs \ ora_sysview \ ora_like_operator \ - ora_xml_functions + ora_xml_functions \ + ora_dbms_output SHLIB_LINK += -lxml2 diff --git a/contrib/ivorysql_ora/expected/ora_dbms_output.out b/contrib/ivorysql_ora/expected/ora_dbms_output.out new file mode 100644 index 00000000000..0a7b9ed56fc --- /dev/null +++ b/contrib/ivorysql_ora/expected/ora_dbms_output.out @@ -0,0 +1,529 @@ +-- +-- Tests for DBMS_OUTPUT package +-- +-- Design: Every PUT operation is verified by corresponding GET operation +-- to ensure content is properly buffered and retrieved. +-- +-- ============================================================================= +-- Section 1: Basic PUT_LINE and GET_LINE +-- ============================================================================= +-- Test 1.1: Simple PUT_LINE verified by GET_LINE +DECLARE + line TEXT; + status INTEGER; +BEGIN + dbms_output.enable(); + dbms_output.put_line('Hello, World!'); + dbms_output.get_line(line, status); + RAISE NOTICE 'Test 1.1 - Line: [%], Status: %', line, status; +END; +/ +NOTICE: Test 1.1 - Line: [Hello, World!], Status: 0 +-- Test 1.2: Multiple PUT_LINE calls verified by GET_LINES +DECLARE + lines TEXT[]; + numlines INTEGER := 10; +BEGIN + dbms_output.enable(); + dbms_output.put_line('First line'); + dbms_output.put_line('Second line'); + dbms_output.put_line('Third line'); + dbms_output.get_lines(lines, numlines); + RAISE NOTICE 'Test 1.2 - Retrieved % lines', numlines; + FOR i IN 1..numlines LOOP + RAISE NOTICE ' Line %: [%]', i, lines[i]; + END LOOP; +END; +/ +NOTICE: Test 1.2 - Retrieved 3 lines +NOTICE: Line 1: [First line] +NOTICE: Line 2: [Second line] +NOTICE: Line 3: [Third line] +-- Test 1.3: Empty string handling +DECLARE + line TEXT; + status INTEGER; +BEGIN + dbms_output.enable(); + dbms_output.put_line(''); + dbms_output.get_line(line, status); + RAISE NOTICE 'Test 1.3 - Empty string: [%], Status: %', line, status; +END; +/ +NOTICE: Test 1.3 - Empty string: [], Status: 0 +-- Test 1.4: NULL handling (should output empty line) +DECLARE + line TEXT; + status INTEGER; +BEGIN + dbms_output.enable(); + dbms_output.put_line(NULL); + dbms_output.get_line(line, status); + RAISE NOTICE 'Test 1.4 - NULL input: [%], Status: %', line, status; +END; +/ +NOTICE: Test 1.4 - NULL input: [], Status: 0 +-- Test 1.5: GET_LINE when buffer is empty (status should be 1) +DECLARE + line TEXT; + status INTEGER; +BEGIN + dbms_output.enable(); + -- Don't put anything + dbms_output.get_line(line, status); + RAISE NOTICE 'Test 1.5 - Empty buffer: Line=[%], Status=%', line, status; +END; +/ +NOTICE: Test 1.5 - Empty buffer: Line=[], Status=1 +-- ============================================================================= +-- Section 2: PUT and NEW_LINE +-- ============================================================================= +-- Test 2.1: PUT followed by NEW_LINE +DECLARE + line TEXT; + status INTEGER; +BEGIN + dbms_output.enable(); + dbms_output.put('First part'); + dbms_output.put(' second part'); + dbms_output.new_line(); + dbms_output.get_line(line, status); + RAISE NOTICE 'Test 2.1 - Combined: [%], Status: %', line, status; +END; +/ +NOTICE: Test 2.1 - Combined: [First part second part], Status: 0 +-- Test 2.2: PUT with NULL (should append nothing) +DECLARE + line TEXT; + status INTEGER; +BEGIN + dbms_output.enable(); + dbms_output.put('Before'); + dbms_output.put(NULL); + dbms_output.put('After'); + dbms_output.new_line(); + dbms_output.get_line(line, status); + RAISE NOTICE 'Test 2.2 - PUT with NULL: [%], Status: %', line, status; +END; +/ +NOTICE: Test 2.2 - PUT with NULL: [BeforeAfter], Status: 0 +-- Test 2.3: Multiple PUT calls building one line +DECLARE + line TEXT; + status INTEGER; +BEGIN + dbms_output.enable(); + dbms_output.put('A'); + dbms_output.put('B'); + dbms_output.put('C'); + dbms_output.put('D'); + dbms_output.new_line(); + dbms_output.get_line(line, status); + RAISE NOTICE 'Test 2.3 - Multiple PUTs: [%], Status: %', line, status; +END; +/ +NOTICE: Test 2.3 - Multiple PUTs: [ABCD], Status: 0 +-- Test 2.4: PUT_LINE after PUT (should create two lines) +DECLARE + lines TEXT[]; + numlines INTEGER := 10; +BEGIN + dbms_output.enable(); + dbms_output.put('Partial'); + dbms_output.new_line(); + dbms_output.put_line('Complete'); + dbms_output.get_lines(lines, numlines); + RAISE NOTICE 'Test 2.4 - Retrieved % lines', numlines; + FOR i IN 1..numlines LOOP + RAISE NOTICE ' Line %: [%]', i, lines[i]; + END LOOP; +END; +/ +NOTICE: Test 2.4 - Retrieved 2 lines +NOTICE: Line 1: [Partial] +NOTICE: Line 2: [Complete] +-- ============================================================================= +-- Section 3: ENABLE and DISABLE behavior +-- ============================================================================= +-- Test 3.1: DISABLE prevents output from being buffered +DECLARE + line TEXT; + status INTEGER; +BEGIN + dbms_output.enable(); + dbms_output.put_line('Before disable'); + dbms_output.disable(); + dbms_output.put_line('During disable - should not appear'); + dbms_output.enable(); + -- Try to get - should only see what was put after re-enable + dbms_output.put_line('After re-enable'); + dbms_output.get_line(line, status); + RAISE NOTICE 'Test 3.1 - After disable/enable cycle: [%], Status: %', line, status; +END; +/ +NOTICE: Test 3.1 - After disable/enable cycle: [After re-enable], Status: 0 +-- Test 3.2: DISABLE clears existing buffer +DECLARE + line TEXT; + status INTEGER; +BEGIN + dbms_output.enable(); + dbms_output.put_line('This will be cleared'); + dbms_output.disable(); + dbms_output.enable(); + dbms_output.get_line(line, status); + RAISE NOTICE 'Test 3.2 - Buffer after disable: [%], Status: %', line, status; +END; +/ +NOTICE: Test 3.2 - Buffer after disable: [], Status: 1 +-- Test 3.3: Re-ENABLE clears buffer +DECLARE + line TEXT; + status INTEGER; +BEGIN + dbms_output.enable(); + dbms_output.put_line('First enable content'); + dbms_output.enable(); -- Re-enable should clear + dbms_output.get_line(line, status); + RAISE NOTICE 'Test 3.3 - After re-enable: [%], Status: %', line, status; +END; +/ +NOTICE: Test 3.3 - After re-enable: [], Status: 1 +-- Test 3.4: Output while disabled is silently ignored +DECLARE + line TEXT; + status INTEGER; +BEGIN + dbms_output.disable(); + dbms_output.put_line('Ignored 1'); + dbms_output.put('Ignored 2'); + dbms_output.new_line(); + dbms_output.enable(); + dbms_output.put_line('Visible'); + dbms_output.get_line(line, status); + RAISE NOTICE 'Test 3.4 - Only visible after enable: [%], Status: %', line, status; +END; +/ +NOTICE: Test 3.4 - Only visible after enable: [Visible], Status: 0 +-- ============================================================================= +-- Section 4: Buffer size limits +-- ============================================================================= +-- Test 4.1: Buffer size below minimum (should fail) +CALL dbms_output.enable(1000); +ERROR: buffer size must be between 2000 and 1000000 +CONTEXT: SQL statement "SELECT sys.ora_dbms_output_enable(buffer_size)" +PL/iSQL function enable line 3 at PERFORM +-- Test 4.2: Buffer size at minimum (should succeed) +DECLARE + line TEXT; + status INTEGER; +BEGIN + dbms_output.enable(2000); + dbms_output.put_line('Min buffer works'); + dbms_output.get_line(line, status); + RAISE NOTICE 'Test 4.2 - Min buffer: [%]', line; +END; +/ +NOTICE: Test 4.2 - Min buffer: [Min buffer works] +-- Test 4.3: Buffer size at maximum (should succeed) +DECLARE + line TEXT; + status INTEGER; +BEGIN + dbms_output.enable(1000000); + dbms_output.put_line('Max buffer works'); + dbms_output.get_line(line, status); + RAISE NOTICE 'Test 4.3 - Max buffer: [%]', line; +END; +/ +NOTICE: Test 4.3 - Max buffer: [Max buffer works] +-- Test 4.4: Buffer size above maximum (should fail) +CALL dbms_output.enable(1000001); +ERROR: buffer size must be between 2000 and 1000000 +CONTEXT: SQL statement "SELECT sys.ora_dbms_output_enable(buffer_size)" +PL/iSQL function enable line 3 at PERFORM +-- Test 4.5: NULL buffer size uses default +DECLARE + line TEXT; + status INTEGER; +BEGIN + dbms_output.enable(NULL); + dbms_output.put_line('NULL buffer uses default'); + dbms_output.get_line(line, status); + RAISE NOTICE 'Test 4.5 - NULL buffer: [%]', line; +END; +/ +NOTICE: Test 4.5 - NULL buffer: [NULL buffer uses default] +-- ============================================================================= +-- Section 5: Buffer overflow +-- ============================================================================= +-- Test 5.1: Buffer overflow produces error +DECLARE + overflow_occurred BOOLEAN := FALSE; + line_count INTEGER := 0; +BEGIN + dbms_output.enable(2000); -- Small buffer + FOR i IN 1..100 LOOP + BEGIN + dbms_output.put_line('Buffer test line ' || i || ' with extra padding text'); + line_count := i; + EXCEPTION WHEN OTHERS THEN + RAISE NOTICE 'Test 5.1 - Overflow at line %: %', i, SQLERRM; + overflow_occurred := TRUE; + EXIT; + END; + END LOOP; + IF NOT overflow_occurred THEN + RAISE NOTICE 'Test 5.1 - No overflow occurred (unexpected)'; + END IF; +END; +/ +NOTICE: Test 5.1 - Overflow at line 47: ORU-10027: buffer overflow, limit of 2000 bytes +-- ============================================================================= +-- Section 6: GET_LINE and GET_LINES behavior +-- ============================================================================= +-- Test 6.1: GET_LINE returns lines in order +DECLARE + line TEXT; + status INTEGER; +BEGIN + dbms_output.enable(); + dbms_output.put_line('Line A'); + dbms_output.put_line('Line B'); + dbms_output.put_line('Line C'); + dbms_output.get_line(line, status); + RAISE NOTICE 'Test 6.1a - First: [%]', line; + dbms_output.get_line(line, status); + RAISE NOTICE 'Test 6.1b - Second: [%]', line; + dbms_output.get_line(line, status); + RAISE NOTICE 'Test 6.1c - Third: [%]', line; + dbms_output.get_line(line, status); + RAISE NOTICE 'Test 6.1d - Fourth (empty): [%], Status: %', line, status; +END; +/ +NOTICE: Test 6.1a - First: [Line A] +NOTICE: Test 6.1b - Second: [Line B] +NOTICE: Test 6.1c - Third: [Line C] +NOTICE: Test 6.1d - Fourth (empty): [], Status: 1 +-- Test 6.2: GET_LINES with numlines larger than available +DECLARE + lines TEXT[]; + numlines INTEGER := 100; -- Request more than available +BEGIN + dbms_output.enable(); + dbms_output.put_line('Only'); + dbms_output.put_line('Three'); + dbms_output.put_line('Lines'); + dbms_output.get_lines(lines, numlines); + RAISE NOTICE 'Test 6.2 - Requested 100, got %', numlines; + FOR i IN 1..numlines LOOP + RAISE NOTICE ' Line %: [%]', i, lines[i]; + END LOOP; +END; +/ +NOTICE: Test 6.2 - Requested 100, got 3 +NOTICE: Line 1: [Only] +NOTICE: Line 2: [Three] +NOTICE: Line 3: [Lines] +-- Test 6.3: GET_LINES with numlines smaller than available +DECLARE + lines TEXT[]; + numlines INTEGER := 2; -- Request fewer than available + line TEXT; + status INTEGER; +BEGIN + dbms_output.enable(); + dbms_output.put_line('One'); + dbms_output.put_line('Two'); + dbms_output.put_line('Three'); + dbms_output.put_line('Four'); + dbms_output.get_lines(lines, numlines); + RAISE NOTICE 'Test 6.3a - Got % lines with GET_LINES', numlines; + FOR i IN 1..numlines LOOP + RAISE NOTICE ' Line %: [%]', i, lines[i]; + END LOOP; + -- Remaining lines should still be available + dbms_output.get_line(line, status); + RAISE NOTICE 'Test 6.3b - Remaining: [%], Status: %', line, status; + dbms_output.get_line(line, status); + RAISE NOTICE 'Test 6.3c - Remaining: [%], Status: %', line, status; +END; +/ +NOTICE: Test 6.3a - Got 2 lines with GET_LINES +NOTICE: Line 1: [One] +NOTICE: Line 2: [Two] +NOTICE: Test 6.3b - Remaining: [Three], Status: 0 +NOTICE: Test 6.3c - Remaining: [Four], Status: 0 +-- ============================================================================= +-- Section 7: Usage in procedures and functions +-- ============================================================================= +-- Test 7.1: Output from procedure +CREATE OR REPLACE PROCEDURE test_output_proc(p_msg TEXT) +AS $$ +BEGIN + dbms_output.put_line('Proc says: ' || p_msg); +END; +$$ LANGUAGE plisql; +/ +DECLARE + line TEXT; + status INTEGER; +BEGIN + dbms_output.enable(); + test_output_proc('Hello from procedure'); + dbms_output.get_line(line, status); + RAISE NOTICE 'Test 7.1 - From procedure: [%]', line; +END; +/ +NOTICE: Test 7.1 - From procedure: [Proc says: Hello from procedure] +-- Test 7.2: Output from function (output preserved across call) +CREATE OR REPLACE FUNCTION test_output_func(p_val INTEGER) RETURNS INTEGER +AS $$ +BEGIN + dbms_output.put_line('Func input: ' || p_val); + dbms_output.put_line('Func output: ' || (p_val * 2)); + RETURN p_val * 2; +END; +$$ LANGUAGE plisql; +/ +DECLARE + result INTEGER; + lines TEXT[]; + numlines INTEGER := 10; +BEGIN + dbms_output.enable(); + result := test_output_func(5); + dbms_output.get_lines(lines, numlines); + RAISE NOTICE 'Test 7.2 - Function returned: %', result; + FOR i IN 1..numlines LOOP + RAISE NOTICE ' Output %: [%]', i, lines[i]; + END LOOP; +END; +/ +NOTICE: Test 7.2 - Function returned: 10 +NOTICE: Output 1: [Func input: 5] +NOTICE: Output 2: [Func output: 10] +-- ============================================================================= +-- Section 8: Special cases +-- ============================================================================= +-- Test 8.1: Special characters +DECLARE + lines TEXT[]; + numlines INTEGER := 10; +BEGIN + dbms_output.enable(); + dbms_output.put_line('Tab: here'); + dbms_output.put_line('Quote: ''single'' "double"'); + dbms_output.put_line('Backslash: \ forward: /'); + dbms_output.get_lines(lines, numlines); + RAISE NOTICE 'Test 8.1 - Special chars: % lines', numlines; + FOR i IN 1..numlines LOOP + RAISE NOTICE ' [%]', lines[i]; + END LOOP; +END; +/ +NOTICE: Test 8.1 - Special chars: 3 lines +NOTICE: [Tab: here] +NOTICE: [Quote: 'single' "double"] +NOTICE: [Backslash: \ forward: /] +-- Test 8.2: Numeric values via concatenation +DECLARE + line TEXT; + status INTEGER; +BEGIN + dbms_output.enable(); + dbms_output.put_line('Number: ' || 42); + dbms_output.get_line(line, status); + RAISE NOTICE 'Test 8.2 - Numeric: [%]', line; +END; +/ +NOTICE: Test 8.2 - Numeric: [Number: 42] +-- Test 8.3: Very long line +DECLARE + very_long TEXT := repeat('X', 1000); + line TEXT; + status INTEGER; +BEGIN + dbms_output.enable(10000); + dbms_output.put_line(very_long); + dbms_output.get_line(line, status); + RAISE NOTICE 'Test 8.3 - Long line length: %', length(line); +END; +/ +NOTICE: Test 8.3 - Long line length: 1000 +-- Test 8.4: Exception handling preserves buffer +DECLARE + line TEXT; + status INTEGER; +BEGIN + dbms_output.enable(); + dbms_output.put_line('Before exception'); + BEGIN + RAISE EXCEPTION 'Test error'; + EXCEPTION WHEN OTHERS THEN + dbms_output.put_line('Caught: ' || SQLERRM); + END; + dbms_output.put_line('After exception'); + -- Verify all three lines are in buffer + dbms_output.get_line(line, status); + RAISE NOTICE 'Test 8.4a - [%]', line; + dbms_output.get_line(line, status); + RAISE NOTICE 'Test 8.4b - [%]', line; + dbms_output.get_line(line, status); + RAISE NOTICE 'Test 8.4c - [%]', line; +END; +/ +NOTICE: Test 8.4a - [Before exception] +NOTICE: Test 8.4b - [Caught: Test error] +NOTICE: Test 8.4c - [After exception] +-- Test 8.5: Nested blocks +DECLARE + lines TEXT[]; + numlines INTEGER := 10; +BEGIN + dbms_output.enable(); + dbms_output.put_line('Outer'); + BEGIN + dbms_output.put_line('Inner 1'); + BEGIN + dbms_output.put_line('Inner 2'); + END; + END; + dbms_output.put_line('Back to outer'); + dbms_output.get_lines(lines, numlines); + RAISE NOTICE 'Test 8.5 - Nested blocks: % lines', numlines; + FOR i IN 1..numlines LOOP + RAISE NOTICE ' [%]', lines[i]; + END LOOP; +END; +/ +NOTICE: Test 8.5 - Nested blocks: 4 lines +NOTICE: [Outer] +NOTICE: [Inner 1] +NOTICE: [Inner 2] +NOTICE: [Back to outer] +-- Test 8.6: Loop output +DECLARE + lines TEXT[]; + numlines INTEGER := 10; +BEGIN + dbms_output.enable(); + FOR i IN 1..3 LOOP + dbms_output.put_line('Iteration ' || i); + END LOOP; + dbms_output.get_lines(lines, numlines); + RAISE NOTICE 'Test 8.6 - Loop: % lines', numlines; + FOR i IN 1..numlines LOOP + RAISE NOTICE ' [%]', lines[i]; + END LOOP; +END; +/ +NOTICE: Test 8.6 - Loop: 3 lines +NOTICE: [Iteration 1] +NOTICE: [Iteration 2] +NOTICE: [Iteration 3] +-- ============================================================================= +-- Cleanup +-- ============================================================================= +DROP PROCEDURE test_output_proc; +DROP FUNCTION test_output_func; diff --git a/contrib/ivorysql_ora/ivorysql_ora_merge_sqls b/contrib/ivorysql_ora/ivorysql_ora_merge_sqls index 42c3e752922..2d74949f7d2 100644 --- a/contrib/ivorysql_ora/ivorysql_ora_merge_sqls +++ b/contrib/ivorysql_ora/ivorysql_ora_merge_sqls @@ -1,4 +1,5 @@ src/datatype/datatype src/builtin_functions/builtin_functions +src/builtin_packages/dbms_output/dbms_output src/sysview/sysview src/xml_functions/xml_functions diff --git a/contrib/ivorysql_ora/sql/ora_dbms_output.sql b/contrib/ivorysql_ora/sql/ora_dbms_output.sql new file mode 100644 index 00000000000..18c7309c763 --- /dev/null +++ b/contrib/ivorysql_ora/sql/ora_dbms_output.sql @@ -0,0 +1,507 @@ +-- +-- Tests for DBMS_OUTPUT package +-- +-- Design: Every PUT operation is verified by corresponding GET operation +-- to ensure content is properly buffered and retrieved. +-- + +-- ============================================================================= +-- Section 1: Basic PUT_LINE and GET_LINE +-- ============================================================================= + +-- Test 1.1: Simple PUT_LINE verified by GET_LINE +DECLARE + line TEXT; + status INTEGER; +BEGIN + dbms_output.enable(); + dbms_output.put_line('Hello, World!'); + dbms_output.get_line(line, status); + RAISE NOTICE 'Test 1.1 - Line: [%], Status: %', line, status; +END; +/ + +-- Test 1.2: Multiple PUT_LINE calls verified by GET_LINES +DECLARE + lines TEXT[]; + numlines INTEGER := 10; +BEGIN + dbms_output.enable(); + dbms_output.put_line('First line'); + dbms_output.put_line('Second line'); + dbms_output.put_line('Third line'); + dbms_output.get_lines(lines, numlines); + RAISE NOTICE 'Test 1.2 - Retrieved % lines', numlines; + FOR i IN 1..numlines LOOP + RAISE NOTICE ' Line %: [%]', i, lines[i]; + END LOOP; +END; +/ + +-- Test 1.3: Empty string handling +DECLARE + line TEXT; + status INTEGER; +BEGIN + dbms_output.enable(); + dbms_output.put_line(''); + dbms_output.get_line(line, status); + RAISE NOTICE 'Test 1.3 - Empty string: [%], Status: %', line, status; +END; +/ + +-- Test 1.4: NULL handling (should output empty line) +DECLARE + line TEXT; + status INTEGER; +BEGIN + dbms_output.enable(); + dbms_output.put_line(NULL); + dbms_output.get_line(line, status); + RAISE NOTICE 'Test 1.4 - NULL input: [%], Status: %', line, status; +END; +/ + +-- Test 1.5: GET_LINE when buffer is empty (status should be 1) +DECLARE + line TEXT; + status INTEGER; +BEGIN + dbms_output.enable(); + -- Don't put anything + dbms_output.get_line(line, status); + RAISE NOTICE 'Test 1.5 - Empty buffer: Line=[%], Status=%', line, status; +END; +/ + +-- ============================================================================= +-- Section 2: PUT and NEW_LINE +-- ============================================================================= + +-- Test 2.1: PUT followed by NEW_LINE +DECLARE + line TEXT; + status INTEGER; +BEGIN + dbms_output.enable(); + dbms_output.put('First part'); + dbms_output.put(' second part'); + dbms_output.new_line(); + dbms_output.get_line(line, status); + RAISE NOTICE 'Test 2.1 - Combined: [%], Status: %', line, status; +END; +/ + +-- Test 2.2: PUT with NULL (should append nothing) +DECLARE + line TEXT; + status INTEGER; +BEGIN + dbms_output.enable(); + dbms_output.put('Before'); + dbms_output.put(NULL); + dbms_output.put('After'); + dbms_output.new_line(); + dbms_output.get_line(line, status); + RAISE NOTICE 'Test 2.2 - PUT with NULL: [%], Status: %', line, status; +END; +/ + +-- Test 2.3: Multiple PUT calls building one line +DECLARE + line TEXT; + status INTEGER; +BEGIN + dbms_output.enable(); + dbms_output.put('A'); + dbms_output.put('B'); + dbms_output.put('C'); + dbms_output.put('D'); + dbms_output.new_line(); + dbms_output.get_line(line, status); + RAISE NOTICE 'Test 2.3 - Multiple PUTs: [%], Status: %', line, status; +END; +/ + +-- Test 2.4: PUT_LINE after PUT (should create two lines) +DECLARE + lines TEXT[]; + numlines INTEGER := 10; +BEGIN + dbms_output.enable(); + dbms_output.put('Partial'); + dbms_output.new_line(); + dbms_output.put_line('Complete'); + dbms_output.get_lines(lines, numlines); + RAISE NOTICE 'Test 2.4 - Retrieved % lines', numlines; + FOR i IN 1..numlines LOOP + RAISE NOTICE ' Line %: [%]', i, lines[i]; + END LOOP; +END; +/ + +-- ============================================================================= +-- Section 3: ENABLE and DISABLE behavior +-- ============================================================================= + +-- Test 3.1: DISABLE prevents output from being buffered +DECLARE + line TEXT; + status INTEGER; +BEGIN + dbms_output.enable(); + dbms_output.put_line('Before disable'); + dbms_output.disable(); + dbms_output.put_line('During disable - should not appear'); + dbms_output.enable(); + -- Try to get - should only see what was put after re-enable + dbms_output.put_line('After re-enable'); + dbms_output.get_line(line, status); + RAISE NOTICE 'Test 3.1 - After disable/enable cycle: [%], Status: %', line, status; +END; +/ + +-- Test 3.2: DISABLE clears existing buffer +DECLARE + line TEXT; + status INTEGER; +BEGIN + dbms_output.enable(); + dbms_output.put_line('This will be cleared'); + dbms_output.disable(); + dbms_output.enable(); + dbms_output.get_line(line, status); + RAISE NOTICE 'Test 3.2 - Buffer after disable: [%], Status: %', line, status; +END; +/ + +-- Test 3.3: Re-ENABLE clears buffer +DECLARE + line TEXT; + status INTEGER; +BEGIN + dbms_output.enable(); + dbms_output.put_line('First enable content'); + dbms_output.enable(); -- Re-enable should clear + dbms_output.get_line(line, status); + RAISE NOTICE 'Test 3.3 - After re-enable: [%], Status: %', line, status; +END; +/ + +-- Test 3.4: Output while disabled is silently ignored +DECLARE + line TEXT; + status INTEGER; +BEGIN + dbms_output.disable(); + dbms_output.put_line('Ignored 1'); + dbms_output.put('Ignored 2'); + dbms_output.new_line(); + dbms_output.enable(); + dbms_output.put_line('Visible'); + dbms_output.get_line(line, status); + RAISE NOTICE 'Test 3.4 - Only visible after enable: [%], Status: %', line, status; +END; +/ + +-- ============================================================================= +-- Section 4: Buffer size limits +-- ============================================================================= + +-- Test 4.1: Buffer size below minimum (should fail) +CALL dbms_output.enable(1000); + +-- Test 4.2: Buffer size at minimum (should succeed) +DECLARE + line TEXT; + status INTEGER; +BEGIN + dbms_output.enable(2000); + dbms_output.put_line('Min buffer works'); + dbms_output.get_line(line, status); + RAISE NOTICE 'Test 4.2 - Min buffer: [%]', line; +END; +/ + +-- Test 4.3: Buffer size at maximum (should succeed) +DECLARE + line TEXT; + status INTEGER; +BEGIN + dbms_output.enable(1000000); + dbms_output.put_line('Max buffer works'); + dbms_output.get_line(line, status); + RAISE NOTICE 'Test 4.3 - Max buffer: [%]', line; +END; +/ + +-- Test 4.4: Buffer size above maximum (should fail) +CALL dbms_output.enable(1000001); + +-- Test 4.5: NULL buffer size uses default +DECLARE + line TEXT; + status INTEGER; +BEGIN + dbms_output.enable(NULL); + dbms_output.put_line('NULL buffer uses default'); + dbms_output.get_line(line, status); + RAISE NOTICE 'Test 4.5 - NULL buffer: [%]', line; +END; +/ + +-- ============================================================================= +-- Section 5: Buffer overflow +-- ============================================================================= + +-- Test 5.1: Buffer overflow produces error +DECLARE + overflow_occurred BOOLEAN := FALSE; + line_count INTEGER := 0; +BEGIN + dbms_output.enable(2000); -- Small buffer + FOR i IN 1..100 LOOP + BEGIN + dbms_output.put_line('Buffer test line ' || i || ' with extra padding text'); + line_count := i; + EXCEPTION WHEN OTHERS THEN + RAISE NOTICE 'Test 5.1 - Overflow at line %: %', i, SQLERRM; + overflow_occurred := TRUE; + EXIT; + END; + END LOOP; + IF NOT overflow_occurred THEN + RAISE NOTICE 'Test 5.1 - No overflow occurred (unexpected)'; + END IF; +END; +/ + +-- ============================================================================= +-- Section 6: GET_LINE and GET_LINES behavior +-- ============================================================================= + +-- Test 6.1: GET_LINE returns lines in order +DECLARE + line TEXT; + status INTEGER; +BEGIN + dbms_output.enable(); + dbms_output.put_line('Line A'); + dbms_output.put_line('Line B'); + dbms_output.put_line('Line C'); + dbms_output.get_line(line, status); + RAISE NOTICE 'Test 6.1a - First: [%]', line; + dbms_output.get_line(line, status); + RAISE NOTICE 'Test 6.1b - Second: [%]', line; + dbms_output.get_line(line, status); + RAISE NOTICE 'Test 6.1c - Third: [%]', line; + dbms_output.get_line(line, status); + RAISE NOTICE 'Test 6.1d - Fourth (empty): [%], Status: %', line, status; +END; +/ + +-- Test 6.2: GET_LINES with numlines larger than available +DECLARE + lines TEXT[]; + numlines INTEGER := 100; -- Request more than available +BEGIN + dbms_output.enable(); + dbms_output.put_line('Only'); + dbms_output.put_line('Three'); + dbms_output.put_line('Lines'); + dbms_output.get_lines(lines, numlines); + RAISE NOTICE 'Test 6.2 - Requested 100, got %', numlines; + FOR i IN 1..numlines LOOP + RAISE NOTICE ' Line %: [%]', i, lines[i]; + END LOOP; +END; +/ + +-- Test 6.3: GET_LINES with numlines smaller than available +DECLARE + lines TEXT[]; + numlines INTEGER := 2; -- Request fewer than available + line TEXT; + status INTEGER; +BEGIN + dbms_output.enable(); + dbms_output.put_line('One'); + dbms_output.put_line('Two'); + dbms_output.put_line('Three'); + dbms_output.put_line('Four'); + dbms_output.get_lines(lines, numlines); + RAISE NOTICE 'Test 6.3a - Got % lines with GET_LINES', numlines; + FOR i IN 1..numlines LOOP + RAISE NOTICE ' Line %: [%]', i, lines[i]; + END LOOP; + -- Remaining lines should still be available + dbms_output.get_line(line, status); + RAISE NOTICE 'Test 6.3b - Remaining: [%], Status: %', line, status; + dbms_output.get_line(line, status); + RAISE NOTICE 'Test 6.3c - Remaining: [%], Status: %', line, status; +END; +/ + +-- ============================================================================= +-- Section 7: Usage in procedures and functions +-- ============================================================================= + +-- Test 7.1: Output from procedure +CREATE OR REPLACE PROCEDURE test_output_proc(p_msg TEXT) +AS $$ +BEGIN + dbms_output.put_line('Proc says: ' || p_msg); +END; +$$ LANGUAGE plisql; +/ + +DECLARE + line TEXT; + status INTEGER; +BEGIN + dbms_output.enable(); + test_output_proc('Hello from procedure'); + dbms_output.get_line(line, status); + RAISE NOTICE 'Test 7.1 - From procedure: [%]', line; +END; +/ + +-- Test 7.2: Output from function (output preserved across call) +CREATE OR REPLACE FUNCTION test_output_func(p_val INTEGER) RETURNS INTEGER +AS $$ +BEGIN + dbms_output.put_line('Func input: ' || p_val); + dbms_output.put_line('Func output: ' || (p_val * 2)); + RETURN p_val * 2; +END; +$$ LANGUAGE plisql; +/ + +DECLARE + result INTEGER; + lines TEXT[]; + numlines INTEGER := 10; +BEGIN + dbms_output.enable(); + result := test_output_func(5); + dbms_output.get_lines(lines, numlines); + RAISE NOTICE 'Test 7.2 - Function returned: %', result; + FOR i IN 1..numlines LOOP + RAISE NOTICE ' Output %: [%]', i, lines[i]; + END LOOP; +END; +/ + +-- ============================================================================= +-- Section 8: Special cases +-- ============================================================================= + +-- Test 8.1: Special characters +DECLARE + lines TEXT[]; + numlines INTEGER := 10; +BEGIN + dbms_output.enable(); + dbms_output.put_line('Tab: here'); + dbms_output.put_line('Quote: ''single'' "double"'); + dbms_output.put_line('Backslash: \ forward: /'); + dbms_output.get_lines(lines, numlines); + RAISE NOTICE 'Test 8.1 - Special chars: % lines', numlines; + FOR i IN 1..numlines LOOP + RAISE NOTICE ' [%]', lines[i]; + END LOOP; +END; +/ + +-- Test 8.2: Numeric values via concatenation +DECLARE + line TEXT; + status INTEGER; +BEGIN + dbms_output.enable(); + dbms_output.put_line('Number: ' || 42); + dbms_output.get_line(line, status); + RAISE NOTICE 'Test 8.2 - Numeric: [%]', line; +END; +/ + +-- Test 8.3: Very long line +DECLARE + very_long TEXT := repeat('X', 1000); + line TEXT; + status INTEGER; +BEGIN + dbms_output.enable(10000); + dbms_output.put_line(very_long); + dbms_output.get_line(line, status); + RAISE NOTICE 'Test 8.3 - Long line length: %', length(line); +END; +/ + +-- Test 8.4: Exception handling preserves buffer +DECLARE + line TEXT; + status INTEGER; +BEGIN + dbms_output.enable(); + dbms_output.put_line('Before exception'); + BEGIN + RAISE EXCEPTION 'Test error'; + EXCEPTION WHEN OTHERS THEN + dbms_output.put_line('Caught: ' || SQLERRM); + END; + dbms_output.put_line('After exception'); + -- Verify all three lines are in buffer + dbms_output.get_line(line, status); + RAISE NOTICE 'Test 8.4a - [%]', line; + dbms_output.get_line(line, status); + RAISE NOTICE 'Test 8.4b - [%]', line; + dbms_output.get_line(line, status); + RAISE NOTICE 'Test 8.4c - [%]', line; +END; +/ + +-- Test 8.5: Nested blocks +DECLARE + lines TEXT[]; + numlines INTEGER := 10; +BEGIN + dbms_output.enable(); + dbms_output.put_line('Outer'); + BEGIN + dbms_output.put_line('Inner 1'); + BEGIN + dbms_output.put_line('Inner 2'); + END; + END; + dbms_output.put_line('Back to outer'); + dbms_output.get_lines(lines, numlines); + RAISE NOTICE 'Test 8.5 - Nested blocks: % lines', numlines; + FOR i IN 1..numlines LOOP + RAISE NOTICE ' [%]', lines[i]; + END LOOP; +END; +/ + +-- Test 8.6: Loop output +DECLARE + lines TEXT[]; + numlines INTEGER := 10; +BEGIN + dbms_output.enable(); + FOR i IN 1..3 LOOP + dbms_output.put_line('Iteration ' || i); + END LOOP; + dbms_output.get_lines(lines, numlines); + RAISE NOTICE 'Test 8.6 - Loop: % lines', numlines; + FOR i IN 1..numlines LOOP + RAISE NOTICE ' [%]', lines[i]; + END LOOP; +END; +/ + +-- ============================================================================= +-- Cleanup +-- ============================================================================= +DROP PROCEDURE test_output_proc; +DROP FUNCTION test_output_func; diff --git a/contrib/ivorysql_ora/src/builtin_packages/dbms_output/dbms_output--1.0.sql b/contrib/ivorysql_ora/src/builtin_packages/dbms_output/dbms_output--1.0.sql new file mode 100644 index 00000000000..7e356754901 --- /dev/null +++ b/contrib/ivorysql_ora/src/builtin_packages/dbms_output/dbms_output--1.0.sql @@ -0,0 +1,127 @@ +/*------------------------------------------------------------------------- + * 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_output--1.0.sql + * + * Oracle-compatible DBMS_OUTPUT package. + * Provides PUT_LINE, PUT, NEW_LINE, GET_LINE, and GET_LINES functions. + * + * contrib/ivorysql_ora/src/builtin_packages/dbms_output/dbms_output--1.0.sql + * + *------------------------------------------------------------------------- + */ + +-- Register C functions for DBMS_OUTPUT +CREATE FUNCTION sys.ora_dbms_output_enable(buffer_size INTEGER DEFAULT 20000) +RETURNS VOID +AS 'MODULE_PATHNAME', 'ora_dbms_output_enable' +LANGUAGE C VOLATILE; + +CREATE FUNCTION sys.ora_dbms_output_disable() +RETURNS VOID +AS 'MODULE_PATHNAME', 'ora_dbms_output_disable' +LANGUAGE C VOLATILE; + +CREATE FUNCTION sys.ora_dbms_output_put_line(a TEXT) +RETURNS VOID +AS 'MODULE_PATHNAME', 'ora_dbms_output_put_line' +LANGUAGE C VOLATILE; + +CREATE FUNCTION sys.ora_dbms_output_put(a TEXT) +RETURNS VOID +AS 'MODULE_PATHNAME', 'ora_dbms_output_put' +LANGUAGE C VOLATILE; + +CREATE FUNCTION sys.ora_dbms_output_new_line() +RETURNS VOID +AS 'MODULE_PATHNAME', 'ora_dbms_output_new_line' +LANGUAGE C VOLATILE; + +-- Create composite types for GET_LINE and GET_LINES return values +CREATE TYPE sys.dbms_output_line AS ( + line TEXT, + status INTEGER +); + +CREATE TYPE sys.dbms_output_lines AS ( + lines TEXT[], + numlines INTEGER +); + +CREATE FUNCTION sys.ora_dbms_output_get_line() +RETURNS sys.dbms_output_line +AS 'MODULE_PATHNAME', 'ora_dbms_output_get_line' +LANGUAGE C VOLATILE; + +CREATE FUNCTION sys.ora_dbms_output_get_lines(numlines INTEGER) +RETURNS sys.dbms_output_lines +AS 'MODULE_PATHNAME', 'ora_dbms_output_get_lines' +LANGUAGE C VOLATILE; + +-- Create DBMS_OUTPUT package +CREATE OR REPLACE PACKAGE dbms_output IS + PROCEDURE enable(buffer_size INTEGER DEFAULT 20000); + PROCEDURE disable; + PROCEDURE put_line(a TEXT); + PROCEDURE put(a TEXT); + PROCEDURE new_line; + PROCEDURE get_line(line OUT TEXT, status OUT INTEGER); + PROCEDURE get_lines(lines OUT TEXT[], numlines IN OUT INTEGER); +END dbms_output; + +CREATE OR REPLACE PACKAGE BODY dbms_output IS + + PROCEDURE enable(buffer_size INTEGER DEFAULT 20000) IS + BEGIN + PERFORM sys.ora_dbms_output_enable(buffer_size); + END; + + PROCEDURE disable IS + BEGIN + PERFORM sys.ora_dbms_output_disable(); + END; + + PROCEDURE put_line(a TEXT) IS + BEGIN + PERFORM sys.ora_dbms_output_put_line(a); + END; + + PROCEDURE put(a TEXT) IS + BEGIN + PERFORM sys.ora_dbms_output_put(a); + END; + + PROCEDURE new_line IS + BEGIN + PERFORM sys.ora_dbms_output_new_line(); + END; + + PROCEDURE get_line(line OUT TEXT, status OUT INTEGER) IS + result sys.dbms_output_line; + BEGIN + SELECT * INTO result FROM sys.ora_dbms_output_get_line(); + line := result.line; + status := result.status; + END; + + PROCEDURE get_lines(lines OUT TEXT[], numlines IN OUT INTEGER) IS + result sys.dbms_output_lines; + BEGIN + SELECT * INTO result FROM sys.ora_dbms_output_get_lines(numlines); + lines := result.lines; + numlines := result.numlines; + END; + +END dbms_output; diff --git a/contrib/ivorysql_ora/src/builtin_packages/dbms_output/dbms_output.c b/contrib/ivorysql_ora/src/builtin_packages/dbms_output/dbms_output.c new file mode 100644 index 00000000000..d36de900b23 --- /dev/null +++ b/contrib/ivorysql_ora/src/builtin_packages/dbms_output/dbms_output.c @@ -0,0 +1,520 @@ +/*------------------------------------------------------------------------- + * 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_output.c + * + * This file contains the native implementation of Oracle's DBMS_OUTPUT + * package for IvorySQL. + * + * Provides session-level buffering for PUT_LINE, PUT, NEW_LINE, + * GET_LINE, and GET_LINES functions with full Oracle compatibility. + * + * contrib/ivorysql_ora/src/builtin_packages/dbms_output/dbms_output.c + * + *------------------------------------------------------------------------- + */ + +#include "postgres.h" + +#include "access/xact.h" +#include "fmgr.h" +#include "funcapi.h" +#include "lib/stringinfo.h" +#include "utils/array.h" +#include "utils/builtins.h" +#include "utils/memutils.h" + +/* + * DBMS_OUTPUT buffer structure + * + * This is a per-backend global buffer that stores output lines. + * The buffer is transaction-scoped and cleared on COMMIT/ROLLBACK. + */ +typedef struct DbmsOutputBuffer +{ + char **lines; /* Array of completed line strings */ + int line_count; /* Current number of lines in buffer */ + int buffer_size; /* Max bytes allowed (Oracle uses bytes) */ + int buffer_used; /* Current bytes used in buffer */ + bool enabled; /* Buffer enabled/disabled state */ + StringInfo current_line; /* Accumulator for PUT calls (not yet a line) */ + int read_position; /* Current position for GET_LINE/GET_LINES */ + bool callback_registered; /* Track if xact callback is registered */ + MemoryContext buffer_mcxt; /* Memory context for buffer allocations */ + int lines_allocated; /* Size of lines array */ +} DbmsOutputBuffer; + +/* Global buffer - one per backend process */ +static DbmsOutputBuffer *output_buffer = NULL; + +/* Internal function declarations */ +static void init_output_buffer(int buffer_size); +static void cleanup_output_buffer(void); +static void add_line_to_buffer(const char *line); +static void dbms_output_xact_callback(XactEvent event, void *arg); +static void ensure_lines_capacity(void); + +/* SQL-callable function declarations */ +PG_FUNCTION_INFO_V1(ora_dbms_output_enable); +PG_FUNCTION_INFO_V1(ora_dbms_output_disable); +PG_FUNCTION_INFO_V1(ora_dbms_output_put_line); +PG_FUNCTION_INFO_V1(ora_dbms_output_put); +PG_FUNCTION_INFO_V1(ora_dbms_output_new_line); +PG_FUNCTION_INFO_V1(ora_dbms_output_get_line); +PG_FUNCTION_INFO_V1(ora_dbms_output_get_lines); + + +/* + * init_output_buffer + * + * Initialize or re-initialize the output buffer. + * CRITICAL: Oracle behavior - ENABLE always clears existing buffer. + */ +static void +init_output_buffer(int buffer_size) +{ + MemoryContext oldcontext; + + /* Oracle behavior: ENABLE always clears existing buffer */ + if (output_buffer != NULL) + cleanup_output_buffer(); + + /* Allocate buffer structure in TopMemoryContext */ + oldcontext = MemoryContextSwitchTo(TopMemoryContext); + + output_buffer = (DbmsOutputBuffer *) palloc0(sizeof(DbmsOutputBuffer)); + + /* Create dedicated memory context for buffer contents */ + output_buffer->buffer_mcxt = AllocSetContextCreate( + TopMemoryContext, + "DBMS_OUTPUT buffer", + ALLOCSET_DEFAULT_SIZES); + + MemoryContextSwitchTo(output_buffer->buffer_mcxt); + + /* Oracle tracks buffer in BYTES, not lines */ + if (buffer_size < 0) + output_buffer->buffer_size = INT_MAX; /* NULL = unlimited (Oracle 10g R2+) */ + else + output_buffer->buffer_size = buffer_size; + + /* + * Pre-allocate line array with reasonable initial size. + * For unlimited (INT_MAX), don't allocate huge array upfront - + * we'll grow dynamically via ensure_lines_capacity(). + */ + if (output_buffer->buffer_size == INT_MAX) + output_buffer->lines_allocated = 1000; /* Start with 1000 lines for unlimited */ + else + { + output_buffer->lines_allocated = output_buffer->buffer_size / 80; + if (output_buffer->lines_allocated < 100) + output_buffer->lines_allocated = 100; /* Minimum array size */ + } + + output_buffer->lines = (char **) palloc0(sizeof(char *) * output_buffer->lines_allocated); + output_buffer->current_line = makeStringInfo(); + output_buffer->enabled = true; + output_buffer->line_count = 0; + output_buffer->buffer_used = 0; + output_buffer->read_position = 0; + output_buffer->callback_registered = false; + + MemoryContextSwitchTo(oldcontext); + + /* Register transaction callback (only once per buffer lifecycle) */ + if (!output_buffer->callback_registered) + { + RegisterXactCallback(dbms_output_xact_callback, NULL); + output_buffer->callback_registered = true; + } +} + +/* + * cleanup_output_buffer + * + * Free all buffer resources and reset to NULL. + * Called on transaction end (COMMIT/ROLLBACK) and when ENABLE is called. + */ +static void +cleanup_output_buffer(void) +{ + if (output_buffer == NULL) + return; + + /* Unregister callback if it was registered */ + if (output_buffer->callback_registered) + { + UnregisterXactCallback(dbms_output_xact_callback, NULL); + output_buffer->callback_registered = false; + } + + /* Delete memory context (automatically frees all lines and current_line) */ + MemoryContextDelete(output_buffer->buffer_mcxt); + + /* Free buffer structure itself */ + pfree(output_buffer); + output_buffer = NULL; +} + +/* + * ensure_lines_capacity + * + * Grow the lines array if needed to accommodate more lines. + */ +static void +ensure_lines_capacity(void) +{ + MemoryContext oldcontext; + int new_capacity; + char **new_lines; + + if (output_buffer->line_count < output_buffer->lines_allocated) + return; /* Still have space */ + + /* Grow by 50% */ + new_capacity = output_buffer->lines_allocated + (output_buffer->lines_allocated / 2); + if (new_capacity < output_buffer->lines_allocated + 100) + new_capacity = output_buffer->lines_allocated + 100; + + oldcontext = MemoryContextSwitchTo(output_buffer->buffer_mcxt); + new_lines = (char **) repalloc(output_buffer->lines, sizeof(char *) * new_capacity); + output_buffer->lines = new_lines; + output_buffer->lines_allocated = new_capacity; + MemoryContextSwitchTo(oldcontext); +} + +/* + * add_line_to_buffer + * + * Add a completed line to the buffer. + * Checks for buffer overflow based on byte usage (Oracle behavior). + */ +static void +add_line_to_buffer(const char *line) +{ + MemoryContext oldcontext; + int line_bytes; + char *line_copy; + + /* Calculate bytes for this line (Oracle counts actual bytes) */ + line_bytes = strlen(line); + + /* Check buffer overflow BEFORE adding (Oracle behavior) */ + if (output_buffer->buffer_used + line_bytes > output_buffer->buffer_size) + ereport(ERROR, + (errcode(ERRCODE_PROGRAM_LIMIT_EXCEEDED), + errmsg("ORU-10027: buffer overflow, limit of %d bytes", + output_buffer->buffer_size))); + + /* Ensure we have space in lines array */ + ensure_lines_capacity(); + + /* Store line in buffer memory context */ + oldcontext = MemoryContextSwitchTo(output_buffer->buffer_mcxt); + line_copy = pstrdup(line); + output_buffer->lines[output_buffer->line_count++] = line_copy; + output_buffer->buffer_used += line_bytes; + MemoryContextSwitchTo(oldcontext); +} + +/* + * dbms_output_xact_callback + * + * Transaction callback to clean up buffer on COMMIT/ROLLBACK. + * Oracle behavior: buffer is transaction-scoped, not session-scoped. + */ +static void +dbms_output_xact_callback(XactEvent event, void *arg) +{ + switch (event) + { + case XACT_EVENT_ABORT: + case XACT_EVENT_COMMIT: + case XACT_EVENT_PREPARE: + /* Clean up buffer at transaction end */ + cleanup_output_buffer(); + break; + + default: + /* XACT_EVENT_PRE_COMMIT, etc. - ignore */ + break; + } +} + +/* + * ora_dbms_output_enable + * + * Enable output buffering with optional size limit. + * NULL parameter means UNLIMITED (Oracle 10g R2+). + * Oracle constraints: 2000 to 1000000 bytes when explicitly specified. + * Default (from SQL): 20000 bytes. + */ +Datum +ora_dbms_output_enable(PG_FUNCTION_ARGS) +{ + int32 buffer_size; + + /* Handle NULL argument (means UNLIMITED) */ + if (PG_ARGISNULL(0)) + buffer_size = -1; /* -1 = unlimited */ + else + { + buffer_size = PG_GETARG_INT32(0); + + /* Oracle constraints: 2000 to 1000000 bytes when explicitly specified */ + if (buffer_size < 2000 || buffer_size > 1000000) + ereport(ERROR, + (errcode(ERRCODE_INVALID_PARAMETER_VALUE), + errmsg("buffer size must be between 2000 and 1000000"))); + } + + /* Initialize buffer (clears existing if present) */ + init_output_buffer(buffer_size); + + PG_RETURN_VOID(); +} + +/* + * ora_dbms_output_disable + * + * Disable output buffering. + * Oracle behavior: buffer persists (can still GET_LINE), but PUT_LINE is ignored. + */ +Datum +ora_dbms_output_disable(PG_FUNCTION_ARGS) +{ + if (output_buffer != NULL) + output_buffer->enabled = false; + + PG_RETURN_VOID(); +} + +/* + * ora_dbms_output_put_line + * + * Output a line to the buffer (with newline). + * If there's pending PUT text, append it first (Oracle behavior). + * Oracle behavior: NULL is treated as empty string. + */ +Datum +ora_dbms_output_put_line(PG_FUNCTION_ARGS) +{ + char *line_str; + + /* Silently discard if buffer not enabled (Oracle behavior) */ + if (output_buffer == NULL || !output_buffer->enabled) + PG_RETURN_VOID(); + + /* Handle NULL argument - treat as empty string (Oracle behavior) */ + if (PG_ARGISNULL(0)) + line_str = ""; + else + { + text *line_text = PG_GETARG_TEXT_PP(0); + line_str = text_to_cstring(line_text); + } + + /* If there's pending PUT text, append it first (Oracle behavior) */ + if (output_buffer->current_line->len > 0) + { + appendStringInfoString(output_buffer->current_line, line_str); + add_line_to_buffer(output_buffer->current_line->data); + resetStringInfo(output_buffer->current_line); + } + else + { + /* No pending PUT text, just add the line */ + add_line_to_buffer(line_str); + } + + PG_RETURN_VOID(); +} + +/* + * ora_dbms_output_put + * + * Output text without newline (accumulates in current_line). + * Oracle behavior: not retrievable until NEW_LINE or PUT_LINE is called. + * Oracle behavior: NULL is treated as empty string (appends nothing). + */ +Datum +ora_dbms_output_put(PG_FUNCTION_ARGS) +{ + char *str; + + /* Silently discard if buffer not enabled */ + if (output_buffer == NULL || !output_buffer->enabled) + PG_RETURN_VOID(); + + /* Handle NULL argument - treat as empty string (Oracle behavior) */ + if (PG_ARGISNULL(0)) + str = ""; + else + { + text *text_arg = PG_GETARG_TEXT_PP(0); + str = text_to_cstring(text_arg); + } + + /* Accumulate in current_line without creating a line yet */ + appendStringInfoString(output_buffer->current_line, str); + + PG_RETURN_VOID(); +} + +/* + * ora_dbms_output_new_line + * + * Flush accumulated PUT text as a line. + * Oracle behavior: creates empty line if no PUT text accumulated. + */ +Datum +ora_dbms_output_new_line(PG_FUNCTION_ARGS) +{ + /* Silently discard if buffer not enabled */ + if (output_buffer == NULL || !output_buffer->enabled) + PG_RETURN_VOID(); + + /* Flush current_line to buffer as a completed line */ + if (output_buffer->current_line->len > 0) + { + add_line_to_buffer(output_buffer->current_line->data); + resetStringInfo(output_buffer->current_line); + } + else + { + /* Empty NEW_LINE creates empty string line (Oracle behavior) */ + add_line_to_buffer(""); + } + + PG_RETURN_VOID(); +} + +/* + * ora_dbms_output_get_line + * + * Retrieve one line from buffer. + * Returns: (line TEXT, status INTEGER) + * - status = 0: success, line contains data + * - status = 1: no more lines, line is NULL (Oracle behavior) + */ +Datum +ora_dbms_output_get_line(PG_FUNCTION_ARGS) +{ + TupleDesc tupdesc; + Datum values[2]; + bool nulls[2] = {false, false}; + HeapTuple tuple; + + /* Build tuple descriptor for return type */ + if (get_call_result_type(fcinfo, NULL, &tupdesc) != TYPEFUNC_COMPOSITE) + ereport(ERROR, + (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), + errmsg("function returning record called in context that cannot accept type record"))); + + tupdesc = BlessTupleDesc(tupdesc); + + if (output_buffer == NULL || + output_buffer->read_position >= output_buffer->line_count) + { + /* No more lines available - return NULL, not empty string (Oracle behavior) */ + nulls[0] = true; /* line = NULL */ + values[0] = (Datum) 0; + values[1] = Int32GetDatum(1); /* status = 1 (no more lines) */ + } + else + { + /* Return next line */ + char *line = output_buffer->lines[output_buffer->read_position++]; + + values[0] = CStringGetTextDatum(line); + values[1] = Int32GetDatum(0); /* status = 0 (success) */ + } + + tuple = heap_form_tuple(tupdesc, values, nulls); + PG_RETURN_DATUM(HeapTupleGetDatum(tuple)); +} + +/* + * ora_dbms_output_get_lines + * + * Retrieve multiple lines from buffer. + * Input: numlines (max lines to retrieve) + * Returns: (lines TEXT[], actual_count INTEGER) + * - actual_count is set to number of lines actually retrieved + */ +Datum +ora_dbms_output_get_lines(PG_FUNCTION_ARGS) +{ + int32 requested_lines; + int32 actual_lines = 0; + ArrayType *lines_array; + Datum *line_datums; + int available_lines; + int i; + TupleDesc tupdesc; + Datum values[2]; + bool nulls[2] = {false, false}; + HeapTuple tuple; + + requested_lines = PG_GETARG_INT32(0); + + /* Build tuple descriptor for return type */ + if (get_call_result_type(fcinfo, NULL, &tupdesc) != TYPEFUNC_COMPOSITE) + ereport(ERROR, + (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), + errmsg("function returning record called in context that cannot accept type record"))); + + tupdesc = BlessTupleDesc(tupdesc); + + if (output_buffer == NULL) + { + /* No buffer, return empty array */ + lines_array = construct_empty_array(TEXTOID); + actual_lines = 0; + } + else + { + /* Calculate how many lines we can actually return */ + available_lines = output_buffer->line_count - output_buffer->read_position; + actual_lines = (requested_lines < available_lines) ? requested_lines : available_lines; + + if (actual_lines > 0) + { + line_datums = (Datum *) palloc(sizeof(Datum) * actual_lines); + + for (i = 0; i < actual_lines; i++) + { + char *line = output_buffer->lines[output_buffer->read_position++]; + + line_datums[i] = CStringGetTextDatum(line); + } + + lines_array = construct_array(line_datums, actual_lines, TEXTOID, -1, false, TYPALIGN_INT); + pfree(line_datums); + } + else + { + lines_array = construct_empty_array(TEXTOID); + } + } + + /* Return composite (lines[], count) */ + values[0] = PointerGetDatum(lines_array); + values[1] = Int32GetDatum(actual_lines); + + tuple = heap_form_tuple(tupdesc, values, nulls); + PG_RETURN_DATUM(HeapTupleGetDatum(tuple)); +} diff --git a/src/pl/plisql/src/expected/plisql_nested_subproc2.out b/src/pl/plisql/src/expected/plisql_nested_subproc2.out index 9a0cf92660f..9f6025de6aa 100755 --- a/src/pl/plisql/src/expected/plisql_nested_subproc2.out +++ b/src/pl/plisql/src/expected/plisql_nested_subproc2.out @@ -3996,11 +3996,6 @@ begin end; / INFO: var1 = 2 -ERROR: schema "dbms_output" does not exist -LINE 1: CALL dbms_output.put_line('xiexie') - ^ -QUERY: CALL dbms_output.put_line('xiexie') -CONTEXT: PL/iSQL function inline_code_block line 5 at CALL create or replace function test.test_f(id integer) return integer is var1 integer; function test_f(id integer) return integer; From 8a1a87742298c059b7173a653d7a41325d46ac04 Mon Sep 17 00:00:00 2001 From: Rophy Tsai Date: Tue, 2 Dec 2025 23:54:32 +0000 Subject: [PATCH 02/13] fix: store NULL and empty string as NULL in DBMS_OUTPUT Oracle treats empty strings as NULL. Both PUT_LINE('') and PUT_LINE(NULL) should store actual NULL values, which GET_LINE returns as SQL NULL. Verified against Oracle 23.26 Free. Fixes #25 --- .../ivorysql_ora/expected/ora_dbms_output.out | 4 +- .../dbms_output/dbms_output.c | 54 +++++++++++++++---- 2 files changed, 46 insertions(+), 12 deletions(-) diff --git a/contrib/ivorysql_ora/expected/ora_dbms_output.out b/contrib/ivorysql_ora/expected/ora_dbms_output.out index 0a7b9ed56fc..4ccd43851a3 100644 --- a/contrib/ivorysql_ora/expected/ora_dbms_output.out +++ b/contrib/ivorysql_ora/expected/ora_dbms_output.out @@ -50,7 +50,7 @@ BEGIN RAISE NOTICE 'Test 1.3 - Empty string: [%], Status: %', line, status; END; / -NOTICE: Test 1.3 - Empty string: [], Status: 0 +NOTICE: Test 1.3 - Empty string: [], Status: 0 -- Test 1.4: NULL handling (should output empty line) DECLARE line TEXT; @@ -62,7 +62,7 @@ BEGIN RAISE NOTICE 'Test 1.4 - NULL input: [%], Status: %', line, status; END; / -NOTICE: Test 1.4 - NULL input: [], Status: 0 +NOTICE: Test 1.4 - NULL input: [], Status: 0 -- Test 1.5: GET_LINE when buffer is empty (status should be 1) DECLARE line TEXT; diff --git a/contrib/ivorysql_ora/src/builtin_packages/dbms_output/dbms_output.c b/contrib/ivorysql_ora/src/builtin_packages/dbms_output/dbms_output.c index d36de900b23..63d35f3f157 100644 --- a/contrib/ivorysql_ora/src/builtin_packages/dbms_output/dbms_output.c +++ b/contrib/ivorysql_ora/src/builtin_packages/dbms_output/dbms_output.c @@ -201,6 +201,7 @@ ensure_lines_capacity(void) * * Add a completed line to the buffer. * Checks for buffer overflow based on byte usage (Oracle behavior). + * NULL lines are stored as NULL pointers (Oracle behavior). */ static void add_line_to_buffer(const char *line) @@ -210,7 +211,8 @@ add_line_to_buffer(const char *line) char *line_copy; /* Calculate bytes for this line (Oracle counts actual bytes) */ - line_bytes = strlen(line); + /* NULL lines count as 0 bytes */ + line_bytes = (line != NULL) ? strlen(line) : 0; /* Check buffer overflow BEFORE adding (Oracle behavior) */ if (output_buffer->buffer_used + line_bytes > output_buffer->buffer_size) @@ -224,7 +226,8 @@ add_line_to_buffer(const char *line) /* Store line in buffer memory context */ oldcontext = MemoryContextSwitchTo(output_buffer->buffer_mcxt); - line_copy = pstrdup(line); + /* Store NULL as NULL pointer, not as empty string */ + line_copy = (line != NULL) ? pstrdup(line) : NULL; output_buffer->lines[output_buffer->line_count++] = line_copy; output_buffer->buffer_used += line_bytes; MemoryContextSwitchTo(oldcontext); @@ -307,20 +310,24 @@ ora_dbms_output_disable(PG_FUNCTION_ARGS) * * Output a line to the buffer (with newline). * If there's pending PUT text, append it first (Oracle behavior). - * Oracle behavior: NULL is treated as empty string. + * Oracle behavior: NULL stores actual NULL in buffer (not empty string). */ Datum ora_dbms_output_put_line(PG_FUNCTION_ARGS) { char *line_str; + bool is_null = false; /* Silently discard if buffer not enabled (Oracle behavior) */ if (output_buffer == NULL || !output_buffer->enabled) PG_RETURN_VOID(); - /* Handle NULL argument - treat as empty string (Oracle behavior) */ + /* Handle NULL argument - Oracle stores actual NULL */ if (PG_ARGISNULL(0)) - line_str = ""; + { + line_str = NULL; + is_null = true; + } else { text *line_text = PG_GETARG_TEXT_PP(0); @@ -330,13 +337,15 @@ ora_dbms_output_put_line(PG_FUNCTION_ARGS) /* If there's pending PUT text, append it first (Oracle behavior) */ if (output_buffer->current_line->len > 0) { - appendStringInfoString(output_buffer->current_line, line_str); + /* Append non-NULL text to current line */ + if (!is_null) + appendStringInfoString(output_buffer->current_line, line_str); add_line_to_buffer(output_buffer->current_line->data); resetStringInfo(output_buffer->current_line); } else { - /* No pending PUT text, just add the line */ + /* No pending PUT text, just add the line (may be NULL) */ add_line_to_buffer(line_str); } @@ -439,7 +448,16 @@ ora_dbms_output_get_line(PG_FUNCTION_ARGS) /* Return next line */ char *line = output_buffer->lines[output_buffer->read_position++]; - values[0] = CStringGetTextDatum(line); + /* Handle NULL lines (Oracle behavior: PUT_LINE(NULL) stores actual NULL) */ + if (line == NULL) + { + nulls[0] = true; + values[0] = (Datum) 0; + } + else + { + values[0] = CStringGetTextDatum(line); + } values[1] = Int32GetDatum(0); /* status = 0 (success) */ } @@ -493,17 +511,33 @@ ora_dbms_output_get_lines(PG_FUNCTION_ARGS) if (actual_lines > 0) { + bool *line_nulls; + int lbound = 1; /* 1-based array indexing */ + line_datums = (Datum *) palloc(sizeof(Datum) * actual_lines); + line_nulls = (bool *) palloc(sizeof(bool) * actual_lines); for (i = 0; i < actual_lines; i++) { char *line = output_buffer->lines[output_buffer->read_position++]; - line_datums[i] = CStringGetTextDatum(line); + /* Handle NULL lines (Oracle behavior) */ + if (line == NULL) + { + line_nulls[i] = true; + line_datums[i] = (Datum) 0; + } + else + { + line_nulls[i] = false; + line_datums[i] = CStringGetTextDatum(line); + } } - lines_array = construct_array(line_datums, actual_lines, TEXTOID, -1, false, TYPALIGN_INT); + lines_array = construct_md_array(line_datums, line_nulls, 1, &actual_lines, &lbound, + TEXTOID, -1, false, TYPALIGN_INT); pfree(line_datums); + pfree(line_nulls); } else { From ce711ad5c5306da73383888501dee4e9ec421dac Mon Sep 17 00:00:00 2001 From: Rophy Tsai Date: Wed, 3 Dec 2025 00:02:03 +0000 Subject: [PATCH 03/13] feat: add 32767 byte line length limit to DBMS_OUTPUT Oracle enforces a maximum line length of 32767 bytes per line. Exceeding this limit raises ORU-10028 error. - Check line length in PUT_LINE before adding to buffer - Check accumulated line length in PUT before appending - Add test cases for line length boundary conditions Verified against Oracle 23.26 Free. Fixes #21 --- .../ivorysql_ora/expected/ora_dbms_output.out | 42 +++++++++++++++++++ contrib/ivorysql_ora/sql/ora_dbms_output.sql | 42 +++++++++++++++++++ .../dbms_output/dbms_output.c | 37 ++++++++++++++-- 3 files changed, 118 insertions(+), 3 deletions(-) diff --git a/contrib/ivorysql_ora/expected/ora_dbms_output.out b/contrib/ivorysql_ora/expected/ora_dbms_output.out index 4ccd43851a3..4d025ba62b5 100644 --- a/contrib/ivorysql_ora/expected/ora_dbms_output.out +++ b/contrib/ivorysql_ora/expected/ora_dbms_output.out @@ -523,6 +523,48 @@ NOTICE: [Iteration 1] NOTICE: [Iteration 2] NOTICE: [Iteration 3] -- ============================================================================= +-- Section 9: Line Length Limit (32767 bytes) +-- ============================================================================= +-- Test 9.1: PUT_LINE at exactly 32767 bytes (should succeed) +DECLARE + long_line TEXT := repeat('X', 32767); + line TEXT; + status INTEGER; +BEGIN + dbms_output.enable(100000); + dbms_output.put_line(long_line); + dbms_output.get_line(line, status); + RAISE NOTICE 'Test 9.1 - Max line (32767 bytes): length=%, Status=%', length(line), status; +END; +/ +NOTICE: Test 9.1 - Max line (32767 bytes): length=32767, Status=0 +-- Test 9.2: PUT_LINE exceeding 32767 bytes (should fail with ORU-10028) +DECLARE + long_line TEXT := repeat('X', 32768); +BEGIN + dbms_output.enable(100000); + dbms_output.put_line(long_line); + RAISE NOTICE 'Test 9.2 - Should not reach here'; +EXCEPTION WHEN OTHERS THEN + RAISE NOTICE 'Test 9.2 - Line overflow error: %', SQLERRM; +END; +/ +NOTICE: Test 9.2 - Line overflow error: ORU-10028: line length overflow, limit of 32767 bytes per line +-- Test 9.3: PUT accumulating to exceed 32767 bytes (should fail with ORU-10028) +DECLARE + chunk TEXT := repeat('X', 32767); +BEGIN + dbms_output.enable(100000); + dbms_output.put(chunk); + dbms_output.put('Y'); -- This triggers the overflow + dbms_output.new_line(); + RAISE NOTICE 'Test 9.3 - Should not reach here'; +EXCEPTION WHEN OTHERS THEN + RAISE NOTICE 'Test 9.3 - PUT overflow error: %', SQLERRM; +END; +/ +NOTICE: Test 9.3 - PUT overflow error: ORU-10028: line length overflow, limit of 32767 bytes per line +-- ============================================================================= -- Cleanup -- ============================================================================= DROP PROCEDURE test_output_proc; diff --git a/contrib/ivorysql_ora/sql/ora_dbms_output.sql b/contrib/ivorysql_ora/sql/ora_dbms_output.sql index 18c7309c763..68a9b725899 100644 --- a/contrib/ivorysql_ora/sql/ora_dbms_output.sql +++ b/contrib/ivorysql_ora/sql/ora_dbms_output.sql @@ -500,6 +500,48 @@ BEGIN END; / +-- ============================================================================= +-- Section 9: Line Length Limit (32767 bytes) +-- ============================================================================= +-- Test 9.1: PUT_LINE at exactly 32767 bytes (should succeed) +DECLARE + long_line TEXT := repeat('X', 32767); + line TEXT; + status INTEGER; +BEGIN + dbms_output.enable(100000); + dbms_output.put_line(long_line); + dbms_output.get_line(line, status); + RAISE NOTICE 'Test 9.1 - Max line (32767 bytes): length=%, Status=%', length(line), status; +END; +/ + +-- Test 9.2: PUT_LINE exceeding 32767 bytes (should fail with ORU-10028) +DECLARE + long_line TEXT := repeat('X', 32768); +BEGIN + dbms_output.enable(100000); + dbms_output.put_line(long_line); + RAISE NOTICE 'Test 9.2 - Should not reach here'; +EXCEPTION WHEN OTHERS THEN + RAISE NOTICE 'Test 9.2 - Line overflow error: %', SQLERRM; +END; +/ + +-- Test 9.3: PUT accumulating to exceed 32767 bytes (should fail with ORU-10028) +DECLARE + chunk TEXT := repeat('X', 32767); +BEGIN + dbms_output.enable(100000); + dbms_output.put(chunk); + dbms_output.put('Y'); -- This triggers the overflow + dbms_output.new_line(); + RAISE NOTICE 'Test 9.3 - Should not reach here'; +EXCEPTION WHEN OTHERS THEN + RAISE NOTICE 'Test 9.3 - PUT overflow error: %', SQLERRM; +END; +/ + -- ============================================================================= -- Cleanup -- ============================================================================= diff --git a/contrib/ivorysql_ora/src/builtin_packages/dbms_output/dbms_output.c b/contrib/ivorysql_ora/src/builtin_packages/dbms_output/dbms_output.c index 63d35f3f157..334c7fd7de3 100644 --- a/contrib/ivorysql_ora/src/builtin_packages/dbms_output/dbms_output.c +++ b/contrib/ivorysql_ora/src/builtin_packages/dbms_output/dbms_output.c @@ -59,6 +59,9 @@ typedef struct DbmsOutputBuffer /* Global buffer - one per backend process */ static DbmsOutputBuffer *output_buffer = NULL; +/* Oracle line length limit: 32767 bytes per line */ +#define DBMS_OUTPUT_MAX_LINE_LENGTH 32767 + /* Internal function declarations */ static void init_output_buffer(int buffer_size); static void cleanup_output_buffer(void); @@ -311,12 +314,14 @@ ora_dbms_output_disable(PG_FUNCTION_ARGS) * Output a line to the buffer (with newline). * If there's pending PUT text, append it first (Oracle behavior). * Oracle behavior: NULL stores actual NULL in buffer (not empty string). + * Oracle behavior: raises ORU-10028 if line exceeds 32767 bytes. */ Datum ora_dbms_output_put_line(PG_FUNCTION_ARGS) { char *line_str; bool is_null = false; + int line_len = 0; /* Silently discard if buffer not enabled (Oracle behavior) */ if (output_buffer == NULL || !output_buffer->enabled) @@ -332,11 +337,19 @@ ora_dbms_output_put_line(PG_FUNCTION_ARGS) { text *line_text = PG_GETARG_TEXT_PP(0); line_str = text_to_cstring(line_text); + line_len = strlen(line_str); } /* If there's pending PUT text, append it first (Oracle behavior) */ if (output_buffer->current_line->len > 0) { + /* Check line length limit BEFORE appending (Oracle behavior) */ + if (output_buffer->current_line->len + line_len > DBMS_OUTPUT_MAX_LINE_LENGTH) + ereport(ERROR, + (errcode(ERRCODE_PROGRAM_LIMIT_EXCEEDED), + errmsg("ORU-10028: line length overflow, limit of %d bytes per line", + DBMS_OUTPUT_MAX_LINE_LENGTH))); + /* Append non-NULL text to current line */ if (!is_null) appendStringInfoString(output_buffer->current_line, line_str); @@ -345,7 +358,14 @@ ora_dbms_output_put_line(PG_FUNCTION_ARGS) } else { - /* No pending PUT text, just add the line (may be NULL) */ + /* No pending PUT text - check line length for direct add */ + if (line_len > DBMS_OUTPUT_MAX_LINE_LENGTH) + ereport(ERROR, + (errcode(ERRCODE_PROGRAM_LIMIT_EXCEEDED), + errmsg("ORU-10028: line length overflow, limit of %d bytes per line", + DBMS_OUTPUT_MAX_LINE_LENGTH))); + + /* Just add the line (may be NULL) */ add_line_to_buffer(line_str); } @@ -358,11 +378,13 @@ ora_dbms_output_put_line(PG_FUNCTION_ARGS) * Output text without newline (accumulates in current_line). * Oracle behavior: not retrievable until NEW_LINE or PUT_LINE is called. * Oracle behavior: NULL is treated as empty string (appends nothing). + * Oracle behavior: raises ORU-10028 if line exceeds 32767 bytes. */ Datum ora_dbms_output_put(PG_FUNCTION_ARGS) { char *str; + int str_len; /* Silently discard if buffer not enabled */ if (output_buffer == NULL || !output_buffer->enabled) @@ -370,13 +392,22 @@ ora_dbms_output_put(PG_FUNCTION_ARGS) /* Handle NULL argument - treat as empty string (Oracle behavior) */ if (PG_ARGISNULL(0)) - str = ""; - else + PG_RETURN_VOID(); /* NULL appends nothing */ + { text *text_arg = PG_GETARG_TEXT_PP(0); str = text_to_cstring(text_arg); } + str_len = strlen(str); + + /* Check line length limit BEFORE appending (Oracle behavior) */ + if (output_buffer->current_line->len + str_len > DBMS_OUTPUT_MAX_LINE_LENGTH) + ereport(ERROR, + (errcode(ERRCODE_PROGRAM_LIMIT_EXCEEDED), + errmsg("ORU-10028: line length overflow, limit of %d bytes per line", + DBMS_OUTPUT_MAX_LINE_LENGTH))); + /* Accumulate in current_line without creating a line yet */ appendStringInfoString(output_buffer->current_line, str); From 74dd6d6f2a293cf9bc51e9160d9ff71e2d5e6fff Mon Sep 17 00:00:00 2001 From: Rophy Tsai Date: Wed, 3 Dec 2025 05:06:01 +0000 Subject: [PATCH 04/13] fix: address CodeRabbit review feedback for DBMS_OUTPUT - Fix potential integer overflow in buffer check by using subtraction instead of addition (line_bytes > buffer_size - buffer_used) - Normalize negative numlines parameter to 0 in GET_LINES --- .../src/builtin_packages/dbms_output/dbms_output.c | 7 ++++++- 1 file changed, 6 insertions(+), 1 deletion(-) diff --git a/contrib/ivorysql_ora/src/builtin_packages/dbms_output/dbms_output.c b/contrib/ivorysql_ora/src/builtin_packages/dbms_output/dbms_output.c index 334c7fd7de3..131139f3c05 100644 --- a/contrib/ivorysql_ora/src/builtin_packages/dbms_output/dbms_output.c +++ b/contrib/ivorysql_ora/src/builtin_packages/dbms_output/dbms_output.c @@ -218,7 +218,8 @@ add_line_to_buffer(const char *line) line_bytes = (line != NULL) ? strlen(line) : 0; /* Check buffer overflow BEFORE adding (Oracle behavior) */ - if (output_buffer->buffer_used + line_bytes > output_buffer->buffer_size) + /* Use subtraction to avoid potential integer overflow in addition */ + if (line_bytes > output_buffer->buffer_size - output_buffer->buffer_used) ereport(ERROR, (errcode(ERRCODE_PROGRAM_LIMIT_EXCEEDED), errmsg("ORU-10027: buffer overflow, limit of %d bytes", @@ -520,6 +521,10 @@ ora_dbms_output_get_lines(PG_FUNCTION_ARGS) requested_lines = PG_GETARG_INT32(0); + /* Normalize negative values to 0 (Oracle behavior) */ + if (requested_lines < 0) + requested_lines = 0; + /* Build tuple descriptor for return type */ if (get_call_result_type(fcinfo, NULL, &tupdesc) != TYPEFUNC_COMPOSITE) ereport(ERROR, From a0b03695430f732f031752e47fc5f2b3982f2e7f Mon Sep 17 00:00:00 2001 From: Rophy Tsai Date: Wed, 3 Dec 2025 06:57:21 +0000 Subject: [PATCH 05/13] docs: clarify Oracle compatibility in DBMS_OUTPUT comments Address CodeRabbit review feedback: - Change "full Oracle compatibility" to "high Oracle compatibility" - Clarify that re-ENABLE clearing buffer is IvorySQL behavior (not Oracle) - Clarify that buffer size range is IvorySQL-enforced (stricter than Oracle) - Reference GitHub issues #22 and #26 for tracking differences --- .../dbms_output/dbms_output.c | 20 +++++++++++++------ 1 file changed, 14 insertions(+), 6 deletions(-) diff --git a/contrib/ivorysql_ora/src/builtin_packages/dbms_output/dbms_output.c b/contrib/ivorysql_ora/src/builtin_packages/dbms_output/dbms_output.c index 131139f3c05..4c545bbe696 100644 --- a/contrib/ivorysql_ora/src/builtin_packages/dbms_output/dbms_output.c +++ b/contrib/ivorysql_ora/src/builtin_packages/dbms_output/dbms_output.c @@ -19,7 +19,8 @@ * package for IvorySQL. * * Provides session-level buffering for PUT_LINE, PUT, NEW_LINE, - * GET_LINE, and GET_LINES functions with full Oracle compatibility. + * GET_LINE, and GET_LINES functions with high Oracle compatibility. + * See ora_dbms_output.sql tests for known behavioral differences. * * contrib/ivorysql_ora/src/builtin_packages/dbms_output/dbms_output.c * @@ -83,14 +84,17 @@ PG_FUNCTION_INFO_V1(ora_dbms_output_get_lines); * init_output_buffer * * Initialize or re-initialize the output buffer. - * CRITICAL: Oracle behavior - ENABLE always clears existing buffer. + * + * IvorySQL behavior: ENABLE always clears existing buffer. + * Note: Oracle preserves buffer on re-ENABLE; this is an intentional + * IvorySQL simplification. See GitHub issue #26 for tracking. */ static void init_output_buffer(int buffer_size) { MemoryContext oldcontext; - /* Oracle behavior: ENABLE always clears existing buffer */ + /* IvorySQL behavior: ENABLE clears existing buffer (differs from Oracle) */ if (output_buffer != NULL) cleanup_output_buffer(); @@ -266,8 +270,12 @@ dbms_output_xact_callback(XactEvent event, void *arg) * * Enable output buffering with optional size limit. * NULL parameter means UNLIMITED (Oracle 10g R2+). - * Oracle constraints: 2000 to 1000000 bytes when explicitly specified. - * Default (from SQL): 20000 bytes. + * + * IvorySQL-enforced range: 2000 to 1000000 bytes when explicitly specified. + * Note: Oracle silently clamps below-min values to 2000 and has no upper limit. + * See GitHub issue #22 for tracking this difference. + * + * Default (from SQL wrapper): 20000 bytes. */ Datum ora_dbms_output_enable(PG_FUNCTION_ARGS) @@ -281,7 +289,7 @@ ora_dbms_output_enable(PG_FUNCTION_ARGS) { buffer_size = PG_GETARG_INT32(0); - /* Oracle constraints: 2000 to 1000000 bytes when explicitly specified */ + /* IvorySQL-enforced range (stricter than Oracle, see issue #22) */ if (buffer_size < 2000 || buffer_size > 1000000) ereport(ERROR, (errcode(ERRCODE_INVALID_PARAMETER_VALUE), From e90d67bc6f3546f84d5b47a5f39c9eb9979dcb22 Mon Sep 17 00:00:00 2001 From: Rophy Tsai Date: Wed, 3 Dec 2025 07:08:33 +0000 Subject: [PATCH 06/13] test: update opr_sanity expected output for DBMS_OUTPUT types Add dbms_output_line and dbms_output_lines composite types to the expected output for the collation sanity check query. --- src/oracle_test/regress/expected/opr_sanity.out | 10 ++++++---- 1 file changed, 6 insertions(+), 4 deletions(-) diff --git a/src/oracle_test/regress/expected/opr_sanity.out b/src/oracle_test/regress/expected/opr_sanity.out index c01476f9444..32a119205e5 100644 --- a/src/oracle_test/regress/expected/opr_sanity.out +++ b/src/oracle_test/regress/expected/opr_sanity.out @@ -2344,10 +2344,12 @@ WHERE c.oid = attrelid AND c.oid < 16384 AND c.relkind != 'v' AND -- we don't care about columns in views attcollation != 0 AND attcollation != (SELECT oid FROM pg_collation WHERE collname = 'C'); - relname | attname | attcollation ----------+---------+-------------- - dual | dummy | 100 -(1 row) + relname | attname | attcollation +-------------------+---------+-------------- + dual | dummy | 100 + dbms_output_line | line | 100 + dbms_output_lines | lines | 100 +(3 rows) -- Double-check that collation-sensitive indexes have "C" collation, too. SELECT indexrelid::regclass, indrelid::regclass, iclass, icoll From a6f814fa90d597d6a88d00fcfeed2ffad3cd5c28 Mon Sep 17 00:00:00 2001 From: Rophy Tsai Date: Wed, 3 Dec 2025 07:14:15 +0000 Subject: [PATCH 07/13] test: update opr_sanity_1.out expected output for DBMS_OUTPUT types --- src/test/regress/expected/opr_sanity_1.out | 10 ++++++---- 1 file changed, 6 insertions(+), 4 deletions(-) diff --git a/src/test/regress/expected/opr_sanity_1.out b/src/test/regress/expected/opr_sanity_1.out index 9ea90d7a629..a2210aedd05 100644 --- a/src/test/regress/expected/opr_sanity_1.out +++ b/src/test/regress/expected/opr_sanity_1.out @@ -2341,10 +2341,12 @@ WHERE c.oid = attrelid AND c.oid < 16384 AND c.relkind != 'v' AND -- we don't care about columns in views attcollation != 0 AND attcollation != (SELECT oid FROM pg_collation WHERE collname = 'C'); - relname | attname | attcollation ----------+---------+-------------- - dual | dummy | 100 -(1 row) + relname | attname | attcollation +-------------------+---------+-------------- + dual | dummy | 100 + dbms_output_line | line | 100 + dbms_output_lines | lines | 100 +(3 rows) -- Double-check that collation-sensitive indexes have "C" collation, too. SELECT indexrelid::regclass, indrelid::regclass, iclass, icoll From ebbb425d0e97d4607dff0ffbd9fae95ef990c82f Mon Sep 17 00:00:00 2001 From: Rophy Tsai Date: Wed, 24 Dec 2025 08:09:52 +0000 Subject: [PATCH 08/13] fix: address PR review comments for DBMS_OUTPUT - ENABLE(NULL) now uses max buffer (1000000) instead of INT_MAX - Add named constants for buffer size limits and line allocation - Add XACT_EVENT_PARALLEL_COMMIT/ABORT handling - Remove references to external issue trackers (#22, #26) - Update test comments to reflect NULL buffer behavior --- .../ivorysql_ora/expected/ora_dbms_output.out | 6 +- contrib/ivorysql_ora/sql/ora_dbms_output.sql | 4 +- .../dbms_output/dbms_output.c | 55 ++++++++++--------- 3 files changed, 34 insertions(+), 31 deletions(-) diff --git a/contrib/ivorysql_ora/expected/ora_dbms_output.out b/contrib/ivorysql_ora/expected/ora_dbms_output.out index 4d025ba62b5..0395b1b6668 100644 --- a/contrib/ivorysql_ora/expected/ora_dbms_output.out +++ b/contrib/ivorysql_ora/expected/ora_dbms_output.out @@ -242,18 +242,18 @@ CALL dbms_output.enable(1000001); ERROR: buffer size must be between 2000 and 1000000 CONTEXT: SQL statement "SELECT sys.ora_dbms_output_enable(buffer_size)" PL/iSQL function enable line 3 at PERFORM --- Test 4.5: NULL buffer size uses default +-- Test 4.5: NULL buffer size uses maximum (1000000) DECLARE line TEXT; status INTEGER; BEGIN dbms_output.enable(NULL); - dbms_output.put_line('NULL buffer uses default'); + dbms_output.put_line('NULL buffer uses max'); dbms_output.get_line(line, status); RAISE NOTICE 'Test 4.5 - NULL buffer: [%]', line; END; / -NOTICE: Test 4.5 - NULL buffer: [NULL buffer uses default] +NOTICE: Test 4.5 - NULL buffer: [NULL buffer uses max] -- ============================================================================= -- Section 5: Buffer overflow -- ============================================================================= diff --git a/contrib/ivorysql_ora/sql/ora_dbms_output.sql b/contrib/ivorysql_ora/sql/ora_dbms_output.sql index 68a9b725899..a304ad052e5 100644 --- a/contrib/ivorysql_ora/sql/ora_dbms_output.sql +++ b/contrib/ivorysql_ora/sql/ora_dbms_output.sql @@ -238,13 +238,13 @@ END; -- Test 4.4: Buffer size above maximum (should fail) CALL dbms_output.enable(1000001); --- Test 4.5: NULL buffer size uses default +-- Test 4.5: NULL buffer size uses maximum (1000000) DECLARE line TEXT; status INTEGER; BEGIN dbms_output.enable(NULL); - dbms_output.put_line('NULL buffer uses default'); + dbms_output.put_line('NULL buffer uses max'); dbms_output.get_line(line, status); RAISE NOTICE 'Test 4.5 - NULL buffer: [%]', line; END; diff --git a/contrib/ivorysql_ora/src/builtin_packages/dbms_output/dbms_output.c b/contrib/ivorysql_ora/src/builtin_packages/dbms_output/dbms_output.c index 4c545bbe696..8660a2c9724 100644 --- a/contrib/ivorysql_ora/src/builtin_packages/dbms_output/dbms_output.c +++ b/contrib/ivorysql_ora/src/builtin_packages/dbms_output/dbms_output.c @@ -63,6 +63,14 @@ static DbmsOutputBuffer *output_buffer = NULL; /* Oracle line length limit: 32767 bytes per line */ #define DBMS_OUTPUT_MAX_LINE_LENGTH 32767 +/* Buffer size limits (IvorySQL-enforced, stricter than Oracle) */ +#define DBMS_OUTPUT_MIN_BUFFER_SIZE 2000 +#define DBMS_OUTPUT_MAX_BUFFER_SIZE 1000000 + +/* Initial line array allocation parameters */ +#define DBMS_OUTPUT_MIN_LINES_ALLOCATED 100 +#define DBMS_OUTPUT_ESTIMATED_LINE_LENGTH 80 + /* Internal function declarations */ static void init_output_buffer(int buffer_size); static void cleanup_output_buffer(void); @@ -87,7 +95,7 @@ PG_FUNCTION_INFO_V1(ora_dbms_output_get_lines); * * IvorySQL behavior: ENABLE always clears existing buffer. * Note: Oracle preserves buffer on re-ENABLE; this is an intentional - * IvorySQL simplification. See GitHub issue #26 for tracking. + * IvorySQL simplification. */ static void init_output_buffer(int buffer_size) @@ -111,25 +119,16 @@ init_output_buffer(int buffer_size) MemoryContextSwitchTo(output_buffer->buffer_mcxt); - /* Oracle tracks buffer in BYTES, not lines */ - if (buffer_size < 0) - output_buffer->buffer_size = INT_MAX; /* NULL = unlimited (Oracle 10g R2+) */ - else - output_buffer->buffer_size = buffer_size; + /* Store buffer size in bytes (IvorySQL enforces 2000-1000000 range) */ + output_buffer->buffer_size = buffer_size; /* * Pre-allocate line array with reasonable initial size. - * For unlimited (INT_MAX), don't allocate huge array upfront - - * we'll grow dynamically via ensure_lines_capacity(). + * Estimate based on average line length, with a minimum allocation. */ - if (output_buffer->buffer_size == INT_MAX) - output_buffer->lines_allocated = 1000; /* Start with 1000 lines for unlimited */ - else - { - output_buffer->lines_allocated = output_buffer->buffer_size / 80; - if (output_buffer->lines_allocated < 100) - output_buffer->lines_allocated = 100; /* Minimum array size */ - } + output_buffer->lines_allocated = buffer_size / DBMS_OUTPUT_ESTIMATED_LINE_LENGTH; + if (output_buffer->lines_allocated < DBMS_OUTPUT_MIN_LINES_ALLOCATED) + output_buffer->lines_allocated = DBMS_OUTPUT_MIN_LINES_ALLOCATED; output_buffer->lines = (char **) palloc0(sizeof(char *) * output_buffer->lines_allocated); output_buffer->current_line = makeStringInfo(); @@ -253,7 +252,9 @@ dbms_output_xact_callback(XactEvent event, void *arg) switch (event) { case XACT_EVENT_ABORT: + case XACT_EVENT_PARALLEL_ABORT: case XACT_EVENT_COMMIT: + case XACT_EVENT_PARALLEL_COMMIT: case XACT_EVENT_PREPARE: /* Clean up buffer at transaction end */ cleanup_output_buffer(); @@ -269,31 +270,33 @@ dbms_output_xact_callback(XactEvent event, void *arg) * ora_dbms_output_enable * * Enable output buffering with optional size limit. - * NULL parameter means UNLIMITED (Oracle 10g R2+). * - * IvorySQL-enforced range: 2000 to 1000000 bytes when explicitly specified. - * Note: Oracle silently clamps below-min values to 2000 and has no upper limit. - * See GitHub issue #22 for tracking this difference. + * IvorySQL-enforced range: 2000 to 1000000 bytes. + * - NULL parameter uses maximum (1000000 bytes) for safety. + * - Default (from SQL wrapper): 20000 bytes. * - * Default (from SQL wrapper): 20000 bytes. + * Note: Oracle allows unlimited buffer with NULL and silently clamps + * below-min values to 2000. IvorySQL enforces stricter limits as a + * protective measure for the initial implementation. */ Datum ora_dbms_output_enable(PG_FUNCTION_ARGS) { int32 buffer_size; - /* Handle NULL argument (means UNLIMITED) */ + /* Handle NULL argument - use maximum allowed size */ if (PG_ARGISNULL(0)) - buffer_size = -1; /* -1 = unlimited */ + buffer_size = DBMS_OUTPUT_MAX_BUFFER_SIZE; else { buffer_size = PG_GETARG_INT32(0); - /* IvorySQL-enforced range (stricter than Oracle, see issue #22) */ - if (buffer_size < 2000 || buffer_size > 1000000) + /* IvorySQL-enforced range (stricter than Oracle) */ + if (buffer_size < DBMS_OUTPUT_MIN_BUFFER_SIZE || buffer_size > DBMS_OUTPUT_MAX_BUFFER_SIZE) ereport(ERROR, (errcode(ERRCODE_INVALID_PARAMETER_VALUE), - errmsg("buffer size must be between 2000 and 1000000"))); + errmsg("buffer size must be between %d and %d", + DBMS_OUTPUT_MIN_BUFFER_SIZE, DBMS_OUTPUT_MAX_BUFFER_SIZE))); } /* Initialize buffer (clears existing if present) */ From 6245ed213d3fc988904d3e8bbf86ac1e6f43aca0 Mon Sep 17 00:00:00 2001 From: Rophy Tsai Date: Wed, 24 Dec 2025 10:25:08 +0000 Subject: [PATCH 09/13] fix: make DBMS_OUTPUT buffer session-scoped like Oracle Buffer now persists across COMMIT/ROLLBACK instead of being cleared. This matches Oracle's behavior where the buffer is local to the session. - Remove transaction callback registration - Remove dbms_output_xact_callback function - Remove callback_registered field from struct - Remove unused xact.h include --- .../dbms_output/dbms_output.c | 48 +------------------ 1 file changed, 2 insertions(+), 46 deletions(-) diff --git a/contrib/ivorysql_ora/src/builtin_packages/dbms_output/dbms_output.c b/contrib/ivorysql_ora/src/builtin_packages/dbms_output/dbms_output.c index 8660a2c9724..8dfb15cb6cd 100644 --- a/contrib/ivorysql_ora/src/builtin_packages/dbms_output/dbms_output.c +++ b/contrib/ivorysql_ora/src/builtin_packages/dbms_output/dbms_output.c @@ -29,7 +29,6 @@ #include "postgres.h" -#include "access/xact.h" #include "fmgr.h" #include "funcapi.h" #include "lib/stringinfo.h" @@ -41,7 +40,7 @@ * DBMS_OUTPUT buffer structure * * This is a per-backend global buffer that stores output lines. - * The buffer is transaction-scoped and cleared on COMMIT/ROLLBACK. + * The buffer is session-scoped and persists across transactions (Oracle behavior). */ typedef struct DbmsOutputBuffer { @@ -52,7 +51,6 @@ typedef struct DbmsOutputBuffer bool enabled; /* Buffer enabled/disabled state */ StringInfo current_line; /* Accumulator for PUT calls (not yet a line) */ int read_position; /* Current position for GET_LINE/GET_LINES */ - bool callback_registered; /* Track if xact callback is registered */ MemoryContext buffer_mcxt; /* Memory context for buffer allocations */ int lines_allocated; /* Size of lines array */ } DbmsOutputBuffer; @@ -75,7 +73,6 @@ static DbmsOutputBuffer *output_buffer = NULL; static void init_output_buffer(int buffer_size); static void cleanup_output_buffer(void); static void add_line_to_buffer(const char *line); -static void dbms_output_xact_callback(XactEvent event, void *arg); static void ensure_lines_capacity(void); /* SQL-callable function declarations */ @@ -136,23 +133,15 @@ init_output_buffer(int buffer_size) output_buffer->line_count = 0; output_buffer->buffer_used = 0; output_buffer->read_position = 0; - output_buffer->callback_registered = false; MemoryContextSwitchTo(oldcontext); - - /* Register transaction callback (only once per buffer lifecycle) */ - if (!output_buffer->callback_registered) - { - RegisterXactCallback(dbms_output_xact_callback, NULL); - output_buffer->callback_registered = true; - } } /* * cleanup_output_buffer * * Free all buffer resources and reset to NULL. - * Called on transaction end (COMMIT/ROLLBACK) and when ENABLE is called. + * Called when ENABLE is called to re-initialize the buffer. */ static void cleanup_output_buffer(void) @@ -160,13 +149,6 @@ cleanup_output_buffer(void) if (output_buffer == NULL) return; - /* Unregister callback if it was registered */ - if (output_buffer->callback_registered) - { - UnregisterXactCallback(dbms_output_xact_callback, NULL); - output_buffer->callback_registered = false; - } - /* Delete memory context (automatically frees all lines and current_line) */ MemoryContextDelete(output_buffer->buffer_mcxt); @@ -240,32 +222,6 @@ add_line_to_buffer(const char *line) MemoryContextSwitchTo(oldcontext); } -/* - * dbms_output_xact_callback - * - * Transaction callback to clean up buffer on COMMIT/ROLLBACK. - * Oracle behavior: buffer is transaction-scoped, not session-scoped. - */ -static void -dbms_output_xact_callback(XactEvent event, void *arg) -{ - switch (event) - { - case XACT_EVENT_ABORT: - case XACT_EVENT_PARALLEL_ABORT: - case XACT_EVENT_COMMIT: - case XACT_EVENT_PARALLEL_COMMIT: - case XACT_EVENT_PREPARE: - /* Clean up buffer at transaction end */ - cleanup_output_buffer(); - break; - - default: - /* XACT_EVENT_PRE_COMMIT, etc. - ignore */ - break; - } -} - /* * ora_dbms_output_enable * From c647a68f57cf352c99e4c702e3b2f49b35f83aaa Mon Sep 17 00:00:00 2001 From: Rophy Tsai Date: Thu, 25 Dec 2025 00:53:23 +0000 Subject: [PATCH 10/13] test: add regression tests for session-scoped DBMS_OUTPUT buffer Test 10.1: Verify buffer persists after block ends (implicit commit) Test 10.2: Verify multiple blocks accumulate in buffer --- .../ivorysql_ora/expected/ora_dbms_output.out | 62 ++++++++++++++++++ contrib/ivorysql_ora/sql/ora_dbms_output.sql | 64 +++++++++++++++++++ 2 files changed, 126 insertions(+) diff --git a/contrib/ivorysql_ora/expected/ora_dbms_output.out b/contrib/ivorysql_ora/expected/ora_dbms_output.out index 0395b1b6668..9352a69f118 100644 --- a/contrib/ivorysql_ora/expected/ora_dbms_output.out +++ b/contrib/ivorysql_ora/expected/ora_dbms_output.out @@ -565,6 +565,68 @@ END; / NOTICE: Test 9.3 - PUT overflow error: ORU-10028: line length overflow, limit of 32767 bytes per line -- ============================================================================= +-- Section 10: Session Scope (buffer persists across transactions) +-- ============================================================================= +-- Test 10.1: Buffer persists after block ends (implicit commit) +-- Write in first block +DO $$ +BEGIN + dbms_output.enable(1000000); + dbms_output.put_line('Written in block 1'); +END; +$$; +-- Read in second block (different transaction) +DO $$ +DECLARE + v_line TEXT; + v_status INTEGER; +BEGIN + dbms_output.get_line(v_line, v_status); + IF v_status = 0 THEN + RAISE NOTICE 'Test 10.1 - Read after commit: [%]', v_line; + ELSE + RAISE NOTICE 'Test 10.1 FAILED - Buffer was cleared (status=%)', v_status; + END IF; +END; +$$; +NOTICE: Test 10.1 - Read after commit: [Written in block 1] +-- Test 10.2: Multiple blocks accumulate in buffer +DO $$ +BEGIN + dbms_output.enable(1000000); + dbms_output.put_line('Line from block A'); +END; +$$; +DO $$ +BEGIN + dbms_output.put_line('Line from block B'); +END; +$$; +DO $$ +BEGIN + dbms_output.put_line('Line from block C'); +END; +$$; +DO $$ +DECLARE + v_line TEXT; + v_status INTEGER; + v_count INTEGER := 0; +BEGIN + LOOP + dbms_output.get_line(v_line, v_status); + EXIT WHEN v_status != 0; + v_count := v_count + 1; + RAISE NOTICE 'Test 10.2 - Line %: [%]', v_count, v_line; + END LOOP; + RAISE NOTICE 'Test 10.2 - Total lines read: %', v_count; +END; +$$; +NOTICE: Test 10.2 - Line 1: [Line from block A] +NOTICE: Test 10.2 - Line 2: [Line from block B] +NOTICE: Test 10.2 - Line 3: [Line from block C] +NOTICE: Test 10.2 - Total lines read: 3 +-- ============================================================================= -- Cleanup -- ============================================================================= DROP PROCEDURE test_output_proc; diff --git a/contrib/ivorysql_ora/sql/ora_dbms_output.sql b/contrib/ivorysql_ora/sql/ora_dbms_output.sql index a304ad052e5..9ba94bb9094 100644 --- a/contrib/ivorysql_ora/sql/ora_dbms_output.sql +++ b/contrib/ivorysql_ora/sql/ora_dbms_output.sql @@ -542,6 +542,70 @@ EXCEPTION WHEN OTHERS THEN END; / +-- ============================================================================= +-- Section 10: Session Scope (buffer persists across transactions) +-- ============================================================================= + +-- Test 10.1: Buffer persists after block ends (implicit commit) +-- Write in first block +DO $$ +BEGIN + dbms_output.enable(1000000); + dbms_output.put_line('Written in block 1'); +END; +$$; + +-- Read in second block (different transaction) +DO $$ +DECLARE + v_line TEXT; + v_status INTEGER; +BEGIN + dbms_output.get_line(v_line, v_status); + IF v_status = 0 THEN + RAISE NOTICE 'Test 10.1 - Read after commit: [%]', v_line; + ELSE + RAISE NOTICE 'Test 10.1 FAILED - Buffer was cleared (status=%)', v_status; + END IF; +END; +$$; + +-- Test 10.2: Multiple blocks accumulate in buffer +DO $$ +BEGIN + dbms_output.enable(1000000); + dbms_output.put_line('Line from block A'); +END; +$$; + +DO $$ +BEGIN + dbms_output.put_line('Line from block B'); +END; +$$; + +DO $$ +BEGIN + dbms_output.put_line('Line from block C'); +END; +$$; + +DO $$ +DECLARE + v_line TEXT; + v_status INTEGER; + v_count INTEGER := 0; +BEGIN + LOOP + dbms_output.get_line(v_line, v_status); + EXIT WHEN v_status != 0; + v_count := v_count + 1; + RAISE NOTICE 'Test 10.2 - Line %: [%]', v_count, v_line; + END LOOP; + RAISE NOTICE 'Test 10.2 - Total lines read: %', v_count; +END; +$$; + -- ============================================================================= -- Cleanup -- ============================================================================= From 8ae2835630eaeb307759f05300fd62ba7005a292 Mon Sep 17 00:00:00 2001 From: Rophy Tsai Date: Thu, 25 Dec 2025 01:19:27 +0000 Subject: [PATCH 11/13] test: add regression test for VARCHAR2 OUT parameter compatibility Section 11 tests document current limitation where VARCHAR2 OUT parameters fail with "corresponding argument is not writable" error. Oracle's GET_LINE uses VARCHAR2 for OUT parameters, but IvorySQL's implementation uses TEXT. Implicit casts don't work for OUT parameters. Tests expect ERROR output to document current behavior before fix. --- .../ivorysql_ora/expected/ora_dbms_output.out | 41 +++++++++++++++++++ contrib/ivorysql_ora/sql/ora_dbms_output.sql | 40 ++++++++++++++++++ 2 files changed, 81 insertions(+) diff --git a/contrib/ivorysql_ora/expected/ora_dbms_output.out b/contrib/ivorysql_ora/expected/ora_dbms_output.out index 9352a69f118..8e6c1c47510 100644 --- a/contrib/ivorysql_ora/expected/ora_dbms_output.out +++ b/contrib/ivorysql_ora/expected/ora_dbms_output.out @@ -627,6 +627,47 @@ NOTICE: Test 10.2 - Line 2: [Line from block B] NOTICE: Test 10.2 - Line 3: [Line from block C] NOTICE: Test 10.2 - Total lines read: 3 -- ============================================================================= +-- Section 11: VARCHAR2 Parameter Compatibility (Oracle standard type) +-- ============================================================================= +-- Test 11.1: GET_LINE with VARCHAR2 OUT parameter +-- Oracle uses VARCHAR2 for GET_LINE, migrated code commonly uses VARCHAR2 variables +DO $$ +DECLARE + v_line VARCHAR2(32767); + v_status INTEGER; +BEGIN + dbms_output.enable(1000000); + dbms_output.put_line('VARCHAR2 test line'); + dbms_output.get_line(v_line, v_status); + IF v_status = 0 THEN + RAISE NOTICE 'Test 11.1 - VARCHAR2 GET_LINE: [%]', v_line; + ELSE + RAISE NOTICE 'Test 11.1 FAILED - status=%', v_status; + END IF; +END; +$$; +ERROR: procedure parameter "line" is an output parameter but corresponding argument is not writable +CONTEXT: PL/iSQL function inline_code_block line 8 at CALL +-- Test 11.2: GET_LINES with VARCHAR2[] OUT parameter +DO $$ +DECLARE + v_lines VARCHAR2(32767)[]; + v_numlines INTEGER := 10; +BEGIN + dbms_output.enable(1000000); + dbms_output.put_line('Line A'); + dbms_output.put_line('Line B'); + dbms_output.get_lines(v_lines, v_numlines); + IF v_numlines = 2 THEN + RAISE NOTICE 'Test 11.2 - VARCHAR2[] GET_LINES: % lines', v_numlines; + ELSE + RAISE NOTICE 'Test 11.2 FAILED - got % lines', v_numlines; + END IF; +END; +$$; +ERROR: procedure parameter "lines" is an output parameter but corresponding argument is not writable +CONTEXT: PL/iSQL function inline_code_block line 9 at CALL +-- ============================================================================= -- Cleanup -- ============================================================================= DROP PROCEDURE test_output_proc; diff --git a/contrib/ivorysql_ora/sql/ora_dbms_output.sql b/contrib/ivorysql_ora/sql/ora_dbms_output.sql index 9ba94bb9094..d5e3c5baebc 100644 --- a/contrib/ivorysql_ora/sql/ora_dbms_output.sql +++ b/contrib/ivorysql_ora/sql/ora_dbms_output.sql @@ -606,6 +606,46 @@ BEGIN END; $$; +-- ============================================================================= +-- Section 11: VARCHAR2 Parameter Compatibility (Oracle standard type) +-- ============================================================================= + +-- Test 11.1: GET_LINE with VARCHAR2 OUT parameter +-- Oracle uses VARCHAR2 for GET_LINE, migrated code commonly uses VARCHAR2 variables +DO $$ +DECLARE + v_line VARCHAR2(32767); + v_status INTEGER; +BEGIN + dbms_output.enable(1000000); + dbms_output.put_line('VARCHAR2 test line'); + dbms_output.get_line(v_line, v_status); + IF v_status = 0 THEN + RAISE NOTICE 'Test 11.1 - VARCHAR2 GET_LINE: [%]', v_line; + ELSE + RAISE NOTICE 'Test 11.1 FAILED - status=%', v_status; + END IF; +END; +$$; + +-- Test 11.2: GET_LINES with VARCHAR2[] OUT parameter +DO $$ +DECLARE + v_lines VARCHAR2(32767)[]; + v_numlines INTEGER := 10; +BEGIN + dbms_output.enable(1000000); + dbms_output.put_line('Line A'); + dbms_output.put_line('Line B'); + dbms_output.get_lines(v_lines, v_numlines); + IF v_numlines = 2 THEN + RAISE NOTICE 'Test 11.2 - VARCHAR2[] GET_LINES: % lines', v_numlines; + ELSE + RAISE NOTICE 'Test 11.2 FAILED - got % lines', v_numlines; + END IF; +END; +$$; + -- ============================================================================= -- Cleanup -- ============================================================================= From 42afdcc873823f74b34a0562bfe516318bb695b7 Mon Sep 17 00:00:00 2001 From: Rophy Tsai Date: Thu, 25 Dec 2025 01:22:08 +0000 Subject: [PATCH 12/13] fix: add VARCHAR2 overloads for DBMS_OUTPUT OUT parameters Oracle uses VARCHAR2 for GET_LINE and GET_LINES OUT parameters. When users declare variables as VARCHAR2 (common Oracle practice), implicit casts don't work for OUT parameters because the value cannot be written back through the cast. Add overloaded procedures: - get_line(line OUT VARCHAR2, status OUT INTEGER) - get_lines(lines OUT VARCHAR2[], numlines IN OUT INTEGER) This allows migrated Oracle code using VARCHAR2 to work correctly. --- .../ivorysql_ora/expected/ora_dbms_output.out | 6 ++---- .../dbms_output/dbms_output--1.0.sql | 18 ++++++++++++++++++ 2 files changed, 20 insertions(+), 4 deletions(-) diff --git a/contrib/ivorysql_ora/expected/ora_dbms_output.out b/contrib/ivorysql_ora/expected/ora_dbms_output.out index 8e6c1c47510..ede62f2699d 100644 --- a/contrib/ivorysql_ora/expected/ora_dbms_output.out +++ b/contrib/ivorysql_ora/expected/ora_dbms_output.out @@ -646,8 +646,7 @@ BEGIN END IF; END; $$; -ERROR: procedure parameter "line" is an output parameter but corresponding argument is not writable -CONTEXT: PL/iSQL function inline_code_block line 8 at CALL +NOTICE: Test 11.1 - VARCHAR2 GET_LINE: [VARCHAR2 test line] -- Test 11.2: GET_LINES with VARCHAR2[] OUT parameter DO $$ DECLARE @@ -665,8 +664,7 @@ BEGIN END IF; END; $$; -ERROR: procedure parameter "lines" is an output parameter but corresponding argument is not writable -CONTEXT: PL/iSQL function inline_code_block line 9 at CALL +NOTICE: Test 11.2 - VARCHAR2[] GET_LINES: 2 lines -- ============================================================================= -- Cleanup -- ============================================================================= diff --git a/contrib/ivorysql_ora/src/builtin_packages/dbms_output/dbms_output--1.0.sql b/contrib/ivorysql_ora/src/builtin_packages/dbms_output/dbms_output--1.0.sql index 7e356754901..d19432af4fb 100644 --- a/contrib/ivorysql_ora/src/builtin_packages/dbms_output/dbms_output--1.0.sql +++ b/contrib/ivorysql_ora/src/builtin_packages/dbms_output/dbms_output--1.0.sql @@ -78,7 +78,9 @@ CREATE OR REPLACE PACKAGE dbms_output IS PROCEDURE put(a TEXT); PROCEDURE new_line; PROCEDURE get_line(line OUT TEXT, status OUT INTEGER); + PROCEDURE get_line(line OUT VARCHAR2, status OUT INTEGER); PROCEDURE get_lines(lines OUT TEXT[], numlines IN OUT INTEGER); + PROCEDURE get_lines(lines OUT VARCHAR2[], numlines IN OUT INTEGER); END dbms_output; CREATE OR REPLACE PACKAGE BODY dbms_output IS @@ -116,6 +118,14 @@ CREATE OR REPLACE PACKAGE BODY dbms_output IS status := result.status; END; + PROCEDURE get_line(line OUT VARCHAR2, status OUT INTEGER) IS + result sys.dbms_output_line; + BEGIN + SELECT * INTO result FROM sys.ora_dbms_output_get_line(); + line := result.line; + status := result.status; + END; + PROCEDURE get_lines(lines OUT TEXT[], numlines IN OUT INTEGER) IS result sys.dbms_output_lines; BEGIN @@ -124,4 +134,12 @@ CREATE OR REPLACE PACKAGE BODY dbms_output IS numlines := result.numlines; END; + PROCEDURE get_lines(lines OUT VARCHAR2[], numlines IN OUT INTEGER) IS + result sys.dbms_output_lines; + BEGIN + SELECT * INTO result FROM sys.ora_dbms_output_get_lines(numlines); + lines := result.lines; + numlines := result.numlines; + END; + END dbms_output; From 5fad8c8a528767774c06d7caf2cb431ab2012ac9 Mon Sep 17 00:00:00 2001 From: Rophy Tsai Date: Thu, 25 Dec 2025 02:36:27 +0000 Subject: [PATCH 13/13] feat: implement dynamic ring buffer for DBMS_OUTPUT - Ring buffer with length-prefixed strings (2 bytes per line overhead) - Dynamic growth: expands by min(buffer_size, max(DEFAULT_BUFFER_SIZE, capacity * GROWTH_FACTOR)) - ENABLE(NULL) creates unlimited buffer starting at DEFAULT_BUFFER_SIZE - Values < MIN_BUFFER_SIZE silently clamped to minimum (Oracle behavior) - Buffer space recycled when lines are read via GET_LINE/GET_LINES - Per-line overhead not counted toward user-specified limit (Oracle behavior) --- .../ivorysql_ora/expected/ora_dbms_output.out | 77 +++- contrib/ivorysql_ora/sql/ora_dbms_output.sql | 72 ++- .../dbms_output/dbms_output.c | 426 ++++++++++++++---- 3 files changed, 463 insertions(+), 112 deletions(-) diff --git a/contrib/ivorysql_ora/expected/ora_dbms_output.out b/contrib/ivorysql_ora/expected/ora_dbms_output.out index ede62f2699d..69b4f1d5a61 100644 --- a/contrib/ivorysql_ora/expected/ora_dbms_output.out +++ b/contrib/ivorysql_ora/expected/ora_dbms_output.out @@ -208,11 +208,8 @@ NOTICE: Test 3.4 - Only visible after enable: [Visible], Status: 0 -- ============================================================================= -- Section 4: Buffer size limits -- ============================================================================= --- Test 4.1: Buffer size below minimum (should fail) +-- Test 4.1: Buffer size below minimum (silently clamped to 2000, Oracle behavior) CALL dbms_output.enable(1000); -ERROR: buffer size must be between 2000 and 1000000 -CONTEXT: SQL statement "SELECT sys.ora_dbms_output_enable(buffer_size)" -PL/iSQL function enable line 3 at PERFORM -- Test 4.2: Buffer size at minimum (should succeed) DECLARE line TEXT; @@ -237,12 +234,9 @@ BEGIN END; / NOTICE: Test 4.3 - Max buffer: [Max buffer works] --- Test 4.4: Buffer size above maximum (should fail) +-- Test 4.4: Buffer size above 1000000 (now allowed, no max limit) CALL dbms_output.enable(1000001); -ERROR: buffer size must be between 2000 and 1000000 -CONTEXT: SQL statement "SELECT sys.ora_dbms_output_enable(buffer_size)" -PL/iSQL function enable line 3 at PERFORM --- Test 4.5: NULL buffer size uses maximum (1000000) +-- Test 4.5: NULL buffer size uses unlimited (starts at 20000, grows dynamically) DECLARE line TEXT; status INTEGER; @@ -279,6 +273,34 @@ BEGIN END; / NOTICE: Test 5.1 - Overflow at line 47: ORU-10027: buffer overflow, limit of 2000 bytes +-- Test 5.2: User limit honored even after internal buffer expansion +-- Small lines cause internal buffer to expand (2-byte overhead per line) +-- but user-perceived content limit should still be enforced +DECLARE + v_count INTEGER := 0; +BEGIN + dbms_output.enable(2000); -- 2000 byte content limit + -- Write 1-byte lines until overflow + -- Internal: 1-byte lines need 3 bytes each (2 prefix + 1 data) + -- Buffer will expand from 2000 to accommodate overhead + -- But content limit (2000 bytes) should still be enforced + FOR i IN 1..3000 LOOP + BEGIN + dbms_output.put_line('X'); + v_count := i; + EXCEPTION WHEN OTHERS THEN + EXIT; + END; + END LOOP; + -- Should write exactly 2000 lines (2000 bytes content) + IF v_count = 2000 THEN + RAISE NOTICE 'Test 5.2 - User limit honored after expansion: PASSED (% lines)', v_count; + ELSE + RAISE NOTICE 'Test 5.2 - FAILED: expected 2000 lines, got %', v_count; + END IF; +END; +/ +NOTICE: Test 5.2 - User limit honored after expansion: PASSED (2000 lines) -- ============================================================================= -- Section 6: GET_LINE and GET_LINES behavior -- ============================================================================= @@ -666,6 +688,43 @@ END; $$; NOTICE: Test 11.2 - VARCHAR2[] GET_LINES: 2 lines -- ============================================================================= +-- Section 12: Buffer Space Recycling (Oracle recycles space after GET_LINE) +-- ============================================================================= +-- Test 12.1: Buffer space should be recycled after GET_LINE +-- Oracle frees buffer space when lines are read, allowing reuse +DO $$ +DECLARE + v_line TEXT; + v_status INTEGER; + v_chunk TEXT := RPAD('X', 50, 'X'); -- 50 byte line +BEGIN + dbms_output.enable(2000); -- 2000 byte buffer + + -- Phase 1: Write 30 lines (approx 1500 bytes, within limit) + FOR i IN 1..30 LOOP + dbms_output.put_line(v_chunk); + END LOOP; + + -- Phase 2: Read 20 lines (should free ~1000 bytes) + FOR i IN 1..20 LOOP + dbms_output.get_line(v_line, v_status); + END LOOP; + + -- Phase 3: Write 20 more lines (~1000 bytes) + -- With recycling: ~500 bytes unread + 1000 new = 1500 bytes (OK) + -- Without recycling: 1500 + 1000 = 2500 bytes (overflow) + BEGIN + FOR i IN 1..20 LOOP + dbms_output.put_line(v_chunk); + END LOOP; + RAISE NOTICE 'Test 12.1 - Buffer recycling: PASSED'; + EXCEPTION WHEN OTHERS THEN + RAISE NOTICE 'Test 12.1 - Buffer recycling FAILED: %', SQLERRM; + END; +END; +$$; +NOTICE: Test 12.1 - Buffer recycling: PASSED +-- ============================================================================= -- Cleanup -- ============================================================================= DROP PROCEDURE test_output_proc; diff --git a/contrib/ivorysql_ora/sql/ora_dbms_output.sql b/contrib/ivorysql_ora/sql/ora_dbms_output.sql index d5e3c5baebc..42d646eae26 100644 --- a/contrib/ivorysql_ora/sql/ora_dbms_output.sql +++ b/contrib/ivorysql_ora/sql/ora_dbms_output.sql @@ -208,7 +208,7 @@ END; -- Section 4: Buffer size limits -- ============================================================================= --- Test 4.1: Buffer size below minimum (should fail) +-- Test 4.1: Buffer size below minimum (silently clamped to 2000, Oracle behavior) CALL dbms_output.enable(1000); -- Test 4.2: Buffer size at minimum (should succeed) @@ -235,10 +235,10 @@ BEGIN END; / --- Test 4.4: Buffer size above maximum (should fail) +-- Test 4.4: Buffer size above 1000000 (now allowed, no max limit) CALL dbms_output.enable(1000001); --- Test 4.5: NULL buffer size uses maximum (1000000) +-- Test 4.5: NULL buffer size uses unlimited (starts at 20000, grows dynamically) DECLARE line TEXT; status INTEGER; @@ -276,6 +276,34 @@ BEGIN END; / +-- Test 5.2: User limit honored even after internal buffer expansion +-- Small lines cause internal buffer to expand (2-byte overhead per line) +-- but user-perceived content limit should still be enforced +DECLARE + v_count INTEGER := 0; +BEGIN + dbms_output.enable(2000); -- 2000 byte content limit + -- Write 1-byte lines until overflow + -- Internal: 1-byte lines need 3 bytes each (2 prefix + 1 data) + -- Buffer will expand from 2000 to accommodate overhead + -- But content limit (2000 bytes) should still be enforced + FOR i IN 1..3000 LOOP + BEGIN + dbms_output.put_line('X'); + v_count := i; + EXCEPTION WHEN OTHERS THEN + EXIT; + END; + END LOOP; + -- Should write exactly 2000 lines (2000 bytes content) + IF v_count = 2000 THEN + RAISE NOTICE 'Test 5.2 - User limit honored after expansion: PASSED (% lines)', v_count; + ELSE + RAISE NOTICE 'Test 5.2 - FAILED: expected 2000 lines, got %', v_count; + END IF; +END; +/ + -- ============================================================================= -- Section 6: GET_LINE and GET_LINES behavior -- ============================================================================= @@ -646,6 +674,44 @@ BEGIN END; $$; +-- ============================================================================= +-- Section 12: Buffer Space Recycling (Oracle recycles space after GET_LINE) +-- ============================================================================= + +-- Test 12.1: Buffer space should be recycled after GET_LINE +-- Oracle frees buffer space when lines are read, allowing reuse +DO $$ +DECLARE + v_line TEXT; + v_status INTEGER; + v_chunk TEXT := RPAD('X', 50, 'X'); -- 50 byte line +BEGIN + dbms_output.enable(2000); -- 2000 byte buffer + + -- Phase 1: Write 30 lines (approx 1500 bytes, within limit) + FOR i IN 1..30 LOOP + dbms_output.put_line(v_chunk); + END LOOP; + + -- Phase 2: Read 20 lines (should free ~1000 bytes) + FOR i IN 1..20 LOOP + dbms_output.get_line(v_line, v_status); + END LOOP; + + -- Phase 3: Write 20 more lines (~1000 bytes) + -- With recycling: ~500 bytes unread + 1000 new = 1500 bytes (OK) + -- Without recycling: 1500 + 1000 = 2500 bytes (overflow) + BEGIN + FOR i IN 1..20 LOOP + dbms_output.put_line(v_chunk); + END LOOP; + RAISE NOTICE 'Test 12.1 - Buffer recycling: PASSED'; + EXCEPTION WHEN OTHERS THEN + RAISE NOTICE 'Test 12.1 - Buffer recycling FAILED: %', SQLERRM; + END; +END; +$$; + -- ============================================================================= -- Cleanup -- ============================================================================= diff --git a/contrib/ivorysql_ora/src/builtin_packages/dbms_output/dbms_output.c b/contrib/ivorysql_ora/src/builtin_packages/dbms_output/dbms_output.c index 8dfb15cb6cd..8b1519bde0c 100644 --- a/contrib/ivorysql_ora/src/builtin_packages/dbms_output/dbms_output.c +++ b/contrib/ivorysql_ora/src/builtin_packages/dbms_output/dbms_output.c @@ -41,39 +41,57 @@ * * This is a per-backend global buffer that stores output lines. * The buffer is session-scoped and persists across transactions (Oracle behavior). + * + * Uses a contiguous ring buffer with length-prefixed strings to allow buffer + * space recycling when lines are read via GET_LINE/GET_LINES (Oracle behavior). + * + * Each line is stored as: [2-byte length][data bytes] + * NULL lines use length = 0xFFFF as a marker. + * + * The buffer grows dynamically when internal storage is full but user-perceived + * content limit is not reached (length prefixes don't count toward user limit). */ typedef struct DbmsOutputBuffer { - char **lines; /* Array of completed line strings */ - int line_count; /* Current number of lines in buffer */ - int buffer_size; /* Max bytes allowed (Oracle uses bytes) */ - int buffer_used; /* Current bytes used in buffer */ + char *buffer; /* Contiguous ring buffer */ + int capacity; /* Current internal buffer size (bytes) */ + int head; /* Next write position (byte offset) */ + int tail; /* Next read position (byte offset) */ + int64 buffer_size; /* User-specified content limit, -1 = unlimited */ + int buffer_used; /* Content bytes only (user-perceived usage) */ + int line_count; /* Number of lines currently in buffer */ bool enabled; /* Buffer enabled/disabled state */ StringInfo current_line; /* Accumulator for PUT calls (not yet a line) */ - int read_position; /* Current position for GET_LINE/GET_LINES */ MemoryContext buffer_mcxt; /* Memory context for buffer allocations */ - int lines_allocated; /* Size of lines array */ } DbmsOutputBuffer; /* Global buffer - one per backend process */ static DbmsOutputBuffer *output_buffer = NULL; -/* Oracle line length limit: 32767 bytes per line */ +/* Oracle line length limit: 32767 bytes per line (fits in 2-byte length prefix) */ #define DBMS_OUTPUT_MAX_LINE_LENGTH 32767 -/* Buffer size limits (IvorySQL-enforced, stricter than Oracle) */ +/* Buffer size constants */ #define DBMS_OUTPUT_MIN_BUFFER_SIZE 2000 -#define DBMS_OUTPUT_MAX_BUFFER_SIZE 1000000 +#define DBMS_OUTPUT_DEFAULT_BUFFER_SIZE 20000 +#define DBMS_OUTPUT_UNLIMITED ((int64) -1) + +/* Length prefix size and NULL marker */ +#define DBMS_OUTPUT_LENGTH_PREFIX_SIZE 2 +#define DBMS_OUTPUT_NULL_MARKER 0xFFFF -/* Initial line array allocation parameters */ -#define DBMS_OUTPUT_MIN_LINES_ALLOCATED 100 -#define DBMS_OUTPUT_ESTIMATED_LINE_LENGTH 80 +/* Dynamic growth factor */ +#define DBMS_OUTPUT_GROWTH_FACTOR 0.20 /* Internal function declarations */ -static void init_output_buffer(int buffer_size); +static void init_output_buffer(int64 buffer_size); static void cleanup_output_buffer(void); -static void add_line_to_buffer(const char *line); -static void ensure_lines_capacity(void); +static void expand_buffer(int needed_space); +static void add_line_to_buffer(const char *line, int line_len); +static void ring_write(int pos, const char *data, int len); +static void ring_read(int pos, char *data, int len); +static uint16 ring_read_uint16(int pos); +static void ring_write_uint16(int pos, uint16 value); /* SQL-callable function declarations */ PG_FUNCTION_INFO_V1(ora_dbms_output_enable); @@ -90,14 +108,24 @@ PG_FUNCTION_INFO_V1(ora_dbms_output_get_lines); * * Initialize or re-initialize the output buffer. * + * buffer_size: user-specified content limit in bytes, or -1 for unlimited. + * + * Initial allocation strategy: + * - For fixed size: allocate buffer_size bytes initially + * - For unlimited (-1): allocate DBMS_OUTPUT_DEFAULT_BUFFER_SIZE bytes initially + * + * The buffer grows dynamically when internal storage is full but user limit + * is not reached. + * * IvorySQL behavior: ENABLE always clears existing buffer. * Note: Oracle preserves buffer on re-ENABLE; this is an intentional * IvorySQL simplification. */ static void -init_output_buffer(int buffer_size) +init_output_buffer(int64 buffer_size) { MemoryContext oldcontext; + int initial_capacity; /* IvorySQL behavior: ENABLE clears existing buffer (differs from Oracle) */ if (output_buffer != NULL) @@ -116,23 +144,27 @@ init_output_buffer(int buffer_size) MemoryContextSwitchTo(output_buffer->buffer_mcxt); - /* Store buffer size in bytes (IvorySQL enforces 2000-1000000 range) */ + /* Store buffer size (user limit, or -1 for unlimited) */ output_buffer->buffer_size = buffer_size; /* - * Pre-allocate line array with reasonable initial size. - * Estimate based on average line length, with a minimum allocation. + * Initial capacity: allocate claimed size, or default for unlimited. + * Buffer will grow dynamically if internal storage fills up before + * user-perceived content limit is reached. */ - output_buffer->lines_allocated = buffer_size / DBMS_OUTPUT_ESTIMATED_LINE_LENGTH; - if (output_buffer->lines_allocated < DBMS_OUTPUT_MIN_LINES_ALLOCATED) - output_buffer->lines_allocated = DBMS_OUTPUT_MIN_LINES_ALLOCATED; + if (buffer_size == DBMS_OUTPUT_UNLIMITED) + initial_capacity = DBMS_OUTPUT_DEFAULT_BUFFER_SIZE; + else + initial_capacity = (int) buffer_size; - output_buffer->lines = (char **) palloc0(sizeof(char *) * output_buffer->lines_allocated); + output_buffer->capacity = initial_capacity; + output_buffer->buffer = (char *) palloc(output_buffer->capacity); output_buffer->current_line = makeStringInfo(); output_buffer->enabled = true; - output_buffer->line_count = 0; + output_buffer->head = 0; + output_buffer->tail = 0; output_buffer->buffer_used = 0; - output_buffer->read_position = 0; + output_buffer->line_count = 0; MemoryContextSwitchTo(oldcontext); } @@ -149,7 +181,7 @@ cleanup_output_buffer(void) if (output_buffer == NULL) return; - /* Delete memory context (automatically frees all lines and current_line) */ + /* Delete memory context (automatically frees buffer and current_line) */ MemoryContextDelete(output_buffer->buffer_mcxt); /* Free buffer structure itself */ @@ -158,68 +190,235 @@ cleanup_output_buffer(void) } /* - * ensure_lines_capacity + * expand_buffer * - * Grow the lines array if needed to accommodate more lines. + * Expand the internal buffer capacity when it's full but user-perceived + * content limit is not reached. + * + * Growth strategy: + * - Fixed buffer: min(buffer_size, max(DEFAULT_BUFFER_SIZE, capacity * GROWTH_FACTOR)) + * - Unlimited: max(DEFAULT_BUFFER_SIZE, capacity * GROWTH_FACTOR) + * + * This involves "packing" the ring buffer: linearizing any wrapped data + * into a new larger buffer. */ static void -ensure_lines_capacity(void) +expand_buffer(int needed_space) { MemoryContext oldcontext; + int growth; int new_capacity; - char **new_lines; + char *new_buffer; + int internal_used; + + /* Calculate current internal usage */ + internal_used = output_buffer->buffer_used + + (output_buffer->line_count * DBMS_OUTPUT_LENGTH_PREFIX_SIZE); - if (output_buffer->line_count < output_buffer->lines_allocated) - return; /* Still have space */ + /* Calculate base growth: max(DEFAULT_BUFFER_SIZE, capacity * GROWTH_FACTOR) */ + growth = (int) (output_buffer->capacity * DBMS_OUTPUT_GROWTH_FACTOR); + if (growth < DBMS_OUTPUT_DEFAULT_BUFFER_SIZE) + growth = DBMS_OUTPUT_DEFAULT_BUFFER_SIZE; - /* Grow by 50% */ - new_capacity = output_buffer->lines_allocated + (output_buffer->lines_allocated / 2); - if (new_capacity < output_buffer->lines_allocated + 100) - new_capacity = output_buffer->lines_allocated + 100; + /* For fixed-size buffers, cap growth at buffer_size */ + if (output_buffer->buffer_size != DBMS_OUTPUT_UNLIMITED) + { + if (growth > output_buffer->buffer_size) + growth = (int) output_buffer->buffer_size; + } + + /* Ensure we grow enough to fit needed_space */ + while (output_buffer->capacity + growth < internal_used + needed_space) + { + if (output_buffer->buffer_size != DBMS_OUTPUT_UNLIMITED) + growth += (int) output_buffer->buffer_size; + else + growth += DBMS_OUTPUT_DEFAULT_BUFFER_SIZE; + } + + new_capacity = output_buffer->capacity + growth; + /* Allocate new buffer in buffer memory context */ oldcontext = MemoryContextSwitchTo(output_buffer->buffer_mcxt); - new_lines = (char **) repalloc(output_buffer->lines, sizeof(char *) * new_capacity); - output_buffer->lines = new_lines; - output_buffer->lines_allocated = new_capacity; + new_buffer = (char *) palloc(new_capacity); MemoryContextSwitchTo(oldcontext); + + /* + * Pack (linearize) the ring buffer data into new buffer. + * Ring buffer may have wrapped: [....DATA2....][head] [tail][DATA1....] + * After packing: [DATA1....DATA2....] + */ + if (internal_used > 0) + { + int tail_wrap = output_buffer->tail % output_buffer->capacity; + int head_wrap = output_buffer->head % output_buffer->capacity; + + if (tail_wrap < head_wrap) + { + /* Data is contiguous: tail to head */ + memcpy(new_buffer, output_buffer->buffer + tail_wrap, internal_used); + } + else + { + /* Data wraps around: tail to end, then start to head */ + int first_chunk = output_buffer->capacity - tail_wrap; + + memcpy(new_buffer, output_buffer->buffer + tail_wrap, first_chunk); + memcpy(new_buffer + first_chunk, output_buffer->buffer, head_wrap); + } + } + + /* Free old buffer and update pointers */ + pfree(output_buffer->buffer); + output_buffer->buffer = new_buffer; + output_buffer->capacity = new_capacity; + output_buffer->tail = 0; + output_buffer->head = internal_used; +} + +/* + * ring_write + * + * Write data to the ring buffer at the given position, handling wrap-around. + */ +static void +ring_write(int pos, const char *data, int len) +{ + int wrap_pos = pos % output_buffer->capacity; + int first_chunk = output_buffer->capacity - wrap_pos; + + if (first_chunk >= len) + { + /* No wrap needed */ + memcpy(output_buffer->buffer + wrap_pos, data, len); + } + else + { + /* Data wraps around */ + memcpy(output_buffer->buffer + wrap_pos, data, first_chunk); + memcpy(output_buffer->buffer, data + first_chunk, len - first_chunk); + } +} + +/* + * ring_read + * + * Read data from the ring buffer at the given position, handling wrap-around. + */ +static void +ring_read(int pos, char *data, int len) +{ + int wrap_pos = pos % output_buffer->capacity; + int first_chunk = output_buffer->capacity - wrap_pos; + + if (first_chunk >= len) + { + /* No wrap needed */ + memcpy(data, output_buffer->buffer + wrap_pos, len); + } + else + { + /* Data wraps around */ + memcpy(data, output_buffer->buffer + wrap_pos, first_chunk); + memcpy(data + first_chunk, output_buffer->buffer, len - first_chunk); + } +} + +/* + * ring_read_uint16 + * + * Read a 2-byte unsigned integer from the ring buffer, handling wrap-around. + */ +static uint16 +ring_read_uint16(int pos) +{ + unsigned char bytes[2]; + + ring_read(pos, (char *) bytes, 2); + return (uint16) bytes[0] | ((uint16) bytes[1] << 8); +} + +/* + * ring_write_uint16 + * + * Write a 2-byte unsigned integer to the ring buffer. + */ +static void +ring_write_uint16(int pos, uint16 value) +{ + unsigned char bytes[2]; + + bytes[0] = value & 0xFF; + bytes[1] = (value >> 8) & 0xFF; + ring_write(pos, (char *) bytes, 2); } /* * add_line_to_buffer * - * Add a completed line to the buffer. - * Checks for buffer overflow based on byte usage (Oracle behavior). - * NULL lines are stored as NULL pointers (Oracle behavior). + * Add a completed line to the ring buffer. + * + * Overflow check (Oracle behavior): + * 1. Check user-perceived limit (content bytes only, not counting length prefixes) + * 2. If internal storage is full but user limit not reached, expand buffer + * + * NULL lines use a special marker (0xFFFF) as length. */ static void -add_line_to_buffer(const char *line) +add_line_to_buffer(const char *line, int line_len) { - MemoryContext oldcontext; - int line_bytes; - char *line_copy; + int entry_size; + int internal_used; + int internal_needed; - /* Calculate bytes for this line (Oracle counts actual bytes) */ - /* NULL lines count as 0 bytes */ - line_bytes = (line != NULL) ? strlen(line) : 0; + /* + * Check user-perceived buffer limit BEFORE adding (Oracle behavior). + * Only content bytes count toward limit, not length prefixes. + * Skip check for unlimited buffer (buffer_size == -1). + */ + if (output_buffer->buffer_size != DBMS_OUTPUT_UNLIMITED) + { + /* Use subtraction to avoid potential integer overflow in addition */ + if (line_len > output_buffer->buffer_size - output_buffer->buffer_used) + ereport(ERROR, + (errcode(ERRCODE_PROGRAM_LIMIT_EXCEEDED), + errmsg("ORU-10027: buffer overflow, limit of %lld bytes", + (long long) output_buffer->buffer_size))); + } - /* Check buffer overflow BEFORE adding (Oracle behavior) */ - /* Use subtraction to avoid potential integer overflow in addition */ - if (line_bytes > output_buffer->buffer_size - output_buffer->buffer_used) - ereport(ERROR, - (errcode(ERRCODE_PROGRAM_LIMIT_EXCEEDED), - errmsg("ORU-10027: buffer overflow, limit of %d bytes", - output_buffer->buffer_size))); + /* Calculate total entry size: 2-byte length prefix + data */ + entry_size = DBMS_OUTPUT_LENGTH_PREFIX_SIZE + (line != NULL ? line_len : 0); - /* Ensure we have space in lines array */ - ensure_lines_capacity(); + /* + * Check if internal buffer needs expansion. + * Internal storage = content bytes + (line_count * 2 bytes for prefixes) + */ + internal_used = output_buffer->buffer_used + + (output_buffer->line_count * DBMS_OUTPUT_LENGTH_PREFIX_SIZE); + internal_needed = internal_used + entry_size; - /* Store line in buffer memory context */ - oldcontext = MemoryContextSwitchTo(output_buffer->buffer_mcxt); - /* Store NULL as NULL pointer, not as empty string */ - line_copy = (line != NULL) ? pstrdup(line) : NULL; - output_buffer->lines[output_buffer->line_count++] = line_copy; - output_buffer->buffer_used += line_bytes; - MemoryContextSwitchTo(oldcontext); + if (internal_needed > output_buffer->capacity) + { + /* Expand buffer to accommodate the new entry */ + expand_buffer(entry_size); + } + + /* Write length prefix (or NULL marker) */ + if (line == NULL) + { + ring_write_uint16(output_buffer->head, DBMS_OUTPUT_NULL_MARKER); + } + else + { + ring_write_uint16(output_buffer->head, (uint16) line_len); + /* Write line data */ + if (line_len > 0) + ring_write(output_buffer->head + DBMS_OUTPUT_LENGTH_PREFIX_SIZE, line, line_len); + } + + output_buffer->head += entry_size; + output_buffer->buffer_used += line_len; + output_buffer->line_count++; } /* @@ -227,32 +426,27 @@ add_line_to_buffer(const char *line) * * Enable output buffering with optional size limit. * - * IvorySQL-enforced range: 2000 to 1000000 bytes. - * - NULL parameter uses maximum (1000000 bytes) for safety. - * - Default (from SQL wrapper): 20000 bytes. + * - NULL parameter: unlimited buffer (grows dynamically, Oracle behavior) + * - Default (from SQL wrapper): DEFAULT_BUFFER_SIZE bytes + * - Minimum: MIN_BUFFER_SIZE bytes (values below are clamped, Oracle behavior) * - * Note: Oracle allows unlimited buffer with NULL and silently clamps - * below-min values to 2000. IvorySQL enforces stricter limits as a - * protective measure for the initial implementation. + * Oracle behavior: silently clamps below-min values to MIN_BUFFER_SIZE. */ Datum ora_dbms_output_enable(PG_FUNCTION_ARGS) { - int32 buffer_size; + int64 buffer_size; - /* Handle NULL argument - use maximum allowed size */ + /* Handle NULL argument - unlimited buffer (Oracle behavior) */ if (PG_ARGISNULL(0)) - buffer_size = DBMS_OUTPUT_MAX_BUFFER_SIZE; + buffer_size = DBMS_OUTPUT_UNLIMITED; else { buffer_size = PG_GETARG_INT32(0); - /* IvorySQL-enforced range (stricter than Oracle) */ - if (buffer_size < DBMS_OUTPUT_MIN_BUFFER_SIZE || buffer_size > DBMS_OUTPUT_MAX_BUFFER_SIZE) - ereport(ERROR, - (errcode(ERRCODE_INVALID_PARAMETER_VALUE), - errmsg("buffer size must be between %d and %d", - DBMS_OUTPUT_MIN_BUFFER_SIZE, DBMS_OUTPUT_MAX_BUFFER_SIZE))); + /* Oracle behavior: silently clamp below-min values to 2000 */ + if (buffer_size < DBMS_OUTPUT_MIN_BUFFER_SIZE) + buffer_size = DBMS_OUTPUT_MIN_BUFFER_SIZE; } /* Initialize buffer (clears existing if present) */ @@ -321,7 +515,8 @@ ora_dbms_output_put_line(PG_FUNCTION_ARGS) /* Append non-NULL text to current line */ if (!is_null) appendStringInfoString(output_buffer->current_line, line_str); - add_line_to_buffer(output_buffer->current_line->data); + add_line_to_buffer(output_buffer->current_line->data, + output_buffer->current_line->len); resetStringInfo(output_buffer->current_line); } else @@ -334,7 +529,7 @@ ora_dbms_output_put_line(PG_FUNCTION_ARGS) DBMS_OUTPUT_MAX_LINE_LENGTH))); /* Just add the line (may be NULL) */ - add_line_to_buffer(line_str); + add_line_to_buffer(line_str, line_len); } PG_RETURN_VOID(); @@ -398,13 +593,14 @@ ora_dbms_output_new_line(PG_FUNCTION_ARGS) /* Flush current_line to buffer as a completed line */ if (output_buffer->current_line->len > 0) { - add_line_to_buffer(output_buffer->current_line->data); + add_line_to_buffer(output_buffer->current_line->data, + output_buffer->current_line->len); resetStringInfo(output_buffer->current_line); } else { /* Empty NEW_LINE creates empty string line (Oracle behavior) */ - add_line_to_buffer(""); + add_line_to_buffer("", 0); } PG_RETURN_VOID(); @@ -413,7 +609,7 @@ ora_dbms_output_new_line(PG_FUNCTION_ARGS) /* * ora_dbms_output_get_line * - * Retrieve one line from buffer. + * Retrieve one line from buffer and recycle its space (Oracle behavior). * Returns: (line TEXT, status INTEGER) * - status = 0: success, line contains data * - status = 1: no more lines, line is NULL (Oracle behavior) @@ -434,8 +630,7 @@ ora_dbms_output_get_line(PG_FUNCTION_ARGS) tupdesc = BlessTupleDesc(tupdesc); - if (output_buffer == NULL || - output_buffer->read_position >= output_buffer->line_count) + if (output_buffer == NULL || output_buffer->line_count == 0) { /* No more lines available - return NULL, not empty string (Oracle behavior) */ nulls[0] = true; /* line = NULL */ @@ -444,20 +639,36 @@ ora_dbms_output_get_line(PG_FUNCTION_ARGS) } else { - /* Return next line */ - char *line = output_buffer->lines[output_buffer->read_position++]; + /* Read length prefix from ring buffer */ + uint16 line_len = ring_read_uint16(output_buffer->tail); + int entry_size; - /* Handle NULL lines (Oracle behavior: PUT_LINE(NULL) stores actual NULL) */ - if (line == NULL) + if (line_len == DBMS_OUTPUT_NULL_MARKER) { + /* NULL line */ nulls[0] = true; values[0] = (Datum) 0; + entry_size = DBMS_OUTPUT_LENGTH_PREFIX_SIZE; + /* NULL lines don't count toward buffer_used */ } else { - values[0] = CStringGetTextDatum(line); + /* Read line data */ + char *line_data = palloc(line_len + 1); + + ring_read(output_buffer->tail + DBMS_OUTPUT_LENGTH_PREFIX_SIZE, + line_data, line_len); + line_data[line_len] = '\0'; + values[0] = CStringGetTextDatum(line_data); + pfree(line_data); + entry_size = DBMS_OUTPUT_LENGTH_PREFIX_SIZE + line_len; + output_buffer->buffer_used -= line_len; } values[1] = Int32GetDatum(0); /* status = 0 (success) */ + + /* Advance tail to recycle buffer space */ + output_buffer->tail += entry_size; + output_buffer->line_count--; } tuple = heap_form_tuple(tupdesc, values, nulls); @@ -467,7 +678,7 @@ ora_dbms_output_get_line(PG_FUNCTION_ARGS) /* * ora_dbms_output_get_lines * - * Retrieve multiple lines from buffer. + * Retrieve multiple lines from buffer and recycle their space (Oracle behavior). * Input: numlines (max lines to retrieve) * Returns: (lines TEXT[], actual_count INTEGER) * - actual_count is set to number of lines actually retrieved @@ -479,7 +690,6 @@ ora_dbms_output_get_lines(PG_FUNCTION_ARGS) int32 actual_lines = 0; ArrayType *lines_array; Datum *line_datums; - int available_lines; int i; TupleDesc tupdesc; Datum values[2]; @@ -509,8 +719,8 @@ ora_dbms_output_get_lines(PG_FUNCTION_ARGS) else { /* Calculate how many lines we can actually return */ - available_lines = output_buffer->line_count - output_buffer->read_position; - actual_lines = (requested_lines < available_lines) ? requested_lines : available_lines; + actual_lines = (requested_lines < output_buffer->line_count) ? + requested_lines : output_buffer->line_count; if (actual_lines > 0) { @@ -522,19 +732,35 @@ ora_dbms_output_get_lines(PG_FUNCTION_ARGS) for (i = 0; i < actual_lines; i++) { - char *line = output_buffer->lines[output_buffer->read_position++]; + /* Read length prefix from ring buffer */ + uint16 line_len = ring_read_uint16(output_buffer->tail); + int entry_size; - /* Handle NULL lines (Oracle behavior) */ - if (line == NULL) + if (line_len == DBMS_OUTPUT_NULL_MARKER) { + /* NULL line */ line_nulls[i] = true; line_datums[i] = (Datum) 0; + entry_size = DBMS_OUTPUT_LENGTH_PREFIX_SIZE; } else { + /* Read line data */ + char *line_data = palloc(line_len + 1); + + ring_read(output_buffer->tail + DBMS_OUTPUT_LENGTH_PREFIX_SIZE, + line_data, line_len); + line_data[line_len] = '\0'; line_nulls[i] = false; - line_datums[i] = CStringGetTextDatum(line); + line_datums[i] = CStringGetTextDatum(line_data); + pfree(line_data); + entry_size = DBMS_OUTPUT_LENGTH_PREFIX_SIZE + line_len; + output_buffer->buffer_used -= line_len; } + + /* Advance tail to recycle buffer space */ + output_buffer->tail += entry_size; + output_buffer->line_count--; } lines_array = construct_md_array(line_datums, line_nulls, 1, &actual_lines, &lbound,