DB_LINK w/o tnsnames.ora
A question popped up, which I thought was interesting. How can you create a DB_LINK
in Oracle without the DBA changing the tnsnames.ora
file? It’s actually quite easy, especially if the DBA sets the TNS address name the same as the instance’s service name or in older databases SID value.
- Do the following with the
tnsping
utility:tnsping mohawk
It should return this when the server’s
hostname
ismohawk
and domain name istechtinker.com
:TNS Ping Utility for Linux: Version 11.2.0.2.0 - Production on 26-JUL-2016 16:55:58 Copyright (c) 1997, 2011, Oracle. All rights reserved. Used parameter files: Used TNSNAMES adapter to resolve the alias Attempting to contact (DESCRIPTION = (ADDRESS = (PROTOCOL = TCP)(HOST = mohawk.techtinker.com)(PORT = 1521)) (CONNECT_DATA = (SERVER = DEDICATED) (SERVICE_NAME = ORCL))) OK (10 msec)
- You can now create a
DB_LINK
in another Oracle instance without atnsnames.ora
entry by referencing the type of server connection and service name with the following syntax (please note that you should remove extraneous white space):CREATE DATABASE LINK test CONNECT TO student IDENTIFIED BY student USING '(DESCRIPTION=(ADDRESS=(PROTOCOL=tcp)(HOST=mohawk.techtinker.com)(PORT=1521))(CONNECT_DATA=(SERVER=DEDICATED)(SERVICE_NAME=ORCL)))'
In an older database version, you may need to refer to the
SID
, like this:CREATE DATABASE LINK test CONNECT TO student IDENTIFIED BY student USING '(DESCRIPTION=(ADDRESS=(PROTOCOL=tcp)(HOST=mohawk.techtinker.com)(PORT=1521))(CONNECT_DATA=(SERVER=DEDICATED)(SID=ORCL)))'
Then, you can query a contact table in the remote instance like this:
SELECT COUNT(*) FROM contact@test;
As always, I hope this helps somebody trying to solve a problem.