标签云
asm恢复 bbed bootstrap$ dul In Memory kcbzib_kcrsds_1 kccpb_sanity_check_2 MySQL恢复 ORA-00312 ORA-00607 ORA-00704 ORA-00742 ORA-01110 ORA-01555 ORA-01578 ORA-08103 ORA-600 2131 ORA-600 2662 ORA-600 2663 ORA-600 3020 ORA-600 4000 ORA-600 4137 ORA-600 4193 ORA-600 4194 ORA-600 16703 ORA-600 kcbzib_kcrsds_1 ORA-600 KCLCHKBLK_4 ORA-15042 ORA-15196 ORACLE 12C oracle dul ORACLE PATCH Oracle Recovery Tools oracle加密恢复 oracle勒索 oracle勒索恢复 oracle异常恢复 Oracle 恢复 ORACLE恢复 ORACLE数据库恢复 oracle 比特币 OSD-04016 YOUR FILES ARE ENCRYPTED 勒索恢复 比特币加密文章分类
- Others (2)
- 中间件 (2)
- WebLogic (2)
- 操作系统 (103)
- 数据库 (1,716)
- DB2 (22)
- MySQL (74)
- Oracle (1,576)
- Data Guard (52)
- EXADATA (8)
- GoldenGate (24)
- ORA-xxxxx (160)
- ORACLE 12C (72)
- ORACLE 18C (6)
- ORACLE 19C (15)
- ORACLE 21C (3)
- Oracle 23ai (8)
- Oracle ASM (68)
- Oracle Bug (8)
- Oracle RAC (54)
- Oracle 安全 (6)
- Oracle 开发 (28)
- Oracle 监听 (28)
- Oracle备份恢复 (575)
- Oracle安装升级 (94)
- Oracle性能优化 (62)
- 专题索引 (5)
- 勒索恢复 (81)
- PostgreSQL (18)
- PostgreSQL恢复 (6)
- SQL Server (28)
- SQL Server恢复 (9)
- TimesTen (7)
- 达梦数据库 (2)
- 生活娱乐 (2)
- 至理名言 (11)
- 虚拟化 (2)
- VMware (2)
- 软件开发 (37)
- Asp.Net (9)
- JavaScript (12)
- PHP (2)
- 小工具 (20)
-
最近发表
- 不当使用_allow_resetlogs_corruption参数引起ORA-600 2662错误
- CSSD signal 11 in thread clssnmRcfgMgrThread故障处理
- 使用sid方式直接访问pdb(USE_SID_AS_SERVICE_LISTENER)
- ORA-00069: cannot acquire lock — table locks disabled for xxxx
- ORA-600 [4000] [a]相关bug
- sql server数据库“正在恢复”故障处理
- 如何判断数据文件是否处于begin backup状态
- CDM备份缺少归档打开数据库报ORA-600 kcbzib_kcrsds_1故障处理
- ORA-07445: exception encountered: core dump [expgod()+43] [IN_PAGE_ERROR]
- 2025年第一起ORA-600 16703故障恢复
- _gc_undo_affinity=FALSE触发ORA-01558
- public授权语句
- 中文环境显示AR8MSWIN1256(阿拉伯语字符集)
- 处理 Oracle 块损坏
- Oracle各种类型坏块说明和处理
- fio测试io,导致磁盘文件系统损坏故障恢复
- ORA-742 写丢失常见bug记录
- Oracle 19c 202501补丁(RUs+OJVM)-19.26
- 避免 19c 数据库性能问题需要考虑的事项 (Doc ID 3050476.1)
- Bug 21915719 Database hang or may fail to OPEN in 12c IBM AIX or HPUX Itanium – ORA-742, DEADLOCK or ORA-600 [kcrfrgv_nextlwn_scn] ORA-600 [krr_process_read_error_2]
标签归档:12.1.0.2
ORACLE 12C In-Memory功能性能测试
启用In-Memory功能
数据库版本12.1.0.2及其以上版本,inmemory_size参数设置为合适值
SQL> SELECT * FROM V$VERSION; BANNER CON_ID -------------------------------------------------------------------------------- ---------- Oracle Database 12c Enterprise Edition Release 12.1.0.2.0 - 64bit 0 PL/SQL Release 12.1.0.2.0 - 0 CORE 12.1.0.2.0 0 TNS for Linux: Version 12.1.0.2.0 - 0 NLSRTL Version 12.1.0.2.0 - 0 SQL> SHOW PARAMETER inmemory; NAME TYPE VALUE ------------------------------------ ----------- ------------------------------ inmemory_clause_default string inmemory_force string DEFAULT inmemory_query string ENABLE inmemory_size big integer 200M
创建表
这里可以知道,创建表大小为13631488,但是未使用In-Memory功能
SQL> create table t_xifenfei_in_memory as select * from dba_objects; Table created. SQL> SELECT BYTES FROM USER_SEGMENTS WHERE SEGMENT_NAME='T_XIFENFEI_IN_MEMORY'; BYTES ---------- 13631488 SQL> select TABLE_NAME,INMEMORY_PRIORITY,INMEMORY_DISTRIBUTE,INMEMORY_COMPRESSION from user_tables; TABLE_NAME INMEMORY INMEMORY_DISTRI INMEMORY_COMPRESS ------------------------------ -------- --------------- ----------------- T_XIFENFEI_IN_MEMORY SQL> SELECT * FROM V$INMEMORY_AREA; POOL ALLOC_BYTES USED_BYTES POPULATE_STATUS CON_ID -------------------------- ----------- ---------- -------------------------- ---------- 1MB POOL 166723584 0 DONE 3 64KB POOL 33554432 0 DONE 3
未使用In-Memory功能测试
SQL> SET AUTOT TRACE SQL> SELECT * FROM T_XIFENFEI_IN_MEMORY; 90902 rows selected. Execution Plan ---------------------------------------------------------- Plan hash value: 3598036702 ------------------------------------------------------------------------------------------ | Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | ------------------------------------------------------------------------------------------ | 0 | SELECT STATEMENT | | 90902 | 9M| 427 (1)| 00:00:01 | | 1 | TABLE ACCESS FULL| T_XIFENFEI_IN_MEMORY | 90902 | 9M| 427 (1)| 00:00:01 | ------------------------------------------------------------------------------------------ Statistics ---------------------------------------------------------- 5 recursive calls 0 db block gets 7505 consistent gets 1527 physical reads 0 redo size 12125231 bytes sent via SQL*Net to client 67212 bytes received via SQL*Net from client 6062 SQL*Net roundtrips to/from client 2 sorts (memory) 0 sorts (disk) 90902 rows processed
这里可以看到未使用In-Memory功能,数据库查询执行计划使用TABLE ACCESS FULL,consistent gets为7505
使用In-Memory功能测试
SQL> alter table T_XIFENFEI_IN_MEMORY inmemory; Table altered. SQL> select TABLE_NAME,INMEMORY_PRIORITY,INMEMORY_DISTRIBUTE,INMEMORY_COMPRESSION from user_tables; TABLE_NAME INMEMORY INMEMORY_DISTRI INMEMORY_COMPRESS ------------------------------ -------- --------------- ----------------- T_XIFENFEI_IN_MEMORY NONE AUTO DISTRIBUTE FOR QUERY --因为只是把该表设置了INMEMORY,但是未查询过,所以查询V$INMEMORY_AREA中未使用相关内存 SQL> SELECT * FROM V$INMEMORY_AREA; POOL ALLOC_BYTES USED_BYTES POPULATE_STATUS CON_ID -------------------------- ----------- ---------- -------------------------- ---------- 1MB POOL 166723584 0 DONE 3 64KB POOL 33554432 0 DONE 3 --进行一次全表扫描 SQL> SELECT COUNT(*) FROM T_XIFENFEI_IN_MEMORY; COUNT(*) ---------- 90902 --再次查看,已经使用了分配的In-Memory中内存 SQL> SELECT * FROM V$INMEMORY_AREA; POOL ALLOC_BYTES USED_BYTES POPULATE_STATUS CON_ID -------------------------- ----------- ---------- -------------------------- ---------- 1MB POOL 166723584 4194304 DONE 3 64KB POOL 33554432 131072 DONE 3 SQL> SET AUTOT TRACE SQL> SELECT * FROM T_XIFENFEI_IN_MEMORY; 90902 rows selected. Execution Plan ---------------------------------------------------------- Plan hash value: 3598036702 --------------------------------------------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | --------------------------------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | 90902 | 9M| 20 (45)| 00:00:01 | | 1 | TABLE ACCESS INMEMORY FULL| T_XIFENFEI_IN_MEMORY | 90902 | 9M| 20 (45)| 00:00:01 | --------------------------------------------------------------------------------------------------- Statistics ---------------------------------------------------------- 3 recursive calls 0 db block gets 4 consistent gets 0 physical reads 0 redo size 4946298 bytes sent via SQL*Net to client 67212 bytes received via SQL*Net from client 6062 SQL*Net roundtrips to/from client 0 sorts (memory) 0 sorts (disk) 90902 rows processed
这里我们可以发现,使用了In-Memory功能之后,数据库consistent gets为4,相比未使用In-Memory之前的7505,性能最少提高近2000倍.
ORACLE 12C In-Memory组件初试
根据Oracle官方的宣传12.1.0.2的In-Memory组件实现内存列存储提高Oracle性能而且弥补在列存储中的不足。感谢Lunar的文档支持
12.1.0.2版本
[oracle@localhost ~]$ sqlplus chf/xifenfei@pdb1 SQL*Plus: Release 12.1.0.2.0 Beta on Thu Apr 24 21:39:43 2014 Copyright (c) 1982, 2014, Oracle. All rights reserved. Connected to: Oracle Database 12c Enterprise Edition Release 12.1.0.2.0 - 64bit With the Partitioning, OLAP, Advanced Analytics and Real Application Testing options SQL> select * from v$version; BANNER CON_ID -------------------------------------------------------------------------------- ---------- Oracle Database 12c Enterprise Edition Release 12.1.0.2.0 - 64bit 0 PL/SQL Release 12.1.0.2.0 - 0 CORE 12.1.0.2.0 0 TNS for Linux: Version 12.1.0.2.0 - 0 NLSRTL Version 12.1.0.2.0 - 0
关于In-Memory组件
SQL> select parameter,value from v$option where parameter like 'In-Memory%'; PARAMETER VALUE ---------------------------------------------------------------- ------------- In-Memory Column Store TRUE In-Memory Aggregation TRUE
关于inmemory参数
SQL> select NAME,value,DESCRIPTION from v$parameter where NAME like 'inmemory%'; NAME VALUE -------------------- -------------------- DESCRIPTION --------------------------------------------------- inmemory_size 0 size in bytes of in-memory area inmemory_clause_defa ult Default in-memory clause for new tables inmemory_force DEFAULT Force tables to be in-memory or not inmemory_query ENABLE Specifies whether in-memory queries are allowed
启用In-Memory功能
SQL> show parameter inmemory; NAME TYPE VALUE ------------------------------------ ----------- ------------------------------ inmemory_clause_default string inmemory_force string DEFAULT inmemory_query string ENABLE inmemory_size big integer 0 SQL> alter system set inmemory_size=200M scope=spfile; System altered. SQL> shutdown immediate Pluggable Database closed. SQL> startup Pluggable Database opened. SQL> show parameter inmemory; NAME TYPE VALUE ------------------------------------ ----------- ---------------------- inmemory_clause_default string inmemory_force string DEFAULT inmemory_query string ENABLE inmemory_size big integer 200M
创建测试表
SQL> create table t_xifenfei_in_memory as select * from dba_objects; Table created. SQL> select TABLE_NAME,INMEMORY_PRIORITY,INMEMORY_DISTRIBUTE,INMEMORY_COMPRESSION from user_tables; TABLE_NAME INMEMORY INMEMORY_DISTRI INMEMORY_COMPRESS ------------------------------ -------- --------------- ----------------- T_XIFENFEI_IN_MEMORY SQL> alter table T_XIFENFEI_IN_MEMORY inmemory; Table altered. SQL> select TABLE_NAME,INMEMORY_PRIORITY,INMEMORY_DISTRIBUTE,INMEMORY_COMPRESSION from user_tables; TABLE_NAME INMEMORY INMEMORY_DISTRI INMEMORY_COMPRESS ------------------------- -------- --------------- ----------------- T_XIFENFEI_IN_MEMORY NONE AUTO DISTRIBUTE FOR QUERY