How to dump to a delimited file using PLSQL


A frequently ask question is "how can I dump a query to a delimited flat file". In addition to using sqlplus (see flat), you can use PLSQL and the builtin UTL_FILE routine.

The following is an example of what this code would look like:

create or replace function  dump_csv( p_query     in varchar2,
                                      p_separator in varchar2 default ',',
                                      p_dir       in varchar2 ,
                                      p_filename  in varchar2 )
return number
is
    l_output        utl_file.file_type;
    l_theCursor     integer default dbms_sql.open_cursor;
    l_columnValue   varchar2(4000);
    l_status        integer;
    l_colCnt        number default 0;
    l_separator     varchar2(10) default '';
    l_cnt           number default 0;
begin
    l_output := utl_file.fopen( p_dir, p_filename, 'w' );

    dbms_sql.parse(  l_theCursor,  p_query, dbms_sql.native );

    for i in 1 .. 255 loop
        begin
            dbms_sql.define_column( l_theCursor, i, l_columnValue, 4000 );
            l_colCnt := i;
        exception
            when others then
                if ( sqlcode = -1007 ) then exit;
                else
                    raise;
                end if;
        end;
    end loop;

    dbms_sql.define_column( l_theCursor, 1, l_columnValue, 4000 );

    l_status := dbms_sql.execute(l_theCursor);

    loop
        exit when ( dbms_sql.fetch_rows(l_theCursor) <= 0 );
        l_separator := '';
        for i in 1 .. l_colCnt loop
            dbms_sql.column_value( l_theCursor, i, l_columnValue );
            utl_file.put( l_output, l_separator || l_columnValue );
            l_separator := p_separator;
        end loop;
        utl_file.new_line( l_output );
        l_cnt := l_cnt+1;
    end loop;
    dbms_sql.close_cursor(l_theCursor);

    utl_file.fclose( l_output );
    return l_cnt;
end dump_csv;
/

REM Here is an example of using the above:


create or replace procedure test_dump_csv
as
    l_rows  number;
begin
    l_rows := dump_csv( 'select * from all_users where rownum < 25', ',', '/tmp', 'test.dat' );
end;
/

I've made this compatible with Oracle7.3 and up.

It should be noted that in Oracle8.0.5 and up, the call the UTL_FILE.FOPEN make take an optional 4'th parameter -- an integer specifying the linesize upto 32k (as it is, the above is limited to 1023bytes/line, with 8.0.5 and up it is limited to 32k/line).

Additionally, you could use DBMS_SQL.DESCRIBE_COLUMNS to figure out the number of columns -- I loop upto 255 times to discover how many there are. DBMS_SQL.DESCRIBE_COLUMNS was added in 8.0 (so I did not use it for 7.3 people).

Make sure to setup UTL_FILE on your system. See this page for help on that

Lastly, I bind everything to a 4000 byte varchar2. This'll not work very well for CLOBS, BLOBS, LONGS and LONG RAWS.

All information and materials provided here are provided "as-is"; Oracle disclaims all express and implied warranties, including, the implied warranties of merchantability or fitness for a particular use. Oracle shall not be liable for any damages, including, direct, indirect, incidental, special or consequential damages for loss of profits, revenue, data or data use, incurred by you or any third party in connection with the use of this information or these materials.