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..69b4f1d5a61 --- /dev/null +++ b/contrib/ivorysql_ora/expected/ora_dbms_output.out @@ -0,0 +1,731 @@ +-- +-- 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 (silently clamped to 2000, Oracle behavior) +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; +/ +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 1000000 (now allowed, no max limit) +CALL dbms_output.enable(1000001); +-- Test 4.5: NULL buffer size uses unlimited (starts at 20000, grows dynamically) +DECLARE + line TEXT; + status INTEGER; +BEGIN + dbms_output.enable(NULL); + 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 max] +-- ============================================================================= +-- 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 +-- 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 +-- ============================================================================= +-- 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] +-- ============================================================================= +-- 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 +-- ============================================================================= +-- 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 +-- ============================================================================= +-- 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; +$$; +NOTICE: Test 11.1 - VARCHAR2 GET_LINE: [VARCHAR2 test line] +-- 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; +$$; +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; +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..42d646eae26 --- /dev/null +++ b/contrib/ivorysql_ora/sql/ora_dbms_output.sql @@ -0,0 +1,719 @@ +-- +-- 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 (silently clamped to 2000, Oracle behavior) +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 1000000 (now allowed, no max limit) +CALL dbms_output.enable(1000001); + +-- Test 4.5: NULL buffer size uses unlimited (starts at 20000, grows dynamically) +DECLARE + line TEXT; + status INTEGER; +BEGIN + dbms_output.enable(NULL); + dbms_output.put_line('NULL buffer uses max'); + 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; +/ + +-- 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 +-- ============================================================================= + +-- 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; +/ + +-- ============================================================================= +-- 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; +/ + +-- ============================================================================= +-- 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; +$$; + +-- ============================================================================= +-- 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; +$$; + +-- ============================================================================= +-- 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 +-- ============================================================================= +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..d19432af4fb --- /dev/null +++ b/contrib/ivorysql_ora/src/builtin_packages/dbms_output/dbms_output--1.0.sql @@ -0,0 +1,145 @@ +/*------------------------------------------------------------------------- + * 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_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 + + 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_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 + SELECT * INTO result FROM sys.ora_dbms_output_get_lines(numlines); + lines := result.lines; + 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; 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..8b1519bde0c --- /dev/null +++ b/contrib/ivorysql_ora/src/builtin_packages/dbms_output/dbms_output.c @@ -0,0 +1,783 @@ +/*------------------------------------------------------------------------- + * 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 high Oracle compatibility. + * See ora_dbms_output.sql tests for known behavioral differences. + * + * contrib/ivorysql_ora/src/builtin_packages/dbms_output/dbms_output.c + * + *------------------------------------------------------------------------- + */ + +#include "postgres.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 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 *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) */ + MemoryContext buffer_mcxt; /* Memory context for buffer allocations */ +} DbmsOutputBuffer; + +/* Global buffer - one per backend process */ +static DbmsOutputBuffer *output_buffer = NULL; + +/* Oracle line length limit: 32767 bytes per line (fits in 2-byte length prefix) */ +#define DBMS_OUTPUT_MAX_LINE_LENGTH 32767 + +/* Buffer size constants */ +#define DBMS_OUTPUT_MIN_BUFFER_SIZE 2000 +#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 + +/* Dynamic growth factor */ +#define DBMS_OUTPUT_GROWTH_FACTOR 0.20 + +/* Internal function declarations */ +static void init_output_buffer(int64 buffer_size); +static void cleanup_output_buffer(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); +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. + * + * 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(int64 buffer_size) +{ + MemoryContext oldcontext; + int initial_capacity; + + /* IvorySQL behavior: ENABLE clears existing buffer (differs from Oracle) */ + 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); + + /* Store buffer size (user limit, or -1 for unlimited) */ + output_buffer->buffer_size = buffer_size; + + /* + * 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. + */ + if (buffer_size == DBMS_OUTPUT_UNLIMITED) + initial_capacity = DBMS_OUTPUT_DEFAULT_BUFFER_SIZE; + else + initial_capacity = (int) buffer_size; + + output_buffer->capacity = initial_capacity; + output_buffer->buffer = (char *) palloc(output_buffer->capacity); + output_buffer->current_line = makeStringInfo(); + output_buffer->enabled = true; + output_buffer->head = 0; + output_buffer->tail = 0; + output_buffer->buffer_used = 0; + output_buffer->line_count = 0; + + MemoryContextSwitchTo(oldcontext); +} + +/* + * cleanup_output_buffer + * + * Free all buffer resources and reset to NULL. + * Called when ENABLE is called to re-initialize the buffer. + */ +static void +cleanup_output_buffer(void) +{ + if (output_buffer == NULL) + return; + + /* Delete memory context (automatically frees buffer and current_line) */ + MemoryContextDelete(output_buffer->buffer_mcxt); + + /* Free buffer structure itself */ + pfree(output_buffer); + output_buffer = NULL; +} + +/* + * expand_buffer + * + * 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 +expand_buffer(int needed_space) +{ + MemoryContext oldcontext; + int growth; + int new_capacity; + 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); + + /* 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; + + /* 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_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 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, int line_len) +{ + int entry_size; + int internal_used; + int internal_needed; + + /* + * 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))); + } + + /* Calculate total entry size: 2-byte length prefix + data */ + entry_size = DBMS_OUTPUT_LENGTH_PREFIX_SIZE + (line != NULL ? line_len : 0); + + /* + * 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; + + 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++; +} + +/* + * ora_dbms_output_enable + * + * Enable output buffering with optional size limit. + * + * - 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) + * + * Oracle behavior: silently clamps below-min values to MIN_BUFFER_SIZE. + */ +Datum +ora_dbms_output_enable(PG_FUNCTION_ARGS) +{ + int64 buffer_size; + + /* Handle NULL argument - unlimited buffer (Oracle behavior) */ + if (PG_ARGISNULL(0)) + buffer_size = DBMS_OUTPUT_UNLIMITED; + else + { + buffer_size = PG_GETARG_INT32(0); + + /* 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) */ + 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 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) + PG_RETURN_VOID(); + + /* Handle NULL argument - Oracle stores actual NULL */ + if (PG_ARGISNULL(0)) + { + line_str = NULL; + is_null = true; + } + else + { + 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); + add_line_to_buffer(output_buffer->current_line->data, + output_buffer->current_line->len); + resetStringInfo(output_buffer->current_line); + } + else + { + /* 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, line_len); + } + + 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). + * 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) + PG_RETURN_VOID(); + + /* Handle NULL argument - treat as empty string (Oracle behavior) */ + if (PG_ARGISNULL(0)) + 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); + + 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, + output_buffer->current_line->len); + resetStringInfo(output_buffer->current_line); + } + else + { + /* Empty NEW_LINE creates empty string line (Oracle behavior) */ + add_line_to_buffer("", 0); + } + + PG_RETURN_VOID(); +} + +/* + * ora_dbms_output_get_line + * + * 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) + */ +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->line_count == 0) + { + /* 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 + { + /* Read length prefix from ring buffer */ + uint16 line_len = ring_read_uint16(output_buffer->tail); + int entry_size; + + 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 + { + /* 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); + PG_RETURN_DATUM(HeapTupleGetDatum(tuple)); +} + +/* + * ora_dbms_output_get_lines + * + * 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 + */ +Datum +ora_dbms_output_get_lines(PG_FUNCTION_ARGS) +{ + int32 requested_lines; + int32 actual_lines = 0; + ArrayType *lines_array; + Datum *line_datums; + int i; + TupleDesc tupdesc; + Datum values[2]; + bool nulls[2] = {false, false}; + HeapTuple tuple; + + 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, + (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 */ + actual_lines = (requested_lines < output_buffer->line_count) ? + requested_lines : output_buffer->line_count; + + 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++) + { + /* Read length prefix from ring buffer */ + uint16 line_len = ring_read_uint16(output_buffer->tail); + int entry_size; + + 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_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, + TEXTOID, -1, false, TYPALIGN_INT); + pfree(line_datums); + pfree(line_nulls); + } + 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/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 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; 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