oracle共享服务器配置汇总
对于共享服务器的配置进行了汇总,也发现一些隐藏的错误
方式一,多种监听(专用连接有专有连接的监听,共享服务有共享服务的监听)
方式二,一种监听,专有和共享的都设定在一个监听上
以下,liste1是专有服务器连接方式,
liste2是专门的共享服务器连接方式
liste3是专有服务和共享服务混合的方式
方式二,一种监听,专有和共享的都设定在一个监听上
以下,liste1是专有服务器连接方式,
liste2是专门的共享服务器连接方式
liste3是专有服务和共享服务混合的方式
listener.ora 配置如下。
LISTE1 =
(ADDRESS_LIST=
(ADDRESS=(PROTOCOL=tcp)(HOST=oel1.oracle.com)(PORT=1521))
)
LISTE1 =
(ADDRESS_LIST=
(ADDRESS=(PROTOCOL=tcp)(HOST=oel1.oracle.com)(PORT=1521))
)
SID_LIST_LISTE1=
(SID_LIST=
(SID_DESC=
(GLOBAL_DBNAME=PROD.oracle.com)
(SID_NAME=PROD)
(ORACLE_HOME=/u01/app/oracle/product/10.2.0/db_1)
)
)
(SID_LIST=
(SID_DESC=
(GLOBAL_DBNAME=PROD.oracle.com)
(SID_NAME=PROD)
(ORACLE_HOME=/u01/app/oracle/product/10.2.0/db_1)
)
)
LISTE2 =
(ADDRESS_LIST=
(ADDRESS=(PROTOCOL=tcp)(HOST=oel1.oracle.com)(PORT=1529))
)
SID_LIST_LISTE2=
(SID_LIST=
(SID_DESC=
(GLOBAL_DBNAME=PROD.oracle.com)
(SID_NAME=PROD)
(ORACLE_HOME=/u01/app/oracle/product/10.2.0/db_1)
)
)
(ADDRESS_LIST=
(ADDRESS=(PROTOCOL=tcp)(HOST=oel1.oracle.com)(PORT=1529))
)
SID_LIST_LISTE2=
(SID_LIST=
(SID_DESC=
(GLOBAL_DBNAME=PROD.oracle.com)
(SID_NAME=PROD)
(ORACLE_HOME=/u01/app/oracle/product/10.2.0/db_1)
)
)
LISTE3 =
(ADDRESS_LIST=
(ADDRESS=(PROTOCOL=tcp)(HOST=oel1.oracle.com)(PORT=1520))
(ADDRESS=(PROTOCOL=tcp)(HOST=oel1.oracle.com)(PORT=1530))
)
(ADDRESS_LIST=
(ADDRESS=(PROTOCOL=tcp)(HOST=oel1.oracle.com)(PORT=1520))
(ADDRESS=(PROTOCOL=tcp)(HOST=oel1.oracle.com)(PORT=1530))
)
SID_LIST_LISTE3=
(SID_LIST=
(SID_DESC=
(GLOBAL_DBNAME=PROD.oracle.com)
(SID_NAME=PROD)
(ORACLE_HOME=/u01/app/oracle/product/10.2.0/db_1)
)
)
(SID_LIST=
(SID_DESC=
(GLOBAL_DBNAME=PROD.oracle.com)
(SID_NAME=PROD)
(ORACLE_HOME=/u01/app/oracle/product/10.2.0/db_1)
)
)
tnsnames.ora 文件配置如下
--配置了多个端口的专用服务连接
PROD =
(DESCRIPTION =
(ADDRESS_LIST =
(ADDRESS = (PROTOCOL = tcp)(HOST = oel1.oracle.com)(PORT = 1520))
(ADDRESS = (PROTOCOL = tcp)(HOST = oel1.oracle.com)(PORT = 1521))
)
(CONNECT_DATA =
(SERVICE_NAME = PROD.oracle.com)
)
)
--配置了共享服务连接
SPROD =
(DESCRIPTION =
(ADDRESS_LIST =
(ADDRESS = (PROTOCOL = tcp)(HOST = oel1.oracle.com)(PORT = 1529))
)
(CONNECT_DATA =
(SERVICE_NAME = PROD.oracle.com)
(SERVER=SHARED)
)
)
--配置共享服务连接,验证可以有多个共享服务器并存
XPROD =
(DESCRIPTION =
(ADDRESS_LIST =
(ADDRESS = (PROTOCOL = tcp)(HOST = oel1.oracle.com)(PORT = 1530))
)
(CONNECT_DATA =
(SERVICE_NAME = PROD.oracle.com)
(SERVER=SHARED)
)
)
--配置了多个端口的专用服务连接
PROD =
(DESCRIPTION =
(ADDRESS_LIST =
(ADDRESS = (PROTOCOL = tcp)(HOST = oel1.oracle.com)(PORT = 1520))
(ADDRESS = (PROTOCOL = tcp)(HOST = oel1.oracle.com)(PORT = 1521))
)
(CONNECT_DATA =
(SERVICE_NAME = PROD.oracle.com)
)
)
--配置了共享服务连接
SPROD =
(DESCRIPTION =
(ADDRESS_LIST =
(ADDRESS = (PROTOCOL = tcp)(HOST = oel1.oracle.com)(PORT = 1529))
)
(CONNECT_DATA =
(SERVICE_NAME = PROD.oracle.com)
(SERVER=SHARED)
)
)
--配置共享服务连接,验证可以有多个共享服务器并存
XPROD =
(DESCRIPTION =
(ADDRESS_LIST =
(ADDRESS = (PROTOCOL = tcp)(HOST = oel1.oracle.com)(PORT = 1530))
)
(CONNECT_DATA =
(SERVICE_NAME = PROD.oracle.com)
(SERVER=SHARED)
)
)
--配置dispatcher
SQL> show parameter dispatch
NAME TYPE VALUE
------------------------------------ ----------- ------------------------------
dispatchers string (protocol=tcp)(service=PROD.or
acle.com)(dispatchers=2)
max_dispatchers integer 2
--根据需要来配置共享服务的参数。当然session,processes也需要相应的设置,如果值太小,共享服务连接就会很慢。
------------------------------------ ----------- ------------------------------
dispatchers string (protocol=tcp)(service=PROD.or
acle.com)(dispatchers=2)
max_dispatchers integer 2
--根据需要来配置共享服务的参数。当然session,processes也需要相应的设置,如果值太小,共享服务连接就会很慢。
SQL> show parameter shared
NAME TYPE VALUE
------------------------------------ ----------- ------------------------------
hi_shared_memory_address integer 0
max_shared_servers integer 2
shared_memory_address integer 0
shared_pool_reserved_size big integer 4404019
shared_pool_size big integer 0
shared_server_sessions integer 50
shared_servers integer 1
------------------------------------ ----------- ------------------------------
hi_shared_memory_address integer 0
max_shared_servers integer 2
shared_memory_address integer 0
shared_pool_reserved_size big integer 4404019
shared_pool_size big integer 0
shared_server_sessions integer 50
shared_servers integer 1
--配置本地监听
!!!如果配置的共享服务时非默认监听Listeners,默认端口1521,则需要在local listener中注册。
因为我建了两个监听liste2,liste3,所以把它们的端口信息都注册进去
alter system set local_listener='(address_list=(address=(protocol=tcp)(host=oel1.oracle.com)(port=1529))(address=(protocol=tcp)(host=oel1.oracle.com)(port=1530)))';
!!!如果配置的共享服务时非默认监听Listeners,默认端口1521,则需要在local listener中注册。
因为我建了两个监听liste2,liste3,所以把它们的端口信息都注册进去
alter system set local_listener='(address_list=(address=(protocol=tcp)(host=oel1.oracle.com)(port=1529))(address=(protocol=tcp)(host=oel1.oracle.com)(port=1530)))';
SQL> show parameter local_lis
NAME TYPE VALUE
------------------------------------ ----------- ------------------------------
local_listener string (address_list=(address=(protoc
l=tcp)(host=oel1.oracle.com)(
port=1529))(address=(protocol=
tcp)(host=oel1.oracle.com)(por
t=1530)))
-启动监听
LSNRCTL> start liste1
------------------------------------ ----------- ------------------------------
local_listener string (address_list=(address=(protoc
l=tcp)(host=oel1.oracle.com)(
port=1529))(address=(protocol=
tcp)(host=oel1.oracle.com)(por
t=1530)))
-启动监听
LSNRCTL> start liste1
LSNRCTL> start liste2
LSNRCTL> start liste3
--查看共享服务是否配置正常。加粗的地方因为起了2个dispatcher,所以有2个D开头的handlers.
LSNRCTL> service liste3
Connecting to (ADDRESS=(PROTOCOL=tcp)(HOST=oel1.oracle.com)(PORT=1520))
Services Summary...
Service "PROD.oracle.com" has 2 instance(s).
Instance "PROD", status UNKNOWN, has 1 handler(s) for this service...
Handler(s):
"DEDICATED" established:0 refused:0
LOCAL SERVER
Instance "PROD", status READY, has 3 handler(s) for this service...
Handler(s):
"D001" established:0 refused:0 current:0 max:972 state:ready
DISPATCHER < oel1 pid:>
(ADDRESS=(PROTOCOL=tcp)(HOST=oel1.oracle.com)(PORT=46966))
"D000" established:0 refused:0 current:0 max:972 state:ready
DISPATCHER < oel1 pid:>
(ADDRESS=(PROTOCOL=tcp)(HOST=oel1.oracle.com)(PORT=57952))
"DEDICATED" established:0 refused:0 state:ready
LOCAL SERVER
Service "PROD_XPT.oracle.com" has 1 instance(s).
Instance "PROD", status READY, has 1 handler(s) for this service...
Handler(s):
"DEDICATED" established:0 refused:0 state:ready
LOCAL SERVER
The command completed successfully >>
LSNRCTL> service liste3
Connecting to (ADDRESS=(PROTOCOL=tcp)(HOST=oel1.oracle.com)(PORT=1520))
Services Summary...
Service "PROD.oracle.com" has 2 instance(s).
Instance "PROD", status UNKNOWN, has 1 handler(s) for this service...
Handler(s):
"DEDICATED" established:0 refused:0
LOCAL SERVER
Instance "PROD", status READY, has 3 handler(s) for this service...
Handler(s):
"D001" established:0 refused:0 current:0 max:972 state:ready
DISPATCHER < oel1 pid:>
(ADDRESS=(PROTOCOL=tcp)(HOST=oel1.oracle.com)(PORT=46966))
"D000" established:0 refused:0 current:0 max:972 state:ready
DISPATCHER < oel1 pid:>
(ADDRESS=(PROTOCOL=tcp)(HOST=oel1.oracle.com)(PORT=57952))
"DEDICATED" established:0 refused:0 state:ready
LOCAL SERVER
Service "PROD_XPT.oracle.com" has 1 instance(s).
Instance "PROD", status READY, has 1 handler(s) for this service...
Handler(s):
"DEDICATED" established:0 refused:0 state:ready
LOCAL SERVER
The command completed successfully >>
--测试一把
[oracle@oel1 admin]$ sqlplus sys/oracle@XPROD as sysdba
Connected to:
Oracle Database 10g Enterprise Edition Release 10.2.0.1.0 - Production
With the Partitioning, OLAP and Data Mining options
SQL>
--判断连接session是否接入了共享服务
[oracle@oel1 admin]$ sqlplus sys/oracle@SPROD as sysdba
[oracle@oel1 admin]$ sqlplus sys/oracle@SPROD as sysdba
SQL*Plus: Release 10.2.0.1.0 - Production on Fri Oct 26 20:37:34 2012
Copyright (c) 1982, 2005, Oracle. All rights reserved.
Connected to:
Oracle Database 10g Enterprise Edition Release 10.2.0.1.0 - Production
With the Partitioning, OLAP and Data Mining options
SQL> select sid,server from v$session where sid=(select sid from v$mystat where rownum
--使用端口连接来确认Liste1,liste3的两个端口都可以正常访问
[oracle@oel1 admin]$ sqlplus sys/oracle@oel1.oracle.com:1520/PROD.oracle.com as sysdba
Connected to:
Oracle Database 10g Enterprise Edition Release 10.2.0.1.0 - Production
With the Partitioning, OLAP and Data Mining options
[oracle@oel1 admin]$ sqlplus sys/oracle@oel1.oracle.com:1521/PROD.oracle.com as sysdba
Connected to:
Oracle Database 10g Enterprise Edition Release 10.2.0.1.0 - Production
With the Partitioning, OLAP and Data Mining options
LSNRCTL> service liste1
Connecting to (ADDRESS=(PROTOCOL=tcp)(HOST=oel1.oracle.com)(PORT=1521))
Services Summary...
Service "PROD.oracle.com" has 2 instance(s).
Instance "PROD", status UNKNOWN, has 1 handler(s) for this service...
Handler(s):
"DEDICATED" established:8 refused:0
LOCAL SERVER
Instance "PROD", status READY, has 3 handler(s) for this service...
Handler(s):
"D001" established:0 refused:0 current:0 max:972 state:ready
DISPATCHER < oel1 pid:>
(ADDRESS=(PROTOCOL=tcp)(HOST=oel1.oracle.com)(PORT=46966))
"D000" established:0 refused:0 current:0 max:972 state:ready
DISPATCHER < oel1 pid:>
(ADDRESS=(PROTOCOL=tcp)(HOST=oel1.oracle.com)(PORT=57952))
"DEDICATED" established:0 refused:0 state:ready
LOCAL SERVER
Service "PROD_XPT.oracle.com" has 1 instance(s).
Instance "PROD", status READY, has 1 handler(s) for this service...
Handler(s):
"DEDICATED" established:0 refused:0 state:ready
LOCAL SERVER
The command completed successfully
LSNRCTL> service liste2
Connecting to (ADDRESS=(PROTOCOL=tcp)(HOST=oel1.oracle.com)(PORT=1529))
Services Summary...
Service "PROD.oracle.com" has 1 instance(s).
Instance "PROD", status UNKNOWN, has 1 handler(s) for this service...
Handler(s):
"DEDICATED" established:0 refused:0
LOCAL SERVER
The command completed successfully >>
SID SERVER
---------- ---------
160 SHARED
---------- ---------
160 SHARED
--使用端口连接来确认Liste1,liste3的两个端口都可以正常访问
[oracle@oel1 admin]$ sqlplus sys/oracle@oel1.oracle.com:1520/PROD.oracle.com as sysdba
SQL*Plus: Release 10.2.0.1.0 - Production on Fri Oct 26 20:44:38 2012
Copyright (c) 1982, 2005, Oracle. All rights reserved.
Connected to:
Oracle Database 10g Enterprise Edition Release 10.2.0.1.0 - Production
With the Partitioning, OLAP and Data Mining options
[oracle@oel1 admin]$ sqlplus sys/oracle@oel1.oracle.com:1521/PROD.oracle.com as sysdba
SQL*Plus: Release 10.2.0.1.0 - Production on Fri Oct 26 20:45:12 2012
Copyright (c) 1982, 2005, Oracle. All rights reserved.
Connected to:
Oracle Database 10g Enterprise Edition Release 10.2.0.1.0 - Production
With the Partitioning, OLAP and Data Mining options
SQL>
--共享服务器关闭失败,所以在做data guard等场景时,不适合用共享服务器模式
SQL> shut immediate
ORA-00106: cannot startup/shutdown database when connected to a dispatcher
SQL>
SQL> shut immediate
ORA-00106: cannot startup/shutdown database when connected to a dispatcher
SQL>
--复现共享服务绑定监听错误的情况
--把本地监听设置为空
SQL> alter system set local_listener='';
--把本地监听设置为空
SQL> alter system set local_listener='';
System altered.
LSNRCTL> service liste1
Connecting to (ADDRESS=(PROTOCOL=tcp)(HOST=oel1.oracle.com)(PORT=1521))
Services Summary...
Service "PROD.oracle.com" has 2 instance(s).
Instance "PROD", status UNKNOWN, has 1 handler(s) for this service...
Handler(s):
"DEDICATED" established:8 refused:0
LOCAL SERVER
Instance "PROD", status READY, has 3 handler(s) for this service...
Handler(s):
"D001" established:0 refused:0 current:0 max:972 state:ready
DISPATCHER < oel1 pid:>
(ADDRESS=(PROTOCOL=tcp)(HOST=oel1.oracle.com)(PORT=46966))
"D000" established:0 refused:0 current:0 max:972 state:ready
DISPATCHER < oel1 pid:>
(ADDRESS=(PROTOCOL=tcp)(HOST=oel1.oracle.com)(PORT=57952))
"DEDICATED" established:0 refused:0 state:ready
LOCAL SERVER
Service "PROD_XPT.oracle.com" has 1 instance(s).
Instance "PROD", status READY, has 1 handler(s) for this service...
Handler(s):
"DEDICATED" established:0 refused:0 state:ready
LOCAL SERVER
The command completed successfully
LSNRCTL> service liste2
Connecting to (ADDRESS=(PROTOCOL=tcp)(HOST=oel1.oracle.com)(PORT=1529))
Services Summary...
Service "PROD.oracle.com" has 1 instance(s).
Instance "PROD", status UNKNOWN, has 1 handler(s) for this service...
Handler(s):
"DEDICATED" established:0 refused:0
LOCAL SERVER
The command completed successfully >>
SQL*Plus: Release 10.2.0.1.0 - Production on Fri Oct 26 20:34:44 2012
Copyright (c) 1982, 2005, Oracle. All rights reserved.
ERROR:
ORA-12523: TNS:listener could not find instance appropriate for the client
connection
所以本地监听的配置是必须的。
ORA-12523: TNS:listener could not find instance appropriate for the client
connection
所以本地监听的配置是必须的。