Skip to content

Commit b52dc2f

Browse files
committed
Adding some scripts
0 parents  commit b52dc2f

12 files changed

+1188
-0
lines changed

Diff for: ASH2.sql

+151
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,151 @@
1+
-- how much history do we have:
2+
select min(sample_time) from V$ACTIVE_SESSION_HISTORY
3+
4+
-- top events
5+
select event,count(*) from DBA_HIST_ACTIVE_SESS_HISTORY where sample_time> sysdate-1/24
6+
and user_id>0
7+
group by event
8+
order by count(*) desc;
9+
10+
11+
-- top sql
12+
select sql_id,count(*) from DBA_HIST_ACTIVE_SESS_HISTORY where sample_time> sysdate-1/24
13+
and user_id>0
14+
group by sql_id
15+
order by count(*) desc;
16+
17+
18+
-- see specific samples
19+
select sample_time,user_id,sql_id,event from DBA_HIST_ACTIVE_SESS_HISTORY
20+
where 1=1
21+
--and sample_time> to_date('03-MAR-11 15:30','dd-mon-yy hh24:mi')
22+
and sample_time> sysdate-1/24
23+
--and user_id>0
24+
--and session_id=371
25+
order by sample_time;
26+
27+
-- look for hot buffers
28+
select p1,p2,p3,count(*) from DBA_HIST_ACTIVE_SESS_HISTORY
29+
where sample_time> to_date('03-MAR-11 15:30','dd-mon-yy hh24:mi')
30+
and sample_time< to_date('03-MAR-11 16:30','dd-mon-yy hh24:mi')
31+
and user_id>0
32+
and event='buffer busy waits'
33+
group by p1,p2,p3
34+
order by count(*)
35+
36+
37+
38+
SELECT SEGMENT_NAME, SEGMENT_TYPE FROM DBA_EXTENTS
39+
WHERE FILE_ID = 1 AND 231928 BETWEEN BLOCK_ID AND
40+
BLOCK_ID + BLOCKS - 1;
41+
42+
43+
44+
45+
-- top SQL waiting for a specific events
46+
select sql_id,count(*) from DBA_HIST_ACTIVE_SESS_HISTORY
47+
where sample_time> sysdate-1/24
48+
and user_id>0
49+
and event is null
50+
group by sql_id
51+
order by count(*)
52+
53+
-- top programs waiting for a specific events
54+
select program,count(*) from DBA_HIST_ACTIVE_SESS_HISTORY
55+
where sample_time> to_date('03-MAR-11 15:30','dd-mon-yy hh24:mi')
56+
and sample_time< to_date('03-MAR-11 16:30','dd-mon-yy hh24:mi')
57+
and user_id>0
58+
and event='buffer busy waits'
59+
group by program
60+
order by count(*)
61+
62+
-- top users waiting for a specific events
63+
select user_id,count(*) from DBA_HIST_ACTIVE_SESS_HISTORY
64+
where sample_time> to_date('03-MAR-11 15:30','dd-mon-yy hh24:mi')
65+
and sample_time< to_date('03-MAR-11 16:30','dd-mon-yy hh24:mi')
66+
and user_id>0
67+
and event='buffer busy waits'
68+
group by user_id
69+
order by count(*) 2 3 4 5 6 7 ;
70+
71+
-- Everyone waiting for specific event
72+
select sample_time,user_id,sql_id,event,p1,blocking_session from V$ACTIVE_SESSION_HISTORY
73+
where event like 'library%'
74+
75+
-- Who is waiting for specific event the most:
76+
select SESSION_ID,user_id,sql_id,round(sample_time,'hh'),count(*) from V$ACTIVE_SESSION_HISTORY
77+
where event like 'log file sync'
78+
group by SESSION_ID,user_id,sql_id,round(sample_time,'hh')
79+
order by count(*) desc
80+
81+
82+
83+
84+
85+
select event,count(*) from DBA_HIST_ACTIVE_SESS_HISTORY
86+
where sample_time> to_date('03-MAR-11 15:30','dd-mon-yy hh24:mi')
87+
and sample_time< to_date('03-MAR-11 16:00','dd-mon-yy hh24:mi')
88+
and user_id>0
89+
group by event
90+
order by count(*) desc
91+
92+
93+
select to_char(trunc(sample_time, 'hh24') + round((cast(sample_time as date)- trunc(cast(sample_time as date), 'hh24'))*60*24/5)*5/60/24, 'dd/mm/yyyy hh24:mi'),count(*) from DBA_HIST_ACTIVE_SESS_HISTORY
94+
where sample_time> to_date('03-MAR-11 15:30','dd-mon-yy hh24:mi')
95+
and sample_time< to_date('03-MAR-11 16:30','dd-mon-yy hh24:mi')
96+
and user_id=209
97+
and event='buffer busy waits'
98+
group by to_char(trunc(sample_time, 'hh24') + round((cast(sample_time as date)- trunc(cast(sample_time as date), 'hh24'))*60*24/5)*5/60/24, 'dd/mm/yyyy hh24:mi')
99+
order by count(*)
100+
101+
102+
select sql_id,count(*) from V$ACTIVE_SESSION_HISTORY
103+
where sample_time> to_date('08-FEB-10 13:00','dd-mon-yy hh24:mi')
104+
and sample_time< to_date('08-FEB-10 16:00','dd-mon-yy hh24:mi')
105+
and user_id>0
106+
group by sql_id
107+
order by count(*) desc
108+
109+
select * from dba_views where view_name like 'DBA_HIST%'
110+
111+
select sh.sample_time,sh.SESSION_ID,user_id,sh.sql_id,event,p1,blocking_session,PROGRAM,sql_text
112+
from DBA_HIST_ACTIVE_SESS_HISTORY sh
113+
left outer join DBA_HIST_SQLTEXT sq on sq.sql_id=sh.sql_id
114+
where 1=1
115+
and sample_time> to_date('08-FEB-10 00:00','dd-mon-yy hh24:mi')
116+
and sample_time< to_date('08-FEB-10 23:00','dd-mon-yy hh24:mi')
117+
and user_id=61
118+
--and sql_id='809u1jtt54kfy'
119+
order by sample_time
120+
121+
122+
select trunc(sample_time),
123+
sum(case when INSTANCE_NUMBER=1 then 1 else 0 end) inst1,
124+
sum(case when INSTANCE_NUMBER=2 then 1 else 0 end) inst2
125+
from DBA_HIST_ACTIVE_SESS_HISTORY sh
126+
where 1=1
127+
and user_id=61
128+
group by trunc(sample_time)
129+
order by trunc(sample_time)
130+
131+
132+
133+
select * from DBA_HIST_SQLTEXT where sql_id='d15cdr0zt3vtp';
134+
where dbms_lob.instr(sql_text, 'GLOBAL',1,1) > 0
135+
136+
desc DBA_HIST_ACTIVE_SESS_HISTORY
137+
138+
EXEC DBMS_MONITOR.session_trace_enable(session_id =>1234, serial_num=>1234, waits=>TRUE, binds=>FALSE);
139+
140+
select sample_time,user_id,sql_id,event,p1,blocking_session from V$ACTIVE_SESSION_HISTORY
141+
where event like 'library%'
142+
143+
select * from v$active_session_history where session_id=306
144+
6969666696
145+
select SESSION_ID,user_id,sql_id,round(sample_time,'hh'),count(*) from V$ACTIVE_SESSION_HISTORY
146+
where event like 'log file sync'
147+
group by SESSION_ID,user_id,sql_id,round(sample_time,'hh')
148+
order by count(*) desc
149+
150+
151+
select * from dba_users; 61

