Skip to content

Commit

Permalink
First commit
Browse files Browse the repository at this point in the history
  • Loading branch information
gwens committed Jan 30, 2018
0 parents commit 833cec6
Show file tree
Hide file tree
Showing 40 changed files with 792 additions and 0 deletions.
23 changes: 23 additions & 0 deletions 00_readme_first.txt
@@ -0,0 +1,23 @@
Dear reader,

thank you for your interest in Expert Oracle Exadata, 2nd edition.

Throughout the book you witnessed a pleathora of useful diagnostic
scripts. While the contents of many was shown in the body of the book,
some of them are lengthy enough that we decided not to print their
contents in the listings and rather include them here.

Please make sure to refer to the book for more information and context
of these scripts! Always consult the official Oracle documentation.

Before you start using _any_ of these scripts:
- You must understand what the script you are about to use actually does
(including any effects)
- You must ensure that you are in compliance with Oracle licensing
- You have to test the script thoroughly in a development environment first

Although great care has been taken by the authors, it is your
responsibility to remain in compliance with Oracle licensing, your
environment's standards, procedures and change control.

Have fun!
Binary file added 9781430262411.jpg
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
27 changes: 27 additions & 0 deletions LICENSE.txt
@@ -0,0 +1,27 @@
Freeware License, some rights reserved

Copyright (c) 2015 Martin Bach, Kristofferson Arao, Andy Colvin, Frits Hoogland, Kerry Osborne, Randy Johnson, and Tanel Poder

Permission is hereby granted, free of charge, to anyone obtaining a copy
of this software and associated documentation files (the "Software"),
to work with the Software within the limits of freeware distribution and fair use.
This includes the rights to use, copy, and modify the Software for personal use.
Users are also allowed and encouraged to submit corrections and modifications
to the Software for the benefit of other users.

It is not allowed to reuse, modify, or redistribute the Software for
commercial use in any way, or for a user�s educational materials such as books
or blog articles without prior permission from the copyright holder.

The above copyright notice and this permission notice need to be included
in all copies or substantial portions of the software.

THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR
IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY,
FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE
AUTHORS OR COPYRIGHT HOLDERS OR APRESS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER
LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM,
OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE
SOFTWARE.


16 changes: 16 additions & 0 deletions README.md
@@ -0,0 +1,16 @@
# Apress Source Code

