All Oracle specialists know that a predicate X=NULL can never be true and we should use “X is NULL” in such cases. The Oracle optimizer knows about that, so if we create a table like this:
Continue readingCategory Archives: curious
ORA exceptions that can’t be caught by exception handler
I know 2 “special” exceptions that can’t be processed in exception handler:
- “ORA-01013: user requested cancel of current operation”
- “ORA-03113: end-of-file on communication channel”
- and + “ORA-00028: your session has been killed” from Matthias Rogel
Tanel Poder described the first one (ORA-01013) in details here: https://tanelpoder.com/2010/02/17/how-to-cancel-a-query-running-in-another-session/ where Tanel shows that this error is based on SIGURG signal (kill -URG
):
-- 1013 will not be caught:
declare
e exception;
pragma exception_init(e,-1013);
begin
raise e;
exception when others then dbms_output.put_line('caught');
end;
/
declare
*
ERROR at line 1:
ORA-01013: user requested cancel of current operation
ORA-06512: at line 5
v$blog #funny #friday
select title, short_url
from v$blog
where pubDate>=systimestamp - interval '5' month;
with v$blog as (
select
title
,to_timestamp_tz(pubDate,'DY, dd mon yyyy hh24:mi:ss TZR') pubDate
,short_url
,description
from xmltable(
'/rss/channel/item'
passing
xmltype(httpuritype('https://orasql.org/feed/').getclob())
columns
title varchar2(70) path 'title'
,pubDate varchar2(40) path 'pubDate'
,url varchar2(128) path 'link'
,short_url varchar2(50) path 'guid'
,description varchar2(500) path 'fn:substring(./description,1,500)'
)
)
select title, short_url from v$blog where pubDate>=systimestamp - interval '5' month;
Funny friday Oracle SQL quiz: query running N seconds
Write a pure SQL query with PL/SQL that stop after :N seconds, where :N is a bind variable.
with v(start_hsecs, delta, flag) as ( select hsecs as start_hsecs, 0 as delta, 1 as flag from v$timer union all select v.start_hsecs, (t.hsecs-v.start_hsecs)/100 as delta, case when (t.hsecs-v.start_hsecs)/100 > :N /* seconds */ then v.flag*-1 else v.flag+1 end as flag from v, v$timer t where v.flag>0 and t.hsecs>=v.start_hsecs ) select delta from v where 0>flag / --end
SQL> var N number
SQL> exec :N := 3 /* seconds */;
PL/SQL procedure successfully completed.
SQL> select...
DELTA
----------
3.01
1 row selected.
Elapsed: 00:00:03.01
Another my solution using sys.standard.current_timestamp, so some internal pl/sql…:
select count(*) from dual
connect by sys.standard.current_timestamp - current_timestamp <= interval'3'second;
Another bug with lateral
Compare the results of the following query with the clause “fetch first 2 rows only”
with t1(a) as (select * from table(odcinumberlist(1,3))) ,t2(a,b) as (select * from table(ku$_objnumpairlist( sys.ku$_objnumpair(1,1), sys.ku$_objnumpair(1,2), sys.ku$_objnumpair(1,3), sys.ku$_objnumpair(3,1), sys.ku$_objnumpair(3,2), sys.ku$_objnumpair(3,3) ))) ,t(id) as (select * from table(odcinumberlist(1,2,3,4,5,6,7))) select * from t, lateral(select t1.a,t2.b from t1,t2 where t1.a = t2.a and t1.a = t.id order by t2.b fetch first 2 rows only )(+) order by id; ID A B ---------- ---------- ---------- 1 1 1 1 3 1 2 1 1 2 3 1 3 1 1 3 3 1 4 1 1 4 3 1 5 1 1 5 3 1 6 1 1 6 3 1 7 1 1 7 3 1 14 rows selected.
with this one (i’ve just commented out the line with “fetch-first-rows-only”:
with t1(a) as (select * from table(odcinumberlist(1,3))) ,t2(a,b) as (select * from table(ku$_objnumpairlist( sys.ku$_objnumpair(1,1), sys.ku$_objnumpair(1,2), sys.ku$_objnumpair(1,3), sys.ku$_objnumpair(3,1), sys.ku$_objnumpair(3,2), sys.ku$_objnumpair(3,3) ))) ,t(id) as (select * from table(odcinumberlist(1,2,3,4,5,6,7))) select * from t, lateral(select t1.a,t2.b from t1,t2 where t1.a = t2.a and t1.a = t.id order by t2.b -- fetch first 2 rows only )(+) order by id; ID A B ---------- ---------- ---------- 1 1 2 1 1 3 1 1 1 2 3 3 2 3 3 1 3 3 3 4 5 6 7 11 rows selected.
Obviously, the first query should return less rows than second one, but we can see that it returned more rows and join predicate “and t1.a = t.id” was ignored, because A and B are not empty and “A” is not equal to t.ID.
Create External Table as Select
I was looking through a test script and saw something I didn’t know you could do in Oracle. I mentioned it to an Oracle ACE and he didn’t know it either. I then said to the External Table engineers “Oh I see you’ve added this cool new feature” and he replied dryly – “Yes, we added it in Oracle 10.1”. Ouch! So just in case you also didn’t know, you can create an External Table using a CTAS and the ORACLE_DATAPUMP driver.
This feature only work with the ORACLE_DATAPUMP access driver (it does NOT work with with the LOADER, HIVE, or HDFS drivers) and we can use it like this:
SQL> create table cet_test organization external
2 (
3 type ORACLE_DATAPUMP
4 default directory T_WORK
5 location ('xt_test01.dmp','xt_test02.dmp')
6 ) parallel 2
7 as select * from lineitem
Table created.
Checking the results shows us
-rw-rw---- ... 786554880 Mar 9 10:48 xt_test01.dmp
-rw-rw---- ... 760041472 Mar 9 10:48 xt_test02.dmp
This can be a great way of creating a (redacted) sample of data to give to a developer to test or for a bug repro to give to support or to move between systems.
Bug with integer literals in PL/SQL
This interesting question was posted on our russian forum yesterday:
We have a huge PL/SQL package and this simple function returns wrong result when it’s located at the end of package body:
create or replace package body PKGXXX as ... function ffff return number is nRes number; begin nRes := 268435456; return nRes; end; end; /But it works fine in any of the following cases:
* replace 268435456 with power(2, 28), or
* replace 268435456 with small literal like 268, or
* move this function to the beginning of package body
The one of the interesting findings was that the returned value is equal to the one of literals in another function.
We can reproduce this bug even with an anonymous pl/sql block. The following test case uses 32768 integer literals from 1000001 to 1032768 and prints 5 other integers:
declare n number; begin n:=1000001; -- this part n:=1000002; -- creates n:=1000003; -- 32768 ... -- integer n:=1032768; -- literals dbms_output.put_line('100000='||100000); -- it should print: 100000=100000 dbms_output.put_line('32766 ='||32766); dbms_output.put_line('32767 ='||32767); dbms_output.put_line('32768 ='||32768); dbms_output.put_line('32769 ='||32769); end;
declare c clob:='declare n number;begin'||chr(10); f varchar2(100):='n:=%s;'||chr(10); v varchar2(32767); n number:=32768; begin for i in 1..n loop v:=v||utl_lms.format_message(f,to_char(1e7+i)); if length(v)>30000 then c:=c||v; v:=''; end if; end loop; v:=v||q'[ dbms_output.put_line('100000='||100000); dbms_output.put_line('32766 ='||32766); dbms_output.put_line('32767 ='||32767); dbms_output.put_line('32768 ='||32768); dbms_output.put_line('32769 ='||32769); end; ]'; c:=c||v; execute immediate c; end; /
100000=10000001 32766 =32766 32767 =32767 32768 =10000002 32769 =10000003
This test case well demonstrates wrong results:
* instead of 100000 we get 10000001, which is the value from first line after “begin”, ie 1st integer literal in the code,
* for 32766 and 32767 oracle returns right values
* instead of 32768 (==32767+1) it returns 10000002, which is the integer from 2nd line, ie 2nd integer literal in the code,
* instead of 32769 (==32767+2) it returns 10000003, which is the integer from 3rd line, ie 3rd integer literal in the code
After several tests I can make a conclusion:
- It doesn’t matter what plsql_optimize_level or plsql_code_type you set, was debug enabled or not, the behaviour is the same.
- It seems that this is a kind of PL/SQL optimization: during parsing, oracle leaves integer literal in place if its value is in range -32768..32767 (16bit signed int), but if its value is out of this range, oracle adds this value into array of integers’ constants and replaces the value with the index of this element in this array. But because of index value overflow in cases when a count of such integer literals becomes larger than 32768, instead of Nth element of this array, oracle returns Mth element, where M is mod(N,32767).
So we can describe this behaviour using first test case:
declare n number; begin n:=1000001; -- this part n:=1000002; -- creates n:=1000003; -- 32768 ... -- integer n:=1032768; -- literals dbms_output.put_line('100000='||100000); -- it should print 100000, ie 32768th element of array, but prints 10000001 -- where 10000001 is the 1st element of array (1==mod(32768,32767)) dbms_output.put_line('32766 ='||32766); -- these 2 lines print right values, dbms_output.put_line('32767 ='||32767); -- because their values are in the range of -32768..32767 dbms_output.put_line('32768 ='||32768); -- this line contains 32769th element and prints 2nd element of array (2==mod(32769,32767)) dbms_output.put_line('32769 ='||32769); -- this line contains 32770th element and prints 3nd element of array (3==mod(32770,32767)) end;
The following query can help you to find objects which can potentially have this problem:
select s.owner,s.name,s.type ,sum(regexp_count(text,'(\W|^)3\d{4,}([^.0-9]|$)')) nums_count -- this regexp counts integer literals >= 30000 from dba_source s where owner='&owner' and type in ('FUNCTION','PROCEDURE','PACKAGE','PACKAGE BODY') group by s.owner,s.name,s.type having sum(regexp_count(text,'(\W|^)3\d{4,}([^.0-9]|$)'))>32767 -- filter only objects which have >=32767 integer literal
Workaround:
You may noticed that I wrote about INTEGER literals only, so the easiest workaround is to make them FLOAT – just add “.” to the end of each literal:
declare n number; begin n:=1000001.; n:=1000002.; n:=1000003.; ... n:=1032768.; dbms_output.put_line('100000='||100000.); dbms_output.put_line('32766 ='||32766.); dbms_output.put_line('32767 ='||32767.); dbms_output.put_line('32768 ='||32768.); dbms_output.put_line('32769 ='||32769.); end;
declare c clob:='declare n number;begin'||chr(10); f varchar2(100):='n:=%s.;'||chr(10); -- I've added here "." v varchar2(32767); n number:=32768; begin for i in 1..n loop v:=v||utl_lms.format_message(f,to_char(1e7+i)); if length(v)>30000 then c:=c||v; v:=''; end if; end loop; v:=v||q'[ dbms_output.put_line('100000='||100000.); -- . dbms_output.put_line('32766 ='||32766.); dbms_output.put_line('32767 ='||32767.); dbms_output.put_line('32768 ='||32768.); dbms_output.put_line('32769 ='||32769.); end; ]'; c:=c||v; execute immediate c; end; /
Ampersand instead of colon for bind variables
I’ve troubleshooted one query today and I was very surprised that bind variables in this query were specified with &ersand instead of :colon! I have never seen this before and I couldn’t find anything about this in documentation…
Unfortunately SQL*Plus doesn’t support ampersand yet, even if you disable define (“set define off”),
so I’ve tested such behaviour with this code:
set def off serverout on exec declare s varchar2(1); begin execute immediate 'select 1 from dual where dummy=&var' into s using 'X'; dbms_output.put_line(s); end;
And it really works! //at least on 11.2.0.2 and 12.2.0.1
SQL> set def off serverout on SQL> exec declare s varchar2(1); begin execute immediate 'select 1 from dual where dummy=&var' into s using 'X'; dbms_output.put_line(s); end; 1 PL/SQL procedure successfully completed. SQL> select substr(sql_text,1,40) stext,sql_id,executions,rows_processed from v$sqlarea a where sql_text like '%dual%&var'; STEXT SQL_ID EXECUTIONS ROWS_PROCESSED ------------------------------------- ------------- ---------- -------------- select 1 from dual where dummy=&var ckkw4u3atxz02 3 3 SQL> select * from table(dbms_xplan.display_cursor('ckkw4u3atxz02')); PLAN_TABLE_OUTPUT -------------------------------------------------------------------------- SQL_ID ckkw4u3atxz02, child number 0 ------------------------------------- select 1 from dual where dummy=&var Plan hash value: 272002086 -------------------------------------------------------------------------- | Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | -------------------------------------------------------------------------- | 0 | SELECT STATEMENT | | | | 2 (100)| | |* 1 | TABLE ACCESS FULL| DUAL | 1 | 2 | 2 (0)| 00:00:01 | -------------------------------------------------------------------------- Predicate Information (identified by operation id): --------------------------------------------------- 1 - filter("DUMMY"=:VAR) 18 rows selected.
Update: Btw, it works for SQL only, not for PL/SQL:
SQL> var v varchar2(1); SQL> begin &v = 'Z'; end; 2 / begin &v = 'Z'; end; * ERROR at line 1: ORA-06550: line 1, column 7: PLS-00103: Encountered the symbol "&" when expecting one of the following: SQL> exec &v := 'X'; BEGIN &v := 'X'; END; * ERROR at line 1: ORA-06550: line 1, column 7: PLS-00103: Encountered the symbol "&" when expecting one of the following: The symbol "&" was ignored.
SQL> exec :v := 'X'; PL/SQL procedure successfully completed. SQL> select * from dual where dummy=&v 2 ; D - X
And we can can use mixed placeholders:
SQL> select * from dual where dummy=&v and &v=:v; D - X
8 queens chess problem: solution in Oracle SQL
This is just another solution of this problem for a chessboard, but you can choose any size of the checkerboard:
with t as (select level i, cast(level as varchar2(1)) c from dual connect by level<=&d) ,x(l,s,n) as ( select 1 l, c s, chr(97)||c||' ' from t union all select l+1, x.s||t.c, n||chr(97+l)||i||' ' from x join t on instr(s,c)=0 and not exists(select 0 from dual where L+1 - t.i = level - substr(s,level,1) or L+1 + t.i = level + substr(s,level,1) connect by level<=length(s)) where L<&d ) select n from x where l=&d
SQL> @tests/f Size[8]: 8 N -------------------------------------------------------------------------------- a1 b5 c8 d6 e3 f7 g2 h4 a1 b6 c8 d3 e7 f4 g2 h5 a1 b7 c4 d6 e8 f2 g5 h3 a1 b7 c5 d8 e2 f4 g6 h3 a2 b4 c6 d8 e3 f1 g7 h5 a2 b5 c7 d1 e3 f8 g6 h4 a2 b5 c7 d4 e1 f8 g6 h3 a2 b6 c1 d7 e4 f8 g3 h5 a2 b6 c8 d3 e1 f4 g7 h5 a2 b7 c3 d6 e8 f5 g1 h4 a2 b7 c5 d8 e1 f4 g6 h3 a2 b8 c6 d1 e3 f5 g7 h4 a3 b1 c7 d5 e8 f2 g4 h6 a3 b5 c2 d8 e1 f7 g4 h6 a3 b5 c2 d8 e6 f4 g7 h1 a3 b5 c7 d1 e4 f2 g8 h6 a3 b5 c8 d4 e1 f7 g2 h6 a3 b6 c2 d5 e8 f1 g7 h4 a3 b6 c2 d7 e1 f4 g8 h5 a3 b6 c2 d7 e5 f1 g8 h4 a3 b6 c4 d1 e8 f5 g7 h2 a3 b6 c4 d2 e8 f5 g7 h1 a3 b6 c8 d1 e4 f7 g5 h2 a3 b6 c8 d1 e5 f7 g2 h4 a3 b6 c8 d2 e4 f1 g7 h5 a3 b7 c2 d8 e5 f1 g4 h6 a3 b7 c2 d8 e6 f4 g1 h5 a3 b8 c4 d7 e1 f6 g2 h5 a4 b1 c5 d8 e2 f7 g3 h6 a4 b1 c5 d8 e6 f3 g7 h2 a4 b2 c5 d8 e6 f1 g3 h7 a4 b2 c7 d3 e6 f8 g1 h5 a4 b2 c7 d3 e6 f8 g5 h1 a4 b2 c7 d5 e1 f8 g6 h3 a4 b2 c8 d5 e7 f1 g3 h6 a4 b2 c8 d6 e1 f3 g5 h7 a4 b6 c1 d5 e2 f8 g3 h7 a4 b6 c8 d2 e7 f1 g3 h5 a4 b6 c8 d3 e1 f7 g5 h2 a4 b7 c1 d8 e5 f2 g6 h3 a4 b7 c3 d8 e2 f5 g1 h6 a4 b7 c5 d2 e6 f1 g3 h8 a4 b7 c5 d3 e1 f6 g8 h2 a4 b8 c1 d3 e6 f2 g7 h5 a4 b8 c1 d5 e7 f2 g6 h3 a4 b8 c5 d3 e1 f7 g2 h6 a5 b1 c4 d6 e8 f2 g7 h3 a5 b1 c8 d4 e2 f7 g3 h6 a5 b1 c8 d6 e3 f7 g2 h4 a5 b2 c4 d6 e8 f3 g1 h7 a5 b2 c4 d7 e3 f8 g6 h1 a5 b2 c6 d1 e7 f4 g8 h3 a5 b2 c8 d1 e4 f7 g3 h6 a5 b3 c1 d6 e8 f2 g4 h7 a5 b3 c1 d7 e2 f8 g6 h4 a5 b3 c8 d4 e7 f1 g6 h2 a5 b7 c1 d3 e8 f6 g4 h2 a5 b7 c1 d4 e2 f8 g6 h3 a5 b7 c2 d4 e8 f1 g3 h6 a5 b7 c2 d6 e3 f1 g4 h8 a5 b7 c2 d6 e3 f1 g8 h4 a5 b7 c4 d1 e3 f8 g6 h2 a5 b8 c4 d1 e3 f6 g2 h7 a5 b8 c4 d1 e7 f2 g6 h3 a6 b1 c5 d2 e8 f3 g7 h4 a6 b2 c7 d1 e3 f5 g8 h4 a6 b2 c7 d1 e4 f8 g5 h3 a6 b3 c1 d7 e5 f8 g2 h4 a6 b3 c1 d8 e4 f2 g7 h5 a6 b3 c1 d8 e5 f2 g4 h7 a6 b3 c5 d7 e1 f4 g2 h8 a6 b3 c5 d8 e1 f4 g2 h7 a6 b3 c7 d2 e4 f8 g1 h5 a6 b3 c7 d2 e8 f5 g1 h4 a6 b3 c7 d4 e1 f8 g2 h5 a6 b4 c1 d5 e8 f2 g7 h3 a6 b4 c2 d8 e5 f7 g1 h3 a6 b4 c7 d1 e3 f5 g2 h8 a6 b4 c7 d1 e8 f2 g5 h3 a6 b8 c2 d4 e1 f7 g5 h3 a7 b1 c3 d8 e6 f4 g2 h5 a7 b2 c4 d1 e8 f5 g3 h6 a7 b2 c6 d3 e1 f4 g8 h5 a7 b3 c1 d6 e8 f5 g2 h4 a7 b3 c8 d2 e5 f1 g6 h4 a7 b4 c2 d5 e8 f1 g3 h6 a7 b4 c2 d8 e6 f1 g3 h5 a7 b5 c3 d1 e6 f8 g2 h4 a8 b2 c4 d1 e7 f5 g3 h6 a8 b2 c5 d3 e1 f7 g4 h6 a8 b3 c1 d6 e2 f5 g7 h4 a8 b4 c1 d3 e6 f2 g7 h5 92 rows selected.
with t as (select level i, to_char(level,'fm00') c from dual connect by level<=&d) ,x(l,s,n) as ( select 1 l, c s, chr(97)||c||' ' from t union all select l+1, x.s||t.c, n||chr(97+l)||to_char(i,'fm00')||' ' from x join t on instr(s,c)=0 and not exists(select 0 from dual where L+1 - t.i = level - substr(s,length(c)*level-1,length(c)) or L+1 + t.i = level + substr(s,length(c)*level-1,length(c)) connect by level<=length(s)) where L<&d ) select n from x where l=&d
It works quite fast:
8*8 ~ 0.1s
9*9 ~ 0.6s
10*10 ~4s
set arrays 1000; col n for a80; accept d prompt "Size[8]: " default 8; with t as (select/*+inline*/ level i, cast(level as varchar2(2)) c from dual connect by level<=&d) ,x(l,s,n) as ( select 1 l, c s, chr(97)||c||' ' from t union all select l+1, x.s||t.c, n||chr(97+l)||i||' ' from x join t on instr(s,c)=0 and not exists(select 0 from dual where L+1 - t.i = level - substr(s,level,1) or L+1 + t.i = level + substr(s,level,1) connect by level<=length(s)) where L<&d ) select n from x where l=&d / col n clear;
Update: Fixed the typo, thanks to Brian Fitzgerald (@ExaGridDba)
A function gets called twice if the result_cache is used
Recently I showed simple example how result_cache works with non-deterministic functions and observed strange behaviour: a function gets fired once in the normal query, but twice with the result_cache hint.
Moreover, only third and subsequent query executions return same cached results as second query execution.
I didn’t want to investigate such behavior, just because 1) we should not cache the results of non-deterministic functions and 2) it doesn’t matter if we use deterministic functions.
But later I was asked to explain this, so this post is just a short description with test case.
Look at the simple function that just returns random values:
create or replace function f_nondeterministic(p int:=100) return int as res number; begin res:=round(dbms_random.value(0,p)); return res; end;
SQL> exec dbms_result_cache.flush; PL/SQL procedure successfully completed. SQL> select/*+ result_cache */ f_nondeterministic(1000) nondeter from dual; NONDETER ---------- 481 SQL> select/*+ result_cache */ f_nondeterministic(1000) nondeter from dual; NONDETER ---------- 689 SQL> select/*+ result_cache */ f_nondeterministic(1000) nondeter from dual; NONDETER ---------- 689
SQL> exec dbms_result_cache.flush; PL/SQL procedure successfully completed. SQL> select/*+ result_cache */ f_nondeterministic(1000) nondeter from dual; NONDETER ---------- 481 SQL> select name,value from v$result_cache_statistics where name in ( 'Create Count Success', 'Find Count'); NAME VALUE -------------------------------------------------- ---------- Create Count Success 1 Find Count 0 SQL> select/*+ result_cache */ f_nondeterministic(1000) nondeter from dual; NONDETER ---------- 689 SQL> select name,value from v$result_cache_statistics where name in ( 'Create Count Success', 'Find Count'); NAME VALUE -------------------------------------------------- ---------- Create Count Success 1 Find Count 1 SQL> select/*+ result_cache */ f_nondeterministic(1000) nondeter from dual; NONDETER ---------- 689 SQL> select name,value from v$result_cache_statistics where name in ( 'Create Count Success', 'Find Count'); NAME VALUE -------------------------------------------------- ---------- Create Count Success 1 Find Count 2 SQL> select name,bucket_no, id,type,status,pin_count,scan_count,invalidations from v$result_cache_objects o; NAME BUCKET_NO ID TYPE STATUS PIN_COUNT SCAN_COUNT INVALIDATIONS -------------------------------------------------- ---------- ---------- ---------- --------- ---------- ---------- ------------- XTENDER.F_NONDETERMINISTIC 552 0 Dependency Published 0 0 0 select/*+ result_cache */ f_nondeterministic(1000) 2102 1 Result Published 0 2 0 nondeter from dual
As you can see, second execution returns different result than first one.
If we change this function:
create or replace function f_nondeterministic(p int:=100) return int as res number; begin res:=round(dbms_random.value(0,p)); dbms_output.put_line('fired! ('||res||')'); return res; end;
and repeat this test-case:
SQL> select/*+ result_cache */ f_nondeterministic(1000) nondeter from dual; NONDETER ---------- 943 -- << (2) 1 row selected. fired! (607) -- << (1) fired! (943) -- << (2) SQL> / NONDETER ---------- 607 -- << (1) 1 row selected. SQL> / NONDETER ---------- 607 -- << (1) 1 row selected. SQL> / NONDETER ---------- 607 -- << (1) 1 row selected.
we will see that there were 2 function executions: first result was cached, and the second was fetched!