Sunday, November 22, 2020

OracleJVM integer Array Size Limit and Out of Memory Error

Java provides 4 Primitive Data Types (byte, short, int, long) to represent integer numbers. In this Blog, we will look their array size limits in relation to two OracleJVM errors: ORA-29532 OutOfMemoryError and ORA-27102: out of memory.

Note: Tested in Oracle 19c on Linux.


1. ORA-29532 java.lang.OutOfMemoryError


Nenad's Blog: Troubleshooting java.lang.OutOfMemoryError in the Oracle Database made a deep investigation of ORA-29532 OutOfMemoryError, and found the internal hard-coded maximum total size in bytes: 536870895 It shows that for int[] array size of 134217723 (0x7FFFFFB, about 128MB Java int), there is no memory error. However, adding just one additional element will cause OutOfMemoryError (By default, Java int data type is a 32-bit signed).

We will explore further ORA-29532 OutOfMemoryError and list the 4 hard-coded integer array size limits on 4 respective Java integer Primitive Data Types.

At first, we copy Nenad's test code and add one method for byte[].

drop java source "Demo";

create or replace and compile java source named "Demo" as
public class Demo {
    public static void defineIntArray(int p_size) throws Exception {
      //Test of ORA-29532: Java call terminated by uncaught Java exception: java.lang.OutOfMemoryError
      //copy from https://nenadnoveljic.com/blog/troubleshooting-java-lang-outofmemoryerror-in-the-oracle-database/
      int[] v = new int[p_size];
      System.out.println("OracleJvm int[].length: " + v.length);
    }

    public static void defineByteArray(int p_size) throws Exception {
      byte[] v = new byte[p_size];
      System.out.println("OracleJvm byte[].length: " + v.length);
    }
}     
/

create Or replace procedure p_define_int_array (p_size number)
as language java name 'Demo.defineIntArray(int)' ;
/

create Or replace procedure p_define_byte_array (p_size number)
as language java name 'Demo.defineByteArray(int)' ;
/
Run the same test to demonstrate OracleJVM java.lang.OutOfMemoryError exactly at 134217724:

SQL > exec p_define_int_array(134217723);

  OracleJvm int[].length: 134217723


SQL > exec p_define_int_array(134217724);

  Exception in thread "Root Thread" java.lang.OutOfMemoryError
          at Demo.defineIntArray(Demo:29)
  BEGIN p_define_int_array(134217724); END;
  
  *
  ERROR at line 1:
  ORA-29532: Java call terminated by uncaught Java exception: java.lang.OutOfMemoryError
  ORA-06512: at "K.P_DEFINE_INT_ARRAY", line 1
  ORA-06512: at line 1
Following Blog's guidelines: switch off JIT compiler to obtain descriptive call stack, we disable OracleJVM Just-in-Time (JIT):

  alter system set java_jit_enabled=false;
and (gdb) disassemble joe_make_primitive_array:

# --------------------------- long, max: 0x3fffffd ---------------------------
  <+107>:   cmp    %r13d,%eax
  <+110>:   jl     0x583c639 <joe_make_primitive_array+121>
  <+112>:   cmp    $0x3fffffd,%rdx
  <+119>:   jbe    0x583c64b <joe_make_primitive_array+139>
  <+121>:   lea    0x11b9ed78(%rip),%rax        # 0x173db3b8 <ioa_ko_j_l_out_of_memory_error>
  <+128>:   mov    %r15,%rdi
  <+131>:   mov    (%rax),%rsi
  <+134>:   callq  0x58459f0 <joe_blow>
  <+139>:   mov    0x1f1(%r15),%r9
# --------------------------- int, max: 0x7fffffb ---------------------------    
  <+299>:   cmp    %r13d,%eax
  <+302>:   jl     0x583c6f9 <joe_make_primitive_array+313>
  <+304>:   cmp    $0x7fffffb,%rdx
  <+311>:   jbe    0x583c70b <joe_make_primitive_array+331>
  <+313>:   lea    0x11b9ecb8(%rip),%rax        # 0x173db3b8 <ioa_ko_j_l_out_of_memory_error>
  <+320>:   mov    %r15,%rdi
  <+323>:   mov    (%rax),%rsi
  <+326>:   callq  0x58459f0 <joe_blow>
  <+331>:   mov    0x1f1(%r15),%r9
