SQL Loader : ORA-01722: invalid number

I was loading below data to Oracle Database 11g using SQL * Loader

7935,EDDIE,CLERK,7698,03-FEB-98,2000,NULL,10
7936,TIM,SALESMAN,7782,03-FEB-98,2000,750,10
7937,CHARLIE,MANAGER,7839,03-FEB-98,2000,1010,10
7938,MARY,ANALYST,7566,03-FEB-98,2000,,10

and when I checked the bad file, I had this error :

$ cat emp1.log
Record 1: Rejected - Error on table PRAJEETH.EMP1, column COMM.
ORA-01722: invalid number

and bad file has one record

$ cat emp1.bad
7935,EDDIE,CLERK,7698,03-FEB-98,2000,NULL,10

What could have caused this error was slightly suprising. And I noticed that the value NULL was actually the seventh column of the table and the datatype is NUMBER. Take a look at the structure of the table.

SQL> desc emp1
 Name                       Null?    Type
 -------------------------- -------- ------------------
 EMPNO                               NUMBER(4)
 ENAME                               VARCHAR2(10)
 JOB                                 VARCHAR2(9)
 MGR                                 NUMBER(4)
 HIREDATE                            DATE
 SAL                                 NUMBER(7,2)
 COMM                                NUMBER(7,2)
 DEPTNO                              NUMBER(2)
 

But, there were thousands of records in the datafile and changing NULL to empty string will be more damaging. So, I didnt take search and replace approach, instead used what is provided by SQL Loader's built-in functionality.

Remedy

Let us see how we can overcome this error. In the SQL Loader control file, we need to use REPLACE function to replace NULL with empty string.

LOAD DATA 
APPEND 
infile emp1.txt 
badfile emp1.bad 
discardfile emp1.discar d
INTO TABLE prajeeth.emp1 
fields terminated by ',' optionally enclosed by '"' 
( 
     empno, 
     ename, 
     job, 
     mgr, 
     hiredate, 
     sal, 
     comm     CHAR     "REPLACE (:COMM, 'NULL', '')", 
     deptno 
)

SQL Loader creates bind variables during the load and the bind variable will be named by the name of the column in the table. We make use that bind variable (here it is :COMM) in the REPLACE function to replace NULL by empty string.

Verification

After loading the data, checked the bad and log file of SQL Loader and query the rows before and after loading.

SQL> SELECT * FROM emp;

     EMPNO ENAME      JOB              MGR HIREDATE         SAL       COMM     DEPTNO
---------- ---------- --------- ---------- --------- ---------- ---------- ----------
      7839 KING       PRESIDENT            17-NOV-81       5000                    10
      7698 BLAKE      MANAGER         7839 01-MAY-81       2850                    30
      7782 CLARK      MANAGER         7839 09-JUN-81       2450                    10
      7566 JONES      MANAGER         7839 02-APR-81       2975                    20
      7788 SCOTT      ANALYST         7566 19-APR-87       3000                    20
      7902 FORD       ANALYST         7566 03-DEC-81       3000                    20
      7369 SMITH      CLERK           7902 17-DEC-80        800                    20
      7499 ALLEN      SALESMAN        7698 20-FEB-81       1600        300         30
      7521 WARD       SALESMAN        7698 22-FEB-81       1250        500         30
      7654 MARTIN     SALESMAN        7698 28-SEP-81       1250       1400         30
      7844 TURNER     SALESMAN        7698 08-SEP-81       1500          0         30
      7876 ADAMS      CLERK           7788 23-MAY-87       1100                    20
      7900 JAMES      CLERK           7698 03-DEC-81        950                    30
      7934 MILLER     CLERK           7782 23-JAN-82       1300                    10
      7935 EDDIE      CLERK           7698 03-FEB-98       2000                    10
      7936 TIM        SALESMAN        7782 03-FEB-98       2000        750         10
      7937 CHARLIE    MANAGER         7839 03-FEB-98       2000       1010         10
      7938 MARY       ANALYST         7566 03-FEB-98       2000                    10

18 rows selected.

All the records in the datafile is now inserted to table.

Comments