修改props$.NLS_CHARACTERSET导致ORA-00900异常恢复

联系:手机/微信(+86 17813235971) QQ(107644445)

标题:修改props$.NLS_CHARACTERSET导致ORA-00900异常恢复

作者:惜分飞©版权所有[未经本人同意,不得以任何形式转载,否则有进一步追究法律责任的权利.]

今天一朋友和我说他的数据库不能open,open过程提示ORA-00900错误,通过分析alert日志和props$表,发现他们修改了一个无效的NLS_CHARACTERSET值,导致数据库无法正常启动(准确的说,因为数据库里面该值无效,当数据库open的过程中,检测到控制文件指定的编码和该值不一致,然后修改控制文件的编码,修改之后,数据库一到mount状态执行任何语句都报ORA-00900错误),通过一些工具修改NLS_CHARACTERSET为正确值该故障解决

重现ORA-00900故障

SQL> select * from v$version;
BANNER
--------------------------------------------------------------------------------
Oracle Database 11g Enterprise Edition Release 11.2.0.3.0 - Production
PL/SQL Release 11.2.0.3.0 - Production
CORE    11.2.0.3.0      Production
TNS for Linux: Version 11.2.0.3.0 - Production
NLSRTL Version 11.2.0.3.0 - Production
SQL> select value$ from props$ where name='NLS_CHARACTERSET';
VALUE$
-------------------------------------------------------
ZHS16GBK
SQL> update props$ set value$='AL16UTF16' where name='NLS_CHARACTERSET';
1 row updated.
SQL> commit;
Commit complete.
SQL> alter database backup controlfile to trace as '/tmp/ora11g.ctl';
Database altered.
SQL> shutdown immediate;
Database closed.
Database dismounted.
ORACLE instance shut down.
SQL> startup
ORACLE instance started.
Total System Global Area  175775744 bytes
Fixed Size                  1343668 bytes
Variable Size             117444428 bytes
Database Buffers           50331648 bytes
Redo Buffers                6656000 bytes
Database mounted.
ORA-01092: ORACLE instance terminated. Disconnection forced
ORA-00604: error occurred at recursive SQL level 1
ORA-00900: invalid SQL statement
Process ID: 5277
Session ID: 125 Serial number: 5
SQL> startup nomount;
ORACLE instance started.
Total System Global Area  175775744 bytes
Fixed Size                  1343668 bytes
Variable Size             117444428 bytes
Database Buffers           50331648 bytes
Redo Buffers                6656000 bytes
SQL> alter database mount;
Database altered.
SQL> alter database open;
alter database open
*
ERROR at line 1:
ORA-00900: invalid SQL statement
SQL>select * from dual;
select * from dual
*
ERROR at line 1:
ORA-00900: invalid SQL statement
SQL> shutdown abort
ORACLE instance shut down.

第一次startup(open)过程报错

SMON: enabling tx recovery
Updating character set in controlfile to AL16UTF16
Errors in file /u01/oracle/diag/rdbms/ora11g/ora11g/trace/ora11g_ora_5277.trc:
ORA-00604: error occurred at recursive SQL level %s
ORA-00900: invalid SQL statementursive SQL level %s
Errors in file /u01/oracle/diag/rdbms/ora11g/ora11g/trace/ora11g_ora_5277.trc:
ORA-00604: error occurred at recursive SQL level %s
ORA-00900: invalid SQL statementursive SQL level %s
Error 604 happened during db open, shutting down database
USER (ospid: 5277): terminating the instance due to error 604
Errors in file /u01/oracle/diag/rdbms/ora11g/ora11g/trace/ora11g_smon_5243.trc:
ORA-00604: error occurred at recursive SQL level %s
ORA-00900: invalid SQL statementursive SQL level %s
Instance terminated by USER, pid = 5277
ORA-1092 signalled during: ALTER DATABASE OPEN...
opiodr aborting process unknown ospid (5277) as a result of ORA-1092
Sat May 18 00:44:27 2013
ORA-1092 : opitsk aborting process

这里比较明显的看到有一条(Updating character set in controlfile to AL16UTF16),正是由于这个操作,更新控制文件的编码为一个无效的编码,从而导致在后面数据库mount(加载控制文件)之后,就不能再进行其他任何操作

解决思路
使用odu找出来block位置,或者在同版本库中查询
使用dul或者bbed修改props$的NLS_CHARACTERSET值
重建控制文件(noresetlogs方式)

处理过程

SQL> shutdown abort
ORACLE instance shut down.
odu找出来block位置
dul或者bbed修改block值
重建控制文件(noresetlogs方式)
SQL> startup
ORACLE instance started.
Total System Global Area  175775744 bytes
Fixed Size                  1343668 bytes
Variable Size             117444428 bytes
Database Buffers           50331648 bytes
Redo Buffers                6656000 bytes
Database mounted.
ORA-01113: file 1 needs media recovery
ORA-01110: data file 1: '/u01/oracle/oradata/ora11g/system01.dbf'
SQL> recover database;
Media recovery complete.
SQL> alter database open;
Database altered.

从oracle 9i开始,修改数据库的编码,直接使用alter database character set internal_use方式进行,而不要使用直接修改props$基表,更不能修改一个实际中不存在的编码值(本文中数据库编码和国家编码搞混淆从而出现该故障)

One thought on “修改props$.NLS_CHARACTERSET导致ORA-00900异常恢复

  1. 下午好。
    我有相同的症状,并受到显著数据库被蒸发。
    DUL,ODU,BBED你怎么能修复它,因为没有人回答我是否会很感激。
    在有关信息的底部。
    原因
    SQL> update sys.props$ set value$ = ‘AL16UTF16′ where name=’NLS_CHARACTERSET’;
    SQL> COMMIT;
    SQL> SHUTDOWN IMMEDIATE;
    失败
    SQL>STARTUP NOMOUNT;
    ORACLE instance started.
    Total System Global Area 9887760384 bytes
    Fixed Size 2229944 bytes
    Variable Size 3489663304 bytes
    Database Buffers 6375342080 bytes
    Redo Buffers 20525056 bytes
    SQL> SELECT * FROM DUAL;
    ADDR INDX INST_ID DU
    —————- ———- ———- —
    0000000110268CA8 0 1 X
    SQL> ALTER DATABASE MOUNT;
    Database altered.
    SQL> SELECT * FROM DUAL;
    SELECT * FROM DUAL
    *
    ERROR at line 1:
    ORA-00900: invalid SQL statement
    SQL> ALTER DATABASE OPEN;
    ALTER DATABASE OPEN
    *
    ERROR at line 1:
    ORA-00900: invalid SQL statement
    alertLog
    Updating character set in controlfile to AL16UTF16
    Errors in file /oracle/diag/rdbms/nydb/NYDB/trace/NYDB_ora_58261694.trc:
    ORA-00604: error occurred at recursive SQL level %s
    ORA-00900: invalid SQL statementursive SQL level %s
    谢谢。
    多多保重。

发表评论

邮箱地址不会被公开。 必填项已用*标注

12 + 4 =