This repository accompanies [*Expert Oracle Exadata*](http://www.apress.com/9781430262411) by Martin Bach, Kristofferson Arao, Andy Colvin, Frits Hoogland, Kerry Osborne, Randy Johnson, and Tanel Poder (Apress, 2015).

[comment]: #cover
![Cover image](9781430262411.jpg)

Download the files as a zip using the green button, or clone the repository to your machine using Git.

## Releases

Release v1.0 corresponds to the code in the published book, without corrections or updates.

## Contributions

See the file Contributing.md for more information on how you can contribute to this repository.
19 changes: 19 additions & 0 deletions as.sql
@@ -0,0 +1,19 @@
set pagesize 999
set lines 150
col username format a13
col prog format a10 trunc
col sql_text format a41 trunc
col sid format 9999
col child for 99999
col avg_etime for 999,999.99
select sid, substr(program,1,19) prog, address, hash_value, b.sql_id, child_number child, plan_hash_value, executions execs,
(elapsed_time/decode(nvl(executions,0),0,1,executions))/1000000 avg_etime,
sql_text
from v$session a, v$sql b
where status = 'ACTIVE'
and username is not null
and a.sql_id = b.sql_id
and a.sql_child_number = b.child_number
and sql_text not like 'select sid, substr(program,1,19) prog, address, hash_value, b.sql_id, child_number child,%' -- don't show this query
order by sql_id, sql_child_number
/
21 changes: 21 additions & 0 deletions calibrate_io.sql
@@ -0,0 +1,21 @@
set serveroutput on

DECLARE
miops PLS_INTEGER;
mmbps PLS_INTEGER;
alat NUMBER;
BEGIN

dbms_resource_manager.calibrate_io (
num_physical_disks => &no_of_disks,
max_latency => 10,
max_iops => miops,
max_mbps => mmbps,
actual_latency => alat
);

dbms_output.put_line('max_iops = ' || miops);
dbms_output.put_line('max_mbps = ' || mmbps);
dbms_output.put_line('latency = ' || alat);
end;
/
19 changes: 19 additions & 0 deletions cdb_as.sql
@@ -0,0 +1,19 @@
set pagesize 999
set lines 170
col username format a13
col prog format a10 trunc
col sql_text format a41 trunc
col sid format 9999
col child for 99999
col avg_etime for 999,999.99
select a.con_id,sid, substr(program,1,19) prog, address, hash_value, b.sql_id, child_number child, plan_hash_value, executions execs,
(elapsed_time/decode(nvl(executions,0),0,1,executions))/1000000 avg_etime,
sql_text
from v$session a, v$sql b
where status = 'ACTIVE'
and username is not null
and a.sql_id = b.sql_id
and a.sql_child_number = b.child_number
and sql_text not like 'select a.con_id,sid, substr(program,1,19) prog, address, hash_value, b.sql_id, child_number child,%' -- don't show this query
order by sql_id, sql_child_number
/
8 changes: 8 additions & 0 deletions cdb_tables.sql
@@ -0,0 +1,8 @@
set lines 150
select con_id, owner, table_name, status, last_analyzed, num_rows, blocks, degree
from cdb_tables
where con_id in (select con_id from v$pdbs where name like nvl('&pdb_name', name))
and owner like nvl('&owner',owner)
and table_name like nvl('&table_name',table_name)
order by con_id, owner, table_name
/
2 changes: 2 additions & 0 deletions check_px.sql
@@ -0,0 +1,2 @@
column value for 999,999
select * from V$PX_PROCESS_SYSSTAT where statistic like '%In Use%';
17 changes: 17 additions & 0 deletions comp_ratio.sql
@@ -0,0 +1,17 @@
set lines 155
compute sum of totalsize_megs on report
break on report
col owner for a10
col segment_name for a20
col segment_type for a10
col totalsize_megs for 999,999.9
col compression_ratio for 999.9
select owner, segment_name, segment_type type,
sum(bytes/1024/1024) as totalsize_megs,
&original_size/sum(bytes/1024/1024) as compression_ratio
from dba_segments
where owner like nvl('&owner',owner)
and segment_name like nvl('&table_name',segment_name)
and segment_type like nvl('&type',segment_type)
group by owner, segment_name, tablespace_name, segment_type
order by 5;
14 changes: 14 additions & 0 deletions contributing.md
@@ -0,0 +1,14 @@
# Contributing to Apress Source Code

Copyright for Apress source code belongs to the author(s). However, under fair use you are encouraged to fork and contribute minor corrections and updates for the benefit of the author(s) and other readers.

## How to Contribute

1. Make sure you have a GitHub account.
2. Fork the repository for the relevant book.
3. Create a new branch on which to make your change, e.g.
`git checkout -b my_code_contribution`
4. Commit your change. Include a commit message describing the correction. Please note that if your commit message is not clear, the correction will not be accepted.
5. Submit a pull request.

Thank you for your contribution!
7 changes: 7 additions & 0 deletions dba_tables.sql
@@ -0,0 +1,7 @@
set lines 150
col table_name for a40
select owner, table_name, status, last_analyzed, num_rows, blocks, degree
from dba_tables
where owner like nvl('&owner',owner)
and table_name like nvl('&table_name',table_name)
/
4 changes: 4 additions & 0 deletions dplan.sql
@@ -0,0 +1,4 @@
set lines 180
select * from table(dbms_xplan.display_cursor('&sql_id','&child_no','typical'))
/

2 changes: 2 additions & 0 deletions dump_block.sql
@@ -0,0 +1,2 @@
@find_trace
alter system dump datafile &fileno block &blockno;
6 changes: 6 additions & 0 deletions esfc_keep_tables.sql
@@ -0,0 +1,6 @@
select owner, table_name, status, last_analyzed, num_rows, blocks, degree, cell_flash_cache
from dba_tables
where owner like nvl('&owner',owner)
and table_name like nvl('&table_name',table_name)
and cell_flash_cache like nvl('&cell_flash_cache','KEEP')
/
5 changes: 5 additions & 0 deletions find_trace.sql
@@ -0,0 +1,5 @@

set lines 150
col value for a145

select value from v$diag_info where name = 'Default Trace File';
20 changes: 20 additions & 0 deletions flush_sql.sql
@@ -0,0 +1,20 @@
set serveroutput on
set pagesize 9999
set linesize 155
var name varchar2(50)
accept sql_id -
prompt 'Enter value for sql_id: '

BEGIN

select address||','||hash_value into :name
from v$sqlarea
where sql_id like '&&sql_id';

dbms_shared_pool.purge(:name,'C',1);

END;
/

undef sql_id
undef name
24 changes: 24 additions & 0 deletions fs.sql
@@ -0,0 +1,24 @@
col sql_text for a60 wrap
set verify off
set pagesize 999
set lines 155
col username format a13
col prog format a22
col sid format 999
col child_number format 99999 heading CHILD
col ocategory format a10
col avg_etime format 9,999,999.99
col avg_pio format 9,999,999.99
col avg_lio format 999,999,999
col etime format 9,999,999.99

select sql_id, child_number, plan_hash_value plan_hash, executions execs,
(elapsed_time/1000000)/decode(nvl(executions,0),0,1,executions) avg_etime,
buffer_gets/decode(nvl(executions,0),0,1,executions) avg_lio,
sql_text
from v$sql s
where upper(sql_text) like upper(nvl('&sql_text',sql_text))
and sql_text not like '%from v$sql where sql_text like nvl(%'
and sql_id like nvl('&sql_id',sql_id)
order by 1, 2, 3
/
61 changes: 61 additions & 0 deletions fsx.sql
@@ -0,0 +1,61 @@
----------------------------------------------------------------------------------------
--
-- File name: fsx.sql
--
-- Purpose: Find SQL and report whether it was Offloaded and % of I/O saved.
--
-- Author: Kerry Osborne
--
-- Usage: This scripts prompts for two values.
--
-- sql_text: a piece of a SQL statement like %select col1, col2 from skew%
--
-- sql_id: the sql_id of the statement if you know it (leave blank to ignore)
--
-- Description:
--
-- This script can be used to locate statements in the shared pool and
-- determine whether they have been executed via Smart Scans.
--
-- It is based on the observation that the IO_CELL_OFFLOAD_ELIGIBLE_BYTES
-- column in V$SQL is only greater than 0 when a statement is executed
-- using a Smart Scan. The IO_SAVED_% column attempts to show the ratio of
-- of data received from the storage cells to the actual amount of data
-- that would have had to be retrieved on non-Exadata storage. Note that
-- as of 11.2.0.2, there are issues calculating this value with some queries.
--
-- Note that the AVG_ETIME will not be acurate for parallel queries. The
-- ELAPSED_TIME column contains the sum of all parallel slaves. So the
-- script divides the value by the number of PX slaves used which gives an
-- approximation.
--
-- Note also that if parallel slaves are spread across multiple nodes on
-- a RAC database the PX_SERVERS_EXECUTIONS column will not be set.
--
-- See kerryosborne.oracle-guy.com for additional information.
---------------------------------------------------------------------------------------
set pagesize 999
set lines 190
col sql_text format a70 trunc
col child format 99999
col execs format 9,999
col avg_etime format 99,999.99
col "IO_SAVED_%" format 999.99
col avg_px format 999
col offload for a7

select sql_id, child_number child, plan_hash_value plan_hash, executions execs,
(elapsed_time/1000000)/decode(nvl(executions,0),0,1,executions)/
decode(px_servers_executions,0,1,px_servers_executions/decode(nvl(executions,0),0,1,executions)) avg_etime,
px_servers_executions/decode(nvl(executions,0),0,1,executions) avg_px,
decode(IO_CELL_OFFLOAD_ELIGIBLE_BYTES,0,'No','Yes') Offload,
decode(IO_CELL_OFFLOAD_ELIGIBLE_BYTES,0,0,100*(IO_CELL_OFFLOAD_ELIGIBLE_BYTES-IO_INTERCONNECT_BYTES)
/decode(IO_CELL_OFFLOAD_ELIGIBLE_BYTES,0,1,IO_CELL_OFFLOAD_ELIGIBLE_BYTES)) "IO_SAVED_%",
sql_text
from v$sql s
where upper(sql_text) like upper(nvl('&sql_text',sql_text))
and sql_text not like 'BEGIN :sql_text := %'
and sql_text not like '%IO_CELL_OFFLOAD_ELIGIBLE_BYTES%'
and sql_id like nvl('&sql_id',sql_id)
order by 1, 2, 3
/
33 changes: 33 additions & 0 deletions fsx2.sql
@@ -0,0 +1,33 @@
set verify off
set pagesize 999
set lines 190
col sql_text format a40 word_wrap
col child format 99999
col execs format 9,999
col avg_etime format 99,999.99
col avg_cpu format 9,999.99
col avg_lio format 9,999,999
col avg_pio format 9,999,999
col "IO_SAVED_%" format 999.99
col avg_px format 999
col offload for a7

select sql_id, avg_etime, px, Offload, sql_text from (
select sql_id, child_number child, plan_hash_value plan_hash, executions execs,
(elapsed_time/1000000)/decode(nvl(executions,0),0,1,executions) avg_etime,
--decode(IO_CELL_OFFLOAD_ELIGIBLE_BYTES,0,buffer_gets/decode(nvl(executions,0),0,1,executions),null) avg_lio,
--decode(IO_CELL_OFFLOAD_ELIGIBLE_BYTES,0,disk_reads/decode(nvl(executions,0),0,1,executions),null) avg_pio,
px_servers_executions/decode(nvl(executions,0),0,1,executions) px,
decode(IO_CELL_OFFLOAD_ELIGIBLE_BYTES,0,'No','Yes') Offload,
decode(IO_CELL_OFFLOAD_ELIGIBLE_BYTES,0,0,
100*(IO_CELL_OFFLOAD_ELIGIBLE_BYTES-IO_INTERCONNECT_BYTES)
/decode(IO_CELL_OFFLOAD_ELIGIBLE_BYTES,0,1,IO_CELL_OFFLOAD_ELIGIBLE_BYTES)) "IO_SAVED_%",
sql_text
from v$sql s
where upper(sql_text) like upper(nvl('&sql_text',sql_text))
and sql_text not like 'BEGIN :sql_text := %'
and sql_text not like '%IO_CELL_OFFLOAD_ELIGIBLE_BYTES%'
and sql_id like nvl('&sql_id',sql_id)
)
order by 1, 2, 3
/
25 changes: 25 additions & 0 deletions fsx3.sql
@@ -0,0 +1,25 @@
set verify off
set pagesize 999
set lines 190
col sql_text format a20 trunc
col child format 99999
col execs format 9,999
col avg_etime format 9,999,999.99
col avg_cpu format 9,999,999.99
col avg_lio format 999,999,999
col avg_pio format 999,999,999
col "IO_SAVED_%" format 999.99
col avg_px format 999
col offload for a7

select sql_id, child_number child,
decode(IO_CELL_OFFLOAD_ELIGIBLE_BYTES,0,'No','Yes') Offload,
executions execs,
IO_CELL_OFFLOAD_ELIGIBLE_BYTES eligible_bytes, sql_text
from v$sql s
where upper(sql_text) like upper(nvl('&sql_text',sql_text))
and sql_text not like 'BEGIN :sql_text := %'
and sql_text not like '%IO_CELL_OFFLOAD_ELIGIBLE_BYTES%'
and sql_id like nvl('&sql_id',sql_id)
order by 1, 2, 3
/

0 comments on commit 833cec6

Please sign in to comment.