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

Home -> Community -> Mailing Lists -> Oracle-L -> Re: Sqlldr "automatic" control file

Re: Sqlldr "automatic" control file

From: Tom Pall <tom_at_cdproc.com>
Date: Mon, 28 Aug 2000 11:27:42 -0500
Message-Id: <10602.115650@fatcity.com>


If you use this scrip from Jared Still against the Oracle table which has no data in it, you'll get the files you need.

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
----- Original Message -----

From: Brian Wisniewski <brian_wisniewski_at_yahoo.com> To: Multiple recipients of list ORACLE-L <ORACLE-L_at_fatcity.com> Sent: Monday, August 28, 2000 11:32 AM
Subject: Re: Sqlldr "automatic" control file

> I've used platinum's fast unload to do this but for most purchasing
> another tool to create a control file is out of the question.
> 
> - Brian
> 
> --- "Figueiredo, Pedro" <PFigueiredo_at_europeantelecom.at> wrote:
> > Hi,
> > 
> > I want to load data to a table with lots of fields (exported with
> > fixed
> > length from a SQL*Server).
> > The table is already created on my Oracle database
> > Anyone knows a way to automatically "extract" the design of this
> > table and
> > produce a sqlldr control file to import the data?
> > 
> > Thanks in advance
> > 
> > Pedro Figueiredo
> > 
> > -- 
> > Author: Figueiredo, Pedro
> >   INET: PFigueiredo_at_europeantelecom.at
> > 
> > Fat City Network Services    -- (858) 538-5051  FAX: (858) 538-5051
> > San Diego, California        -- Public Internet access / Mailing
> > Lists
> > --------------------------------------------------------------------
> > To REMOVE yourself from this mailing list, send an E-Mail message
> > to: ListGuru_at_fatcity.com (note EXACT spelling of 'ListGuru') and in
> > the message BODY, include a line containing: UNSUB ORACLE-L
> > (or the name of mailing list you want to be removed from).  You may
> > also send the HELP command for other information (like subscribing).
> 
> 
> __________________________________________________
> Do You Yahoo!?
> Yahoo! Mail - Free email you can access from anywhere!
> http://mail.yahoo.com/
> -- 
> Author: Brian Wisniewski
>   INET: brian_wisniewski_at_yahoo.com
> 
> Fat City Network Services    -- (858) 538-5051  FAX: (858) 538-5051
> San Diego, California        -- Public Internet access / Mailing Lists
> --------------------------------------------------------------------
> To REMOVE yourself from this mailing list, send an E-Mail message
> to: ListGuru_at_fatcity.com (note EXACT spelling of 'ListGuru') and in
> the message BODY, include a line containing: UNSUB ORACLE-L
Received on Mon Aug 28 2000 - 11:27:42 CDT

Original text of this message

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