假设我们要在ORACLE里同时能访问SQL Server里默认的pubs和Northwind两个数据库。
可参考最初写的通过异构服务链接oracle 和sql server 数据库
1、在安装了ORACLE9i Standard Edition或者ORACLE9i Enterprise Edition的windows机器上(IP:192.168.0.1),
产品要选了透明网关( Transparent Gateway)里要访问Microsoft SQL Server数据库.
$ORACLE9I_HOME\tg4msql\admin下新写initpubs.ora和initnorthwind.ora配置文件
initpubs.ora内容如下:
HS_FDS_CONNECT_INFO="SERVER=sqlserver_hostname;DATABASE=pubs"
HS_DB_NAME=pubs
HS_FDS_TRACE_LEVEL=OFF
HS_FDS_RECOVERY_ACCOUNT=RECOVER
HS_FDS_RECOVERY_PWD=RECOVER
initnorthwind.ora内容如下:
HS_FDS_CONNECT_INFO="SERVER=sqlserver_hostname;DATABASE=Northwind"
HS_DB_NAME=Northwind
HS_FDS_TRACE_LEVEL=OFF
HS_FDS_RECOVERY_ACCOUNT=RECOVER
HS_FDS_RECOVERY_PWD=RECOVER
(蓝色字的部分可以根据具体要访问的SQL Server数据库的情况而修改)
$ORACLE9I_HOME\network\admin 下listener.ora内容如下:
LISTENER =
(DESCRIPTION_LIST =
(DESCRIPTION =
(ADDRESS_LIST =
(ADDRESS = (PROTOCOL = TCP)(HOST = 192.168.0.1)(PORT = 1521))
)
)
)
SID_LIST_LISTENER =
(SID_LIST =
(SID_DESC =
(GLOBAL_DBNAME = test9)
(ORACLE_HOME = d:\oracle\ora92)
(SID_NAME = test9)
)
(SID_DESC=
(SID_NAME=pubs)
(ORACLE_HOME=d:\\Ora92)
(PROGRAM=tg4msql)
)
(SID_DESC=
(SID_NAME=northwind)
(ORACLE_HOME=d:\Oracle\Ora92)
(PROGRAM=tg4msql)
)
)
重启动这台做gateway的windows机器上(IP:192.168.0.1)TNSListener服务.
(凡是按此步骤新增可访问的SQL Server数据库时,TNSListener服务都要重启动)
2、ORACLE8I,ORACLE9I的端配置tnsnames.ora, 添加下面的内容:
pubs =
(DESCRIPTION =
(ADDRESS_LIST =
(ADDRESS = (PROTOCOL = TCP)(HOST = 192.168.0.2)(PORT = 1521))
)
(CONNECT_DATA =
(SID = pubs)
)
(HS = pubs)
)
northwind =
(DESCRIPTION =
(ADDRESS_LIST =
(ADDRESS = (PROTOCOL = TCP)(HOST = 192.168.0.2)(PORT = 1521))
)
(CONNECT_DATA =
(SID = northwind)
)
(HS = northwind)
)
保存tnsnames.ora后,在命令行下
tnsping pubs
tnsping northwind
出现类似提示,即为成功
Attempting to contact (DESCRIPTION = (ADDRESS_LIST = (ADDRESS = (PROTOCOL = TCP)(HOST = 192.168.0.2)
(PORT = 1521))) (CONNECT_DATA = (SID = pubs)) (HS = pubs))
OK(20毫秒)
Attempting to contact (DESCRIPTION = (ADDRESS_LIST = (ADDRESS = (PROTOCOL = TCP)(HOST = 192.168.0.2)
(PORT = 1521))) (CONNECT_DATA = (SID = northwind)) (HS = northwind))
OK(20毫秒)
设置数据库参数global_names=false。
设置global_names=false不要求建立的数据库链接和目的数据库的全局名称一致。
global_names=true则要求, 多少有些不方便。
oracle9i和oracle8i都可以在DBA用户下用SQL命令改变global_names参数
alter system set global_names=false;
建立公有的数据库链接:
create public database link pubs connect to testuser identified by testuser_pwd using 'pubs';
create public database link northwind connect to testuser identified by testuser_pwd using 'northwind';
(假设SQL Server下pubs和northwind已有足够权限的用户登录testuser,密码为testuser_pwd)
访问SQL Server下数据库里的数据:
select * from stores@pubs;
...... ......
select * from region@northwind;
...... ......
使用sql *plus copy命令从本地数据库复制暑假到MS SQL SERVER中:
copy from scott/tiger@myoracle insert EMP@pubs using select * from EMP
3、使用时的注意事项
ORACLE通过访问SQL Server的数据库链接时,用select * 的时候字段名是用双引号引起来的。
例如:
create table stores as select * from stores@pubs;
select zip from stores;
ERROR 位于第 1 行:
ORA-00904: 无效列名
select "zip" from stores;
zip
-----
98056
92789
96745
98014
90019
89076
已选择6行。
用SQL Navigator或Toad看从SQL Server转移到ORACLE里的表的建表语句为:
CREATE TABLE stores
("stor_id" CHAR(4) NOT NULL,
"stor_name" VARCHAR2(40),
"stor_address" VARCHAR2(40),
"city" VARCHAR2(20),
"state" CHAR(2),
"zip" CHAR(5))
PCTFREE 10
PCTUSED 40
INITRANS 1
MAXTRANS 255
TABLESPACE users
STORAGE (
INITIAL 131072
NEXT 131072
PCTINCREASE 0
MINEXTENTS 1
MAXEXTENTS 2147483645
)
/
总结: WINDOWS下ORACLE9i网关服务器在$ORACLE9I_HOME\tg4msql\admin目录下的initsqlserver_databaseid.ora
WINDOWS下ORACLE9i网关服务器listener.ora里面
(SID_DESC=
(SID_NAME=sqlserver_databaseid)
(ORACLE_HOME=d:\Oracle\Ora92)
(PROGRAM=tg4msql)
)
UNIX或WINDOWS下ORACLE8I,ORACLE9I服务器tnsnames.ora里面
northwind =
(DESCRIPTION =
(ADDRESS_LIST =
(ADDRESS = (PROTOCOL = TCP)(HOST = 192.168.0.2)(PORT = 1521))
)
(CONNECT_DATA =
(SID = sqlserver_databaseid)
)
(HS = sqlserver_databaseid)
)
sqlserver_databaseid一致才行.
【责编:admin】
--------------------next---------------------