月归档:四月 2013

从执行效率上分析为什么SYSTEM不适宜存储业务数据

为什么不建议客户把业务数据存放到SYSTEM表空间中,一直想通过试验的数据来说明问题,今天见老熊的邮件和同事的blog(为什么不要把用户表存储到SYSTEM表空间)来说明把业务数据存放在SYSTEM表空间中效率的影响
数据库版本

SQL> select * from v$version;

BANNER
--------------------------------------------------------------------------------
Oracle Database 11g Enterprise Edition Release 11.2.0.3.0 - 64bit Production
PL/SQL Release 11.2.0.3.0 - Production
CORE    11.2.0.3.0      Production
TNS for Linux: Version 11.2.0.3.0 - Production
NLSRTL Version 11.2.0.3.0 - Production

创建测试环境

SQL> conn chf/xifenfei
Connected.

SQL> create table t_xifenfei_u(id number) tablespace users;

Table created.

SQL> create table t_xifenfei_s(id number) tablespace system;

Table created.

SQL>  select table_name,tablespace_name from user_tables;   

TABLE_NAME                     TABLESPACE_NAME
------------------------------ ------------------------------
T_XIFENFEI_U                   USERS
T_XIFENFEI_S                   SYSTEM

非系统表空间测试

SQL> select STATISTIC#,NAME from v$statname where name='CPU used by this session';

STATISTIC# NAME
---------- ----------------------------------------------------------------
        17 CPU used by this session

SQL> select * from v$mystat where STATISTIC#=17;

       SID STATISTIC#      VALUE
---------- ---------- ----------
       189         17         33

SQL> set timing on
SQL> begin
  2  for i in 1..200000 loop
  3  insert into t_xifenfei_u values(i);
  4  end loop;
  5  end;
  6  /

PL/SQL procedure successfully completed.

Elapsed: 00:00:05.97
SQL> select * from v$mystat where STATISTIC#=17;

       SID STATISTIC#      VALUE
---------- ---------- ----------
       189         17        629

Elapsed: 00:00:00.00

测试结果显示,非系统表空间中的表插入200000条记录,使用时间为5.97秒;使用CPU为629-33=596

系统表空间测试

SQL> begin
  2  for i in 1..200000 loop
  3  insert into t_xifenfei_s values(i);
  4  end loop;
  5  end;
  6  /

PL/SQL procedure successfully completed.

Elapsed: 00:00:14.00
SQL> select * from v$mystat where STATISTIC#=17;

       SID STATISTIC#      VALUE
---------- ---------- ----------
       189         17       2019

Elapsed: 00:00:00.00

测试结果显示,对系统表空间中的表插入200000条记录,使用时间为14秒;使用CPU为2019-629=1390,基本上可以看出来无论是CPU消耗还是执行时间上,系统表空间占用都是非系统表空间两倍以上

分析原因

SQL> conn / as sysdba
Connected.

SQL> select * from (SELECT i.ksppinm NAME, i.ksppity TYPE, v.ksppstvl VALUE, 
  2  v.ksppstdf isdefault FROM x$ksppi i, x$ksppcv v WHERE i.indx = v.indx AND 
  3  i.ksppinm LIKE '/_%%' ESCAPE '/') where name like '%db_alw%';

NAME                                 TYPE VALUE           ISDEFAULT
------------------------------ ---------- --------------- ---------
_db_always_check_system_ts              1 TRUE            TRUE

SQL> alter system set "_db_always_check_system_ts"=false;

System altered.

SQL> conn chf/xifenfei
Connected.

SQL>  select * from v$mystat where STATISTIC#=17;   

       SID STATISTIC#      VALUE
---------- ---------- ----------
       127         17          1

Elapsed: 00:00:00.01
SQL> begin
  2  for i in 1..200000 loop
  3  insert into t_xifenfei_s values(i);
  4  end loop;
  5  end;
  6  /

PL/SQL procedure successfully completed.