# --------------------------- short, max: 0xffffff7 ---------------------------  
  <+491>:   cmp    %r13d,%eax
  <+494>:   jl     0x583c7b9 <joe_make_primitive_array+505>
  <+496>:   cmp    $0xffffff7,%rdx
  <+503>:   jbe    0x583c7cb <joe_make_primitive_array+523>
  <+505>:   lea    0x11b9ebf8(%rip),%rax        # 0x173db3b8 <ioa_ko_j_l_out_of_memory_error>
  <+512>:   mov    %r15,%rdi
  <+515>:   mov    (%rax),%rsi
  <+518>:   callq  0x58459f0 <joe_blow>
  <+523>:   mov    0x1f1(%r15),%r9
# --------------------------- byte, max: 0x1fffffef ---------------------------  
  <+676>:   cmp    %r13d,%eax
  <+679>:   jl     0x583c872 <joe_make_primitive_array+690>
  <+681>:   cmp    $0x1fffffef,%rdx
  <+688>:   jbe    0x583c884 <joe_make_primitive_array+708>
  <+690>:   lea    0x11b9eb3f(%rip),%rax        # 0x173db3b8 <ioa_ko_j_l_out_of_memory_error>
  <+697>:   mov    %r15,%rdi
  <+700>:   mov    (%rax),%rsi
  <+703>:   callq  0x58459f0 <joe_blow>
  <+708>:   mov    0x1f1(%r15),%r9
Copy 4 hex constants from above 4 cmp instructions and map to 4 integer Primitive Data Types:

  long  (8 bytes, 0x3fffffd =67108861 )
  int   (4 bytes, 0x7fffffb =134217723) 
  short (2 bytes, 0xffffff7 =268435447)
  byte  (1 byte,  0x1fffffef=536870895)
Above assemble code shows that each integer type is handled individually with different hard-coded limit, but total memory is capped below 512MB.

For example, for data type int, the input parameter array size (register rdx, passed as arg2 to joe_make_primitive_array) is checked against fixed constant 0x7fffffb (134217723, a hard-coded value). According to cmp status flags, create array if rdx below or equal to 0x7fffffb (%rdx - $0x7fffffb, CF=1 or ZF=1); otherwise continue to "ioa_ko_j_l_out_of_memory_error".

  <+304>:   cmp    $0x7fffffb,%rdx
  <+311>:   jbe    0x583c70b <joe_make_primitive_array+331>
  <+313>:   lea    0x11b9ecb8(%rip),%rax        # 0x173db3b8 <ioa_ko_j_l_out_of_memory_error>
We can also see that there is another memory pre-check before each integer type check. If the memory limit in eax is less than input parameter array size in r13d (%r13d > %eax), then jump to "ioa_ko_j_l_out_of_memory_error" (Note: maximum rax seems 0x20000000=536870912=512MB, probably default Heap Size since 11.2, see later appended MOS Doc ID 2526642.1).

  <+299>:   cmp    %r13d,%eax
  <+302>:   jl     0x583c6f9 <joe_make_primitive_array+313>
Now we can verify the limit of byte integer type exactly at 536870896:

SQL > exec p_define_byte_array(536870895);
  OracleJvm byte[].length: 536870895

SQL > exec p_define_byte_array(536870896);
  Exception in thread "Root Thread" java.lang.OutOfMemoryError
          at Demo.defineByteArray(Demo:31)
  BEGIN p_define_byte_array(536870896); END;
  
  *
  ERROR at line 1:
  ORA-29532: Java call terminated by uncaught Java exception: java.lang.OutOfMemoryError
  ORA-06512: at "K.P_DEFINE_BYTE_ARRAY", line 1
  ORA-06512: at line 1
Oracle MOS: Java Stored Procedure suddenly fails with java.lang.OutOfMemoryError (Doc ID 2526642.1) wrote:
Symptoms
  A database routine implemented as a Java Stored procedure receives the following error.
  ORA-29532: Java call terminated by uncaught Java exception: java.lang.OutOfMemoryError
  This routine may have worked previously or it may be brand new development.
  
Cause
  The DB JVM does not have enough session Heap Memory. This error occurs when a Java Stored Procedure 
  (ie. a PL/SQL routine where the body is implemented in Java ) does not have enough Heap space 
  to work with the amount of data being processed. If this were a client-side java program 
  using the Java Runtime Engine (JRE) (ie. java.exe), one would use the -Xmx parameter to configure the Heap Memory.  
  However, as the Oracle DB JVM is running in the process space of the Oracle executable, 
  there is no way to use the -Xmx switch.  The JVM has a default Heap Size (512MB since 11.2) 
  but it is also configurable using a method in the "Java Runtime" class called "oracle.aurora.vm.OracleRuntime".  
  Along with other "java runtime" related switches, this class contains a couple methods 
  that can be used to manage the Java Heap Size.  Therefore, if you encounter the OutOfMemoryError 
  and need to increase from either the default or a previous configured amount, 
  you can use oracle.aurora.vm.OracleRuntime.setMaxMemorySize to allocate more memory for the Java Heap.
