今天发现一个Oracle测试库的字符集设置不正确,原本的字符集是UTF-8,正确的字符集应该是ZHS16GBK,因为UTF-8是ZHS16GBK的超集,无法修改,只能重建数据库,幸好该测试库上还没有数据。
虽然用DBCA也可以创建数据库,但我个人更喜欢手工创建数据库,其主要步骤如下(数据库版本11.2):
1. 设置ORACLE_SID
默认的ORACLE_SID是orcl,我个人强烈建议起个唯一、且意义的名字,比如**testdb,**proddb等等,在Oracle用户下执行:
- export ORACLE_SID=lxdbtest
export ORACLE_SID=lxdbtest
2. 重建PFILE
在$ORACLE_HOME/dbs目录下重建pfile(initORACLE_SID.ora,本例为initlxdbtest.ora),除了以下三个参数,其它参数都可以不用设置(使用默认值):
- db_name=lxdbtest
- control_files='/home/oracle/app/oradata/lxdbtest/control01.ctl','/home/oracle/app/oradata/lxdbtest/control02.ctl','/home/oracle/app/oradata/lxdbtest/control03.ctl'
- memory_target=2G
db_name=lxdbtest
control_files='/home/oracle/app/oradata/lxdbtest/control01.ctl','/home/oracle/app/oradata/lxdbtest/control02.ctl','/home/oracle/app/oradata/lxdbtest/control03.ctl'
memory_target=2G
为了安全起见,控制文件一定要指定多份,在生产库上,要把它们分开放在不同的物理磁盘上,这里因为是测试库,所以才放在同一个磁盘上。
3. 启动实例至nomount状态
有了pfile就可以启动实例至nomount状态了:
- $ sqlplus / as sysdba
- SQL*Plus: Release 11.2.0.1.0 Production on Thu Jul 25 21:01:16 2013
- Copyright (c) 1982, 2009, Oracle. All rights reserved.
- Connected to an idle instance.
- SQL> startup nomount
- ORACLE instance started.
- Total System Global Area 2137886720 bytes
- Fixed Size 2215064 bytes
- Variable Size 1224737640 bytes
- Database Buffers 905969664 bytes
- Redo Buffers 4964352 bytes
- SQL>
$ sqlplus / as sysdba SQL*Plus: Release 11.2.0.1.0 Production on Thu Jul 25 21:01:16 2013 Copyright (c) 1982, 2009, Oracle. All rights reserved. Connected to an idle instance. SQL> startup nomount
ORACLE instance started. Total System Global Area 2137886720 bytes
Fixed Size 2215064 bytes
Variable Size 1224737640 bytes
Database Buffers 905969664 bytes
Redo Buffers 4964352 bytes
SQL>
4. 执行CREATE DATABASE语句
- CREATE DATABASE lxdbtest
- LOGFILE GROUP 1 ('/home/oracle/app/oradata/lxdbtest/redo01a.log','/data/oradata/lxdbtest/redo01b.log') SIZE 100M BLOCKSIZE 512,
- GROUP 2 ('/home/oracle/app/oradata/lxdbtest/redo02a.log','/data/oradata/lxdbtest/redo02b.log') SIZE 100M BLOCKSIZE 512,
- GROUP 3 ('/home/oracle/app/oradata/lxdbtest/redo03a.log','/data/oradata/lxdbtest/redo03b.log') SIZE 100M BLOCKSIZE 512
- MAXLOGFILES 5
- MAXLOGMEMBERS 5
- MAXLOGHISTORY 1
- MAXDATAFILES 600
- CHARACTER SET ZHS16GBK
- NATIONAL CHARACTER SET AL16UTF16
- EXTENT MANAGEMENT LOCAL
- DATAFILE '/home/oracle/app/oradata/lxdbtest/system01.dbf' SIZE 2048M REUSE AUTOEXTEND OFF
- SYSAUX DATAFILE '/home/oracle/app/oradata/lxdbtest/sysaux01.dbf' SIZE 2048M REUSE AUTOEXTEND OFF
- DEFAULT TABLESPACE users
- DATAFILE '/home/oracle/app/oradata/lxdbtest/users01.dbf'
- SIZE 2048M REUSE AUTOEXTEND OFF
- DEFAULT TEMPORARY TABLESPACE temptbs
- TEMPFILE '/home/oracle/app/oradata/lxdbtest/temp01.dbf'
- SIZE 2048M REUSE AUTOEXTEND OFF
- UNDO TABLESPACE undotbs
- DATAFILE '/home/oracle/app/oradata/lxdbtest/undotbs01.dbf'
- SIZE 2048M REUSE AUTOEXTEND OFF;
CREATE DATABASE lxdbtest
LOGFILE GROUP 1 ('/home/oracle/app/oradata/lxdbtest/redo01a.log','/data/oradata/lxdbtest/redo01b.log') SIZE 100M BLOCKSIZE 512,
GROUP 2 ('/home/oracle/app/oradata/lxdbtest/redo02a.log','/data/oradata/lxdbtest/redo02b.log') SIZE 100M BLOCKSIZE 512,
GROUP 3 ('/home/oracle/app/oradata/lxdbtest/redo03a.log','/data/oradata/lxdbtest/redo03b.log') SIZE 100M BLOCKSIZE 512
MAXLOGFILES 5
MAXLOGMEMBERS 5
MAXLOGHISTORY 1
MAXDATAFILES 600
CHARACTER SET ZHS16GBK
NATIONAL CHARACTER SET AL16UTF16
EXTENT MANAGEMENT LOCAL
DATAFILE '/home/oracle/app/oradata/lxdbtest/system01.dbf' SIZE 2048M REUSE AUTOEXTEND OFF
SYSAUX DATAFILE '/home/oracle/app/oradata/lxdbtest/sysaux01.dbf' SIZE 2048M REUSE AUTOEXTEND OFF
DEFAULT TABLESPACE users
DATAFILE '/home/oracle/app/oradata/lxdbtest/users01.dbf'
SIZE 2048M REUSE AUTOEXTEND OFF
DEFAULT TEMPORARY TABLESPACE temptbs
TEMPFILE '/home/oracle/app/oradata/lxdbtest/temp01.dbf'
SIZE 2048M REUSE AUTOEXTEND OFF
UNDO TABLESPACE undotbs
DATAFILE '/home/oracle/app/oradata/lxdbtest/undotbs01.dbf'
SIZE 2048M REUSE AUTOEXTEND OFF;
有几点需要注意:
1)每个日志文件组的日志要放在不同的物理磁盘上,万一有一个磁盘损坏,也不会丢失数据
2)根据需要选择合适的字符集
3)创建了5个基本的表空间:SYSTEM,SYSAUX,默认表空间,默认临时表空间,默认UNDO表空间
5. 根据需要创建应用程序所需的表空间
对于关键业务的数据,应该创建单独的表空间给它使用(最好把表和索引分开放在表空间)
- SQL> create tablespace p95169tbs
- 2 datafile '/home/oracle/app/oradata/lxdbtest/p95169tbs01.dbf' size 10G,
- 3 '/home/oracle/app/oradata/lxdbtest/p95169tbs02.dbf' size 10G;
- Tablespace created.
SQL> create tablespace p95169tbs
2 datafile '/home/oracle/app/oradata/lxdbtest/p95169tbs01.dbf' size 10G,
3 '/home/oracle/app/oradata/lxdbtest/p95169tbs02.dbf' size 10G; Tablespace created.
6. 构建数据字典视图
- @?/rdbms/admin/catalog.sql
- @?/rdbms/admin/catproc.sql
- @?/sqlplus/admin/pupbld.sql
@?/rdbms/admin/catalog.sql
@?/rdbms/admin/catproc.sql
@?/sqlplus/admin/pupbld.sql
7. 修改system,sys的密码
- alter user sys identified by ***;
- alter user system identified by ***;
alter user sys identified by ***;
alter user system identified by ***;
8. 创建SPFILE
- SQL> create spfile from pfile;
- File created.
SQL> create spfile from pfile; File created.
重启数据库后,将以spfile取代pfile.
最后,再顺便说下如何删除数据库。在删除数据库之前,数据库必须是在mount和restricted session状态,具体如下:
- SQL> startup mount
- SQL> alter system enable restricted session;
- System altered.
- SQL> drop database;
- Database dropped.
SQL> startup mount SQL> alter system enable restricted session; System altered. SQL> drop database; Database dropped.
数据库删除成功后,所有的在线日志文件、数据文件都会一并被删除,但归档日志和备份文件不会被删除。