Elapsed: 00:00:06.03

SQL> select * from v$mystat where STATISTIC#=17;   

       SID STATISTIC#      VALUE
---------- ---------- ----------
       127         17        582

通过这里可以发现,修改_db_always_check_system_ts=false之后,system表空间的操作基本上和非系统表空间所差无几(执行时间6.01秒,占用CPU 581=582-1)
在数据库默认情况下db_block_checking和db_block_checksum的值无论如何设置都不能对于SYSTEM表空间生效,也就是说SYSTEM表空间在没有修改_db_always_check_system_ts=false之前,对所有的块操作都要进行db_block_checking和db_block_checksum验证,从而使得数据块的操作效率较非SYSTEM表空间低下。对于一些插入较为频繁的aud$、FGA_LOG$、DEF$_AQCALL等表建议迁移到其他表空间

备注说明
DB_BLOCK_CHECKING

DB_BLOCK_CHECKING specifies whether or not Oracle performs block checking for database blocks.

Values:

OFF or FALSE

No block checking is performed for blocks in user tablespaces. However,
semantic block checking for SYSTEM tablespace blocks is always turned on.

LOW

Basic block header checks are performed after block contents change in memory 
(for example, after UPDATE or INSERT statements, on-disk reads, or 
inter-instance block transfers in Oracle RAC).

MEDIUM

All LOW checks and full semantic checks are performed for all objects except indexes 
(whose contents can be reconstructed by a drop+rebuild on encountering a corruption).

FULL or TRUE

All LOW and MEDIUM checks and full semantic checks are performed for all objects.

Oracle checks a block by going through the data in the block, making sure it is logically 
self-consistent. Block checking can often prevent memory and data corruption. Block checking 
typically causes 1% to 10% overhead,depending on workload and the parameter value. 
The more updates or inserts in a workload, the more expensive it is to turn on block checking.
You should set DB_BLOCK_CHECKING to FULL if the performance overhead is acceptable.

For backward compatibility, the use of FALSE (implying OFF) and TRUE (implying FULL) is preserved.

DB_BLOCK_CHECKSUM

DB_BLOCK_CHECKSUM determines whether DBWn and the direct loader will calculate a checksum 
(a number calculated from all the bytes stored in the block) and store it in the cache header 
of every data block when writing it to disk. Checksums are verified when a block is read - 
only if this parameter is TYPICAL or FULL and the last write of the block stored a checksum. 
In FULL mode, Oracle also verifies the checksum before a change application from update/delete 
statements and recomputes it after the change is applied. In addition, Oracle gives every log block
a checksum before writing it to the current log.

Starting with Oracle Database 11g, most of the log block checksum is done by the generating foreground 
processes, while the LGWR performs the rest of the work, for better CPU and cache efficiency. 
Prior to Oracle Database 11g, the LGWR solely performed the log block checksum.

If this parameter is set to OFF, DBWn calculates checksums only for the SYSTEM tablespace, 
but not for user tablespaces. In addition, no log checksum is performed when this parameter is set to OFF.

Checksums allow Oracle to detect corruption caused by underlying disks, storage systems, or I/O systems. 
If set to FULL, DB_BLOCK_CHECKSUM also catches in-memory corruptions and stops them from making it to the disk.
Turning on this feature in TYPICAL mode causes only an additional 1% to 2% overhead. In the FULL mode it causes
4% to 5% overhead. Oracle recommends that you set DB_BLOCK_CHECKSUM to TYPICAL.

For backward compatibility the use of TRUE (implying TYPICAL) and FALSE (implying OFF) values is preserved.
发表在 Oracle | 一条评论

ORACLE 7.3.4 截图欣赏

此多媒体陈列厅包含 10 张图像

在windows 4运行oracle 7.3.4是一个难得的搭配,今天有机会一见 … 继续阅读

更多多媒体陈列厅 | 评论关闭

使用oradebug hang住某个进程

