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

Home -> Community -> Usenet -> c.d.o.tools -> Re: Creating Flat Files from Oracle Tables

Re: Creating Flat Files from Oracle Tables

From: HD665 <HD665_at_mail2.crown-net.com>
Date: 2000/06/28
Message-ID: <8jd4v4$r2n$1@serv1.iunet.it>#1/1

Sally Madeira wrote in message ...
>Hi,
>
>I am looking for a way to create an export that sends data to a file in
>either Ascii or Fixed
>Length. I do not want to have to use VB to do this (Of course if it is the
>only way then I will
>have to live with that). Does anyone have any tricks that I could use to do
>this whether through
>SQLPlus or someother oracle tools.
>
>Thanks in advance
>Sally
>
>

rem Script Description: This script dumps a table to a comma delimited ascii file

rem                     only drawback is line length is likely to be padded
with
rem                     quite a few spaces if the 'set trimspool on' option
is
rem                     not in your version of SQLPLUS.
rem
rem                     NOTE: It aLso builds a control file and a parameter
file for SQL*LOADER.
rem
rem Output file:        tdump.sql,{table name}.ctl,{table name}.par,
rem                     {table name}.txt
rem
rem Prepared By:        Oracle Resource Stop
rem
rem Usage Information: SQLPLUS SYS/pswd
rem                     @tabledump.sql {owner name} {table name}
rem

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 tdump.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;

@tdump
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 off;

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;

spool off;
set trimspool off;
set serverout off;
clear buffer;
clear column;
undef dumpfile;
undef dumptable;
undef dumpowner; Received on Wed Jun 28 2000 - 00:00:00 CDT

Original text of this message

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