I needed to migrate an Oracle 10.1.0.3 32-bit database on one server to
10.2.0.3 64-bit on another server, and do it with
only 1 hour of downtime. Here are my notes on
minimum downtime upgrades:
In the consulting world, these sort of tasks are
old hat, and we?ve got lots of tricks up our sleeves
to get a database from one box to another without
resorting to the old, tired, and painfully slow
exp/imp.
I set myself up a task list that would accomplish
the migration with minimum downtime:
- Back up the production database (10.1.0.3
32-bit) via RMAN to a NAS array (we?ll just call
it /nas)
- Create an instance on the new server (64-bit
10.2.0.3) and restore the controlfile from /nas
- Restore the database to the new server
- Start the database on the new server in
mount mode
- Copy archive logs from the old server
periodically, catalog them on the new server and
recover database over and over until you?re
ready to migrate
- Shut down production, start it in restricted
mode, archive log current, and shut it down
again
- Apply the final archive log to the new
server and ?alter database open resetlogs
upgrade?
- Run @?/rdbms/admin/catupgrd.sql (remember,
it's not catpatch.sql anymore)
- Shutdown, start up, and run utlirp.sql and
utlrp.sql to change packages from 32-bit to
64-bit
- All finished!
Can anyone figure out the missing step there
without reading any further? One missing step caused
#8 (running catupgrd.sql) to fail miserably.
Everything went very smoothly until step #8. When
running that step, I received the following error
after about 5 minutes:
ORA-20000: Insufficient privileges to
analyze an object in Dictionary Schema
ORA-06512: at "SYS.DBMS_STATS", line 13323
ORA-06512: at "SYS.DBMS_STATS", line 13649
ORA-06512: at "SYS.DBMS_STATS", line 15985
ORA-06512: at "SYS.DBMS_STATS", line 16027
ORA-06512: at line 2
That was an odd error, considering I was logged
in as SYS. Just to be overly safe and perform a step
I never should have had to do, I explicitly granted
ANALYZE ANY and ANALYZE ANY DICTIONARY to SYS, just
in case. I ran it once more, and received the same
error.
Further investigation showed that the error
occurred while running cmpdbmig.sql, during this
command:
execute dbms_registry.gather_stats(null);
To diagnose the error, I decided to see if
dbms_stats had the same issue.
BEGIN dbms_stats.gather_table_stats('SYS',
'SOURCE$'); END;
*
ERROR at line 1:
ORA-20000: Unable to analyze TABLE "SYS"."SOURCE$",
insufficient privileges or
does not exist
ORA-06512: at "SYS.DBMS_STATS", line 13046
ORA-06512: at "SYS.DBMS_STATS", line 13076
ORA-06512: at line 1
I couldn't gather statistics on the SOURCE$ table
even though I was logged in as SYS. This error was a
little different, saying that I had insufficient
privileges OR the object did not exist.
SQL> show user
USER is "SYS"
SQL> desc source$
Name
Null? Type
----------------------------------------- -------- -------
OBJ#
NOT NULL NUMBER
LINE
NOT NULL NUMBER
SOURCE
VARCHAR2(4000)
As expected, the object exists and I?m SYS. I
tried everything I could think of, but under no
circumstances could I make the DBMS_STATS package
work against SYS objects. I thought that perhaps I
had gotten a little too clever with my
upgrade strategy.
Finally, it dawned on me that there was one step
I had missed before running the catupgrd.sql script:
I did not add a tempfile to the TEMP tablespace!
Remember always, if you restore from backup, there
WILL NOT BE a temporary tablespace anymore. It is
not included in your backups!
SQL> alter tablespace temp
add tempfile '/u01/app/oracle/oradata/temp01.dbf' size
1000M;
Tablespace altered.
SQL> exec dbms_stats.gather_table_stats('SYS',
'SOURCE$');
PL/SQL procedure successfully completed.
As if by magic, it suddenly works! All the
?insufficient privilege? errors put to rest with the
creation of a temporary tablespace file. I reran
catupgrd.sql, did the final steps, and the migration
went off without a hitch!
As such, I hereby submit that the error should be
rewritten to:
ORA-20000: Insufficient privileges to analyze an
object in Dictionary Schema or something like that,
or perhaps not like that whatsoever. Please contact
the internet.