<?xml version="1.0" encoding="UTF-8"?><rss version="2.0"
	xmlns:content="http://purl.org/rss/1.0/modules/content/"
	xmlns:wfw="http://wellformedweb.org/CommentAPI/"
	xmlns:dc="http://purl.org/dc/elements/1.1/"
	xmlns:atom="http://www.w3.org/2005/Atom"
	xmlns:sy="http://purl.org/rss/1.0/modules/syndication/"
	xmlns:slash="http://purl.org/rss/1.0/modules/slash/"
	>

<channel>
	<title>scripts &#8211; 但行好事 莫问前程</title>
	<atom:link href="http://www.jydba.net/index.php/archives/category/scripts/feed" rel="self" type="application/rss+xml" />
	<link>http://www.jydba.net</link>
	<description></description>
	<lastBuildDate>Thu, 24 Apr 2025 01:57:11 +0000</lastBuildDate>
	<language>zh-CN</language>
	<sy:updatePeriod>hourly</sy:updatePeriod>
	<sy:updateFrequency>1</sy:updateFrequency>
	<generator>https://wordpress.org/?v=4.9.10</generator>
	<item>
		<title>Using SQL Script Get Information  about ASM</title>
		<link>http://www.jydba.net/index.php/archives/2031</link>
		<comments>http://www.jydba.net/index.php/archives/2031#respond</comments>
		<pubDate>Thu, 12 Jan 2017 02:28:11 +0000</pubDate>
		<dc:creator><![CDATA[YongJing(敬勇)]]></dc:creator>
				<category><![CDATA[scripts]]></category>

		<guid isPermaLink="false">http://www.jydba.net/?p=2031</guid>
		<description><![CDATA[当诊断ASM问题时,如果知道ASM磁盘组名,磁盘组类型,磁盘状态,ASM实例初始 [&#8230;... ]]></description>
				<content:encoded><![CDATA[<p>当诊断ASM问题时,如果知道ASM磁盘组名,磁盘组类型,磁盘状态,ASM实例初始化参数,与是否有rebalance操作在执行,对于诊断都是有帮助的。在这些情况下,通常会生成一个html格式的报告,通过在ASM实例中运行SQL脚本来生成。该脚本如下:</p>
<pre>[grid@jyrac1 ~]$ cat asm_report.sql

spool /home/grid/ASM_report.html
set markup html on
set echo off
set feedback off
set pages 10000
break on INST_ID on GROUP_NUMBER
prompt ASM report
select to_char(SYSDATE, 'DD-Mon-YYYY HH24:MI:SS') "Time" from dual;
prompt Version
select * from V$VERSION where BANNER like '%Database%' order by 1;
prompt Cluster wide operations
select * from GV$ASM_OPERATION order by 1;
prompt
prompt Disk groups, including the dismounted disk groups
select * from V$ASM_DISKGROUP order by 1, 2, 3;
prompt All disks, including the candidate disks
select GROUP_NUMBER, DISK_NUMBER, FAILGROUP, NAME, LABEL, PATH, MOUNT_STATUS, HEADER_STATUS, STATE, OS_MB, TOTAL_MB, FREE_MB, CREATE_DATE, MOUNT_DATE, SECTOR_SIZE, VOTING_FILE, FAILGROUP_TYPE
from V$ASM_DISK
where MODE_STATUS='ONLINE'
order by 1, 2;
prompt Offline disks
select GROUP_NUMBER, DISK_NUMBER, FAILGROUP, NAME, MOUNT_STATUS, HEADER_STATUS, STATE, REPAIR_TIMER
from V$ASM_DISK
where MODE_STATUS='OFFLINE'
order by 1, 2;
prompt Disk group attributes
select GROUP_NUMBER, NAME, VALUE from V$ASM_ATTRIBUTE where NAME not like 'template%' order by 1;
prompt Connected clients
select * from V$ASM_CLIENT order by 1, 2;
prompt Non-default ASM specific initialisation parameters, including the hidden ones
select KSPPINM "Parameter", KSPFTCTXVL "Value"
from X$KSPPI a, X$KSPPCV2 b
where a.INDX + 1 = KSPFTCTXPN and (KSPPINM like '%asm%' or KSPPINM like '%balance%' or KSPPINM like '%auto_manage%') and kspftctxdf = 'FALSE'
order by 1 desc;
prompt Memory, cluster and instance specific initialisation parameters
select NAME "Parameter", VALUE "Value", ISDEFAULT "Default"
from V$PARAMETER
where NAME like '%target%' or NAME like '%pool%' or NAME like 'cluster%' or NAME like 'instance%'
order by 1;
prompt Disk group imbalance
select g.NAME "Diskgroup",
100*(max((d.TOTAL_MB-d.FREE_MB + (128*g.ALLOCATION_UNIT_SIZE/1048576))/(d.TOTAL_MB + (128*g.ALLOCATION_UNIT_SIZE/1048576)))-min((d.TOTAL_MB-d.FREE_MB + (128*g.ALLOCATION_UNIT_SIZE/1048576))/(d.TOTAL_MB + (128*g.ALLOCATION_UNIT_SIZE/1048576))))/max((d.TOTAL_MB-d.FREE_MB + (128*g.ALLOCATION_UNIT_SIZE/1048576))/(d.TOTAL_MB + (128*g.ALLOCATION_UNIT_SIZE/1048576))) "Imbalance",
count(*) "Disk count",
g.TYPE "Type"
from V$ASM_DISK_STAT d , V$ASM_DISKGROUP_STAT g
where d.GROUP_NUMBER = g.GROUP_NUMBER and d.STATE = 'NORMAL' and d.MOUNT_STATUS = 'CACHED'
group by g.NAME, g.TYPE;
prompt End of ASM report
set markup html off
set echo on
set feedback on
exit

</pre>
<p>为了生成报告并保存为/home/grid/ASM_report.html,以Grid Infrastructure用户(通常为grid或oracle)来执行</p>
<pre>[grid@jyrac1 ~]$ sqlplus / as sysasm @asm_report.sql

SQL*Plus: Release 11.2.0.4.0 Production on Thu Jan 12 09:44:24 2017

Copyright (c) 1982, 2013, Oracle.  All rights reserved.


Connected to:
Oracle Database 11g Enterprise Edition Release 11.2.0.4.0 - 64bit Production
With the Real Application Clusters and Automatic Storage Management options

ASM report
</pre>
<p>&nbsp;</p>
<p>&nbsp;</p>
<table border="1" summary="Script output" width="90%" align="center">
<tbody>
<tr>
<th scope="col">Time</th>
</tr>
<tr>
<td>12-Jan-2017 09:44:24</td>
</tr>
</tbody>
</table>
<p>&nbsp;</p>
<p>Version</p>
<p>&nbsp;</p>
<p>&nbsp;</p>
<table border="1" summary="Script output" width="90%" align="center">
<tbody>
<tr>
<th scope="col">BANNER</th>
</tr>
<tr>
<td>Oracle Database 11g Enterprise Edition Release 11.2.0.4.0 &#8211; 64bit Production</td>
</tr>
</tbody>
</table>
<p>&#8230;..</p>
<pre>NORMAL
</pre>
<p>&nbsp;</p>
<p>End of ASM report<br />
SQL&gt; set feedback on SQL&gt; exit Disconnected from Oracle Database 11g Enterprise Edition Release 11.2.0.4.0 &#8211; 64bit Production With the Real Application Clusters and Automatic Storage Management options</p>
<p>报告内容<br />
报告首先显示了报告生成的时间与ASM的版本。<br />
<a href="http://www.jydba.net/wp-content/uploads/1-4.jpg"><img class="alignnone size-medium wp-image-2032" src="http://www.jydba.net/wp-content/uploads/1-4-580x96.jpg" alt="" width="580" height="96" srcset="http://www.jydba.net/wp-content/uploads/1-4-580x96.jpg 580w, http://www.jydba.net/wp-content/uploads/1-4-768x128.jpg 768w, http://www.jydba.net/wp-content/uploads/1-4-940x156.jpg 940w, http://www.jydba.net/wp-content/uploads/1-4.jpg 1251w" sizes="(max-width: 580px) 100vw, 580px" /></a><br />
如果存在执行的任何ASM操作将会显示,我这里没有正在执行的ASM操作。所以Cluster wide operations下面没有内容。</p>
<p>接下来可以看到所有磁盘组,包含dismounted磁盘组。<br />
<a href="http://www.jydba.net/wp-content/uploads/2-4.jpg"><img class="alignnone size-medium wp-image-2033" src="http://www.jydba.net/wp-content/uploads/2-4-580x88.jpg" alt="" width="580" height="88" srcset="http://www.jydba.net/wp-content/uploads/2-4-580x88.jpg 580w, http://www.jydba.net/wp-content/uploads/2-4-768x116.jpg 768w, http://www.jydba.net/wp-content/uploads/2-4-940x143.jpg 940w, http://www.jydba.net/wp-content/uploads/2-4.jpg 1121w" sizes="(max-width: 580px) 100vw, 580px" /></a><br />
接下来可以看到磁盘,也会包含那些状态为candidate的磁盘<br />
<a href="http://www.jydba.net/wp-content/uploads/3-3.jpg"><img class="alignnone size-medium wp-image-2034" src="http://www.jydba.net/wp-content/uploads/3-3-580x161.jpg" alt="" width="580" height="161" srcset="http://www.jydba.net/wp-content/uploads/3-3-580x161.jpg 580w, http://www.jydba.net/wp-content/uploads/3-3-768x213.jpg 768w, http://www.jydba.net/wp-content/uploads/3-3-940x261.jpg 940w, http://www.jydba.net/wp-content/uploads/3-3.jpg 1241w" sizes="(max-width: 580px) 100vw, 580px" /></a><br />
接下来是关于脱机磁盘的信息,因为我这里没有脱机磁盘,所以该部分内容为空</p>
<p>再接下来就是磁盘组属性<br />
<a href="http://www.jydba.net/wp-content/uploads/4-4.jpg"><img class="alignnone size-medium wp-image-2035" src="http://www.jydba.net/wp-content/uploads/4-4-580x252.jpg" alt="" width="580" height="252" srcset="http://www.jydba.net/wp-content/uploads/4-4-580x252.jpg 580w, http://www.jydba.net/wp-content/uploads/4-4-768x334.jpg 768w, http://www.jydba.net/wp-content/uploads/4-4-940x409.jpg 940w, http://www.jydba.net/wp-content/uploads/4-4.jpg 1235w" sizes="(max-width: 580px) 100vw, 580px" /></a><br />
接下来是连接到ASM的客户端<br />
<a href="http://www.jydba.net/wp-content/uploads/5-3.jpg"><img class="alignnone size-medium wp-image-2036" src="http://www.jydba.net/wp-content/uploads/5-3-580x81.jpg" alt="" width="580" height="81" srcset="http://www.jydba.net/wp-content/uploads/5-3-580x81.jpg 580w, http://www.jydba.net/wp-content/uploads/5-3-768x107.jpg 768w, http://www.jydba.net/wp-content/uploads/5-3-940x131.jpg 940w, http://www.jydba.net/wp-content/uploads/5-3.jpg 1245w" sizes="(max-width: 580px) 100vw, 580px" /></a><br />
ASM初始化参数包含隐含参数与一些Exadata特定参数(_auto_manage)<br />
<a href="http://www.jydba.net/wp-content/uploads/6-3.jpg"><img class="alignnone size-medium wp-image-2037" src="http://www.jydba.net/wp-content/uploads/6-3-580x80.jpg" alt="" width="580" height="80" srcset="http://www.jydba.net/wp-content/uploads/6-3-580x80.jpg 580w, http://www.jydba.net/wp-content/uploads/6-3-768x106.jpg 768w, http://www.jydba.net/wp-content/uploads/6-3-940x130.jpg 940w, http://www.jydba.net/wp-content/uploads/6-3.jpg 1238w" sizes="(max-width: 580px) 100vw, 580px" /></a><br />
内存,集群与实例特定参数<br />
<a href="http://www.jydba.net/wp-content/uploads/7-3.jpg"><img class="alignnone size-medium wp-image-2038" src="http://www.jydba.net/wp-content/uploads/7-3-580x152.jpg" alt="" width="580" height="152" srcset="http://www.jydba.net/wp-content/uploads/7-3-580x152.jpg 580w, http://www.jydba.net/wp-content/uploads/7-3-768x202.jpg 768w, http://www.jydba.net/wp-content/uploads/7-3-940x247.jpg 940w, http://www.jydba.net/wp-content/uploads/7-3.jpg 1244w" sizes="(max-width: 580px) 100vw, 580px" /></a><br />
最后是磁盘组不平衡信息<br />
<a href="http://www.jydba.net/wp-content/uploads/8-4.jpg"><img class="alignnone size-medium wp-image-2039" src="http://www.jydba.net/wp-content/uploads/8-4-580x79.jpg" alt="" width="580" height="79" srcset="http://www.jydba.net/wp-content/uploads/8-4-580x79.jpg 580w, http://www.jydba.net/wp-content/uploads/8-4-768x105.jpg 768w, http://www.jydba.net/wp-content/uploads/8-4-940x129.jpg 940w, http://www.jydba.net/wp-content/uploads/8-4.jpg 1248w" sizes="(max-width: 580px) 100vw, 580px" /></a></p>
<p>小结:<br />
使用这个报告可以快速查看ASM相关信息,它也可以作为ASM设置的一种备份。</p>
]]></content:encoded>
			<wfw:commentRss>http://www.jydba.net/index.php/archives/2031/feed</wfw:commentRss>
		<slash:comments>0</slash:comments>
		</item>
		<item>
		<title>查询缓冲区缓存忙等待</title>
		<link>http://www.jydba.net/index.php/archives/1734</link>
		<comments>http://www.jydba.net/index.php/archives/1734#respond</comments>
		<pubDate>Thu, 22 Jan 2015 05:14:55 +0000</pubDate>
		<dc:creator><![CDATA[YongJing(敬勇)]]></dc:creator>
				<category><![CDATA[scripts]]></category>

		<guid isPermaLink="false">http://www.jydba.net/?p=1734</guid>
		<description><![CDATA[set pages 9999; column buffer_busy_wait  [&#8230;... ]]></description>
				<content:encoded><![CDATA[<p>set pages 9999;<br />
column buffer_busy_wait format 999,999,999;<br />
column mydate heading &#8216;yr. mo dy Hr.&#8217;</p>
<p>select<br />
to_char(snap_time,&#8217;yyyy-mm-dd HH24&#8242;) mydate,<br />
new.name,<br />
new.buffer_busy_wait-old.buffer_busy_wait buffer_busy_wait<br />
from<br />
perfstat.stats$buffer_pool_statistics old,<br />
perfstat.stats$buffer_pool_statistics new,<br />
perfstat.stats$snapshot sn<br />
where<br />
new.name=old.name<br />
and new.snap_id=sn.snap_id<br />
and old.snap_id=sn.snap_id-1<br />
and new.buffer_busy_wait-old.buffer_busy_wait&gt;1<br />
group by to_char(snap_time,&#8217;yyyy-mm-dd HH24&#8242;),<br />
new.name,<br />
new.buffer_busy_wait-old.buffer_busy_wait;</p>
]]></content:encoded>
			<wfw:commentRss>http://www.jydba.net/index.php/archives/1734/feed</wfw:commentRss>
		<slash:comments>0</slash:comments>
		</item>
		<item>
		<title>通过脚本来查看alert.log</title>
		<link>http://www.jydba.net/index.php/archives/1713</link>
		<comments>http://www.jydba.net/index.php/archives/1713#respond</comments>
		<pubDate>Mon, 12 Jan 2015 04:49:03 +0000</pubDate>
		<dc:creator><![CDATA[YongJing(敬勇)]]></dc:creator>
				<category><![CDATA[scripts]]></category>

		<guid isPermaLink="false">http://www.jydba.net/?p=1713</guid>
		<description><![CDATA[create or replace directory data_dir as  [&#8230;... ]]></description>
				<content:encoded><![CDATA[<p>create or replace directory data_dir as &#8216;/oracle/diag/rdbms/develop/develop/trace&#8217;;</p>
<p>CREATE TABLE alert_log<br />
(<br />
text_line varchar2(2000)<br />
)<br />
ORGANIZATION EXTERNAL<br />
(<br />
TYPE ORACLE_LOADER<br />
DEFAULT DIRECTORY data_dir<br />
ACCESS PARAMETERS<br />
(<br />
records delimited by newline<br />
fields<br />
REJECT ROWS WITH ALL NULL FIELDS<br />
)<br />
LOCATION<br />
(<br />
&#8216;alert_develop.log&#8217;<br />
)<br />
)<br />
REJECT LIMIT unlimited;</p>
<p>select to_char(last_time,&#8217;dd-mon-yyyy hh24:mi&#8217;) shutdown,<br />
to_char(start_time,&#8217;dd-mon-yyyy hh24:mi&#8217;) startup,<br />
round((start_time-last_time)*24*60,2) mins_down,<br />
round((last_time-lag(start_time) over (order by r)),2) days_up,<br />
case when (lead(r) over (order by r) is null )<br />
then round((sysdate-start_time),2)<br />
end days_still_up<br />
from (<br />
select r,<br />
to_date(last_time, &#8216;Dy Mon DD HH24:MI:SS YYYY&#8217;) last_time,<br />
to_date(start_time,&#8217;Dy Mon DD HH24:MI:SS YYYY&#8217;) start_time<br />
from (<br />
select r,<br />
text_line,<br />
lag(text_line,1) over (order by r) start_time,<br />
lag(text_line,2) over (order by r) last_time<br />
from (<br />
select rownum r, text_line<br />
from alert_log<br />
where text_line like &#8216;___ ___ __ __:__:__ 20__&#8217;<br />
or text_line like &#8216;Starting ORACLE instance %&#8217;<br />
)<br />
)<br />
where text_line like &#8216;Starting ORACLE instance %&#8217;<br />
and start_time not like &#8216;Starting ORACLE instance %&#8217; and last_time not like &#8216;Starting ORACLE instance %&#8217;</p>
<p>)</p>
<p>select to_char(&#8216;Fri Mar 09 11:20:21 2012&#8242;,&#8217;dd-mon-yyyy hh24:mi&#8217;) from dual</p>
]]></content:encoded>
			<wfw:commentRss>http://www.jydba.net/index.php/archives/1713/feed</wfw:commentRss>
		<slash:comments>0</slash:comments>
		</item>
		<item>
		<title>获取latch信息</title>
		<link>http://www.jydba.net/index.php/archives/1732</link>
		<comments>http://www.jydba.net/index.php/archives/1732#respond</comments>
		<pubDate>Thu, 12 Jun 2014 05:12:50 +0000</pubDate>
		<dc:creator><![CDATA[YongJing(敬勇)]]></dc:creator>
				<category><![CDATA[scripts]]></category>

		<guid isPermaLink="false">http://www.jydba.net/?p=1732</guid>
		<description><![CDATA[DEF _lhp_what=&#8221;&#38;1&#8243; DEF _ [&#8230;... ]]></description>
				<content:encoded><![CDATA[<p>DEF _lhp_what=&#8221;&amp;1&#8243;<br />
DEF _lhp_sid=&#8221;&amp;2&#8243;<br />
DEF _lhp_name=&#8221;&amp;3&#8243;<br />
DEF _lhp_samples=&#8221;&amp;4&#8243;</p>
<p>COL name FOR A35 TRUNCATE<br />
COL latchprof_total_ms HEAD &#8220;Held ms&#8221; FOR 999999.999<br />
COL latchprof_pct_total_samples head &#8220;Held %&#8221; format 999.99<br />
COL latchprof_avg_ms HEAD &#8220;Avg hold ms&#8221; FOR 999.999<br />
COL dist_samples HEAD Gets<br />
COL total_samples HEAD Held</p>
<p>BREAK ON lhp_name SKIP 1</p>
<p>DEF _IF_ORA_10_OR_HIGHER=&#8221;&#8211;&#8221;</p>
<p>PROMPT<br />
PROMPT &#8212; LatchProf 2.00 by Tanel Poder ( http://www.tanelpoder.com )</p>
<p>COL latchprof_oraversion NOPRINT NEW_VALUE _IF_ORA_10_OR_HIGHER</p>
<p>SET TERMOUT OFF<br />
SELECT DECODE(SUBSTR(BANNER, INSTR(BANNER, &#8216;Release &#8216;)+8,1), 1, &#8221;, &#8216;&#8211;&#8216;) latchprof_oraversion<br />
FROM v$version WHERE ROWNUM=1;<br />
SET TERMOUT ON</p>
<p>WITH<br />
t1 AS (SELECT hsecs FROM v$timer),<br />
samples AS (<br />
SELECT /*+ ORDERED USE_NL(l) USE_NL(s) USE_NL(l.gv$latchholder.x$ksuprlat) NO_TRANSFORM_DISTINCT_AGG */<br />
&amp;_lhp_what<br />
&amp;_IF_ORA_10_OR_HIGHER , COUNT(DISTINCT gets) dist_samples<br />
, COUNT(*) total_samples<br />
, COUNT(*) / &amp;_lhp_samples total_samples_pct<br />
FROM<br />
(SELECT /*+ NO_MERGE */ 1 FROM DUAL CONNECT BY LEVEL &lt;= &amp;_lhp_samples) s,<br />
v$latchholder l,<br />
(SELECT<br />
sid indx<br />
, sql_hash_value sqlhash<br />
, sql_address sqladdr<br />
&amp;_IF_ORA_10_OR_HIGHER , sql_child_number sqlchild<br />
&amp;_IF_ORA_10_OR_HIGHER , sql_id sqlid<br />
FROM v$session) s<br />
WHERE<br />
l.sid LIKE &#8216;&amp;_lhp_sid&#8217;<br />
AND (LOWER(l.name) LIKE LOWER(&#8216;%&amp;_lhp_name%&#8217;) OR LOWER(RAWTOHEX(l.laddr)) LIKE LOWER(&#8216;%&amp;_lhp_name%&#8217;))<br />
AND l.sid = s.indx<br />
GROUP BY<br />
&amp;_lhp_what<br />
ORDER BY<br />
total_samples DESC<br />
),<br />
t2 AS (SELECT hsecs FROM v$timer)<br />
SELECT /*+ ORDERED */<br />
&amp;_lhp_what<br />
, s.total_samples<br />
&amp;_IF_ORA_10_OR_HIGHER , s.dist_samples<br />
&#8212; , s.total_samples_pct<br />
, s.total_samples / &amp;_lhp_samples * 100 latchprof_pct_total_samples<br />
, (t2.hsecs &#8211; t1.hsecs) * 10 * s.total_samples / &amp;_lhp_samples latchprof_total_ms<br />
&#8212; s.dist_events,<br />
&amp;_IF_ORA_10_OR_HIGHER , (t2.hsecs &#8211; t1.hsecs) * 10 * s.total_samples / dist_samples / &amp;_lhp_samples latchprof_avg_ms<br />
FROM<br />
t1,<br />
samples s,<br />
t2<br />
WHERE ROWNUM &lt;= 30<br />
/</p>
]]></content:encoded>
			<wfw:commentRss>http://www.jydba.net/index.php/archives/1732/feed</wfw:commentRss>
		<slash:comments>0</slash:comments>
		</item>
		<item>
		<title>获取当前所有会话等待事件信息</title>
		<link>http://www.jydba.net/index.php/archives/1730</link>
		<comments>http://www.jydba.net/index.php/archives/1730#respond</comments>
		<pubDate>Wed, 15 Jan 2014 05:11:24 +0000</pubDate>
		<dc:creator><![CDATA[YongJing(敬勇)]]></dc:creator>
				<category><![CDATA[scripts]]></category>

		<guid isPermaLink="false">http://www.jydba.net/?p=1730</guid>
		<description><![CDATA[select s.sid,s.username,s.event,s.wait_t [&#8230;... ]]></description>
				<content:encoded><![CDATA[<p>select s.sid,s.username,s.event,s.wait_time,s.state,s.seconds_in_wait,p.PROGRAM,s.MACHINE,<br />
(select c.SQL_FULLTEXT from v$sqlarea c where c.SQL_ID=s.SQL_ID) sql_fulltext,<br />
(select c.BIND_DATA from v$sqlarea c where c.SQL_ID=s.SQL_ID) BIND_DATA,s.SQL_ID,<br />
s.P1TEXT,s.p1,s.p1raw,s.P2TEXT,s.p2,s.P2RAW,s.P3TEXT,s.P3,s.P3RAW<br />
from v$session s,v$process p<br />
where s.username is not null and s.PADDR=p.ADDR<br />
and s.event not like&#8217;%SQL*Net%&#8217;<br />
order by s.wait_time desc</p>
]]></content:encoded>
			<wfw:commentRss>http://www.jydba.net/index.php/archives/1730/feed</wfw:commentRss>
		<slash:comments>0</slash:comments>
		</item>
		<item>
		<title>获取数据库每天的排序统计数据脚本</title>
		<link>http://www.jydba.net/index.php/archives/1716</link>
		<comments>http://www.jydba.net/index.php/archives/1716#respond</comments>
		<pubDate>Sun, 12 Jan 2014 04:52:46 +0000</pubDate>
		<dc:creator><![CDATA[YongJing(敬勇)]]></dc:creator>
				<category><![CDATA[scripts]]></category>

		<guid isPermaLink="false">http://www.jydba.net/?p=1716</guid>
		<description><![CDATA[set pages 9999; column sorts_memory form [&#8230;... ]]></description>
				<content:encoded><![CDATA[<p>set pages 9999;<br />
column sorts_memory format 999,999,999<br />
column sorts_disk format 999,999,999<br />
column ratio format .9999</p>
<p>select<br />
to_char(sn.snap_time,&#8217;day&#8217;) DAY,<br />
avg(newmem.value-oldmem.value) sorts_memory,<br />
avg(newdsk.value-olddsk.value) sorts_dsk<br />
from<br />
stats$sysstat oldmem,<br />
stats$sysstat newmem,<br />
stats$sysstat newdsk,<br />
stats$sysstat olddsk,<br />
stats$snapshot sn<br />
where<br />
newdsk.snap_id=sn.snap_id<br />
and olddsk.snap_id=sn.snap_id-1<br />
and newmem.snap_id=sn.snap_id<br />
and oldmem.snap_id=sn.snap_id-1<br />
and oldmem.name=&#8217;sorts (memory)&#8217;<br />
and newmem.name=&#8217;sorts (memory)&#8217;<br />
and olddsk.name=&#8217;sorts (disk)&#8217;<br />
and newdsk.name=&#8217;sorts (disk)&#8217;<br />
and newmem.value-oldmem.value&gt;0<br />
and newdsk.value-olddsk.value&gt;0<br />
group by to_char(sn.snap_time,&#8217;day&#8217;);</p>
<p>select<br />
to_char(sn.begin_interval_time,&#8217;day&#8217;) DAY,<br />
avg(newmem.value-oldmem.value) sorts_memory,<br />
avg(newdsk.value-olddsk.value) sorts_dsk<br />
from<br />
dba_hist_sysstat oldmem,<br />
dba_hist_sysstat newmem,<br />
dba_hist_sysstat newdsk,<br />
dba_hist_sysstat olddsk,<br />
dba_hist_snapshot sn<br />
where<br />
newdsk.snap_id=sn.snap_id<br />
and olddsk.snap_id=sn.snap_id-1<br />
and newmem.snap_id=sn.snap_id<br />
and oldmem.snap_id=sn.snap_id-1<br />
and oldmem.stat_name=&#8217;sorts (memory)&#8217;<br />
and newmem.stat_name=&#8217;sorts (memory)&#8217;<br />
and olddsk.stat_name=&#8217;sorts (disk)&#8217;<br />
and newdsk.stat_name=&#8217;sorts (disk)&#8217;<br />
and newmem.value-oldmem.value&gt;0<br />
and newdsk.value-olddsk.value&gt;0<br />
group by to_char(sn.begin_interval_time,&#8217;day&#8217;);</p>
]]></content:encoded>
			<wfw:commentRss>http://www.jydba.net/index.php/archives/1716/feed</wfw:commentRss>
		<slash:comments>0</slash:comments>
		</item>
		<item>
		<title>获取会话所使用的undo block统计数据</title>
		<link>http://www.jydba.net/index.php/archives/1726</link>
		<comments>http://www.jydba.net/index.php/archives/1726#respond</comments>
		<pubDate>Wed, 13 Nov 2013 05:07:22 +0000</pubDate>
		<dc:creator><![CDATA[YongJing(敬勇)]]></dc:creator>
				<category><![CDATA[scripts]]></category>

		<guid isPermaLink="false">http://www.jydba.net/?p=1726</guid>
		<description><![CDATA[select used_ublk from v$transaction wher [&#8230;... ]]></description>
				<content:encoded><![CDATA[<p>select used_ublk<br />
from v$transaction<br />
where addr = (select taddr<br />
from v$session<br />
where sid = (select sid<br />
from v$mystat<br />
where rownum = 1<br />
)<br />
)</p>
]]></content:encoded>
			<wfw:commentRss>http://www.jydba.net/index.php/archives/1726/feed</wfw:commentRss>
		<slash:comments>0</slash:comments>
		</item>
		<item>
		<title>获取数据库缓冲区缓存丢失统计数据</title>
		<link>http://www.jydba.net/index.php/archives/1722</link>
		<comments>http://www.jydba.net/index.php/archives/1722#respond</comments>
		<pubDate>Tue, 12 Nov 2013 05:02:45 +0000</pubDate>
		<dc:creator><![CDATA[YongJing(敬勇)]]></dc:creator>
				<category><![CDATA[scripts]]></category>

		<guid isPermaLink="false">http://www.jydba.net/?p=1722</guid>
		<description><![CDATA[set lines 80; set pages 999; column myda [&#8230;... ]]></description>
				<content:encoded><![CDATA[<p>set lines 80;<br />
set pages 999;<br />
column mydate heading &#8216;Yr. Mo Dy Hr.&#8217; format a16<br />
column c1 heading &#8220;execs&#8221; format 9,999,999<br />
column c2 heading &#8220;Cache Misses|While Executing&#8221; format 9,999,999<br />
column c3 heading &#8220;Library Cache|Miss Ratio&#8221; format 999,99999</p>
<p>break on mydate skip 2;<br />
select<br />
to_char(sn.snap_time,&#8217;yyyy-mm-dd HH24&#8242;) mydate,<br />
sum(new.pins-old.pins) c1,<br />
sum(new.reloads-old.reloads) c2,<br />
sum(new.reloads-old.reloads)/<br />
sum(new.pins-old.pins) c3<br />
from<br />
stats$librarycache old,<br />
stats$librarycache new,<br />
stats$snapshot sn<br />
where new.snap_id=sn.snap_id<br />
and old.snap_id=new.snap_id-1<br />
and old.namespace=new.namespace<br />
group by to_char(sn.snap_time,&#8217;yyyy-mm-dd HH24&#8242;);</p>
<p>select<br />
to_char(sn.begin_interval_time,&#8217;yyyy-mm-dd HH24&#8242;) mydate,<br />
sum(new.pins-old.pins) c1,<br />
sum(new.reloads-old.reloads) c2,<br />
sum(new.reloads-old.reloads)/<br />
sum(new.pins-old.pins) c3<br />
from<br />
dba_hist_librarycache old,<br />
dba_hist_librarycache new,<br />
dba_hist_snapshot sn<br />
where new.snap_id=sn.snap_id<br />
and old.snap_id=new.snap_id-1<br />
and old.namespace=new.namespace<br />
group by to_char(sn.begin_interval_time,&#8217;yyyy-mm-dd HH24&#8242;);</p>
]]></content:encoded>
			<wfw:commentRss>http://www.jydba.net/index.php/archives/1722/feed</wfw:commentRss>
		<slash:comments>0</slash:comments>
		</item>
		<item>
		<title>查询内存与磁盘排序统计数据</title>
		<link>http://www.jydba.net/index.php/archives/1724</link>
		<comments>http://www.jydba.net/index.php/archives/1724#respond</comments>
		<pubDate>Wed, 23 Oct 2013 05:04:32 +0000</pubDate>
		<dc:creator><![CDATA[YongJing(敬勇)]]></dc:creator>
				<category><![CDATA[scripts]]></category>

		<guid isPermaLink="false">http://www.jydba.net/?p=1724</guid>
		<description><![CDATA[set pages 9999; column mydate heading &# [&#8230;... ]]></description>
				<content:encoded><![CDATA[<p>set pages 9999;<br />
column mydate heading &#8216;Yr. Mo Dy Hr.&#8217; format a16<br />
column sorts_memory format 999,999,999<br />
column sorts_disk format 999,999,999<br />
column ratio format .99999</p>
<p>select<br />
to_char(sn.snap_time,&#8217;yyyy-mm-dd HH24&#8242;) mydate,<br />
newmem.value-oldmem.value sorts_memory,<br />
newdsk.value-olddsk.value sorts_disk,<br />
((newdsk.value-olddsk.value)/(newmem.value-oldmem.value)) ratio<br />
from<br />
stats$sysstat oldmem,<br />
stats$sysstat newmem,<br />
stats$sysstat olddsk,<br />
stats$sysstat newdsk,<br />
stats$snapshot sn<br />
where<br />
newdsk.snap_id=sn.snap_id<br />
and olddsk.snap_id=sn.snap_id-1<br />
and newmem.snap_id=sn.snap_id<br />
and oldmem.snap_id=sn.snap_id-1<br />
and oldmem.name=&#8217;sorts (memory)&#8217;<br />
and newmem.name=&#8217;sorts (memory)&#8217;<br />
and olddsk.name=&#8217;sorts (disk)&#8217;<br />
and newdsk.name=&#8217;sorts (disk)&#8217;<br />
and newmem.value-oldmem.value&gt;0<br />
and newdsk.value-olddsk.value&gt;0;</p>
<p>select<br />
to_char(sn.begin_interval_time,&#8217;yyyy-mm-dd HH24&#8242;) mydate,<br />
newmem.value-oldmem.value sorts_memory,<br />
newdsk.value-olddsk.value sorts_disk,<br />
((newdsk.value-olddsk.value)/(newmem.value-oldmem.value)) ratio<br />
from<br />
dba_hist_sysstat oldmem,<br />
dba_hist_sysstat newmem,<br />
dba_hist_sysstat olddsk,<br />
dba_hist_sysstat newdsk,<br />
dba_hist_snapshot sn<br />
where<br />
newdsk.snap_id=sn.snap_id<br />
and olddsk.snap_id=sn.snap_id-1<br />
and newmem.snap_id=sn.snap_id<br />
and oldmem.snap_id=sn.snap_id-1<br />
and oldmem.stat_name=&#8217;sorts (memory)&#8217;<br />
and newmem.stat_name=&#8217;sorts (memory)&#8217;<br />
and olddsk.stat_name=&#8217;sorts (disk)&#8217;<br />
and newdsk.stat_name=&#8217;sorts (disk)&#8217;<br />
and newmem.value-oldmem.value&gt;0<br />
and newdsk.value-olddsk.value&gt;0;</p>
]]></content:encoded>
			<wfw:commentRss>http://www.jydba.net/index.php/archives/1724/feed</wfw:commentRss>
		<slash:comments>0</slash:comments>
		</item>
		<item>
		<title>获取热点对象</title>
		<link>http://www.jydba.net/index.php/archives/1728</link>
		<comments>http://www.jydba.net/index.php/archives/1728#respond</comments>
		<pubDate>Mon, 14 Oct 2013 05:08:30 +0000</pubDate>
		<dc:creator><![CDATA[YongJing(敬勇)]]></dc:creator>
				<category><![CDATA[scripts]]></category>

		<guid isPermaLink="false">http://www.jydba.net/?p=1728</guid>
		<description><![CDATA[select tch, file#, dbablk, case when obj [&#8230;... ]]></description>
				<content:encoded><![CDATA[<p>select tch,<br />
file#,<br />
dbablk,<br />
case<br />
when obj = 4294967295 then<br />
&#8216;rbs/compat segment&#8217;<br />
else<br />
(select max(&#8216;(&#8216; || object_type || &#8216;) &#8216; || owner || &#8216;.&#8217; ||<br />
object_name) || decode(count(*), 1, &#8221;, &#8216; maybe!&#8217;)<br />
from dba_objects<br />
where data_object_id = X.OBJ)<br />
end what<br />
from (select tch, file#, dbablk, obj<br />
from x$bh<br />
where state &lt;&gt; 0<br />
order by tch desc) x<br />
where rownum &lt; = 5;</p>
<p>select * from dba_extents z,<br />
(select tch, file#, dbablk, obj<br />
from x$bh<br />
where state &lt;&gt; 0<br />
and rownum &lt; = 5<br />
order by tch desc) y<br />
where z.file_id=y.file# and z.block_id&lt;=y.dbablk and z.block_id+z.blocks-1&gt;=y.dbablk;</p>
<p>select * from dba_extents where file_id = FILE# and block_id &lt; = DBABLK and block_id+blocks-1 &gt;= DBABLK。</p>
]]></content:encoded>
			<wfw:commentRss>http://www.jydba.net/index.php/archives/1728/feed</wfw:commentRss>
		<slash:comments>0</slash:comments>
		</item>
		<item>
		<title>获取隐藏参数</title>
		<link>http://www.jydba.net/index.php/archives/1720</link>
		<comments>http://www.jydba.net/index.php/archives/1720#respond</comments>
		<pubDate>Sat, 12 Oct 2013 04:59:03 +0000</pubDate>
		<dc:creator><![CDATA[YongJing(敬勇)]]></dc:creator>
				<category><![CDATA[scripts]]></category>

		<guid isPermaLink="false">http://www.jydba.net/?p=1720</guid>
		<description><![CDATA[select x.ksppinm NAME,y.ksppstvl value,x [&#8230;... ]]></description>
				<content:encoded><![CDATA[<p>select x.ksppinm NAME,y.ksppstvl value,x.ksppdesc describ<br />
from x$ksppi x, x$ksppcv y<br />
where x.inst_id=USERENV(&#8216;Instance&#8217;)<br />
and y.inst_id=USERENV(&#8216;Instance&#8217;)<br />
and x.indx=y.indx<br />
and x.ksppinm like &#8216;%&amp;par%&#8217;;</p>
]]></content:encoded>
			<wfw:commentRss>http://www.jydba.net/index.php/archives/1720/feed</wfw:commentRss>
		<slash:comments>0</slash:comments>
		</item>
		<item>
		<title>获取数据库每小时的排序统计数据</title>
		<link>http://www.jydba.net/index.php/archives/1718</link>
		<comments>http://www.jydba.net/index.php/archives/1718#respond</comments>
		<pubDate>Thu, 12 Sep 2013 04:57:56 +0000</pubDate>
		<dc:creator><![CDATA[YongJing(敬勇)]]></dc:creator>
				<category><![CDATA[scripts]]></category>

		<guid isPermaLink="false">http://www.jydba.net/?p=1718</guid>
		<description><![CDATA[set pages 9999; column sorts_memory form [&#8230;... ]]></description>
				<content:encoded><![CDATA[<p>set pages 9999;<br />
column sorts_memory format 999,999,999<br />
column sorts_disk format 999,999,999<br />
column ratio format .99999</p>
<p>select<br />
to_char(sn.snap_time,&#8217;HH24&#8242;),<br />
avg(newmem.value-oldmem.value) sorts_memory,<br />
avg(newdsk.value-olddsk.value) sorts_disk<br />
from<br />
stats$sysstat oldmem,<br />
stats$sysstat newmem,<br />
stats$sysstat olddsk,<br />
stats$sysstat newdsk,<br />
stats$snapshot sn<br />
where<br />
newdsk.snap_id=sn.snap_id<br />
and olddsk.snap_id=sn.snap_id-1<br />
and newmem.snap_id=sn.snap_id<br />
and oldmem.snap_id=sn.snap_id-1<br />
and oldmem.name=&#8217;sorts (memory)&#8217;<br />
and newmem.name=&#8217;sorts (memory)&#8217;<br />
and olddsk.name=&#8217;sorts (disk)&#8217;<br />
and newdsk.name=&#8217;sorts (disk)&#8217;<br />
and newmem.value-oldmem.value&gt;0<br />
and newdsk.value-olddsk.value&gt;0<br />
group by to_char(sn.snap_time,&#8217;HH24&#8242;);</p>
<p>select<br />
to_char(sn.begin_interval_time,&#8217;HH24&#8242;),<br />
avg(newmem.value-oldmem.value) sorts_memory,<br />
avg(newdsk.value-olddsk.value) sorts_disk<br />
from<br />
dba_hist_sysstat oldmem,<br />
dba_hist_sysstat newmem,<br />
dba_hist_sysstat olddsk,<br />
dba_hist_sysstat newdsk,<br />
dba_hist_snapshot sn<br />
where<br />
newdsk.snap_id=sn.snap_id<br />
and olddsk.snap_id=sn.snap_id-1<br />
and newmem.snap_id=sn.snap_id<br />
and oldmem.snap_id=sn.snap_id-1<br />
and oldmem.stat_name=&#8217;sorts (memory)&#8217;<br />
and newmem.stat_name=&#8217;sorts (memory)&#8217;<br />
and olddsk.stat_name=&#8217;sorts (disk)&#8217;<br />
and newdsk.stat_name=&#8217;sorts (disk)&#8217;<br />
and newmem.value-oldmem.value&gt;0<br />
and newdsk.value-olddsk.value&gt;0<br />
group by to_char(sn.begin_interval_time,&#8217;HH24&#8242;);</p>
]]></content:encoded>
			<wfw:commentRss>http://www.jydba.net/index.php/archives/1718/feed</wfw:commentRss>
		<slash:comments>0</slash:comments>
		</item>
	</channel>
</rss>