Diff for: DataGuard.txt

+50
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,50 @@
1+
-- Find which logs were applied in the last day
2+
SELECT SEQUENCE#, to_char(FIRST_TIME,'hh24:mi:ss dd/mm/yyyy'), to_char(NEXT_TIME,'hh24:mi:ss dd/mm/yyyy'),APPLIED FROM V$ARCHIVED_LOG where next_time>sysdate-1 ORDER BY SEQUENCE# ;
3+
4+
5+
-- Find last applied log
6+
select to_char(max(FIRST_TIME),'hh24:mi:ss dd/mm/yyyy') FROM V$ARCHIVED_LOG where applied='YES';
7+
8+
-- What are the managed standby processes doing?
9+
SELECT PROCESS, STATUS, THREAD#, SEQUENCE#, BLOCK#, BLOCKS FROM V$MANAGED_STANDBY;
10+
11+
-- Are we on production or standby?
12+
SELECT DATABASE_ROLE, DB_UNIQUE_NAME INSTANCE, OPEN_MODE, PROTECTION_MODE, PROTECTION_LEVEL, SWITCHOVER_STATUS FROM V$DATABASE;
13+
14+
-- Check for errors
15+
SELECT MESSAGE FROM V$DATAGUARD_STATUS;
16+
17+
-- Check that the DB was openned correctly
18+
SELECT RECOVERY_MODE FROM V$ARCHIVE_DEST_STATUS;
19+
20+
-- important lag statistics
21+
select * from v$dataguard_stats;
22+
23+
24+
-- configure log shipping on primary
25+
alter system set log_archive_dest_3='SERVICE=DEVPCOMB LGWR ASYNC VALID_FOR=(ONLINE_LOGFILES, PRIMARY_ROLE) DB_UNIQUE_NAME=DEVPCOMB';
26+
alter system set log_archive_dest_state_3='enable';
27+
28+
29+
-- stopping and starting managed recovery on standby
30+
alter database recover managed standby database cancel;
31+
alter database recover managed standby database disconnect;
32+
ALTER DATABASE RECOVER MANAGED STANDBY DATABASE USING CURRENT LOGFILE disconnect;
33+
34+
35+
-- Manually register an archive log on standby
36+
alter database register physical logfile '<fullpath/filename>';
37+
38+
-- Check if standby logs are configured right
39+
set lines 100 pages 999
40+
col member format a70
41+
select st.group#
42+
, st.sequence#
43+
, ceil(st.bytes / 1048576) mb
44+
, lf.member
45+
from v$standby_log st
46+
, v$logfile lf
47+
where st.group# = lf.group#
48+
/
49+
50+

