Chinaunix首页 | 论坛 | 博客
  • 博客访问: 240041
  • 博文数量: 115
  • 博客积分: 10
  • 博客等级: 民兵
  • 技术积分: 930
  • 用 户 组: 普通用户
  • 注册时间: 2010-12-30 05:27
文章分类

全部博文(115)

文章存档

2011年(10)

2010年(21)

2009年(19)

2008年(65)

我的朋友

分类: Oracle

2011-02-09 16:35:00

本文作者: biti_rainy (biti_rainy@itpub.net)

 

摘要:本文通过简单实验来尝试说明cursor_sharing=similar的含义。
1.1.        实验现象
我们先看看在表没有分析无统计数据情况下的表现  

sql> alter session set cursor_sharing = similar; 

  

session altered. 

 

sql> select name,value from v$sysstat where name like %parse%; 

  

name                                                                  value 

---------------------------------------------------------------- ---------- 

parse time cpu                                                         4948 

parse time elapsed                                                    4468 

parse count (total)                                                   170148 

parse count (hard)                                                    1619  (硬分析次数)

parse count (failures)                                                80 

  

sql> select count(*) from t where object_id = 1000; 

  

   count(*) 

---------- 

          0 

  

sql> select name,value from v$sysstat where name like %parse%; 

  

name                                                                  value 

---------------------------------------------------------------- ---------- 

parse time cpu                                                         4948 

parse time elapsed                                                     4468 

parse count (total)                                                  170172 

parse count (hard)                                                     1620 

parse count (failures)                                                   80 

  

sql> / 

  

name                                                                  value 

---------------------------------------------------------------- ---------- 

parse time cpu                                                         4948 

parse time elapsed                                                     4468 

parse count (total)                                                  170176 

parse count (hard)                                                     1620 

parse count (failures)                                                   80 

  

sql> select count(*) from t where object_id = 1000; 

  

   count(*) 

---------- 

          0 

  

sql> select name,value from v$sysstat where name like %parse%; 

  

name                                                                  value 

---------------------------------------------------------------- ---------- 

parse time cpu                                                         4948 

parse time elapsed                                                     4468 

parse count (total)                                                  170178 

parse count (hard)                                                     1620 

parse count (failures)                                                   80 

  

sql> select count(*) from t where object_id = 1001; 

  

   count(*) 

---------- 

          0 

  

sql> select name,value from v$sysstat where name like %parse%; 

  

name                                                                  value 

---------------------------------------------------------------- ---------- 

parse time cpu                                                         4948 

parse time elapsed                                                     4468 

parse count (total)                                                  170180 

parse count (hard)                                              1620(即使object_id发生变化依然没有硬解析)

parse count (failures)                                                   80 

 

我们再来看分析表和字段信息后的表现

sql> analyze table t1 compute statistics for table for columns object_id; 

  

table analyzed. 

  

sql> select name,value from v$sysstat where name like %parse%; 

  

name                                                                  value 

---------------------------------------------------------------- ---------- 

parse time cpu                                                         4973 

parse time elapsed                                                     4495 

parse count (total)                                                  170982 

parse count (hard)                                                     1640 

parse count (failures)                                                   80 

  

sql> select count(*) from t1 where object_id = 5000; 

  

   count(*) 

---------- 

          0 

  

sql> select name,value from v$sysstat where name like %parse%; 

  

name                                                                  value 

---------------------------------------------------------------- ---------- 

parse time cpu                                                         4973 

parse time elapsed                                                     4495 

parse count (total)                                                  170984 

parse count (hard)                                                     1641 

parse count (failures)                                                   80 

  

sql> select count(*) from t1 where object_id = 5000; 

  

   count(*) 

---------- 

          0 

  

sql> select name,value from v$sysstat where name like %parse%; 

  

name                                                                  value 

---------------------------------------------------------------- ---------- 

parse time cpu                                                         4973 

parse time elapsed                                                     4495 

parse count (total)                                                  171008 

parse count (hard)                                                     1641 (重复执行没发生变化)

parse count (failures)                                                   80 

  

sql> select count(*) from t1 where object_id = 5001; 

  

   count(*) 

---------- 

          0 

  

sql> select name,value from v$sysstat where name like %parse%; 

  

name                                                                  value 

---------------------------------------------------------------- ---------- 

parse time cpu                                                         4973 

parse time elapsed                                                     4495 

parse count (total)                                                  171010 

parse count (hard)                                                 1642 (当object_id变化的时候产生硬分析)

parse count (failures)                                                   80 

  

sql> 

 

sql> select sql_text,child_number from v$sql where sql_text like select count(*) from t1 where%; 

  

sql_text 

------------------------------------------------------------------------------

child_number 

------------ 

select count(*) from t1 where object_id = :"sys_b_0" 

            0 

  

select count(*) from t1 where object_id = :"sys_b_0" 

            1

 
1.2.        结论
可以看出若存在object_id的 histograms ,则每次是不同的值的时候都产生硬解析 ,若不存在 histograms,则不产生硬解析。换句话说,当表的字段被分析过存在histograms的时候,similar 的表现和exact一样,当表的字段没被分析,不存在histograms的时候,similar的表现和force一样。这样避免了一味地如force一样转换成变量形式,因为有histograms的情况下转换成变量之后就容易产生错误的执行计划,没有利用上统计信息。而exact呢,在没有histograms的情况下也要分别产生硬解析,这样的话,由于执行计划不会受到数据分布的影响(因为没有统计信息)重新解析是没有实质意义的。而similar则综合了两者的优点。

 

 

作者简介: 



网名coolyl

oracle专家。有丰富的oracle实践经验,对体系结构、备份恢复、sql优化、整体性能优化、oracle internal都有深入研究。

个人教育和成长经历:

对数据库应用设计中如何正确地应用oracle特性以扬长避短具有深刻理解。

有丰富的oracle实践经验,对数据库的体系结构、备份恢复、sql优化、数据库整体性能优化、oracle internal都有深入研究。

曾于某电信集成公司负责计费系统的开发,然后成为某系统集成公司的dba,再辗转在香港一家跨国公司珠海研发中心担任技术负责人(公司主要产品就是sql与数据库优化工具,产品主要销往欧洲和北美),此后成为自由职业者,为客户提供独立的oracle数据库的技术服务和高级性能调整等培训,同时提供itpub华南和华东的培训。

目前服务于国内某大型电子商务网站,维护系统数据库并提供开发支持.

擅长的技术领域:oracle 

目前的工作动态:alibaba  dba

个人blog:http://blog.itpub.net/biti_riany

e-mail:biti_rainy@itpub.net
阅读(946) | 评论(0) | 转发(0) |
给主人留下些什么吧!~~