By Laurent Schneider
There is a new command in 11g to display the current events.
It is oradebug eventdump.
For example :
SQL> alter session set events '10046 trace name context
forever,level 12:942 trace name ERRORSTACK level 3';
SQL>
oradebug setmypid
Statement processed.
SQL> oradebug
eventdump session
sql_trace level=12 942
trace name
ERRORSTACK level 3
Read metalink note 436036.1
In 10g and before, the command was oradebug dump events 1 and the
list was dumped in a trace file. 11g directly outputs to the
console.
Note: There is no backward compatibility with unsupported
tools like oradebug.
In 11g, you will get an ORA-00076 with dump events:
SQL> oradebug setmypid
Statement processed.
SQL> oradebug dump events 1
ORA-00076: dump EVENTS not found
$ oerr ora 76
00076, 00000, "dump %s not found"
//
*Cause: An attempt was made to invoke a dump that does not exist.
// *Action: Type DUMPLIST to see the list of available dumps.
Or, how many rows would be returned by:
select * from dual where dbms_random.value=dbms_random.value;
It is wrong to assume the function will be evaluated twice.
The short answer would be : do not rely on
random plsql functions in SQL�
Here is a test case in 11.2.0.2 and 10.2.0.3
SQL> select version from v$instance;
VERSION
-----------------
10.2.0.3.0
SQL> select *
from dual where dbms_random.value=dbms_random.value;
no rows
selected
Execution Plan
----------------------------------------------------------
Plan hash value: 1224005312
---------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)|
Time |
---------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 2 | 2 (0)|
00:00:01 |
|* 1 | FILTER | | |
| | |
| 2 | TABLE ACCESS FULL| DUAL
| 1 | 2 | 2 (0)| 00:00:01 |
---------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
1 -
filter("DBMS_RANDOM"."VALUE"()="DBMS_RANDOM"."VALUE"())
In 10g, the function is executed twice per row, and the chance to
have two different values is more than 99.9999�%.
SQL> select version from v$instance;
VERSION
-----------------
11.2.0.2.0
SQL> select *
from dual where dbms_random.value=dbms_random.value D - X
Execution Plan
----------------------------------------------------------
Plan hash value: 1224005312
---------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)|
Time
|--------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 2 | 2 (0)|
00:00:01 |
|* 1 | FILTER | | |
| | |
| 2 | TABLE ACCESS FULL| DUAL
| 1 | 2 | 2 (0)| 00:00:01 |
---------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
1 -
filter("DBMS_RANDOM"."VALUE"() IS NOT NULL)
Here the optimized execute the function only once per row,
and since the result is never null, it always evaluates to true.
Is this a bug or a feature?
In my opinion it is a confusing tuning enhancement that may break
badsome programs.
In the discussion, I mentioned that prior dbms_random.value IS
NOT NULL is an unsafe construct.
|
|
|
Get the Complete
Oracle Tuning Details
The landmark book
"Oracle
Tuning: The Definitive Reference Second Edition" has been
updated with over 1,150 pages of expert performance tuning tips.
It's packed with scripts and tools to hypercharge Oracle 11g
performance and you can
buy it for 40% off directly from the publisher.
|
|
Download your Oracle scripts now:
www.oracle-script.com
The
definitive Oracle Script collection for every Oracle professional DBA
|
|
|
|

Copyright ©
1996 -2017 by Burleson. All rights reserved.
Oracle® is the registered trademark of Oracle
Corporation. SQL Server® is the registered trademark of Microsoft
Corporation. Many of the designations used by computer vendors to distinguish their
products are claimed as Trademarks
|
|