Call now: 252-767-6166  
Oracle Training Oracle Support Development Oracle Apps

 
 Home
 E-mail Us
 Oracle Articles
New Oracle Articles


 Oracle Training
 Oracle Tips

 Oracle Forum
 Class Catalog


 Remote DBA
 Oracle Tuning
 Emergency 911
 RAC Support
 Apps Support
 Analysis
 Design
 Implementation
 Oracle Support


 SQL Tuning
 Security

 Oracle UNIX
 Oracle Linux
 Monitoring
 Remote s
upport
 Remote plans
 Remote
services
 Application Server

 Applications
 Oracle Forms
 Oracle Portal
 App Upgrades
 SQL Server
 Oracle Concepts
 Software Support

 Remote S
upport  
 Development  

 Implementation


 Consulting Staff
 Consulting Prices
 Help Wanted!

 


 Oracle Posters
 Oracle Books

 Oracle Scripts
 Ion
 Excel-DB  

Don Burleson Blog 


 

 

 


 

 

 
 

How to read a text file into an Oracle table

Oracle Database Tips by Donald BurlesonDecember 13,  2015 - Updated April 9, 2016

 

Loading text files into Oracle tables can be done in a variety of ways.  You can load the text file as:


- SQL*Loader: This will read the text, line by line.

- External Table: See these notes on Oracle external tables: 

  1. Load text file with External Tables

  2. Oracle External Table error and ORA-29913

  3. Oracle External Tables

  4. ETL read test file with pipelined table functions

- Use a program:  You can read Oracle data with a Pro*C program.

- Use utl_file:  You can read a text file and load it into a table using PL/SQL with utl_file.  Here is a anonymous PL/SQL for reading a text file into a table:

set serveroutput on;

CREATE or replace DIRECTORY USER_DIR AS '/home/oracle';

GRANT READ ON DIRECTORY USER_DIR TO PUBLIC;

DECLARE
V1 VARCHAR2(200); --32767
F1 UTL_FILE.FILE_TYPE;
BEGIN
F1 := UTL_FILE.FOPEN('USER_DIR','temp.txt','R');
Loop
BEGIN
UTL_FILE.GET_LINE(F1,V1);
dbms_output.put_line(V1);
EXCEPTION WHEN No_Data_Found THEN EXIT; END;
end loop;

IF UTL_FILE.IS_OPEN(F1) THEN
dbms_output.put_line('File is Open');
end if;

UTL_FILE.FCLOSE(F1);
END;
/
set serveroutput off;

As we see, there are many ways to read a text file and load it into a table.

Nice Trick for Reading Text Files Into tables

Have you ever had the need to read a text file into Oracle? And parse out pieces of information when you do it? Yes, you can do it with SQL Loader, but Oracle external tables offer much more flexibility. The example below shows you how to read an Oracle text alert log into an Oracle table, but you can use this method to read any text file.

First, define your directory and grant the required privileges:

create directory log_dir as '/u01/app/oracle/admin/orcl/bdump';
grant read on directory log_dir to dba;
grant write on directory log_dir to dba;

Next, we create our external table:

create table alert_log
(txt_line varchar2(512))
organization external
(type ORACLE_LOADER
default directory log_dir
access parameters (records delimited by newline
fields
(txt_line char(512)))
location ('alert_orcl.log')
);

Note that we set the length of the line to 512. Just set it to the maximum length of the line. Oracle will read to the end of the record as delimited by the new line.

At this point, we can read the table as any oracle table.

Select * from alert_log;

Create table ora_alert_log as (select rownum as line_number, txt_line from alert_log);

If you run the create table as select, you now have a standard Oracle table containing lines of text. At this point, you can do all kinds of queries and data manipulations.

You can search specific lines to load into your table.


 

 

��  
 
 
Oracle Training at Sea
 
 
 
 
oracle dba poster
 

 
Follow us on Twitter 
 
Oracle performance tuning software 
 
Oracle Linux poster
 
 
 

 

Burleson is the American Team

Note: This Oracle documentation was created as a support and Oracle training reference for use by our DBA performance tuning consulting professionals.  Feel free to ask questions on our Oracle forum.

Verify experience! Anyone considering using the services of an Oracle support expert should independently investigate their credentials and experience, and not rely on advertisements and self-proclaimed expertise. All legitimate Oracle experts publish their Oracle qualifications.

Errata?  Oracle technology is changing and we strive to update our BC Oracle support information.  If you find an error or have a suggestion for improving our content, we would appreciate your feedback.  Just  e-mail:  

and include the URL for the page.


                    









Burleson Consulting

The Oracle of Database Support

Oracle Performance Tuning

Remote DBA Services


 

Copyright © 1996 -  2020

All rights reserved by Burleson

Oracle ® is the registered trademark of Oracle Corporation.