Friday, October 24, 2008

Some pratices in Oracle DB.

-- #############################################################################################
--
-- %Purpose: ANALYZE table with estimate or compute, depending on table size, see SIGN(n)
--
-- Use: Any table less than 10 MB in total size has statistics computed
-- while tables larger than 10 MB have statistics estimated.
-- SIGN(n) ==> if n < 0 the function returns -1
-- if n = 0 the functions returns 0
-- if n > 0 the functions returns 1
--
-- #############################################################################################
--
set feed off;
set pagesize 10000;
set wrap off;
set linesize 200;
set heading on;
set tab on;
set scan on;
set verify off;
spool compute_or_estimate.sql
--
SELECT 'ANALYZE TABLE '||owner||'.'||table_name||' '||
DECODE(SIGN(10485760 - initial_extent),1,'COMPUTE STATISTICS;',
'ESTIMATE STATISTICS;')
FROM sys.dba_tables
WHERE owner NOT IN ('SYS','SYSTEM');
/
--
spool off;
set feed on;
@compute_or_estimate.sql

-- #############################################################################################
--
-- %Purpose: Buffer Cache Analysis - Objects (Analysis of V$CACHE)
--
-- Use: Needs Oracle DBA Access
--
-- #############################################################################################
--
set feed off;
set pagesize 10000;
set wrap off;
set linesize 200;
set heading on;
set tab on;
set scan off;
set verify off;
set termout on;

column BT format a29 heading 'Block Type'
column KIND format a12 heading 'Object Type'
column CB format 99990 heading 'Nr of Blocks'
column NAME format a24 heading 'Object Name'

ttitle left 'Buffer Cache Analysis - Objects' skip 2

spool buffer_cache_analysis_obj.log

select NAME,
KIND,
decode (CLASS#,0, 'FREE',
1, 'DATA INDEX',
2, 'SORT',
3, 'SAVE UNDO',
4, 'SEG HEADER',
5, 'SAVE UNDO SH',
6, 'FREELIST BLOCK',
'OTHER') as BT,
count (BLOCK#) as CB
from V$CACHE
group by
NAME,
KIND,
CLASS#
order by
CB desc,
NAME,
KIND
/

spool off;

-- #############################################################################################
--
-- %Purpose: Buffer Cache Analysis - Slot Status (Analysis of V$CACHE)
--
-- Use: Needs Oracle DBA Access
--
-- #############################################################################################
--
set feed off;
set pagesize 10000;
set wrap off;
set linesize 200;
set heading on;
set tab on;
set scan on;
set verify off;
set termout on;

ttitle left 'Buffer Cache Analysis - Slot Status' skip 2

spool buffer_cache_analysis_slots.log

select decode (STATUS, 'free', 'FREE',
'xcur', 'INST EXCL',
'scur', 'INST SHAR',
'cr', 'CONS READ',
'read', 'DISK READ',
'mrec', 'MED RECO',
'irec', 'INS RECO', 'OTHER') "Slot Status",
count(*) "Counts"
from V$CACHE
group by
STATUS
/

spool off;

-- #############################################################################################
--
-- %Purpose: Calculate 'Average Length of the Dirty Buffer Write Queue' for Performance Tuning
--
-- Use: Oracle DBA
--
-- #############################################################################################
--
PROMPT ========================================================================
PROMPT This script lists the Dirty Queue Length. The longer the queue length,
PROMPT the more trouble the dbwr is having keeping up.
PROMPT
PROMPT Average length of the dirty buffer write queue:
PROMPT
PROMPT If this is larger than the value of:
PROMPT
PROMPT 1. (db_files * db_file_simultaneous_writes)/2 [Calculation-1]
PROMPT
PROMPT or
PROMPT
PROMPT 2. 1/4 of db_block_buffers [Calculation-1]
PROMPT
PROMPT which ever is smaller and also there is a platform specific limit
PROMPT on the write batch size (normally 1024 or 2048 buffers). If the average
PROMPT length of the dirty buffer write queue is larger than the value
PROMPT calculated before, increase db_file_simultaneous_writes or db_files.
PROMPT Also check for disks that are doing many more IOs than other disks.
PROMPT ========================================================================
--
column "Write Request Length" format 999,999.99
--
SELECT (SUM(DECODE(name,'db_files',value)) *
SUM(DECODE(name,'db_file_simultaneous_writes',value)))/2
"Calculation-1"
FROM v$system_parameter
WHERE name IN ('db_files','db_file_simultaneous_writes');
--
SELECT (SUM(DECODE(name,'db_block_buffers',value)) / 4)
"Calculation-2"
FROM v$system_parameter
WHERE name IN ('db_block_buffers');
--
SELECT SUM(DECODE(name,'summed dirty queue length',value)) /
SUM(DECODE(name,'write requests',value)) "Write Request Length"
FROM v$sysstat
WHERE name IN ( 'summed dirty queue length','write requests')
AND value > 0;

-- #############################################################################################
--
-- %Purpose: Circuits trough Dispatcher to Shared Serverprozess, MTS und Shared-Server
--
-- #############################################################################################
--
-- Das Diagramm «Circuit» zeigt die virtuellen Verbindung zur Datenbank
-- Instance via Dispatcher und Shared Serverprozess, welcher den User
-- Process verarbeitet.
--
-- Dispatcher Statistics
--
-- Das Diagramm «Dispatcher» zeigt die Statistiken der Dispatcher Prozesse
-- der Datenbank Instance.
--
-- Actual MTS-Parameters
--
-- SELECT NAME, VALUE
-- FROM V$PARAMETER
-- WHERE NAME LIKE '%mts%' OR NAME LIKE '%MTS%';
--
-- Max. Number of Server-Processes
--
-- SELECT * FROM V$MTS

-- Queue
--
-- Das Diagramm «Queue» zeigt die Aktivitäten des Multi-Threaded Servers.
--
-- #############################################################################################
--
set feed off;
set pagesize 10000;
set wrap off;
set linesize 200;
set heading on;
set tab on;
set scan on;
set verify off;
--
ttitle left 'Circuits trough Dispatcher to Shared Serverprozess' -
skip 2

select rawtohex(c.circuit),d.name,s.sid,s.serial#,
c.status, c.queue,c.bytes
from v$circuit c,v$dispatcher d, v$shared_server s1,v$session s
where c.dispatcher = d.paddr(+)
and c.server = s1.paddr(+)
and c.saddr = s.saddr(+)
order by c.circuit;

ttitle left 'Dispatcher Statistics' -
skip 2

select name, status, accept, messages, bytes, idle, busy
from v$dispatcher
order by name;

ttitle left 'Processes actually waiting for a shared server' -
skip 2

SELECT QUEUED
FROM V$QUEUE
WHERE TYPE = 'COMMON';

ttitle left 'Activity of MTS' -
skip 2

select rawtohex(paddr), type, queued, totalq,
decode(totalq, 0, 0, wait/totalq/100) "totalq"
from v$queue order by paddr;
-- #############################################################################################
--
-- %Purpose: Compare HW-Mark which is say 20% larger than the actual data in the tables (Ora7)
--
-- This script lists all of the tables specified by owner,
-- where the High Water Mark is say 20% larger than the actual
-- data in the tables.
-- This will indicate which tables require a rebuild.
--
-- Notes:
--
-- This script generates another script(hwm_get_sql.lst), which
-- it calls at the end. The hwm_get_sql.lst file is NOT deleted
-- when it is finished.
-- You do NOT need to run an analyze on the tables before running
-- this script
--
-- The ROWID format changed between Oracle 7 and Oracle 8.
--
-- ################################
-- THIS SCRIPT IS FOR ORACLE 7 ONLY
-- ################################
--
-- Author: John Dixon, published on http://www.revealnet.com
--
-- #############################################################################################
--
set echo off
set heading off
set pagesize 0
set feedback off
set linesize 1000
set trimspool on
set wrap on
set verify off
rem Get the variables
accept table_owner char prompt 'Enter the table owner: '
accept percentage_larger number default 20 prompt 'Enter the percentage larger threshold the HWM can be [default 20]: '
prompt This may take a while...
rem
set termout off
rem
spool hwm_get_sql.lst
prompt set echo off
prompt set heading off
prompt set termout on
prompt set verify off

rem Step 1 - First generate the script to calc hwm and data for each table in schema.

select 'select owner,segment_name,hwm,actual_data from'||chr(10)||
' (SELECT round((COUNT(DISTINCT SUBSTR(rowid,15,4)||'||chr(10)||
'SUBSTR(rowid,1,8))+1)*'||vp.value/1024||'/1024) as Actual_Data FROM '||chr(10)||
ds.owner||'.'||ds.segment_name||') ad,'||chr(10)||
'(select s.owner,s.segment_name,round(s.BLOCKS*'||vp.value/1024||'/1024) as HWM '||chr(10)||
'from dba_segments s, dba_tables t where s.owner='''||ds.owner||''' '||chr(10)||
'and s.segment_name='''||ds.segment_name||''' and t.owner=s.owner and t.table_name=s.segment_name) hw'||chr(10)||
' where hw.hwm>(ad.actual_data*&&percentage_larger/100)+ad.actual_data'||
' and ad.actual_data >0;'
from dba_segments ds, dba_tables dt, v$parameter vp
where ds.owner=upper('&&Table_Owner') and
ds.segment_name=dt.table_name and
ds.owner=dt.owner
and vp.name='db_block_size'
order by segment_name
/
spool off

rem STEP 2 - Now Generate the output

rem spool hwm.lst
set termout on
column Owner format A10 heading Owner
column segment_name format a40
column hwm format 999,999,999
column actual_data format 999,999,999

prompt High Water Mark Report - This will indicate tables that require rebuilding.
prompt Owner Table HWM(Mb) Data(Mb)
start hwm_get_sql.lst
REM spool off (hwm.lst)

-- #############################################################################################
--
-- %Purpose: Compare HW-Mark which is say 20% larger than the actual data in the tables (Ora8)
--
-- This script lists all of the tables specified by owner,
-- where the High Water Mark is say 20% larger than the actual
-- data in the tables.
-- This will indicate which tables require a rebuild.
--
-- Notes:
--
-- This script generates another script(hwm_get_sql.lst), which
-- it calls at the end. The hwm_get_sql.lst file is NOT deleted
-- when it is finished.
-- You do NOT need to run an analyze on the tables before running
-- this script
--
-- The ROWID format changed between Oracle 7 and Oracle 8.
--
-- ################################
-- THIS SCRIPT IS FOR ORACLE 8 ONLY
-- ################################
--
-- Author: John Dixon, published on http://www.revealnet.com
--
-- #############################################################################################
--
set echo off
set heading off
set pagesize 0
set feedback off
set linesize 1000
set trimspool on
set wrap on
set verify off
rem Get the variables
accept table_owner char prompt 'Enter the table owner: '
accept percentage_larger number default 20 prompt 'Enter the percentage larger threshold the HWM can be [default 20]: '
prompt This may take a while...
rem
set termout off
rem
spool hwm_get_sql.lst
prompt set echo off
prompt set heading off
prompt set termout on
prompt set verify off

rem Step 1 - First generate the script to calc hwm and data for each table in schema.

select 'select owner,segment_name,hwm,actual_data from'||chr(10)||
' (SELECT round((COUNT(DISTINCT '||chr(10)||
'SUBSTR(rowid,1,15))+1)*'||vp.value/1024||'/1024) as Actual_Data FROM '||chr(10)||
ds.owner||'.'||ds.segment_name||') ad,'||chr(10)||
'(select s.owner,s.segment_name,round(s.BLOCKS*'||vp.value/1024||'/1024) as HWM '||chr(10)||
'from dba_segments s, dba_tables t where s.owner='''||ds.owner||''' '||chr(10)||
'and s.segment_name='''||ds.segment_name||''' and t.owner=s.owner and t.table_name=s.segment_name) hw'||chr(10)||
' where hw.hwm>(ad.actual_data*&&percentage_larger/100)+ad.actual_data'||
' and ad.actual_data >0;'
from dba_segments ds, dba_tables dt, v$parameter vp
where ds.owner=upper('&&Table_Owner') and
ds.segment_name=dt.table_name and
ds.owner=dt.owner
and vp.name='db_block_size'
order by segment_name
/
spool off

rem STEP 2 - Now Generate the output

rem spool hwm.lst
set termout on
column Owner format A10 heading Owner
column segment_name format a40
column hwm format 999,999,999
column actual_data format 999,999,999

prompt High Water Mark Report - This will indicate tables that require rebuilding.
prompt Owner Table HWM(Mb) Data(Mb)
start hwm_get_sql.lst
REM spool off (hwm.lst)
-- #############################################################################################
--
-- %Purpose: DECODE as a very effizient use of IF-THEN-ELSE
--
-- Use: DECODE(expr,search,result,default)
-- if expr IS equal to search, Oracle returns result,
-- if no match is found, Oracle returns default.
--
-- #############################################################################################
--
-- Quite slow is .......
--
select count(*), sum(sal)
from emp
where DEPTNO = 10
and ename like 'SMITH%';
--
select count(*), sum(sal)
from emp
where DEPTNO = 30
and ename like 'SMITH%';
--
-- .... the same result much more efficiently with DECODE
--
-- Remeber that NULL values are never included in, nor do they affect the
-- outcome of, the COUNT and SUM functions
--
SELECT COUNT(DECODE(deptno,10,'*',NULL)) D10_count,
COUNT(DECODE(deptno,30,'*',NULL)) D30_count,
SUM(DECODE(deptno,10,sal,NULL)) D10_sal,
SUM(DECODE(deptno,30,sal,NULL)) D30_sal
FROM emp
WHERE ename like 'SMITH%';

-- #############################################################################################
--
-- %Purpose: Database Trigger to implement an UPDATE CASCADE with Oracle8i
--
-- In Oracle8i the Referential Integrity is checked in the
-- Trigger, therefore there is no mutating problem. However
-- there is one problem with the following update:
--
-- UPDATE dept set deptno = deptno + 10;
--
-- This update will update all departments with deptno 10
-- to the already existing deptno 20, and triggers again
-- this rows. Now all rows with deptno 20 will be changed
-- to 30 and again all rows with deptno 30 will be changed
-- to 40 and so on and on ... finally all rows have
-- deptno = 50 !
--
-- Therefore it's not allowed to update to an existing
-- primary key, if this primary key have any childs.
--
-- #############################################################################################
--
CREATE OR REPLACE TRIGGER scott.dept_emp_update
AFTER UPDATE ON SCOTT.DEPT
REFERENCING
NEW AS NEW
OLD AS OLD
FOR EACH ROW

DECLARE
eDeptNoExists EXCEPTION;

-- Check if child table have child records with this new
-- deptno, this is not allowed.

CURSOR curs_exists_deptno IS
SELECT 'X'
FROM emp
WHERE deptno = :NEW.deptno;

rtEmp curs_exists_deptno%ROWTYPE;

BEGIN
IF(:NEW.deptno <> :OLD.deptno) THEN

OPEN curs_exists_deptno;
FETCH curs_exists_deptno INTO rtEmp;

IF (curs_exists_deptno%FOUND) THEN
CLOSE curs_exists_deptno;
RAISE eDeptNoExists;
END IF;

CLOSE curs_exists_deptno;

UPDATE emp
SET deptno = :NEW.deptno
WHERE deptno = :OLD.deptno;
END IF;

EXCEPTION
WHEN eDeptNoExists THEN
RAISE_APPLICATION_ERROR (-20102,'Error: This Primary Key: '
||TO_CHAR(:NEW.deptno)||' exists and has child rows in emp, this tiggers again an update and so on ...');
END dept_emp_update;
-- #############################################################################################
--
-- %Purpose: Date arithmetic with Oracle (e.g. How to add 1 [sec] to a date ?)
--
-- You can add and subtract number constants as well as other dates
-- from dates. Oracle interprets number constants in arithmetic date
-- expressions as numbers of days. For example, SYSDATE + 1 is tomorrow.
-- SYSDATE - 7 is one week ago. SYSDATE + (10/1440) is ten minutes from now.
-- Subtracting the HIREDATE column of the EMP table from SYSDATE returns
-- the number of days since each employee was hired. You cannot multiply
-- or divide DATE values. Oracle provides functions for many common date
-- operations. For example, the ADD_MONTHS function lets you add or subtract
-- months from a date. The MONTHS_BETWEEN function returns the number of
-- months between two dates. The fractional portion of the result represents
-- that portion of a 31-day month.
--
-- #############################################################################################
--
set serveroutput on;
declare
oldDate DATE;
newDate DATE;
begin
oldDate := to_date('31.12.1999:23:59:59','DD.MM.YYYY:HH24:MI:SS');
newDate := oldDate + 1/86400;
dbms_output.put_line(
'newDate=' ||to_char(newDate,'DD.MM.YYYY:HH24:MI:SS');
end;
/

newDate=01.01.2000:00:00:00
PL/SQL procedure successfully completed.
-- #############################################################################################
--
-- %Purpose: Disable all relational constraints on tables owned by the user that executes this script
--
-- #############################################################################################
--
-- Requires Oracle 8.1
--
------------------------------------------------------------------------------
PROMPT
PROMPT Generating script to disable the relational constraints...

set pagesize 0
set feedback off
set termout off
set linesize 100
set trimspool on
set wrap on

spool disable_relational_constraints.lst.sql

PROMPT PROMPT
PROMPT PROMPT Disabling relational constraints...

SELECT 'PROMPT ... disabling constraint '||constraint_name||' on table '||table_name
, 'alter table '||table_name||' disable constraint '||constraint_name||';'
FROM user_constraints
WHERE constraint_type = 'R'
/

spool off
set feedback on
set termout on
spool disable_relational_constraints.log
@disable_relational_constraints.lst.sql
spool off
-- #############################################################################################
--
-- %Purpose: Displays an ordered list of all non-index segments > 10 MB
--
-- #############################################################################################
--
select
substr(owner,1,12) "Owner",
substr(segment_name,1,30) "Segment Name",
substr(segment_type,1,10) "Seg Type",
substr(tablespace_name,1,15) "Tablespace",
round(bytes/1000000) MB
from dba_segments
where (bytes > 10000000) and (segment_type <> 'INDEX')
order by bytes
/
-- #############################################################################################
--
-- %Purpose: Displays an ordered list of the indexes on a given table
--
-- #############################################################################################
--
set linesize 120 verify off

SELECT
i.table_name "Table",
i.index_name "Index",
i.uniqueness "Type",
c.column_position "N",
c.column_name "Column"
from
all_indexes i,
all_ind_columns c
where
i.table_name like upper('&Table') and
i.owner = c.index_owner and
i.index_name = c.index_name
order by
i.table_name,
i.index_name,
c.column_position
/

-- #############################################################################################
--
-- %Purpose: Displays database resource usage statistics (Whole instance or Session)
--
-- #############################################################################################
--
set serveroutput on size 100000 verify off feedback off
--
accept sid number default 0 prompt 'Enter SID, or press Return for System Stats: '
accept interval number default 10 prompt 'Time interval in seconds [10]: '
prompt
prompt Statistic Change
prompt --------- ------;
--
declare
max_statistic# number;
current_second integer;
type stats_table is table of number index by binary_integer;
first_stat stats_table;
second_stat stats_table;
stat_name varchar2(64);
stat_class number;
begin
select max(statistic#) into max_statistic# from v$statname;
current_second := to_number(to_char(sysdate,'SSSSS'));
while to_number(to_char(sysdate,'SSSSS')) = current_second
loop null; end loop;
current_second := to_number(to_char(sysdate,'SSSSS'));
for i in 0 .. max_statistic# loop
if &&sid = 0 then
select value into first_stat(i)
from v$sysstat v
where v.statistic# = i;
else
select value into first_stat(i)
from v$sesstat v
where v.sid = &&sid and v.statistic# = i;
end if;
end loop;
while to_number(to_char(sysdate,'SSSSS')) < current_second + &&interval
loop null; end loop;
for i in 0 .. max_statistic# loop
if &&sid = 0 then
select value into second_stat(i)
from v$sysstat v
where v.statistic# = i;
else
select value into second_stat(i)
from v$sesstat v
where v.sid = &&sid and v.statistic# = i;
end if;
end loop;
for i in 0 .. max_statistic# loop
if (second_stat(i) - first_stat(i)) > 0 then
select v.name, v.class into stat_name, stat_class
from v$statname v where v.statistic# = i;
if stat_class in (1,8,64,128) then
dbms_output.put(rpad(stat_name,52));
dbms_output.put_line( to_char(second_stat(i) - first_stat(i),'9,999,990'));
end if;
end if;
end loop;
end;
/
prompt
undef sid interval
set feedback on
-- #############################################################################################
--
-- %Purpose: Displays the execution plan for a SQL DML statement
--
-- The SQL statement should be in a separate text file,
-- with either a ";" at the end of the line or a "/" on
-- the next line. A plan_table table is required.
--
-- Usage: sqlplus user/pwd @explain filename
--
-- #############################################################################################
--
set feedback off arraysize 10 trimspool on linesize 1000
--
alter session set optimizer_percent_parallel = 100;
--
delete from plan_table;
commit;
--
set echo on
explain plan for
@&1
set echo off
--
col "Query Plan" for a70
--
select
to_char(id,'999') ID,
to_char(parent_id,'999') pt,
initcap(
lpad(' ',2*(level-1)) ||
operation || ' ' ||
options || ' ' ||
decode(object_name,null,null,'of') || ' ' ||
object_name || ' ' ||
object_type || ' ' ||
decode(id,0,'Cost = ' || ltrim(to_char(position,'999,999,999')))
) "Query Plan",
to_char(cardinality,'999,999,999') "Row Count",
substr(InitCap(other_tag),1,30) Other
from
plan_table
start with id = 0 connect by prior id = parent_id
/
--
rollback;
--
set feedback on
-- #############################################################################################
--
-- %Purpose: Drop all objects of the user that executes this script.
--
-- #############################################################################################
--
-- Akadia SQL Utility Scripts
--
-- Requires Oracle 8.1
--
------------------------------------------------------------------------------

PROMPT
PROMPT Generating script to drop the objects...

set pagesize 0
set feedback off
set termout off
set linesize 100
set trimspool on
set wrap on

spool drop_user_objects.lst.sql

PROMPT PROMPT
PROMPT PROMPT Dropping public synonyms...

SELECT 'PROMPT ... dropping public synonym '||synonym_name
, 'drop public synonym '||synonym_name||';'
FROM all_synonyms
WHERE table_owner = ( SELECT user
FROM dual
)
/

PROMPT PROMPT
PROMPT PROMPT Dropping relational constraints...

SELECT 'PROMPT ... dropping constraint '||constraint_name||' on table '||table_name
, 'alter table '||table_name||' drop constraint '||constraint_name||';'
FROM user_constraints
WHERE constraint_type = 'R'
/

PROMPT PROMPT
PROMPT PROMPT Dropping remaining user objects...

select 'PROMPT ... dropping '||object_type||' '||object_name
, 'drop '||object_type||' '||object_name||';'
from user_objects
WHERE object_type != 'INDEX'
/

spool off

set feedback on
set termout on
spool drop_user_objects.log
@drop_user_objects.lst.sql

PROMPT
PROMPT All database objects of the user dropped.
PROMPT Please review the log file drop_user_objects.log in the current directory.
PROMPT
PROMPT Count of remaining objects:

set feedback off

SELECT count(*) REMAINING_USER_OBJECTS
FROM user_objects
/

set feedback on
spool off
-- #############################################################################################
--
-- %Purpose: Enable all relational constraints on tables owned by the user that executes this script
--
-- #############################################################################################
--
-- Requires Oracle 8.1
--
------------------------------------------------------------------------------
PROMPT
PROMPT Generating script to enable disabled relational constraints...

set pagesize 0
set feedback off
set termout off
set linesize 100
set trimspool on
set wrap on

spool enable_relational_constraints.lst.sql

PROMPT PROMPT
PROMPT PROMPT Enabling relational constraints...

SELECT 'PROMPT ... enabling constraint '||constraint_name||' on table '||table_name
, 'alter table '||table_name||' enable constraint '||constraint_name||';'
FROM user_constraints
WHERE constraint_type = 'R'
AND status = 'DISABLED'
/

spool off
set feedback on
set termout on
spool enable_relational_constraints.log
@enable_relational_constraints.lst.sql
spool off
-- #############################################################################################
--
-- %Purpose: Extensive Partitioning Examples for Oracle8 Partition Option
--
-- Example 1: - The Partition Key is part of the Primary Key
-- - Partition Key: [date_cdr]
-- - Primary Key: [bkg_id,date_cdr]
--
-- Example 2: - The Partition Key is NOT part of the Primary Key
-- - Partition Key: [date_req]
-- - Primary Key: [bkg_id,req_id]
--
-- #############################################################################################
--
DROP TABLE cdr CASCADE CONSTRAINTS;
--
CREATE TABLE cdr (
bkg_id NUMBER(15) NOT NULL,
date_cdr DATE NOT NULL,
calltype NUMBER(2) NOT NULL)
PARTITION BY RANGE (date_cdr)
(PARTITION cdr_01_1999 VALUES LESS THAN
(TO_DATE('01.02.1999','DD.MM.YYYY'))
TABLESPACE cdr
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0,
PARTITION cdr_02_1999 VALUES LESS THAN
(TO_DATE('01.03.1999','DD.MM.YYYY'))
TABLESPACE cdr
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0,
PARTITION cdr_03_1999 VALUES LESS THAN
(TO_DATE('01.04.1999','DD.MM.YYYY'))
TABLESPACE cdr
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0,
PARTITION cdr_04_1999 VALUES LESS THAN
(TO_DATE('01.05.1999','DD.MM.YYYY'))
TABLESPACE cdr
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0,
PARTITION cdr_05_1999 VALUES LESS THAN (MAXVALUE)
TABLESPACE cdr
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0)
/
-------------------------------------------------------------------
-- Local NON prefixed Primary Key (UNIQUE)
--
-- Der linke Teil des Index stimmt nicht
-- mit dem Partition-Key [date_cdr] überein
-------------------------------------------------------------------
ALTER TABLE cdr ADD (
CONSTRAINT pk_cdr
PRIMARY KEY (bkg_id,date_cdr)
USING INDEX
LOCAL
(PARTITION cdr_01_1999
TABLESPACE idx_cdr
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0,
PARTITION cdr_02_1999
TABLESPACE idx_cdr
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0,
PARTITION cdr_03_1999
TABLESPACE idx_cdr
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0,
PARTITION cdr_04_1999
TABLESPACE idx_cdr
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0,
PARTITION cdr_05_1999
TABLESPACE idx_cdr
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0))
/
--
-------------------------------------------------------------------
-- Local NON prefixed Key (non UNIQUE)
--
-- Der linke Teil des Index stimmt nicht
-- mit dem Partition-Key [date_cdr] überein
-- Der Index kann NICHT UNIQUE sein, da calltype nicht Teil des
-- Primary Keys ist.
-------------------------------------------------------------------
CREATE INDEX cdr_idx_1 ON cdr (calltype)
LOCAL
(PARTITION cdr_01_1999
TABLESPACE idx_cdr
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0,
PARTITION cdr_02_1999
TABLESPACE idx_cdr
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0,
PARTITION cdr_03_1999
TABLESPACE idx_cdr
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0,
PARTITION cdr_04_1999
TABLESPACE idx_cdr
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0,
PARTITION cdr_05_1999
TABLESPACE idx_cdr
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0)
/
--
-------------------------------------------------------------------
-- Local prefixed Index (UNIQUE)
--
-- Der linke Teil des Index stimmt
-- mit dem Partition-Key [date_cdr] überein, deshalb kann der
-- Index UNIQUE sein.
-------------------------------------------------------------------
--
CREATE UNIQUE INDEX cdr_idx_2 ON cdr (date_cdr,bkg_id)
LOCAL
(PARTITION cdr_01_1999
TABLESPACE idx_cdr
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0,
PARTITION cdr_02_1999
TABLESPACE idx_cdr
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0,
PARTITION cdr_03_1999
TABLESPACE idx_cdr
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0,
PARTITION cdr_04_1999
TABLESPACE idx_cdr
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0,
PARTITION cdr_05_1999
TABLESPACE idx_cdr
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0)
/
ALTER TABLE cdr ADD (
CONSTRAINT cdr_idx_2
UNIQUE (date_cdr,bkg_id))
/
--
-------------------------------------------------------------------
-- Local prefixed Index (UNIQUE)
--
-- Der linke Teil des Index entspricht dem Partition-Key [date_cdr].
-- Deshalb kann der Index UNIQUE sein.
-------------------------------------------------------------------
--
CREATE UNIQUE INDEX cdr_idx_3 ON cdr (date_cdr)
LOCAL
(PARTITION cdr_01_1999
TABLESPACE idx_cdr
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0,
PARTITION cdr_02_1999
TABLESPACE idx_cdr
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0,
PARTITION cdr_03_1999
TABLESPACE idx_cdr
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0,
PARTITION cdr_04_1999
TABLESPACE idx_cdr
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0,
PARTITION cdr_05_1999
TABLESPACE idx_cdr
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0)
/
-------------------------------------------------------------------
-- Example 2: - Der Partition Key ist NICHT Teil des Primary Keys
-- - Partition Key: [date_req]
-- - Primary Key: [bkg_id,req_id]
-------------------------------------------------------------------
--
DROP TABLE req CASCADE CONSTRAINTS;
--
CREATE TABLE req (
bkg_id NUMBER(15) NOT NULL,
req_id NUMBER(15) NOT NULL,
date_req DATE NOT NULL,
status NUMBER(2) NOT NULL)
PARTITION BY RANGE (date_req)
(PARTITION req_01_1999 VALUES LESS THAN
(TO_DATE('01.02.1999','DD.MM.YYYY'))
TABLESPACE req
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0,
PARTITION req_02_1999 VALUES LESS THAN
(TO_DATE('01.03.1999','DD.MM.YYYY'))
TABLESPACE req
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0,
PARTITION req_03_1999 VALUES LESS THAN
(TO_DATE('01.04.1999','DD.MM.YYYY'))
TABLESPACE req
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0,
PARTITION req_04_1999 VALUES LESS THAN
(TO_DATE('01.05.1999','DD.MM.YYYY'))
TABLESPACE req
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0,
PARTITION req_05_1999 VALUES LESS THAN (MAXVALUE)
TABLESPACE req
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0)
/
-------------------------------------------------------------------
-- Normaler Primary Key, unpartitioniert, nicht zu empfehlen
-- da der Index wieder sehr gross wird. Besser nach einem anderen
-- Kriterium partionieren, zB [bkg_id,req_id]
-------------------------------------------------------------------
--
ALTER TABLE req ADD (
CONSTRAINT pk_req
PRIMARY KEY (bkg_id,req_id)
USING INDEX
TABLESPACE idx_req
STORAGE
(INITIAL 500K
NEXT 500K
MINEXTENTS 1
MAXEXTENTS UNLIMITED
PCTINCREASE 0
FREELISTS 2)
)
/
ALTER TABLE req DROP PRIMARY KEY
/
-------------------------------------------------------------------
-- Globaler Primary Key, ein "MUST" für Primary Keys welche ohne
-- den Partition-Key auskommen müssen.
-------------------------------------------------------------------
--
CREATE UNIQUE INDEX pk_req ON req (bkg_id,req_id)
GLOBAL
PARTITION BY RANGE (bkg_id,req_id)
(PARTITION pk_req_01
VALUES LESS THAN (100000,100000)
TABLESPACE idx_bkg
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0,
PARTITION pk_req_02
VALUES LESS THAN (200000,200000)
TABLESPACE idx_bkg
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0,
PARTITION pk_req_03
VALUES LESS THAN (300000,300000)
TABLESPACE idx_bkg
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0,
PARTITION pk_req_04
VALUES LESS THAN (MAXVALUE,MAXVALUE)
TABLESPACE idx_bkg
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0)
/
ALTER TABLE req ADD (
CONSTRAINT pk_req
PRIMARY KEY (bkg_id,req_id))
/
-------------------------------------------------------------------
-- Local prefixed Index (UNIQUE wäre möglich)
--
-- Der linke Teil des Index stimmt mit dem Partition-Key
-- [date_req] überein.
-------------------------------------------------------------------
--
CREATE INDEX idx_req_1 ON req (date_req,req_id)
LOCAL
(PARTITION req_01_1999
TABLESPACE idx_req
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0,
PARTITION req_02_1999
TABLESPACE idx_req
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0,
PARTITION req_03_1999
TABLESPACE idx_req
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0,
PARTITION req_04_1999
TABLESPACE idx_req
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0,
PARTITION req_05_1999
TABLESPACE idx_req
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0)
/
-------------------------------------------------------------------
-- Local prefixed Index nur auf Partition-Key
--
-- Der Index entspricht mit dem Partition-Key [date_req]
-------------------------------------------------------------------
--
CREATE INDEX idx_req_2 ON req (date_req)
LOCAL
(PARTITION req_01_1999
TABLESPACE idx_req
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0,
PARTITION req_02_1999
TABLESPACE idx_req
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0,
PARTITION req_03_1999
TABLESPACE idx_req
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0,
PARTITION req_04_1999
TABLESPACE idx_req
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0,
PARTITION req_05_1999
TABLESPACE idx_req
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0)
/
-------------------------------------------------------------------
-- Local non prefixed Index
--
-- Der linke Teil des Index stimmt NICHT mit dem
-- Partition-Key date_req überein
-------------------------------------------------------------------
--
CREATE INDEX idx_req_3 ON req (req_id,date_req)
LOCAL
(PARTITION req_01_1999
TABLESPACE idx_req
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0,
PARTITION req_02_1999
TABLESPACE idx_req
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0,
PARTITION req_03_1999
TABLESPACE idx_req
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0,
PARTITION req_04_1999
TABLESPACE idx_req
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0,
PARTITION req_05_1999
TABLESPACE idx_req
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0)
/
-------------------------------------------------------------------
-- Local non prefixed Index
--
-- Der Index ist ein beliebiges Attribut
-------------------------------------------------------------------
--
CREATE INDEX idx_req_4 ON req (req_id)
LOCAL
(PARTITION req_01_1999
TABLESPACE idx_req
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0,
PARTITION req_02_1999
TABLESPACE idx_req
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0,
PARTITION req_03_1999
TABLESPACE idx_req
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0,
PARTITION req_04_1999
TABLESPACE idx_req
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0,
PARTITION req_05_1999
TABLESPACE idx_req
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0)
/
-------------------------------------------------------------------
-- Bitmapped Indexe
--
-- Bitmapped Indexe sind immer local, global nicht möglich
-------------------------------------------------------------------
--
CREATE BITMAP INDEX idx_bm_req_1 ON req (status)
LOCAL
(PARTITION req_01_1999
TABLESPACE idx_req
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0,
PARTITION req_02_1999
TABLESPACE idx_req
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0,
PARTITION req_03_1999
TABLESPACE idx_req
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0,
PARTITION req_04_1999
TABLESPACE idx_req
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0,
PARTITION req_05_1999
TABLESPACE idx_req
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0)
/
-------------------------------------------------------------------
-- Anfügen von zwei neuen Partitionen
-------------------------------------------------------------------
--
ALTER TABLE req
SPLIT PARTITION req_05_1999 AT (TO_DATE('31.05.1999','DD.MM.YYYY'))
INTO
(PARTITION req_05_1999_1
TABLESPACE req
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0,
PARTITION req_05_1999_2
TABLESPACE req
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0)
/
ALTER TABLE req
RENAME PARTITION req_05_1999_1 TO req_05_1999
/
ALTER TABLE req
RENAME PARTITION req_05_1999_2 TO req_06_1999
/
--
ALTER TABLE req
SPLIT PARTITION req_06_1999 AT (TO_DATE('30.06.1999','DD.MM.YYYY'))
INTO
(PARTITION req_06_1999_1
TABLESPACE req
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0,
PARTITION req_06_1999_2
TABLESPACE req
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0)
/
--
-- Die local Indexes wurden auch aufgeteilt und müssen
-- nun wieder auf die gleichen Partionsnamen geändert werden
--
ALTER TABLE req
RENAME PARTITION req_06_1999_1 TO req_06_1999
/
ALTER TABLE req
RENAME PARTITION req_06_1999_2 TO req_07_1999
/
--
ALTER INDEX idx_req_1
RENAME PARTITION req_05_1999_1 TO req_05_1999
/
ALTER INDEX idx_req_1
RENAME PARTITION req_06_1999_1 TO req_06_1999
/
ALTER INDEX idx_req_1
RENAME PARTITION req_06_1999_2 TO req_07_1999
/
--
ALTER INDEX idx_req_2
RENAME PARTITION req_05_1999_1 TO req_05_1999
/
ALTER INDEX idx_req_2
RENAME PARTITION req_06_1999_1 TO req_06_1999
/
ALTER INDEX idx_req_2
RENAME PARTITION req_06_1999_2 TO req_07_1999
/
--
ALTER INDEX idx_req_3
RENAME PARTITION req_05_1999_1 TO req_05_1999
/
ALTER INDEX idx_req_3
RENAME PARTITION req_06_1999_1 TO req_06_1999
/
ALTER INDEX idx_req_3
RENAME PARTITION req_06_1999_2 TO req_07_1999
/
--
ALTER INDEX idx_req_4
RENAME PARTITION req_05_1999_1 TO req_05_1999
/
ALTER INDEX idx_req_4
RENAME PARTITION req_06_1999_1 TO req_06_1999
/
ALTER INDEX idx_req_4
RENAME PARTITION req_06_1999_2 TO req_07_1999
/
--
ALTER INDEX idx_bm_req_1
RENAME PARTITION req_05_1999_1 TO req_05_1999
/
ALTER INDEX idx_bm_req_1
RENAME PARTITION req_06_1999_1 TO req_06_1999
/
ALTER INDEX idx_bm_req_1
RENAME PARTITION req_06_1999_2 TO req_07_1999
/
--
-- Rebuild aller local Indexes
--
ALTER TABLE req MODIFY PARTITION req_01_1999
REBUILD UNUSABLE LOCAL INDEXES
/
ALTER TABLE req MODIFY PARTITION req_02_1999
REBUILD UNUSABLE LOCAL INDEXES
/
ALTER TABLE req MODIFY PARTITION req_03_1999
REBUILD UNUSABLE LOCAL INDEXES
/
ALTER TABLE req MODIFY PARTITION req_04_1999
REBUILD UNUSABLE LOCAL INDEXES
/
ALTER TABLE req MODIFY PARTITION req_05_1999
REBUILD UNUSABLE LOCAL INDEXES
/
ALTER TABLE req MODIFY PARTITION req_06_1999
REBUILD UNUSABLE LOCAL INDEXES
/
ALTER TABLE req MODIFY PARTITION req_07_1999
REBUILD UNUSABLE LOCAL INDEXES
/
-------------------------------------------------------------------
-- Anfügen von einer neuen Partition für den Primary Key
-------------------------------------------------------------------
--
ALTER INDEX pk_req
SPLIT PARTITION pk_req_04 AT (400000,400000)
INTO
(PARTITION pk_req_04_1
TABLESPACE req
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0,
PARTITION pk_req_04_2
TABLESPACE req
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0)
/
ALTER INDEX pk_req
RENAME PARTITION pk_req_04_1 TO pk_req_04
/
ALTER INDEX pk_req
RENAME PARTITION pk_req_04_2 TO pk_req_05
/
--
-- Rebuild des Primary Keys einzeln für jede Partition
--
ALTER INDEX pk_req
REBUILD PARTITION pk_req_01
/
ALTER INDEX pk_req
REBUILD PARTITION pk_req_02
/
ALTER INDEX pk_req
REBUILD PARTITION pk_req_03
/
ALTER INDEX pk_req
REBUILD PARTITION pk_req_04
/
ALTER INDEX pk_req
REBUILD PARTITION pk_req_05
/

--
-- Add Partition (Der Partition Key ist Teil des Primary Keys)
--
-- Dies ist nur möglich, wenn die letzte Partition nicht
-- durch MAXVALUE begrenzt ist. Deshalb löschen wir die
-- letzte Partition zuerst. Die local Indexes werden beim
-- Hinzufügen von Partitions automatisch auch mit einer
-- Indexpartition ergänzt (sehr gute Wartbarkeit).
--
ALTER TABLE cdr DROP PARTITION cdr_05_1999;
ALTER TABLE cdr
ADD PARTITION cdr_05_1999 VALUES LESS THAN
(TO_DATE('01.06.1999','DD.MM.YYYY'))
TABLESPACE cdr
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0;
ALTER TABLE cdr
ADD PARTITION cdr_06_1999 VALUES LESS THAN
(TO_DATE('01.07.1999','DD.MM.YYYY'))
TABLESPACE cdr
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0;
ALTER TABLE cdr
ADD PARTITION cdr_07_1999 VALUES LESS THAN
(TO_DATE('01.08.1999','DD.MM.YYYY'))
TABLESPACE cdr
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0;
--
-- Add Partition (Der Partition Key ist nicht Teil des Primary Keys)
--
-- Auch hier werden die local Indexes automatisch nachgefahren.
-- Die Indexpartition des global Primary Key bleibt logischerweise
-- unberührt, da dies eine vollkommen autonome Partition ist.
--
ALTER TABLE req DROP PARTITION req_07_1999;
ALTER TABLE req
ADD PARTITION req_07_1999 VALUES LESS THAN
(TO_DATE('01.08.1999','DD.MM.YYYY'))
TABLESPACE req
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0;
ALTER TABLE req
ADD PARTITION req_08_1999 VALUES LESS THAN
(TO_DATE('01.09.1999','DD.MM.YYYY'))
TABLESPACE req
STORAGE (INITIAL 1K NEXT 100M MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0;
--
-- Move Partition
--
ALTER TABLE req
MOVE PARTITION req_08_1999
TABLESPACE tab
STORAGE (INITIAL 1K NEXT 1K MINEXTENTS 1 MAXEXTENTS UNLIMITED) PCTFREE 0;
--
-- Indexe müssen rebuilded werden, da sie durch Move
-- Partition IU wurden (Index Unusable)
--
ALTER INDEX idx_req_1
REBUILD PARTITION req_08_1999
/
ALTER INDEX idx_req_2
REBUILD PARTITION req_08_1999
/
ALTER INDEX idx_req_3
REBUILD PARTITION req_08_1999
/
ALTER INDEX idx_req_4
REBUILD PARTITION req_08_1999
/
-- #############################################################################################
--
-- %Purpose: Flush Shared Pool when it reaches 60-70% of it's capacity
--
-- Use: SYS-User
--
-- #############################################################################################
--
-- On a recent project we had a problem where performance would start
-- acceptable at the beginning of the day and by mid-day would be
-- totally unacceptable. Investigation showed that the third party
-- application that ran on top of the Oracle database was generating
-- ad hoc SQL without using bind variables. This generation of ad hoc
-- SQL and non-use of bind variables was resulting in proliferation of
-- non-reusable code fragments in the shared pool, one user had over
-- 90 shared pool segments assigned for queries that differed only by
-- the selection parameter (for example "where last_name='SMITH'"
-- instead of "where last_name='JONES'"). This proliferation of multiple
-- nearly identical SQL statements meant that for each query issued
-- the time to scan the shared pool for identical statements was increasing
-- for each non-reusable statement generated.
--
-- A flush of the shared pool was the only solution to solve this performance
-- problem, resulting that all other query returned again in less than a second.
--
-- It was determined that an automatic procedure was needed to monitor
-- the shared pool and flush it when it reached 60-70% of capacity.

--
-- The following procedue was created:
--
CREATE OR REPLACE VIEW sys.sql_summary AS SELECT
username,
sharable_mem,
persistent_mem,
runtime_mem
FROM sys.v_$sqlarea a, dba_users b
WHERE a.parsing_user_id = b.user_id;

CREATE OR REPLACE PROCEDURE flush_it AS

CURSOR get_share IS
SELECT SUM(sharable_mem)
FROM sys.sql_summary;

CURSOR get_var IS
SELECT value
FROM v$sga
WHERE name like 'Var%';

CURSOR get_time is
SELECT SYSDATE
FROM dual;

todays_date DATE;
mem_ratio NUMBER;
share_mem NUMBER;
variable_mem NUMBER;
cur INTEGER;
sql_com VARCHAR2(60);
row_proc NUMBER;

BEGIN

OPEN get_share;
OPEN get_var;

FETCH get_share INTO share_mem;
DBMS_OUTPUT.PUT_LINE('share_mem: '||to_char(share_mem));

FETCH get_var INTO variable_mem;
DBMS_OUTPUT.PUT_LINE('variable_mem: '||to_char(variable_mem));

mem_ratio:=share_mem/variable_mem;
DBMS_OUTPUT.PUT_LINE('mem_ratio: '||to_char(mem_ratio));

IF (mem_ratio>0.3) THEN
DBMS_OUTPUT.PUT_LINE ('Flushing Shared Pool ...');
cur:=DBMS_SQL.open_cursor;
sql_com:='ALTER SYSTEM FLUSH SHARED_POOL';
DBMS_SQL.PARSE(cur,sql_com,dbms_sql.v7);
row_proc:=DBMS_SQL.EXECUTE(cur);
DBMS_SQL.CLOSE_CURSOR(cur);
END IF;
END;
/

-- This procedure was then loaded into the job queue and scheduled to run
-- every hour using the following commands:

DECLARE
job NUMBER;
BEGIN
DBMS_JOB.SUBMIT(job,'flush_it;',sysdate,'sysdate+1/24');
END;
/
-- #############################################################################################
--
-- %Purpose: Formatted SELECT * FROM 'table' Statement Results
--
-- SQL Script to display data FROM any table in a Vertical Layout
-- and only 1 row per viewable page
--
-- Sample output for the emp table output format is :
--
-- DEPT = --------------------------CRIME [5]
-- EMP_NO = ------------------------1 [1]
-- FIRST_NAME = --------------------JOHN [4]
-- JOIN_DATE = ---------------------02/01/1999 17:38:56 [9]
-- LAST_NAME = ---------------------DOE [3]
-- MIDDLE_INITIAL = ----------------P [1]
--
-- Press return To Continue
--
-- #############################################################################################

col eol newline
set head off pages 0 numf 9999999999.99
set lines 200 wrap on trimspool on
prompt NOTE : LONG/RAW/LOB COLUMNS WILL NOT BE DISPLAYED
prompt
set feedback off verify off echo off
accept tab prompt "Enter table name: [Example: emp] "
prompt
prompt To enter strings in the WHERE clause or ORDER BY, enclose it
prompt within '''' single quotes instead of the usual single quote
prompt [Example: ename = ''''JAMES'''']
prompt
accept wher prompt "Enter Where clause {default is none}: "
accept oner prompt "Enter owner {default is current user}: "
accept sortorder prompt "Enter Order by clause <1,3,5,..> {default is unordered}: "
prompt
prompt Press Return ...
prompt
set termout off
col COLUMN_NAME noprint
col wherstmt new_val wherclause
col ordby new_val orderby
col usr new_val objuser
SELECT
DECODE(NVL(LENGTH('&sortorder'),0),0,'' ,' ORDER BY &sortorder') ordby ,
DECODE(NVL(LENGTH('&wher'),0),0,'' ,' WHERE &wher') wherstmt ,
NVL(UPPER('&oner'),USER) usr FROM dual;

spool vertdisp.sql

SELECT
'set pages '||TO_CHAR(count(*)+2) eol,
'set head off pause on numf 999999999999.99 lines 80 ' eol,
'set feedback off verify off echo off termout on trimspool on' eol
FROM
DBA_TAB_COLUMNS
WHERE OWNER = '&objuser' AND
TABLE_NAME = UPPER('&tab') AND
DATA_TYPE NOT LIKE ('%RAW');

prompt SELECT

SELECT
COLUMN_NAME,
'RPAD('||''''||COLUMN_NAME||' = '||
''''||',33,'||''''||'-'||''''||') '||'||'||
DECODE(DATA_TYPE,'DATE','TO_CHAR('||COLUMN_NAME||','||''''||'MM/DD/YYYY HH24:MI:SS'||''''||')',
COLUMN_NAME) || ' '||
DECODE(DATA_TYPE,'NUMBER',DECODE(SIGN(DATA_SCALE-1),-1,' ||',
' ||'),' '||' ||')|| ''''|| ' ['||''''||'||'||
' TO_CHAR(NVL(LENGTH('||COLUMN_NAME||'),0))'||
'||'||''''||']'||''''||' eol,' cl
FROM
DBA_TAB_COLUMNS
WHERE
OWNER = '&objuser' AND
TABLE_NAME = UPPER('&tab') AND
DATA_TYPE NOT LIKE ('%RAW') AND
COLUMN_NAME < (SELECT MAX(COLUMN_NAME)
FROM DBA_TAB_COLUMNS
WHERE OWNER = '&objuser' AND
TABLE_NAME = UPPER('&tab'))
UNION
SELECT
COLUMN_NAME,
'RPAD('||''''||COLUMN_NAME||' = '||
''''||',33,'||''''||'-'||''''||') '||'||'||
DECODE(DATA_TYPE,'DATE','TO_CHAR('||COLUMN_NAME||','||''''||'MM/DD/YYYY HH24:MI:SS'||''''||')',
COLUMN_NAME) || ' '||
DECODE(DATA_TYPE,'NUMBER',DECODE(SIGN(DATA_SCALE-1),-1,' ||',
' ||'),' '||' ||')|| ''''|| ' ['||''''||'||'||
' TO_CHAR(NVL(LENGTH('||COLUMN_NAME||'),0))'||
'||'||''''||']'||''''||' eol'||
' FROM &objuser..&tab '||' &wherclause '||' &orderby ;' cl
FROM
DBA_TAB_COLUMNS
WHERE
OWNER = '&objuser' AND
TABLE_NAME = UPPER('&tab') AND
DATA_TYPE NOT LIKE ('%RAW') AND
COLUMN_NAME = (SELECT MAX(COLUMN_NAME )
FROM DBA_TAB_COLUMNS
WHERE OWNER = '&objuser' AND
TABLE_NAME = UPPER('&tab'))
ORDER BY COLUMN_NAME;
spool off
start vertdisp
clear colu
-- #############################################################################################
--
-- %Purpose: Generate 'CREATE TABLE' Script for an existing Table in the database
--
-- Use: SYSTEM, SYS or user having SELECT ANY TABLE system privilege
--
-- #############################################################################################
--
set serveroutput on size 200000
set echo off
set feedback off
set verify off
set showmode off
--
ACCEPT l_user CHAR PROMPT 'Username: '
ACCEPT l_table CHAR PROMPT 'Tablename: '
--
DECLARE
CURSOR TabCur IS
SELECT table_name,owner,tablespace_name,
initial_extent,next_extent,
pct_used,pct_free,pct_increase,degree
FROM sys.dba_tables
WHERE owner=upper('&&l_user')
AND table_name=UPPER('&&l_table');
--
CURSOR ColCur(TableName varchar2) IS
SELECT column_name col1,
DECODE (data_type,
'LONG', 'LONG ',
'LONG RAW', 'LONG RAW ',
'RAW', 'RAW ',
'DATE', 'DATE ',
'CHAR', 'CHAR' || '(' || data_length || ') ',
'VARCHAR2', 'VARCHAR2' || '(' || data_length || ') ',
'NUMBER', 'NUMBER' ||
DECODE (NVL(data_precision,0),0, ' ',' (' || data_precision ||
DECODE (NVL(data_scale, 0),0, ') ',',' || DATA_SCALE || ') '))) ||
DECODE (NULLABLE,'N', 'NOT NULL',' ') col2
FROM sys.dba_tab_columns
WHERE table_name=TableName
AND owner=UPPER('&&l_user')
ORDER BY column_id;
--
ColCount NUMBER(5);
MaxCol NUMBER(5);
FillSpace NUMBER(5);
ColLen NUMBER(5);
--
BEGIN
MaxCol:=0;
--
FOR TabRec in TabCur LOOP
SELECT MAX(column_id) INTO MaxCol FROM sys.dba_tab_columns
WHERE table_name=TabRec.table_name
AND owner=TabRec.owner;
--
dbms_output.put_line('CREATE TABLE '||TabRec.table_name);
dbms_output.put_line('( ');
--
ColCount:=0;
FOR ColRec in ColCur(TabRec.table_name) LOOP
ColLen:=length(ColRec.col1);
FillSpace:=40 - ColLen;
dbms_output.put(ColRec.col1);
--
FOR i in 1..FillSpace LOOP
dbms_output.put(' ');
END LOOP;
--
dbms_output.put(ColRec.col2);
ColCount:=ColCount+1;
--
IF (ColCount < MaxCol) THEN
dbms_output.put_line(',');
ELSE
dbms_output.put_line(')');
END IF;
END LOOP;
--
dbms_output.put_line('TABLESPACE '||TabRec.tablespace_name);
dbms_output.put_line('PCTFREE '||TabRec.pct_free);
dbms_output.put_line('PCTUSED '||TabRec.pct_used);
dbms_output.put_line('STORAGE ( ');
dbms_output.put_line(' INITIAL '||TabRec.initial_extent);
dbms_output.put_line(' NEXT '||TabRec.next_extent);
dbms_output.put_line(' PCTINCREASE '||TabRec.pct_increase);
dbms_output.put_line(' )');
dbms_output.put_line('PARALLEL '||TabRec.degree);
dbms_output.put_line('/');
END LOOP;
END;
/
-- #############################################################################################
--
-- %Purpose: Generate INSERT statements for existing data in a table
--
-- Author: christoph.bohl@akadia.com
--
-- #############################################################################################
--
PROMPT ==========================================================================
PROMPT Generate INSERT statements for existing data in a table
PROMPT ==========================================================================
PROMPT
PROMPT You'll be prompted for the following:
PROMPT - table_name: The name of the table to generate statements (case insensitive)
PROMPT - col1: The name of a column you want to fill with fixed data (case insensitive)
PROMPT . - [ENTER]: do not use this functionality
PROMPT - col1_value: The value for the column above (case sensitive)
PROMPT . - Enter String Values within two single quotes: ''example''
PROMPT . - [ENTER]: do not use this functionality
PROMPT - col2: The name of a column you want to fill with fixed data (case insensitive)
PROMPT . - [ENTER]: do not use this functionality
PROMPT - col2_value: The value for the column above (case sensitive)
PROMPT . - Enter String Values within two single quotes: ''example''
PROMPT . - [ENTER]: do not use this functionality
PROMPT

