External table with ORACLE_LOADER
June 6, 2012 Leave a comment
Today, I will discuss how to create external table and show you the primary usage of it.
Data in external table is saved outside of the database. To easily understand what does it mean, let’s discuss the following example:
user1 is the user, who is connected to the ORCL database and should see mytable content.
user2 is the user, who modifies data.csv file using Excel and places it in the directory accessible for oracle database.
Pic 1.
This approach may be achieved by ORACLE_LOADER or ORACLE_DATA.
In my example , I will use ORACLE_LOADER.
1. Create csv document and fill it with some data:
2. Change data.csv with data.txt. So change csv extension to txt.
This will help you to determine by which character is data separated.
As you can see records are separated by newline and delimiter is comma (,)
So let’s write a script:
3.
/*Create necessary directories
Bad file will be saved in bad_dir. As you know bad file is for saving data,
that was not loaded into the database because of some error.
*/
create directory data_dir as 'D:\data';
create directory bad_dir as 'D:\data\bad';
create directory log_dir as 'D:\log';
/*Create table owner*/
create user a identified by a default tablespace USERS;
/*Grant necessary privileges*/
grant create session to a;
grant read on directory data_dir to a;
grant write on directory bad_dir to a;
grant write on directory log_dir to a;
grant create table to a;
/*Connect as “a” user and create external table*/
Create table data_table(
Name varchar2(30),
Surname varchar2(60),
quantity number
)
organization external(
type ORACLE_LOADER
default directory data_dir
access parameters(
records delimited by newline
badfile bad_dir:'data.bad'
logfile log_dir:'data.log'
fields terminated by ','
missing field values are null
(name,surname,quantity)
)
location('data.txt')
)
parallel
reject limit unlimited;
I think external table options are self-explanatory….
Let’s check table content:
SQL> select * from data_table;
NAME SURNAME QUANTITY
---------- ----------- ----------
Mariam Kupatadze 1
Giorgi Beridze 1
Change the content of data.txt file to the following
/*data.txt*/
Giorgi,Beridze,1
Mariam,Kupatadze,2
and re-run the query
SQL> select * from data_table;
NAME SURNAME QUANTITY
---------- ----------- ----------
Mariam Kupatadze 2
Giorgi Beridze 1
as you can see changes were reflected.
Note, external table is read only. Let’s try updating it:
update data_table set surname='Kupa' where surname='Kupatadze';
You will get an error
Now let’s change the content of data.txt to the following
/*data.txt*/
Giorgi,Beridze,1
Mariam,Kupatadze,2
mmmmmm,mmmmmmm,mmm
and re-run the query
SQL> select * from data_table;
NAME SURNAME QUANTITY
---------- ----------- ----------
Mariam Kupatadze 2
Giorgi Beridze 1
There is no changes, why ?
Now let’s see the log file and then bad file:
At the end of the log file you will notice the following error:
error processing column QUANTITY in row 3 for datafile D:\data\data.csv
ORA-01722: invalid number
In the bad file, there is:
mmm,mmm,mmm
Because of quantity column type was number, string “mmm” was not inserted in it.
So log file showed us the error “invalid number” and bad file saved data that was causing an error.
I hope it was helpful for you. Good Luck!