Oracle FAQ | Your Portal to the Oracle Knowledge Grid |
![]() |
![]() |
Home -> Community -> Usenet -> c.d.o.misc -> Re: Oracle Data Unloader Tool
Here is a script than can give you the ASCII dump. As you can see, I did not write it. Jared Still wrote it. Its beautiful !!!
suresh.bhat_at_mitchell-energy.com
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;
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
'replace(' || column_name || ',' || '''' || '"' || '''' || ') ' || ' ||' || '''' || '"' || '''', column_id
select 'from &dumpowner..&dumptable' from dual; select '/' from dual; select 'spool off' from dual;
select 'userid = /' || chr(10) ||
'control = ' || lower('&dumptable') || '.ctl' || chr(10) || 'log = ' || lower('&dumptable') || '.log' || chr(10) || 'bad = ' || lower('&dumptable')|| '.bad' || chr(10)from dual;
'infile ' || ''''|| lower('&dumptable') || '.txt' || '''' || chr(10) ||
'into table &dumptable' || chr(10) || 'fields terminated by ' || '''' || ',' || '''' || 'optionally enclosed by ' || '''' || '"' || '''' || chr(10)from dual;
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
Andy Hering <andy_hering_at_forecross.com> wrote in article <356D8634.968F778D_at_forecross.com>...
> Hi, > > I am looking for a way to do the opposite of SQL*LOADER, bascially to > unload data in a table in my database to an ASCII flatfile. I know I > can do this in Sybase and MSSQL using the BCP command. However, in > Oracle, there doesn't seem to be a tool that allows me to do this. Does > SQL*LOADER have any "hidden" options to do this? Has anybody found a > way to do this? > > I know there are some third party tools that do this kind of thing, but > I wanted to avoid using them unless for some reason you can download > them for free. I am trying to write a shell script that will bascially > unload data from a table in a database using whatever the vendor > supplies. In the case of Sybase and MSSQL, I can use BCP; Informix has > UNLOAD. However, with Oracle I seem to be stuck. Any suggestions? > > Thanks, > Andy > > P.S. -> I know I can use svrmgrl or sqlplus to perform the select and > save the output to a file, but I was also trying to avoid using this. > >Received on Thu Jun 04 1998 - 00:00:00 CDT
![]() |
![]() |