Skip to Main Content
  • Questions
  • String buffer into Oracle (utl, xml)

Breadcrumb

Question and Answer

Connor McDonald

Thanks for the question, Pawel.

Asked: September 20, 2017 - 11:59 am UTC

Last updated: September 25, 2017 - 12:59 pm UTC

Version: 11g

Viewed 1000+ times

You Asked

I have procedure to create xml file and save it on disc directory:

create or replace procedure test_write_xml_data_to_file 
(p_directory varchar2, p_file_name varchar2) as

v_file UTL_FILE.FILE_TYPE;
v_amount INTEGER := 32767;
v_xml_data XMLType;
v_char_buffer varchar2(32767);
begin

    v_file:= UTL_FILE.FOPEN(p_directory,p_file_name,'w',v_amount);

    UTL_FILE.PUT_LINE(v_file, '<?xml version="1."?>');

    select
      extract(
        XMLELEMENT("my_list",
          XMLAGG(
            XMLELEMENT("myName", col1 ||''|| col2) order by col1)),'/my_list') as xml_test
    into v_xml_data
    from tableABC;

    v_char_buffer :=v_xml_data.GETSTRINGVAL();

    UTL_FILE.put(v_file,v_char_buffer);
    UTL_FILE.fflush(v_file);
    UTL_FILE.fclose(v_file);

end test_write_xml_data_to_file;


When I execute it I got error:
execute test_write_xml_data_to_file('DMP_XML','test_xml.xml')
Error report -
ORA-19011: Character string buffer too small
ORA-06512: at "SYS.XMLTYPE", line 169
ORA-06512: at "FPWH.TEST_WRITE_XML_DATA_TO_FILE", line 31
ORA-06512: at line 1
19011. 00000 -  "Character string buffer too small" 
*Cause:    The string result asked for is too big to return back
*Action:   Get the result as a lob instead


How to change my procedure to correct?
Thank you in advance

and Connor said...

You are limited to 32k with varchar2, and even if you could go larger, there is a 32k line limit for utl_file. So you'll need to break up those lines. For example

SQL> set serverout on
SQL> declare
  2    p_directory varchar2(10) := 'TEMP';
  3    p_file_name varchar2(10) := 'xml.out';
  4
  5    v_file UTL_FILE.FILE_TYPE;
  6    v_amount INTEGER := 32767;
  7    v_xml_data XMLType;
  8    v_char_buffer varchar2(32767);
  9
 10    l_lob clob;
 11    l_idx pls_integer;
 12    start_pos pls_integer := 1;
 13  begin
 14     dbms_lob.createtemporary(l_lob,true);
 15      v_file:= UTL_FILE.FOPEN(p_directory,p_file_name,'w',v_amount);
 16
 17      UTL_FILE.PUT_LINE(v_file, '<?xml version="1."?>');
 18
 19      select
 20        extract(
 21          XMLELEMENT("my_list",
 22            XMLAGG(
 23              XMLELEMENT("myName", owner ||''|| object_name) order by object_id)),'/my_list') as xml_test
 24      into v_xml_data
 25      from dba_objects
 26      where rownum <= 10;
 27
 28      l_lob :=v_xml_data.GETclobVAL();
 29      loop
 30        l_idx := instr(l_lob,'</myName>');
 31        if l_idx > 0 then
 32           dbms_output.put_line(substr(l_lob,start_pos,l_idx+8));
 33           --UTL_FILE.put_line(v_file,substr(l_lob,start_pos,l_idx+8));
 34           l_lob := substr(l_lob,l_idx+9);
 35        else
 36           dbms_output.put_line(substr(l_lob,start_pos));
 37           --UTL_FILE.put_line(v_file,substr(l_lob,start_pos));
 38           exit;
 39        end if;
 40      end loop;
 41
 42      UTL_FILE.fflush(v_file);
 43      UTL_FILE.fclose(v_file);
 44     dbms_lob.freetemporary(l_lob);
 45
 46  end;
 47  /
<my_list><myName>SYSI_OBJ#</myName>
<myName>SYSC_FILE#_BLOCK#</myName>
<myName>SYSTS$</myName>
<myName>SYSICOL$</myName>
<myName>SYSUSER$</myName>
<myName>SYSCDEF$</myName>
<myName>SYSI_TAB1</myName>
<myName>SYSI_OBJ2</myName>
<myName>SYSI_OBJ5</myName>
<myName>SYSI_IND1</myName>
</my_list>

PL/SQL procedure successfully completed.



Rating

  (2 ratings)

Is this answer out of date? If it is, please let us know via a Comment

Comments

Pawel, September 21, 2017 - 7:11 am UTC

thank you Connor,
I will test it on Monday and will let you know, as now I have days off

XML test

A reader, September 25, 2017 - 7:33 am UTC

I have tested the code and it's working!
thanks for help
Connor McDonald
September 25, 2017 - 12:59 pm UTC

glad we could help

More to Explore

PL/SQL demos

Check out more PL/SQL tutorials on our LiveSQL tool.

PL/SQL docs

PL/SQL reference manual from the Oracle documentation library