Tek-Tips is the largest IT community on the Internet today!

Members share and learn making Tek-Tips Forums the best source of peer-reviewed technical information on the Internet!

  • Congratulations Chris Miller on being selected by the Tek-Tips community for having the most helpful posts in the forums last week. Way to Go!

Export Table in Oracle to pipe delimited text file 1

Status
Not open for further replies.

jcw12000

Technical User
Sep 30, 2011
38
ZA
Hi Guys

I have a client that works on Oracle. Now for my dumb question, what script can I send the client to extract a table with all columns into a pipe delimited txt file.

Thanks
 
jcw,

this is a bit tricky.

There are numerous possible solutions, but their use depends on the technical ability of your client.
Is it just one table, because if it is, a sql plus script would be quite simple to use.

Alternatively, application express has a data unloading tool, and so does TOAD.
TOAD is superior to APEX in this regard, so it would get my vote.

Do you have remote access to the table? If you do, then you could just grab the data yourself.

Regards

T
 
Here is a handy little SQL script (intended for use in SQL*Plus) that prompts for any table, in any schema, using any delimiter of your choice, to output a text file (of your choice) containing the contents of the table:

Code:
set echo off
accept x prompt "Enter the table to ASCII: "
accept ownr prompt "Which schema owns table '&x'?: "
accept y prompt "Enter the flat file to write: "
accept delim prompt "Enter the symbol to use as the delimiter in the text file: "
set verify off
set feedback off
set heading off
set pagesize 0
set linesize 32767
set trimout on
set trimspool on
var sq char
exec :sq := ''''
var dq char
exec :dq := '"'
prompt
prompt Following output is generated script that writes text output from table "&x"
prompt 
spool temp.sql
prompt set echo off
prompt set feedback off
prompt set heading off
prompt set pagesize 0
prompt spool &y
prompt Select
select decode (rownum
               ,1,:sq||:dq||:sq||'||'
               ,'||'||:sq||'&delim'||:dq||:sq||'||')
       || column_name || '|| ''"''' 
  from all_tab_columns
 where table_name = upper('&x') and owner = upper('&ownr');
prompt from &x
prompt /
prompt spool off
prompt set feedback on
prompt set heading on
prompt set pagesize 20
spool off
prompt
prompt Following is text output written to file "&y"
prompt
@temp
set echo off
prompt
prompt Output file = "&y"
prompt

I saved the script to the name, "GenASCIIAnyDelimiter.sql". Here is the invocation and its results for a two-column table named "s_region":

Code:
17:26:25 WM-HUNTDL/dhunt:DHUNT SQL> @GenASCIIAnyDelimiter
Enter the table to ASCII: s_region
Which schema owns table 's_region'?: summit
Enter the flat file to write: region.txt
Enter the symbol to use as the delimiter in the text file: |

Following output is generated script that writes text output from table "s_region"

set echo off
set feedback off
set heading off
set pagesize 0
spool region.txt
Select
'"'||ID|| '"'
||'|"'||NAME|| '"'
from s_region
/
spool off
set feedback on
set heading on
set pagesize 20

Following is text output written to file "region.txt"

"1"|"North America"
"2"|"South America"
"3"|"Africa / Middle East"
"4"|"Asia"
"5"|"Europe"

Output file = "region.txt"
I used a pipe symbol in the case, above, to illustrate proof of concept per your request. The script also encloses each value in double quotes ("), but you can eliminate the double quotes if you prefer.

Let us know if this is helpful.

[santa]Mufasa
(aka Dave of Sandy, Utah, USA)
“People may forget what you say, but they will never forget how you made them feel.
 
A long time since I've been on here due to work intrusions, but I see you're still doing the business dave, have a star!

The internet - allowing those who don't know what they're talking about to have their say.
 
Thanks very much, Ken. Great to see you are back !

[santa]Mufasa
(aka Dave of Sandy, Utah, USA)
“People may forget what you say, but they will never forget how you made them feel.
 
Status
Not open for further replies.

Part and Inventory Search

Sponsor

Back
Top