联系:手机/微信(+86 17813235971) QQ(107644445)
标题:物理备库在read only时报ORA-01552错误处理
作者:惜分飞©版权所有[未经本人同意,不得以任何形式转载,否则有进一步追究法律责任的权利.]
物理备库在read only时报ORA-01552错误
Tue Jan 06 11:53:38 中国标准时间 2015 alter database open read only Tue Jan 06 11:53:38 中国标准时间 2015 SMON: enabling cache recovery Tue Jan 06 11:53:39 中国标准时间 2015 Database Characterset is ZHS16GBK Opening with internal Resource Manager plan replication_dependency_tracking turned off (no async multimaster replication found) Physical standby database opened for read only access. Completed: alter database open read only Tue Jan 06 11:54:04 中国标准时间 2015 Errors in file c:\oracle\product\10.2.0\admin\ntsy\udump\ntsy_ora_9080.trc: ORA-00604: 递归 SQL 级别 1 出现错误 ORA-01552: 非系统表空间 'MY_SPACE' 不能使用系统回退段 ORA-06512: 在 line 2
分析trace文件
*** ACTION NAME:() 2015-01-06 11:54:04.828 *** MODULE NAME:(sqlplus.exe) 2015-01-06 11:54:04.828 *** SERVICE NAME:(SYS$USERS) 2015-01-06 11:54:04.828 *** SESSION ID:(1284.9) 2015-01-06 11:54:04.828 Error in executing triggers on connect internal *** 2015-01-06 11:54:04.828 ksedmp: internal or fatal error ORA-00604: 递归 SQL 级别 1 出现错误 ORA-01552: 非系统表空间 'MY_SPACE' 不能使用系统回退段 ORA-06512: 在 line 2 *** 2015-01-06 11:54:05.843 Process diagnostic dump for ORACLE.EXE (MMNL), OS id=10492, pid: 13, proc_ser: 1, sid: <no session>
这里可以看出来,是由于执行触发器导致该问题,根据经验第一感觉很可能是logon之类的触发器导致。
查询触发器
SQL> select trigger_name,trigger_type,OWNER from dba_triggers where owner='OP'; TRIGGER_NAME TRIGGER_TYPE OWNER ------------------------------ ---------------- ------------------------------ LOGAD AFTER EVENT OP TR_TRACE_DDL AFTER EVENT OP
只有这两个触发器是基于事件的,另外从名字和dba_source中确定
SQL> select text from dba_source where name='LOGAD'; TEXT -------------------------------------------------------------------------------- TRIGGER "OP".logad after logon on database begin insert into logad values (SYS_CONTEXT('USERENV', 'SESSION_USER'), SYSDATE,SYS_CO NTEXT('USERENV','IP_ADDRESS')) ; end; 已选择6行。 SQL> select text from dba_source where name='TR_TRACE_DDL'; TEXT -------------------------------------------------------------------------------- TRIGGER "OP".tr_trace_ddl AFTER ddl ON database DECLARE sql_text ora_name_list_t; state_sql ddl$trace.ddl_sql%TYPE; BEGIN FOR i IN 1..ora_sql_txt(sql_text) LOOP state_sql := state_sql||sql_text(i); END LOOP; TEXT -------------------------------------------------------------------------------- INSERT INTO ddl$trace(login_user,audsid,machine,ipaddress, schema_user,schema_object,ddl_time,ddl_sql) VALUES(ora_login_user,userenv('SESSIONID'),sys_context('userenv','host'), sys_context('userenv','ip_address'),ora_dict_obj_owner,ora_dict_obj_name,SYSDATE ,state_sql); EXCEPTION WHEN OTHERS THEN -- sp_write_log('捕获DDL语句异常错误:'||SQLERRM); null; END tr_trace_ddl;
基本上确定LOGAD是登录触发器,tr_trace_ddl是记录ddl触发器,那现在问题应该出在LOGAD的触发器上.因为该触发器在备库上当有用户登录之时,他也会工作插入记录到logad表中,由于数据库是只读,因此就出现了类似ORA-01552错误
解决方法
在触发器中加判断数据库角色条件,当数据库为物理备库之时才执行dml操作
SQL> CREATE OR REPLACE TRIGGER "OP".logad 2 AFTER LOGON on database 3 declare 4 db_role varchar2(30); 5 begin 6 select database_role into db_role from v$database; 7 If db_role <> 'PHYSICAL STANDBY' then 8 insert into op.logad values (SYS_CONTEXT('USERENV', 'SESSION_USER'), 9 SYSDATE,SYS_CONTEXT('USERENV','IP_ADDRESS')) ; 10 end if; 11 end; 12 / Warning: Trigger created with compilation errors. SQL> show error; Errors for TRIGGER "OP".logad: LINE/COL ERROR -------- ----------------------------------------------------------------- 4/1 PL/SQL: SQL Statement ignored 4/40 PL/SQL: ORA-00942: table or view does not exist SQL> conn / as sysdba Connected. SQL> grant select on v_$database to op; Grant succeeded. SQL> CREATE OR REPLACE TRIGGER "OP".logad 2 AFTER LOGON on database 3 declare 4 db_role varchar2(30); 5 begin 6 select database_role into db_role from v$database; 7 If db_role <> 'PHYSICAL STANDBY' then 8 insert into op.logad values (SYS_CONTEXT('USERENV', 'SESSION_USER'), 9 SYSDATE,SYS_CONTEXT('USERENV','IP_ADDRESS')) ; 10 end if; 12 end; 12 / Trigger created.
数据库open正常
Completed: ALTER DATABASE RECOVER MANAGED STANDBY DATABASE cancel Tue Jan 06 13:51:20 中国标准时间 2015 alter database open read only Tue Jan 06 13:51:21 中国标准时间 2015 SMON: enabling cache recovery Tue Jan 06 13:51:21 中国标准时间 2015 Database Characterset is ZHS16GBK Opening with internal Resource Manager plan replication_dependency_tracking turned off (no async multimaster replication found) Physical standby database opened for read only access. Tue Jan 06 13:51:23 中国标准时间 2015 db_recovery_file_dest_size of 102400 MB is 0.00% used. This is a user-specified limit on the amount of space that will be used by this database for recovery-related files, and does not reflect the amount of space available in the underlying filesystem or ASM diskgroup. Tue Jan 06 13:51:23 中国标准时间 2015 Completed: alter database open read only