主要用来记录数据库的配置文件,在数据库启动时,Oracle读取参数文件,并根据参数文件中的参数设置来配置数据库。
如内存池的分配,允许打开的进程数和会话数等。
两类参数文件:
pfile:文本文件的参数文件,可以使用vi,vim等编辑器修改,文件名通常为init<sid>.ora
spfile:二进制的参数文件,不能直接修改,只能存放在Oracle服务器端,可以使用EM或指令来修改
(alter system|session set parameter_name = values <>),
文件名通常为spfile<sid>.ora,支持RMAN备份。
优先级别:
Oracle 启动读取参数文件的顺序,如果个文件都不存在,则Oracle会报错
spfile<sid>.ora --> spfile.ora -->init<sid>.ora
参数文件的路径:
spfle:$ORACLE_HOME/dbs/spfile$ORACLE_SID.ora
pfile(9i):$ORALCE_HOME/dbs/init$ORALCE_SID.ora /*10g以后一般不用init<sid>.ora*/
pfile(10g):$ORALCE_BASE/admin/$ORACLE_SID/pfile /*仅当数据库初始化时使用*/
pfile:$ORACLE_HOME/dbs/init.ora /*默认*/
参数文件之间的转化
spfile 转化为pfile
pfile 转换为spfile
从spfile来生成pfile
create pfile from spfile ,执行完毕后,pfile 将保存为$ORACLE_HOME/dbs/init$ORACLE_SID.ora
也可以指定pfile 的路径:create pfile = '<dir>' from spfile;
由pfile 生成spfile
create spfile from pfile
create spfile from pfile = '<dir>'
create spfile = '<dir>' from pfile
11g中的新指令,从memeory中生成
create spfile = '<dir>' from memeory */
演示:
spfile --> pfile
SQL> create pfile from spfile;
File created.
SQL> ho ls -al /u01/app/oracle/10g/dbs/
total 56
drwxr-x--- 2 oracle oinstall 4096 Apr 8 13:49 .
drwxr-x--- 55 oracle oinstall 4096 Apr 7 09:48 ..
-rw-r----- 1 oracle oinstall 1544 Apr 6 12:06 hc_orcl.dat
-rw-r----- 1 oracle oinstall 8385 Sep 11 1998 init.ora
-rw-r----- 1 oracle oinstall 12920 May 3 2001 initdw.ora
-rw------- 1 oracle oinstall 1155 Apr 8 13:49 initorcl.ora
-rw-r----- 1 oracle oinstall 24 Apr 6 12:06 lkORCL
-rw-r----- 1 oracle oinstall 1536 Apr 7 15:50 orapworcl
-rw-r----- 1 oracle oinstall 3584 Apr 8 11:15 spfileorcl.ora
SQL> ho cat /u01/app/oracle/10g/dbs/initorcl.ora
orcl.__db_cache_size=251658240
orcl.__java_pool_size=4194304
orcl.__large_pool_size=4194304
orcl.__shared_pool_size=142606336
orcl.__streams_pool_size=0
*.audit_file_dest='/u01/app/oracle/admin/orcl/adump'
*.background_dump_dest='/u01/app/oracle/admin/orcl/bdump'
*.compatible='10.2.0.1.0'
*.control_files='/u01/app/oracle/oradata/orcl/control01.ctl','/u01/app/oracle/oradata/orcl/control02.ctl', '/u01/app/oracle/oradata/orcl/control03.ctl'
*.core_dump_dest='/u01/app/oracle/admin/orcl/cdump'
*.db_block_size=8192
*.db_create_file_dest='/u01/app/oracle/oradata/orcl'
*.db_create_online_log_dest_1='/u01/app/oracle/disk1'
*.db_create_online_log_dest_2='/u01/app/oracle/disk2'
*.db_domain=''
*.db_file_multiblock_read_count=16
*.db_name='orcl'
*.db_recovery_file_dest='/u01/app/oracle/flash_recovery_area'
*.db_recovery_file_dest_size=2147483648
*.dispatchers='(PROTOCOL=TCP) (SERVICE=orclXDB)'
*.job_queue_processes=10
*.open_cursors=300
*.pga_aggregate_target=135266304
*.processes=150
*.remote_login_passwordfile='EXCLUSIVE'
*.sga_target=406847488
*.undo_management='AUTO'
*.undo_tablespace='UNDOTBS1'
*.user_dump_dest='/u01/app/oracle/admin/orcl/udump'
pfile --> spfile
SQL> create spfile from pfile; /*使用该命令的时候不能转换,如下报错,因为当前的spfile正在使用*/
create spfile from pfile
*
ERROR at line 1:
ORA-32002: cannot create SPFILE already being used by the instance
SQL> create spfile = '/u01/app/oracle/spfileorcl.ora' from pfile;
File created.
SQL> ho cat /u01/app/oracle/spfileorcl.ora;
a*orcl.__db_cache_size=251658240
orcl.__java_pool_size=4194304
orcl.__large_pool_size=4194304
orcl.__shared_pool_size=142606336
orcl.__streams_pool_size=0
*.audit_file_dest='/u01/app/oracle/admin/orcl/adump'
*.background_dump_dest='/u01/app/oracle/admin/orcl/bdump'
*.compatible='10.2.0.1.0'
*.control_files='/u01/app/oracle/oradata/orcl/control01.ctl','/u01/app/oracle/oradata/orcl/control02.ctl','/u01/app/oracle/oradata/orcl/control03.ctl'
*.core_dump_dest='/u01/app/oracle/admin/orcl/cdump'
*.db_block_size=8192
*.db_create_file_dest='/u01/app/oracle/oradata/orcl'
*.db_create_online_log_dest_1='/u01/app/oracle/disk1'
*.db_create_online_log_dest_2='/u01/app/oracle/disk2'
*.db_domain=''
*.db_file_multiblock_read_count=16
*.db_name='orcl'
*.db_recovery_file_dest='/u01/app/oracle/flash_recovery_area'
*.db_recovery_file_dest_size=2147483648
*.dispatchers='(PROTOCOL=TCP) (SERVICE=orclXDB)'
*.job_queue_processes=10
*.open_cursors=300
*.pga_aggregate_target=135266304
*.processes=150
*.remote_login_passwordfile='EXCLUSIVE'
*.sga_target=406847488
*.undo_management='AUTO'
*.undo_tablespace='UNDOTBS1'
*.user_dump_dest='/u01/app/oracle/admin/orcl/udump'
转换后的使用:
假定修改了initorcl.ora中的参数,但Oracle启动是先读取spfile ,故可以在启动的时候指定用initorcl.ora来
初始化参数,启动完毕后,可以创建spfile,则下一次启动就可以使用新的spfile.
假定我们对initorcl.ora作如下修改:
open_cursors=600
processes=250
则关闭数据库后指定以initorcl.ora参数来启动数据库*/
SQL> startup pfile = '/u01/app/oracle/10g/dbs/initorcl.ora';
ORACLE instance started.
Total System Global Area 406847488 bytes
Fixed Size 1219688 bytes
Variable Size 150995864 bytes
Database Buffers 251658240 bytes
Redo Buffers 2973696 bytes
Database mounted.
Database opened.
SQL> create spfile from pfile; /*修改的内容将会更新到spfile*/
File created.
--查看参数文件的名字
SQL> show parameter service_name
NAME TYPE VALUE
------------------------------------ ----------- ------------------------------
service_names string orcl
--查看当前使用的哪个参数文件启动的
SQL> select distinct isspecified from v$spparameter;
ISSPEC
------
FALSE
如果第一个值是FALSE还是TRUE,如果是FALSE,则是pfile,否则则是spfile.
也可以尝试修改spfile ,如果报错则可以判断是从pfile启动,当然所修改的参数必须是可以修改的*/
SQL> alter system set sga_target = 200m scope = spfile;
alter system set sga_target = 200m scope = spfile
*
ERROR at line 1:
ORA-32001: write to SPFILE requested but no SPFILE specified at startup
--强制启动Oracle后再查看是使用的哪个参数启动的。
SQL> startup force
ORACLE instance started.
Total System Global Area 406847488 bytes
Fixed Size 1219688 bytes
Variable Size 150995864 bytes
Database Buffers 251658240 bytes
Redo Buffers 2973696 bytes
Database mounted.
Database opened.
SQL> select distinct isspecified from v$spparameter;
ISSPEC
------
TRUE
FALSE
第一行为TRUE可知,是从spfile启动的,有两行,其中第二行为FALSE,表示有两个参数文件,一个是spfile,一个是pfile
再次尝试看看能否修改spfile:
SQL> alter system set sga_target = 380m scope = spfile; /*修改成功*/
System altered.
参数文件的修改:
如果是pfile ,直接使用vi,vim来修改即可
如果是spfile ,则使用
alter system|session set parametername = values scope = memory | spfile |both sid = 'sid' | ‘*’;
scope
memory : 只对当前实例有效,下次启动则失效
spfile : 只对spfile 修改,必须经过下一次启动才生效,当前的实例没有修改
both :内存与参数文件都将修改,当不指定scope时,缺省为both.
system | session
system :
-- 查询视图:v$parameter
isses_modifiable 可以被alter session修改
isssy_modifiable 可以被alter system修改
-- sid:
sid :只对某一个实例
* :对所有的实例修改
SQL> show parameter sga_ /*查看与sga有关的参数*/
NAME TYPE VALUE
------------------------------------ ----------- ------------------------------
sga_max_size big integer 388M
sga_target big integer 388M
SQL> alter system set sga_max_size = 350m; /*特殊的参数不能被修改*/
alter system set sga_max_size = 350m
*
ERROR at line 1:
ORA-02095: specified initialization parameter cannot be modified
SQL> a scope = spfile
1* alter system set sga_max_size = 350m scope = spfile
SQL> /
System altered.
SQL> select instance_name from v$instance;
INSTANCE_NAME
----------------
orcl
SQL> alter system set sga_max_size = 350m scope = spfile sid = 'orcl';
System altered.
--只改内存
SQL> show parameter pga
NAME TYPE VALUE
------------------------------------ ----------- ------------------------------
pga_aggregate_target big integer 129M
SQL> alter system set pga_aggregate_target = 130m scope = memory;
System altered.
-- 同时修改内存和参数文件,以下两条语句等效
SQL> alter system set pga_aggregate_target = 130m scope = both;
System altered.
SQL> alter system set pga_aggregate_target = 130m ;
System altered.
--alter session
SQL> show parameter sql_
NAME TYPE VALUE
------------------------------------ ----------- ------------------------------
plsql_ccflags string
plsql_code_type string INTERPRETED
plsql_compiler_flags string INTERPRETED, NON_DEBUG
plsql_debug boolean FALSE
plsql_native_library_dir string
plsql_native_library_subdir_count integer 0
plsql_optimize_level integer 2
plsql_v2_compatibility boolean FALSE
plsql_warnings string DISABLE:ALL
sql92_security boolean FALSE
sql_trace boolean FALSE
NAME TYPE VALUE
------------------------------------ ----------- ------------------------------
sql_version string NATIVE
sqltune_category string DEFAULT
SQL> alter session set sql_trace = true;
Session altered.
-- 可以从v$parameter视图中来得到哪些可以使用alter system修改,哪些可以使用alter session来修改。
SQL> col name for a40
SQL> select NAME,ISSES_MODIFIABLE,ISSYS_MODIFIABLE from v$parameter
2 where name like 'sql%';
NAME ISSES ISSYS_MOD
---------------------------------------- ----- ---------
sql_trace TRUE IMMEDIATE
sql92_security FALSE FALSE
sql_version TRUE FALSE
sqltune_category TRUE IMMEDIATE
-- TURE:可以该类型修改,FLASE:不支持该类型修改,IMMEDIATE:也是支持该类型修改
SQL> alter system set sql_version = 8; /*不支持system类型修改*/
alter system set sql_version = 8
*
ERROR at line 1:
ORA-02096: specified initialization parameter is not modifiable with this option
SQL> alter session set sql_version = 8;
ERROR:
ORA-00096: invalid value 8 for parameter sql_version, must be from among MAX,
NATIVE, 8.1.6, 8.1.5
SQL> alter session set sql_version = '8.1.6'; /*支持session类型修改*/
Session altered.
SQL> select distinct issys_modifiable from v$parameter;
ISSYS_MOD
---------
IMMEDIATE /*动态参数,直接修改到内存的参数alter system set <> = <>,后面不需要跟scope*/
FALSE /*静态参数,不能直接修改到内存,alter system set <> = <> scope = spfile*/
DEFERRED /*会话级别参数,直接通过alter session set <> = <>*/
SQL> select distinct isses_modifiable from v$parameter;
ISSES
-----
TRUE
FALSE
--系统中的常用参数:
SQL> ho ls /u01/app/oracle/10g/dbs/
hc_orcl.dat initdw.ora lkORCL spfileorcl.ora
init.ora initorcl.ora orapworcl
SQL> ho cat /u01/app/oracle/10g/dbs/initorcl.ora
/*下面的参数描述了实例相关池的分配情况*/
orcl.__db_cache_size=251658240
orcl.__java_pool_size=4194304
orcl.__large_pool_size=4194304
orcl.__shared_pool_size=142606336
orcl.__streams_pool_size=0
*.audit_file_dest='/u01/app/oracle/admin/orcl/adump' /*警告日志路径*/
*.background_dump_dest='/u01/app/oracle/admin/orcl/bdump' /*后台进程日志路径*/
*.compatible='10.2.0.1.0' /*版本兼容号*/
/*下面是控制文件的信息*/
*.control_files='/u01/app/oracle/oradata/orcl/control01.ctl','/u01/app/oracle/oradata/orcl/control02.ctl','/u01/app/oracle/oradata/orcl/control03.ctl'
*.core_dump_dest='/u01/app/oracle/admin/orcl/cdump' /*服务器进程相关的日志路径*/
*.db_block_size=8192 /*内存块的大小*/
*.db_create_file_dest='/u01/app/oracle/oradata/orcl' /*tablespace ,datafile路径*/
*.db_create_online_log_dest_1='/u01/app/oracle/disk1' /*联机日志文件路径*/
*.db_create_online_log_dest_2='/u01/app/oracle/disk2' /*联机日志文件路径*/
*.db_domain='' /域名/
*.db_file_multiblock_read_count=16 /*一次可读取块的大小:*8k = 128kb*/
*.db_name='orcl' /数据库标识符/
*.db_recovery_file_dest='/u01/app/oracle/flash_recovery_area' /*闪回路径*/
*.db_recovery_file_dest_size=2147483648 /*闪回区可使用的大小GB*/
*.dispatchers='(PROTOCOL=TCP) (SERVICE=orclXDB)' /*共享服务器的配置参数*/
*.job_queue_processes=10 /*当前作业进程数*/
*.open_cursors=600 /*可打开的游标数*/
*.pga_aggregate_target=135266304 /*服务器进程大小*/
*.processes=250 /*描述当前可以运行的进程数*/
*.remote_login_passwordfile='EXCLUSIVE' /*远程登陆是否要用密码文件*/
*.sga_target=406847488 /*定义了sga的大小*/
*.undo_management='AUTO' /*Undo表空间的管理方式为自动管理*/
*.undo_tablespace='UNDOTBS1' /*指定使用哪一个undo表空间*/
*.user_dump_dest='/u01/app/oracle/admin/orcl/udump' /**/
--11g中的参数文件:
-- 隐藏参数:
SQL> desc x$ksppi /*Name列中为隐藏参数的名字*/
Name Null? Type
----------------------------------------- -------- ----------------------------
ADDR RAW(4)
INDX NUMBER
INST_ID NUMBER
KSPPINM VARCHAR2(80)
KSPPITY NUMBER
KSPPDESC VARCHAR2(255)
KSPPIFLG NUMBER
KSPPILRMFLG NUMBER
KSPPIHASH NUMBER
--下面视图中为隐藏参数的值
SQL> desc x$ksppcv
Name Null? Type
----------------------------------------- -------- ----------------------------
ADDR RAW(4)
INDX NUMBER
INST_ID NUMBER
KSPPSTVL VARCHAR2(512)
KSPPSTDVL VARCHAR2(512)
KSPPSTDF VARCHAR2(9)
KSPPSTVF NUMBER
KSPPSTCMNT VARCHAR2(255)
--使用下面的命令来查看系统中的隐藏参数;
SQL> select ksppinm,ksppstvl from x$ksppi a,x$ksppcv b where a.indx = b.indx;
SQL> a and ksppinm like '%_allow%';
1* select ksppinm,ksppstvl from x$ksppi a,x$ksppcv b where a.indx = b.indx and ksppinm like '%_allow%'
SQL> /
KSPPINM KSPPSTVL
---------------------------------------- ----------
_allow_level_without_connect_by FALSE
_asm_allow_only_raw_disks TRUE
_asm_allow_resilver_corruption FALSE
/*
参数的删除:
对于pfile直接编辑删除即可
对于spfile 例如使用alter system set pga_aggregate_target reset将恢复到默认值 */
SQL> show parameter pga
NAME TYPE VALUE
------------------------------------ ----------- ------------------------------
pga_aggregate_target big integer 130M
SQL> alter system reset pga_aggregate_target scope = spfile sid = '*';
System altered.
-- 修改会默认值后重新启动可以看到该参数的值由M变为M
SQL> show parameter pga;
NAME TYPE VALUE
------------------------------------ ----------- ------------------------------
pga_aggregate_target big integer 76M
参数文件(10g中的参数文件)
主要用来记录数据库的配置文件,在数据库启动时,Oracle读取参数文件,并根据参数文件中的参数设置来配置数据库。
如内存池的分配,允许打开的进程数和会话数等。
两类参数文件:
pfile:文本文件的参数文件,可以使用vi,vim等编辑器修改,文件名通常为init<sid>.ora
spfile:二进制的参数文件,不能直接修改,只能存放在Oracle服务器端,可以使用EM或指令来修改
(alter system|session set parameter_name = values <>),
文件名通常为spfile<sid>.ora,支持RMAN备份。
优先级别:
Oracle 启动读取参数文件的顺序,如果个文件都不存在,则Oracle会报错
spfile<sid>.ora --> spfile.ora -->init<sid>.ora
参数文件的路径:
spfle:$ORACLE_HOME/dbs/spfile$ORACLE_SID.ora
pfile(9i):$ORALCE_HOME/dbs/init$ORALCE_SID.ora /*10g以后一般不用init<sid>.ora*/
pfile(10g):$ORALCE_BASE/admin/$ORACLE_SID/pfile /*仅当数据库初始化时使用*/
pfile:$ORACLE_HOME/dbs/init.ora /*默认*/
参数文件之间的转化
spfile 转化为pfile
pfile 转换为spfile
从spfile来生成pfile
create pfile from spfile ,执行完毕后,pfile 将保存为$ORACLE_HOME/dbs/init$ORACLE_SID.ora
也可以指定pfile 的路径:create pfile = '<dir>' from spfile;
由pfile 生成spfile
create spfile from pfile
create spfile from pfile = '<dir>'
create spfile = '<dir>' from pfile
11g中的新指令,从memeory中生成
create spfile = '<dir>' from memeory */
演示:
spfile --> pfile
SQL> create pfile from spfile;
File created.
SQL> ho ls -al /u01/app/oracle/10g/dbs/
total 56
drwxr-x--- 2 oracle oinstall 4096 Apr 8 13:49 .
drwxr-x--- 55 oracle oinstall 4096 Apr 7 09:48 ..
-rw-r----- 1 oracle oinstall 1544 Apr 6 12:06 hc_orcl.dat
-rw-r----- 1 oracle oinstall 8385 Sep 11 1998 init.ora
-rw-r----- 1 oracle oinstall 12920 May 3 2001 initdw.ora
-rw------- 1 oracle oinstall 1155 Apr 8 13:49 initorcl.ora
-rw-r----- 1 oracle oinstall 24 Apr 6 12:06 lkORCL
-rw-r----- 1 oracle oinstall 1536 Apr 7 15:50 orapworcl
-rw-r----- 1 oracle oinstall 3584 Apr 8 11:15 spfileorcl.ora
SQL> ho cat /u01/app/oracle/10g/dbs/initorcl.ora
orcl.__db_cache_size=251658240
orcl.__java_pool_size=4194304
orcl.__large_pool_size=4194304
orcl.__shared_pool_size=142606336
orcl.__streams_pool_size=0
*.audit_file_dest='/u01/app/oracle/admin/orcl/adump'
*.background_dump_dest='/u01/app/oracle/admin/orcl/bdump'
*.compatible='10.2.0.1.0'
*.control_files='/u01/app/oracle/oradata/orcl/control01.ctl','/u01/app/oracle/oradata/orcl/control02.ctl', '/u01/app/oracle/oradata/orcl/control03.ctl'
*.core_dump_dest='/u01/app/oracle/admin/orcl/cdump'
*.db_block_size=8192
*.db_create_file_dest='/u01/app/oracle/oradata/orcl'
*.db_create_online_log_dest_1='/u01/app/oracle/disk1'
*.db_create_online_log_dest_2='/u01/app/oracle/disk2'
*.db_domain=''
*.db_file_multiblock_read_count=16
*.db_name='orcl'
*.db_recovery_file_dest='/u01/app/oracle/flash_recovery_area'
*.db_recovery_file_dest_size=2147483648
*.dispatchers='(PROTOCOL=TCP) (SERVICE=orclXDB)'
*.job_queue_processes=10
*.open_cursors=300
*.pga_aggregate_target=135266304
*.processes=150
*.remote_login_passwordfile='EXCLUSIVE'
*.sga_target=406847488
*.undo_management='AUTO'
*.undo_tablespace='UNDOTBS1'
*.user_dump_dest='/u01/app/oracle/admin/orcl/udump'
pfile --> spfile
SQL> create spfile from pfile; /*使用该命令的时候不能转换,如下报错,因为当前的spfile正在使用*/
create spfile from pfile
*
ERROR at line 1:
ORA-32002: cannot create SPFILE already being used by the instance
SQL> create spfile = '/u01/app/oracle/spfileorcl.ora' from pfile;
File created.
SQL> ho cat /u01/app/oracle/spfileorcl.ora;
a*orcl.__db_cache_size=251658240
orcl.__java_pool_size=4194304
orcl.__large_pool_size=4194304
orcl.__shared_pool_size=142606336
orcl.__streams_pool_size=0
*.audit_file_dest='/u01/app/oracle/admin/orcl/adump'
*.background_dump_dest='/u01/app/oracle/admin/orcl/bdump'
*.compatible='10.2.0.1.0'
*.control_files='/u01/app/oracle/oradata/orcl/control01.ctl','/u01/app/oracle/oradata/orcl/control02.ctl','/u01/app/oracle/oradata/orcl/control03.ctl'
*.core_dump_dest='/u01/app/oracle/admin/orcl/cdump'
*.db_block_size=8192
*.db_create_file_dest='/u01/app/oracle/oradata/orcl'
*.db_create_online_log_dest_1='/u01/app/oracle/disk1'
*.db_create_online_log_dest_2='/u01/app/oracle/disk2'
*.db_domain=''
*.db_file_multiblock_read_count=16
*.db_name='orcl'
*.db_recovery_file_dest='/u01/app/oracle/flash_recovery_area'
*.db_recovery_file_dest_size=2147483648
*.dispatchers='(PROTOCOL=TCP) (SERVICE=orclXDB)'
*.job_queue_processes=10
*.open_cursors=300
*.pga_aggregate_target=135266304
*.processes=150
*.remote_login_passwordfile='EXCLUSIVE'
*.sga_target=406847488
*.undo_management='AUTO'
*.undo_tablespace='UNDOTBS1'
*.user_dump_dest='/u01/app/oracle/admin/orcl/udump'
转换后的使用:
假定修改了initorcl.ora中的参数,但Oracle启动是先读取spfile ,故可以在启动的时候指定用initorcl.ora来
初始化参数,启动完毕后,可以创建spfile,则下一次启动就可以使用新的spfile.
假定我们对initorcl.ora作如下修改:
open_cursors=600
processes=250
则关闭数据库后指定以initorcl.ora参数来启动数据库*/
SQL> startup pfile = '/u01/app/oracle/10g/dbs/initorcl.ora';
ORACLE instance started.
Total System Global Area 406847488 bytes
Fixed Size 1219688 bytes
Variable Size 150995864 bytes
Database Buffers 251658240 bytes
Redo Buffers 2973696 bytes
Database mounted.
Database opened.
SQL> create spfile from pfile; /*修改的内容将会更新到spfile*/
File created.
--查看参数文件的名字
SQL> show parameter service_name
NAME TYPE VALUE
------------------------------------ ----------- ------------------------------
service_names string orcl
--查看当前使用的哪个参数文件启动的
SQL> select distinct isspecified from v$spparameter;
ISSPEC
------
FALSE
如果第一个值是FALSE还是TRUE,如果是FALSE,则是pfile,否则则是spfile.
也可以尝试修改spfile ,如果报错则可以判断是从pfile启动,当然所修改的参数必须是可以修改的*/
SQL> alter system set sga_target = 200m scope = spfile;
alter system set sga_target = 200m scope = spfile
*
ERROR at line 1:
ORA-32001: write to SPFILE requested but no SPFILE specified at startup
--强制启动Oracle后再查看是使用的哪个参数启动的。
SQL> startup force
ORACLE instance started.
Total System Global Area 406847488 bytes
Fixed Size 1219688 bytes
Variable Size 150995864 bytes
Database Buffers 251658240 bytes
Redo Buffers 2973696 bytes
Database mounted.
Database opened.
SQL> select distinct isspecified from v$spparameter;
ISSPEC
------
TRUE
FALSE
第一行为TRUE可知,是从spfile启动的,有两行,其中第二行为FALSE,表示有两个参数文件,一个是spfile,一个是pfile
再次尝试看看能否修改spfile:
SQL> alter system set sga_target = 380m scope = spfile; /*修改成功*/
System altered.
参数文件的修改:
如果是pfile ,直接使用vi,vim来修改即可
如果是spfile ,则使用
alter system|session set parametername = values scope = memory | spfile |both sid = 'sid' | ‘*’;
scope
memory : 只对当前实例有效,下次启动则失效
spfile : 只对spfile 修改,必须经过下一次启动才生效,当前的实例没有修改
both :内存与参数文件都将修改,当不指定scope时,缺省为both.
system | session
system :
-- 查询视图:v$parameter
isses_modifiable 可以被alter session修改
isssy_modifiable 可以被alter system修改
-- sid:
sid :只对某一个实例
* :对所有的实例修改
SQL> show parameter sga_ /*查看与sga有关的参数*/
NAME TYPE VALUE
------------------------------------ ----------- ------------------------------
sga_max_size big integer 388M
sga_target big integer 388M
SQL> alter system set sga_max_size = 350m; /*特殊的参数不能被修改*/
alter system set sga_max_size = 350m
*
ERROR at line 1:
ORA-02095: specified initialization parameter cannot be modified
SQL> a scope = spfile
1* alter system set sga_max_size = 350m scope = spfile
SQL> /
System altered.
SQL> select instance_name from v$instance;
INSTANCE_NAME
----------------
orcl
SQL> alter system set sga_max_size = 350m scope = spfile sid = 'orcl';
System altered.
--只改内存
SQL> show parameter pga
NAME TYPE VALUE
------------------------------------ ----------- ------------------------------
pga_aggregate_target big integer 129M
SQL> alter system set pga_aggregate_target = 130m scope = memory;
System altered.
-- 同时修改内存和参数文件,以下两条语句等效
SQL> alter system set pga_aggregate_target = 130m scope = both;
System altered.
SQL> alter system set pga_aggregate_target = 130m ;
System altered.
--alter session
SQL> show parameter sql_
NAME TYPE VALUE
------------------------------------ ----------- ------------------------------
plsql_ccflags string
plsql_code_type string INTERPRETED
plsql_compiler_flags string INTERPRETED, NON_DEBUG
plsql_debug boolean FALSE
plsql_native_library_dir string
plsql_native_library_subdir_count integer 0
plsql_optimize_level integer 2
plsql_v2_compatibility boolean FALSE
plsql_warnings string DISABLE:ALL
sql92_security boolean FALSE
sql_trace boolean FALSE
NAME TYPE VALUE
------------------------------------ ----------- ------------------------------
sql_version string NATIVE
sqltune_category string DEFAULT
SQL> alter session set sql_trace = true;
Session altered.
-- 可以从v$parameter视图中来得到哪些可以使用alter system修改,哪些可以使用alter session来修改。
SQL> col name for a40
SQL> select NAME,ISSES_MODIFIABLE,ISSYS_MODIFIABLE from v$parameter
2 where name like 'sql%';
NAME ISSES ISSYS_MOD
---------------------------------------- ----- ---------
sql_trace TRUE IMMEDIATE
sql92_security FALSE FALSE
sql_version TRUE FALSE
sqltune_category TRUE IMMEDIATE
-- TURE:可以该类型修改,FLASE:不支持该类型修改,IMMEDIATE:也是支持该类型修改
SQL> alter system set sql_version = 8; /*不支持system类型修改*/
alter system set sql_version = 8
*
ERROR at line 1:
ORA-02096: specified initialization parameter is not modifiable with this option
SQL> alter session set sql_version = 8;
ERROR:
ORA-00096: invalid value 8 for parameter sql_version, must be from among MAX,
NATIVE, 8.1.6, 8.1.5
SQL> alter session set sql_version = '8.1.6'; /*支持session类型修改*/
Session altered.
SQL> select distinct issys_modifiable from v$parameter;
ISSYS_MOD
---------
IMMEDIATE /*动态参数,直接修改到内存的参数alter system set <> = <>,后面不需要跟scope*/
FALSE /*静态参数,不能直接修改到内存,alter system set <> = <> scope = spfile*/
DEFERRED /*会话级别参数,直接通过alter session set <> = <>*/
SQL> select distinct isses_modifiable from v$parameter;
ISSES
-----
TRUE
FALSE
--系统中的常用参数:
SQL> ho ls /u01/app/oracle/10g/dbs/
hc_orcl.dat initdw.ora lkORCL spfileorcl.ora
init.ora initorcl.ora orapworcl
SQL> ho cat /u01/app/oracle/10g/dbs/initorcl.ora
/*下面的参数描述了实例相关池的分配情况*/
orcl.__db_cache_size=251658240
orcl.__java_pool_size=4194304
orcl.__large_pool_size=4194304
orcl.__shared_pool_size=142606336
orcl.__streams_pool_size=0
*.audit_file_dest='/u01/app/oracle/admin/orcl/adump' /*警告日志路径*/
*.background_dump_dest='/u01/app/oracle/admin/orcl/bdump' /*后台进程日志路径*/
*.compatible='10.2.0.1.0' /*版本兼容号*/
/*下面是控制文件的信息*/
*.control_files='/u01/app/oracle/oradata/orcl/control01.ctl','/u01/app/oracle/oradata/orcl/control02.ctl','/u01/app/oracle/oradata/orcl/control03.ctl'
*.core_dump_dest='/u01/app/oracle/admin/orcl/cdump' /*服务器进程相关的日志路径*/
*.db_block_size=8192 /*内存块的大小*/
*.db_create_file_dest='/u01/app/oracle/oradata/orcl' /*tablespace ,datafile路径*/
*.db_create_online_log_dest_1='/u01/app/oracle/disk1' /*联机日志文件路径*/
*.db_create_online_log_dest_2='/u01/app/oracle/disk2' /*联机日志文件路径*/
*.db_domain='' /域名/
*.db_file_multiblock_read_count=16 /*一次可读取块的大小:*8k = 128kb*/
*.db_name='orcl' /数据库标识符/
*.db_recovery_file_dest='/u01/app/oracle/flash_recovery_area' /*闪回路径*/
*.db_recovery_file_dest_size=2147483648 /*闪回区可使用的大小GB*/
*.dispatchers='(PROTOCOL=TCP) (SERVICE=orclXDB)' /*共享服务器的配置参数*/
*.job_queue_processes=10 /*当前作业进程数*/
*.open_cursors=600 /*可打开的游标数*/
*.pga_aggregate_target=135266304 /*服务器进程大小*/
*.processes=250 /*描述当前可以运行的进程数*/
*.remote_login_passwordfile='EXCLUSIVE' /*远程登陆是否要用密码文件*/
*.sga_target=406847488 /*定义了sga的大小*/
*.undo_management='AUTO' /*Undo表空间的管理方式为自动管理*/
*.undo_tablespace='UNDOTBS1' /*指定使用哪一个undo表空间*/
*.user_dump_dest='/u01/app/oracle/admin/orcl/udump' /**/
--11g中的参数文件:
-- 隐藏参数:
SQL> desc x$ksppi /*Name列中为隐藏参数的名字*/
Name Null? Type
----------------------------------------- -------- ----------------------------
ADDR RAW(4)
INDX NUMBER
INST_ID NUMBER
KSPPINM VARCHAR2(80)
KSPPITY NUMBER
KSPPDESC VARCHAR2(255)
KSPPIFLG NUMBER
KSPPILRMFLG NUMBER
KSPPIHASH NUMBER
--下面视图中为隐藏参数的值
SQL> desc x$ksppcv
Name Null? Type
----------------------------------------- -------- ----------------------------
ADDR RAW(4)
INDX NUMBER
INST_ID NUMBER
KSPPSTVL VARCHAR2(512)
KSPPSTDVL VARCHAR2(512)
KSPPSTDF VARCHAR2(9)
KSPPSTVF NUMBER
KSPPSTCMNT VARCHAR2(255)
--使用下面的命令来查看系统中的隐藏参数;
SQL> select ksppinm,ksppstvl from x$ksppi a,x$ksppcv b where a.indx = b.indx;
SQL> a and ksppinm like '%_allow%';
1* select ksppinm,ksppstvl from x$ksppi a,x$ksppcv b where a.indx = b.indx and ksppinm like '%_allow%'
SQL> /
KSPPINM KSPPSTVL
---------------------------------------- ----------
_allow_level_without_connect_by FALSE
_asm_allow_only_raw_disks TRUE
_asm_allow_resilver_corruption FALSE
/*
参数的删除:
对于pfile直接编辑删除即可
对于spfile 例如使用alter system set pga_aggregate_target reset将恢复到默认值 */
SQL> show parameter pga
NAME TYPE VALUE
------------------------------------ ----------- ------------------------------
pga_aggregate_target big integer 130M
SQL> alter system reset pga_aggregate_target scope = spfile sid = '*';
System altered.
-- 修改会默认值后重新启动可以看到该参数的值由M变为M
SQL> show parameter pga;
NAME TYPE VALUE
------------------------------------ ----------- ------------------------------
pga_aggregate_target big integer 76M