How to avoid of recreating pfile or spfile if any error in spfile
Suppose I have done some wrong-edit inside spfile using ALTER SYSTEM SET ... SCOPE=SPFILE from database. Now the next startup process of my database will fail with oracle errors. The conventional approach of solution to this problem is,
1)Connect to SQL*plus as sysdba
2)Create pfile from the spfile.
3)Edit the pfile and correct the parameter settings.
4)Create spfile from the edited correct pfile.
5)Startup your database with the spfile.
But we can omit these steps easily by just creating a pfile and invoke the name of the spfile inside the pfile. After invoking spfile parameter inside pfile in the next line specify the name of the parameter which is cause problem of startup. In this case we gave multiple values of the parameter and oracle will use the last one. So override the invalid parameter value with the valid one and thus will startup the create. After startup we can set valid value in the spfile.
The following example will make you a clear idea.
Step 1:
I have set background_dump_dest parameter to an invalid location in the spfile.
SQL> alter system set background_dump_dest='/oradata2/testing' scope=spfile;
System altered.
Now shutdown the database and start it up.
SQL> shutdown immediate;
Database closed.
Database dismounted.
ORACLE instance shut down.
SQL> startup
ORA-00444: background process "MMAN" failed while starting
ORA-07446: sdnfy: bad value '' for parameter .
Step 2:
Startup fails as we set invalid location to background_dump_dest. Now create a pfile with an entry of spfile and give the location of the spfile. After specify specify the parameter which cause problem(background_dump_dest) and use the valid value. This setting will override the setting inside spfile and thus will help to startup the database.
SQL> !vi /oradata2/mypfile.ora
spfile=/oracle/app/oracle/product/10.2.0/db_1/dbs/spfileshaik.ora
background_dump_dest='/oradata1'
Step 3:
Now start the database with newly created pfile. In fact spfile.
SQL> startup pfile=/oradata2/mypfile.ora
ORACLE instance started.
Total System Global Area 234881024 bytes
Fixed Size 2019800 bytes
Variable Size 113249832 bytes
Database Buffers 113246208 bytes
Redo Buffers 6365184 bytes
Database mounted.
Database opened.
Step 4:
And it worked!!! Now set valid value to the parameter background_dump_dest inside spfile.
SQL> alter system set background_dump_dest='/oradata1' scope=spfile;
System altered.
In this way we can minimize our steps as well as downtime.
1)Connect to SQL*plus as sysdba
2)Create pfile from the spfile.
3)Edit the pfile and correct the parameter settings.
4)Create spfile from the edited correct pfile.
5)Startup your database with the spfile.
But we can omit these steps easily by just creating a pfile and invoke the name of the spfile inside the pfile. After invoking spfile parameter inside pfile in the next line specify the name of the parameter which is cause problem of startup. In this case we gave multiple values of the parameter and oracle will use the last one. So override the invalid parameter value with the valid one and thus will startup the create. After startup we can set valid value in the spfile.
The following example will make you a clear idea.
Step 1:
I have set background_dump_dest parameter to an invalid location in the spfile.
SQL> alter system set background_dump_dest='/oradata2/testing' scope=spfile;
System altered.
Now shutdown the database and start it up.
SQL> shutdown immediate;
Database closed.
Database dismounted.
ORACLE instance shut down.
SQL> startup
ORA-00444: background process "MMAN" failed while starting
ORA-07446: sdnfy: bad value '' for parameter .
Step 2:
Startup fails as we set invalid location to background_dump_dest. Now create a pfile with an entry of spfile and give the location of the spfile. After specify specify the parameter which cause problem(background_dump_dest) and use the valid value. This setting will override the setting inside spfile and thus will help to startup the database.
SQL> !vi /oradata2/mypfile.ora
spfile=/oracle/app/oracle/product/10.2.0/db_1/dbs/spfileshaik.ora
background_dump_dest='/oradata1'
Step 3:
Now start the database with newly created pfile. In fact spfile.
SQL> startup pfile=/oradata2/mypfile.ora
ORACLE instance started.
Total System Global Area 234881024 bytes
Fixed Size 2019800 bytes
Variable Size 113249832 bytes
Database Buffers 113246208 bytes
Redo Buffers 6365184 bytes
Database mounted.
Database opened.
Step 4:
And it worked!!! Now set valid value to the parameter background_dump_dest inside spfile.
SQL> show parameter background_dump_dest
NAME TYPE VALUE
------------------------------------ ----------- ------------------------------
background_dump_dest string /oradata1
SQL> alter system set background_dump_dest='/oradata1' scope=spfile;
System altered.
In this way we can minimize our steps as well as downtime.
Comments
Post a Comment