Hi Readers,
In this article,we will see Migrating Table data from MySQL to Oracle Using SQL* LOADER.
Step 1 :
Connect to Mysql DB and create a table
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 |
[root@ip-172-31-46-32 ~]# mysql -uroot -p Enter password: Welcome to the MySQL monitor. Commands end with ; or \g. Your MySQL connection id is 16 Server version: 5.7.28-log MySQL Community Server (GPL) Copyright (c) 2000, 2019, Oracle and/or its affiliates. All rights reserved. Oracle is a registered trademark of Oracle Corporation and/or its affiliates. Other names may be trademarks of their respective owners. Type 'help;' or '\h' for help. Type '\c' to clear the current input statement. mysql> show databases; +--------------------+ | Database | +--------------------+ | information_schema | | mysql | | oggdb1 | | performance_schema | | sys | +--------------------+ 5 rows in set (0.00 sec) mysql> use oggdb1; Reading table information for completion of table and column names You can turn off this feature to get a quicker startup with -A Database changed mysql> mysql> CREATE TABLE `C_EMP` ( -> `sid` bigint(20) NOT NULL, -> `C_ID` bigint(20) NOT NULL, -> `text` varchar(255) DEFAULT NULL, -> `A_N_S_M` int(11) NOT NULL DEFAULT '0', -> `D_R_I_K` int(11) NOT NULL DEFAULT '0', -> `crd` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP, -> `mdd` timestamp NULL DEFAULT NULL -> ) ENGINE=InnoDB DEFAULT CHARSET=latin1; Query OK, 0 rows affected (0.01 sec) |
Insert data into a table
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 |
mysql> insert into C_EMP values(1,1,'ABCD',10,10,NOW(),NOW()); Query OK, 1 row affected (0.00 sec) mysql> insert into C_EMP values(1,1,'ABCD',10,10,NOW(),NOW()); Query OK, 1 row affected (0.00 sec) mysql> insert into C_EMP values(1,1,'ABCD',10,10,NOW(),NOW()); Query OK, 1 row affected (0.01 sec) mysql> insert into C_EMP values(1,1,'ABCD',10,10,NOW(),NOW()); Query OK, 1 row affected (0.00 sec) mysql> insert into C_EMP values(1,1,'ABCD',10,10,NOW(),NOW()); Query OK, 1 row affected (0.00 sec) mysql> insert into C_EMP values(1,1,'ABCD',10,10,NOW(),NOW()); Query OK, 1 row affected (0.00 sec) mysql> insert into C_EMP values(1,1,'ABCD',10,10,NOW(),NOW()); Query OK, 1 row affected (0.01 sec) mysql> insert into C_EMP values(1,1,'ABCD',10,10,NOW(),NOW()); Query OK, 1 row affected (0.00 sec) mysql> insert into C_EMP values(1,1,'ABCD',10,10,NOW(),NOW()); Query OK, 1 row affected (0.00 sec) mysql> insert into C_EMP values(1,1,'ABCD',10,10,NOW(),NOW()); Query OK, 1 row affected (0.00 sec) |
Crosscheck the data in C_EMP TABLE
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 |
mysql> select * from C_EMP; +-----+------+------+---------+---------+---------------------+---------------------+ | sid | C_ID | text | A_N_S_M | D_R_I_K | crd | mdd | +-----+------+------+---------+---------+---------------------+---------------------+ | 1 | 1 | ABCD | 10 | 10 | 2020-05-01 13:08:53 | 2020-05-01 13:08:53 | | 1 | 1 | ABCD | 10 | 10 | 2020-05-01 13:08:55 | 2020-05-01 13:08:55 | | 1 | 1 | ABCD | 10 | 10 | 2020-05-01 13:08:56 | 2020-05-01 13:08:56 | | 1 | 1 | ABCD | 10 | 10 | 2020-05-01 13:08:57 | 2020-05-01 13:08:57 | | 1 | 1 | ABCD | 10 | 10 | 2020-05-01 13:08:58 | 2020-05-01 13:08:58 | | 1 | 1 | ABCD | 10 | 10 | 2020-05-01 13:08:59 | 2020-05-01 13:08:59 | | 1 | 1 | ABCD | 10 | 10 | 2020-05-01 13:09:00 | 2020-05-01 13:09:00 | | 1 | 1 | ABCD | 10 | 10 | 2020-05-01 13:09:04 | 2020-05-01 13:09:04 | | 1 | 1 | ABCD | 10 | 10 | 2020-05-01 13:09:05 | 2020-05-01 13:09:05 | | 1 | 1 | ABCD | 10 | 10 | 2020-05-01 13:09:06 | 2020-05-01 13:09:06 | +-----+------+------+---------+---------+---------------------+---------------------+ 10 rows in set (0.00 sec) |
Step 2 :
Export data from C_EMP table to CSV file using below query
1 2 3 4 5 6 7 8 9 10 11 |
mysql> select sid, ifnull(C_ID,'') , ifnull(text,''), ifnull(A_N_S_M,''), ifnull(D_R_I_K,''), ifnull(crd,'') , ifnull(mdd,'') from C_EMP INTO OUTFILE '/var/lib/mysql-files/C_EMP.csv' FIELDS TERMINATED BY ',' ENCLOSED BY '' LINES TERMINATED BY '\n' ; Query OK, 10 rows affected (0.00 sec) |
Step 3 :
Check data in CSV file and send to Oracle server
1 2 3 4 5 6 7 8 9 10 11 |
[root@ip-172-31-46-32 ~]# cat /var/lib/mysql-files/C_EMP.csv 1,1,ABCD,10,10,2020-05-01 13:08:53,2020-05-01 13:08:53 1,1,ABCD,10,10,2020-05-01 13:08:55,2020-05-01 13:08:55 1,1,ABCD,10,10,2020-05-01 13:08:56,2020-05-01 13:08:56 1,1,ABCD,10,10,2020-05-01 13:08:57,2020-05-01 13:08:57 1,1,ABCD,10,10,2020-05-01 13:08:58,2020-05-01 13:08:58 1,1,ABCD,10,10,2020-05-01 13:08:59,2020-05-01 13:08:59 1,1,ABCD,10,10,2020-05-01 13:09:00,2020-05-01 13:09:00 1,1,ABCD,10,10,2020-05-01 13:09:04,2020-05-01 13:09:04 1,1,ABCD,10,10,2020-05-01 13:09:05,2020-05-01 13:09:05 1,1,ABCD,10,10,2020-05-01 13:09:06,2020-05-01 13:09:06 |
use SCP to transfer files
1 |
[root@ip-172-31-46-32 ~]# scp /var/lib/mysql-files/C_EMP.csv oracle@ip-172-31-34-208.ap-south-1.compute.internal:/home/oracle/C_EMP.csv |
Oracle Server :
Step 4:
Create a table with required metadata
1 2 3 4 5 6 7 8 9 |
SYS> CREATE TABLE ktexperts.C_EMP ( SID NUMBER(38) NOT NULL, C_ID NUMBER(38) NOT NULL, TEXT VARCHAR2(255 CHAR), A_N_S_M NUMBER(10) NOT NULL, D_R_I_K NUMBER(10) NOT NULL, crd TIMESTAMP(6) NOT NULL, mdd TIMESTAMP(6) ); |
Step 5 :
Create a control file to load data into Oracle database.
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 |
[oracle@ip-172-31-34-208 ~]$ cat C_EMP.ctl LOAD DATA INFILE '/home/oracle/C_EMP.csv' BADFILE '/home/oracle/C_EMP_10.bad' DISCARDFILE '/home/oracle/C_EMP_10.dsc' INTO TABLE "KTEXPERTS"."C_EMP" INSERT FIELDS TERMINATED BY ',' TRAILING NULLCOLS (SID, C_ID, TEXT, A_N_S_M, D_R_I_K, crd date "YYYY-MM-DD HH24:MI:SS", mdd date "YYYY-MM-DD HH24:MI:SS") |
Step 6 :
Load the data into KTEXPERTS schema using SQL*Loader
1 2 3 4 5 6 7 8 9 10 11 |
[oracle@ip-172-31-34-208 ~]$ sqlldr KTEXPERTS control=C_EMP.ctl log=C_EMP.log Password: SQL*Loader: Release 12.1.0.2.0 - Production on Fri May 1 13:20:07 2020 Copyright (c) 1982, 2014, Oracle and/or its affiliates. All rights reserved. Path used: Conventional Commit point reached - logical record count 10 Table "KTEXPERTS"."C_EMP": 10 Rows successfully loaded. Check the log file: C_EMP.log for more information about the load. |
Import successfully done to Oracle database
Now check the data in C_EMP table.
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 |
[oracle@ip-172-31-34-208 ~]$ sqlplus ktexperts/ktexperts SQL*Plus: Release 12.1.0.2.0 Production on Fri May 1 13:20:26 2020 Copyright (c) 1982, 2014, Oracle. All rights reserved. Last Successful login time: Fri May 01 2020 13:20:11 +00:00 Connected to: Oracle Database 12c Enterprise Edition Release 12.1.0.2.0 - 64bit Production With the Partitioning, OLAP, Advanced Analytics and Real Application Testing options KTEXPERTS>> select * from C_EMP; SID C_ID TEXT A_N_S_M D_R_I_K CRD MDD ---------- ---------- --------------- ---------- ---------- ------------------------------ ------------------------------ 1 1 ABCD 10 10 01-MAY-20 01.08.53.000000 PM 01-MAY-20 01.08.53.000000 PM 1 1 ABCD 10 10 01-MAY-20 01.08.55.000000 PM 01-MAY-20 01.08.55.000000 PM 1 1 ABCD 10 10 01-MAY-20 01.08.56.000000 PM 01-MAY-20 01.08.56.000000 PM 1 1 ABCD 10 10 01-MAY-20 01.08.57.000000 PM 01-MAY-20 01.08.57.000000 PM 1 1 ABCD 10 10 01-MAY-20 01.08.58.000000 PM 01-MAY-20 01.08.58.000000 PM 1 1 ABCD 10 10 01-MAY-20 01.08.59.000000 PM 01-MAY-20 01.08.59.000000 PM 1 1 ABCD 10 10 01-MAY-20 01.09.00.000000 PM 01-MAY-20 01.09.00.000000 PM 1 1 ABCD 10 10 01-MAY-20 01.09.04.000000 PM 01-MAY-20 01.09.04.000000 PM 1 1 ABCD 10 10 01-MAY-20 01.09.05.000000 PM 01-MAY-20 01.09.05.000000 PM 1 1 ABCD 10 10 01-MAY-20 01.09.06.000000 PM 01-MAY-20 01.09.06.000000 PM |
I hope above information useful and helpful.
Thank you for giving your valuable time to read the above information. Please click here to subscribe for further updates
KTEXPERTS is always active on below social media platforms.
Facebook : https://www.facebook.com/ktexperts/
LinkedIn : https://www.linkedin.com/company/ktexperts/
Twitter : https://twitter.com/ktexpertsadmin
YouTube : https://www.youtube.com/c/ktexperts
Instagram : https://www.instagram.com/knowledgesharingplatform