Diff for: README

+37
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,37 @@
1+
=========
2+
= About =
3+
=========
4+
5+
This is a collection of useful Oracle SQL and shell scripts that I use.
6+
7+
I don't mind how you use these scripts, but give credit if credit is due.
8+
9+
===========
10+
= License =
11+
===========
12+
13+
Copyright 2011 Gwen Shapira.
14+
15+
These programs are free software: you can redistribute it and/or modify
16+
it under the terms of the GNU General Public License as published by
17+
the Free Software Foundation, either version 3 of the License, or
18+
(at your option) any later version.
19+
20+
These programs are distributed in the hope that it will be useful,
21+
but WITHOUT ANY WARRANTY; without even the implied warranty of
22+
MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the
23+
GNU General Public License for more details.
24+
25+
You should have received a copy of the GNU General Public License
26+
along with this program. If not, see <http://www.gnu.org/licenses/>.
27+
28+
==========================================================================
29+
30+
DataGuard.txt - SQL snippets for monitoring and managing DataGuard
31+
check_and_kill.sql - SQL for checking on what sessions are doing
32+
locks.sql - Queries I use to figure out locking issues
33+
tfsclock.sql - complex query from Oracle that gives a lot of details about locks
34+
job_scheduling.sql - Queries regarding jobs and schedules
35+
SSD.sql - queries I use to decide which segments should be placed on SSDs
36+
undo_space.sql - queries to dig into undo usage
37+
tablespace.sql - queries to manage tablespace sizes

Diff for: SSD.sql

+39
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,39 @@
1+
-- Find segments with most read operations, and hopefully relatively few writes
2+
-- These are good candidates for placing on SSD storage
3+
WITH segment_stats
4+
AS (SELECT ss.owner || '.' || ss.object_name
5+
|| DECODE (ss.subobject_name,NULL, '',
6+
'(' || ss.subobject_name || ')') segment_name,
7+
ss.object_type,
8+
SUM ( CASE WHEN statistic_name LIKE 'physical reads%'
9+
THEN VALUE ELSE 0 END) reads,
10+
SUM ( CASE WHEN statistic_name LIKE 'physical writes%'
11+
THEN VALUE ELSE 0 END) writes,
12+
ROUND (SUM (bytes) / 1048576) mb
13+
FROM v$segment_statistics ss
14+
JOIN dba_segments s
15+
ON (s.owner = ss.owner AND s.segment_name = ss.object_name
16+
AND NVL (ss.subobject_name, 'x') =NVL (s.partition_name, 'x'))
17+
WHERE statistic_name LIKE 'physical reads%'
18+
OR statistic_name LIKE 'physical writes%'
19+
GROUP BY ss.owner,ss.object_name,ss.subobject_name,ss.object_type)
20+
SELECT segment_name, object_type, reads,writes,
21+
ROUND (reads * 100 / SUM (reads) OVER (), 2) pct_reads,
22+
ROUND (writes * 100 / SUM (writes) OVER (), 2) pct_writes,
23+
mb FROM segment_stats
24+
ORDER BY reads DESC
25+
26+
-- find segments with full scans
27+
-- These are not ideal for placing on SSD storage
28+
col segment_name format a60
29+
select
30+
owner || '.' || object_name || DECODE (subobject_name,NULL, '','(' || subobject_name || ')') segment_name,object_type,
31+
value scans
32+
from
33+
V$segment_statistics
34+
where
35+
statistic_name = 'segment scans'
36+
and value != 0
37+
order by
38+
value desc
39+
;

0 commit comments

Comments
 (0)