This section presents the steps involved when you create a database manually. These steps should be followed in the order presented. Before you create the database make sure you have done the planning about the size of the database, number of tablespaces and redo log files you want in the database.
Regarding the size of the database you have to first find out how many tables are going to be created in the database and how much space they will be occupying for the next 1 year or 2. The best thing is to start with some specific size and later on adjust the size depending upon the requirement
Plan the layout of the underlying operating system files your database will comprise. Proper distribution of files can improve database performance dramatically by distributing the I/O during file access. You can distribute I/O in several ways when you install Oracle software and create your database. For example, you can place redo log files on separate disks or use striping. You can situate datafiles to reduce contention. And you can control data density (number of rows to a data block).
Select the standard database block size. This is specified at database creation by the DB_BLOCK_SIZE initialization parameter and cannot be changed after the database is created. For databases, block size of 4K or 8K is widely used
Before you start creating the Database it is best to write down the specification and then proceed
The examples shown in these steps create an example database my_ica_db
Let us create a database my_ica_db with the following specification
Database name and System Identifier
SID=myicadb
DB_NAME=myicadb
TABLESPACES
(we will have 6 tablespaces in this database. With 1
datafile in each tablespace)
Tablespace Name | Datafile Location | Size |
SYSTEM | /u01/oracle/oradata/myica/sys.dbf | 500M |
USERS | /u01/oracle/oradata/myica/usr.dbf | 100M |
UNDOTBS | /u01/oracle/oradata/myica/undo.dbf | 100M |
TEMP | /u01/oracle/oradata/myica/temp.dbf | 100M |
INDEX_DATA | /u01/oracle/oradata/myica/indx.dbf | 100M |
SYSAUX | /u01/oracle/oradata/myica/sysaux.dbf | 100M |
LOGFILES
(we will have 2 log groups in the database)
Logfile Group | Member Location | Size |
GROUP 1 | /u01/oracle/oradata/myica/log1.ora | 10M |
GROUP 2 | /u01/oracle/oradata/myica/log2.ora | 10M |
CONTROL FILE
(We will have 1 Control File in the following
location)
/u01/oracle/oradata/myica/control.ora
PARAMETER FILE
(we will use normal parameter file for now, later
on we can switch to SPFile)
/u01/oracle/dbs/initmyicadb.ora
(remember the parameter file name should of the format init<sid>.ora and it should be in ORACLE_HOME/dbs directory in Unix o/s and ORACLE_HOME/database directory in windows o/s)
Now let us start creating the database.
Step 1: Login to oracle account and make directories for your database.
$ mkdir /u01/oracle/oradata/myica
$ mkdir
/u01/oracle/oradata/myica/bdump
$ mkdir
/u01/oracle/oradata/myica/udump
$ mkdir
/u01/oracle/oradata/myica/recovery
Step 2: Create the parameter file by copying the default template (init.ora) and set the required parameters
$ cd /u01/oracle/dbs
$ cp init.ora initmyicadb.ora
Now open the parameter file and set the following parameters
$ vi initmyicadb.ora
DB_NAME=myicadb
DB_BLOCK_SIZE=8192
CONTROL_FILES=/u01/oracle/oradata/myica/control.ora
UNDO_TABLESPACE=undotbs
UNDO_MANAGEMENT=AUTO
SGA_TARGET=500M
PGA_AGGREGATE_TARGET=100M
LOG_BUFFER=5242880
DB_RECOVERY_FILE_DEST=/u01/oracle/oradata/myica/recovery
DB_RECOVERY_FILE_DEST_SIZE=2G
# The following parameters are required only in 10g or earlier versions
BACKGROUND_DUMP_DEST=/u01/oracle/oradata/myica/bdump
USER_DUMP_DEST=/u01/oracle/oradata/myica/udump
After entering the above parameters save the file by pressing "Esc :wq"
Step 3: Now set ORACLE_SID environment variable and start the instance.
$ export ORACLE_SID=myicadb
$ sqlplus
Enter User: / as sysdba
SQL>startup nomount
Step 4: Give the create database command
Here I am not specifying optional setting such as language, characterset
etc. For these settings oracle will use
the default values. I am giving the bare minimum command to create the
database to keep it simple.
The command to create the database is
SQL> create database myicadb
datafile ‘/u01/oracle/oradata/myica/sys.dbf’ size 500M
sysaux datafile ‘/u01/oracle/oradata/myica/sysaux.dbf’ size 100m
undo tablespace undotbs
datafile
‘/u01/oracle/oradata/myica/undo.dbf’ size 100m
default temporary tablespace temp
tempfile
‘/u01/oracle/oradata/myica/tmp.dbf’ size 100m
logfile
group 1 ‘/u01/oracle/oradata/myica/log1.ora’ size 50m,
group 2 ‘/u01/oracle/oradata/myica/log2.ora’ size 50m;
After the command finishes you will get the following message
Database created.
If you are getting any errors then see accompanying messages. If no
accompanying messages are shown then
you have to see the alert_myicadb.log file located in
BACKGROUND_DUMP_DEST directory, which will show the
exact reason why the command has failed. After you have rectified the
error please delete all created files in
u01/oracle/oradata/myica directory and again give the above command.
Step 5: After the above command finishes, the database will get
mounted and opened. Now create additional
tablespaces
To create USERS tablespace
SQL> create tablespace users
datafile
‘/u01/oracle/oradata/myica/usr.dbf’ size 100M;
To create INDEX_DATA tablespace
SQL>create tablespace index_data
datafile
‘/u01/oracle/oradata/myica/indx.dbf’ size 100M
Step 6: To populate the database with data dictionaries and to
install
procedural options execute
the following scripts
First execute the CATALOG.SQL script to install data dictionaries
SQL>@/u01/oracle/rdbms/admin/catalog.sql
The above script will take several minutes. After the above script is finished run the CATPROC.SQL script to install procedural option.
SQL>@/u01/oracle/rdbms/admin/catproc.sql
This script will also take several minutes to complete.
Step 7: Now change the passwords for SYS and SYSTEM account, since the default passwords change_on_install and manager are known by everybody.
SQL>alter user sys identified by myica;
SQL>alter user system identified by myica;
Step 8: Create Additional user accounts. You can create as many user account as you like. Let us create the popular account SCOTT.
SQL>create user scott default tablespace users
identified by tiger quota 10M on users;
SQL>grant connect to scott;
Step 9: Add this database SID in listener.ora file and restart the listener process.
$ cd /u01/oracle/network/admin
$ vi listener.ora
(This file will already contain sample entries. Copy and paste one sample entry and edit the SID setting)
LISTENER =
(DESCRIPTION_LIST =
(DESCRIPTION =
(ADDRESS =(PROTOCOL = TCP)(HOST=200.200.100.1)(PORT = 1521))
)
)
SID_LIST_LISTENER =
(SID_LIST =
(SID_DESC =
(SID_NAME = PLSExtProc)
(ORACLE_HOME =/u01/oracle)
(PROGRAM = extproc)
)
(SID_DESC =
(SID_NAME=orcl)
(ORACLE_HOME=/u01/oracle)
)
)
#Add these lines in SID_LIST_LISTENER at the bottom of file
(SID_DESC =
(SID_NAME=myicadb)
(ORACLE_HOME=/u01/oracle)
)
Save the file by pressing Esc :wq
Now restart the listener process.
$ lsnrctl stop
$ lsnrctl start
Step 10: It is recommended to take a full database backup after
you just created the database.
How to take backup is deal in the Backup and Recovery Section.
Congratulations you have just created an oracle database.
Interface Computers Academy © 2007-2017 All Rights Reserved