The MOS Note described that "Oracle DB JVM is running in the process space of the Oracle executable" and had one hint about 512MB: "The JVM has a default Heap Size (512MB since 11.2)". As one Solution, MOS Note provided following workaround.

create or replace package Java_Runtime is
  function getHeapSize return number;
  function setHeapSize(num number) return number;
end Java_Runtime;
/

create or replace package body Java_Runtime is
  function getHeapSize return number is
    language java name 'oracle.aurora.vm.OracleRuntime.getMaxMemorySize() returns long';
  function setHeapSize(num number) return number is
    language java name 'oracle.aurora.vm.OracleRuntime.setMaxMemorySize(long) returns long';
end Java_Runtime;
/

declare
   heap_return_val NUMBER;
begin
   -- MOS code has a typo, setMaxMemorySize should be setHeapSize
   -- heap_return_val := Java_Runtime.setMaxMemorySize(1024*1024*1024);
   
   dbms_output.put_line('HeapSize Before Set: '||Java_Runtime.getHeapSize);
   heap_return_val := Java_Runtime.setHeapSize(1024*1024*1024);
   dbms_output.put_line('HeapSize After Set: '||Java_Runtime.getHeapSize);
   
   -- MOS code
   -- MY_JAVA_STORED_PROC(...);
   
   p_define_int_array(134217724);
end;
/

