Rename Database using CONTROLFILE in Oracle
In a recent article, we have demonstrated How to Rename Database and DBID using DBNEWID in Oracle with all available options, click here to go through it.
In this article, we are going to demonstrate How to Rename a Database using CONTROLFILE in Oracle. Existing database rename from source DBSGURU to target GURUDB.
1. Backup of database and SPFILE: Take a full database backup and create PFILE using SPFILE. Click here for RMAN Full Database Backup Scripts in Oracle. If something goes wrong while renaming DB then using this backup database will be restored.
RMAN> backup database plus archivelog delete input;
Starting backup at 06-JUL-21
current log archived
allocated channel: ORA_DISK_1
channel ORA_DISK_1: SID=469 device type=DISK
channel ORA_DISK_1: starting archived log backup set
channel ORA_DISK_1: specifying archived log(s) in backup set
input archived log thread=1 sequence=7 RECID=1 STAMP=1077212320
channel ORA_DISK_1: starting piece 1 at 06-JUL-21
channel ORA_DISK_1: finished piece 1 at 06-JUL-21
piece handle=/oradata/DBSGURU/FRA/DBSGURU/backupset/2021_07_06/o1_mf_annnn_TAG20210706T173840_jg8ky8w9_.bkp tag=TAG20210706T173840 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:00:01
channel ORA_DISK_1: deleting archived log(s)
archived log file name=/oradata/DBSGURU/FRA/DBSGURU/archivelog/2021_07_06/o1_mf_1_7_jg8ky87z_.arc RECID=1 STAMP=1077212320
Finished backup at 06-JUL-21
Starting backup at 06-JUL-21
using channel ORA_DISK_1
channel ORA_DISK_1: starting full datafile backup set
channel ORA_DISK_1: specifying datafile(s) in backup set
input datafile file number=00001 name=/oradata/DBSGURU/system01.dbf
input datafile file number=00003 name=/oradata/DBSGURU/sysaux01.dbf
input datafile file number=00004 name=/oradata/DBSGURU/undotbs01.dbf
input datafile file number=00007 name=/oradata/DBSGURU/users01.dbf
channel ORA_DISK_1: starting piece 1 at 06-JUL-21
channel ORA_DISK_1: finished piece 1 at 06-JUL-21
piece handle=/oradata/DBSGURU/FRA/DBSGURU/backupset/2021_07_06/o1_mf_nnndf_TAG20210706T173842_jg8kybns_.bkp tag=TAG20210706T173842 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:01:25
channel ORA_DISK_1: starting full datafile backup set
channel ORA_DISK_1: specifying datafile(s) in backup set
input datafile file number=00010 name=/oradata/DBSGURU/dbsguru_pdb/sysaux01.dbf
input datafile file number=00009 name=/oradata/DBSGURU/dbsguru_pdb/system01.dbf
input datafile file number=00011 name=/oradata/DBSGURU/dbsguru_pdb/users01.dbf
channel ORA_DISK_1: starting piece 1 at 06-JUL-21
channel ORA_DISK_1: finished piece 1 at 06-JUL-21
piece handle=/oradata/DBSGURU/FRA/DBSGURU/C40921A8BBF963F9E055515375A76B71/backupset/2021_07_06/o1_mf_nnndf_TAG20210706T173842_jg8l101b_.bkp tag=TAG20210706T173842 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:00:25
channel ORA_DISK_1: starting full datafile backup set
channel ORA_DISK_1: specifying datafile(s) in backup set
input datafile file number=00006 name=/oradata/DBSGURU/pdbseed/sysaux01.dbf
input datafile file number=00005 name=/oradata/DBSGURU/pdbseed/system01.dbf
channel ORA_DISK_1: starting piece 1 at 06-JUL-21
channel ORA_DISK_1: finished piece 1 at 06-JUL-21
piece handle=/oradata/DBSGURU/FRA/DBSGURU/C408FE0B46DC5BFFE055515375A76B71/backupset/2021_07_06/o1_mf_nnndf_TAG20210706T173842_jg8l1s7k_.bkp tag=TAG20210706T173842 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:00:35
Finished backup at 06-JUL-21
Starting backup at 06-JUL-21
current log archived
using channel ORA_DISK_1
channel ORA_DISK_1: starting archived log backup set
channel ORA_DISK_1: specifying archived log(s) in backup set
input archived log thread=1 sequence=8 RECID=2 STAMP=1077212468
channel ORA_DISK_1: starting piece 1 at 06-JUL-21
channel ORA_DISK_1: finished piece 1 at 06-JUL-21
piece handle=/oradata/DBSGURU/FRA/DBSGURU/backupset/2021_07_06/o1_mf_annnn_TAG20210706T174108_jg8l2x0w_.bkp tag=TAG20210706T174108 comment=NONE
channel ORA_DISK_1: backup set complete, elapsed time: 00:00:01
channel ORA_DISK_1: deleting archived log(s)
archived log file name=/oradata/DBSGURU/FRA/DBSGURU/archivelog/2021_07_06/o1_mf_1_8_jg8l2wj5_.arc RECID=2 STAMP=1077212468
Finished backup at 06-JUL-21
Starting Control File and SPFILE Autobackup at 06-JUL-21
piece handle=/oradata/DBSGURU/FRA/DBSGURU/autobackup/2021_07_06/o1_mf_s_1077212470_jg8l2zqv_.bkp comment=NONE
Finished Control File and SPFILE Autobackup at 06-JUL-21
SQL> CREATE PFILE FROM SPFILE;
File created.
2. Database name & DBID, Control files along with physical files: Capture database name & DBID before rename along with basics details of DB. Click here to get the command for How to find all physicals files in Oracle.
SQL> SELECT DBID,NAME FROM V$DATABASE;
DBID NAME
---------- ---------
3936528048 DBSGURU
SQL>
SQL> SELECT NAME FROM V$CONTROLFILE;
NAME
--------------------------------------------------------------------------------
/oradata/DBSGURU/controlfile/control01.ctl
/u01/DBSGURU/controlfile/control02.ctl
3. Control file backup to trace: Take a backup of the control file in text format. Here we have two options to generate either to the desire location or to USER_DUMP_DEST location.
SQL> ALTER DATABASE BACKUP CONTROLFILE TO TRACE AS '/home/oracle/DBsGuru_Control.txt';
Database altered.
[oracle@DBsGuruN ~]$ ls -lrt /home/oracle/DBsGuru_Control.txt
-rw-r--r--. 1 oracle oinstall 7509 Jul 6 17:41 /home/oracle/DBsGuru_Control.txt
OR
SQL> SHOW PARAMETER user_dump_dest
NAME TYPE VALUE
------------------------------------ ----------- ------------------------------
user_dump_dest string /u01/app/oracle/product/19.0.0
/db_1/rdbms/log
SQL> ALTER DATABASE BACKUP CONTROLFILE TO TRACE;
Database altered.
[oracle@DBsGuruN ~]$ ls -lrt /u01/app/oracle/diag/rdbms/dbsguru/dbsguru/trace/dbsguru_ora_8295.trc
-rw-r-----. 1 oracle oinstall 8856 Jul 6 17:46 /u01/app/oracle/diag/rdbms/dbsguru/dbsguru/trace/dbsguru_ora_8295.trc
4. Prepare rename database script: To prepare rename database script, edit the trace file which is taken in STEP 3 i.e recreate CONTROLFILE with new database name GURUDB. Here we will be using a new file to recreate CONTROLFILE. Key points to remember to edit the trace file.
4.1: Remove all lines in trace file till before line STARTUP NOMOUNT i.e remove lines that are comments (line started “–“).
4.2: Choose wisely options ARCHIVE/NOARCHIVE while recreating CONTROLFILE.
4.3: Replace database name to GURUDB and keyword REUSE to SET in line CREATE CONTROLFILE command.
4.4: Make sure file extension should be .sql in case want to execute as a script on SQL prompt.
Below is the exact script to recreate CONTROLFILE which we are going to execute in STEP.
vi rename_dbsguru_gurudb.sql
SET ECHO ON
STARTUP NOMOUNT
CREATE CONTROLFILE SET DATABASE "GURUDB" RESETLOGS ARCHIVELOG
MAXLOGFILES 16
MAXLOGMEMBERS 3
MAXDATAFILES 1024
MAXINSTANCES 8
MAXLOGHISTORY 292
LOGFILE
GROUP 1 '/oradata/GURUNEW/onlinelog/o1_mf_1_jfgq11pz_.log' SIZE 50M BLOCKSIZE 512,
GROUP 2 '/oradata/GURUNEW/onlinelog/o1_mf_2_jfgq11ws_.log' SIZE 50M BLOCKSIZE 512,
GROUP 3 '/oradata/GURUNEW/onlinelog/o1_mf_3_jfgq122f_.log' SIZE 50M BLOCKSIZE 512
-- STANDBY LOGFILE
DATAFILE
'/oradata/DBSGURU/system01.dbf',
'/oradata/DBSGURU/sysaux01.dbf',
'/oradata/DBSGURU/undotbs01.dbf',
'/oradata/DBSGURU/pdbseed/system01.dbf',
'/oradata/DBSGURU/pdbseed/sysaux01.dbf',
'/oradata/DBSGURU/users01.dbf',
'/oradata/DBSGURU/dbsguru_pdb/system01.dbf',
'/oradata/DBSGURU/dbsguru_pdb/sysaux01.dbf',
'/oradata/DBSGURU/dbsguru_pdb/users01.dbf'
CHARACTER SET AL32UTF8
;
ALTER DATABASE OPEN RESETLOGS;
ALTER PLUGGABLE DATABASE ALL OPEN;
ALTER TABLESPACE TEMP ADD TEMPFILE '/oradata/DBSGURU/temp01.dbf'
SIZE 33554432 REUSE AUTOEXTEND ON NEXT 655360 MAXSIZE 32767M;
ALTER SESSION SET CONTAINER = "PDB$SEED";
ALTER TABLESPACE TEMP ADD TEMPFILE '/oradata/DBSGURU/pdbseed/temp012021-06-05_22-48-09-365-PM.dbf'
SIZE 37748736 REUSE AUTOEXTEND ON NEXT 655360 MAXSIZE 32767M;
ALTER SESSION SET CONTAINER = "DBSGURU_PDB";
ALTER TABLESPACE TEMP ADD TEMPFILE '/oradata/DBSGURU/dbsguru_pdb/temp01.dbf' REUSE;
ALTER SESSION SET CONTAINER = "CDB$ROOT";
SHOW PDBS;
5. Move/rename CONTROLFILE: For the safer side do rename/move CONTROLFILE instead of drop and from here downtime started.
SQL> SHUTDOWN IMMEDIATE
Database closed.
Database dismounted.
ORACLE instance shut down.
mv /oradata/DBSGURU/controlfile/control01.ctl /oradata/DBSGURU/controlfile/control01.ctl.bkp
mv /u01/DBSGURU/controlfile/control02.ctl /u01/DBSGURU/controlfile/control02.ctlbkp
[oracle@DBsGuruN ~]$ mv /oradata/DBSGURU/controlfile/control01.ctl /oradata/DBSGURU/controlfile/control01.ctl.bkp
[oracle@DBsGuruN ~]$ mv /u01/DBSGURU/controlfile/control02.ctl /u01/DBSGURU/controlfile/control02.ctl.bkp
[oracle@DBsGuruN ~]$ ls -lrt /oradata/DBSGURU/controlfile/control01.ctl.bkp /u01/DBSGURU/controlfile/control02.ctl.bkp
-rw-r-----. 1 oracle oinstall 18726912 Jul 6 18:10 /u01/DBSGURU/controlfile/control02.ctlbkp
-rw-r-----. 1 oracle oinstall 18726912 Jul 6 18:10 /oradata/DBSGURU/controlfile/control01.ctl.bkp
6. Change database new name in SPFILE/PFILE: Rename database in SPFILE/PFILE. Here we are performing via SPFILE.
SQL> STARTUP NOMOUNT
ORACLE instance started.
Total System Global Area 788526632 bytes
Fixed Size 9139752 bytes
Variable Size 507510784 bytes
Database Buffers 268435456 bytes
Redo Buffers 3440640 bytes
SQL> ALTER SYSTEM SET DB_NAME=gurudb SCOPE=SPFILE;
System altered.
SQL> SHUTDOWN IMMEDIATE
ORA-01507: database not mounted
ORACLE instance shut down.
SQL> exit
Disconnected from Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production
Version 19.3.0.0.0
[oracle@DBsGuruN ]$ cd /u01/app/oracle/product/19.0.0/db_1/dbs/
[oracle@DBsGuruN dbs]$ ls -lrt spfiledbsguru.ora
-rw-r-----. 1 oracle oinstall 3584 Jun 6 18:14 spfiledbsguru.ora
[oracle@DBsGuruN dbs]$ cp spfiledbsguru.ora spfiledbsguru.ora.bkp
[oracle@DBsGuruN dbs]$ mv spfiledbsguru.ora spfilegurudb.ora
[oracle@DBsGuruN dbs]$ ls -lrt spfilegurudb.ora
-rw-r-----. 1 oracle oinstall 4608 Jun 6 18:15 spfilegurudb.ora
7. Add entry in oratab: Using any editor command-line tool add an entry in the next line for new name DB in /etc/oratab.
[oracle@DBsGuruN dbs]$ vi /etc/oratab
gurudb:/u01/app/oracle/product/19.0.0/db_1:N
8. Rename database: Follow the below command to rename the database i.e recreate CONTROLFILE. Execute command prepared in STEP 4. Make sure before executing the command you have a valid full database backup. After renaming of database all previous backups will be unusable along with archived redo logs.
[oracle@DBsGuruN ~]$ . oraenv
ORACLE_SID = [dbsguru] ? gurudb
The Oracle base remains unchanged with value /u01/app/oracle
[oracle@DBsGuruN ~]$ sqlplus / as sysdba
SQL*Plus: Release 19.0.0.0.0 - Production on Tue Jul 6 18:33:40 2021
Version 19.3.0.0.0
Copyright (c) 1982, 2019, Oracle. All rights reserved.
Connected to an idle instance.
SQL> @rename_dbsguru_gurudb.sql
SQL> STARTUP NOMOUNT
ORACLE instance started.
Total System Global Area 788526632 bytes
Fixed Size 9139752 bytes
Variable Size 499122176 bytes
Database Buffers 276824064 bytes
Redo Buffers 3440640 bytes
SQL> CREATE CONTROLFILE SET DATABASE "GURUDB" RESETLOGS ARCHIVELOG
2 MAXLOGFILES 16
3 MAXLOGMEMBERS 3
4 MAXDATAFILES 1024
5 MAXINSTANCES 8
6 MAXLOGHISTORY 292
7 LOGFILE
8 GROUP 1 '/oradata/GURUNEW/onlinelog/o1_mf_1_jfgq11pz_.log' SIZE 50M BLOCKSIZE 512,
9 GROUP 2 '/oradata/GURUNEW/onlinelog/o1_mf_2_jfgq11ws_.log' SIZE 50M BLOCKSIZE 512,
10 GROUP 3 '/oradata/GURUNEW/onlinelog/o1_mf_3_jfgq122f_.log' SIZE 50M BLOCKSIZE 512
11 -- STANDBY LOGFILE
12 DATAFILE
13 '/oradata/DBSGURU/system01.dbf',
14 '/oradata/DBSGURU/sysaux01.dbf',
15 '/oradata/DBSGURU/undotbs01.dbf',
16 '/oradata/DBSGURU/pdbseed/system01.dbf',
17 '/oradata/DBSGURU/pdbseed/sysaux01.dbf',
18 '/oradata/DBSGURU/users01.dbf',
19 '/oradata/DBSGURU/dbsguru_pdb/system01.dbf',
20 '/oradata/DBSGURU/dbsguru_pdb/sysaux01.dbf',
21 '/oradata/DBSGURU/dbsguru_pdb/users01.dbf'
22 CHARACTER SET AL32UTF8
23 ;
Control file created.
SQL>
SQL> ALTER DATABASE OPEN RESETLOGS;
Database altered.
SQL>
SQL> ALTER PLUGGABLE DATABASE ALL OPEN;
Pluggable database altered.
SQL>
SQL> ALTER TABLESPACE TEMP ADD TEMPFILE '/oradata/DBSGURU/temp01.dbf'
2 SIZE 33554432 REUSE AUTOEXTEND ON NEXT 655360 MAXSIZE 32767M;
Tablespace altered.
SQL>
SQL> ALTER SESSION SET CONTAINER = "PDB$SEED";
Session altered.
SQL>
SQL> ALTER TABLESPACE TEMP ADD TEMPFILE '/oradata/DBSGURU/pdbseed/temp012021-06-05_22-48-09-365-PM.dbf'
2 SIZE 37748736 REUSE AUTOEXTEND ON NEXT 655360 MAXSIZE 32767M;
Tablespace altered.
SQL>
SQL> ALTER SESSION SET CONTAINER = "DBSGURU_PDB";
Session altered.
SQL>
SQL> ALTER TABLESPACE TEMP ADD TEMPFILE '/oradata/DBSGURU/dbsguru_pdb/temp01.dbf' REUSE;
Tablespace altered.
SQL>
SQL> ALTER SESSION SET CONTAINER = "CDB$ROOT";
Session altered.
SQL>
SQL> SHOW PDBS;
CON_ID CON_NAME OPEN MODE RESTRICTED
---------- ------------------------------ ---------- ----------
2 PDB$SEED READ ONLY NO
3 DBSGURU_PDB READ WRITE NO
9. Validate database new name, Control files along with physical files: Now Validate the database new name along with CONTROLFILES along with all physical files where database name changed from DBSGURU to GURUDB and DBID remains the same. Click here to get the command for How to find all physicals files in Oracle.
SQL> select dbid,name from v$database;
DBID NAME
---------- ---------
3936528048 GURUDB
SQL>
SQL> SELECT NAME FROM V$CONTROLFILE;
NAME
--------------------------------------------------------------------------------
/oradata/DBSGURU/controlfile/control01.ctl
/u01/DBSGURU/controlfile/control02.ctl
10. Validate database services and update TNS entries: Validate database services in LISTENER. Optionally you can reload LISTENER only if all desire services are not started/visible for the database and update/add TNS wherever require.
[oracle@DBsGuruN ~]$ lsnrctl status
LSNRCTL for Linux: Version 19.0.0.0.0 - Production on 06-JUL-2021 18:44:31
Copyright (c) 1991, 2019, Oracle. All rights reserved.
Connecting to (DESCRIPTION=(ADDRESS=(PROTOCOL=TCP)(HOST=DBsGuruN.dbsguru.com)(PORT=1521)))
STATUS of the LISTENER
------------------------
Alias LISTENER
Version TNSLSNR for Linux: Version 19.0.0.0.0 - Production
Start Date 06-JUL-2021 18:38:19
Uptime 0 days 1 hr. 6 min. 11 sec
Trace Level off
Security ON: Local OS Authentication
SNMP OFF
Listener Parameter File /u01/app/oracle/product/19.0.0/db_1/network/admin/listener.ora
Listener Log File /u01/app/oracle/diag/tnslsnr/DBsGuruN/listener/alert/log.xml
Listening Endpoints Summary...
(DESCRIPTION=(ADDRESS=(PROTOCOL=tcp)(HOST=DBsGuruN.dbsguru.com)(PORT=1521)))
(DESCRIPTION=(ADDRESS=(PROTOCOL=ipc)(KEY=EXTPROC1521)))
Services Summary...
Service "GURUDB" has 1 instance(s).
Instance "gurudb", status READY, has 1 handler(s) for this service...
Service "c40921a8bbf963f9e055515375a76b71" has 1 instance(s).
Instance "gurudb", status READY, has 1 handler(s) for this service...
Service "dbsguruXDB" has 1 instance(s).
Instance "gurudb", status READY, has 1 handler(s) for this service...
Service "dbsguru_pdb" has 1 instance(s).
Instance "gurudb", status READY, has 1 handler(s) for this service...
The command completed successfully
11. Create a password file: Create a new password file.
[oracle@DBsGuruN ~]$ orapwd file=$ORACLE_HOME/dbs/orapwgurudb password=P@ssw0rd#567 entries=10
[oracle@DBsGuruN ~]$ ls -lrt $ORACLE_HOME/dbs/orapwgurudb
-rw-r-----. 1 oracle oinstall 6144 Jul 9 10:04 /u01/app/oracle/product/19.0.0/db_1/dbs/orapwgurudb
12. Backup of database and SPFILE: It’s recommended to take a full database backup and create PFILE using SPFILE since all previous backups are unusable due to the new database name. Click here for RMAN Full Database Backup Scripts in Oracle.
SQL> CREATE PFILE FROM SPFILE;
File created.
13: Application checkout: Handover to application to do checkout for database and don’t forget to share new connection strings as required.
This document is just for learning purposes and always validates in the LAB environment first before applying in the LIVE environment.
Hope so you like this article!
Please share your valuable feedback/comments/subscribe and follow us below and don’t forget to click on the bell icon to get the most recent update. Click here to understand more about our pursuit.
Recent articles
- Oracle Critical Database Patch ID for July 2024 along with enabled Download Link
- Oracle Critical Database Patch ID for April 2024 along with enabled Download Link
- Oracle Critical Database Patch ID for January 2024 along with enabled Download Link
- Oracle Critical Database Patch ID for October 2023 along with enabled Download Link
- Oracle Critical Database Patch ID for July 2023 along with enabled Download Link