虚拟化容器,大数据,DBA,中间件,监控。

配置 RAC 负载均衡与故障转移

24 03月
作者:admin|分类:DBA运维
Oracle负载均衡主要是指新会话连接到RAC数据库时,如何判定这个新的连接要连到哪个节点进行工作?通常情况下,负载均衡分为客户端负载
均衡与服务器端负载均衡。客户端负载均衡通常是在客户端的tnsnames.ora中多添加一个链接地址以及LOAD_BALANCE与failover参数。而服务器
端的负载均衡则相对复杂,下面具体描述服务器端负载均衡。
    
一、负载均衡
    注意这里的负载均衡指的是连接的负载均衡,即客户可以随机从不同的实例中连接到数据库
    1.配置tnsnames.ora使得该文件中包含如下全部内容:       
  1. # LISTENERS_DEVDB DEVDB是数据库名,可以使用netmgr,netca编辑或直接使用Vim创建  
  2. LISTENERS_DEVDB =                                                             
  3.   (ADDRESS_LIST =                                                             
  4.     (ADDRESS = (PROTOCOL = TCP)(HOST = rac1-vip.robinson.com)(PORT = 1521))     
  5.     (ADDRESS = (PROTOCOL = TCP)(HOST = rac2-vip.robinson.com)(PORT = 1521))     
  6.   )                                                                           
    2.配置参数文件remote_listener         
  1. SQL> alter system set remote_listener='LISTENERS_DEVDB' scope=both sid='*';   
    3.需要配置连接描述信息的两个IP地址、端口号、以及load_balance子项为yes (主要是load_balance子项)      
  1. DEVDB =                                                                         
  2.   (DESCRIPTION =                                                                
  3.     (ADDRESS = (PROTOCOL = TCP)(HOST = rac1-vip.robinson.com)(PORT = 1521))       
  4.     (ADDRESS = (PROTOCOL = TCP)(HOST = rac2-vip.robinson.com)(PORT = 1521))       
  5.     (LOAD_BALANCE = yes)                                                          
  6.     (CONNECT_DATA =                                                               
  7.       (SERVER = DEDICATED)                                                        
  8.       (SERVICE_NAME = devdb.robinson.com)                                         
  9.     )                                                                             
  10.   )                                                                             
    4.查看侦听器的状态,从下面可以看到devdb.robinson.com服务中有两个实例为其提供服务     
  1. [oracle@rac2 ~]$ lsnrctl status                                                  
  2.     Service "devdb.robinson.com" has 2 instance(s).                                
  3.       Instance "devdb1", status READY, has 1 handler(s) for this service...        
  4.       Instance "devdb2", status READY, has 2 handler(s) for this service...        
    5.测试负载均衡
    使用shell脚本来进行测试负载均衡     
  1. --编辑TestLoadBalance.sh                                                                            
  2.     #!/bin/bash                                                                                       
  3.     #Usage: TestLoadBalance devdb 1000                                                                
  4.     count=0                                                                                           
  5.     while [ $count -lt $2 ]   # Set up a loop control                                                 
  6.     do                        # Begin the loop                                                        
  7.         count='expr $count + 1' # Increment the counter                                                 
  8.         sqlplus -s usr1/usr1pwd@$1 @TestLoadBalance.sql  # Connect instance and execute sql statement   
  9.         sleep 1                                                                                         
  10.     done                                                                                              
  11.                                                                                                     
  12. --TestLoadBalance.sql 脚本                                                                          
  13.     col instance_name format a30                                                                      
  14.     select instance_name from v$instance;                                                             
  15.                                                                                                     
  16. --实施测试                                                                                          
  17.     ./TestLoadBalance.sh devdb 1000                                                                   
  18.                                                                                                       
  19. --查看结果                                                                                          
  20.     SQL> select inst_id,count(1) from gv$instance group by inst_d;                                                    
  21.                                                                                                       
  22.     INST_ID       COUNT(1)                                                                            
  23.     ----------    ----------                                                                          
  24.     devdb1        446                                                                                 
  25.     devdb2        554                                                                                 