set feedback off
set trimspool on
set linesize 255

CREATE OR REPLACE PROCEDURE genins(p_table IN varchar
,p_default_col1 VARCHAR default null
,p_default_col1_value VARCHAR default null
,p_default_col2 VARCHAR default null
,p_default_col2_value VARCHAR default null)
IS
--
l_column_list VARCHAR(2000);
l_value_list VARCHAR(2000);
l_query VARCHAR(2000);
l_cursor INTEGER;
ignore NUMBER;
--
FUNCTION get_cols(p_table VARCHAR)
RETURN VARCHAR
IS
l_cols VARCHAR(2000);
CURSOR l_col_cur(c_table VARCHAR) IS
SELECT column_name
FROM user_tab_columns
WHERE table_name = upper(c_table)
ORDER BY column_id;
BEGIN
l_cols := null;
FOR rec IN l_col_cur(p_table)
LOOP
l_cols := l_cols || rec.column_name || ',';
END LOOP;
RETURN substr(l_cols,1,length(l_cols)-1);
END;
--
FUNCTION get_query(p_table IN VARCHAR
,p_default_col1 VARCHAR
,p_default_col1_value VARCHAR
,p_default_col2 VARCHAR
,p_default_col2_value VARCHAR)
RETURN VARCHAR
IS
l_query VARCHAR(2000);
CURSOR l_query_cur(c_table VARCHAR
,c_default_col1 VARCHAR
,c_default_col1_value VARCHAR
,c_default_col2 VARCHAR
,c_default_col2_value VARCHAR) IS
SELECT decode(column_name,c_default_col1,''''||replace(c_default_col1_value,'''','''''')||'''',
decode(column_name,c_default_col2,''''||replace(c_default_col2_value,'''','''''')||'''',
'decode('||column_name||',null,''null'','||
decode(data_type
,'VARCHAR2','''''''''||'||column_name ||'||'''''''''
,'DATE' ,'''to_date(''''''||to_char('||column_name||',''YYYY-MM-DD HH24:MI:SS'')||'''''',''''YYYY-MM-DD HH24:MI:SS'''')'''
,column_name
) || ')' )) column_query
FROM user_tab_columns
WHERE table_name = upper(c_table)
ORDER BY column_id;
BEGIN
l_query := 'SELECT ';
FOR rec IN l_query_cur(p_table, p_default_col1, p_default_col1_value, p_default_col2, p_default_col2_value)
LOOP
l_query := l_query || rec.column_query || '||'',''||';
END LOOP;
l_query := substr(l_query,1,length(l_query)-7);
RETURN l_query || ' FROM ' || p_table;
END;
--
BEGIN
l_column_list := get_cols(p_table);
l_query := get_query(p_table,upper(p_default_col1),p_default_col1_value
,upper(p_default_col2),p_default_col2_value);
l_cursor := dbms_sql.open_cursor;
DBMS_SQL.PARSE(l_cursor, l_query, DBMS_SQL.native);
DBMS_SQL.DEFINE_COLUMN(l_cursor, 1, l_value_list, 2000);
ignore := DBMS_SQL.EXECUTE(l_cursor);
--
LOOP
IF DBMS_SQL.FETCH_ROWS(l_cursor)>0 THEN
DBMS_SQL.COLUMN_VALUE(l_cursor, 1, l_value_list);
DBMS_OUTPUT.PUT_LINE('INSERT INTO '||p_table||' ('||l_column_list||')');
DBMS_OUTPUT.PUT_LINE(' VALUES ('||l_value_list||');');
ELSE
EXIT;
END IF;
END LOOP;
END;
/

set serveroutput on size 1000000
exec genins('&table_name','&col1','&col1_value','&col2','&col2_value');
set serveroutput off

drop procedure genins;
set feedback on
-- #############################################################################################
--
-- %Purpose: Generate Script to coalesce free Space in cluttered Tablespaces
--
-- #############################################################################################
--
SELECT a1.tablespace_name,COUNT(*) nbr_cont_wholes
FROM sys.dba_free_space a1, sys.dba_free_space a2
WHERE a1.tablespace_name=a2.tablespace_name
AND a1.block_id+a1.blocks = a2.block_id
GROUP BY A1.tablespace_name
/
set heading off
spool alter_ts_coal.sql
SELECT 'ALTER TABLESPACE '||a1.tablespace_name||' COALESCE;'
FROM sys.dba_free_space a1, sys.dba_free_space a2
WHERE a1.tablespace_name=a2.tablespace_name
AND a1.block_id+a1.blocks = a2.block_id
GROUP BY A1.tablespace_name
/
SPOOL OFF
set heading on
@alter_ts_coal.sql
-- #############################################################################################
--
-- %Purpose: Guide for Tuning the Rollback Segments
--
-- #############################################################################################

1). Size and Number of Waits per Rollback-Segment
-------------------------------------------------
SELECT SUBSTR(rsn.name,1,10) "Name",
rss.rssize "Tot-Size [Bytes]",
rss.extents "Extents",
ROUND(rss.rssize/rss.extents) "RS-Size [Bytes]",
waits "Number Waits"
FROM v$rollstat rss, v$rollname rsn
WHERE rss.usn = rsn.usn
ORDER BY rsn.name;

Old Tuning Session: (Rollback Segments with 400 KB Size)

Name Tot-Size [Bytes] Extents RS-Size [Bytes] Number Waits
---------- ---------------- ---------- --------------- ------------
RBS01 8597504 21 409405 1616
RBS02 8597504 21 409405 4125
RBS03 8597504 21 409405 3992
RBS04 8597504 21 409405 4174
RBS05 8597504 21 409405 3617
RBS06 8597504 21 409405 3843
RBS07 8597504 21 409405 3715
RBS08 8597504 21 409405 3730
RBS09 8597504 21 409405 25699
RBS10 8597504 21 409405 3635

New Tuning Session: (Rollback Segments with 5 MB Size)

Name Tot-Size [Bytes] Extents RS-Size [Bytes] Number Waits
---------- ---------------- ---------- --------------- ------------
RBS01 104853504 20 5242675 1715
RBS02 104853504 20 5242675 1835
RBS03 104853504 20 5242675 1338
RBS04 104853504 20 5242675 1499
RBS05 104853504 20 5242675 1572
RBS06 104853504 20 5242675 1628
RBS07 104853504 20 5242675 1533
RBS08 104853504 20 5242675 1689
RBS09 104853504 20 5242675 1461
RBS10 104853504 20 5242675 1663

2). Rollback Contention
-----------------------
SELECT name,gets,waits,
to_char(((gets-waits)*100)/gets,'999.9999') hit_ratio
FROM v$rollstat S, v$rollname R
WHERE S.usn = R.usn
ORDER BY R.name;

Old Tuning Session: (Rollback Segments with 400 KB Size)

NAME GETS WAITS HIT_RATIO
------------------------------ ---------- ---------- ---------
RBS01 5314092 1643 99.9691
RBS02 10363748 4157 99.9599
RBS03 10459920 4017 99.9616
RBS04 10962299 4184 99.9618
RBS05 9469712 3649 99.9615
RBS06 10218019 3889 99.9619
RBS07 9796463 3736 99.9619
RBS08 9900727 3739 99.9622
RBS09 13130819 25721 99.8041
RBS10 9456272 3673 99.9612

New Tuning Session: (Rollback Segments with 5 MB Size)

NAME GETS WAITS HIT_RATIO
------------------------------ ---------- ---------- ---------
RBS01 5837671 1719 99.9706
RBS02 6151758 1835 99.9702
RBS03 5451355 1338 99.9755
RBS04 5105157 1499 99.9706
RBS05 5333881 1574 99.9705
RBS06 6070279 1631 99.9731
RBS07 5611779 1533 99.9727
RBS08 6097782 1692 99.9723
RBS09 5558601 1462 99.9737
RBS10 6418860 1663 99.9741

3). Compare rollback segment waits with total number of gets
------------------------------------------------------------
Rollback segment waits

SELECT v.class, v.count
FROM v$waitstat v
WHERE class IN ('system undo header','system undo block',
'undo header','undo block');

Total number of gets

SELECT TO_CHAR(sum(value),'999,999,999,999') "Total Gets"
FROM v$sysstat
WHERE name in ('db block gets','consistent gets');

Old Tuning Session: (Much waits compared with total Gets)

CLASS COUNT
------------------ ----------
system undo header 0
system undo block 0
undo header 74880
undo block 21618

Total Gets
----------------
8,896,140,872

New Tuning Session: (Much waits compared with total Gets, not better)

CLASS COUNT
------------------ ----------
system undo header 0
system undo block 0
undo header 24138
undo block 28146

Total Gets
----------------
4,152,462,130


4). Overall System-Statistics for ALL Rollback-Segments
-------------------------------------------------------
SELECT statistic#,SUBSTR(name,1,50) "Name",
class,value
FROM v$sysstat
WHERE name in ('user rollbacks',
'rollback changes - undo records applied',
'transaction rollbacks');

Old Tuning Session

STATISTIC# Name CLASS VALUE
---------- -------------------------------------------------- ---------- ------------
5 user rollbacks 1 30
113 rollback changes - undo records applied 128 2'524'864
114 transaction rollbacks 128 29'131

A low number of rollbacks initiate a high nunber of waits !

New Tuning Session

STATISTIC# Name CLASS VALUE
---------- -------------------------------------------------- ---------- ----------
5 user rollbacks 1 51
113 rollback changes - undo records applied 128 111886
114 transaction rollbacks 128 13649

5). Who uses the Rollback Segments
----------------------------------
SELECT r.usn,SUBSTR(r.name,1,10) "Name",s.osuser,
SUBSTR(s.username,1,15) "User",s.sid,x.extents,
x.extends,x.waits,x.shrinks,
x.wraps
FROM sys.v_$rollstat X,
sys.v_$rollname R,
sys.v_$session S,
sys.v_$transaction T
WHERE t.addr = s.taddr (+)
AND x.usn (+) = r.usn
AND t.xidusn (+) = r.usn
ORDER BY r.usn;

Old Tuning Session

USN Name OSUSER User SID EXTENTS EXTENDS WAITS SHRINKS WRAPS
---------- ---------- --------------- --------------- ---------- ---------- ---------- ---------- ---------- ----------
0 SYSTEM 4 0 0 0 0
2 RBS01 poseidon VP_LINK 55 21 321 1703 34 3448
3 RBS02 ota DISPATCHER 35 21 370 4175 42 6589
4 RBS03 poseidon VP_LINK 59 21 445 4074 53 6981
5 RBS04 poseidon VP_LINK 56 21 262 4252 33 7073
6 RBS05 bscs SMH_LINK 76 21 195 3772 22 5847
7 RBS06 21 291 4044 34 6665
8 RBS07 21 259 3803 31 6336
9 RBS08 poseidon VP_LINK 57 21 529 3820 64 6789
10 RBS09 poseidon VP_LINK 54 21 599 25839 69 8153
11 RBS10 21 398 3772 45 5878

