Skip to content

Commit

Permalink
First commit
Browse files Browse the repository at this point in the history
  • Loading branch information
Apress committed Oct 12, 2016
0 parents commit eb757e3
Show file tree
Hide file tree
Showing 571 changed files with 53,204 additions and 0 deletions.
Binary file added 4050.pdf
Binary file not shown.
Binary file added 4051.pdf
Binary file not shown.
Binary file added 9781590599174.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) 2008 Christian Antognini

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.


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

This repository accompanies [*Troubleshooting Oracle Performance*](http://www.apress.com/9781590599174) by Christian Antognini (Apress, 2008).

![Cover image](9781590599174.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.
75 changes: 75 additions & 0 deletions Scripts20100624/changelog.txt
@@ -0,0 +1,75 @@
2008-08-21

- Initial release

2009-03-08

- connect.sql Added DBM11107 and DBA11107
- chapter02\bind_variables.sql Fixed typo in comment
- chapter02\sharable_cursors.sql Added note about sharable_cursors_9i.sql + Fixed comment
- chapter02\sharable_cursors_9i.sql New file
- chapter03\map_session_to_tracefile.sql As of 11g the function LOWER must not be applied to the instance name
- chapter04\col_usage.sql New file
- chapter04\comparing_object_statistics.sql Fixed timing issue after sleep + ORA-00001
- chapter05\bug5015557.sql Fixed hints + Added note about supported database releases
- chapter05\dynamic_sampling_levels.sql Fixed typo in header
- chapter05\optimizer_secure_view_merging.sql Added service to CONNECT statements + Changed notes in header
- chapter06\explain_plan.sql Fixed wrong CTAS in "Setup test environment"
- chapter07\baseline_autoevolution.sql New file
- chapter07\all_rows.sql Added query to show SQL profile in 11g
- chapter08\ParsingTest1.cs New file
- chapter08\ParsingTest2.cs New file
- chapter09\hash_cluster.sql New file
- chapter10\merge_join.sql Added hint gather_plan_statistics to the last three queries
- chapter11\ArrayInterface.cs New file
- chapter11\RowPrefetching.cs New file
- databases\DBA11107 New directory containing the files to create the database DBA11107
- databases\DBM11107 New directory containing the files to create the database DBM11107

2009-05-29

- chapter07\object_stats.sql New file
- chapter07\outline_with_ffs.sql New file
- chapter07\sqltext_to_signature.sql New file

2009-06-10

- chapter09\fbi.sql To avoid index joins set _index_join_enabled to FALSE
- chapter12\wrong_datatype.sql To generate data use "to_date(...)" instead of "sysdate"

2010-06-24

- connect.sql Added DBM10205, DBA10205, DBM11201 and DBA11201
- chapter02\bind_variables.sql Because of 11g modified/added queries against V$SQL_SHARED_CURSOR
- chapter02\sharable_cursors.sql Added SET SERVEROUTPUT OFF in the initialization part
- chapter03\dbms_hprof.sql New file
- chapter03\sql_trace_trigger.sql New file
- chapter06\display_awr.sql Improved query that displays AWR content
- chapter06\execution_plans.sql Added example for UNION ALL (RECURSIVE WITH)
- chapter07\baseline_evolution_delete.sql New file
- chapter07\baseline_upgrade_11g.sql After import added update to set the owner of the SQL tuning set
- chapter07\opt_estimate.sql Uncommented 11g query
- chapter07\outline_with_hj.sql Script compatible with 10g/11g (set "_hash_join_enabled")
- chapter07\tune_last_statement.sql Added SET SERVEROUTPUT OFF in the initialization part
- chapter08\client-side_caching.sql New file
- chapter09\conditions.sql Added queries containing NOT IN condition
- chapter09\hash_cluster.sql Changed comment related to IN operator because of 11.2 improvement
- chapter10\hash_join.sql Fixed typo in description
- chapter10\join_elimination.sql Fixed typo in description
- chapter10\join_elimination2.sql New file
- chapter10\pwj.sql Disabled join-filter pruning
- chapter10\subquery_unnesting.sql Cover many more cases
- chapter11\ArrayInterface.java Added check for the return value of the executeBatch method
- chapter11\ArrayInterfacePerf.java Fixed number of iterations in main method
- chapter11\atomic_refresh.sql Changed CTAS to avoid ORA-30009
- chapter11\dpi_performance.sql Changed CTAS to avoid ORA-30009
- chapter11\px_auto_dop.sql New file
- chapter11\px_ddl.sql Changed the part displaying the parallel DDL status
- chapter11\px_dml.sql Changed the part displaying the parallel DML status
- chapter11\px_query.sql Changed the part displaying the parallel query status
- chapter11\result_cache_plsql.sql Added comment about invalidation in 11.2
- chapter12\data_compression.sql Changed CTAS to avoid ORA-30009
- databases\DBA10205 New directory containing the files to create the database DBA10205
- databases\DBM10205 New directory containing the files to create the database DBM10205
- databases\DBA11201 New directory containing the files to create the database DBA11201
- databases\DBM11201 New directory containing the files to create the database DBM11201
275 changes: 275 additions & 0 deletions Scripts20100624/chapter02/bind_variables.sql
@@ -0,0 +1,275 @@
SET ECHO OFF
REM ***************************************************************************
REM ******************* Troubleshooting Oracle Performance ********************
REM ************************ http://top.antognini.ch **************************
REM ***************************************************************************
REM
REM File name...: bind_variables.sql
REM Author......: Christian Antognini
REM Date........: August 2008
REM Description.: This script shows how and when bind variables lead to the
REM sharing of cursors.
REM Notes.......: This script works as of 10g only. The 9i version is named
REM bind_variables_9i.sql.
REM Parameters..: -
REM
REM You can send feedbacks or questions about this script to top@antognini.ch.
REM
REM Changes:
REM DD.MM.YYYY Description
REM ---------------------------------------------------------------------------
REM 08.03.2009 Fixed typo in comment
REM 24.06.2010 Because of 11g modified/added queries against V$SQL_SHARED_CURSOR
REM ***************************************************************************

SET TERMOUT ON
SET FEEDBACK OFF
SET VERIFY OFF
SET SCAN ON

@../connect.sql

SET ECHO ON

REM
REM Setup test environment
REM

DROP TABLE t;

CREATE TABLE t (n NUMBER, v VARCHAR2(4000));

ALTER SYSTEM FLUSH SHARED_POOL;

COLUMN sql_id NEW_VALUE sql_id

PAUSE

REM
REM This script only works if:
REM - the database character set is a single-byte encoding (e.g. WE8MSWIN1252)
REM - the database national character is a two-byte encoding (e.g. AL16UTF16)
REM

SELECT parameter, value
FROM nls_database_parameters
WHERE parameter IN ('NLS_CHARACTERSET','NLS_NCHAR_CHARACTERSET');

PAUSE

REM
REM Execute three times the same SQL statement. Every time the value of the
REM bind variable is changed. Note that the SQL statement uses two bind
REM variables: a NUMBER and a VARCHAR2(32).
REM

VARIABLE n NUMBER
VARIABLE v VARCHAR2(32)

EXECUTE :n := 1; :v := 'Helicon';

INSERT INTO t (n, v) VALUES (:n, :v);

EXECUTE :n := 2; :v := 'Trantor';

INSERT INTO t (n, v) VALUES (:n, :v);

EXECUTE :n := 3; :v := 'Kalgan';

INSERT INTO t (n, v) VALUES (:n, :v);

PAUSE

REM
REM Display information about the associated child cursors
REM

SELECT sql_id, child_number, executions
FROM v$sql
WHERE sql_text = 'INSERT INTO t (n, v) VALUES (:n, :v)';

PAUSE

REM
REM Re-execute the SQL statement two times. Compared to the previous
REM executions, the size of the VARCHAR2 bind variable is increased.
REM

VARIABLE v VARCHAR2(33)

EXECUTE :n := 4; :v := 'Terminus';

INSERT INTO t (n, v) VALUES (:n, :v);

VARIABLE v VARCHAR2(128)

EXECUTE :n := 4; :v := 'Terminus';

INSERT INTO t (n, v) VALUES (:n, :v);

PAUSE

REM
REM Display information about the associated child cursors
REM

SELECT sql_id, child_number, executions
FROM v$sql
WHERE sql_text = 'INSERT INTO t (n, v) VALUES (:n, :v)';

PAUSE

REM
REM Re-execute the SQL statement two times. Compared to the previous
REM executions, the size of the VARCHAR2 bind variable is increased.
REM

VARIABLE v VARCHAR2(129)

EXECUTE :n := 4; :v := 'Terminus';

INSERT INTO t (n, v) VALUES (:n, :v);

VARIABLE v VARCHAR2(2000)

EXECUTE :n := 4; :v := 'Terminus';

INSERT INTO t (n, v) VALUES (:n, :v);

PAUSE

REM
REM Display information about the associated child cursors
REM

SELECT sql_id, child_number, executions
FROM v$sql
WHERE sql_text = 'INSERT INTO t (n, v) VALUES (:n, :v)';

PAUSE

REM
REM Re-execute the SQL statement two times. Compared to the previous
REM executions, the size of the VARCHAR2 bind variable is increased.
REM

VARIABLE v VARCHAR2(2001)

EXECUTE :n := 4; :v := 'Terminus';

INSERT INTO t (n, v) VALUES (:n, :v);

VARIABLE v VARCHAR2(4000)

EXECUTE :n := 4; :v := 'Terminus';

INSERT INTO t (n, v) VALUES (:n, :v);

PAUSE

REM
REM Display information about the associated child cursors
REM

SELECT sql_id, child_number, executions
FROM v$sql
WHERE sql_text = 'INSERT INTO t (n, v) VALUES (:n, :v)';

PAUSE

REM
REM Several child cursors were generated because of the increasing size of the
REM VARCHAR2 bind variable.
REM

COLUMN bind_mismatch FORMAT a13
COLUMN incomplete_cursor FORMAT a17
COLUMN bind_length_upgradeable FORMAT a23

SELECT child_number, bind_mismatch, incomplete_cursor
FROM v$sql_shared_cursor
WHERE sql_id = '&sql_id';

PAUSE

REM The following query works as of 11.2 only

SELECT child_number, bind_length_upgradeable
FROM v$sql_shared_cursor
WHERE sql_id = '&sql_id';

PAUSE

REM
REM The metadata associated to the bind variables confirms that the database
REM engine uses bind variable graduation to minimize the number of child
REM cursors.
REM

SELECT s.child_number, m.position, m.max_length,
decode(m.datatype,1,'VARCHAR2',2,'NUMBER',m.datatype) aS datatype
FROM v$sql s, v$sql_bind_metadata m
WHERE s.sql_id = '&sql_id'
AND s.child_address = m.address
ORDER BY 1, 2;

PAUSE

REM
REM Show that the boundaries for bind variable graduation (32, 128 and 2000)
REM are bytes, not characters. For that purpose, the national character set
REM is used.
REM

ALTER SYSTEM FLUSH SHARED_POOL;

VARIABLE n NUMBER
VARIABLE v NVARCHAR2(16)

EXECUTE :n := 1; :v := 'Helicon';

INSERT INTO t (n, v) VALUES (:n, :v);

VARIABLE v NVARCHAR2(17)

EXECUTE :n := 2; :v := 'Trantor';

INSERT INTO t (n, v) VALUES (:n, :v);

PAUSE

SELECT sql_id, child_number, executions
FROM v$sql
WHERE sql_text = 'INSERT INTO t (n, v) VALUES (:n, :v)';

PAUSE

SELECT child_number, bind_mismatch, incomplete_cursor
FROM v$sql_shared_cursor
WHERE sql_id = '&sql_id';

PAUSE

REM The following query works as of 11.2 only

SELECT child_number, bind_length_upgradeable
FROM v$sql_shared_cursor
WHERE sql_id = '&sql_id';

PAUSE

SELECT s.child_number, m.position, m.max_length,
decode(m.datatype,1,'VARCHAR2',2,'NUMBER',m.datatype) aS datatype
FROM v$sql s, v$sql_bind_metadata m
WHERE s.sql_id = '&sql_id'
AND s.child_address = m.address
ORDER BY 1, 2;

REM
REM Cleanup
REM

UNDEFINE sql_id

DROP TABLE t;
PURGE TABLE t;

0 comments on commit eb757e3

Please sign in to comment.