二、配置故障转移
    负载均衡是用于实现基于连接的负载均衡,但不能解决节点是否可用,一旦一个节点损坏,已成功连接的客户端并不能转移到其他正常服务的
    实例中。而故障转移功能则使得该功能得以实现。可以使用srvctl 和dbca来创建服务。下面使用dbca来创建一个新的服务,客户端连接到实
    例后,对故障实现透明切换。
    
    1.配置故障转移服务
        在节点rac1使用oracle帐户启动dbca工具,
            a.选择 Oracle Real Application Clusters database
            b.选择 Services Management
            c.集群数据库列表:单击 Next。
            d.数据库服务:单击 Add。
                添加服务:输入sales。
                选择 devdb1 作为首选实例。
                选择 devdb2 作为可用实例。
                TAF 策略:选择 Basic。
                单击 Finish。
            e.数据库配置助手:单击 No 退出。
        配置完毕后,在tnsnames.ora中多出了以下内容,注意是各个节点都会多出以下内容           
  1. SALES =                                                                      
  2.   (DESCRIPTION =                                                             
  3.     (ADDRESS = (PROTOCOL = TCP)(HOST = rac1-vip.robinson.com)(PORT = 1521))    
  4.     (ADDRESS = (PROTOCOL = TCP)(HOST = rac2-vip.robinson.com)(PORT = 1521))    
  5.     (LOAD_BALANCE = yes)                                                       
  6.     (CONNECT_DATA =                                                            
  7.       (SERVER = DEDICATED)                                                     
  8.       (SERVICE_NAME = sales.robinson.com)                                      
  9.       (FAILOVER =      --failover_mode是实现故障转移的关键选项                 
  10.         (TYPE = SELECT)                                                          
  11.         (METHOD = BASIC)   --TAF 策略:此处当前为 Basic                          
  12.         (RETRIES = 180)                                                          
  13.         (DELAY = 5)                                                              
  14.       )                                                                        
  15.     )                                                                          
  16.   )                                                                          
        同时参数service_names会多出一个服务名,位于在配置数据库服务时选择的首选实例中      
  1. SQL> select instance_name from v$instance;                                          
  2.                                                                                     
  3. INSTANCE_NAME                                                                       
  4. ----------------                                                                    
  5. devdb1                                                                              
  6.                                                                                     
  7. SQL> show parameter service_names                                                   
  8.                                                                                     
  9. NAME                                 TYPE        VALUE                              
  10. ------------------------------------ ----------- ------------------------------     
  11. service_names                        string      devdb.robinson.com, sales          
  12.                                                                                     
  13. SQL> select instance_name from v$instance;                                          
  14.                                                                                     
  15. INSTANCE_NAME                                                                       
  16. ----------------                                                                    
  17. devdb2                                                                              
  18.                                                                                     
  19. SQL> show parameter service                                                         
  20.                                                                                     
  21. NAME                                 TYPE        VALUE                              
  22. ------------------------------------ ----------- ------------------------------     
  23. service_names                        string      devdb.robinson.com                 
        使用srvctl工具也可以看到该服务已经正常开始提供服务       
  1. SQL> ho srvctl status service -d devdb -s sales                              
  2. Service sales is running on instance(s) devdb1                               
  3.                                                                              
  4. SQL> ho lsnrctl status                                                       
  5.                                                                              
  6. Service "sales.robinson.com" has 1 instance(s).   --sales正常提供服务        
  7.   Instance "devdb1", status READY, has 2 handler(s) for this service...      
    2.实现故障转移
        下面使用帐户usr1,服务名sales从Windows客户端来登陆,注意要配置好客户端tnsnames,可以将服务器sales项内容全部复制到客户端tnsnames.ora中     
  1. C:\>sqlplus usr1/usr1@sales                                                                         
  2. SQL> col host_name format a20                                                                       
  3. SQL> select instance_number ins_no,instance_name,host_name,status from v$instance;                  
  4.                                                                                                     
  5.     INS_NO INSTANCE_NAME    HOST_NAME            STATUS                                               
  6. ---------- ---------------- -------------------- ------------                                       
  7.          1 devdb1           rac1.robinson.com    OPEN                                                   
  8. SQL> select failover_type,failover_method,failed_over from v$session                                
  9.   2  where username='USR1';                                                                         
  10.                                                                                                     
  11. FAILOVER_TYPE FAILOVER_M FAI                                                                        
  12. ------------- ---------- ---                                                                        
  13. SELECT        BASIC      NO                                                                         
  14.                                                                                                     
  15. --从其它会话使用sys帐户登陆到crm 并关闭该实例                                                         
  16. SQL> show user;                                                                                     
  17. USER is "SYS"                                                                                       
  18. SQL> select instance_name from v$instance;                                                          
  19.                                                                                                     
  20. INSTANCE_NAME                                                                                       
  21. ----------------                                                                                    
  22. devdb1                                                                                              
  23.                                                                                                     
  24. SQL> shutdown abort                                                                                 
  25. ORACLE instance shut down.                                                                          
  26.                                                                                                     
  27. --从先前登陆到sales的会话中验证会话故障切换功能                                                     
  28. SQL> select instance_number ins_no,instance_name,host_name,status from v$instance;                  
  29.                                                                                                     
  30.     INS_NO INSTANCE_NAME    HOST_NAME            STATUS                                               
  31. ---------- ---------------- -------------------- ------------                                       
  32.                  2 devdb2           rac2.robinson.com    OPEN                                               
  33.                                                                                                     
  34. SQL> select failover_type,failover_method,failed_over from v$session                                
  35.   2  where username='USR1';  --第3列显示的为yes,也表明经过故障切换后提供的服务                     
  36.                                                                                                     
  37. FAILOVER_TYPE FAILOVER_M FAI                                                                        
  38. ------------- ---------- ---                                                                        
  39. SELECT        BASIC      YES                                                                            
  40.                                                                                                     
  41. --由下面的查询中可以看到服务名sales被添加到可用实例devdb2,节点rac2 的service_names参数中           
  42. SQL> select instance_name from v$instance;                                                          
  43.                                                                                                     
  44. INSTANCE_NAME                                                                                       
  45. ----------------                                                                                    
  46. devdb2                                                                                              
  47.                                                                                                     
  48. SQL> show parameter service                                                                         
  49.                                                                                                     
  50. NAME                                 TYPE        VALUE                                              
  51. ------------------------------------ ----------- ------------------------------                     
  52. service_names                        string      devdb.robinson.com, sales                            
    3.重新定位故障转移服务到首选实例
        对于首选实例从故障中恢复后,需要手动来重新定位到首选实例       
  1. SQL> startup  --启动devdb1                                                           
  2. SQL> show parameter service_names                                                    
  3.                                                                                      
  4. NAME                                 TYPE        VALUE                               
  5. ------------------------------------ ----------- ------------------------------      
  6. service_names                        string      devdb.robinson.com                  
  7.                                                                                      
  8. SQL> ho srvctl relocate service -d devdb -s sales -i devdb2 -t devdb1                
  9.                                                                                      
  10. SQL> show parameter service_names                                                    
  11.                                                                                      
  12. NAME                                 TYPE        VALUE                               
  13. ------------------------------------ ----------- ------------------------------      
  14. service_names                        string      devdb.robinson.com, sales           
    4.DML故障转移(不同于DQL,因此单独列出)
        使用Windows客户端通过sales服务名登陆       
  1. C:\>sqlplus usr1/usr1@sales                                                            
  2.                                                                                        
  3. SQL> show user;                                                                        
  4. USER is "USR1"                                                                         
  5. SQL> create table tb_temp (id int,ename varchar2(20)) tablespace tbs1;                 
  6.                                                                                          
  7. Table created.                                                                         
  8.                                                                                        
  9. SQL> insert into tb_temp                                                               
  10.   2  select 1,'Robinson' from dual                                                     
  11.   3  union all                                                                         
  12.   4  select 2,'Jackson'  from dual;                                                    
  13.                                                                                        
  14. rows created.                                                                        
  15.                                                                                        
  16. SQL> commit;                                                                           
  17.                                                                                        
  18. Commit complete.                                                                       
  19.                                                                                        
  20. SQL> select * from tb_temp;                                                            
  21.                                                                                        
  22.         ID ENAME                                                                           
  23. ---------- --------------------                                                        
  24.          1 Robinson                                                                        
  25.          2 Jackson                                                                         
  26.                                                                                        
  27. SQL> delete from tb_temp;                                                              
  28.                                                                                        
  29. rows deleted.                                                                        
  30.                                                                                        
  31. SQL> select * from tb_temp;                                                            
  32.                                                                                        
  33. no rows selected                                                                       
        从另一个会话中使用sysdba关闭devdb1(shutdown abort)
        再在刚刚执行表创建的会话中查询记录,收到提示,事务必须被回滚    
  1. SQL> select * from tb_temp;                                                  
  2. select * from tb_temp                                                        
  3. *                                                                            
  4. ERROR at line 1:                                                             
  5. ORA-25402: transaction must roll back                                        
  6.                                                                              
  7. SQL> rollback;                                                               
  8.                                                                              
  9. Rollback complete.                                                           
  10. SQL> select * from tb_temp;                                                  
  11.                                                                              
  12.         ID ENAME                                                                 
  13. ---------- --------------------                                              
  14.          1 Robinson                                                              
  15.          2 Jackson                                                               
  16.                                                                              
  17. SQL> select failover_type,failover_method,failed_over from v$session         
  18.   2  where username='USR1';                                                  
  19.                                                                              
  20. FAILOVER_TYPE FAILOVER_M FAI                                                 
  21. ------------- ---------- ---                                                 
  22. SELECT        BASIC      YES                                                 
        总结:对于DML 操作在实现故障转移时,将严格按照ACID原则来执行,大部分情况需要回滚事务。
浏览1839 评论0
返回
目录
返回
首页
ORACLE RAC 监听配置 (listener.ora tnsnames.ora) 11g R2 RAC客户端负载均衡配置