To access to Oracle databases using nicknames:
step 1. | Install and configure the Oracle client software on the DB2 federated server using the documentation provided by Oracle. You can use either SQL*Net or Net8 to access both Oracle Version 7 and Oracle Version 8 data sources.
| ||||||||||||||||
step 2. | For DB2 federated servers running on UNIX platforms, run the db2djlink.sh script to link-edit the Oracle SQL*Net or Net8 libraries to your DB2 federated server. The db2djlink.sh script is located in /install_directory/lib. Run this script only after installing Oracle's client software on the DB2 federated server. | ||||||||||||||||
step 3. | Set data source environment variables by modifying the DB2DJ.ini file and issuing the db2set command. The db2set command updates the DB2 profile registry with your settings. The DB2DJ.ini file contains configuration information about the
Oracle client software installed on your federated server. In a
multiple parallel processing (MPP) environment, you can use a single
DB2DJ.ini file for all nodes in a particular instance, or you can use a
unique DB2DJ.ini file for one or more nodes in a particular
instance. In a non-MPP environment, there can be only one
DB2DJ.ini file per instance.
| ||||||||||||||||
step 4. | Ensure that the SQL*Net or Net8 tnsnames.ora file is updated for each Oracle server to which communications are configured. Within the tnsnames.ora file, the SID is the name of the Oracle instance, and the HOST is the host name where the Oracle server is located. | ||||||||||||||||
Recycle the DB2 instance:
| |||||||||||||||||
step 6. | Use the CREATE WRAPPER statement to define the wrapper library that will be used to access Oracle data sources. Wrappers are the mechanism that federated servers use to communicate with and retrieve data from data sources. The following example shows a CREATE WRAPPER statement: CREATE WRAPPER SQLNET where SQLNET is the default name of the wrapper module used with Oracle's SQL*Net client software. If using Oracle's Net8 client software, use NET8. You can substitute the default name with a name that you choose; however, if you do so, you also must include the LIBRARY parameter and the name of the wrapper library for your DB2 server platform. See the Administration Guide, Design and Implementation for more information about wrapper library names. | ||||||||||||||||
step 7. | Optional: Set the DB2_DJ_COMM environment variable to include the wrapper library that corresponds to the wrapper module that you created in the previous step; for example: db2set DB2_DJ_COMM = libsqlnet.a The DB2_DJ_COMM environment variable controls whether a wrapper module is loaded when the federated server initializes, which can result in improved performance when the Oracle data source is first accessed. See the Administration Guide, Design and Implementation for more information about wrapper library names. | ||||||||||||||||
step 8. | Use the CREATE SERVER statement to define each Oracle server to which communications are configured; for example: CREATE SERVER ORASERVER TYPE ORACLE VERSION '7.2' WRAPPER SQLNET OPTIONS (NODE "oranode") where:
| ||||||||||||||||
If a user ID or password at the federated server is different from a user ID or password at an Oracle data source, use the CREATE USER MAPPING statement to map the local user ID to the user ID and password defined at the Oracle data source; for example: CREATE USER MAPPING FOR DB2USER TO SERVER ORASERVER OPTIONS ( REMOTE_AUTHID "orauser", REMOTE_PASSWORD "dayl1te") where:
| |||||||||||||||||
Use the CREATE NICKNAME statement to assign a nickname to a view or table located at your Oracle data source. You will use this nickname when you query the Oracle data source. The following example shows a CREATE NICKNAME statement: CREATE NICKNAME ORASALES FOR ORASERVER.SALESDATA.MIDWEST where:
| |||||||||||||||||
step 11. | Repeat the previous step for all database objects that you want create nicknames for. | ||||||||||||||||
step 12. | For each HOST in the DESCRIPTION section of the tnsnames.ora file, update /etc/hosts for UNIX servers and the TCP/IP hosts file for Windows NT servers if necessary. Whether you must update /etc/hosts or the TCP/IP hosts file depends on how TCP/IP is configured on your network. Part of the network must translate the remote host name specified in the DESCRIPTION section in the tnsnames.ora file ("oranode" in the example) to an address. If your network has a name server that recognizes the host name, you do not need to update /etc/hosts or the TCP/IP hosts file. Otherwise, you need an entry for the remote host. See your network administrator to determine how your network is configured.
|
| If you need more information about Oracle code page mappings, continue to
Oracle Code Page Options.
To verify that you successfully configured your federated server to access data sources, go to Verifying Connections to Oracle Data Sources. |