Oracle FAQ Your Portal to the Oracle Knowledge Grid
HOME | ASK QUESTION | ADD INFO | SEARCH | E-MAIL US
 

Home -> Community -> Usenet -> c.d.o.server -> Re: Oracle Server 7.3 table to .CSV file dump

Re: Oracle Server 7.3 table to .CSV file dump

From: Suresh Bhat <suresh.bhat_at_mitchell-energy.com>
Date: 1998/04/30
Message-ID: <01bd744d$f8803ee0$a504fa80@mndnet>#1/1

I completely missed portion of the script written by Jared Still to dump a csv file that I posted on 4/29/98. Thanks to Doug Hardie for notifying me.  Here is the entire script.

set trimspool on
set serverout on
clear buffer
undef dumpfile
undef dumptable
undef dumpowner
var maxcol number
var linelen number
var dumpfile char(40)
col column_id noprint
set pages0 feed off termout on echo off verify off accept dumpowner char prompt 'Owner of table to dump: ' accept dumptable char prompt 'Table to dump: ' begin

        select max(column_id) into :maxcol
        from all_tab_columns
        where table_name = rtrim(upper('&dumptable'))
        and owner = rtrim(upper('&dumpowner'));
        select sum(data_length) + ( :maxcol * 3 ) into :linelen
        from all_tab_columns
        where table_name = rtrim(upper('&dumptable'))
        and owner = rtrim(upper('&dumpowner'));
end;
/
print linelen
print maxcol
spool ./_dump.sql
select 'set trimspool on' from dual;
select 'set termout off pages 0 heading off echo off' from dual;
select 'set line ' || :linelen from dual;
select 'spool ' || lower('&dumptable') || '.txt' from dual;
select 'select' || chr(10) from dual;
select '   ' || '''' || '"'  || '''' || ' || ' ||
        'replace(' || column_name || ',' || '''' ||  '"' || '''' || ') '
        || ' ||' || '''' || '",' || '''' || ' || ',
        column_id

from all_tab_columns
where table_name = upper('&dumptable')
and owner = upper('&dumpowner')
and column_id < :maxcol
union
select ' ' || '''' || '"' || '''' || ' || ' ||
        'replace(' || column_name  || ',' || '''' ||  '"' || '''' || ') '
        || ' ||' || '''' || '"' || '''',
        column_id

from all_tab_columns
where table_name = upper('&dumptable')
and owner = upper('&dumpowner')
and column_id = :maxcol
order by 2
/
select 'from &dumpowner..&dumptable' from dual;
select '/' from dual;
select 'spool off' from dual;

spool off
@@_dump
set line 79
-- build a basic control file

spool _dtmp.sql
select 'spool ' || lower('&dumptable') || '.par' from dual; spool off
@@_dtmp  

select 'userid = /' || chr(10) ||

        'control = ' || lower('&dumptable') || '.ctl' || chr(10) ||
        'log = ' || lower('&dumptable') || '.log' || chr(10) ||
        'bad = ' || lower('&dumptable')|| '.bad' || chr(10)
from dual;
spool _dtmp.sql
select 'spool ' || lower('&dumptable') || '.ctl' from dual; spool off
@@_dtmp
select 'load data' || chr(10) ||

        'infile ' || ''''|| lower('&dumptable') || '.txt' || '''' || chr(10) ||

        'into table &dumptable' || chr(10) ||
        'fields terminated by ' || '''' || ',' || '''' ||
        'optionally enclosed by ' || '''' || '"' || '''' || chr(10)
from dual;
select '(' from dual;
select ' ' || column_name || ',' ,

        column_id
from all_tab_columns
where table_name = upper('&dumptable')
and owner = upper('&dumpowner')
and column_id < :maxcol
union
select ' ' || column_name, column_id
from all_tab_columns
where table_name = upper('&dumptable')
and owner = upper('&dumpowner')
and column_id = :maxcol
order by 2
/
select ')' from dual;
exit

Tony Howard <tonyh_at_gmap.leeds.ac.uk> wrote in article <3546F1BC.E143C216_at_gmap.leeds.ac.uk>...

> I need to dump oracle tables to proper comma delimited format files with
> strings in quotes, i.e. the same format you can use in sqlldr & most
> wordprocessors.
> Any clues much appreciated.
> 
> 
Received on Thu Apr 30 1998 - 00:00:00 CDT

Original text of this message

HOME | ASK QUESTION | ADD INFO | SEARCH | E-MAIL US