LATEST TOPICS

Creating Oracle Database Link with EZCONNECT (Easy Connect)

EZCONNECT (Easy Connect) is there for a long time. However, learned something new today about it; that it can be used to create database links. Hence, thought a post on it would be helpful for others like me who are not aware about it.

What’s EZCONNECT

EZCONNECT is a naming method that can be used to connect to a Oracle database without the need of maintaining TNS entries on the client side i.e. it dosen’t require the client to perform a service name lookup from the TNS_ADMIN/LDAP location.

EZCONNECT was first introduced in Oracle version 10g (10.2) and it remains the same till the latest Oracle version 12c.

The EZCONNECT string has the following format.

-------
[//]host[:port][/service_name]
-------
Field Description
// Required for a URL. Otherwise optional
host Mandatory value: Specify the hostname or IP address of the database server to connect with
port Optional value: Defaults to 1521. Specify if database is listening to a PORT other than the default
service_name Optional value: Specify the database service name to be used to connect with database. If omitted, the value defaults to host of the database server.

DB Link with EZCONNECT

Now, Let me demonstrate with a simple example, how to use the EZCONNECT for creating a DB Link. We would be using the following standard DB Link syntax.

CREATE [ SHARED ] [ PUBLIC ] DATABASE LINK dblink
  [ CONNECT TO
    { CURRENT_USER
    | user IDENTIFIED BY password [ dblink_authentication ]
    }
  | dblink_authentication
  ]
  [ USING connect_string ] ;

However, we would be replacing the connect_string with the EZCONNECT string rather than using a TNS alias or a fully qualified TNS connect string.

Demonstration

I am creating a DB Link in the database orl001 which is on server mylab.oraclebuffer.com. This DB Link will connect to the database orlbcp01 which is on server mybcp.oraclebuffer.com.

SQL> select instance_name,host_name from v$instance;

INSTANCE_N HOST_NAME
---------- ---------------------------
orl001     mylab.oraclebuffer.com

SQL> create public database link orlbcp01_lnk connect to myapp 
identified by myapp using '//mybcp.oraclebuffer.com:1521/orlbcp01';

Database link created.

As we can see, we were allowed to create the DB Link with the EZCONNECT string. This method of creating DB Link doesn’t require us to maintain TNS alias on the database server hosting the DB Link.

Now, lets validate our DB Link whether it is working or not.

SQL> select * from dba_db_links where db_link='ORLBCP01_LNK';

OWNER      DB_LINK         USERNAME   HOST                                     CREATED
---------- --------------- ---------- ---------------------------------------- ---------
PUBLIC     ORLBCP01_LNK    MYAPP      //mybcp.oraclebuffer.com:1521/orlbcp01   22-MAY-15

--------
-------- query v$instance using DB Link ORLBCP01_LNK
SQL> select instance_name,host_name from v$instance@ORLBCP01_LNK;
select instance_name,host_name from v$instance@ORLBCP01_LNK
                                               *
ERROR at line 1:
ORA-12154: TNS:could not resolve the connect identifier specified

Though we were allowed to create DB link with EZCONNECT, somehow it is not working for us.

Lets find out why? We have missed a fundamental requirement of using EZCONNECT. In order to be able to use EZCONNECT, we need to enable the EZCONNECT naming method on the client side using NAMES.DIRECTORY_PATH in sqlnet.ora file.

In my case, EZCONNECT naming method is not enabled on the database server hosting the DB Link.

[oracle@mylab admin]$ hostname
mylab.oraclebuffer.com
[oracle@mylab admin]$ cat sqlnet.ora
NAMES.DIRECTORY_PATH=(tnsnames)

Lets enable the EZCONNECT naming method as follows

NAMES.DIRECTORY_PATH=(tnsnames,EZCONNECT)

Lets try again to see if the DB Link is working now.

SQL> select * from dba_db_links where db_link='ORLBCP01_LNK';

OWNER      DB_LINK         USERNAME   HOST                                     CREATED
---------- --------------- ---------- ---------------------------------------- ---------
PUBLIC     ORLBCP01_LNK    MYAPP      //mybcp.oraclebuffer.com:1521/orlbcp01   22-MAY-15

--------
-------- query v$instance using DB Link ORLBCP01_LNK
SQL> select instance_name,host_name from v$instance@ORLBCP01_LNK;

INSTANCE_NAME    HOST_NAME
---------------- ---------------------------
orlbcp01         mybcp.oraclebuffer.com

As expected, the DB Link is now working fine with EZCONNECT !!

Reference:

http://blog.tanelpoder.com/2012/03/05/create-a-database-link-with-the-new-hostportservice-syntax/

%d bloggers like this:
Visit Us On LinkedinVisit Us On TwitterVisit Us On Google PlusCheck Our Feed