New Tuning Session

USN Name OSUSER User SID EXTENTS EXTENDS WAITS SHRINKS WRAPS
---------- ---------- --------------- --------------- ---------- ---------- ---------- ---------- ---------- ----------
0 SYSTEM 4 0 0 0 1
1 RBS10 20 0 1681 0 299
2 RBS01 20 0 1731 0 277
3 RBS02 poseidon VP_LINK 93 20 0 1850 0 288
4 RBS03 poseidon VP_LINK 92 20 0 1338 0 248
5 RBS04 poseidon VP_LINK 86 20 0 1499 0 232
6 RBS05 bscs SMH_LINK 94 20 0 1583 0 258
7 RBS06 bscs SMH_LINK 113 20 0 1645 0 282
8 RBS07 poseidon VP_LINK 70 20 0 1533 0 260
9 RBS08 20 0 1694 0 274
10 RBS09 20 0 1483 0 264

No more extends and shrinks.
-- #############################################################################################
--
-- %Purpose: Guide for Tuning with UTLBSTAT und UTLESTAT
--
-- #############################################################################################

***********************************
1). Select Library cache statistics
***********************************

The library cache is where Oracle stores object definitions, SQL
statements etc. Each namespace (or library) contains different
types of object. The figures here give a quick summary of the
usage of each namespace. The most useful indicator here is the
RELOADS column.

Nearly no reloads, shared pool is OK.

****************************
2). CPU used by this session
****************************

By comparing the relative time spent waiting on each wait event
and the CPU used by this session, we can see where the Oracle
instance is spending most of its time.

Statistic Total Per Transact Per Logon Per Second
--------------------------- ------------ ------------ ------------ ------------
CPU used by this session 542660 1.18 2647.12 95.22
parse time cpu 244 0 1.19 .04

***********************************
3). Locating CPU-Heavy SQL (Top 15)
***********************************

The statement below finds SQL statements which access database buffers
a lot. Such statements are typically heavy on CPU usage because they are
probably looking at a lot of rows of data:

SELECT disk_reads, buffer_gets, executions,
buffer_gets/executions "Gets/Exec",
disk_reads/executions "Reads/Exec",
round((buffer_gets - disk_reads) / buffer_gets, 2) * 100 "HitRatio",
sql_text
FROM v$sqlarea
WHERE buffer_gets > 10000000
AND executions > 1000000
ORDER BY buffer_gets DESC;

Disk-Reads Buffer-Gets Executions Gets/Exec Reads/Exec HitRatio
---------- ----------- ---------- ---------- ---------- ----------
14607 40882602 3211863 12.7286257 .004547828 100
SQL-Text
---------------------------------------------------------------------------
UPDATE SSCREQUEST SET MSGSTATE=:b1,RESPONSE=:b2,SERVICESTATE=:b3,RETURNCODE
=:b4,INIPARA=:b5,PROCESSTIME=SYSDATE WHERE REQUESTID=:b6

Disk-Reads Buffer-Gets Executions Gets/Exec Reads/Exec HitRatio
---------- ----------- ---------- ---------- ---------- ----------
188249 34923996 1528920 22.8422651 .123125474 99
SQL-Text
---------------------------------------------------------------------------
UPDATE SSCORDER SET STATE=:b1,RETURNCODE=:b2,PRIORITY=:b3,PROCESSTIME=SYSDA
TE,DEFERRED=TO_DATE(:b4,'YYYYMMDDHH24MISS')WHERE REQUESTID=:b5

**********************************************************
4). Locating CPU-Heavy Sessions (CPU used by this session)
**********************************************************

SELECT substr(a.sid,1,5) "Sid",
substr(a.process,1,7) "Process",
substr(a.username,1,20) "User",
v.value "CPU used by this session"
FROM v$statname s, v$sesstat v, v$session a
WHERE s.name = 'CPU used by this session'
and v.statistic#=s.statistic#
AND v.sid = a.sid
and v.value > 1000
ORDER BY v.value DESC;

Sid Process User CPU used by this session
----- ------- -------------------- ------------------------
62 12602 SSCDSP 2791153
82 10949 SSCSMH 1591242
103 12603 SSCDSP 191758
110 16629 DISPATCHER 50677
83 9913 SMH_LINK 48296
69 12430 SSCFSM 44123
59 12265 SSCFSM 43812
60 10997 SSCFSM 43722
51 16628 DISPATCHER 35865
71 11017 SSCSMH 33881
53 12138 SSCFSM 27938

**********************
5). Common Wait Events
**********************

System wide wait events for NON-background processes (PMON,
SMON, etc). Times are in hundreths of seconds. Each one of
these is a context switch which costs CPU time. By looking at
the Total Time you can often determine what is the bottleneck
that processes are waiting for. This shows the total time spent
waiting for a specific event and the average time per wait on
that event.

Ignore any 'idle' wait events. Common IDLE wait events include:

client message - Process waiting for data from the
SQL*Net message from client client application
SQL*Net more data from client
rdbms ipc message - Usually background process waiting for work
pipe get - DBMS_PIPE read waiting for data
Null event - Miscellaneous
pmon timer - PMON waiting for work
smon timer - SMON waiting for work
parallel query dequeue - Waiting for input (Discussed later)

Event Name Count Total Time Avg Time
-------------------------------- ------------- ------------- -------------
log file sync 527031 2076364 3.94
db file sequential read 379096 948531 2.5
write complete waits 1549 90879 58.67
db file scattered read 508925 55312 .11
buffer busy waits 6070 44408 7.32
log file switch completion 276 13875 50.27
latch free 2828 5517 1.95
enqueue 284 2498 8.8
log buffer space 102 753 7.38
buffer deadlock 24 48 2
control file sequential read 134 16 .12

-----------------------------------------
System wide waits for "buffer busy waits"
-----------------------------------------
This wait happens when a session wants to access a database
block in the buffer cache but it cannot as the buffer is "busy".
The two main cases where this can occur are:

- Another session is reading the block into the buffer
- Another session holds the buffer in an incompatible mode to our request

If the TIME spent waiting for buffers is significant then we need to
determine which segment/s is/are suffering from contention.
The "Buffer busy wait statistics" section of the Bstat/estat shows
which block type/s are seeing the most contention. This information
is derived from the V$WAITSTAT which can be queried in isolation.
This shows the class of block with the most waits at the BOTTOM of the list.

SELECT time, count, class
FROM V$WAITSTAT
ORDER BY time,count;

TIME COUNT CLASS
---------- ---------- ------------------
0 0 sort block
0 0 save undo block
0 0 save undo header
0 0 free list
0 0 system undo block
0 0 system undo header
5812 442 segment header
506921 35983 undo block
561185 30039 undo header
922683 203757 data block

Additional information can be obtained from the internal
view X$KCBFWAIT thus:

SELECT count, file#, substr(name,1,50)
FROM x$kcbfwait, v$datafile
WHERE indx + 1 = file#
ORDER BY count;

COUNT FILE# SUBSTR(NAME,1,50)
---------- ---------- --------------------------------------------------
0 3 /data/ota/db1/OTASICAP/data/temp01.dbf
0 4 /data/ota/db1/OTASICAP/data/users.dbf
0 16 /data/ota/db2/OTASICAP/data/idx_sccms_02.dbf
0 17 /data/ota/db1/OTASICAP/data/tbs_sccorder_03.dbf
0 5 /data/ota/db1/OTASICAP/data/tools.dbf
1 1 /data/ota/db1/OTASICAP/data/system01.dbf
9 13 /data/ota/db1/OTASICAP/data/tbs_sccms_01.dbf
14 14 /data/ota/db1/OTASICAP/data/tbs_sccms_02.dbf
36 15 /data/ota/db2/OTASICAP/data/idx_sccms_01.dbf
52 12 /data/ota/db2/OTASICAP/data/idx_sccorder_03.dbf
1181 11 /data/ota/db2/OTASICAP/data/idx_sccorder_02.dbf
5337 7 /data/ota/db2/OTASICAP/data/idx_01.dbf
6535 8 /data/ota/db1/OTASICAP/data/tbs_sccorder_01.dbf
7838 10 /data/ota/db2/OTASICAP/data/idx_sccorder_01.dbf
11479 9 /data/ota/db1/OTASICAP/data/tbs_sccorder_02.dbf
19028 2 /data/ota/db1/OTASICAP/data/rbs01.dbf
47124 18 /data/ota/db2/OTASICAP/data/rbs02.dbf
171997 6 /data/ota/db1/OTASICAP/data/data01.dbf

This shows the file/s with the most waits (at the BOTTOM of the list)
so by combining the two sets of information we know what block
type/s in which file/s are causing waits.
The segments in each file can be seen using a query like:

SELECT distinct owner, segment_name, segment_type
FROM dba_extents
WHERE file_id = &FILE#;

For File-Nr 6:

SELECT distinct owner "Owner",
substr(segment_name,1,30) "Segment-Name",
substr(segment_type,1,20) "Segment-Type"
FROM dba_extents
WHERE file_id = 6;

Owner Segment-Name Segment-Type
------------------------------ ------------------------------ -----------------
DISPATCHER ARCHIVIO_SSC_SMS_CCBS TABLE
DISPATCHER IDX_MSISDN_RELOADFIX INDEX
DISPATCHER RELOADFIX TABLE
DISPATCHER SSCMS_MSCOUNT_5 TABLE
DISPATCHER SSC_CHANGES TABLE
DISPATCHER SSC_SMS_CCBS TABLE
DISPATCHER SSC_SMS_CCBS_OLD TABLE
ORASTAT SEGMENT_INFO TABLE
SYSADM BKP_99_STATE_SSCORDER TABLE
SYSADM SSCAPPS TABLE
SYSADM SSCCDR TABLE
SYSADM SSCCONF TABLE
SYSADM SSCREQUEST TABLE
SYSADM SSCRESPONSE TABLE
SYSADM SSCSMBUF TABLE

If there are a large number of segments of the type listed then
monitoring V$SESSION_WAIT may help isolate which object is causing
the waits. Repeatedly run the following statement and collect the
output. After a period of time sort the results to see which
file & blocks are showing contention:

SELECT p1 "File", p2 "Block", p3 "Reason"
FROM v$session_wait
WHERE event='buffer busy waits';

File Block Reason
---------- ---------- ----------
18 79362 1012
18 67842 1016

File Block Reason
---------- ---------- ----------
6 10526 1016

-----------------------------------------------
System wide waits for "db file sequential read"
-----------------------------------------------
This wait happens when a session is waiting for an IO to complete.
Typically this indicates single block reads, although reads from
a disk sort area may use this wait event when reading several
contiguous blocks. Remember IO is a normal activity so you are
really interested in unnecessary or slow IO activity.

==> Tune SQL Statements

-----------------------------------------------------------------
System wide waits for "db file scattered read" (FULL TABLE SCANS)
-----------------------------------------------------------------
This wait happens when a session is waiting for a multiblock
IO to complete. This typically occurs during FULL TABLE SCANS
or index fast full scans. Oracle reads up to
DB_FILE_MULTIBLOCK_READ_COUNT consecutive blocks at a time
and scatters them into buffers in the buffer cache.
How this is done depends on the value of USE_READV.
If the TIME spent waiting for multiblock reads is significant
then we need to determine which segment/s we are performing
the reads against. See the "Tablespace IO" and "File IO"
sections of the ESTAT report to get information on which
tablespaces / files are servicing multiblock reads (BLKS_READ/READS>1).

It is probably best at this stage to find which sessions
are performing scans and trace them to see if the scans
are expected or not. This statement can be used to see
which sessions may be worth tracing:

SELECT substr(a.sid,1,5) "Sid",
substr(a.process,1,7) "Process",
substr(a.username,1,20) "User",
total_waits, time_waited
FROM v$session_event v, v$session a
WHERE v.event='db file scattered read'
and v.total_waits > 0
and a.sid = v.sid
ORDER BY v.total_waits DESC;

Sid Process User TOTAL_WAITS TIME_WAITED
----- ------- -------------------- ----------- -----------
109 12533 SMH_LINK 136172 6401
111 10391 DISPATCHER 30045 3390
120 31320 VP_LINK 5792 789
75 4214116 VP_LINK 5760 371
101 4290951 SYSADM 1582 462
85 11165 SYSADM 1566 522
6 9832 570 840
82 10949 SSCSMH 179 88
108 52360 VP_LINK 85 65
115 8781 SYS 14 2

USE_READV can have a dramatic effect on the performance of table scans.
On many platforms USE_READV=FALSE performs better than TRUE but
this should be tested.
DB_FILE_MULTIBLOCK_READ_COUNT should generally be made as large
as possible. The value is usually capped by Oracle and so it
cannot be set too high. The 'capped' value differs between platforms
and versions and usually depends on the settings of DB_BLOCK_SIZE
and USE_READV.

Current Settings

use_readv boolean FALSE
db_file_multiblock_read_count integer 32

----------------------------------------------
System wide waits for "enqueue" (local 'lock')
----------------------------------------------
A wait for an enqueue is a wait for a local 'lock'. The count and
average wait times for this wait-event can be misleading as "enqueue"
waits re-arm every few seconds. To qualify how many waits have really
occurred you need the enqueue waits statistic from the statistics
section of the estat report.

To determine which enqueues are causing the most waits system-wide
look at View X$KSQST

SELECT ksqsttyp "Lock",
ksqstget "Gets",
ksqstwat "Waits"
FROM X$KSQST where KSQSTWAT>0;

Lo Gets Waits
-- ---------- ----------
CF 3720 2
CI 1936 2
CU 379 1
DX 23582708 7
ST 4591 20
TX 19710183 16189

TX Transaction Lock

Generally due to application or table setup issues

TM DML enqueue

Generally due to application issues, particularly if
foreign key constraints have not been indexed.

ST Space management enqueue

Usually caused by too much space management occurring
(Eg: small extent sizes, lots of sorting etc..)

----------------------------------
System wide waits for "latch free"
----------------------------------
Latches are like short duration locks that protect critical
bits of code. As a latch wait is typically quite short it is
possible to see a large number of latch waits which only
account for a small percentage of time.
If the TIME spent waiting for latches is significant then we
need to determine which latches are suffering from contention.
The Bstat/estat section on latches shows latch activity in
the period sampled. This section of the estat report is based
on View V$LATCH gives a summary of latch activity since instance
startup and can give an indication of which latches are responsible
for the most time spent waiting for "latch free" thus:

SELECT latch#, substr(name,1,30) gets, misses, sleeps
FROM v$latch
WHERE sleeps>0
ORDER BY sleeps DESC;

LATCH# GETS MISSES SLEEPS
---------- ------------------------------ ---------- ----------
11 cache buffers chains 1619686 103490
18 redo allocation 1934934 8607
37 global tx hash mapping 33542 4493
39 library cache 325559 2555
19 redo copy 18711 2326
8 enqueues 593898 1781
2 session allocation 337507 1506
15 cache buffers lru chain 23440 1411
9 enqueue hash chains 98115 1069
29 undo global data 264600 791
16 system commit number 210693 752
27 transaction allocation 87931 461
7 messages 113626 315
25 dml lock allocation 29710 206
26 list of block allocation 29313 176
4 session idle bit 34286 155
13 multiblock read objects 5452 35
32 row cache objects 326 9
35 global tx free list 1956 7
6 modify parameter values 2 3
38 shared pool 31 3
0 latch wait list 219 2
50 parallel query stats 2 1

cache buffers chains latches

Individual block contention can show up as contention for one of these
latches. Each cache buffers chains latch covers a list of buffers in
the buffer cache.

---------------------------------------------
System wide waits for "log file space/switch"
---------------------------------------------
There are several wait events which may indicate problems with
the redo buffer and redo log throughput:

log buffer space
log file switch (checkpoint incomplete)
log file switch (archiving needed)
log file switch/archive
log file switch (clearing log file)
log file switch completion
switch logfile command

Increase the LOG_BUFFER size until there is no incremental
benefit (sizes > 1Mb are unlikely to add any benefit)

For all other waits:

- Ensure redo logs are on fast disks (NOT RAID5)
- Ensure redo logs are large enough to give a sensible gap
between log switches. A 'rule-of-thumb' is to have one log
switch every 15 to 30 minutes.
- Ensure the ARCHiver process is running and keeping up.

-------------------------------------
System wide waits for "log file sync"
-------------------------------------
This wait happens when a commit (or rollback) is issued and
the session has to wait for the redo entry to be flushed to
disk to guarantee that instance failure will not roll back the transaction.

- Where possible reduce the commit frequency.
Eg: Commit at batch intervals and not per row.
- Speed up redo writing (Eg: Do NOT use RAID 5, use fast disks etc..)

--------------------------------------------
System wide waits for "write complete waits"
--------------------------------------------
This wait happens when a requested buffer is being written to disk
we cannot use the buffer while it is being written.
If the TIME spent waiting for buffers to be written is
significant then note the "Average Write Queue Length"
if this too is large then the the cache aging rate is
too high for the speed that DBWR is writing buffers to disk.

- Decrease the cache aging rate
- Increase the throughput of DBWR

**********************
5). Dirty Queue Length
**********************

The average write queue length gives an indication of whether the cache
is being cleared of dirty blocks fast enough or not. Unless the system
is very high throughput the write queue should never be very large.
As a general guideline if the average write queue is in double figures
it is certainly worth finding where the activity is coming from.
If the figure is in single digits there may still be un-necessary
activity in the cache.

The 2 main ways to improve the write queue length are:

Eliminate any unnecessary write IO from going via the cache.
Improve DBWR throughput. Eg: Use asynchronous writes,
multiple database writer processes, larger block write batch.

Anything above 100 indicates that the DBWR is
having real problems keeping up !

SELECT SUM(DECODE(name,'summed dirty queue length',value)) /
SUM(DECODE(name,'write requests',value)) "Average Write Queue Length"
FROM v$sysstat
WHERE name IN ( 'summed dirty queue length','write requests')
AND value > 0;

Average Write Queue Length (Should be 0)
----------------------------------------
0.35044

*****************************
6). Tablespace IO and File IO
*****************************

TABLE_SPACE Tablespace name
FILE_NAME File name in this tablespace
READS Number of read calls to the OS
BLKS_READ Number of blocks read.
The above two differ only when multi-block
reads are being performed. Eg: On full table
scans we read up to DB_FILE_MULTIBLOCK_READ_COUNT
blocks per read.
READ_TIME Total time for the reads in 1/100ths of a second
WRITES Number of OS write calls
BLKS_WRT Number of blocks written
WRITE_TIME Write time in 1/100ths of a second. NB: this figure
may be incorrect.

TABLE_SPACE READS BLKS_READ READ_TIME WRITES BLKS_WRT WRITE_TIME MEGABYTES
----------------- ------- ---------- ---------- ---------- ---------- ---------- ----------
DATA 24487 88794 4713 17011 17011 531654 524
IDX 6844 6844 26326 38219 38219 1454912 524
RBS 2 2 2 102702 102702 5333108 1598
SYSTEM 101 152 71 97 97 3542 105
TBS_SCCORDER 684066 6344009 86376 46697 46697 2081706 3222
TBS_SCCORDER_IDX 125173 125174 847903 228494 228494 12198710 3222
TBS_SSCMS 28801 28801 41554 39439 39439 1235851 2148
TBS_SSCMS_IDX 20732 20732 5126 231 231 6541 2148
TEMP 51 725 27 89 678 242 1049
TOOLS 0 0 0 0 0 0 105
USERS 0 0 0 15 15 410 105

Read-Time per Block in [MS] = ((READ_TIME/100) / BLKS_READ) * 1000