HeapSize Before Set: 536870912
HeapSize After Set: 1073741824
declare
*
ERROR at line 1:
ORA-29532: Java call terminated by uncaught Java exception: java.lang.OutOfMemoryError
ORA-06512: at "K.P_DEFINE_INT_ARRAY", line 1
ORA-06512: at line 14
We made the test in Oracle 12c and 19c and still got ORA-29532 OutOfMemoryError (for the reason of the hard-coded limit discovered by Nenad's Blog).


2. ORA-27102: out of memory


Blog: Oracle JVM Java OutOfMemoryError and lazy GC was trying to bring up some discussions on OracleJVM OutOfMemoryError in connection with lazy GC.

The first test in the Blog is to allocate 511MB byte array:

SQL > exec createBuffer512(1024*1024*511);
  PL/SQL procedure successfully completed
succeeded without Error.

but the second test with 512MB:

SQL > exec createBuffer512(1024*1024*512);
  
  ERROR at line 1:
  ORA-29532: Java call terminated by uncaught Java exception: java.lang.OutOfMemoryError
  ORA-06512: at "K.CREATEBUFFER512", line 1
  ORA-06512: at line 1
hit the general Java error: ORA-29532 java.lang.OutOfMemoryError, which probably indicates that the JVM is limited by 512MB for one single object instance, in this test, it is "new byte[bufferSize]".

We can see that above hard-coded byte[] limit of 536870895 (0x1fffffef) is between 511MB and 512MB.

   1024*1024*512=536870912 > 536870895 > 535822336=1024*1024*511.
Run a third test case, which gradually allocates memory from 1MB to 511MB, each time increases 1MB per call.

SQL > exec createBuffer512_loop(511, 1, 1);

  Step -- 1 --, Buffer Size (MB) = 1
  Step -- 2 --, Buffer Size (MB) = 2
  Step -- 3 --, Buffer Size (MB) = 3
  ...
  Step -- 202 --, Buffer Size (MB) = 202
  Step -- 203 --, Buffer Size (MB) = 203

  ERROR at line 1:
  ORA-27102: out of memory
  Linux-x86_64 Error: 12: Cannot allocate memory
  Additional information: 12394
  Additional information: 218103808
  ORA-06512: at "K.CREATEBUFFER512", line 1
  ORA-06512: at "K.CREATEBUFFER512_LOOP", line 8
  ORA-06512: at line 1
It reveals that out of memory can be generated even under above discussed hard-coded limit (203MB < 512MB), but the error code is ORA-27102 (in 12c, we saw ORA-29532). The test shows that above 4 integer array size limits for respective 4 integer Primitive Data Types are sufficient, but not necessary conditions for out of memory.

Make a 27102 trace:

  alter session set max_dump_file_size = unlimited;
  alter session set tracefile_identifier='ORA27102_trc3'; 
  alter session set events '27102 trace name errorstack level 3'; 
  exec createBuffer512_loop(511, 1, 1);
Here the extracted error message, call stack, and session wait event from trace file:

----- Error Stack Dump -----
Linux-x86_64 Error: 12: Cannot allocate memory
Additional information: 12394
Additional information: 218103808

BEGIN createBuffer512_loop(511, 1, 1); END;
----- PL/SQL Call Stack -----
  object      line  object
  handle    number  name
0x91948d30         1  procedure K.CREATEBUFFER512
0x8ef98db0         8  procedure K.CREATEBUFFER512_LOOP
0x8ca47e38         1  anonymous block

----- Call Stack Trace -----
FRAME [12] (dbgePostErrorKGE()+1066 -> dbkdChkEventRdbmsErr())
FRAME [13] (dbkePostKGE_kgsf()+71 -> dbgePostErrorKGE())
FRAME [14] (kgerscl()+546 -> dbkePostKGE_kgsf())
FRAME [15] (kgecss()+69 -> kgerscl())
FRAME [16] (ksmrf_init_alloc()+821 -> kgecss())
  CALL TYPE: call   ERROR SIGNALED: yes   COMPONENT: KSM
FRAME [17] (ksmapg()+521 -> ksmrf_init_alloc())
FRAME [18] (kgh_invoke_alloc_cb()+162 -> ksmapg())
  RDI 000000000D000000 RSI 00007F4D777511E0 RDX 000000000CE2D8B0 
FRAME [19] (kghgex()+2713 -> kgh_invoke_alloc_cb())
FRAME [20] (kghfnd()+376 -> kghgex())
FRAME [21] (kghalo()+4908 -> kghfnd())
FRAME [22] (kghgex()+593 -> kghalo())
FRAME [23] (kghfnd()+376 -> kghgex())
FRAME [24] (kghalo()+4908 -> kghfnd())
FRAME [25] (kghgex()+593 -> kghalo())
FRAME [26] (kghalf()+617 -> kghgex())
FRAME [27] (ioc_allocate0()+1094 -> kghalf())
FRAME [28] (iocbf_allocate0()+53 -> ioc_allocate0())
FRAME [29] (ioc_do_call()+1297 -> iocbf_allocate0())
FRAME [30] (joet_switched_env_callback()+376 -> ioc_do_call())
FRAME [31] (ioct_allocate0()+79 -> joet_switched_env_callback())
FRAME [32] (eoa_new_mman_segment()+368 -> ioct_allocate0())
FRAME [33] (eoa_new_mswmem_chunk()+66 -> eoa_new_mman_segment())
FRAME [34] (eomsw_allocate_block()+229 -> eoa_new_mswmem_chunk())
FRAME [35] (eoa_alloc_mswmem_object_no_gc()+2037 -> eomsw_allocate_block())
FRAME [36] (eoa_alloc_mswmem_object()+48 -> eoa_alloc_mswmem_object_no_gc())
FRAME [37] (eoa_new_ool_alloc()+508 -> eoa_alloc_mswmem_object())
FRAME [38] (joe_make_primitive_array()+828 -> eoa_new_ool_alloc())
FRAME [39] (joe_run_vm()+15736 -> joe_make_primitive_array())
FRAME [40] (joe_run()+608 -> joe_run_vm())
FRAME [41] (joe_invoke()+1156 -> joe_run())
FRAME [42] (joet_aux_thread_main()+1674 -> joe_invoke())
FRAME [43] (seoa_note_stack_outside()+34 -> joet_aux_thread_main())
FRAME [44] (joet_thread_main()+64 -> seoa_note_stack_outside())
FRAME [45] (sjontlo_initialize()+178 -> joet_thread_main())
FRAME [46] (joe_enter_vm()+1197 -> sjontlo_initialize())
FRAME [47] (ioei_call_java()+4716 -> joe_enter_vm())
FRAME [48] (ioesub_CALL_JAVA()+569 -> ioei_call_java())
FRAME [49] (seoa_note_stack_outside()+34 -> ioesub_CALL_JAVA())
FRAME [50] (ioe_call_java()+292 -> seoa_note_stack_outside())
FRAME [51] (jox_invoke_java_()+4133 -> ioe_call_java())
FRAME [52] (kkxmjexe()+1493 -> jox_invoke_java_())

    Session Wait History:
     0: waited for 'PGA memory operation'
        =0xd000000, =0x2, =0x0
"Error: 12" is ENOMEM defined in /usr/include/asm-generic/errno-base.h.
"Additional information: 12394" is not clear.
"Additional information: 218103808" points out P1 parameter in Event "PGA memory operation" (12.2 new introduced), which also appears in "RDI 000000000D000000" of kgh_invoke_alloc_cb call (0xd000000 = 218103808).

In the above call stack, there is a subroutine "FRAME [35] (eoa_alloc_mswmem_object_no_gc()", with suffix "no_gc".

"FRAME [38] (joe_make_primitive_array()+828 -> eoa_new_ool_alloc())" shows that "joe_make_primitive_array" already passed line <+708> of byte array size check (see above disassembled code), and is calling "eoa_new_ool_alloc".

Occasionally, session is terminated:

SQL > exec createBuffer512_loop(511, 1, 1);
  ERROR:
  ORA-03114: not connected to ORACLE
  ORA-03113: end-of-file on communication channel
  Process ID: 14461
  Session ID: 907 Serial number: 50430
and Linux dmesg shows:

  Out of memory: Kill process 14461 (oracle_14461_c0) score 781 or sacrifice child
  Killed process 14461 (oracle_14461_c0) total-vm:23745148kB, anon-rss:18595960kB, file-rss:132kB, shmem-rss:538232kB


3. Out of Memory Error Application Handling


If PL/SQL applications hit out of Memory Error even under the discussed hard-coded limit, one possible workaround is try to catch the error, invoke dbms_java.endsession to release memory, and then re-try the application as follows:

set serveroutput on size 50000;
exec dbms_java.set_output(50000);

declare
  java_oom_29532    exception;
  pragma            exception_init(java_oom_29532, -29532);
  l_es_ret          varchar2(100);
begin
  p_define_int_array(134217724);   -- only illustrative demo, real application should use size below the limit
  exception 
    when java_oom_29532 then
      dbms_output.put_line('------ int[134217724] hit ORA-29532: java.lang.OutOfMemoryError ------');
      l_es_ret  := dbms_java.endsession;
      p_define_int_array(134217723);
      dbms_output.put_line('------ int[134217723] Succeed ------');
    when others then
      raise;
end;
/

Exception in thread "Root Thread" java.lang.OutOfMemoryError
        at Demo.defineIntArray(Demo:5)
------ int[134217724] hit ORA-29532: java.lang.OutOfMemoryError ------
OracleJvm int[].length: 134217723
------ int[134217723] Succeed ------

set serveroutput on size 50000;
exec dbms_java.set_output(50000);

declare
  java_oom_27102    exception;
  pragma            exception_init(java_oom_27102, -27102);
  l_es_ret          varchar2(100);
begin
  createBuffer512_loop(511, 1, 1); 
  exception 
    when java_oom_27102 then
      dbms_output.put_line('------ createBuffer512_loop hit ORA-27102: out of memory ------');
      l_es_ret  := dbms_java.endsession;
      createBuffer512_loop(3, 1, 1);
      dbms_output.put_line('------ createBuffer512_loop(3, 1, 1) Succeed ------');
    when others then
      raise;
end;
/

Step -- 284 --, Buffer Size (MB) = 284
Step -- 285 --, Buffer Size (MB) = 285
------ createBuffer512_loop hit ORA-27102: out of memory ------
Step -- 1 --, Buffer Size (MB) = 1
Step -- 2 --, Buffer Size (MB) = 2
Step -- 3 --, Buffer Size (MB) = 3
------ createBuffer512_loop(3, 1, 1) Succeed ------   

Sunday, November 15, 2020

Oracle LOB Chunksize and Buffersize

In this Blog, we first show Oracle LOB chunksize in SQL and Plsql, then look chunksize and buffersize of LOB objects in Java from database and OracleJvm.

Note: Tested in Oracle 12c, 19c on Linux, Solaris, AIX with DB_BLOCK_SIZE=8192 and tablespace BLOCK_SIZE=8192.


1. SQL LOB Chunksize


First we create a table containing CLOB and BLOB columns with different chunk values, and insert one row:

drop table tab_lob cascade constraints;

create table tab_lob(
  id           number,
  clob_8k       clob,
  blob_8k       blob,
  clob_16k      clob,
  blob_16k      blob,
  clob_32k      clob,
  blob_32k      blob
)
lob (clob_8k) store as basicfile (
  enable       storage in row
  chunk        8192)
lob (blob_8k) store as basicfile (
  enable       storage in row
  chunk        8192)
lob (clob_16k) store as basicfile (
  enable       storage in row
  chunk        16384)
lob (blob_16k) store as basicfile (
  enable       storage in row
  chunk        16384)
lob (clob_32k) store as basicfile (
  enable       storage in row
  chunk        32768)
lob (blob_32k) store as basicfile (
  enable       storage in row
  chunk        32768);
  
insert into tab_lob values (1, empty_clob(), empty_blob(), empty_clob(), empty_blob(), empty_clob(), empty_blob());

commit;
List all chunksize with query:

select id, 
      dbms_lob.getchunksize(clob_8k)  clob_8k, 
      dbms_lob.getchunksize(blob_8k)  blob_8k, 
      dbms_lob.getchunksize(clob_16k) clob_16k, 
      dbms_lob.getchunksize(blob_16k) blob_16k,
      dbms_lob.getchunksize(clob_32k) clob_32k, 
      dbms_lob.getchunksize(blob_32k) blob_32k
from tab_lob;               


   ID   CLOB_8K   BLOB_8K   CLOB_16K   BLOB_16K   CLOB_32K   BLOB_32K
  --- --------- --------- ---------- ---------- ---------- ----------
    1      8132      8132      16264      16264      32528      32528
We can see that for chunking factor: 8192, chunksize is 8132, an overhead of 60 (8192-8132) bytes, only 8132 is used to store LOB value. All chunksize are multiple of 8132 instead of 8192 (DB_BLOCK_SIZE).

Here Oracle Docu on DBMS_LOB.GETCHUNKSIZE (19c):
DBMS_LOB.GETCHUNKSIZE Functions 
  When creating the table, you can specify the chunking factor, a multiple of tablespace blocks in bytes. 
  This corresponds to the chunk size used by the LOB data layer when accessing or modifying the LOB value. 
  Part of the chunk is used to store system-related information, and the rest stores the LOB value. 
  This function returns the amount of space used in the LOB chunk to store the LOB value.
The maximum CHUNK value is 32768 (32K), which is the largest Oracle Database block size allowed as documented in 19c LOB Storage with Applications :
LOB Storage CHUNK 
  If the tablespace block size is the same as the database block size, 
  then CHUNK is also a multiple of the database block size. 
  The default CHUNK size is equal to the size of one tablespace block, and the maximum value is 32K. 


2. Plsql and Java LOB Chunksize and BufferSize


We will look two sources of Java LOB objects, one is created in DB and passed to OracleJVM, another is directly created in OracleJVM. Besides chunksize similar to above SQL, Java LOB object has a bufferSize.

Here the test code:

drop java source "LobChunkBufferSize";

create or replace and compile java source named "LobChunkBufferSize" as
import java.sql.Connection;
import java.io.IOException;
import java.sql.SQLException;
import oracle.jdbc.OracleDriver;
import oracle.sql.CLOB;
import oracle.sql.BLOB;

public class LobChunkBufferSize {
    public static void printSizeFromDB(CLOB clob, BLOB blob) throws Exception {
        System.out.println("Java  CLOB ChunkSize: " + clob.getChunkSize() + ", BufferSize: " + clob.getBufferSize());
        System.out.println("Java  BLOB ChunkSize: " + blob.getChunkSize() + ", BufferSize: " + blob.getBufferSize());
    }
    
    public static void printSizeFromOracleJvm() throws Exception {
      Connection conn = new OracleDriver().defaultConnection();
      CLOB clob = CLOB.createTemporary(conn, false, CLOB.DURATION_SESSION);
      System.out.println("OracleJvm CLOB ChunkSize: " + clob.getChunkSize() + ", BufferSize: " + clob.getBufferSize());
      
      BLOB blob = BLOB.createTemporary(conn, false, BLOB.DURATION_SESSION);
      System.out.println("OracleJvm BLOB ChunkSize: " + blob.getChunkSize() + ", BufferSize: " + blob.getBufferSize());
    }
}     
/

create Or replace procedure printSizeFromDB (p_clob clob, p_blob blob) 
as language java name 'LobChunkBufferSize.printSizeFromDB(oracle.sql.CLOB, oracle.sql.BLOB)';
/

create Or replace procedure printSizeFromOracleJvm
as language java name 'LobChunkBufferSize.printSizeFromOracleJvm()' ;
/
First we display Plsql Chunksize, then pass LOB to OracleJVM and display their Chunksize and Buffersize:

set serveroutput on size 50000;
exec dbms_java.set_output(50000);

declare
  l_clob  clob;
  l_blob  blob;
  procedure print (l_name varchar2, l_clob clob, l_blob blob) as
    begin
      dbms_output.put_line(l_name);
      dbms_output.put_line('Plsql CLOB ChunkSize: '||dbms_lob.getchunksize(l_clob));
      dbms_output.put_line('Plsql BLOB ChunkSize: '||dbms_lob.getchunksize(l_blob)); 
      printSizeFromDB(l_clob, l_blob);        
    end;
begin
    select clob_8k, blob_8k into l_clob, l_blob from tab_lob where id = 1;
    print('------- 1. DB Lob 8k -------', l_clob, l_blob);
    
    select clob_16k, blob_16k into l_clob, l_blob from tab_lob where id = 1;
    print('------- 2. DB Lob 16k -------', l_clob, l_blob);
    
    select clob_32k, blob_32k into l_clob, l_blob from tab_lob where id = 1;
    print('------- 3. DB Lob 32k -------', l_clob, l_blob);
    
    dbms_lob.createtemporary(l_clob, TRUE);
    dbms_lob.createtemporary(l_blob, TRUE);        
    print('------- 4. Temporary Lob empty -------', l_clob, l_blob);
    
    l_clob := 'ABCabc123';
    l_blob := utl_raw.cast_to_raw(l_clob);
    print('------- 5. Temporary Lob small -------', l_clob, l_blob);
    dbms_output.put_line('----------**** CLOB length: '||dbms_lob.getlength(l_clob));
    
    l_clob := lpad('ABCabc123', 32767, 'A');
    l_blob := utl_raw.cast_to_raw(l_clob);
    print('------- 6. Temporary Lob big -------', l_clob, l_blob);
    dbms_output.put_line('----------****  CLOB length: '||dbms_lob.getlength(l_clob));
end;
/
Here the result:

  ------- 1. DB Lob 8k -------
  Plsql CLOB ChunkSize: 8132
  Plsql BLOB ChunkSize: 8132
  Java  CLOB ChunkSize: 8132, BufferSize: 32528
  Java  BLOB ChunkSize: 8132, BufferSize: 32528
  ------- 2. DB Lob 16k -------
  Plsql CLOB ChunkSize: 16264
  Plsql BLOB ChunkSize: 16264
  Java  CLOB ChunkSize: 16264, BufferSize: 32528
  Java  BLOB ChunkSize: 16264, BufferSize: 32528
  ------- 3. DB Lob 32k -------
  Plsql CLOB ChunkSize: 32528
  Plsql BLOB ChunkSize: 32528
  Java  CLOB ChunkSize: 32528, BufferSize: 32528
  Java  BLOB ChunkSize: 32528, BufferSize: 32528
  ------- 4. Temporary Lob empty -------
  Plsql CLOB ChunkSize: 8132
  Plsql BLOB ChunkSize: 8132
  Java  CLOB ChunkSize: 8132, BufferSize: 32528
  Java  BLOB ChunkSize: 8132, BufferSize: 32528
  ------- 5. Temporary Lob small -------
  Plsql CLOB ChunkSize: 4000
  Plsql BLOB ChunkSize: 4000
  Java  CLOB ChunkSize: 4000, BufferSize: 32000
  Java  BLOB ChunkSize: 4000, BufferSize: 32000
  ----------**** CLOB length: 9
  ------- 6. Temporary Lob big -------
  Plsql CLOB ChunkSize: 4000
  Plsql BLOB ChunkSize: 4000
  Java  CLOB ChunkSize: 4000, BufferSize: 32000
  Java  BLOB ChunkSize: 4000, BufferSize: 32000
  ----------****  CLOB length: 32767
We can see that Plsql and Java ChunkSize are the same as SQL for 8k, 16k, and 32k, and their BufferSize are always 32528. But Temporary Lob is special. In case of empty, ChunkSize is 8132, when assigned a value, it is decreased to 4000, in which CHUNK seems no more a multiple of the database block size as described in above "LOB Storage CHUNK". Their BufferSize are respectively 32528, 32000.

Now we look ChunkSize and BufferSize for LOB created in OracleJVM:

SQL > exec printSizeFromOracleJvm;

  OracleJvm CLOB ChunkSize: 8132, BufferSize: 32528
  OracleJvm BLOB ChunkSize: 8132, BufferSize: 32528
They are the same as the above case of 8k.

If we open Java class BLOB, we can see that getBufferSize is computed based on getChunkSize (all calculations are Java integer arithmetic), for example, if ChunkSize is 8132, BufferSize is 32528 (4*8132). Its maximum value is hard-coded as 32768 (probably the same limit as largest allowed Oracle Database block size).

public class BLOB extends DatumWithConnection implements Blob {
    public int getBufferSize() throws SQLException {
        ...

        int size = getChunkSize();
        int ret = size;

        if ((size >= 32768) || (size <= 0)) {
            ret = 32768;
        } else {
            ret = 32768 / size * size;
        }
        ...
        
        return ret;
    }
SQL*Plus Release 12.2.0.1.0 New Feature:

SET LOBPREFETCH {0 | n} 
sets the amount of LOB data (in bytes) that SQL*Plus will prefetch from the database at one time (one "roundtrips to/from client"), which has a maximum value of 32767. Each LOB value fetch requires one roundtrip.

One case of dbms_alert.signal deadlock

In this Blog, we present one case of DBMS_ALERT_INFO update deadlock when two sessions calling dbms_alert.signal.

At first, setup test by:

begin
       dbms_alert.register('test_alert_1');
       dbms_alert.register('test_alert_2');
end;
/
Then open 2 Sqlplus Sessions: S1, and S2, run following steps one after another:

---======== S1@T1:  send 'test_alert_1' ========---
exec dbms_alert.signal('test_alert_1', 'alert_msg_1');

---======== S2@T2:  send 'test_alert_2' ========---
exec dbms_alert.signal('test_alert_2', 'alert_msg_2');

---======== S1@T3:  send 'test_alert_2' ========---
exec dbms_alert.signal('test_alert_2', 'alert_msg_2');

---======== S2@T4:  send 'test_alert_1' ========---
exec dbms_alert.signal('test_alert_1', 'alert_msg_1');
After about 3 seconds, S1 (first starting session) hit a deadlock.
  
ERROR at line 1:
ORA-00060: deadlock detected while waiting for resource
ORA-06512: at "SYS.DBMS_ALERT", line 431
ORA-06512: at line 1
The trace file contains the Deadlock graph and Error Stack. It looks like a conventional case of deadlock generated in application of dbms_alert.signal.

Deadlock graph:
                                          ------------Blocker(s)-----------  ------------Waiter(s)------------
Resource Name                             process session holds waits serial  process session holds waits serial
TX-000F0014-00030A6B-00000000-00000000          8     374     X        16904      47     914           X  60788
TX-00020013-00043AF0-00000000-00000000         47     914     X        60788       8     374           X  16904
 
----- Information for waiting sessions -----
Session 374:
  sid: 374 ser: 16904 audsid: 50061287 user: 0/SYS
    flags: (0x8100041) USR/- flags2: (0x40009) -/-/INC
    flags_idl: (0x1) status: BSY/-/-/- kill: -/-/-/-
  pid: 8 O/S info: user: oracle, term: UNKNOWN, ospid: 6207
    image: oracle@testdb
  client details:
    O/S info: user: ksun, term: TESTPC, ospid: 20744:22464
    machine: SYS\TESTPC program: sqlplus.exe
    application name: SQL*Plus, hash value=3669949024
  current SQL:
  UPDATE DBMS_ALERT_INFO SET CHANGED = 'Y', MESSAGE = :B2 WHERE NAME = UPPER(:B1 )
 
Session 914:
  sid: 914 ser: 60788 audsid: 50061288 user: 0/SYS
    flags: (0x8100041) USR/- flags2: (0x40009) -/-/INC
    flags_idl: (0x1) status: BSY/-/-/- kill: -/-/-/-
  pid: 47 O/S info: user: oracle, term: UNKNOWN, ospid: 6325
    image: oracle@testdb
  client details:
    O/S info: user: ksun, term: TESTPC, ospid: 21236:22040
    machine: SYS\TESTPC program: sqlplus.exe
    application name: SQL*Plus, hash value=3669949024
  current SQL:
  UPDATE DBMS_ALERT_INFO SET CHANGED = 'Y', MESSAGE = :B2 WHERE NAME = UPPER(:B1 )
 
----- End of information for waiting sessions -----
 
*** 2020-11-08T14:53:34.649821+01:00
dbkedDefDump(): Starting a non-incident diagnostic dump (flags=0x0, level=1, mask=0x0)
----- Error Stack Dump -----
 at 0x7ffef6442228 placed updexe.c@2062
 at 0x7ffef6443050 placed updexe.c@4637
----- Current SQL Statement for this session (sql_id=6tmkh8j0d3w0p) -----
UPDATE DBMS_ALERT_INFO SET CHANGED = 'Y', MESSAGE = :B2 WHERE NAME = UPPER(:B1 )
----- PL/SQL Stack -----
----- PL/SQL Call Stack -----
  object      line  object
  handle    number  name
0x9ce97888       431  package body SYS.DBMS_ALERT.SIGNAL
0x7294ec28         1  anonymous block
In AskTOM: dbms_alert_info - Ask TOM - Oracle, there is also one case of dbms_alert deadlock.