在一次测试中,需要模拟在归档模式下,数据库发生多次redo切换而这些redo并未被归档的情景,一般来说这样的情况只有在归档目录满的时候会遇到.但是在日常测试中,这样的归档目录满的模拟不太现实,可以通过oradebug SUSPEND来实现该功能,让arcn进程挂起
配置log_archive_max_processes为1(可以配置多个,但是1个更加方便测试)

SQL> show parameter log_archive_max_processes;

NAME                                 TYPE        VALUE
------------------------------------ ----------- ------------------------------
log_archive_max_processes            integer     1

该配置可以在线修改,但是不重启数据库不一定完全生效(测试环境本来是4,修改为1之后,还有arc0和arc1进程)

查找arcn进程

[oracle@localhost trace]$ ps -ef|grep ora_arc
oracle    3686     1  0 21:07 ?        00:00:00 ora_arc0_test

oradebug进程(session 1)

SQL> oradebug  setospid  3686
Oracle pid: 57, Unix process pid: 3686, image: oracle@localhost.localdomain (ARC0)
SQL> oradebug SUSPEND
Statement processed.

alert日志

Tue Apr 16 21:09:42 2013
Unix process pid: 3686, image: oracle@localhost.localdomain (ARC0) flash frozen [ command #1 ]

切换日志(session 2)

SQL> archive log list;
Database log mode              Archive Mode
Automatic archival             Enabled
Archive destination            USE_DB_RECOVERY_FILE_DEST
Oldest online log sequence     53
Next log sequence to archive   55
Current log sequence           55
SQL> alter system switch logfile;

System altered.

SQL> /

System altered.

SQL> alter system checkpoint;

System altered.

SQL> set lines 134
SQL> col member for a40
SQL>   SELECT thread#,
  2           a.sequence#,a.ARCHIVED,
  3           a.group#,
  4           TO_CHAR (first_change#, '9999999999999999') "SCN",
  5           a.status,
  6           MEMBER
  7      FROM v$log a, v$logfile b
  8     WHERE a.group# = B.GROUP#
  9  ORDER BY a.sequence# DESC;

   THREAD#  SEQUENCE# ARC     GROUP# SCN               STATUS           MEMBER
---------- ---------- --- ---------- ----------------- ---------------- ----------------------------
         1         57 NO           3            261053 CURRENT          /data/oracle/oradata/test/redo03.log
         1         56 NO           2            261046 INACTIVE         /data/oracle/oradata/test/redo02.log
         1         55 NO           1            260856 INACTIVE         /data/oracle/oradata/test/redo01.log

SQL> alter system switch logfile;--hang住

此时alert日志

Tue Apr 16 21:10:19 2013
Thread 1 advanced to log sequence 56 (LGWR switch)
  Current log# 2 seq# 56 mem# 0: /data/oracle/oradata/test/redo02.log
Tue Apr 16 21:10:36 2013
Thread 1 advanced to log sequence 57 (LGWR switch)
  Current log# 3 seq# 57 mem# 0: /data/oracle/oradata/test/redo03.log

Tue Apr 16 21:13:13 2013
ORACLE Instance test - Can not allocate log, archival required
Thread 1 cannot allocate new log, sequence 58
All online logs needed archiving
  Current log# 3 seq# 57 mem# 0: /data/oracle/oradata/test/redo03.log

oradebug RESUME(session 1)

SQL> oradebug RESUME  
Statement processed.

alert日志

Tue Apr 16 21:14:23 2013
Unix process pid: 3686, image: oracle@localhost.localdomain (ARC0) resumed
Archived Log entry 2 added for thread 1 sequence 55 ID 0x7dd4ccb7 dest 1:
Archived Log entry 3 added for thread 1 sequence 56 ID 0x7dd4ccb7 dest 1:

hang住会话继续执行(session 2)

SQL> alter system switch logfile;

System altered.
发表在 Oracle | 3 条评论