TBS_SCCORDER: ((86'376/100)/6'344'009)*1000 = 0.13 ms (very fast)
TBS_SCCORDER_IDX: ((847'903/100)/125'174)*1000 = 67.73 ms (very slow)
TBS_SSCMS: ((41'554/100)/28'801)*1000 = 14.43 ms (OK)
TBS_SSCMS_IDX: ((5'126/100)/)20'732*1000 = 2.47 ms (very fast)

TABLE_SPACE FILE_NAME READS BLKS_READ READ_TIME WRITES BLKS_WRT WRITE_TIME MEGABYTES
----------------- ------------------------------------------------ ---------- ---------- ---------- ---------- ---------- ---------- ----------
DATA /data/ota/db1/OTASICAP/data/data01.dbf 24487 88794 4713 17011 17011 531654 524
IDX /data/ota/db2/OTASICAP/data/idx_01.dbf 6844 6844 26326 38219 38219 1454912 524
RBS /data/ota/db1/OTASICAP/data/rbs01.dbf 1 1 0 23922 23922 854404 524
RBS /data/ota/db2/OTASICAP/data/rbs02.dbf 1 1 2 78780 78780 4478704 1074
SYSTEM /data/ota/db1/OTASICAP/data/system01.dbf 101 152 71 97 97 3542 105
TBS_SCCORDER /data/ota/db1/OTASICAP/data/tbs_sccorder_01.dbf 242174 2841155 34210 24178 24178 806926 1074
TBS_SCCORDER /data/ota/db1/OTASICAP/data/tbs_sccorder_02.dbf 282835 2075092 41336 22519 22519 1274780 1074
TBS_SCCORDER /data/ota/db1/OTASICAP/data/tbs_sccorder_03.dbf 159057 1427762 10830 0 0 0 1074
TBS_SCCORDER_IDX /data/ota/db2/OTASICAP/data/idx_sccorder_01.dbf 23354 23354 49920 52053 52053 1963087 1074
TBS_SCCORDER_IDX /data/ota/db2/OTASICAP/data/idx_sccorder_02.dbf 84367 84368 743566 124286 124286 8090752 1074
TBS_SCCORDER_IDX /data/ota/db2/OTASICAP/data/idx_sccorder_03.dbf 17452 17452 54417 52155 52155 2144871 1074
TBS_SSCMS /data/ota/db1/OTASICAP/data/tbs_sccms_01.dbf 12889 12889 19041 17960 17960 562416 1074
TBS_SSCMS /data/ota/db1/OTASICAP/data/tbs_sccms_02.dbf 15912 15912 22513 21479 21479 673435 1074
TBS_SSCMS_IDX /data/ota/db2/OTASICAP/data/idx_sccms_01.dbf 20428 20428 4738 184 184 4997 1074
TBS_SSCMS_IDX /data/ota/db2/OTASICAP/data/idx_sccms_02.dbf 304 304 388 47 47 1544 1074
TEMP /data/ota/db1/OTASICAP/data/temp01.dbf 51 725 27 89 678 242 1049
TOOLS /data/ota/db1/OTASICAP/data/tools.dbf 0 0 0 0 0 0 105
USERS /data/ota/db1/OTASICAP/data/users.dbf 0 0 0 15 15 410 105

**********************
7). Fragmented Objects
**********************

set feed off
set pagesize 5000
break on owner skip 1 on tablespace_name on segment_type
column datum new_value datum noprint
column owner format A10 heading 'Owner'
column tablespace_name format A20 heading 'Tablespace'
column segment_type format A10 heading 'Segment-|Type'
column segment_name format A30 heading 'Segment-|Name'
column extent_id format 999 heading 'Number of|Extents'
column bytes format 999,999,999,999 heading 'Size|[Bytes]'
--
-- Looking for frgmented objects
--
select to_char(sysdate, 'MM/DD/YY') datum,
owner,
tablespace_name,
segment_type,
segment_name,
count(extent_id) extent_id,
sum(bytes) bytes
from sys.dba_extents
where substr(owner,1,10) not in ('SYS')
group by
owner,
tablespace_name,
segment_type,
segment_name
having count(extent_id) > 3
order by 1,2,3,4;

Owner Tablespace Type Name Extents [Bytes]
---------- -------------------- ---------- ------------------------------ --------- ----------------
DISPATCHER IDX INDEX PK_SSC_SMS_CCBS 4 20,971,520
TBS_SCCORDER TABLE SSCORDER 4 419,430,400
TBS_SCCORDER_IDX INDEX IDX_SSCORDER_HISTORY_MSISDN 4 419,430,400

SYSADM TBS_SSCMS TABLE SSCMS 4 2,076,172,288

*************************************************
8). Sessions with bad Buffer Cache Hit Ratio in %
*************************************************

set feed off;
set pagesize 10000;
set wrap off;
set linesize 200;
set heading on;
set tab on;
set scan on;
set verify off;
--
ttitle left 'Show Sessions with bad Buffer Cache Hit Ratio in %' -
skip 2
--
select substr(a.username,1,12) "User",
a.sid "sid",
b.consistent_gets "ConsGets",
b.block_gets "BlockGets",
b.physical_reads "PhysReads",
100 * round((b.consistent_gets + b.block_gets - b.physical_reads) /
(b.consistent_gets + b.block_gets),3) HitRatio
from v$session a, v$sess_io b
where a.sid = b.sid
and (b.consistent_gets + b.block_gets) > 0
and a.username is not null
order by HitRatio asc;

Show Sessions with bad Buffer Cache Hit Ratio in %

User sid ConsGets BlockGets PhysReads HITRATIO
------------ ---------- ---------- ---------- ---------- ----------
SYSADM 101 45719 6 38640 15.5
DISPATCHER 111 466434 16 390966 16.2
VP_LINK 95 94058 6 65802 30
VP_LINK 75 94150 4 43350 54
DISPATCHER 84 1288381 28 470437 63.5
VP_LINK 40 436526 2 116192 73.4
VP_LINK 90 437587 2 112440 74.3
SMH_LINK 109 1920356 1345626 799163 75.5
SSCSMSCI 68 5 0 1 80
DISPATCHER 94 52 8 9 85
SYS 115 58443 6811 6845 89.5
VP_LINK 88 19 2 2 90.5
VP_LINK 72 374313 998401 78614 94.3
VP_LINK 89 373818 997023 78529 94.3
VP_LINK 87 373435 995770 78406 94.3
VP_LINK 97 373546 996162 78587 94.3
VP_LINK 93 374399 998969 78478 94.3
VP_LINK 80 7048 18880 1444 94.4
VP_LINK 70 1813 4768 364 94.5
VP_LINK 92 1851 4952 369 94.6
VP_LINK 86 1870 4994 362 94.7
MIG_OTA 91 1113 8 46 95.9
VP_LINK 104 21 14 1 97.1
VP_LINK 98 56 2 1 98.3
VP_LINK 96 239 578 13 98.4
DISPATCHER 110 1092370 3875255 59535 98.8
SSCSMH 105 59195 35151 1035 98.9
TMH_LINK 77 842 2086 30 99
VP_LINK 114 387838 853135 11724 99.1
SSCSMH 37 984588 543820 11500 99.2
SSCSMH 54 2318348 1304849 20178 99.4
SSCFSM 52 2938795 2408492 25907 99.5
SSCFSM 53 2933194 2403007 25963 99.5
SSCSMH 71 2835536 1592916 23697 99.5
SSCFSM 69 2938692 2407723 26245 99.5
SSCFSM 60 2934409 2404253 25990 99.5
SSCFSM 59 2936309 2406120 25942 99.5
SSCDSP 103 18518943 10226773 106777 99.6
DISPATCHER 51 1200555 2587257 12744 99.7
-- #############################################################################################
--
-- %Purpose: How to implement "Sleep Function" with PL/SQL ?
--
-- The next example TryToGetSlot tries to get free
-- system resources (e.g. to create an index on a
-- busy table). The function waits for some seconds
-- and then tries to get the resource again. After
-- a counter have reached the maximum, the routine
-- exits.
--
-- #############################################################################################
--
CREATE OR REPLACE PROCEDURE TryToGetSlot IS
GotIt BOOLEAN := FALSE;
Count NUMBER := 0;
BEGIN
WHILE (NOT GotIt AND NOT (Count > 10)) LOOP
BEGIN
-- Try to get free slot, if OK, set GotIt = TRUE
-- else EXCEPTION will automatically fire.
(Insert Code here)
GotIt := TRUE;
EXCEPTION
WHEN OTHERS THEN
GotIt := FALSE;
DBMS_LOCK.SLEEP(10);
Count := Count + 1;
END;
END LOOP;
END;
/
-- #############################################################################################
--
-- %Purpose: How to query a n X m relation using the UNION construct to avoid the ORA-1417 error
--
-- Consider the following situation: We have employees and projects.
--
-- An employee can be registered (work for) in 0, 1or more projects. For a certain project,
-- 0 one or more employees are allocated. We have a typical many-to-many relationship which
-- is normalized with the intersection entity PROJALLOC.
--
-- #############################################################################################
--
CREATE TABLE employee (
emp_id NUMBER NOT NULL,
name VARCHAR2(30),
CONSTRAINT emp_pk PRIMARY KEY (emp_id)
);

CREATE TABLE project (
proj_id NUMBER NOT NULL,
name VARCHAR2(30),
CONSTRAINT proj_pk PRIMARY KEY (proj_id)
);

CREATE TABLE projalloc (
emp_id NUMBER NOT NULL,
proj_id NUMBER NOT NULL,
CONSTRAINT pa_pk PRIMARY KEY (proj_id, emp_id),
CONSTRAINT pa_fk1 FOREIGN KEY (proj_id) REFERENCES PROJECT (proj_id),
CONSTRAINT pa_fk2 FOREIGN KEY (emp_id) REFERENCES EMPLOYEE (emp_id)
);

INSERT INTO employee (emp_id,name) VALUES (1,'ALLEN');
INSERT INTO employee (emp_id,name) VALUES (2,'BAKER');
INSERT INTO employee (emp_id,name) VALUES (3,'FORD');
INSERT INTO employee (emp_id,name) VALUES (4,'MILLER');
INSERT INTO employee (emp_id,name) VALUES (5,'SCOTT');

INSERT INTO project (proj_id,name) VALUES (1,'PROJECT 01');
INSERT INTO project (proj_id,name) VALUES (2,'PROJECT 02');
INSERT INTO project (proj_id,name) VALUES (3,'PROJECT 03');
INSERT INTO project (proj_id,name) VALUES (4,'PROJECT 04');
INSERT INTO project (proj_id,name) VALUES (5,'PROJECT 05');

INSERT INTO projalloc (proj_id,emp_id) VALUES (1,1);
INSERT INTO projalloc (proj_id,emp_id) VALUES (1,2);
INSERT INTO projalloc (proj_id,emp_id) VALUES (1,3);
INSERT INTO projalloc (proj_id,emp_id) VALUES (2,2);
INSERT INTO projalloc (proj_id,emp_id) VALUES (2,5);
INSERT INTO projalloc (proj_id,emp_id) VALUES (3,3);
INSERT INTO projalloc (proj_id,emp_id) VALUES (4,3);
COMMIT;

select e.name employee,p.name name
from employee e, projalloc pa, project p
where e.emp_id = pa.emp_id(+)
and p.proj_id = pa.proj_id(+)
order by 1

ORA-01417: a table may be outer joined to at most one other table

--
-- Solution
--
-- Use the UNION construct to query the two special cases
-- (all employees with no project assigned and
-- all projects with no employees assigned).
--
select e.name employee,p.name project
from employee e, projalloc pa, project p
where e.emp_id = pa.emp_id
and p.proj_id = pa.proj_id
union
select e.name, null
from employee e, projalloc pa
where e.emp_id = pa.emp_id(+)
and pa.emp_id is null
union
select null, p.name project
from project p, projalloc pa
where p.proj_id = pa.proj_id(+)
and pa.proj_id is null
order by 1;

EMPLOYEE PROJECT
------------------------------ -----------
ALLEN PROJECT 01
BAKER PROJECT 01
BAKER PROJECT 02
FORD PROJECT 01
FORD PROJECT 03
FORD PROJECT 04
MILLER
SCOTT PROJECT 02
PROJECT 05
-- #############################################################################################
--
-- %Purpose: How to reclaim UNUSED_SPACE from Indexes and Tables using DBMS_SPACE.UNUSED_SPACE
--
-- Before growing a datafile in a tablespace that shows on your
-- space analysis reports, search for space that can be reclaimed
-- from an object that was poorly sized initially. Tables and indexes
-- can be altered with a deallocate unused, thus reclaiming unused
-- space above the high-water mark.
--
-- Example: ALTER TABLE emp DEALLOCATE UNUSED;
--
-- This script prompts you for two pieces of information:
--
-- 1. The type of segment to retrieve, (i=indexes, t=tables)
--
-- 2. The tablespace_name to retrieve from.
--
-- Simply put, this allows you to retrieve one of these segment
-- types by tablespace_name. It is important to note that deallocating
-- unused space became available with Oracle version 7.3.
--
-- #############################################################################################--
--
accept type prompt "Enter the type of segment to check (i=index, t=table): "
accept ts_name prompt "Enter the tablespace name that you wish to check: "
set serveroutput on
feedback off
--
spool unused_space.lst
--
DECLARE
v_total_blocks NUMBER;
v_total_bytes NUMBER;
v_unused_blocks NUMBER;
v_unused_bytes NUMBER;
v_file_id NUMBER;
v_block_id NUMBER;
v_last_block NUMBER;
v_used NUMBER;
v_owner VARCHAR2(12);
v_segment VARCHAR2(80);
v_type CHAR(1);

CURSOR index_c is
SELECT owner, index_name
FROM sys.dba_indexes
WHERE tablespace_name = upper('&ts_name');

CURSOR table_c is
SELECT owner, table_name
FROM sys.dba_tables
WHERE tablespace_name = upper('&ts_name');

BEGIN
DBMS_OUTPUT.ENABLE(100000);
v_type := '&type';
IF (v_type = 'i' or v_type = 'I') THEN
OPEN index_c;
FETCH index_c into v_owner, v_segment;
WHILE index_c%FOUND LOOP
--
DBMS_SPACE.UNUSED_SPACE(v_owner, v_segment, 'INDEX', v_total_blocks, v_total_bytes,
v_unused_blocks, v_unused_bytes, v_file_id, v_block_id, v_last_block);
--
DBMS_OUTPUT.PUT_LINE(CHR(10));
DBMS_OUTPUT.PUT_LINE('Index Name = '||v_segment);
DBMS_OUTPUT.PUT_LINE('Total Blocks = '||v_total_blocks);
DBMS_OUTPUT.PUT_LINE('Total Bytes = '||v_total_bytes);
DBMS_OUTPUT.PUT_LINE('Unused Blocks = '||v_unused_blocks);
DBMS_OUTPUT.PUT_LINE('Unused Bytes = '||v_unused_bytes);
v_used := v_total_blocks - v_unused_blocks;
DBMS_OUTPUT.PUT_LINE('Used Blocks = '||v_used);
v_used := v_total_bytes - v_unused_bytes;
DBMS_OUTPUT.PUT_LINE('Used Bytes = '||v_used);
DBMS_OUTPUT.PUT_LINE('Last used extents file id = '||v_file_id);
DBMS_OUTPUT.PUT_LINE('Last used extents block id = '||v_block_id);
DBMS_OUTPUT.PUT_LINE('Last used block = '||v_last_block);
fetch index_c into v_owner, v_segment;
END LOOP;
CLOSE index_c;
ELSIF (v_type = 't' or v_type = 'T') THEN
OPEN table_c;
FETCH table_c into v_owner, v_segment;
WHILE table_c%FOUND LOOP
--
DBMS_SPACE.UNUSED_SPACE(v_owner, v_segment, 'TABLE', v_total_blocks, v_total_bytes,
v_unused_blocks, v_unused_bytes, v_file_id, v_block_id, v_last_block);
--
v_used := v_total_bytes - v_unused_bytes;
DBMS_OUTPUT.PUT_LINE(CHR(10));
DBMS_OUTPUT.PUT_LINE('Table Name = '||v_segment);
DBMS_OUTPUT.PUT_LINE('Total Blocks = '||v_total_blocks);
DBMS_OUTPUT.PUT_LINE('Total Bytes = '||v_total_bytes);
DBMS_OUTPUT.PUT_LINE('Unused Blocks = '||v_unused_blocks);
DBMS_OUTPUT.PUT_LINE('Unused Bytes = '||v_unused_bytes);
v_used := v_total_blocks - v_unused_blocks;
DBMS_OUTPUT.PUT_LINE('Used Blocks = '||v_used);
v_used := v_total_bytes - v_unused_bytes;
DBMS_OUTPUT.PUT_LINE('Used Bytes = '||v_used);
DBMS_OUTPUT.PUT_LINE('. KBytes = '||v_used/1024);
DBMS_OUTPUT.PUT_LINE('. MBytes = '||(v_used/1024)/1024);
DBMS_OUTPUT.PUT_LINE('Last used extents file id = '||v_file_id);
DBMS_OUTPUT.PUT_LINE('Last used extents block id = '||v_block_id);
DBMS_OUTPUT.PUT_LINE('Last used block = '||v_last_block);
fetch table_c into v_owner, v_segment;
END LOOP;
CLOSE table_c;
END IF;
END;
/
spool off
-- #############################################################################################
--
-- %Purpose: Install SQL*PLUS and PL/SQL Help Tables in Data Dictionary for: SQL>help command
--
-- Use: Privileges for SYSTEM User
--
-- #############################################################################################
--
#!/bin/sh

$ORACLE_HOME/bin/svrmgrl << EOF
connect system/manager
@$ORACLE_HOME/sqlplus/admin/help/helptbl.sql;
exit;
EOF

$ORACLE_HOME/bin/svrmgrl << EOF
connect system/manager
@$ORACLE_HOME/sqlplus/admin/help/helpindx.sql;
exit;
EOF

$ORACLE_HOME/bin/sqlldr userid=system/manager control=$ORACLE_HOME/sqlplus/admin/help/plushelp.ctl
$ORACLE_HOME/bin/sqlldr userid=system/manager control=$ORACLE_HOME/sqlplus/admin/help/plshelp.ctl
$ORACLE_HOME/bin/sqlldr userid=system/manager control=$ORACLE_HOME/sqlplus/admin/help/sqlhelp.ctl
-- #############################################################################################
--
-- %Purpose: Monitor Data Access Activities (Full Table and Index Scans, Chained Rows)
--
-- Use: Needs Oracle DBA Access
--
-- #############################################################################################
--
set feed off;
set pagesize 10000;
set wrap off;
set linesize 200;
set heading on;
set tab on;
set scan on;
set verify off;
set termout on;

column STATISTIC# form 999 head 'Id'
column NA form a32 head 'Statistic'
column RIA form 990.90 head 'Row Access via|Index [%]'
column RTS form 990.90 head 'Row Access via|Table Scan [%]'
column RA form 9999999990 head 'Rows accessed'
column PCR form 990.90 head 'Chained|Rows [%]'
colum CL form 990.90 head 'Cluster|Length'

ttitle left 'Monitor Data Access Activities' skip 2

spool monitor_data_activites.log

select rpad (NAME, 32, '.') as NA,
VALUE
from V$SYSSTAT
where NAME like '%table scan%'
or NAME like '%table fetch%'
or NAME like '%cluster%';

ttitle off

select A.VALUE + B.VALUE as RA,
A.VALUE / (A.VALUE + B.VALUE) * 100.0 as RIA,
B.VALUE / (A.VALUE + B.VALUE) * 100.0 as RTS,
C.VALUE / (A.VALUE + B.VALUE) * 100.0 as PCR,
E.VALUE / D.VALUE as CL
from V$SYSSTAT A,
V$SYSSTAT B,
V$SYSSTAT C,
V$SYSSTAT D,
V$SYSSTAT E
where A.NAME = 'table fetch by rowid'
and B.NAME = 'table scan rows gotten'
and C.NAME = 'table fetch continued row'
and D.NAME = 'cluster key scans'
and E.NAME = 'cluster key scan block gets'
/
-- #############################################################################################
--
-- %Purpose: Monitor Private SQL Areas and PL/SQL space in the UGA and SGA
--
-- PL/SQL allocates most memory from the UGA which is
-- located in the SGA when shared servers are used
--
-- UGA = User Global Area
-- SGA = System Global Area
--
-- Use: Needs Oracle DBA Access
--
-- #############################################################################################
--
set feed off;
set pagesize 10000;
set wrap off;
set linesize 200;
set heading on;
set tab on;
set scan on;
set verify off;
set termout on;

column NA head 'STATISTIC' format a29
column NR_SESS head '#USERS' format 9999
column C1 head 'SUM|[kbyte]' format 999990.90
column C2 head 'AVG|[kbyte]' format 999990.90
column C3 head 'MIN|[kbyte]' format 999990.90
column C4 head 'MAX|[kbyte]' format 999990.90

ttitle left 'Monitor Private SQL Areas and PL/SQL space' skip 2

spool monitor_private_SQL_areas.log

select rpad (B.NAME, 29, '.') as NA,
COUNT(*) as NR_SESS,
SUM(A.VALUE)/1024.0 as C1,
AVG(A.VALUE)/1024.0 as C2,
MIN(A.VALUE)/1024.0 as C3,
MAX(A.VALUE)/1024.0 as C4
from V$SESSTAT A,
V$STATNAME B
where A.STATISTIC# = B.STATISTIC#
and (B.NAME like '%pga%'
or B.NAME like '%uga%'
or B.NAME like '%stored%')
group by B.NAME
/
-- #############################################################################################
--
-- %Purpose: Monitor SQL*Net communication activities
--
-- Use: Needs Oracle DBA Access
--
-- #############################################################################################
--
set feed off;
set pagesize 10000;
set wrap off;
set linesize 200;
set heading on;
set tab on;
set scan on;
set verify off;
set termout on;

column NA format a39 heading 'STATISTIC'
column VALUE format 99999999990 heading 'VALUE'

spool monitor_sqlnet_activities.log

select rpad (NAME, 39, '.') as NA,
VALUE
from V$SYSSTAT
where NAME like ('%SQL*Net%')
order by NA
/

spool off;
-- #############################################################################################
--
-- %Purpose: Monitor Sort Activities (Sorts in Memory, Sorts on Disk)
--
-- Use: Needs Oracle DBA Access
--
-- #############################################################################################
--
set feed off;
set pagesize 10000;
set wrap off;
set linesize 200;
set heading on;
set tab on;
set scan on;
set verify off;
set termout on;

column STATISTIC# format 999 heading 'Id'
column NA format a32 heading 'Parameter'
column NAME format a32 heading 'Statistik'
column VA format a8 heading 'Value'
column VALUE format 9999999990

ttitle left 'Monitor Sort Activities' skip 2

spool monitor_sort_activities.log

select rpad (NAME, 32, '.') as NA,
VALUE as VA
from V$PARAMETER
where NAME like '%sort%'
/

ttitle off

select NAME,
VALUE
from V$SYSSTAT
where NAME in ('sorts (rows)',
'sorts (memory)',
'sorts (disk)')
/

spool off;
-- #############################################################################################
--
-- %Purpose: NLS: Show current NLS database settings from sys.props$
--
-- #############################################################################################
--
spool show_nls_current_settings.lst
ttitle left 'Show current NLS database settings' skip 2
set feed off
set pagesize 30000
set linesize 200
column name format a25
column VALUE$ format a35

SELECT name,value$ FROM sys.props$;

spool off;
-- #############################################################################################
--
-- %Purpose: NLS: Show valid NLS parameters (TERRITORY, CHARACTERSET) from v$nls_valid_values
--
-- #############################################################################################
--
spool show_nls_valid_values.lst
ttitle left 'Show valid NLS parameters (TERRITORY, CHARACTERSET)' skip 2
set feed off
set pagesize 30000
set linesize 200

COLUMN parameter format A15
COLUMN value format A15

SELECT parameter,value
FROM v$nls_valid_values
WHERE parameter = 'CHARACTERSET'
ORDER BY value;

spool off;
-- #############################################################################################
--
-- %Purpose: Overview (OWNER, OBJECT_NAME, OBJECT_TYPE) of all INVALID Objects
--
-- Use: Needs Oracle DBA Access
--
-- #############################################################################################
--
spool show_invalid_objects_summary.lst
set pause off
set feed off;
set pagesize 10000;
set wrap off;
set linesize 200;
set heading on;
set tab on;
set scan on;
set verify off;

ttitle left 'Overview of invalid objects' -
skip 2

column object_type format a25 wrap heading 'Object|Type'
column object_name format a25 wrap heading 'Object|Name'
column status format a8 heading 'Status'
column owner format a10 wrap heading 'Owner'

SELECT owner, object_name, object_type, status
FROM dba_objects
WHERE status != 'VALID';

spool off;
-- #############################################################################################
--
-- %Purpose: Performance Enhancements with PL/SQL DBMS_SQL Bulk-Operations instead of Looping
--
-- Use: Needs Oracle DBA Access
--
-- #############################################################################################
--
DECLARE
vCursor INTEGER := DBMS_SQL.Open_Cursor;
vCount INTEGER;
vStatement VARCHAR2(2000);
vEmps DBMS_SQL.Varchar2_Table;
BEGIN
vStatement := 'UPDATE emp SET sal = sal + 1' ||
' WHERE ename = :ThisEname';
vEmps(1) := 'KING';
vEmps(2) := 'MILLER';
vEmps(3) := 'HUBER';
vEmps(4) := 'SCOTT';
vEmps(5) := 'ADAMS';

BEGIN
DBMS_SQL.Parse(vCursor,vStatement, DBMS_SQL.Native);
DBMS_SQL.Bind_Array(vCursor,'ThisEname',vEmps);
vCount := DBMS_SQL.Execute(vCursor);
DBMS_SQL.Close_Cursor(vCursor);
DBMS_OUTPUT.PUT_LINE('vCount = ' || TO_CHAR(vCount));
END;
END;
-- #############################################################################################
--
-- %Purpose: Recompile all INVALID DB-Objetcs with Dependency Tracking (Very handy Script)
--
-- Environment: Execute under DB-User SYSTEM or SYS
--
-- #############################################################################################
--
set heading off;
set feed off;
set pagesize 10000;
set wrap off;
set linesize 200;
set tab on;
set scan off;
set verify off;
--
SPOOL gen_inv_obj.sql;
select
decode (OBJECT_TYPE, 'PACKAGE BODY',
'alter package ' || a.OWNER||'.'||OBJECT_NAME || ' compile body;',
'alter ' || OBJECT_TYPE || ' ' || a.OWNER||'.'||OBJECT_NAME || '
compile;')
from dba_objects a,
(select max(level) order_number, object_id from public_dependency
connect by object_id = prior referenced_object_id
group by object_id) b
where A.object_id = B.object_id(+)
and STATUS = 'INVALID'
and OBJECT_TYPE in ('PACKAGE BODY', 'PACKAGE', 'FUNCTION', 'PROCEDURE','TRIGGER', 'VIEW')
order by
order_number DESC,OBJECT_TYPE,OBJECT_NAME;
SPOOL off;
@gen_inv_obj.sql;













spool comp_all.tmp

select decode (OBJECT_TYPE, 'PACKAGE BODY',
'alter package ' || OWNER ||'.'||OBJECT_NAME || ' compile body;',
'alter ' || OBJECT_TYPE || ' ' || OWNER||'.'||OBJECT_NAME || ' compile;'
)
from DBA_OBJECTS A,
SYS.ORDER_OBJECT_BY_DEPENDENCY B
where A.OBJECT_ID = B.OBJECT_ID (+)
and A.STATUS = 'INVALID'
and A.OBJECT_TYPE in ('PACKAGE BODY','PACKAGE','FUNCTION','PROCEDURE','TRIGGER','VIEW')
order by B.DLEVEL desc,
A.OBJECT_TYPE,
A.OBJECT_NAME;
--
spool off;
set heading on;
set feed on;
set scan on;
set verify on;
--
@comp_all.tmp
-- #############################################################################################
--
-- %Purpose: SQL Statement to create the PLAN_TABLE used by EXPLAIN PLAN
--
-- #############################################################################################
--
create table PLAN_TABLE (
statement_id varchar2(30),
timestamp date,
remarks varchar2(80),
operation varchar2(30),
options varchar2(30),
object_node varchar2(128),
object_owner varchar2(30),
object_name varchar2(30),
object_instance numeric,
object_type varchar2(30),
optimizer varchar2(255),
search_columns numeric,
id numeric,
parent_id numeric,
position numeric,
cost numeric,
cardinality numeric,
bytes numeric,
other_tag varchar2(255),
other long);
-- #############################################################################################
--
-- %Purpose: Script to increase a sequence above the value the related attribute has
--
-- #############################################################################################
--
-- Akadia SQL utils
--
-- Can be used after data migrations
--
-- Paramters:
-- 1: sequence name
-- 2: table name
-- 3: attribute name
--
-- Sample usage:
-- @incseq.sql my_sequence my_table my_attribute
--
--------------------------------------------------------------------------------
--
SET SERVEROUTPUT ON SIZE 1000000;
--
DECLARE
dummy NUMBER := 0;
curr NUMBER := 0;
BEGIN
--
SELECT &1..nextval INTO dummy FROM dual;
dbms_output.put('start with next value=' || dummy);
--
SELECT max(&3) INTO curr FROM &2;
WHILE dummy < curr LOOP
SELECT &1..nextval INTO dummy FROM dual;
END LOOP;
--
dbms_output.put_line(', end=' || dummy);
--
END;
/
-- #############################################################################################
--
-- %Purpose: Send E-Mail Messages from PL/SQL with Oracle 8.1.6 using UTL_TCP or UTL_SMTP
--
-- Notes: From Oracle8i release 8.1.6 one can send e-mail messages
-- directly from PL/SQL using either the UTL_TCP or UTL_SMTP
-- packages. No pipes or external procedures required.
--
-- The UTL_TCP is a TPC/IP package that provides PL/SQL procedures
-- to support simple TCP/IP-based communications between servers and the
-- outside world. It is used by the SMTP package, to implement Oracle server-based
-- clients for the internet email protocol.
--
-- This package requires that you install the JServer option
--
-- Author: Frank Naude (frank@ibi.co.za)
--
-- #############################################################################################
--
CREATE OR REPLACE PROCEDURE send_mail (
msg_from varchar2 := 'martin.zahn@akadia.com', -- Must be a vaild E-Mail address !
msg_to varchar2 := 'martin.zahn@akadia.com', -- Must be a vaild E-Mail address !
msg_subject varchar2 := 'Message from PL/SQL daemon',
msg_text varchar2 := 'This Message was automatically send by PL/SQL daemon' )
IS
conn utl_tcp.connection;
rc integer;
mailhost varchar2(30) := 'rabbit.akadia.com';
BEGIN
conn := utl_tcp.open_connection(mailhost,25); -- open the SMTP port
dbms_output.put_line(utl_tcp.get_line(conn, TRUE));
rc := utl_tcp.write_line(conn, 'HELO '||mailhost);
dbms_output.put_line(utl_tcp.get_line(conn, TRUE));
rc := utl_tcp.write_line(conn, 'MAIL FROM: '||msg_from);
dbms_output.put_line(utl_tcp.get_line(conn, TRUE));
rc := utl_tcp.write_line(conn, 'RCPT TO: '||msg_to);
dbms_output.put_line(utl_tcp.get_line(conn, TRUE));
rc := utl_tcp.write_line(conn, 'DATA'); -- Start message body
dbms_output.put_line(utl_tcp.get_line(conn, TRUE));
rc := utl_tcp.write_line(conn, 'Subject: '||msg_subject);
rc := utl_tcp.write_line(conn, '');
rc := utl_tcp.write_line(conn, msg_text);
rc := utl_tcp.write_line(conn, '.'); -- End of message body with a "."
dbms_output.put_line(utl_tcp.get_line(conn, TRUE));
rc := utl_tcp.write_line(conn, 'QUIT');
dbms_output.put_line(utl_tcp.get_line(conn, TRUE));
utl_tcp.close_connection(conn); -- Close the connection
EXCEPTION
when others then
raise_application_error(-20000,
'Unable to send E-mail message from pl/sql procedure');
END;
/
show errors

-- Examples:
set serveroutput on

exec send_mail();
exec send_mail(msg_to =>'martin.zahn@akadia.com');
exec send_mail(msg_to =>'martin.zahn@akadia.com',
msg_text=>'How to send E-Mail from PL/SQL');


CREATE OR REPLACE PROCEDURE send_mail2 (
sender IN VARCHAR2,
recipient IN VARCHAR2,
message IN VARCHAR2)
IS
mailhost VARCHAR2(30) := 'rabbit.akadia.com';
smtp_error EXCEPTION;
mail_conn utl_tcp.connection;
PROCEDURE smtp_command(command IN VARCHAR2,
ok IN VARCHAR2 DEFAULT '250')
IS
response varchar2(3);
rc integer;
BEGIN
rc := utl_tcp.write_line(mail_conn, command);
response := substr(utl_tcp.get_line(mail_conn), 1, 3);
IF (response <> ok) THEN
RAISE smtp_error;
END IF;
END;

BEGIN
mail_conn := utl_tcp.open_connection(mailhost, 25);
smtp_command('HELO ' || mailhost);
smtp_command('MAIL FROM: ' || sender);
smtp_command('RCPT TO: ' || recipient);
smtp_command('DATA', '354');
smtp_command(message);
smtp_command('QUIT', '221');
utl_tcp.close_connection(mail_conn);
EXCEPTION
WHEN OTHERS THEN
raise_application_error(-20000,
'Unable to send e-mail message from pl/sql');
END;
/

exec send_mail2('martin.zahn@akadia.com','martin.zahn@akadia.com','Test');

CREATE OR REPLACE PROCEDURE send_mail3 (sender IN VARCHAR2,
recipient IN VARCHAR2,
message IN VARCHAR2)
IS
mailhost VARCHAR2(30) := 'rabbit.akadia.com';
mail_conn utl_smtp.connection;

BEGIN
mail_conn := utl_smtp.open_connection(mailhost, 25);
utl_smtp.helo(mail_conn, mailhost);
utl_smtp.mail(mail_conn, sender);
utl_smtp.rcpt(mail_conn, recipient);
utl_smtp.data(mail_conn, message);
utl_smtp.quit(mail_conn);
EXCEPTION
WHEN OTHERS THEN
raise_application_error(-20000,
'Unable to send e-mail message from pl/sql');
END;
/

exec send_mail3('martin.zahn@akadia.com','martin.zahn@akadia.com','Subject: Test');

-- #############################################################################################
--
-- %Purpose: Set PRIVATE SYNONYMs to Schema of a connected Oracle User
--
-- Use: Each Oracle User
--
-- #############################################################################################
--
set termout on;
set feed off;
set pagesize 10000;
set wrap off;
set linesize 200;
set heading off;
set tab on;
set scan on;
set verify off;
--
PROMPT
PROMPT **** PRIVATE SYNONYME auf waehlbares Schema setzen *****
PROMPT
PROMPT Sie brauchen Schreibrechte im aktuellen Verzeichnis,
PROMPT damit das SQL-Script gen_private_syn.sql generiert
PROMPT werden kann. Dieses wird (leider) nach der Ausfuehrung
PROMPT nicht automatisch geloescht, da sqlplus leider nicht
PROMPT weiss wie man das macht ...
PROMPT
PROMPT ********************************************************
PROMPT
WHENEVER SQLERROR EXIT SQL.CODE
ACCEPT schema_name CHAR PROMPT 'Enter Schema (Object Owner): '
--
-- Generate and run file with synonym commands in current directory
--
set termout off;
spool GEN_PRIVATE_SYN.SQL;
SELECT 'DROP SYNONYM '||synonym_name||';' FROM user_synonyms;
--
SELECT 'CREATE SYNONYM '||table_name||' FOR &&schema_name'||'.'||table_name ||';'
FROM all_tables
WHERE (UPPER(owner) LIKE UPPER('%&&schema_name%') OR
UPPER(owner) LIKE UPPER('&&schema_name'));
--
SELECT 'CREATE SYNONYM '||sequence_name||' FOR &&schema_name'||'.'||sequence_name ||';'
FROM all_sequences
WHERE (UPPER(sequence_owner) LIKE UPPER('%&&schema_name%') OR
UPPER(sequence_owner) LIKE UPPER('&&schema_name'));
--
SELECT DISTINCT 'CREATE SYNONYM '||name||' FOR &&schema_name'||'.'||name||';'
FROM all_source
WHERE (UPPER(owner) LIKE UPPER('%&&schema_name%') OR
UPPER(owner) LIKE UPPER('&&schema_name'))
AND UPPER(type) IN ('PROCEDURE','FUNCTION','PACKAGE');
spool off;
set feed on;
set termout on;
@GEN_PRIVATE_SYN.SQL;
EXIT;
-- #############################################################################################
--
-- %Purpose: Show 'Who owns what where' in the Database
--
-- #############################################################################################
--
-- Script to map tablespace names to database
-- owners, and database owners to tablespaces.
-- This will allow you to see who owns what where.
-- In the event of a tablespace loss, you would
-- then be able to quickly determine what users
-- and tablespaces will be affected. So you should
-- start this script from every export and save
-- the output files at the same place as the
-- export file.
--
-- #############################################################################################

set feed off;
set pagesize 10000;
set wrap off;
set linesize 200;
set heading on;
set tab on;
set echo off;
set scan on;
set verify off;

ttitle left 'Output generated by: ' sql.user -
skip -
skip -
left 'Who owns what where' -
skip -
left 'Oracle Version ' format a15 sql.release -
skip 2
set feed off
set pagesize 10000
break on owner on tablespace_name
column owner format A20 heading 'Owner'
column tablespace_name format A32 heading 'Tablespace'
column objects format A26 heading 'Objects'

spool who_owns_what_where.lst;

select substr(owner,1,20) owner,
substr(tablespace_name,1,32) tablespace_name,
count(*) || ' tables' objects
from sys.dba_tables
group by
substr(owner,1,20),
substr(tablespace_name,1,32)
union
select substr(owner,1,20) owner,
substr(tablespace_name,1,32) tablespace_name,
count(*) || ' indexes' objects
from sys.dba_indexes
group by
substr(owner,1,20),
substr(tablespace_name,1,32);
clear columns
clear breaks

column tablespace_name format A32 heading 'Tablespace'
column owner format A20 heading 'Owner'
column objects format A26 heading 'Objects'
break on tablespace_name on owner

select substr(tablespace_name,1,32) tablespace_name,
substr(owner,1,20) owner,
count(*) || ' tables' objects
from sys.dba_tables
group by
substr(tablespace_name,1,32),
substr(owner,1,20)
union
select substr(tablespace_name,1,32) tablespace_name,
substr(owner,1,20) owner,
count(*) || ' indexes' objects
from sys.dba_indexes
group by
substr(tablespace_name,1,32),
substr(owner,1,20);
spool off;
-- #############################################################################################
--
-- %Purpose: Show 'Who uses what objects' in the Database
--
-- #############################################################################################
--
-- Das Diagramm «Table Access» zeigt alle Datenbankobjekte, welche zur
-- Zeit von welcher Session benutzt werden.
--
-- #############################################################################################
--
set feed off;
set pagesize 10000;
set wrap off;
set linesize 200;
set heading on;
set tab on;
set scan on;
set verify off;
--
ttitle left 'Who uses what objects' -
skip 2

select sid "Sid", substr(owner,1,15) "Owner",
substr(object,1,20) "Object"
from v$access
where owner != 'SYS'
order by owner;
-- #############################################################################################
--
-- %Purpose: Show Buffer Cache Hit Ratio in % for active Instance since last Startup
--
-- #############################################################################################
--
-- Der Buffer Cache enthält Kopien der gelesenen Daten Blocks aus
-- den Datenbankfiles. Alle Sessions teilen sich den Buffer Cache, der Inhalt
-- des Buffer Caches wird gemäss einem LRU Algorithmus mittels DBWR auf die
-- DB geschrieben. Muss ein Block im Datenbankfile gelesen werden, so handelt
-- es sich dabei um einen Cache Miss, wird der Block bereits im Memory gefunden
-- so spricht man von einem Cache Hit.
-- Die Tabelle V$SYSSTAT zeigt die kumulierten Werte seit die Instance
-- gestartet wurde. Die Physical Reads seit dem Instance Startup verschlechtert
-- die Hit-Ratio, nach einer bestimmten Zeit pendelt sich der Wert ein.
--
-- Es sollte ein HitRatio mit folgenden Werten angestrebt werden:
--
-- Datenbank mit vielen Online-Transaction intensiven Benutzern: 98%
-- Batch intensive Applikation: 89%
--
-- #############################################################################################
--
set feed off;
set pagesize 10000;
set wrap off;
set linesize 200;
set heading on;
set tab on;
set scan on;
set verify off;
--
ttitle left 'Show Buffer Cache Hit Ratio in %' -
skip 2
--
select (1 - (sum(decode(a.name,'physical reads',value,0)) /
(sum(decode(a.name,'consistent gets',value,0)) +
sum(decode(a.name,'db block gets',value,0))))) * 100 "Hit Ratio in %"
from v$sysstat a;
-- #############################################################################################
--
-- %Purpose: Show Characteristics for SYSTEM and other Rollback Segments
--
-- #############################################################################################
--
spool show_rollback_segment.lst
ttitle left 'Rollback-Segment Status' -
skip 2
set feed off
set pagesize 10000
column datum new_value datum noprint
column tablespace_name format A32 heading 'Tablespace'
column segment_name format a16 heading "Rollback-Segment"
column status format a15 heading "Status"
column owner format a10 heading "Owner"

SELECT to_char(sysdate, 'MM/DD/YY') datum,
segment_name,
tablespace_name,
status,
owner
FROM sys.dba_rollback_segs;
ttitle off;

SELECT 'Number of Extents in SYSTEM Rollback Segment (1): ' || COUNT(*) "Extents"
FROM dba_extents
WHERE segment_name = 'SYSTEM'
AND segment_type = 'ROLLBACK';

SELECT 'Number of Extents in SYSTEM Rollback Segment (2): ' || extents "Extents"
FROM v$rollstat WHERE usn = 0;


SELECT 'Maximal Number of Extents in SYSTEM Rollback Segment: ' || max_extents "Max Extents"
FROM dba_rollback_segs
WHERE segment_name = 'SYSTEM';

ttitle left 'SYSTEM Rollback-Segment Status' -
skip 2

SELECT usn ,extents,rssize,hwmsize,optsize
FROM v$rollstat WHERE usn = 0;

spool off;

-- USN Rollback Segment Number (0 = SYSTEM RS)
-- EXTENTS Number of allocated Extents.
-- RSSIZE Total size of the Rollback Segment in Bytes.
-- HWMSIZE High water mark of Rollback Segment in Bytes
-- OPTSIZE Optimal size of Rollback Segment (should be NULL).


-- #############################################################################################
--
-- %Purpose: Show Constraints of Tabelles for a Schema Owner which be choosen
--
-- Use: Needs Oracle DBA Access
--
-- #############################################################################################
--
set feed off;
set pagesize 10000;
set wrap off;
set linesize 200;
set heading on;
set tab on;
set scan on;
set verify off;
--
spool show_constraints.lst
ttitle off;
column owner format a8 heading 'Table|Owner'
column constraint_name format a30 heading 'Constraint|Name'
column search_condition format a30 heading 'Text'
column table_name noprint new_value tab
column column_name format a15 heading 'Column|Name'
column r_constraint_name format a30 heading 'Reference|Constraint'
column status format A8 heading 'Status'

ttitle left 'Constraints of Tabelle: 'tab skip 2

ACCEPT user_namen CHAR PROMPT 'Schema Owner: '

break on table_name skip page -
on owner skip 2 -
on constraint_name skip -

select c.constraint_name,
i.search_condition,
c.table_name,
c.column_name,
i.r_constraint_name,
i.status
from dba_cons_columns c,
dba_constraints i
where i.table_name = c.table_name
and i.constraint_name = c.constraint_name
and i.owner = c.owner
and i.owner LIKE UPPER('&user_namen')
order by c.table_name,
c.constraint_name,
c.column_name;
spool off;
-- #############################################################################################
--
-- %Purpose: Show Contents of the Controlfile and Oracle Data Dictionary
--
-- Use: Needs Oracle DBA Access
--
-- #############################################################################################
--
ttitle left 'Output generated by: ' sql.user ' at: ' format a8 datum -
left 'Oracle Version ' format a15 sql.release -
skip -
skip -
left 'Datafiles in Data Dictionary (View: dba_data_files)' -
skip 2

set feed off
set pagesize 10000

break on tablespace_name
column datum new_value datum noprint
column tablespace_name format a10 heading "Tablespace"
column file_name format a38 heading "Datafile"
column file_id format 99 heading "File-ID"
column bytes format 99,999,999 heading "Space|[KB]"
column status format a9 heading "Status"

select to_char(sysdate, 'MM/DD/YY') datum,
tablespace_name,
file_name,
file_id,
bytes/1000 bytes,
status
from dba_data_files
order by file_id;

ttitle left 'Datafiles in Controlfile (Table: v$dbfile)' -
skip 2

set feed off
set pagesize 10000
column name format a40 heading "Datafile"
column file# format 99 heading "File-ID"
select name,file# from v$dbfile;

ttitle left 'Logfiles in Controlfile (Table: v$logfile)' -
skip 2

set feed off
set pagesize 10000
column member format a40 heading "Logfile"
column group# format 99 heading "Group-Nr"
column status format a10 heading "Status"
select member,group#,status from v$logfile;
-- #############################################################################################
--
-- %Purpose: Show DB-Events which causing Sessions to wait
--
-- #############################################################################################
--
-- Die V$SESSION_WAIT View enthält sämtliche Events, welche die User-
-- und System Sessions in den Wartezustand versetzen. Diese View kann
-- verwendet werden, um rasch einen Performance Engpass herauszufinden.
--
-- Eine Waiting Time von 0 zeigt an, dass die Session
-- gerade auf einen Event wartet. Grosse Wait Times weisen auf ein
-- Performance Problem hin (siehe Oracle Tuning Guide Seite A-4).
--
-- #############################################################################################
--
set feed off;
set pagesize 10000;
set wrap off;
set linesize 200;
set heading on;
set tab on;
set scan on;
set verify off;
--
ttitle left 'Session Events' -
skip 2

select w.Sid "Sid", nvl(substr(s.username,1,15),'Background') "User",
substr(w.event,1,25) "Event", w.wait_time "Wait Time"
from v$session_wait w, v$session s
where w.sid = s.sid
order by 2,4;
-- #############################################################################################
--
-- %Purpose: Show DB-Files with Heavy I/O (where are Hotspots of Reads und Writes) ?
--
-- READ_PCT: Prozent an gesamten Reads, Summe von READ_PCT = 100%
-- WRITE_PCT: Prozent an gesamten Writes, Summe von WRITE_PCT = 100%
--
-- IF there is a large number of writes to the temporary tablespace
-- you can increase SORT_AREA_SIZE
--
-- #############################################################################################
--
set feed off;
set pagesize 10000;
set wrap off;
set linesize 200;
set heading on;
set tab on;
set scan on;
set verify off;
--
drop table tot_read_writes;
create table tot_read_writes
as select sum(phyrds) phys_reads, sum(phywrts) phys_wrts
from v$filestat;

spool show_io_activity.lst
ttitle left 'Disk I/O s by Datafile' -
skip 2

column name format a40 heading "Filename"
column phyrds format 999,999,999 heading "Reads|Number"
column phywrts format 999,999,999 heading "Writes|Number"
column read_pct format 999.99 heading "Reads|in [%]"
column write_pct format 999.99 heading "Writes|in [%]"
select name, phyrds, phyrds * 100 / trw.phys_reads read_pct,
phywrts, phywrts * 100 / trw.phys_wrts write_pct
from tot_read_writes trw, v$datafile df, v$filestat fs
where df.file# = fs.file#
order by phyrds desc;
spool off;
set feed on echo off termout on pages 24 verify on
ttitle off
-- #############################################################################################
--
-- %Purpose: Show DBMS_JOBS for all Oracle Users
--
-- Use: Needs Oracle DBA Access
--
-- #############################################################################################
--
ttitle off;
SELECT SUBSTR(job,1,4) "Job",
SUBSTR(log_user,1,5) "User",
SUBSTR(schema_user,1,5) "Schema",
SUBSTR(TO_CHAR(last_date,'DD.MM.YYYY HH24:MI'),1,16) "Last Date",
SUBSTR(TO_CHAR(next_date,'DD.MM.YYYY HH24:MI'),1,16) "Next Date",
SUBSTR(broken,1,2) "B",
SUBSTR(failures,1,6) "Failed",
SUBSTR(what,1,20) "Command"
FROM dba_jobs;
-- #############################################################################################
--
-- %Purpose: Show Data Dictionary Cache Hit % for active Instance since last Startup
--
-- #############################################################################################
--
-- Der Data Dictionary Cache ist Teil des Shared Pools. Nach dem Instance
-- Startup werden die Data Dictionary Informationen ins Memory geladen.
-- Nach einer gewissen Betriebszeit sollte sich ein stabiler Zustand
-- einstellen. Der Data Dictionary Cache Miss sollte kleiner als 10 % sein.
--
-- #############################################################################################
--
set feed off;
set pagesize 10000;
set wrap off;
set linesize 200;
set heading on;
set tab on;
set scan on;
set verify off;
--
ttitle left 'Show Data Dictionary Cache Hit %' -
skip 2

select (1- (sum(getmisses)/sum(gets))) * 100 "Data Dictionary Cache Hit %"
from v$rowcache;
-- #############################################################################################
--
-- %Purpose: Show Database Space used for all Schema-Owners
--
-- #############################################################################################
--
spool show_used_space_by_users.lst

ttitle left 'Used Space for each ORACLE User' -
skip 2

set feed off
set linesize 80
set pagesize 5000
set underline '-'

break on owner skip 1 on tablespace_name on segment_type
column owner format A16 heading 'Owner'
column segment_type format A10 heading 'Object'
column tablespace_name format A26 heading 'Tablespace'
column bytes format 9,999,999,999 heading 'Used Space|[Bytes]'
column blocks format 999,999 heading 'Used Space|[Blocks]'
compute sum of bytes blocks on owner
--
-- Count Space for each Oracle Object
--
select substr(owner,1,16) owner,
substr(tablespace_name,1,26) tablespace_name,
substr(segment_type,1,10) segment_type,
sum(bytes) bytes,
sum(blocks) blocks
from sys.dba_extents
group by
substr(owner,1,16),
substr(tablespace_name,1,26),
substr(segment_type,1,10)
order by 1,2,3;
clear breaks
clear computes
clear column

spool off;
-- #############################################################################################
--
-- %Purpose: Show Database Triggers for Schema Owner
--
-- #############################################################################################
--
ACCEPT user_namen CHAR PROMPT 'Schema Owner: '
--
set feed off;
set pagesize 10000;
set wrap off;
set linesize 200;
set heading on;
set tab on;
set scan on;
set verify off;
--
spool show_trigger.lst
ttitle off

column trigger_name format a20 heading 'Trigger|Name'
column trigger_type format a20 heading 'Trigger|Typ'
column table_owner format a10 heading 'Table|Owner'
column table_name noprint new_value tab
column table_name format a20 heading 'Table|Name'
column triggering_event format a20 heading 'Event'
column status format A8 heading 'Status'

ttitle left 'Trigger of Tabelle: 'tab skip 2

break on table_name skip page -
on owner skip 2 -
on constraint_name skip -

select distinct table_owner,
table_name,
trigger_name,
trigger_type,
triggering_event,
status
from dba_triggers
where table_owner LIKE UPPER('&user_namen');
spool off;
-- #############################################################################################
--
-- %Purpose: Show File-I/O Rate, System-I/O Rate and Throughput on all DB-Files
--
-- #############################################################################################
--
-- File I/O Rate
--
-- Das File I/O Rate Diagramm zeigt die Anzahl physical reads
-- und writes pro Sekunde der Oracle Datenbankfiles der gesamten Instance.
--
-- System I/O Rate
--
-- Das System I/O Rate Diagramm zeigt die Anzahl logischen und physischen
-- Reads sowie die Anzahl Blockänderungen pro Sekunde.
--
-- Throughput
--
-- Das Diagramm zeigt die Anzahl User Calls und Transaktionen pro
-- Sekunde der gesamten Instance.
--
-- #############################################################################################
--
set feed off;
set pagesize 10000;
set wrap off;
set linesize 200;
set heading on;
set tab on;
set scan on;
set verify off;
--
ttitle left 'File I/O Rate' -
skip 2

select sum(phyrds), sum(phywrts)
from v$filestat;

ttitle left 'System I/O Rate' -
skip 2

select (sum(decode(name,'db block gets', value,0)) +
sum(decode(name,'consistent gets', value,0))) "BLOCK GETS+CONSISTENT GETS",
sum(decode(name,'db block changes', value,0)) "DB BLOCK CHANGES",
sum(decode(name,'physical reads', value,0)) "PHYSICAL READS"
from v$sysstat;

ttitle left 'Throughput' -
skip 2

select sum(decode(name,'user commits', value,0)) "USER COMMITS",
sum(decode(name,'user calls', value,0)) "USER CALLS"
from v$sysstat;
-- #############################################################################################
--
-- %Purpose: Show Foreign-Key Refrences from / to Oracle Tables
--
-- Use: Needs Oracle DBA Access
--
-- #############################################################################################
--
spool obj_dependencies.lst
set feed off
set pagesize 10000
ttitle off

break on owner on referenced_type on referenced_name on type skip 1
column datum new_value datum noprint
column owner format A10 heading 'Object|Owner'
column name format A24 heading 'Object|Name'
column type format A10 heading 'Object|Type'
column referenced_name format A22 heading 'Parent|Name'
column referenced_type format A10 heading 'Parent|Type'

ttitle center 'Dependencies to/from all Objects' skip 2

select to_char(sysdate, 'MM/DD/YY') datum,
substr(owner,1,10) owner,
substr(referenced_type,1,10) referenced_type,
substr(referenced_name,1,22) referenced_name,
substr(type,1,10) type,
substr(name,1,24) name
from dba_dependencies
where owner not in ('SYS','SYSTEM')
and referenced_type not in ('NON-EXISTENT')
order by 1,2,3,4,5,6;

spool off;
exit;
-- #############################################################################################
--
-- %Purpose: Show Foreign-Primarykey Relations with Foreign Keys without an Index
--
-- The scripts below provide information on foreign key
-- usage. The first script lists the foreign keys and the
-- second lists foreign keys that are missing indexes on
-- the foreign key columns in the child table. If the index
-- is not in place, share lock problems may occur on the
-- parent table.
--
-- #############################################################################################
--
set feed off;
set pagesize 10000;
set wrap off;
set linesize 200;
set heading on;
set tab on;
set scan on;
set verify off;
--
spool show_foreign_keys.lst
ttitle off;
COLUMN tab_owner FORMAT A10 HEADING "Owner";
COLUMN tab_name_fk FORMAT A15 HEADING "FK-Table";
COLUMN col_name_fk FORMAT A15 HEADING "FK-Column";
COLUMN tab_name_pk FORMAT A15 HEADING "PK-Table";
COLUMN col_name_pk FORMAT A15 HEADING "PK-Column"
--
ttitle left 'Foreign Key Listing' skip 2

break on tab_owner -
on tab_name_fk skip -

SELECT a.owner tab_owner,
a.table_name tab_name_fk,
c.column_name col_name_fk,
b.table_name tab_name_pk,
d.column_name col_name_pk
FROM dba_constraints a, dba_constraints b,
dba_cons_columns c, dba_cons_columns d
WHERE a.r_constraint_name = b.constraint_name
AND a.constraint_type = 'R'
AND b.constraint_type = 'P'
AND a.r_owner=b.owner
AND a.constraint_name = c.constraint_name
AND b.constraint_name=d.constraint_name
AND a.owner = c.owner
AND a.table_name=c.table_name
AND b.owner = d.owner
AND a.owner NOT IN ('SYS','SYSTEM')
AND b.table_name=d.table_name
ORDER BY 1,2,3;
--
SELECT acc.owner||'-> '||acc.constraint_name||'('||acc.column_name
||'['||acc.position||'])'||' ***** Missing Index'
"Indexes Missing on Child Table"
FROM all_cons_columns acc, all_constraints ac
WHERE ac.constraint_name = acc.constraint_name
AND ac.constraint_type = 'R'
AND acc.owner NOT IN ('SYS','SYSTEM')
AND (acc.owner, acc.table_name, acc.column_name, acc.position) IN
(SELECT acc.owner, acc.table_name, acc.column_name, acc.position
FROM all_cons_columns acc, all_constraints ac
WHERE ac.constraint_name = acc.constraint_name
AND ac.constraint_type = 'R'
MINUS
SELECT table_owner, table_name, column_name, column_position
FROM all_ind_columns)
ORDER BY acc.owner, acc.constraint_name,
acc.column_name, acc.position;
spool off;
set feed on echo off termout on pages 24 verify on
ttitle off
-- #############################################################################################
--
-- %Purpose: Show Free List Hit Ratio in % to verify Database Block Contention
--
-- #############################################################################################
--
-- Das Diagramm «Free List Hit %» zeigt Informationen zur Datenblock
-- Contention. Für jedes Segment unterhält Oracle ein oder mehrere Freelists.
-- Freelists enthalten allozierte Datenblocks für diesen Segment- Extent mit
-- freiem Platz für INSERTS. Bei vielen concurrent INSERTS sind unter
-- Umständen mehrere Freelists zu erstellen.
--
-- #############################################################################################
--
set feed off;
set pagesize 10000;
set wrap off;
set linesize 200;
set heading on;
set tab on;
set scan on;
set verify off;
--
ttitle left 'Free List Hit%' -
skip 2

select (sum(value)-(sum(count)/2))/sum(value)*100 "Gets"
from v$waitstat w, v$sysstat s
where w.class='free list'
and s.name in ('db block gets', 'consistent gets');

select (sum(count) / (sum(value))) * 100 "Misses"
from v$waitstat w, v$sysstat s
where w.class='free list'
and s.name in ('db block gets', 'consistent gets');
-- #############################################################################################
--
-- %Purpose: Show Highwater Mark of a table (Choose Table and Schema Owner)
--
-- Calculate Highwatermark as follows or use Package DBMS_SPACE.UNUSED_SPACE
--
-- select blocks
-- from dba_segments
-- where owner = 'PPB'
-- and segment_name = 'ACM';
--
-- select empty_blocks
-- from dba_tables
-- where owner = 'PPB'
-- and table_name = 'ACM';
--
-- Highwatermark := blocks - empty_blocks -1;
--
-- Beispiel: Ausgangslage der Tabelle Test
-- ---------------------------------------
-- Total Blocks = 440
-- Total Bytes = 1802240
-- Unused Blocks = 15
-- Unused Bytes = 61440
-- Highwater Mark = (440 - 15 - 1) = 424
--
-- ALTER TABLE test DEALLOCATE UNUSED; /* Verändert Unused Blocks und Bytes */
--
-- Total Blocks = 425
-- Total Bytes = 1740800
-- Unused Blocks = 0
-- Unused Bytes = 0
-- Highwater Mark = (425 - 0 - 1) = 424
--
-- DELETE FROM test; /* Verändert HWM nicht, SELECT COUNT(*) geht lange ! */
--
-- Total Blocks = 425
-- Total Bytes = 1740800
-- Unused Blocks = 0
-- Unused Bytes = 0
-- Highwater Mark = (425 - 0 - 1) = 424
--
-- TRUNCATE TABLE test; /* Reset der HWM, SELECT COUNT(*) geht schnell ! */
--
-- Total Blocks = 20
-- Total Bytes = 81920
-- Unused Blocks = 19
-- Unused Bytes = 77824
-- Highwater Mark = (20 - 19 - 1) = 0
--
-- #############################################################################################
--
set serveroutput on size 200000
set echo off
set feedback off
set verify off
set showmode off
set linesize 500
--
ACCEPT l_user CHAR PROMPT 'Schemaowner: '
ACCEPT l_table CHAR PROMPT 'Tablename: '
--
declare
OP1 number;
OP2 number;
OP3 number;
OP4 number;
OP5 number;
OP6 number;
OP7 number;
HWM number;
begin
dbms_space.unused_space(UPPER('&&l_user'),UPPER('&&l_table'),'TABLE',OP1,OP2,OP3,OP4,OP5,OP6,OP7);
HWM := OP1 - OP3 - 1;
dbms_output.put_line('--------------------------');
dbms_output.put_line('Total Blocks = '||OP1);
dbms_output.put_line('Total Bytes = '||OP2);
dbms_output.put_line('Unused Blocks = '||OP3);
dbms_output.put_line('Unused Bytes = '||OP4);
dbms_output.put_line('Highwater Mark = ('||OP1||' - '||OP3||' - 1) = '||HWM);
end;
/
-- #############################################################################################
--
-- %Purpose: Show Hit-Ratios, Consistent-Gets, DB-Block-Gets, Physical-Reads for the Sessions
--
-- #############################################################################################
--
set feed off;
set pagesize 10000;
set wrap off;
set linesize 200;
set heading on;
set tab on;
set scan on;
set verify off;
--
spool show_session_hit_ratio.lst

ttitle 'User Hit Ratios' -
skip 2

column nl newline;
column "Hit Ratio" format 999.99
column "User Session" format a15;
set pagesize 999

select se.username||'('|| se.sid||')' "User Session",
sum(decode(name, 'consistent gets',value, 0)) "Consis Gets",
sum(decode(name, 'db block gets',value, 0)) "DB Blk Gets",
sum(decode(name, 'physical reads',value, 0)) "Phys Reads",
(sum(decode(name, 'consistent gets',value, 0)) +
sum(decode(name, 'db block gets',value, 0)) -
sum(decode(name, 'physical reads',value, 0)))
/
(sum(decode(name, 'consistent gets',value, 0)) +
sum(decode(name, 'db block gets',value, 0)) ) * 100 "Hit Ratio"
from v$sesstat ss, v$statname sn, v$session se
where ss.sid = se.sid
and sn.statistic# = ss.statistic#
and value != 0
and sn.name in ('db block gets', 'consistent gets', 'physical reads')
group by se.username, se.sid
having
(sum(decode(name, 'consistent gets',value, 0)) +
sum(decode(name, 'db block gets',value, 0)) -
sum(decode(name, 'physical reads',value, 0)))
/
(sum(decode(name, 'consistent gets',value, 0)) +
sum(decode(name, 'db block gets',value, 0)) ) * 100
< 100;
spool off;
set feed on echo off termout on pages 24 verify on
ttitle off
-- #############################################################################################
--
-- %Purpose: Show I/O between DB-Server and Clients over SQL*Net in Bytes/s
--
-- Purpose: Network Bytes Rate
--
-- Das Diagramm «Network Bytes Rate» zeigt die Anzahl Bytes / Sekunde an
-- Daten, die vom Datenbank Server und seinen Clients über SQL*Net
-- ausgetauscht werden.
--
-- Network I/O Rate
--
-- Das Diagramm «Network I/O Rate» zeigt die Anzahl Message
-- Packete / Sekunde die vom Datenbank Server und seinen Clients
-- über SQL*Net ausgetauscht werden.
--
-- #############################################################################################
--
set feed off;
set pagesize 10000;
set wrap off;
set linesize 200;
set heading on;
set tab on;
set scan on;
set verify off;
--
ttitle left 'Network Bytes Rate' -
skip 2

column sum_value format 999,999,999,999 heading 'Sum Bytes'
column total_waits format 999,999,999,999 heading 'Total Waits ms'

select sum(value) sum_value from v$sysstat
where name like 'bytes%SQL*Net%';

ttitle left 'Network I/O Rate' -
skip 2

select sum(total_waits) total_waits
from v$system_event
where event like 'SQL*Net%';
-- #############################################################################################
--
-- %Purpose: Show INITIAL, NEXT, Total Extents, Total Blocks of DB-Objects
--
-- #############################################################################################
--
set feed off;
set pagesize 10000;
set wrap off;
set linesize 200;
set heading on;
set tab on;
set scan on;
set verify off;
--
spool show_object_storage_info.lst

ttitle 'Object Storage Information' -
skip 2

SELECT SUBSTR(s.owner,1,20) || '.' ||SUBSTR(s.segment_name,1,20) "Object Name",
SUBSTR(s.segment_type,1,10) "Type",
SUBSTR(s.tablespace_name,1,10) Tspace,
NVL(NVL(t.initial_extent, i.initial_extent),r.initial_extent) "FstExt",
NVL(NVL(t.next_extent,i.next_extent),R.NEXT_EXTENT) "NxtExt",
s.extents "TotExt",
s.blocks "TotBlks"
FROM dba_rollback_segs R,
dba_indexes I,
dba_tables T,
dba_segments S
WHERE s.segment_type IN ('CACHE','CLUSTER','INDEX','ROLLBACK','TABLE','TEMPORARY')
AND s.owner NOT IN ('SYSTEM')
AND s.owner = t.owner (+)
AND s.segment_name = t.table_name (+)
AND s.tablespace_name = t.tablespace_name (+)
AND s.owner = i.owner (+)
AND s.segment_name = i.index_name (+)
AND s.tablespace_name = i.tablespace_name (+)
AND s.owner = r.owner (+)
AND s.segment_name = r.segment_name (+)
AND s.tablespace_name = r.tablespace_name (+)
ORDER BY 2,1;
spool off;
set feed on echo off termout on pages 24 verify on
ttitle off
-- #############################################################################################
--
-- %Purpose: Show Indexes for a Schema Owner
--
-- Use: Needs Oracle DBA Access
--
-- #############################################################################################
--
spool show_indexes.lst
set pause off
set feed off;
set pagesize 10000;
set wrap off;
set linesize 200;
set heading on;
set tab on;
set scan on;
set verify off;

column index_name format a25 wrap heading 'Index|Name'
column uni format a5 heading 'Uniq-|ness'
column tablespace_name format a10 wrap heading 'Tablespace'
column table_name noprint new_value tab
column column_name format a26 heading 'Column|Name'
column table_owner format a10 heading 'Table|Owner'

ttitle left 'Indexes of Tabelle: 'tab skip 2

ACCEPT user_namen CHAR PROMPT 'Schema Owner: '

break on table_name skip page -
on table_owner skip 2 -
on index_name skip -
on uni -
on tablespace_name

select i.table_owner,
i.index_name,
c.table_name,
c.column_name,
decode(i.uniqueness,'UNIQUE','YES','NONUNIQUE','NO','???') uni,
i.tablespace_name
from dba_ind_columns c, dba_indexes i
where i.table_name = c.table_name
and i.index_name = c.index_name
and i.table_name like upper('%')
and i.table_owner = c.table_owner
and i.table_owner LIKE UPPER('&user_namen')
order by i.table_owner,
c.table_name,
i.uniqueness desc,
c.index_name,
c.column_position;
spool off;
-- #############################################################################################
--
-- %Purpose: Show Library Cache Hit % for the Shared Pool of the Instance
--
-- #############################################################################################
--
-- Der Library Cache ist Teil des Shared Pools.
-- Cache Misses im Library Cache sind «sehr teuer», da das SQL-Statement
-- geladen, geparst und ausgeführt werden muss. Hier gilt die Regel, dass
-- 99 % aller SQL-Statements in geparster Form im Memory vorliegen müssen.
-- Ist dies nicht der Fall so muss der Wert SHARED_POOL_SIZE erhöht werden.
--
-- #############################################################################################
--
set feed off;
set pagesize 10000;
set wrap off;
set linesize 200;
set heading on;
set tab on;
set scan on;
set verify off;
--
ttitle left 'Show Library Cache Hit %' -
skip 2

select (1-(sum(reloads)/sum(pins))) *100 "Library Cache Hit %"
from v$librarycache;
-- #############################################################################################
--
-- %Purpose: Show Low-level Locks (Latches) on internal shared Memory Structures
--
-- #############################################################################################
--
set feed off;
set pagesize 10000;
set wrap off;
set linesize 200;
set heading on;
set tab on;
set scan on;
set verify off;
--
ttitle left 'Latch Statistics' -
skip 2

select substr(ln.name,1,30) "Name",l.gets,l.misses,l.sleeps,
l.immediate_gets "ImmGets",l.immediate_misses "ImmMiss"
from v$latch l, v$latchname ln, v$latchholder lh
where l.latch#=ln.latch#
and l.addr=lh.laddr(+)
order by l.level#, l.latch#;
-- #############################################################################################
--
-- %Purpose: Show Memory Sort Hit % (Memory and Disc)
--
-- #############################################################################################
--
set feed off;
set pagesize 10000;
set wrap off;
set linesize 200;
set heading on;
set tab on;
set scan on;
set verify off;
--
ttitle left 'Show Memory Sort Hit %' -
skip 2

select (sum(decode(name, 'sorts (memory)', value, 0)) /
(sum(decode(name, 'sorts (memory)', value, 0)) +
sum(decode(name, 'sorts (disk)', value, 0)))) * 100 "Memory Sort Hit %"
from v$sysstat;
-- #############################################################################################
--
-- %Purpose: Show Number of Logswitches per Hour and Day as a Histogram
--
-- Use: Needs Oracle DBA Access
--
-- #############################################################################################
--

### Version for Oracle 7

set feed off;
set pagesize 10000;
set wrap off;
set linesize 200;
set heading on;
set tab on;
set scan on;
set verify off;
--
spool show_logswitches.lst

ttitle left 'Redolog File Status aus V$LOG' skip 2

select group#, sequence#,
Members, archived, status, first_time
from v$log;

ttitle left 'Anzahl Logswitches pro Stunde' skip 2

select substr(time,1,5) day,
to_char(sum(decode(substr(time,10,2),'00',1,0)),'99') "00",
to_char(sum(decode(substr(time,10,2),'01',1,0)),'99') "01",
to_char(sum(decode(substr(time,10,2),'02',1,0)),'99') "02",
to_char(sum(decode(substr(time,10,2),'03',1,0)),'99') "03",
to_char(sum(decode(substr(time,10,2),'04',1,0)),'99') "04",
to_char(sum(decode(substr(time,10,2),'05',1,0)),'99') "05",
to_char(sum(decode(substr(time,10,2),'06',1,0)),'99') "06",
to_char(sum(decode(substr(time,10,2),'07',1,0)),'99') "07",
to_char(sum(decode(substr(time,10,2),'08',1,0)),'99') "08",
to_char(sum(decode(substr(time,10,2),'09',1,0)),'99') "09",
to_char(sum(decode(substr(time,10,2),'10',1,0)),'99') "10",
to_char(sum(decode(substr(time,10,2),'11',1,0)),'99') "11",
to_char(sum(decode(substr(time,10,2),'12',1,0)),'99') "12",
to_char(sum(decode(substr(time,10,2),'13',1,0)),'99') "13",
to_char(sum(decode(substr(time,10,2),'14',1,0)),'99') "14",
to_char(sum(decode(substr(time,10,2),'15',1,0)),'99') "15",
to_char(sum(decode(substr(time,10,2),'16',1,0)),'99') "16",
to_char(sum(decode(substr(time,10,2),'17',1,0)),'99') "17",
to_char(sum(decode(substr(time,10,2),'18',1,0)),'99') "18",
to_char(sum(decode(substr(time,10,2),'19',1,0)),'99') "19",
to_char(sum(decode(substr(time,10,2),'20',1,0)),'99') "20",
to_char(sum(decode(substr(time,10,2),'21',1,0)),'99') "21",
to_char(sum(decode(substr(time,10,2),'22',1,0)),'99') "22",
to_char(sum(decode(substr(time,10,2),'23',1,0)),'99') "23"
from v$log_history
group by substr(time,1,5)
/
spool off;

### Version for Oracle 8.1.x

set feed off;
set pagesize 10000;
set wrap off;
set linesize 200;
set heading on;
set tab on;
set scan on;
set verify off;
--
spool show_logswitches.lst

ttitle left 'Redolog File Status from V$LOG' skip 2

select group#, sequence#,
Members, archived, status, first_time
from v$log;

ttitle left 'Number of Logswitches per hour' skip 2

select to_char(first_time,'YYYY.MM.DD') day,
to_char(sum(decode(substr(to_char(first_time,'DDMMYYYY:HH24:MI'),10,2),'00',1,0)),'99') "00",
to_char(sum(decode(substr(to_char(first_time,'DDMMYYYY:HH24:MI'),10,2),'01',1,0)),'99') "01",
to_char(sum(decode(substr(to_char(first_time,'DDMMYYYY:HH24:MI'),10,2),'02',1,0)),'99') "02",
to_char(sum(decode(substr(to_char(first_time,'DDMMYYYY:HH24:MI'),10,2),'03',1,0)),'99') "03",
to_char(sum(decode(substr(to_char(first_time,'DDMMYYYY:HH24:MI'),10,2),'04',1,0)),'99') "04",
to_char(sum(decode(substr(to_char(first_time,'DDMMYYYY:HH24:MI'),10,2),'05',1,0)),'99') "05",
to_char(sum(decode(substr(to_char(first_time,'DDMMYYYY:HH24:MI'),10,2),'06',1,0)),'99') "06",
to_char(sum(decode(substr(to_char(first_time,'DDMMYYYY:HH24:MI'),10,2),'07',1,0)),'99') "07",
to_char(sum(decode(substr(to_char(first_time,'DDMMYYYY:HH24:MI'),10,2),'08',1,0)),'99') "08",
to_char(sum(decode(substr(to_char(first_time,'DDMMYYYY:HH24:MI'),10,2),'09',1,0)),'99') "09",
to_char(sum(decode(substr(to_char(first_time,'DDMMYYYY:HH24:MI'),10,2),'10',1,0)),'99') "10",
to_char(sum(decode(substr(to_char(first_time,'DDMMYYYY:HH24:MI'),10,2),'11',1,0)),'99') "11",
to_char(sum(decode(substr(to_char(first_time,'DDMMYYYY:HH24:MI'),10,2),'12',1,0)),'99') "12",
to_char(sum(decode(substr(to_char(first_time,'DDMMYYYY:HH24:MI'),10,2),'13',1,0)),'99') "13",
to_char(sum(decode(substr(to_char(first_time,'DDMMYYYY:HH24:MI'),10,2),'14',1,0)),'99') "14",
to_char(sum(decode(substr(to_char(first_time,'DDMMYYYY:HH24:MI'),10,2),'15',1,0)),'99') "15",
to_char(sum(decode(substr(to_char(first_time,'DDMMYYYY:HH24:MI'),10,2),'16',1,0)),'99') "16",
to_char(sum(decode(substr(to_char(first_time,'DDMMYYYY:HH24:MI'),10,2),'17',1,0)),'99') "17",
to_char(sum(decode(substr(to_char(first_time,'DDMMYYYY:HH24:MI'),10,2),'18',1,0)),'99') "18",
to_char(sum(decode(substr(to_char(first_time,'DDMMYYYY:HH24:MI'),10,2),'19',1,0)),'99') "19",
to_char(sum(decode(substr(to_char(first_time,'DDMMYYYY:HH24:MI'),10,2),'20',1,0)),'99') "20",
to_char(sum(decode(substr(to_char(first_time,'DDMMYYYY:HH24:MI'),10,2),'21',1,0)),'99') "21",
to_char(sum(decode(substr(to_char(first_time,'DDMMYYYY:HH24:MI'),10,2),'22',1,0)),'99') "22",
to_char(sum(decode(substr(to_char(first_time,'DDMMYYYY:HH24:MI'),10,2),'23',1,0)),'99') "23"
from v$log_history
group by to_char(first_time,'YYYY.MM.DD')
/
spool off;

### Version for Oracle 8.1.x with archived redologs

alter session set nls_date_format = 'DD.MM.YYYY:HH24:MI';

spool show_logswitches.lst

ttitle left 'Redolog File Status from V$LOG' skip 2

select group#, sequence#,
Members, archived, status, first_time
from v$log;

ttitle left 'Number of Logswitches per Hour' skip 2

select substr(completion_time,1,5) day,
to_char(sum(decode(substr(completion_time,12,2),'00',1,0)),'99') "00",
to_char(sum(decode(substr(completion_time,12,2),'01',1,0)),'99') "01",
to_char(sum(decode(substr(completion_time,12,2),'02',1,0)),'99') "02",
to_char(sum(decode(substr(completion_time,12,2),'03',1,0)),'99') "03",
to_char(sum(decode(substr(completion_time,12,2),'04',1,0)),'99') "04",
to_char(sum(decode(substr(completion_time,12,2),'05',1,0)),'99') "05",
to_char(sum(decode(substr(completion_time,12,2),'06',1,0)),'99') "06",
to_char(sum(decode(substr(completion_time,12,2),'07',1,0)),'99') "07",
to_char(sum(decode(substr(completion_time,12,2),'08',1,0)),'99') "08",
to_char(sum(decode(substr(completion_time,12,2),'09',1,0)),'99') "09",
to_char(sum(decode(substr(completion_time,12,2),'10',1,0)),'99') "10",
to_char(sum(decode(substr(completion_time,12,2),'11',1,0)),'99') "11",
to_char(sum(decode(substr(completion_time,12,2),'12',1,0)),'99') "12",
to_char(sum(decode(substr(completion_time,12,2),'13',1,0)),'99') "13",
to_char(sum(decode(substr(completion_time,12,2),'14',1,0)),'99') "14",
to_char(sum(decode(substr(completion_time,12,2),'15',1,0)),'99') "15",
to_char(sum(decode(substr(completion_time,12,2),'16',1,0)),'99') "16",
to_char(sum(decode(substr(completion_time,12,2),'17',1,0)),'99') "17",
to_char(sum(decode(substr(completion_time,12,2),'18',1,0)),'99') "18",
to_char(sum(decode(substr(completion_time,12,2),'19',1,0)),'99') "19",
to_char(sum(decode(substr(completion_time,12,2),'20',1,0)),'99') "20",
to_char(sum(decode(substr(completion_time,12,2),'21',1,0)),'99') "21",
to_char(sum(decode(substr(completion_time,12,2),'22',1,0)),'99') "22",
to_char(sum(decode(substr(completion_time,12,2),'23',1,0)),'99') "23"
from V$ARCHIVED_LOG
group by substr(completion_time,1,5)
/
spool off;

-- #############################################################################################
--
-- %Purpose: Show Number of Objects (Tab,Ind,Syn,Vew,Seq,Prc,Fun,Pck,Trg) for each Oracle User
--
-- Use: Needs Oracle DBA Access
--
-- #############################################################################################

--
-- Version for Oracle7/8
--
set feed off;
set pagesize 10000;
set wrap off;
set linesize 200;
set heading on;
set tab on;
set scan on;
set verify off;

column Tab format 9999 heading "Tab"
column Ind format 9999 heading "Ind"
column Syn format 9999 heading "Syn"
column Vew format 9999 heading "Vew"
column Seq format 9999 heading "Seq"
column Prc format 9999 heading "Prc"
column Fun format 9999 heading "Fun"
column Pck format 9999 heading "Pck"
column Trg format 9999 heading "Trg"
column Dep format 9999 heading "Dep"

spool list_objects_by_user.lst
ttitle 'Object Count by User' -
skip 2

SELECT SUBSTR(username,1,10) "User",
COUNT(DECODE(o.type, 2, o.obj#, '')) Tab,
COUNT(DECODE(o.type, 1, o.obj#, '')) Ind,
COUNT(DECODE(o.type, 5, o.obj#, '')) Syn,
COUNT(DECODE(o.type, 4, o.obj#, '')) Vew,
COUNT(DECODE(o.type, 6, o.obj#, '')) Seq,
COUNT(DECODE(o.type, 7, o.obj#, '')) Prc,
COUNT(DECODE(o.type, 8, o.obj#, '')) Fun,
COUNT(DECODE(o.type, 9, o.obj#, '')) Pck,
COUNT(DECODE(o.type,12, o.obj#, '')) Trg,
COUNT(DECODE(o.type,10, o.obj#, '')) Dep
FROM sys.obj$ o, sys.dba_users U
WHERE u.user_id = o.owner# (+)
AND o.type > 0
GROUP BY username;
spool off
set feed on echo off termout on pages 24 verify on

--
-- Version for Oracle8i
--
set feed off;
set pagesize 10000;
set wrap off;
set linesize 200;
set heading on;
set tab on;
set scan on;
set verify off;

column Tab format 9999 heading "Tab"
column Ind format 9999 heading "Ind"
column Syn format 9999 heading "Syn"
column Vew format 9999 heading "Vew"
column Seq format 9999 heading "Seq"
column Prc format 9999 heading "Prc"
column Fun format 9999 heading "Fun"
column Pck format 9999 heading "Pck"
column Trg format 9999 heading "Trg"
column Dep format 9999 heading "Dep"

spool list_objects_by_user.lst
ttitle 'Object Count by User' -
skip 2

SELECT SUBSTR(username,1,10) "User",
COUNT(DECODE(o.type#, 2, o.obj#, '')) Tab,
COUNT(DECODE(o.type#, 1, o.obj#, '')) Ind,
COUNT(DECODE(o.type#, 5, o.obj#, '')) Syn,
COUNT(DECODE(o.type#, 4, o.obj#, '')) Vew,
COUNT(DECODE(o.type#, 6, o.obj#, '')) Seq,
COUNT(DECODE(o.type#, 7, o.obj#, '')) Prc,
COUNT(DECODE(o.type#, 8, o.obj#, '')) Fun,
COUNT(DECODE(o.type#, 9, o.obj#, '')) Pck,
COUNT(DECODE(o.type#,12, o.obj#, '')) Trg,
COUNT(DECODE(o.type#,10, o.obj#, '')) Dep
FROM sys.obj$ o, sys.dba_users U
WHERE u.user_id = o.owner# (+)
AND o.type# > 0
GROUP BY username;
spool off
set feed on echo off termout on pages 24 verify on
-- #############################################################################################
--
-- %Purpose: Show Number of Rows per Block for a Table (Only for Oracle7 ROWID)
--
-- #############################################################################################
--
set echo off
set feedback off
set verify off
set showmode off
set pagesize 5000
set linesize 500
--
ACCEPT l_table CHAR PROMPT 'Tablename: '
--
spool show_rows_per_block_ora7.lst
ttitle left 'Table Rows Per Block' -
skip 2
--
SELECT SUBSTR(T.ROWID,1,8) || '-' ||
SUBSTR(T.ROWID,15,4) "Block",
COUNT(*) "Rows_Per_Block"
FROM &&l_table T
WHERE ROWNUM < 2000
GROUP BY SUBSTR(T.ROWID,1,8) || '-' || SUBSTR(T.ROWID,15,4);
spool off;
-- #############################################################################################
--
-- %Purpose: Show Number of Transactions and other Cursor Statistics (Commits, Rollbacks, etc)
--
-- Use: Needs Oracle DBA Access
--
-- #############################################################################################
--
set feed off;
set pagesize 10000;
set wrap off;
set linesize 200;
set heading on;
set tab on;
set scan on;
set verify off;
--
column STATISTIC# format 999 heading 'Id'
column NA format a32 heading 'Statistic'
column PPE format 99990.90
column NR_TX format 99999990
column NR_RECC format 99990.90

ttitle left 'Monitor Cursor Activites' skip 2

spool cursor_activites.log
set termout on

select rpad (NAME, 32, '.') as NA,
VALUE
from V$SYSSTAT
where NAME like '%cursor%'
or NAME in ('parse count',
'execute count',
'user calls',
'user commits',
'user rollbacks',
'parse time cpu',
'parse time elapsed',
'recursive calls')
/

ttitle left 'Number of Transactions' skip 2

select A.VALUE + B.VALUE as NR_TX
from V$SYSSTAT A,
V$SYSSTAT B
where A.NAME = 'user commits'
and B.NAME = 'user rollbacks'
/

ttitle left 'Recursive call Per user call' skip 2

select C.VALUE / D.VALUE as NR_RECC
from V$SYSSTAT C,
V$SYSSTAT D
where C.NAME = 'recursive calls'
and D.NAME = 'user calls'
/

ttitle left 'Parse per Execute [%]' skip 2

select E.VALUE / F.VALUE * 100.0 as PPE
from V$SYSSTAT E,
V$SYSSTAT F
where E.NAME = 'parse count'
and F.NAME = 'execute count'
/

spool off
ttitle off
-- #############################################################################################
--
-- %Purpose: Show Number of physical Reads and Writes per Sec for each DB-File (I/O Details)
--
-- #############################################################################################
--
set feed off;
set pagesize 10000;
set wrap off;
set linesize 200;
set heading on;
set tab on;
set scan on;
set verify off;
--
ttitle left 'File I/O Rate Details since last Instance Startup' -
skip 2

select substr(NAME,1,30) "NAME",PHYRDS,PHYWRTS,PHYBLKRD,PHYBLKWRT
from V$DBFILE DF, V$FILESTAT FS
where DF.FILE#=FS.FILE#
order by NAME;
-- #############################################################################################
--
-- %Purpose: Show Object Privileges for Schema Owner which can be choosen
--
-- Use: Needs Oracle DBA Access
--
-- #############################################################################################
--
set feed off;
set pagesize 10000;
set wrap off;
set linesize 200;
set heading on;
set tab on;
set scan on;
set verify off;

spool show_grants.lst
ttitle off

ACCEPT user_namen CHAR PROMPT 'Schema Owner: '

column owner format a10 heading 'Object|Owner'
column grantor format a22 heading 'User who|performed the Grant'
column grantee format a24 heading 'User/Role to whom|Access was granted'
column privilege format a12 heading 'Object|Privilege'
column table_name noprint new_value tab

ttitle left 'Object Grants on: 'tab skip 2

break on table_name skip page -
on owner skip 2 -
on grantor skip -
on grantee -
on privileges

select substr(table_name,1,20) table_name,
substr(owner,1,16) owner,
substr(grantor,1,24) grantor,
substr(grantee,1,24) grantee,
substr(privilege,1,12) privilege
from dba_tab_privs
where upper(owner) LIKE UPPER('&user_namen')
order by 1,2,3,4,5;
spool off;
-- #############################################################################################
--
-- %Purpose: Show Objects and Comments from the Oracle Data Dictionary (View DICTIONARY)
--
-- Use: Needs Oracle DBA Access
--
-- #############################################################################################
--
set termout on;
set feed off;
set pagesize 10000;
set wrap off;
set linesize 200;
set heading off;
set tab on;
set scan on;
set verify off;
spool show_dictionary.lst
select substr(table_name,1,20) "Table Name",
substr(comments,1,100) "Comment"
from dictionary
order by table_name;
spool off;
-- #############################################################################################
--
-- %Purpose: Show Objects which cannot allocate NEXT Extent (ORA-01653)
--
-- alter table credit allocate extent;
-- ORA-01653: unable to extend table PPB.CREDIT by 5000 in tablespace CRE
--
-- #############################################################################################
--
set feed off;
set pagesize 10000;
set wrap off;
set linesize 200;
set heading on;
set tab on;
set scan on;
set verify off;
--
spool show_objects_no_next_extent.lst

ttitle 'Show Objects which cannot allocate the next extent' -
skip 2

column owner format a10;
column segment_name format a22;
column segment_type format a10;
column tablespace_name format a14;
column next_extent format 999,999,999;

SELECT seg.owner, seg.segment_name,
seg.segment_type, seg.tablespace_name,
t.next_extent
FROM sys.dba_segments seg,
sys.dba_tables t
WHERE (seg.segment_type = 'TABLE'
AND seg.segment_name = t.table_name
AND seg.owner = t.owner
AND NOT EXISTS
(select tablespace_name
from dba_free_space free
where free.tablespace_name = t.tablespace_name
and bytes >= t.next_extent ))
UNION
SELECT seg.owner, seg.segment_name,
seg.segment_type, seg.tablespace_name,
DECODE (seg.segment_type,
'CLUSTER', c.next_extent)
FROM sys.dba_segments seg,
sys.dba_clusters c
WHERE (seg.segment_type = 'CLUSTER'
AND seg.segment_name = c.cluster_name
AND seg.owner = c.owner
AND NOT EXISTS
(select tablespace_name
from dba_free_space free
where free.tablespace_name = c.tablespace_name
and bytes >= c.next_extent ))
UNION
SELECT seg.owner, seg.segment_name,
seg.segment_type, seg.tablespace_name,
DECODE (seg.segment_type,
'INDEX', i.next_extent )
FROM sys.dba_segments seg,
sys.dba_indexes i
WHERE (seg.segment_type = 'INDEX'
AND seg.segment_name = i.index_name
AND seg.owner = i.owner
AND NOT EXISTS
(select tablespace_name
from dba_free_space free
where free.tablespace_name = i.tablespace_name
and bytes >= i.next_extent ))
UNION
SELECT seg.owner, seg.segment_name,
seg.segment_type, seg.tablespace_name,
DECODE (seg.segment_type,
'ROLLBACK', r.next_extent)
FROM sys.dba_segments seg,
sys.dba_rollback_segs r
where (seg.segment_type = 'ROLLBACK'
AND seg.segment_name = r.segment_name
AND seg.owner = r.owner
AND NOT EXISTS
(select tablespace_name
from dba_free_space free
where free.tablespace_name = r.tablespace_name
and bytes >= r.next_extent ))
/
ttitle 'Segments that are sitting on the Maximum Extents Allowable' -
skip 2

select e.owner, e.segment_name, e.segment_type, count(*), avg(max_extents)
from dba_extents e, dba_segments s
where e.segment_name = s.segment_name
and e.owner = s.owner
group by e.owner, e.segment_name, e.segment_type
having count(*) = avg(max_extents)
/
spool off;
set feed on echo off termout on pages 24 verify on
ttitle off


-- #############################################################################################
--
-- %Purpose: Show Partition Indexes (DBA_IND_COLUMNS, DBA_INDEXES)
--
-- Use: Needs Oracle DBA Access
--
-- #############################################################################################
--
set feed off;
set pagesize 100000;
set wrap off;
set linesize 200;
set heading on;
set tab on;
set scan on;
set verify off;

spool show_part_indexes.lst
set pause off

column index_name format a25 wrap heading 'Index|Name'
column uni format a5 heading 'Uniq-|ness'
column table_name noprint new_value tab
column column_name format a30 heading 'Column|Name'
column table_owner format a10 heading 'Table|Owner'

ttitle left 'Partitioned Indexes of Table: 'tab skip 2

break on table_name skip page -
on table_owner skip 2 -
on index_name skip

select i.table_owner,
i.index_name,
c.table_name,
c.column_name,
decode(i.uniqueness,'UNIQUE','YES','NONUNIQUE','NO','???') uni
from dba_ind_columns c, dba_indexes i
where i.table_name = c.table_name
and i.index_name = c.index_name
and i.table_name like upper('%')
and i.table_owner = c.table_owner
and i.partitioned = 'YES'
order by i.table_owner,
c.table_name,
i.uniqueness desc,
c.index_name,
c.column_position;
spool off;
set feed on echo off termout on pages 24 verify on;
ttitle off;
-- #############################################################################################
--
-- %Purpose: Show Partition Tables and Indexes (DBA_TAB_PARTITIONS)
--
-- Use: Needs Oracle DBA Access
--
-- #############################################################################################
--
set feed off;
set pagesize 100000;
set wrap off;
set linesize 200;
set heading on;
set tab on;
set scan on;
set verify off;
--
ttitle left 'Show Partition Tables' -
skip 2

set linesize 200
set pagesize 500
column table_name format a20 heading "Table|Name"
column index_name format a20 heading "Index|Name"
column partition_name format a20 heading "Partition|Name"
column tablespace_name format a10 heading "Tablespace"
column partition_position format 999999 heading "Partition|Position"

break on table_name;

spool show_partition_tables.lst

select table_name,
partition_name,
partition_position,
tablespace_name
from dba_tab_partitions
order by table_name,partition_position;

break on index_name;

select index_name,
partition_name,
partition_position,
tablespace_name
from dba_ind_partitions
order by index_name,partition_position;

spool off
set feed on echo off termout on pages 24 verify on;
ttitle off;
-- #############################################################################################
--
-- %Purpose: Show Primary and Foreign Key Relationsships
--
-- Use: Needs Oracle DBA Access
--
-- #############################################################################################
--
spool show_fk_pk_relations.lst
set feed off
set pagesize 10000
ttitle off
--
ttitle left 'Primary and Foreign Key Relationsships' skip 2
set feed off
set pagesize 10000
--
column datum new_value datum noprint
column for_owner format A5 heading 'Table|Owner'
column pri_tsname format A10 heading 'Tablespace'
column for_table format A17 heading 'From|Foreign|Table'
column for_col format A16 heading 'From|Foreign|Column'
column pri_table format A17 heading 'To|Primary|Table'
column pri_col format A16 heading 'To|Primary|Column'
break on for_owner skip 1

select a.owner for_owner,
e.tablespace_name pri_tsname,
a.table_name for_table,
c.column_name for_col,
b.table_name pri_table,
d.column_name pri_col
from dba_constraints a,
dba_constraints b,
dba_cons_columns c,
dba_cons_columns d,
dba_tables e
where a.owner not in ('SYS','SYSTEM')
and a.r_constraint_name = b.constraint_name
and a.constraint_type = 'R'
and b.constraint_type = 'P'
and a.r_owner = b.owner
and a.constraint_name = c.constraint_name
and a.owner = c.owner
and a.table_name = c.table_name
and b.constraint_name = d.constraint_name
and b.owner = d.owner
and b.table_name = d.table_name
and b.table_name = e.table_name
order by a.owner,a.table_name;
-- #############################################################################################
--
-- %Purpose: Show Procedures of a Schema Owner
--
-- #############################################################################################
--
ACCEPT user_namen CHAR PROMPT 'Schema Owner: '

set feed off;
set pagesize 10000;
set wrap off;
set linesize 200;
set heading on;
set tab on;
set scan on;
set verify off;
--
spool show_procedures.lst
ttitle off
column datum new_value datum noprint
column owner format A20 heading 'Procedure|Owner'
column name format A20 heading 'Procedure|Name'
column type format A20 heading 'Procedure|Type'

ttitle left 'Defined Procedures, Functions, Packages'skip 2

select distinct to_char(sysdate, 'MM/DD/YY') datum,
substr(owner,1,12) owner,
substr(name,1,27) name,
substr(type,1,27) type
from dba_source
where owner LIKE UPPER('&user_namen')
order by 1,2,3,4;
spool off;
-- #############################################################################################
--
-- %Purpose: Show Redo Allocation Hits in % (Redolog Tuning)
--
-- Redo Allocation Tuning
--
-- Das Diagramm «Redo Allocation Hit %» zeigt das Buffer Tuning der Redolog
-- File Aktivitäten. Die Misses dürfen nicht grösser als 1 % sein.
--
-- Das Diagramm «Redo Statistics» zeigt die Anzahl Redo Entries, Space
-- Requests und Synch. Writes pro Sekunde für die Datenbank Instance.
--
-- #############################################################################################
--
set feed off;
set pagesize 10000;
set wrap off;
set linesize 200;
set heading on;
set tab on;
set scan on;
set verify off;
--
ttitle left 'Redo Alloc Hit%' -
skip 2

select ((gets+immediate_gets) /
(gets+immediate_gets+misses+immediate_misses)) *100 "Redo Alloc Hit%"
from v$latch
where name = 'redo allocation';

ttitle left 'Redo Statistics' -
skip 2

select sum(decode(name,'redo entries', value,0)) "Redo Entries",
sum(decode(name,'redo log space requests', value,0)) "Space Requests",
sum(decode(name,'redo synch writes', value,0)) "Synch Writes"
from v$sysstat;
-- #############################################################################################
--
-- %Purpose: Show Redo Waits ('redo log space wait time', 'redo log space requests')
--
-- #############################################################################################
--
col name format a30 justify l heading 'Redo Log Buffer'
col value format 99,999,990 justify c heading 'Waits'
SELECT name,
value
FROM v$sysstat
WHERE name IN ('redo log space wait time','redo log space requests')
/
-- #############################################################################################
--
-- %Purpose: Show Roles granted to Users and Roles
--
-- #############################################################################################
--
spool show_roles.lst
--
ttitle left 'Display Roles granted to Users and Roles' -
skip 2
set feed off
set pagesize 10000
break on grantee skip 1
column datum new_value datum noprint
column grantee format A27 heading 'User or Role|receiving the Grant'
column granted_role format A30 heading 'Granted|Role'
column default_role format A10 heading 'Default|Role'
column admin_option format A10 heading 'Admin|Option'

select to_char(sysdate, 'MM/DD/YY') datum,
substr(grantee,1,27) grantee,
substr(granted_role,1,30) granted_role,
substr(default_role,1,20) default_role,
substr(admin_option,1,10) admin_option
from dba_role_privs
where grantee not in ('SYS','SYSTEM')
order by 1,2,3;
-- #############################################################################################
--
-- %Purpose: Show Rollback Segment Report Usage (Nowait Hit %, Waits, Shrinks)
--
-- #############################################################################################
--
-- Rollback Nowait Hit % zeigt die Hits und Misses für die Online Rollback
-- Segmente. Ist dieser Wert zu gross, so müssen mehr Rollbacksegmente
-- erstellt werden.
--
-- Rollback Segment Waits
--
-- Rollback Segment Waits können einfach aus v$waitstat gelesen werden.

-- Waits auf «undo header» werden häufig verringert, indem man weitere
-- Rollback Segmente erstellt.
-- Waits auf «undo block» werden verringert, indem man Rollback Segmente
-- mit mehr Extents erstellt (10 - 20 Extents).
--
-- Rollback Segments Shrinks
--
-- Rollbacksegmente sollten nicht dauernd wachsen und wieder kleiner werden,
-- um den OPTIMAL Parameter einzuhalten. Dies kann mit dem folgenden Query
-- kontrolliert werden. EXTENTS und SHRINKS sollten keine auftreten, sonst
-- muss der Parameter OPTIMAL angepasst werden.
--
-- #############################################################################################
--
set feed off;
set pagesize 10000;
set wrap off;
set linesize 200;
set heading on;
set tab on;
set scan on;
set verify off;
--
ttitle left 'Rollback Nowait Hit %' -
skip 2

select ((sum(gets)-sum(waits)) / sum(gets)) * 100 "Rollback Nowait Hit %"
from v$rollstat;

ttitle left 'Rollback Segment Waits' -
skip 2

SELECT * from v$waitstat;

ttitle left 'Rollback Segments Shrinks' -
skip 2

SELECT substr(name,1,5) "Name", extents,
gets, waits, extends, shrinks
FROM v$rollstat stat, v$rollname name
WHERE stat.usn = name.usn
AND status = 'ONLINE';
-- #############################################################################################
--
-- %Purpose: Show SQL-Code of CPU-Intensive Oracle Prozesses in the Memory
--
-- #############################################################################################
--
-- Tuning an application involves tuning the SQL statements that are poorly
-- designed. While tuning applications, it is important for a DBA to find out which
-- SQL statements are consuming a large amount of CPU resources.
-- After tracking down these statements, the DBA can tune them to consume a less
-- CPU, improving response timings considerably. The script will work only on UNIX
-- operating systems.
--
-- It displays the top 10 CPU-intensive Oracle processes on the
-- operating system with the first column giving the %CPU used, the second column
-- unix PID, the third column USER , the fourth column TERMINAL, and the last
-- column Unix PROCESS. Enter the Unix PID at the prompt and it will display the
-- statement belonging to that process.
--
-- ps -eaf -o pcpu,pid,user,tty,comm | grep ora | grep -v \/sh | grep -v ora_ | sort -r | head -20
--
-- #############################################################################
--
column username format a10
column terminal format a9
column sql_text format a30
prompt
prompt
prompt
prompt Enter The UNIX PID :
accept PID
--
SELECT a.username, a.terminal, a.program, b.sql_text
FROM v$session a, v$sqlarea b, v$process c
WHERE (c.spid = '&PID' OR a.process = '&PID')
AND a.paddr = c.addr
AND a.sql_address = b.address
/
-- #############################################################################################
--
-- %Purpose: Show SQL-Statements in Memory for the connected Sessions (Shared Cursors)
--
-- #############################################################################################
--
-- Das Diagramm «SQL Area» zeigt die shared Cusor Informationen
-- im Library Cache.
--
-- #############################################################################################
--
set feed off;
set pagesize 10000;
set wrap off;
set linesize 200;
set heading on;
set tab on;
set scan on;
set verify off;
--
column username format a12 heading 'User'
ttitle left 'SQL of connected sessions' -
skip 2

select distinct nvl(username,type) username,sid,sql_text
from v$session, v$sqlarea
where sql_hash_value = hash_value
and sql_text is not null
order by username;
-- #############################################################################################
--
-- %Purpose: Show SQL-Statements in Memory with I/O-intensiv SQL-Statements (V$SQLAREA)
--
-- #############################################################################################
--
-- Output from V$SQLAREA:
--
-- EXECUTIONS: The number of executions that took place on this object
-- since iw was brought into the library cache.
--
-- READS_PER_RUN: Number od Disk-Bytes reads per execution, If this is high, then
-- the statement is I/O bound.
--
-- I/O-intensive SQL-Statements in the memory (V$SQLAREA)
--
-- Total Read-Per-Run Disk-Reads Buffer-Gets Hit
-- SQL-Statement Runs [Number of] [Number of] [Number of] Ratio [%]
-- ------------------------------- -------- -------------- ------------ ------------ ---------
-- DECLARE job BINARY_INTEGER := : 1 204,670.0 204,670 47,982 ###
-- DECLARE job BINARY_INTEGER := 1 77,858.0 77,858 181,282 57
-- select msisdn, function, modif 1 12,087.0 12,087 25,602 53
-- select msisdn, function, modif 1 12,031.0 12,031 25,599 53
-- select msisdn, function, modifi 1 11,825.0 11,825 25,598 54
-- select "A".rowid, 'PPB', 'FRAG 1 11,538.0 11,538 11,542 0
-- select msisdn.ms_id ,to_char(msi 270 3,259.1 879,953 3,939,464 78
-- select msisdn.ms_id from msis 270 3,258.0 879,656 3,939,723 78
--
-- The last two statements are quit heavy, they runs 270 times, each time they needed 3000
-- disk reads, total used 870000 disk reads
--
-- #############################################################################################
--
set feed off;
set pagesize 10000;
set wrap off;
set linesize 200;
set heading on;
set tab on;
set scan on;
set verify off;
--
column sql_text format a40 heading 'SQL-Statement'
column executions format 999,999 heading 'Total|Runs'
column reads_per_run format 999,999,999.9 heading 'Read-Per-Run|[Number of]'
column disk_reads format 999,999,999 heading 'Disk-Reads|[Number of]'
column buffer_gets format 999,999,999 heading 'Buffer-Gets|[Number of]'
column hit_ratio format 99 heading 'Hit|Ratio [%]'

ttitle left 'I/O-intensive SQL-Statements in the memory (V$SQLAREA)' -
skip 2

SELECT sql_text, executions,
round(disk_reads / executions, 2) reads_per_run,
disk_reads, buffer_gets,
round((buffer_gets - disk_reads) / buffer_gets, 2)*100 hit_ratio
FROM v$sqlarea
WHERE executions > 0
AND buffer_gets > 0
AND (buffer_gets - disk_reads) / buffer_gets < 0.80
ORDER BY 3 desc;
-- #############################################################################################
--
-- %Purpose: Shared Pool Minimium Size Calculator
--
-- Oracle Server - Enterprise Edition 8.1.X - 10.1.X
--
-- Use: Needs Oracle DBA Access
--
-- This script provides the following items: Current Shared Pool Size, Sum
-- of Shared Pool Objects, Sum of SQL Size, Sum of User Size and the Minumum
-- suggested Shared Pool Size for this Instance.
--
-- FYI: If the SHARED_POOL has been flushed recently, the
-- ==== "Minimum Suggested Shared Pool Size" may not be calculated properly.
--
-- #############################################################################################
--
spool minshpool.lst

set numwidth 15
column shared_pool_size format 999,999,999
column sum_obj_size format 999,999,999
column sum_sql_size format 999,999,999
column sum_user_size format 999,999,999
column min_shared_pool format 999,999,999
select to_number(value) shared_pool_size,
sum_obj_size,
sum_sql_size,
sum_user_size,
(sum_obj_size + sum_sql_size+sum_user_size)* 1.3 min_shared_pool
from (select sum(sharable_mem) sum_obj_size
from v$db_object_cache where type <> 'CURSOR'),
(select sum(sharable_mem) sum_sql_size
from v$sqlarea),
(select sum(250 * users_opening) sum_user_size
from v$sqlarea), v$parameter
where name = 'shared_pool_size'
/
spool off-- #############################################################################################
--
-- %Purpose: Show SYSTEM Privileges of Oracle-Roles and DB-User
--
-- #############################################################################################
--
ttitle left 'Output generated by: ' sql.user ' at: ' format a8 datum -
skip -
skip -
left 'System Privileges on Users and Roles' -
skip -
left 'Oracle Version ' format a15 sql.release -
skip 2
set feed off
set pagesize 10000
break on grantee skip 1
column datum new_value datum noprint
column grantee format A27 heading 'User or Role|receiving the Grant'
column privilege format A40 heading 'System|Privilege'
column admin_option format A10 heading 'Admin|Option'

select to_char(sysdate, 'MM/DD/YY') datum,
substr(grantee,1,27) grantee,
substr(privilege,1,40) privilege,
substr(admin_option,1,10) admin_option
from dba_sys_privs
order by 1,2,3;
-- #############################################################################################
--
-- %Purpose: Show Segments with critical Number of Extents, soon reaching MAX_EXTENTS
--
-- #############################################################################################
--
clear columns -
breaks -
computes
set pagesize 100

column owner format a15
column segment_name format a20
column segment_type format a20

SELECT owner,segment_name,segment_type,extents,max_extents
FROM dba_segments
WHERE max_extents <= 10*(extents)
AND max_extents != 0;

column owner clear
column segment_name clear
column segment_type clear
-- #############################################################################################
--
-- %Purpose: Show Sequences for Schema Owner
--
-- #############################################################################################
--
ACCEPT user_namen CHAR PROMPT 'Schema Owner: '

set feed off;
set pagesize 10000;
set wrap off;
set linesize 200;
set heading on;
set tab on;
set scan on;
set verify off;
--
spool show_sequences.lst
ttitle off

column datum new_value datum noprint
column sequence_owner format A20 heading 'Sequence|Owner'
column sequence_name noprint new_value sequence
column min_value format 99 heading 'Minimal|Value '
column max_value format 9.999EEEE heading 'Maximal |Value '
column increment_by format 99 heading 'Incr|By '
column last_number format 9999999 heading 'Last |Number '
column cache_size format 9999 heading 'Cache|Size '
column order_flag format a7 heading 'Order ?'
column cycle_flag format a7 heading 'Cycle ?'

ttitle left 'Properties for Sequence: 'sequence skip 2

break on sequence_name skip page -
on sequence_owner skip 2 -

select to_char(sysdate, 'MM/DD/YY') datum,
substr(sequence_owner,1,12) sequence_owner,
substr(sequence_name,1,27) sequence_name,
min_value,
max_value,
increment_by,
last_number,
cache_size,
decode(order_flag,
'Y','Yes',
'N','No') order_flag,
decode(cycle_flag,
'Y','Yes',
'N','No') cycle_flag
from dba_sequences
where sequence_owner LIKE UPPER('&user_namen')
order by 1,2,3,4;
spool off;
-- #############################################################################################
--
-- %Purpose: Show Session Statistic (Users Logged-On, Users Waiting, Users Waiting-for-Locks)
--
-- #############################################################################################
--
-- Das Diagramm «No. of Users Logged On» zeigt die Anzahl concurrent
-- Users Sessions, unabhänig davon ob sie nun aktiv sind oder nicht.
--
-- Das Diagramm «No. of Users Running» zeigt die Users Sessions,
-- welche eine Transaktion ausführen.
--
-- Das Diagramm «No. of Users Waiting» zeigt die User Sessions, die
-- auf einen Event (for whatever reason) warten müssen, um eine Aktion durchzuführen.
--
-- Das Diagramm «No. of Users Waiting for Lock» zeigt die User Sessions,
-- die auf die Freigabe eines Locks warten müssen.
--
-- #############################################################################################
--
set feed off;
set pagesize 10000;
set wrap off;
set linesize 200;
set heading on;
set tab on;
set scan on;
set verify off;
ttitle off;
--
select sessions_current "Users logged on"
from v$license;
--
select count(*) "Users running"
from v$session_wait
where wait_time!=0;
--
ttitle left 'Users waiting' -
skip 2

select substr(w.sid,1,5) "Sid",
substr(s.username,1,15) "User",
substr(event,1,40) "Event",
seconds_in_wait "Wait [s]"
from v$session_wait w, v$session s
where s.sid = w.sid
and state = 'WAITING'
and event not like 'SQL*Net%'
and event != 'client message'
and event not like '%mon timer'
and event != 'rdbms ipc message'
and event != 'Null Event';
--
select count(*) "Users waiting for locks"
from v$session
where lockwait is not null;
-- #############################################################################################
--
-- %Purpose: Show Sessions with bad Buffer Cache Hit Ratio in %
--
-- #############################################################################################
--
set feed off;
set pagesize 10000;
set wrap off;
set linesize 200;
set heading on;
set tab on;
set scan on;
set verify off;
--
ttitle left 'Show Sessions with bad Buffer Cache Hit Ratio in %' -
skip 2
--
select substr(a.username,1,12) "User",
a.sid "sid",
b.consistent_gets "ConsGets",
b.block_gets "BlockGets",
b.physical_reads "PhysReads",
100 * round((b.consistent_gets + b.block_gets - b.physical_reads) /
(b.consistent_gets + b.block_gets),3) HitRatio
from v$session a, v$sess_io b
where a.sid = b.sid
and (b.consistent_gets + b.block_gets) > 0
and a.username is not null
order by HitRatio asc;
-- #############################################################################################
--
-- %Purpose: Show Size of each Object itself (without content) in the Database
--
-- Show size of each object in the database. Note
-- that NOT the size including the rows will be
-- shown for tables, but the size for the table itself.
--
-- #############################################################################################
--
set feed off;
set pagesize 10000;
set wrap off;
set linesize 200;
set heading on;
set tab on;
set scan on;
set verify off;
spool show_obyect_size.lst
ttitle off;

column owner format a8 heading 'Object|Owner'
column name format a30 heading 'Name'
column type format a13 heading 'Type'
column source_size format 99999999 heading 'Source|Size'
column parsed_size format 99999999 heading 'Parsed|Size'
column code_size format 99999999 heading 'Code|Size'
column error_size format 99999999 heading 'Error|Size'

SELECT owner, name, type, source_size, parsed_size, code_size, error_size
FROM my_object_size
WHERE owner NOT IN ('SYS','SYSTEM','PUBLIC')
ORDER BY owner,type
/
spool off;
-- #############################################################################################
--
-- %Purpose: Show Startup Time of the Oracle Instance (Different for Ora7 and Ora8: V$INSTANCE)
--
-- #############################################################################################
--
-- Instance Startup-Time for Oracle-7
--
SELECT TO_CHAR(TO_DATE(D.Value,'J'),'DD.MM.YYYY')||' '||
TO_CHAR(TO_DATE(S.Value,'SSSSS'),'HH24:MI:SS')
Startup_Time
FROM V$INSTANCE D, V$INSTANCE S
WHERE D.Key = 'STARTUP TIME - JULIAN'
AND S.Key = 'STARTUP TIME - SECONDS';
--
-- Instance Startup-Time for Oracle-8
--
SELECT TO_CHAR(startup_time,'DD.MM.YYYY:HH24:MI:SS') Startup_Time
FROM v$instance;
-- #############################################################################################
--
-- %Purpose: Show Statistics of connected Sessions (PID, Connection-Type, Username, Logon-Time)
--
-- #############################################################################################
--
col osuser format a10 trunc heading "OSUSER AS"
col orauser format a10 trunc
col machine format a10 trunc
col sprogram format a15 trunc
col process format a20 trunc
col server format a3 trunc
col sess_id format 9999
col proc_id format a7
--
SELECT s.osuser osuser,
s.username orauser,
s.machine machine,
s.program sprogram,
p.program process,
s.sid sess_id,
p.spid proc_id,
s.logon_time,
s.server server
FROM v$session s,
v$process p
WHERE s.paddr = p.addr
AND type != 'BACKGROUND'
AND p.username is not null
ORDER BY 6
/
col osuser clear
col machine clear
col orauser clear
ttitle off
-- #############################################################################################
--
-- %Purpose: Show Status for all Objects (VALID, INVALID) of a Schema Owner
--
-- Show object of a user or wildcard incl. status
-- (choice valid or invalid (default both)
--
-- #############################################################################################
--
col user_name noprint new_value user_name
col date_time noprint new_value date_time
col owner format a13 trunc
col object_name format a30
col object_type format a8 trunc heading OBJ-TYPE
col status format a7
col last_ddl_time format a17
prompt
prompt User name, wildcard or for all users:
prompt Object name, wildcard or for all objects:
prompt V = valid, I = invalid, = valid and invalid:
prompt
accept user_name char prompt "User name: "
accept object_name char prompt "Object name: "
accept status char prompt "Status: "
set echo off termout off pause off
select upper(nvl('&&user_name','%')) user_name,
to_char(sysdate,'dd.mm.yyyy hh24:mi') date_time
from dual;
set termout on;
set feed on;
set pagesize 10000;
set wrap off;
set linesize 200;
set tab on;
set verify off
set timing off
ttitle left 'Objects of user 'user_name' at 'date_time -
right sql.pno skip 2
spool show_object_status.lst
select owner, object_name,
decode(object_type,'PACKAGE','PCK-SPEZ',
'PACKAGE BODY','PCK-BODY',
'DATABASE LINK','DB-LINK',
object_type) object_type,
status, to_char(last_ddl_time,'dd.mm.yy hh24:mi:ss') last_ddl_time
from sys.dba_objects
where owner like nvl(upper('&user_name'),'%')
and object_name like nvl(upper('&object_name'),'%')
and status like decode(upper(substr('&status',1,1)),
'V', 'VALID',
'I','INVALID',
'%')
order by owner, object_name, object_type
/
spool off
prompt
prompt show_object_status.lst has been spooled
prompt
-- #############################################################################################
--
-- %Purpose: Show Synonyms for all Schmea Owners
--
-- #############################################################################################
--
set feed off;
set pagesize 10000;
set wrap off;
set linesize 200;
set heading on;
set tab on;
set scan on;
set verify off;
--
spool show_synonyms.lst
break on table_owner skip 1
column datum new_value datum noprint
column owner format A12 heading 'Synonym|Owner'
column table_owner format A12 heading 'Table|Owner'
column table_name format A26 heading 'Table|Name'
column synonym_name format A26 heading 'Synonym|Name'

select to_char(sysdate, 'MM/DD/YY') datum,
substr(table_owner,1,12) table_owner,
substr(table_name,1,26) table_name,
substr(synonym_name,1,26) synonym_name,
substr(owner,1,12) owner
from dba_synonyms
where table_owner not in ('SYS','SYSTEM','DBSNMP');
order by 1,2,3,4;
spool off;
-- #############################################################################################
--
-- %Purpose: Show Table Grants for all Schema Owners
--
-- Use: Each Oracle User
--
-- #############################################################################################
--
spool show_column_grants.lst
ttitle left 'Show grants on table columns' skip 2
set feed off
set pagesize 10000

column owner noprint new_value own
column table_name format A20 heading 'Object|Name' trunc
column column_name format A20 heading 'Column|Name' trunc
column privilege format A9 heading 'Privilege' trunc
column grantee format A17 heading 'User/Role to whom|Access is granted' trunc
column grantor format A10 heading 'User who|made Grant' trunc

ttitle center 'Object Owner: 'own skip 2

break on owner skip page on grantee on grantor skip 1

select owner,
grantee,
grantor,
table_name,
column_name,
privilege
from dba_col_privs
order by owner, grantee, grantor, table_name
/
spool off;
-- #############################################################################################
--
-- %Purpose: Show Table Structure (Column-Name, Datentyp, etc) for all Schema-Owners
--
-- #############################################################################################
--
spool show_table_columns.lst
set feed off
set pagesize 10000
ttitle off
--
column table_name noprint new_value tab
column owner format a10 heading 'Table|Owner'
column column_name format a30 heading 'Column|Name'
column data_type format a9 heading 'Data|Type'
column nullable format a8 heading 'Nulls ?'
column data_length format a14 heading 'Maximum Data|Length [Bytes]'
column data_precision format a9 heading 'Data|Precision'
column data_scale format a5 heading 'Data|Scale'
--
ttitle center 'Columns of Table: 'tab skip 2
--
break on table_name skip page -
on owner skip 2 -
--
select owner,
table_name,
column_name,
data_type,
to_char(data_length) data_length,
to_char(data_precision) data_precision,
to_char(data_scale) data_scale,
decode(nullable,'Y','','N','NOT NULL') nullable
from dba_tab_columns
where table_name like upper('%')
and upper(owner) not in ('SYSTEM','SYS','DBSNMP')
order by owner,
table_name,
column_name;
--
spool off;
-- #############################################################################################
--
-- %Purpose: Show Table Structure (Column-Name, Datentyp, etc) for all Schema-Owners
--
-- #############################################################################################
--
spool show_table_columns.lst
set feed off
set pagesize 10000
ttitle off
--
column table_name noprint new_value tab
column owner format a10 heading 'Table|Owner'
column column_name format a30 heading 'Column|Name'
column data_type format a9 heading 'Data|Type'
column nullable format a8 heading 'Nulls ?'
column data_length format a14 heading 'Maximum Data|Length [Bytes]'
column data_precision format a9 heading 'Data|Precision'
column data_scale format a5 heading 'Data|Scale'
--
ttitle center 'Columns of Table: 'tab skip 2
--
break on table_name skip page -
on owner skip 2 -
--
select owner,
table_name,
column_name,
data_type,
to_char(data_length) data_length,
to_char(data_precision) data_precision,
to_char(data_scale) data_scale,
decode(nullable,'Y','','N','NOT NULL') nullable
from dba_tab_columns
where table_name like upper('%')
and upper(owner) not in ('SYSTEM','SYS','DBSNMP')
order by owner,
table_name,
column_name;
--
spool off;
-- #############################################################################################
--
-- %Purpose: Show Table and Column Comments
--
-- Use: Needs Oracle DBA Access
--
-- #############################################################################################
--
set feed off;
set pagesize 10000;
set wrap off;
set linesize 200;
set heading on;
set tab on;
set scan on;
set verify off;

ttitle off;
column owner format a5 heading 'Table|Owner'
column t1 format a20 heading 'Table|Name'
column comments format A100 heading 'Comments'
ttitle left 'Table Comments' skip 2

ACCEPT user_namen CHAR PROMPT 'Enter Schema Owner: '

break on owner
spool show_tab_col_comments.lst

SELECT owner,table_name t1,comments
FROM dba_tab_comments
WHERE owner LIKE UPPER('&user_namen');

column t2 noprint new_value tab
column column_name format a20 heading 'Column|Name'
ttitle off;
clear break;

ttitle left 'Column Comments on Tabelle: 'tab skip 2

break on t2 skip page -
on owner skip 2 -

SELECT owner,table_name t2,column_name,comments
FROM dba_col_comments
WHERE owner LIKE UPPER('&user_namen');

spool off;
set feed on echo off termout on pages 24 verify on;
ttitle off;
-- #############################################################################################
--
-- %Purpose: Show Tablespace Status Information
--
-- #############################################################################################
--
ttitle left 'Output generated by: ' sql.user ' at: ' format a8 datum -
skip -
skip -
left 'Tablespace Status' -
skip -
left 'Oracle Version ' format a15 sql.release -
skip 2
set feed off
set pagesize 10000
column datum new_value datum noprint
column tablespace_name format A64 heading 'Tablespace'
column status format a15 heading "Status"

select to_char(sysdate, 'MM/DD/YY') datum,
tablespace_name,
status
from sys.dba_tablespaces;
-- #############################################################################################
--
-- %Purpose: Show Users with High CPU Processing since Instance Startup
--
-- #############################################################################################
--
set feed off;
set pagesize 10000;
set wrap off;
set linesize 80;
set heading on;
set tab on;
set scan on;
set verify off;
--
spool show_users_with_high_cpu_processing.lst

ttitle 'Show Users with High CPU Processing' -
skip 2

column user_process format a10 heading "UserProcess(SID)"
column value format 999,999,999.99

select ss.username||'('||se.sid||')' user_process, value
from v$session ss, v$sesstat se, v$statname sn
where se.statistic# = sn.statistic#
and name like '%CPU used by this session%'
and se.sid = ss.sid
and ss.username is not null
order by substr(name,1,25), value desc
/
spool off;
set feed on echo off termout on pages 24 verify on
ttitle off


-- #############################################################################################
--
-- %Purpose: Show Views for Schmea-Owner
--
-- #############################################################################################
--
spool show_views.lst
ttitle left 'All Database Views' skip 2
set feed off
set pagesize 30000
set linesize 200
break on owner skip 1
column owner format A5 heading 'View|Owner'
column view_name format A20 heading 'View|Name'
column text_length format 9999999 heading 'View-Length|[Bytes]'

select substr(owner,1,5) owner,
substr(view_name,1,60) view_name,
text_length
from dba_views
where owner not in ('SYS','DBSNMP','SYSTEM')
order by 1,2,3;
spool off;
-- #############################################################################################
--
-- %Purpose: Show all INVALD Objects in the Database for all Users except SYS and SYSTEM
--
-- Use: SYSTEM, SYS or user having SELECT ANY TABLE system privilege
--
-- #############################################################################################
--
set verify off
set pagesize 200
set feedback off
column owner format A15
column object_name format A30 heading 'Object'
column object_id format 999999 heading "Id#"
column object_type format A15
column status format A8
ttitle left 'Invalid Objects found for ...'skip 2
--
-- Lists all invalid objects for a database
--
spool list_invalid_objects.lst
set termout off
--
SELECT owner, object_name, object_id, object_type, status
FROM dba_objects
WHERE status != 'VALID'
AND owner NOT IN ('SYS','SYSTEM');
--
spool off
--
-- Create script which can be used to recompile
-- all of the invalid objects
--
ttitle off
set concat +
spool compile_invalid_objects.sql
set concat .
set feedback off
set heading off
set pagesize 999
set verify off

SELECT DISTINCT 'sqlplus '||owner||'/'||owner||'<'prompt Compiling '||owner||' objects...'||chr(10)||
'execute dbms_utility.compile_schema('||chr(39)||owner||chr(39)||');'||
chr(10)||'show err;'||chr(10)||'quit'||chr(10)||'EOF'
FROM dba_objects
WHERE status != 'VALID'
AND object_type != 'VIEW'
AND owner NOT IN ('SYS','SYSTEM');

SELECT 'sqlplus '||owner||'/'||owner||'<'prompt Compiling '||owner||' views...'||chr(10)||
'alter view '||object_name||' compile;'||chr(10)||
'show errors view '||object_name||';'||chr(10)||'quit'||chr(10)||'EOF'
FROM dba_objects
WHERE status != 'VALID'
AND object_type = 'VIEW'
AND owner NOT IN ('SYS','SYSTEM');

spool off
set termout on

PROMPT
PROMPT list_invalid_objects.lst has been spooled
PROMPT compile_invalid_objects.sql has been spooled
PROMPT
-- #############################################################################################
--
-- %Purpose: Show all Privileges for a connected User through Roles and direct
--
-- Show all Privileges for a connected user over Roles and
-- direct. Show all System- and Object Privileges as well.
--
-- #############################################################################################
--
set feed off
set pagesize 30000
set linesize 200
clear breaks columns
set pause off
spool show_privileges_for_user.lis
--
ttitle left "Currently active Role(s) for User: " sql.user -
skip 2
column username format A22 heading 'User' trunc
column role format A40 heading 'Active|Role' trunc
column default_role format A7 heading 'Default|Role' trunc
column admin_option format A7 heading 'Admin|Option' trunc
--
break on username

select username,role,default_role,admin_option
from user_role_privs, session_roles
where granted_role = role
order by role
/
--
ttitle left "Currently inactive Role(s) for User: " sql.user -
skip 2
column username format A22 heading 'User' trunc
column granted_role format A40 heading 'Granted|Role' trunc
column default_role format A7 heading 'Default|Role' trunc
column admin_option format A7 heading 'Admin|Option' trunc

select username,granted_role,default_role,admin_option
from user_role_privs
where not exists (select 'x'
from session_roles
where role = granted_role)
union
select 'All Role(s) are active','','',''
from dual
where 0 = (select count('x')
from user_role_privs
where not exists (select 'x'
from session_roles
where role = granted_role))
order by 1,2
/
--
ttitle left "Sub-Role(s) for User: " sql.user -
skip 2
column granted_role format A39 heading 'These Role(s) are granted to ...' trunc
column role format A39 heading '... these Role(s)'

select granted_role,role
from role_role_privs
union
select 'No Sub-Role(s) found',''
from dual
where 0 = (select count('x')
from role_role_privs)
/
--
ttitle "System Privileges through Roles and direct for User: " sql.user -
skip 2
column role format A40 heading 'Role' trunc
column privilege format A30 heading 'System|Privilege' trunc
column admin_option format A7 heading 'Admin|Option' trunc
--
break on role skip 1

select role,privilege,admin_option
from role_sys_privs
union
select 'directly' role,privilege,admin_option
from user_sys_privs
order by 1,2
/
--
ttitle "Object Privileges through Roles and direct for User: " sql.user -
skip 2
column role format a20 heading 'Role' trunc
column owner format a17 heading 'Object|Owner' trunc
column table_name format a20 heading 'Object|Name' trunc
column privilege format a12 heading 'Privilege' trunc
column grantable format a6 heading 'Admin|Option' trunc
break on role on owner on table_name

select role, owner, table_name, privilege, grantable
from role_tab_privs
where role in (select role
from session_roles)
and column_name is null
union
select 'directly' role, owner, table_name, privilege, grantable
from user_tab_privs_recd
order by 1,2,3,4
/
--
ttitle "Column Privileges for User: " sql.user -
skip 2
column role format a16 heading 'Role' trunc
column owner format a10 heading 'Object|Owner' trunc
column table_name format a20 heading 'Object|Name' trunc
column column_name format a20 heading 'Column|Name' trunc
column privilege format a10 heading 'Privilege' trunc

select role, owner, table_name, column_name, privilege, grantable
from role_tab_privs
where role in (select role
from session_roles)
and column_name is not null
union
select 'directly' role, owner, table_name, column_name,
privilege, grantable
from user_col_privs_recd
order by 1,2,3,4
/
spool off
clear breaks columns
ttitle off
prompt
prompt Listing created in "showpriv.lis"
prompt
-- #############################################################################################
--
-- %Purpose: Show complete System Statistic, e.g. Full Table Scans, Redolog Infos from V$SYSSTAT
--
-- #############################################################################################
--
-- System Statistics
--
-- Das Diagramm «System Stats» zeigt alle Parameter der wichtigen System
-- Statistiktabelle v$sysstat.
--
-- Auswertung der System Statistik
--
-- Aus den Systemstatistiken können wichtige Informationen gewonnen werden.
-- Man beachte dass es sich bei diesen Angaben immer um kumulierte Werte seit
-- dem letzten Startup handelt.
--
-- Full Table Scans
--
-- table scan blocks gotten 61'900'307
-- table scan rows gotten 194'6840'695
-- table scans (long tables) 13'267
-- table scans (short tables) 307'195
--
-- Index Scans
--
-- table fetch by rowid 15'653'655
--
-- Redo Waits
--
-- redo log space requests 1018
-- redo log space wait time 21263
--
-- Bei grösseren Waits sind die RDO-Files zu vergrössern und er Parameter
-- LOG_BUFFER muss erhöht werden. Die Zeit ist in 1/100 Sekunden angegeben
-- (21263 = 212 Sekunden = 3,5 Minuten in etwa 5 Wochen).
--
-- #############################################################################################
--
set feed off;
set pagesize 10000;
set wrap off;
set linesize 200;
set heading on;
set tab on;
set scan on;
set verify off;
--
ttitle left 'System Statistics' -
skip 2

select s.name, s.value
from v$sysstat s
order by s.name, s.value;
-- #############################################################################################
--
-- %Purpose: Show all Schmea Objects (Tables,Synonyms,Views,Sequences,Indexes)
--
-- Use: Jeder Oracle User
--
-- #############################################################################################
--
spool show_all_objects.lst
set feed off
set pagesize 10000
ttitle off

column datum new_value datum noprint
column owner format A10 heading 'Owner'
column object_name format A38 heading 'Object-|Name'
column object_type format A10 heading 'Object-|Type'
column created format A10 heading 'Created'
column status format A8 heading 'Status'

ttitle left 'Show all Schema Objects (Tables,Synonyms,Views,Sequences,Indexes)' skip 2

break on owner skip 1 on object_type

select to_char(sysdate, 'MM/DD/YY') datum,
substr(owner,1,10) owner,
substr(object_type,1,10) object_type,
substr(object_name,1,38) object_name,
substr(created,1,11) created,
substr(status,1,8) status
from dba_objects
where substr(owner,1,10) not in ('SYS','SYSTEM','PUBLIC','DBSNMP')
order by 1,2,3,4;

spool off;
exit;
-- #############################################################################################
--
-- %Purpose: Show block chaining (chained rows) with ANALYZE TABLE LIST CHAINED ROWS
--
-- Use: Needs Oracle DBA Access
--
-- #############################################################################################
--
set echo off termout off
DROP TABLE lst_chained_rows$tmp;
set termout on
CREATE TABLE lst_chained_rows$tmp
(
owner_name VARCHAR2(30),
table_name VARCHAR2(30),
cluster_name VARCHAR2(30),
head_rowid ROWID,
timestamp DATE
);
--
accept user_namen char prompt 'Username or %: '
accept tabellen_namen char prompt 'Tablename or %: '
set feed off echo off termout off pages 0 verify off array 1
--
SPOOL list_chained_rows.sql
SELECT 'ANALYZE TABLE '||OWNER||'.'||TABLE_NAME,
'LIST CHAINED ROWS INTO lst_chained_rows$tmp;'
FROM sys.dba_tables
WHERE owner LIKE UPPER('&user_namen')
AND table_name LIKE UPPER('&tabellen_namen')
ORDER BY owner, table_name;
--
spool off
set feed on echo on termout on pages 66 verify on
@list_chained_rows.sql
--
set echo off
column table_name format a30
column owner_name format a16 trunc
--
spool list_chained_rows.lst
--
SELECT RPAD(owner_name,16,'.') owner_name,
RPAD(c.table_name,30,'.') table_name,
num_rows,
COUNT(*) ch_rows, pct_free
FROM sys.dba_tables t, lst_chained_rows$tmp c
WHERE t.owner = c.owner_name
AND t.table_name = c.table_name
GROUP BY owner_name, c.table_name, pct_free, num_rows
UNION
SELECT 'No block chaining',NULL,0,0,0
FROM dual
WHERE 0 = ( SELECT COUNT(*)
FROM lst_chained_rows$tmp
WHERE rownum = 1 )
ORDER BY 1,2;
spool off
set feed on echo off termout on pages 24 verify on
ttitle off
DROP TABLE lst_chained_rows$tmp;
-- #############################################################################################
--
-- %Purpose: Show columns that have the same name but different characteristics
--
-- This script lists columns that have the same name but
-- different characteristics. They may cause problems
-- when tables are joined on the columns or unexpected
-- results are returned.
--
-- #############################################################################################
--
accept user_namen char prompt 'Schemaowner or Wildcard : '
set feed off echo off termout on pages 5000 lines 500 verify off array 1
--
spool list_colnames_with_diff_length.lst
ttitle left 'Columns with Inconsistent Data Lengths' -
skip 2

SELECT SUBSTR(owner,1,10) "Owner",
column_name "ColName", table_name||' '||data_type||'('||
DECODE(data_type, 'NUMBER', data_precision, data_length)||')' "Characteristics"
FROM all_tab_columns
WHERE (column_name, owner)
IN (SELECT column_name, owner
FROM all_tab_columns
GROUP BY column_name, owner
HAVING MIN(DECODE(data_type, 'NUMBER', data_precision, data_length))
< max(decode(data_type, 'NUMBER', data_precision, data_length)))
AND owner LIKE UPPER('&user_namen');
spool off;
set feed on echo off termout on pages 24 verify on;
-- #############################################################################################
--
-- %Purpose: Show detailled Report of Library Cache Usage in the Shared Pool of the Instance
--
-- #############################################################################################
--
-- Das Diagramm «Library Cache Details» zeigt Detailinformationen
-- des Library Cache im Shared Pool der Instance. Der Library Cache
-- enthält SQL und PL/SQL Code in geparster Form. Es ist wichtig, dass
-- die Ratio für diese Bereiche nahezu 100% beträgt.
--
-- #############################################################################################
--
set feed off;
set pagesize 10000;
set wrap off;
set linesize 200;
set heading on;
set tab on;
set scan on;
set verify off;
--
ttitle left 'Library Cache Details' -
skip 2

select namespace,gets,gethits,
round(gethitratio*100) "RATIO%",
pins,pinhits,round(pinhitratio*100) "RATIO%"
from v$librarycache
order by namespace;
-- #############################################################################################
--
-- %Purpose: Show fragmented Objects (more than 3 Extents)
--
-- Use: Needs Oracle DBA Access
--
-- #############################################################################################
--
set feed off
set pagesize 5000
break on owner skip 1 on tablespace_name on segment_type
column datum new_value datum noprint
column owner format A10 heading 'Owner'
column tablespace_name format A20 heading 'Tablespace'
column segment_type format A10 heading 'Segment-|Type'
column segment_name format A30 heading 'Segment-|Name'
column extent_id format 999 heading 'Number of|Extents'
column bytes format 999,999,999,999 heading 'Size|[Bytes]'
--
-- Looking for fragmented objects
--
select to_char(sysdate, 'MM/DD/YY') datum,
owner,
tablespace_name,
segment_type,
segment_name,
count(extent_id) extent_id,
sum(bytes) bytes
from sys.dba_extents
where substr(owner,1,10) not in ('SYS')
group by
owner,
tablespace_name,
segment_type,
segment_name
having count(extent_id) > 3
order by 1,2,3,4;
-- #############################################################################################
--
-- %Purpose: Show free Space in all Datafiles and if AUTOEXTENT is ON
--
-- #############################################################################################
--
clear columns -
breaks -
computes
set pagesize 100

column file_name format a32
column tablespace_name format a15
column status format a3 trunc
column t format 999,999.000 heading "Total MB"
column a format a4 heading "Aext"
column p format 990.00 heading "% Free"

SELECT df.file_name,
df.tablespace_name,
df. status,
(df.bytes/1024000) t,
(fs.s/df.bytes*100) p,
decode (ae.y,1,'YES','NO') a
FROM dba_data_files df,
(SELECT file_id,SUM(bytes) s
FROM dba_free_space
GROUP BY file_id) fs,
(SELECT file#, 1 y
FROM sys.filext$
GROUP BY file#) ae
WHERE df.file_id = fs.file_id
AND ae.file#(+) = df.file_id
ORDER BY df.tablespace_name, df.file_id;

column file_name clear
column tablespace_name clear
column status clear
column t clear
column a clear
column p clear
ttitle off
-- #############################################################################################
--
-- %Purpose: Show information about your current database account (who am I)
--
-- #############################################################################################
--
set termout off
set head off
set termout on

select 'User: '|| user || ' on database ' || global_name,
'(Terminal='||USERENV('TERMINAL')||
', Session-Id='||USERENV('SESSIONID')||')'
from global_name;

set head on feed on
-- #############################################################################################
--
-- %Purpose: Show installed Database Version and Options with Port specific infos
--
-- Use: Needs Oracle DBA Access
--
-- #############################################################################################
--
set feed off;
set pagesize 10000;
set wrap off;
set linesize 200;
set heading on;
set tab on;
set scan on;
set verify off;
set termout on;
set serveroutput on;

ttitle left 'Oracle Version:' skip 2

select banner
from sys.v$version;

ttitle left 'Installed Options:' skip 2

select parameter
from sys.v$option
where value = 'TRUE';

ttitle left 'Not Installed Options:' skip 2

select parameter
from sys.v$option
where value <> 'TRUE';

prompt
begin
dbms_output.put_line('Specific Port Information: '||dbms_utility.port_string);
end;
/
prompt

set head on feed on

-- #############################################################################################
--
-- %Purpose: Show last Checkpoints in the File Headers
--
-- #############################################################################################
--
ttitle left 'Output generated by: ' sql.user ' at: ' format a8 datum -
skip -
skip -
left 'Show last Checkpoints in the File Headers' -
skip -
left 'Oracle Version ' format a15 sql.release -
skip 2
set feed off
set pagesize 10000
set linesize 500
break on grantee skip 1
column datum new_value datum noprint
column file_nr format 999999 heading 'File#'
column checkpoint_time format A20 heading 'Checkpoint|Time'
column file_name format A59 heading 'Filename'

select FILE# file_nr,
to_char(CHECKPOINT_TIME,'DD.MM.YYYY:HH24:MI:SS') checkpoint_time,
name file_name
from v$datafile_header;
-- #############################################################################################
--
-- %Purpose: Show next sequence number from sequence (without to increment it with NEXTVAL)
--
-- Use: Needs SYS access
--
-- #############################################################################################
--
set feed off;
set pagesize 10000;
set wrap off;
set linesize 200;
set heading on;
set tab on;
set scan on;
set verify off;
--
spool show_nextval.lst
ttitle left 'Shows next sequence number without incrementing it' skip 2
--
accept sequence_owner char prompt "Sequence Owner <% for all>: " default %
accept sequence_name char prompt "Sequence Name <% for all>: " default %
--
col sequence_owner format a20 heading 'Sequence|Owner'
col sequence_name format a25 heading 'Sequence|Name'
col next_seq format 99999999 heading 'Next|Value'
col cache format a25 heading 'Cache'

select sequence_owner, sequence_name, next_seq, cache
from (select sequence_owner, sequence_name,
nextvalue next_seq, 'in cache' cache
from v$_sequences
where nextvalue is not null
union
select sequence_owner, sequence_name,
highwater next_seq, 'created nocache' cache
from v$_sequences
where nextvalue is null
union
select sequence_owner, sequence_name,
last_number next_seq, 'not in cache' cache
from dba_sequences s
where not exists (select sequence_owner, sequence_name
from v$_sequences v
where v.sequence_name = s.sequence_name
and v.sequence_owner = s.sequence_owner))
where sequence_owner like upper('&sequence_owner')
and sequence_name like upper('&sequence_name')
order by sequence_owner, sequence_name
/
undefine sequence_owner
undefine sequence_name
col sequence_owner clear
col sequence_name clear
set verify on
spool off

rem -------------------------------------------------------------------------
rem Shows actual DML-Locks (incl. Table-Name)
rem WAIT = YES are users waiting for a lock
rem -----------------------------------------------------------------------
rem
--
SET PAGES 24 LINES 80 FEED ON ECHO OFF TERMOUT ON HEAD ON
COLUMN PROGRAM FORMAT A80 TRUNC
COLUMN LOCKER FORMAT A10 TRUNC
COLUMN T_OWNER FORMAT A10 TRUNC
COLUMN OBJECT_NAME FORMAT A25 TRUNC
COLUMN WAIT FORMAT A4
TTITLE "Actual DML-Locks (TM+TX)"
--
select /*+ rule */
decode(L.REQUEST,0,'NO','YES') WAIT,
S.OSUSER,
S.PROCESS,
S.USERNAME LOCKER,
U.NAME T_OWNER,
O.NAME OBJECT_NAME,
' '||S.PROGRAM PROGRAM
from V$LOCK L,
V$SESSION S,
OBJ$ O,
USER$ U
where U.USER# = O.OWNER#
and S.SID = L.SID
and L.ID1 = O.OBJ#
and L.TYPE = 'TM'
union
select decode(L.REQUEST,0,'NO','YES') WAIT,
S.OSUSER,
S.PROCESS,
S.USERNAME LOCKER,
'-',
'Record(s)',
' '||S.PROGRAM PROGRAM
from V$LOCK L,
V$SESSION S
where S.SID = L.SID
and L.TYPE = 'TX'
order by 7,5,1,2,6
/
ttitle off
col program clear
col locker clear
col t_owner clear
col object_name clear
col wait clear
rem -------------------------------------------------------------------------
rem Show users waiting for a lock, the locker and the
rem SQL-Command they are waiting for a lock
rem osuser, schema and PIDs are shown
rem -----------------------------------------------------------------------
rem
--
SET PAGES 24 LINES 100 FEED ON ECHO OFF TERMOUT ON HEAD ON
COLUMN OS_LOCKER FORMAT A15 TRUNC
COLUMN OS_WAITER FORMAT A15 TRUNC
COLUMN LOCKER_SCHEMA FORMAT A15 TRUNC
COLUMN WAITER_SCHEMA FORMAT A15 TRUNC
COLUMN WAITER_PID FORMAT A10
COLUMN LOCKER_PID FORMAT A10
COLUMN SQL_TEXT_WAITER FORMAT A100 WRAP
COLUMN DATABASE NOPRINT NEW_VALUE DATABASE
COLUMN DATUM_ZEIT NOPRINT NEW_VALUE DATUM_ZEIT
SET TERMOUT OFF ECHO OFF FEED OFF
SET TERMOUT ON
TTITLE CENTER 'Current Lock-Waits' SKIP 2
--
select /*+ ordered
no_merge(L_WAITER)
no_merge(L_LOCKER) use_hash(L_LOCKER)
no_merge(S_WAITER) use_hash(S_WAITER)
no_merge(S_LOCKER) use_hash(S_LOCKER)
use_nl(O)
use_nl(U)
*/
/* first the table-level locks (TM) and mixed TM/TX TX/TM */
S_LOCKER.OSUSER OS_LOCKER,
S_LOCKER.USERNAME LOCKER_SCHEMA,
S_LOCKER.PROCESS LOCKER_PID,
S_WAITER.OSUSER OS_WAITER,
S_WAITER.USERNAME WAITER_SCHEMA,
S_WAITER.PROCESS WAITER_PID,
'Table lock (TM): '||U.NAME||'.'||O.NAME||
' - Mode held: '||
decode(L_LOCKER.LMODE,
0, 'None', /* same as Monitor */
1, 'Null', /* N */
2, 'Row-S (SS)', /* L */
3, 'Row-X (SX)', /* R */
4, 'Share', /* S */
5, 'S/Row-X (SSX)', /* C */
6, 'Exclusive', /* X */
'???: '||to_char(L_LOCKER.LMODE))||
' / Mode requested: '||
decode(L_WAITER.REQUEST,
0, 'None', /* same as Monitor */
1, 'Null', /* N */
2, 'Row-S (SS)', /* L */
3, 'Row-X (SX)', /* R */
4, 'Share', /* S */
5, 'S/Row-X (SSX)', /* C */
6, 'Exclusive', /* X */
'???: '||to_char(L_WAITER.REQUEST))
SQL_TEXT_WAITER
from
V$LOCK L_WAITER,
V$LOCK L_LOCKER,
V$SESSION S_WAITER,
V$SESSION S_LOCKER,
OBJ$ O,
USER$ U
where S_WAITER.SID = L_WAITER.SID
and L_WAITER.TYPE IN ('TM')
and S_LOCKER.sid = L_LOCKER.sid
and L_LOCKER.ID1 = L_WAITER.ID1
and L_WAITER.REQUEST > 0
and L_LOCKER.LMODE > 0
and L_WAITER.ADDR != L_LOCKER.ADDR
and L_WAITER.ID1 = O.OBJ#
and U.USER# = O.OWNER#
union
select /*+ ordered
no_merge(L_WAITER)
no_merge(L_LOCKER) use_hash(L_LOCKER)
no_merge(S_WAITER) use_hash(S_WAITER)
no_merge(S_LOCKER) use_hash(S_LOCKER)
no_merge(L1_WAITER) use_hash(L1_WAITER)
no_merge(O) use_hash(O)
*/
/* now the (usual) row-locks TX */
S_LOCKER.OSUSER OS_LOCKER,
S_LOCKER.USERNAME LOCKER_SCHEMA,
S_LOCKER.PROCESS LOCK_PID,
S_WAITER.OSUSER OS_WAITER,
S_WAITER.USERNAME WAITER_SCHEMA,
S_WAITER.PROCESS WAITER_PID,
'TX: '||O.SQL_TEXT SQL_TEXT_WAITER
from
V$LOCK L_WAITER,
V$LOCK L_LOCKER,
V$SESSION S_WAITER,
V$SESSION S_LOCKER,
V$_LOCK1 L1_WAITER,
V$OPEN_CURSOR O
where S_WAITER.SID = L_WAITER.SID
and L_WAITER.TYPE IN ('TX')
and S_LOCKER.sid = L_LOCKER.sid
and L_LOCKER.ID1 = L_WAITER.ID1
and L_WAITER.REQUEST > 0
and L_LOCKER.LMODE > 0
and L_WAITER.ADDR != L_LOCKER.ADDR
and L1_WAITER.LADDR = L_WAITER.ADDR
and L1_WAITER.KADDR = L_WAITER.KADDR
and L1_WAITER.SADDR = O.SADDR
and O.HASH_VALUE = S_WAITER.SQL_HASH_VALUE
/
TTITLE OFF
COLUMN OS_LOCKER CLEAR
COLUMN OS_WAITER CLEAR
COLUMN LOCKER_SCHEMA CLEAR
COLUMN WAITER_SCHEMA CLEAR
COLUMN WAITER_PID CLEAR
COLUMN LOCKER_PID CLEAR
COLUMN SQL_TEXT_WAITER CLEAR
COLUMN DATABASE CLEAR
COLUMN DATUM_ZEIT CLEAR
rem
rem $Header: utllockt.sql 21-jan-2003.16:21:56 bnnguyen Exp $ locktree.sql
rem
Rem Copyright (c) 1989, 2003, Oracle Corporation. All rights reserved.
Rem NAME
REM UTLLOCKT.SQL
Rem FUNCTION - Print out the lock wait-for graph in tree structured fashion.
Rem This is useful for diagnosing systems that are hung on locks.
Rem NOTES
Rem MODIFIED
Rem bnnguyen 01/21/03 - bug2166717
Rem pgreenwa 04/27/95 - fix column definitions for LOCK_HOLDERS
Rem pgreenwa 04/26/95 - modify lock_holders query to use new dba_locks f
Rem glumpkin 10/20/92 - Renamed from LOCKTREE.SQL
Rem jloaiza 05/24/91 - update for v7
Rem rlim 04/29/91 - change char to varchar2
Rem Loaiza 11/01/89 - Creation
Rem

/* Print out the lock wait-for graph in a tree structured fashion.
*
* This script prints the sessions in the system that are waiting for
* locks, and the locks that they are waiting for. The printout is tree
* structured. If a sessionid is printed immediately below and to the right
* of another session, then it is waiting for that session. The session ids
* printed at the left hand side of the page are the ones that everyone is
* waiting for.
*
* For example, in the following printout session 9 is waiting for
* session 8, 7 is waiting for 9, and 10 is waiting for 9.
*
* WAITING_SESSION TYPE MODE REQUESTED MODE HELD LOCK ID1 LOCK ID2
* ----------------- ---- ----------------- ----------------- -------- --------
* 8 NONE None None 0 0
* 9 TX Share (S) Exclusive (X) 65547 16
* 7 RW Exclusive (X) S/Row-X (SSX) 33554440 2
* 10 RW Exclusive (X) S/Row-X (SSX) 33554440 2
*
* The lock information to the right of the session id describes the lock
* that the session is waiting for (not the lock it is holding).
*
* Note that this is a script and not a set of view definitions because
* connect-by is used in the implementation and therefore a temporary table
* is created and dropped since you cannot do a join in a connect-by.
*
* This script has two small disadvantages. One, a table is created when
* this script is run. To create a table a number of locks must be
* acquired. This might cause the session running the script to get caught
* in the lock problem it is trying to diagnose. Two, if a session waits on
* a lock held by more than one session (share lock) then the wait-for graph
* is no longer a tree and the conenct-by will show the session (and any
* sessions waiting on it) several times.
*/


/* Select all sids waiting for a lock, the lock they are waiting on, and the
* sid of the session that holds the lock.
* UNION
* The sids of all session holding locks that someone is waiting on that
* are not themselves waiting for locks. These are included so that the roots
* of the wait for graph (the sessions holding things up) will be displayed.
*/
drop table lock_holders;

create table LOCK_HOLDERS /* temporary table */
(
waiting_session number,
holding_session number,
lock_type varchar2(26),
mode_held varchar2(14),
mode_requested varchar2(14),
lock_id1 varchar2(22),
lock_id2 varchar2(22)
);

drop table dba_locks_temp;
create table dba_locks_temp as select * from dba_locks;

/* This is essentially a copy of the dba_waiters view but runs faster since
* it caches the result of selecting from dba_locks.
*/
insert into lock_holders
select w.session_id,
h.session_id,
w.lock_type,
h.mode_held,
w.mode_requested,
w.lock_id1,
w.lock_id2
from dba_locks_temp w, dba_locks_temp h
where h.blocking_others = 'Blocking'
and h.mode_held != 'None'
and h.mode_held != 'Null'
and w.mode_requested != 'None'
and w.lock_type = h.lock_type
and w.lock_id1 = h.lock_id1
and w.lock_id2 = h.lock_id2;

commit;

drop table dba_locks_temp;

insert into lock_holders
select holding_session, null, 'None', null, null, null, null
from lock_holders
minus
select waiting_session, null, 'None', null, null, null, null
from lock_holders;
commit;

column waiting_session format a17;
column lock_type format a17;
column lock_id1 format a17;
column lock_id2 format a17;

/* Print out the result in a tree structured fashion */
select lpad(' ',3*(level-1)) || waiting_session waiting_session,
lock_type,
mode_requested,
mode_held,
lock_id1,
lock_id2
from lock_holders
connect by prior waiting_session = holding_session
start with holding_session is null;

drop table lock_holders;
-- #############################################################################################
--
-- %Purpose: Show the most resource intensive SQL statements that have been recently executed
--
-- Displays a list of the most resource intensive SQL statements
-- that have been recently executed. Resource use is ranked by the
-- number of SGA buffer gets, which is a good indicator of the work done.
-- Only statements that are still cached in the SGA are searched -
-- statements are discarded using an LRU algorithim.
--
-- #############################################################################################
--
set linesize 1200 verify off feedback 100

accept gets default 100000 prompt "Min buffer gets [100,000] "

col sql_text for a1000

select
s.BUFFER_GETS,
s.DISK_READS,
s.ROWS_PROCESSED,
s.EXECUTIONS,
substr(u.NAME,1,10) Username,
s.SQL_TEXT
from
v$sqlarea s,
sys.user$ u
where
s.buffer_gets > &&gets and
s.parsing_user_id = u.user# and
u.name <> 'SYS'
order by
s.buffer_gets desc
/
set feedback on
-- #############################################################################################
--
-- %Purpose: Show the most resource intensive SQL statements that have been recently executed
--
-- Displays a list of the most resource intensive SQL statements
-- that have been recently executed. Resource use is ranked by the
-- number of SGA buffer gets, which is a good indicator of the work done.
-- Only statements that are still cached in the SGA are searched -
-- statements are discarded using an LRU algorithim.
--
-- #############################################################################################
--
set linesize 1200 verify off feedback 100

accept gets default 100000 prompt "Min buffer gets [100,000] "

col sql_text for a1000

select
s.BUFFER_GETS,
s.DISK_READS,
s.ROWS_PROCESSED,
s.EXECUTIONS,
substr(u.NAME,1,10) Username,
s.SQL_TEXT
from
v$sqlarea s,
sys.user$ u
where
s.buffer_gets > &&gets and
s.parsing_user_id = u.user# and
u.name <> 'SYS'
order by
s.buffer_gets desc
/
set feedback on
-- #############################################################################################
--
-- %Purpose: Show total, free and used space in all tablespaces / database files
--
-- Use: Needs Oracle DBA Access
--
-- #############################################################################################
--
clear buffer
clear columns
clear breaks
set linesize 500
set pagesize 5000
column a1 heading 'Tablespace' format a15
column a2 heading 'Data File' format a45
column a3 heading 'Total|Space [MB]' format 99999.99
column a4 heading 'Free|Space [MB]' format 99999.99
column a5 heading 'Free|%' format 9999.99
break on a1 on report
compute sum of a3 on a1
compute sum of a4 on a1
compute sum of a3 on report
compute sum of a4 on report
SELECT a.tablespace_name a1,
a.file_name a2,
a.avail a3,
NVL(b.free,0) a4,
NVL(ROUND(((free/avail)*100),2),0) a5
FROM (SELECT tablespace_name,
SUBSTR(file_name,1,45) file_name,
file_id,
ROUND(SUM(bytes/(1024*1024)),3) avail
FROM sys.dba_data_files
GROUP BY tablespace_name,
SUBSTR(file_name,1,45),
file_id) a,
(SELECT tablespace_name,
file_id,
ROUND(SUM(bytes/(1024*1024)),3) free
FROM sys.dba_free_space
GROUP BY tablespace_name, file_id) b
WHERE a.file_id = b.file_id (+)
ORDER BY 1, 2
/
-- #############################################################################################
--
-- %Purpose: Show waiting Sessions blocked through other Sessions
--
-- #############################################################################################
--
-- Die View ROW_LOCK_WAITS zeigt die wartenden Sessions. Dieses Statement
-- ist als View implementiert, es darf keine Rows zurückbringen, da sonst
-- ein User warten muss.
--
-- create or replace view row_lock_waits
-- (username, sid, object_owner,
-- object_name, sql_text, file_nr, block_nr, record_nr)
-- as
-- select s.username, s.sid,
-- o.owner,
-- o.object_name,
-- a.sql_text,
-- s.row_wait_file#,
-- s.row_wait_block#,
-- s.row_wait_row#
-- from v$session s, v$sqlarea a, dba_objects o
-- where o.object_id = s.row_wait_obj#
-- and s.sql_address = a.address
-- and s.row_wait_obj# > 0;
--
-- #############################################################################################
--
set feed off;
set pagesize 10000;
set wrap off;
set linesize 200;
set heading on;
set tab on;
set scan on;
set verify off;
--
ttitle left 'Waiting Sessions' -
skip 2

select * from row_lock_waits;
-- #############################################################################################
--
-- %Purpose: Show which Users are accessing which Rollback Segments.
--
-- It is sometimes useful to know which users are accessing the rollback segments.
-- This is important when a user is continally filling the rollback segments
--
-- #############################################################################################
--
set feed off;
set pagesize 10000;
set wrap off;
set linesize 200;
set heading on;
set tab on;
set scan on;
set verify off;
--
spool show_rollback_segment_usage.lst

ttitle 'Current Rollback Segment Usage' -
skip 2

column "Rollback Segment Name" format a18;
column "Oracle User Session" format a40;

select r.name "Rollback Segment Name",
p.spid "Process ID",
s.username||'('||l.sid||')' "Oracle User Session",
sq.sql_text
from v$sqlarea sq, v$lock l, v$process p, v$session s, v$rollname r
where l.sid = p.pid(+)
and s.sid = l.sid
and trunc(l.id1(+) / 65536) = r.usn
and l.type(+) = 'TX'
and l.lmode(+) = 6
and s.sql_address = sq.address
and s.sql_hash_value = sq.hash_value
order by r.name
/
spool off;
set feed on echo off termout on pages 24 verify on
ttitle off
-- #############################################################################################
--
-- %Purpose: Show which Users are accessing which Rollback Segments.
--
-- It is sometimes useful to know which users are accessing the rollback segments.
-- This is important when a user is continally filling the rollback segments
--
-- #############################################################################################
--
set feed off;
set pagesize 10000;
set wrap off;
set linesize 200;
set heading on;
set tab on;
set scan on;
set verify off;
--
spool show_rollback_segment_usage.lst

ttitle 'Current Rollback Segment Usage' -
skip 2

column "Rollback Segment Name" format a18;
column "Oracle User Session" format a40;

select r.name "Rollback Segment Name",
p.spid "Process ID",
s.username||'('||l.sid||')' "Oracle User Session",
sq.sql_text
from v$sqlarea sq, v$lock l, v$process p, v$session s, v$rollname r
where l.sid = p.pid(+)
and s.sid = l.sid
and trunc(l.id1(+) / 65536) = r.usn
and l.type(+) = 'TX'
and l.lmode(+) = 6
and s.sql_address = sq.address
and s.sql_hash_value = sq.hash_value
order by r.name
/
spool off;
set feed on echo off termout on pages 24 verify on
ttitle off
-- #############################################################################################
--
-- %Purpose: Show SID,SERIAL#,PID,STATUS,SCHEMA,OSUSER,BOX,PRG,LOGON_TIME of logged on Users
--
-- #############################################################################################
--
SET linesize 200 PAGESIZE 1000 FEED OFF;
COLUMN "sid,serial#" FORMAT A12
COLUMN "pid" FORMAT 999
COLUMN "status" FORMAT A8
COLUMN "schema" FORMAT A10
COLUMN "osuser" FORMAT A10
COLUMN "box" FORMAT A16
COLUMN "prg" FORMAT A30
--
SELECT
''''
|| s.sid
|| ','
|| s.serial#
|| ''';' "sid,serial#"
, p.spid "pid"
, s.status "status"
, s.schemaname "schema"
, s.osuser "osuser"
, s.machine "box"
, s.program "prg"
, TO_CHAR(s.logon_time, 'DD.MM.YYYY HH24:MI') "logon_time"
FROM
v$session s,
v$process p
WHERE s.paddr = p.addr
ORDER BY s.username
/
-- #############################################################################################
--
-- %Purpose: Shows SQL-Statement for connected SID/SRL# from V$SQLTEXT
--
-- #############################################################################################
--
set linesize 2000 trimspool on
select
to_char(s.SID,'999') SID,
to_char(s.Serial#,'999999') Srl#,
substr(s.OSUSER,1,10) OsUsr,
substr(s.SCHEMANAME,1,10) Schema,
substr(t.Sql_text,1,100) Sql_text
from
v$session s,
v$sqltext t
where
s.type <> 'BACKGROUND' and
s.sql_address = t.address (+) and
t.piece (+) = 0
order by
s.Status,
s.SID
/

-- #############################################################################################
--
-- %Purpose: Shows the User that has performed the most physical disk reads
--
-- This script shows the user that has performed the most physical
-- disk reads. You use the columns sid and serial# as input into
-- dbms_system.set_sql_trace_in_session to commence tracing the
-- offending user.
--
-- #############################################################################################
--
SELECT ses.sid, ses.serial#, ses.osuser, ses.process, sio.physical_reads
FROM v$session ses, v$sess_io sio
WHERE ses.sid = sio.sid
AND nvl(ses.username,'SYS') not in ('SYS', 'SYSTEM')
AND sio.physical_reads = (SELECT MAX(physical_reads)
FROM v$session ses2, v$sess_io sio2
WHERE ses2.sid = sio2.sid
AND ses2.username
NOT IN ('SYSTEM', 'SYS'));
-- #############################################################################################
--
-- %Purpose: Shows the User that has performed the most physical disk reads
--
-- This script shows the user that has performed the most physical
-- disk reads. You use the columns sid and serial# as input into
-- dbms_system.set_sql_trace_in_session to commence tracing the
-- offending user.
--
-- #############################################################################################
--
SELECT ses.sid, ses.serial#, ses.osuser, ses.process, sio.physical_reads
FROM v$session ses, v$sess_io sio
WHERE ses.sid = sio.sid
AND nvl(ses.username,'SYS') not in ('SYS', 'SYSTEM')
AND sio.physical_reads = (SELECT MAX(physical_reads)
FROM v$session ses2, v$sess_io sio2
WHERE ses2.sid = sio2.sid
AND ses2.username
NOT IN ('SYSTEM', 'SYS'));
-- #############################################################################################
--
-- %Purpose: Solutions for the "Mutation Table Problem" with DELETE CASCADE and Cascade Update
--
-- #############################################################################################
--
-- See http://www.akadia.com/services/ora_mutating_table_problems.html for the whole text.
--
-- Solution: Using a temporary table
--
-- If you need to update a mutating table, then you could use a temporary table,
-- a PL/SQL table, or a package variable to bypass these restrictions. For example,
-- in place of a single AFTER row trigger that updates the original table, resulting in
-- a mutating table error, you may be able to use two triggers - an AFTER row trigger that
-- updates a temporary table, and an AFTER statement trigger that updates the original table
-- with the values from the temporary table.
--
-- In the next example "from the real world", we want to show this. The table CUG can
-- only have records of the following types
--
-- A: Type = 1
-- B: Type = 2 (Leader for C or D)
-- C: Type = 3 (Lead by B)
-- D: Type = 4 (Lead by B)
-- Note, that the types C and D must be lead by the CUG type B.
--
drop table CUG cascade constraints;
create table CUG (
id_cug number(12) not null primary key,
id_B number(12) not null,
type number(1),
foreign key (id_B) references CUG (id_cug) on delete cascade);

drop table CUGTMP;
create global temporary table CUGTMP (
id_B number(12),
type number(1))
on commit delete rows;

create or replace trigger bi_r
before insert on CUG
for each row
declare
l_type CUG.type%type;
begin
if (:new.type in (3,4)) then
select type into l_type from CUG
where id_cug = :new.id_B;
end if;
if (l_type != 2) then
raise_application_error(-20002,
'Project- and Community CUGs must have a leading company');
end if;
end;
/

create or replace trigger au_r
after update of id_B on CUG
for each row
begin
insert into CUGTMP (id_B,type)
values (:new.id_B,:new.type);
end;
/

create or replace trigger au_s
after update of id_B on CUG
declare
l_id_B number(12);
l_typeCD number(1);
l_typeB number(1);
cursor cur_cugtmp is
select id_B,type
from CUGTMP;
begin
open cur_cugtmp;
loop
fetch cur_cugtmp into l_id_B,l_typeCD;
exit when cur_cugtmp%notfound;
dbms_output.put_line('DEBUG: au_s: id_B ' || to_char(l_id_B) || ', type : ' || to_char(l_typeCD));
select type into l_typeB from CUG
where id_cug = l_id_B;
dbms_output.put_line('au_s: type : ' || to_char(l_typeB));
if (l_typeB != 2) then
raise_application_error(-20002,
'Project- and Community CUGs must have a leading company');
end if;
end loop;
close cur_cugtmp;
end;
/

insert into CUG (id_cug,id_B,type)
values (0,0,0);
-- company 1
insert into CUG (id_cug,id_B,type)
values (1,0,2);
-- company 2
insert into CUG (id_cug,id_B,type)
values (2,0,2);
-- project 1
insert into CUG (id_cug,id_B,type)
values (3,1,3);
-- project 2
insert into CUG (id_cug,id_B,type)
values (4,2,3);
-- community 1
insert into CUG (id_cug,id_B,type)
values (5,1,4);
-- community 2
insert into CUG (id_cug,id_B,type)
values (6,2,4);
commit;

update CUG set id_B = 2 where id_cug in (3,4,5,6);
-- #############################################################################################
--
-- %Purpose: Summary of INVALID Objects ordered by Object Type
--
-- Use: Needs Oracle DBA Access
--
-- #############################################################################################
--
spool show_summary_invalid_objects.lst
set pause off
set feed off;
set pagesize 10000;
set wrap off;
set linesize 200;
set heading on;
set tab on;
set scan on;
set verify off;

ttitle left 'Summary of invalid objects for User: ' sql.user -
skip 2

column object_type format a25 wrap heading 'Object|Type'
column status format a8 heading 'Status'

SELECT DISTINCT (object_type), status, COUNT(*)
FROM dba_objects
WHERE status != 'VALID'
GROUP BY owner, object_type, status;
-- #############################################################################################
--
-- %Purpose: Try to set SQL_TRACE ON for another Session / Program
--
-- Use: SYS-User
--
-- #############################################################################################
--
CREATE OR REPLACE
PROCEDURE try_sql_trace_for_session (ProgName IN VARCHAR2) IS
--
-- Try to enable SQL_TRACE for ProgName
--
-- Example
--
-- SQL> set serveroutput on;
-- SQL> execute sys.TRY_SQL_TRACE_FOR_SESSION('SqlNav');
-- SID: 11 Serial#: 58
-- Tracing enabled ... bye, bye
--
-- PL/SQL procedure successfully completed.
--
nCount NUMBER := 0;

CURSOR curs_get_sid IS
SELECT sid,serial#
FROM v$session
WHERE program LIKE '%'||ProgName||'%';

BEGIN
WHILE nCount = 0
LOOP
FOR rec IN curs_get_sid LOOP
dbms_output.put_line('SID: '||rec.sid||' Serial#: '||rec.serial#);
dbms_system.set_sql_trace_in_session(rec.sid,rec.serial#,TRUE);
nCount := 1;
END LOOP;
dbms_lock.sleep(10);
END LOOP;
dbms_output.put_line('Tracing enabled ... bye, bye');
END;
/
-- #############################################################################################
--
-- %Purpose: Tuning Redologs und Checkpoints (Contention, Waits, Number/Duration of Checkpoints)
--
-- #############################################################################################

1). Redolog Buffer Contention
-----------------------------
SELECT SUBSTR(name,1,20) "Name",gets,misses,immediate_gets,immediate_misses
FROM v$latch
WHERE name in ('redo allocation', 'redo copy');

Name GETS MISSES IMMEDIATE_GETS IMMEDIATE_MISSES
-------------------- ---------- ---------- -------------- ----------------
redo allocation 277'446'780 2'534'627 0 0
redo copy 33'818 27'694 357'613'861 150'511

MISSES/GETS (must be < 1%)

Redo allocation: (2'534'627 / 277'446'780) * 100 = 0.91 %
Redo Copy: (27'694 / 33'818) * 100 = 81.8 %

IMMEDIATE_MISSES/(IMMEDIATE_GETS+IMMEDIATE_MISSES) (must be < 1%)

Redo Copy: 150'511/(150'511+357'613'861) = 0.04 %

2). Waits on Redo Log Buffer
----------------------------
SELECT name,value
FROM v$sysstat
WHERE name = 'redo log space requests';

The value of 'redo log space requests' reflects the number
of times a user process waits for space in the redo log buffer.
Optimal is if the value is near 0 (Oracle Manual says this ...)

NAME VALUE
---------------------------------------------------------------- ----------
redo log space requests 22641

4). Number of Checkpoints per hour
----------------------------------
set feed off;
set pagesize 10000;
set wrap off;
set linesize 200;
set heading on;
set tab on;
set scan on;
set verify off;
--
spool show_logswitches.lst

ttitle left 'Redolog File Status from V$LOG' skip 2

select group#, sequence#,
Members, archived, status, first_time
from v$log;

ttitle left 'Number of Logswitches per Hour' skip 2

select to_char(first_time,'YYYY.MM.DD') day,
to_char(sum(decode(substr(to_char(first_time,'DDMMYYYY:HH24:MI'),10,2),'00',1,0)),'99') "00",
to_char(sum(decode(substr(to_char(first_time,'DDMMYYYY:HH24:MI'),10,2),'01',1,0)),'99') "01",
to_char(sum(decode(substr(to_char(first_time,'DDMMYYYY:HH24:MI'),10,2),'02',1,0)),'99') "02",
to_char(sum(decode(substr(to_char(first_time,'DDMMYYYY:HH24:MI'),10,2),'03',1,0)),'99') "03",
to_char(sum(decode(substr(to_char(first_time,'DDMMYYYY:HH24:MI'),10,2),'04',1,0)),'99') "04",
to_char(sum(decode(substr(to_char(first_time,'DDMMYYYY:HH24:MI'),10,2),'05',1,0)),'99') "05",
to_char(sum(decode(substr(to_char(first_time,'DDMMYYYY:HH24:MI'),10,2),'06',1,0)),'99') "06",
to_char(sum(decode(substr(to_char(first_time,'DDMMYYYY:HH24:MI'),10,2),'07',1,0)),'99') "07",
to_char(sum(decode(substr(to_char(first_time,'DDMMYYYY:HH24:MI'),10,2),'08',1,0)),'99') "08",
to_char(sum(decode(substr(to_char(first_time,'DDMMYYYY:HH24:MI'),10,2),'09',1,0)),'99') "09",
to_char(sum(decode(substr(to_char(first_time,'DDMMYYYY:HH24:MI'),10,2),'10',1,0)),'99') "10",
to_char(sum(decode(substr(to_char(first_time,'DDMMYYYY:HH24:MI'),10,2),'11',1,0)),'99') "11",
to_char(sum(decode(substr(to_char(first_time,'DDMMYYYY:HH24:MI'),10,2),'12',1,0)),'99') "12",
to_char(sum(decode(substr(to_char(first_time,'DDMMYYYY:HH24:MI'),10,2),'13',1,0)),'99') "13",
to_char(sum(decode(substr(to_char(first_time,'DDMMYYYY:HH24:MI'),10,2),'14',1,0)),'99') "14",
to_char(sum(decode(substr(to_char(first_time,'DDMMYYYY:HH24:MI'),10,2),'15',1,0)),'99') "15",
to_char(sum(decode(substr(to_char(first_time,'DDMMYYYY:HH24:MI'),10,2),'16',1,0)),'99') "16",
to_char(sum(decode(substr(to_char(first_time,'DDMMYYYY:HH24:MI'),10,2),'17',1,0)),'99') "17",
to_char(sum(decode(substr(to_char(first_time,'DDMMYYYY:HH24:MI'),10,2),'18',1,0)),'99') "18",
to_char(sum(decode(substr(to_char(first_time,'DDMMYYYY:HH24:MI'),10,2),'19',1,0)),'99') "19",
to_char(sum(decode(substr(to_char(first_time,'DDMMYYYY:HH24:MI'),10,2),'20',1,0)),'99') "20",
to_char(sum(decode(substr(to_char(first_time,'DDMMYYYY:HH24:MI'),10,2),'21',1,0)),'99') "21",
to_char(sum(decode(substr(to_char(first_time,'DDMMYYYY:HH24:MI'),10,2),'22',1,0)),'99') "22",
to_char(sum(decode(substr(to_char(first_time,'DDMMYYYY:HH24:MI'),10,2),'23',1,0)),'99') "23"
from v$log_history
group by to_char(first_time,'YYYY.MM.DD')
/
spool off;


DAY 00 01 02 03 04 05 06 07 08 09 10 11 12 13 14 15 16 17 18 19 20 21 22 23
----- --- --- --- --- --- --- --- --- --- --- --- --- --- --- --- --- --- --- --- --- --- --- --- ---
07/07 0 0 0 0 0 0 0 0 0 0 0 0 0 0 1 2 0 0 0 0 0 0 0 0
07/08 0 0 0 0 0 0 0 0 0 0 0 5 0 4 1 0 1 0 0 0 0 0 0 0
07/12 0 0 0 0 0 0 0 0 0 0 1 1 0 1 1 0 0 0 0 0 0 0 0 0
07/13 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 1 0
07/14 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 0 1 1 1 1 0 0
07/15 1 0 0 0 0 0 0 0 0 0 0 0 2 1 0 0 1 2 2 0 0 0 0 0
07/16 0 0 10 10 15 11 5 0 0 0 0 0 2 5 5 4 5 7 6 6 7 4 4 4
07/17 2 2 1 3 4 6 9 10 11 11 12 12 11 11 12 11 11 12 12 9 9 10 12 9
07/18 12 9 10 10 8 8 9 10 9 8 9 10 10 11 10 11 10 10 11 10 11 9 10 10
07/19 9 3 1 1 0 0 4 6 7 7 4 5 11 10 5 4 5 7 6 8 7 5 5 3
07/20 1 1 8 10 7 5 4 5 4 5 7 7 9 7 9 9 7 9 10 11 12 11 12 9
07/21 9 10 10 10 12 10 7 8 9 8 9 10 11 11 11 8 10 10 12 7 6 7 7 7
07/22 8 7 9 10 8 6 7 8 8 8 9 9 9 10 9 9 9 9 9 9 10 7 6 7
07/23 5 5 7 7 7 2 3 3 4 5 6 5 5 4 3 3 4 4 6 6 5 9 8 5
07/24 4 4 5 4 7 6 5 8 8 11 11 11

log_checkpoint_interval = 900'000'000 (OK, must be greather than Redolog-File)
log_checkpoint_timeout = 1200 (Set it to 0, so time-based checkpoints are disabled)

5). Time needed to write a checkpoint
-------------------------------------
Beginning database checkpoint by background
Mon Aug 2 16:37:36 1999
Thread 1 advanced to log sequence 2860
Current log# 4 seq# 2860 mem# 0: /data/ota/db1/OTASICAP/redo/redoOTASICAP04.log
Mon Aug 2 16:43:31 1999
Completed database checkpoint by background

==> 6 Minutes

Mon Aug 2 16:45:15 1999
Beginning database checkpoint by background
Mon Aug 2 16:45:15 1999
Thread 1 advanced to log sequence 2861
Current log# 5 seq# 2861 mem# 0: /data/ota/db1/OTASICAP/redo/redoOTASICAP05.log
Mon Aug 2 16:50:29 1999
Completed database checkpoint by background

==> 5.5 Minutes

Mon Aug 2 16:51:50 1999
Beginning database checkpoint by background
Mon Aug 2 16:51:51 1999
Thread 1 advanced to log sequence 2862
Current log# 6 seq# 2862 mem# 0: /data/ota/db1/OTASICAP/redo/redoOTASICAP06.log
Mon Aug 2 16:56:44 1999
Completed database checkpoint by background

==> 5.5 Minutes-- #############################################################################################
--
-- %Purpose: Which ROLES are currently enabled for my Session ?
--
-- When a user logs on, Oracle enables all privileges granted explicitly
-- to the user and all privileges in the user's default roles. During the
-- session, the user or an application can use the SET ROLE statement
-- any number of times to change the roles currently enabled for the session.
-- The number of roles that can be concurrently enabled is limited by the
-- initialization parameter MAX_ENABLED_ROLES. You can see which roles are
-- currently enabled by examining the SESSION_ROLES data dictionary view.
--
-- #############################################################################################
--
SELECT role FROM session_roles;
--
-- You can check the DB access in your application context using the following code construct.
--
DECLARE
HasAccess BOOLEAN := FALSE;
CURSOR cur_get_role IS
SELECT role FROM session_roles;
BEGIN
FOR role_rec IN cur_get_role LOOP
IF (UPPER(role_rec.role) IN ('ADMIN','CLERK')) THEN
HasAccess := TRUE;
END IF;
END LOOP;
IF (NOT HasAccess) THEN
RAISE_APPLICATION_ERROR (-20020,'Sorry, you have no access to the database');
END IF;
END;
/

No comments: