合 Detailed Overview of Connecting Oracle to MySQL Using DG4ODBC Database Link (Doc ID 1320645.1)
APPLIES TO:
MySQL Connectors - Version 3.51 to 6.8 [Release 3.51 to 6.8]
Oracle Database - Enterprise Edition - Version 11.1.0.6 to 12.1.0.2 [Release 11.1 to 12.1]
MySQL Server - Version 5.5 to 5.7 [Release 5.5 to 5.7]
Oracle Database Cloud Schema Service - Version N/A and later
Gen 1 Exadata Cloud at Customer (Oracle Exadata Database Cloud Machine) - Version N/A and later
Information in this document applies to any platform.
ODBC, UnixODBC, DG4ODBC, MySQL, ODBCINI, Database Link
GOAL
How to connect Oracle to MySQL Server through ODBC database link
SOLUTION
Oracle database server uses DG4ODBC as the data gateway for connecting to non-Oracle RDBMS. This requires the proper setup for all components involved in transferring data from Oracle to MySQL and back. These components interact with each other in the following way:
+-----------------------------
| |
| [ORACLE] <---> [DG4ODBC] <---> [ODBC Driver Manager] <---> [ODBC Driver] |
| |
+--------------------------------------------------------------------------+
/|\
|
NETWORK
|
|/
+--
| |
| [MySQL Server] |
| |
+-----------------------+
In this article we will configure each component and diagnose problems that are most likely to be encountered during the setup process. NOTE: There are few articles in the internet that skip [ODBC Driver Manager] and connect directly [DG4ODBC] <- - -> [ODBC Driver]. It might work for some
drivers such as DataDirect or specific configurations, but beware that MySQL [ODBC Driver] (versions 3.51.x and 5.1.x) is not supposed to be loaded directly. The recommended driver manager is UnixODBC v.2.2.14 or newer. Configuring ODBC connections in 32-bit OS might be slightly easier than in 64-bit OS. The latter can execute 32 and 64-bit code and more attention must be paid to the components versions. In other words, when configuring ODBC you cannot mix 32-bit and 64-bit components within the Client Host. This is so because 32-bit binaries code can only load 32-bit binaries and 64-bit binaries can only load 64-bit binaries. [MySQL Server] is always independent because all communication with the driver is done through the network protocol. You have the choice to place [MySQL Server] on
executable is not important.
Step 1
We shall start from determining if [Oracle] and [DG4ODBC] are 32/64-bits:
1 2 3 4 5 | $ file $ORACLE_HOME/bin/dg4odbc /home/dbs/app/Ora/product/11.2.0/dbhome_1/bin/dg4odbc: ELF 64-bit LSB executable, AMD x86-64, version 1 (SYSV), for GNU/Linux 2.6.9, dynamically linked (uses shared libs), for GNU/Linux 2.6.9, not stripped |
The above command output says that we must use 64-bit [ODBC Driver Manager] and 64-bit [ODBC Driver]
Step 2
Getting and installing ODBC Driver Manager.
You should download and install the latest version of the UnixODBC driver manager from the site -
and click on the 'Download' option.
Follow the steps detailed there to install and configure the driver manager.
Step 3
Getting and installing [ODBC Driver].
Similar to UnixODBC, it is possible to have several different versions of MySQL Connector/ODBC driver. Installing the driver from tar.gz package does not require root privileges and allows installing the driver at custom locations, so we will do so.
More details about installing MySQL Connector/ODBC can be found here:
http://dev.mysql.com/doc/refman/5.5/en/connector-odbc-installation-binary-unix.html
Download the latest tar.gz package from the following page:
http://dev.mysql.com/downloads/connector/odbc/#downloads
Unpack the driver into ~/app directory:
1 2 3 | $ cd ~/app $ gunzip -c <tar_file_name>.tar.gz | tar xvf - |
This command creates the connector directory and extracts all needed files in it. Create a symbolic link with a shorter name:
$ ln -s
The latest versions of all the MySQL software can be downloaded from -
Step 4
Configuring ODBC data source for MySQL Connector/ODBC driver is described here:
https://dev.mysql.com/doc/connector-odbc/en/connector-odbc-configuration-dsn-unix.html
So, we will create odbc.ini file in ~/etc:
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 | [myodbc5] Driver = /home/dbs/app/myodbc-x.x.x/lib/libmyodbc5.so Description = Connector/ODBC x.x Driver DSN SERVER = <IP ADDRESS> PORT = <MYSQL PORT NUMBER> USER = mysql_user PASSWORD = ***** DATABASE = test OPTION = 0 TRACE = OFF +---------------------------------------------------------------------------+ | NOTE: Database names are case sensitive in MySQL, so mind what you put | | in DATABASE parameter. 'DATABASE = test' and 'DATABASE = TEST' will point | | to different databases. It may cause an error because of trying to use a | | non-existing database. This error may occur in a system where file names | | are case sensitive (Linux/Unix systems) | | Parameter names, however, are not case sensitive: | | 'DATABASE = test' and 'database = test' are equal. | +---------------------------------------------------------------------------+ |
Step 5 (Optional)
Verifying the ODBC connection using isql command line.
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 | $ export ODBCINI=/home/dbs/etc/odbc.ini $ export LD_LIBRARY_PATH=/home/dbs/app/unixodbc-x.x.x/lib:$LD_LIBRARY_PATH $ cd ~/app/unixodbc-x.x.x/bin/ $ ./isql myodbc5 -v +---------------------------------------+ | Connected! | | | | sql-statement | | help [tablename] | | quit | | | +---------------------------------------+ |
The above output will display if connection has been established successfully. Next, trying to send a simple query to list tables in the database:
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 | SQL> show tables; +-----------------------------------------------------------------+ | Tables_in_test | +-----------------------------------------------------------------+ | tab1 | | tab2 | +-----------------------------------------------------------------+ SQLRowCount returns 2 2 rows fetched |
That was the good scenario when everything went smoothly. However, you might get the following errors:
Error 1:
[IM002][unixODBC][Driver Manager]Data source name not found,
no default driver specified
ISQL]ERROR: Could not SQLConnect
error usually comes if ODBCINI variable is not pointing to the correct
odbc.ini file. To fix this error try:
$ cat $ODBCINI
The command should display the contents of odbc.ini file with all settings we have configured on Step 4. If the file is there and the same error comes again, check the data source name. The parameter name for isql must be exactly the same as the section name in odbc.ini file.
Error 2:
./isql: error while loading shared libraries: libodbc.so.1: cannot open shared object file: No such file or directory This error means that LD_LIBRARY_PATH is set wrong and the linker cannot find the main UnixODBC [Driver Manager] library libodbc.so. The solution is to export the directory containing libodbc.so ito LD_LIBRARY_PATH env variable
as shown at the beginning of Step 5.
The following command must not show failing dependencies:
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 | $ ldd isql linux-vdso.so.1 => (0x00007fffe4ffc000) libodbc.so.1 => /home/dbs/app/unixodbc-2.2.14/lib/libodbc.so.1 (0x00002ae5263e8000) libdl.so.2 => /lib64/libdl.so.2 (0x00000036b1c00000) libreadline.so.5 => /usr/lib64/libreadline.so.5 (0x00000036b1000000) libncurses.so.5 => /usr/lib64/libncurses.so.5 (0x00000036c4400000) libpthread.so.0 => /lib64/libpthread.so.0 (0x00000036b2000000) libc.so.6 => /lib64/libc.so.6 (0x00000036b1400000) /lib64/ld-linux-x86-64.so.2 (0x00000036b0c00000) |
Error 3:
[S1000][unixODBC][MySQL][ODBC 5.1 Driver]Access denied for user 'dbs'@'%'