Sokrates on Oracle

Tom’s print_table as a SQL Macro

Posted by Matthias Rogel on 5. May 2021

I have used Tom Kyte’s “print_table” (Jonathan Lewis has archived the code on https://jonathanlewis.wordpress.com/2020/11/26/print_table ) quite a lot during the last nearly 20 years. There are many use cases where it comes in handy to have a resultset of a query formatted as one row “per column per row”. I have adapted the above mentioned code into a pipelined table function fprint_table, so I can do a

select * from table(fprint_table(q'| <whatever query> |'))

, which I find even more useful. However it is a pain to parse back again the column-names of the original-query (using substr), so I always wished there was sometimes some native method to have the “one row per column per row” – result in the form “ROW / COLUMN / VALUE”. Having watched Chris Saxon’s fantastic presentation on Pattern Matching and SQL Macros ( google for “sql macro chris saxon” – code on https://livesql.oracle.com/apex/livesql/file/content_KPBT70LOJM9EIEWT5WWQTMXRN.html ) it was clear to me that SQL Macros could do that.

Since I am currently ill (learnt a new word this week – “lumboischialgia” – which is no fun especially when it is bilateral !), I decided to play around a bit with Oracle 21 (and especially SQL Macros) on my Oracle Always Free account and see how to implement that.

First of all, it is clear that different columns of a query can have different datatypes and in order to have “VALUE” support all those datatypes, it either has to be an ANYDATA or we have to transform other datatypes than VARCHAR2 and CHAR into VARCHAR2. I decided to go for the latter option (ANYDATA is a bit bulky IMO and Tom’s print_table also simply converts everything into VARCHAR2, so I should be also allowed to do so 🙂). So, first we need a SQL Macro to convert all columns of a table into VARCHAR2s. Here we go

create or replace function tab_to_char(p_tab dbms_tf.table_t)
  return clob sql_macro(table)
is
  ret clob;
begin
  ret := 'select ';
  for i in 1 .. tab_to_char.p_tab.column.count loop
    ret := 
	  ret || 
	  'to_char(' || tab_to_char.p_tab.column(i).description.name || 
          ') as ' || trim(both '"' from tab_to_char.p_tab.column(i).description.name) ||
	  case when i < tab_to_char.p_tab.column.count then ', ' end;
  end loop;
  ret := ret || ' from p_tab';
  
  -- dbms_output.put_line(ret);
  return ret;
end tab_to_char;
/ 

In short, we just apply to_char() to every column (works for DATE, NUMBER, TIMESTAMP, is not needed but also works for VARCHAR2, works also for INTERVAL). Let’s try it out ! Of course, we need some sample data, so I collected some of the titles of my favourite football team 1. FC Kaiserslautern into a table.


create table titles_kaiserslautern(
  what 			varchar2(30),
  when 			date,
  spectators 	number,
  remark 		varchar2(100)
);

insert into titles_kaiserslautern values('German Championship', date'1951-06-30', 85000, '2:1 against Preußen Münster in Berlin');
insert into titles_kaiserslautern values('German Championship', date'1953-06-21', 80000, '4:1 against VfB Stuttgart in Berlin');
insert into titles_kaiserslautern values('German Cup Winner', date'1990-05-19', 76391, '3:2 against Werder Bremen in Berlin');
insert into titles_kaiserslautern values('German Championship', date'1991-06-15', 55000, '6:2 against 1. FC Köln in Köln');
insert into titles_kaiserslautern values('German Supercup', date'1991-08-06', 8000, '3:1 against Werder Bremen in Hannover');
insert into titles_kaiserslautern values('German Cup Winner', date'1996-05-25', 75800, '1:0 against Karlsruher SC in Berlin');
insert into titles_kaiserslautern values('German Championship', date'1998-05-02', 38000, '4:0 against VfL Wolfsburg in Kaiserslautern');
  
commit;

Now, let’s see what tab_to_char does to it – for the sake of briefness let’s restrict to the German championships –

SQL> with championships as (select * from titles_kaiserslautern where what = 'German Championship' order by when)
  2  select * from tab_to_char(championships);

WHAT                   WHEN               SPECTATORS   REMARK
---------------------- ------------------ ------------ --------------------------------------------------
German Championship    30-JUN-51          85000        2:1 against Preußen Münster in Berlin
German Championship    21-JUN-53          80000        4:1 against VfB Stuttgart in Berlin
German Championship    15-JUN-91          55000        6:2 against 1. FC Köln in Köln
German Championship    02-MAY-98          38000        4:0 against VfL Wolfsburg in Kaiserslautern

Hmm, does not look other than the result of a

select * from titles_kaiserslautern where what = 'German Championship' order by when;

of course, since everything is converted to VARCHAR2 (note that the calls to to_char in tab_to_char use the current NLS-settings of the session rather than set explicitly the NLS_DATE_FORMAT as Tom did in the above mentioned code) and hence it makes no difference for our eyes. However, it is needed at that step as in the next step we will use UNPIVOT to unpivot all columns into a single column (and this needs them to be of the same datatype !). Note also that the next step is a SQL Macro calling our first SQL Macro. Here it is:

create or replace function print_table(p_tab dbms_tf.table_t)
  return clob sql_macro(table)
is
  ret clob;
begin
  ret := 'select 
  * 
from 
  (select * from (select rownum as "ROW", t.* from tab_to_char(p_tab) t)) 
  unpivot include nulls (
    value
    for "COLUMN" in
    (
';
  for i in 1 .. print_table.p_tab.column.count loop
    ret := 
	  ret || 
	  '      ' || trim(both '"' from print_table.p_tab.column(i).description.name) 
	  || ' as ''' || trim(both '"' from print_table.p_tab.column(i).description.name) || '''' ||
	  case when i < print_table.p_tab.column.count then ', ' end || chr(10);
  end loop;
  ret := 
    ret || '
    )
  )';
  
  -- dbms_output.put_line(ret);
  return ret;
  
end print_table;
/ 

and in all its beauty we get

SQL> select * from print_table(titles_kaiserslautern);

       ROW COLUMN     VALUE
---------- ---------- ---------------------------------------------
         1 WHAT       German Championship
         1 WHEN       30-JUN-51
         1 SPECTATORS 85000
         1 REMARK     2:1 against Preußen Münster in Berlin
         2 WHAT       German Championship
         2 WHEN       21-JUN-53
         2 SPECTATORS 80000
         2 REMARK     4:1 against VfB Stuttgart in Berlin
         3 WHAT       German Cup Winner
         3 WHEN       19-MAY-90
         3 SPECTATORS 76391
         3 REMARK     3:2 against Werder Bremen in Berlin
         4 WHAT       German Championship
         4 WHEN       15-JUN-91
         4 SPECTATORS 55000
         4 REMARK     6:2 against 1. FC Köln in Köln
         5 WHAT       German Supercup
         5 WHEN       06-AUG-91
         5 SPECTATORS 8000
         5 REMARK     3:1 against Werder Bremen in Hannover
         6 WHAT       German Cup Winner
         6 WHEN       25-MAY-96
         6 SPECTATORS 75800
         6 REMARK     1:0 against Karlsruher SC in Berlin
         7 WHAT       German Championship
         7 WHEN       02-MAY-98
         7 SPECTATORS 38000
         7 REMARK     4:0 against VfL Wolfsburg in Kaiserslautern

28 rows selected.

The argument of print_table does not need to be a table, it also can be a subquery:

SQL> with s as (select * from titles_kaiserslautern where spectators < 50000 order by spectators)
  2  select * from print_table(s);

       ROW COLUMN     VALUE
---------- ---------- ---------------------------------------------
         1 WHAT       German Supercup
         1 WHEN       06-AUG-91
         1 SPECTATORS 8000
         1 REMARK     3:1 against Werder Bremen in Hannover
         2 WHAT       German Championship
         2 WHEN       02-MAY-98
         2 SPECTATORS 38000
         2 REMARK     4:0 against VfL Wolfsburg in Kaiserslautern

8 rows selected.

Finally, I learnt a new Oracle-exception. Of course I could not resist to use a subquery using print_table to be the input for print_table. However:

SQL> with s as (select * from print_table(titles_kaiserslautern))
  2  select * from print_table(s);
with s as (select * from print_table(titles_kaiserslautern))
*
ERROR at line 1:
ORA-64630: unsupported use of SQL macro: use of SQL macro inside WITH clause is not supported

My conclusion: SQL macros are really cool stuff ! Great we have them available !

Posted in Allgemein | Leave a Comment »

Find first n gaps in integer primary key

Posted by Matthias Rogel on 13. September 2016

Setup

sokrates@12.1 > create table t( pk int primary key check(pk > 0));

Table created.

sokrates@12.1 > insert /*+ignore_row_on_dupkey_index(t(pk)) */ into t
sokrates@12.1 > select trunc(dbms_random.value(1, 1e5)) from dual
sokrates@12.1 > connect by level <= 1e5 
sokrates@12.1 > /

63187 rows created.

Finding the first n gaps

sokrates@12.1 > variable n number
sokrates@12.1 > exec :n := 1000

PL/SQL procedure successfully completed.

sokrates@12.1 > set autotr traceonly timi on
sokrates@12.1 > with
sokrates@12.1 > gaps(g, counter, isgap) as
sokrates@12.1 > (
sokrates@12.1 >    select 0, 1, cast(null as varchar2(1)) from dual
sokrates@12.1 >    union all
sokrates@12.1 >    select
sokrates@12.1 >       gaps.g + 1,
sokrates@12.1 >       gaps.counter + case when t.pk is null then 1 else 0 end,
sokrates@12.1 >       case when t.pk is null then 'x' end
sokrates@12.1 >    from gaps, t
sokrates@12.1 >    where gaps.counter <= :n
sokrates@12.1 >    and t.pk(+) = gaps.g + 1
sokrates@12.1 > )
sokrates@12.1 > search breadth first by g asc set o
sokrates@12.1 > cycle g set is_cycle to 1 default 0
sokrates@12.1 > select
sokrates@12.1 >    gaps.g
sokrates@12.1 > from
sokrates@12.1 >    gaps
sokrates@12.1 > where
sokrates@12.1 >    gaps.isgap = 'x'
sokrates@12.1 > /

1000 rows selected.

Elapsed: 00:00:00.12

Execution Plan
----------------------------------------------------------
Plan hash value: 3013247790

----------------------------------------------------------------------------------------------------------
| Id  | Operation                                 | Name         | Rows  | Bytes | Cost (%CPU)| Time  |
----------------------------------------------------------------------------------------------------------
|   0 | SELECT STATEMENT                          |              |     2 |    30 |     5  (20)| 00:00:01 |
|*  1 |  VIEW                                     |              |     2 |    30 |     5  (20)| 00:00:01 |
|   2 |   UNION ALL (RECURSIVE WITH) BREADTH FIRST|              |       |       |            |       |
|   3 |    FAST DUAL                              |              |     1 |       |     2   (0)| 00:00:01 |
|   4 |    NESTED LOOPS OUTER                     |              |     1 |    39 |     2   (0)| 00:00:01 |
|*  5 |     RECURSIVE WITH PUMP                   |              |       |       |            |       |
|*  6 |     INDEX UNIQUE SCAN                     | SYS_C0087690 |     1 |    13 |     0   (0)| 00:00:01 |
----------------------------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   1 - filter("GAPS"."ISGAP"='x')
   5 - filter("GAPS"."COUNTER"<=TO_NUMBER(:N))
   6 - access("T"."PK"(+)="GAPS"."G"+1)

Note
-----
   - dynamic statistics used: dynamic sampling (level=2)


Statistics
----------------------------------------------------------
          0  recursive calls
          0  db block gets
       2656  consistent gets
          0  physical reads
          0  redo size
       9313  bytes sent via SQL*Net to client
        500  bytes received via SQL*Net from client
          2  SQL*Net roundtrips to/from client
       2635  sorts (memory)
          0  sorts (disk)
       1000  rows processed

Posted in Allgemein, sql | 3 Comments »

Nominated for Oracle Database Developer Choice Awards (SQL) – San Francisco calling

Posted by Matthias Rogel on 2. October 2015

I don’t know why and by whom, but I was nominated for the Oracle Database Developer Choice Awards – SQL Category as one of eight SQL developers.

a1

Cite from https://community.oracle.com/community/database/awards:

….

The Oracle Database Developer Choice Awards celebrate and recognize technical expertise and contributions in the Oracle Database community. As longtime and new users of Oracle Database move to the Cloud and take advantage of this exciting new architecture, community experts will play a critical role in helping them succeed.

, so I am quite happy to be part of such an illustrious selection.

Until 15th of October everyone with an otn-account can still vote on https://community.oracle.com/community/database/awards/sql-voting.

I know Stew, Kim and Sayan quite well from “the community” and so I am aware of the fact they deserve it more than me, but anyway – you can still vote for me ( I’m quite sure I’m the sexiest of the candidates – for this reason I already was always chosen as class representative in school 😉 )

Nice side effect: somehow my boss got wind of the whole thing and so he will send me to OOW 2015 regardless of the result of the voting.

So, looking quite forward to go and hopefully meet quite a lot of  you guys there !

Posted in Allgemein | Leave a Comment »

The Fundamental theorem of arithmetic – SQL version

Posted by Matthias Rogel on 26. May 2015

Every positive integer (except the number 1) can be represented in exactly one way apart from rearrangement as a product of one or more primes, see for example Wolfram MathWorld or Wikipedia.

Here is the SQL-Version, we compute this for all integers up to 100

with bound as
(
select 100 as bound from dual
),
n_until_bound as (
select level+1 n
from dual
connect by level <= (select bound.bound from bound)
),
primes_under_bound as
(
select n_until_bound.n as prime
from n_until_bound
minus
select n1.n * n2.n
from n_until_bound n1, n_until_bound n2
where n1.n <= n2.n
and n1.n <= (select sqrt(bound.bound) from bound)
),
primepowers_until_bound as
(
select p.prime, l.exponent
from primes_under_bound p, lateral(select level as exponent from dual connect by level <= log(p.prime, (select bound.bound from bound))) l
),
factors as
(
select n.n, pb.prime, pb.exponent
from n_until_bound n, primepowers_until_bound pb
where mod(n.n, power(pb.prime, pb.exponent)) = 0
),
largestfactors as
(
select
 f.n, f.prime, min(f.exponent) keep(dense_rank first order by f.exponent desc) as exponent
from factors f
group by f.n, f.prime
)
select /*+pallel */ lf.n || ' = ' || listagg(lf.prime || case when lf.exponent > 1 then ' ^ ' || lf.exponent end, ' * ') within group(order by lf.prime asc) as factorization
from largestfactors lf
group by lf.n
order by lf.n
FACTORIZATION
----------------------------------------------------------------------------------------------------
2 = 2
3 = 3
4 = 2 ^ 2
5 = 5
6 = 2 * 3
7 = 7
8 = 2 ^ 3
9 = 3 ^ 2
10 = 2 * 5
11 = 11
12 = 2 ^ 2 * 3
13 = 13
14 = 2 * 7
15 = 3 * 5
16 = 2 ^ 4
17 = 17
18 = 2 * 3 ^ 2
19 = 19
20 = 2 ^ 2 * 5
21 = 3 * 7
22 = 2 * 11
23 = 23
24 = 2 ^ 3 * 3
25 = 5 ^ 2
26 = 2 * 13
27 = 3 ^ 3
28 = 2 ^ 2 * 7
29 = 29
30 = 2 * 3 * 5
31 = 31
32 = 2 ^ 5
33 = 3 * 11
34 = 2 * 17
35 = 5 * 7
36 = 2 ^ 2 * 3 ^ 2
37 = 37
38 = 2 * 19
39 = 3 * 13
40 = 2 ^ 3 * 5
41 = 41
42 = 2 * 3 * 7
43 = 43
44 = 2 ^ 2 * 11
45 = 3 ^ 2 * 5
46 = 2 * 23
47 = 47
48 = 2 ^ 4 * 3
49 = 7 ^ 2
50 = 2 * 5 ^ 2
51 = 3 * 17
52 = 2 ^ 2 * 13
53 = 53
54 = 2 * 3 ^ 3
55 = 5 * 11
56 = 2 ^ 3 * 7
57 = 3 * 19
58 = 2 * 29
59 = 59
60 = 2 ^ 2 * 3 * 5
61 = 61
62 = 2 * 31
63 = 3 ^ 2 * 7
64 = 2 ^ 6
65 = 5 * 13
66 = 2 * 3 * 11
67 = 67
68 = 2 ^ 2 * 17
69 = 3 * 23
70 = 2 * 5 * 7
71 = 71
72 = 2 ^ 3 * 3 ^ 2
73 = 73
74 = 2 * 37
75 = 3 * 5 ^ 2
76 = 2 ^ 2 * 19
77 = 7 * 11
78 = 2 * 3 * 13
79 = 79
80 = 2 ^ 4 * 5
81 = 3 ^ 4
82 = 2 * 41
83 = 83
84 = 2 ^ 2 * 3 * 7
85 = 5 * 17
86 = 2 * 43
87 = 3 * 29
88 = 2 ^ 3 * 11
89 = 89
90 = 2 * 3 ^ 2 * 5
91 = 7 * 13
92 = 2 ^ 2 * 23
93 = 3 * 31
94 = 2 * 47
95 = 5 * 19
96 = 2 ^ 5 * 3
97 = 97
98 = 2 * 7 ^ 2
99 = 3 ^ 2 * 11
100 = 2 ^ 2 * 5 ^ 2

Posted in fun, sql | Tagged: , | 1 Comment »

A Greedy Algorithm using Recursive subquery factoring ( or better – read the comments – using pattern matching)

Posted by Matthias Rogel on 22. May 2015

Today is friday and I like the twitter-hashtag #FibonacciFriday,
so I tweeted

 

Don’t be afraid of having a look at the wikipedia-site, the math is not complicated at all ( you don’t need more than adding natural numbers smaller than hundred ), nevertheless the theorem is nice from a mathematical point of view.

And there is also mentioned

… For any given positive integer, a representation that satisfies the conditions of Zeckendorf’s theorem can be found by using a greedy algorithm, choosing the largest possible Fibonacci number at each stage. …

After thinking a bit about it, I came to the idea to implement it solely in SQL which might show the strength of this language.

Here we go, we compute the Zeckendorf representations of the first 200 natural numbers in SQL.

If you are not familiar with the xmlquery-part of it, see what Tom Kyte learned from me


with
n as
(
 /* the first 200 natural numbers */
 select level as n
 from dual
 connect by level <= 200
),
f(n, a, b) as
(
 /* construct fibonaccis, 30 are surely enough ... */
 select 1 as n, 1 as a, 1 as b
 from dual
 union all
 select n+1, b, a+b
 from f
 where n<=30
)
,
fibonaccis as
(
 select
 f.a as f
 from f
),
decomp(n, s) as
(
 /* here is the magic recursive subquery factoring */
 select
 n.n,
 (select cast(max(fibonaccis.f) as varchar2(100)) from fibonaccis where fibonaccis.f <= n.n)
 from n
 union all
 select
 d.n,
 rtrim
 (
 d.s || ' + ' ||
 (
 select cast(max(fibonaccis.f) as varchar2(10))
 from fibonaccis
 where fibonaccis.f <= d.n - xmlquery(d.s returning content).getNumberVal()
 ),
 ' + '
 )
 from decomp d
 where
 d.s !=
 rtrim
 (
 d.s || ' + ' ||
 (
 select cast(max(fibonaccis.f) as varchar2(10))
 from fibonaccis
 where fibonaccis.f <= d.n - xmlquery(d.s returning content).getNumberVal()
 ),
 ' + '
 )
)
/* we only want "the last" decomp, the one with maximal length */
select
 decomp.n ||
 ' = ' ||
 min(decomp.s) keep(dense_rank first order by length(decomp.s) desc)
 as zeckendorf_representation
from decomp
group by decomp.n
order by decomp.n
/

ZECKENDORF_REPRESENTATION
------------------------------------------------------------------------------------------------------------------------------------------------------------
1 = 1
2 = 2
3 = 3
4 = 3 + 1
5 = 5
6 = 5 + 1
7 = 5 + 2
8 = 8
9 = 8 + 1
10 = 8 + 2
11 = 8 + 3
12 = 8 + 3 + 1
13 = 13
14 = 13 + 1
15 = 13 + 2
16 = 13 + 3
17 = 13 + 3 + 1
18 = 13 + 5
19 = 13 + 5 + 1
20 = 13 + 5 + 2
21 = 21
22 = 21 + 1
23 = 21 + 2
24 = 21 + 3
25 = 21 + 3 + 1
26 = 21 + 5
27 = 21 + 5 + 1
28 = 21 + 5 + 2
29 = 21 + 8
30 = 21 + 8 + 1
31 = 21 + 8 + 2
32 = 21 + 8 + 3
33 = 21 + 8 + 3 + 1
34 = 34
35 = 34 + 1
36 = 34 + 2
37 = 34 + 3
38 = 34 + 3 + 1
39 = 34 + 5
40 = 34 + 5 + 1
41 = 34 + 5 + 2
42 = 34 + 8
43 = 34 + 8 + 1
44 = 34 + 8 + 2
45 = 34 + 8 + 3
46 = 34 + 8 + 3 + 1
47 = 34 + 13
48 = 34 + 13 + 1
49 = 34 + 13 + 2
50 = 34 + 13 + 3
51 = 34 + 13 + 3 + 1
52 = 34 + 13 + 5
53 = 34 + 13 + 5 + 1
54 = 34 + 13 + 5 + 2
55 = 55
56 = 55 + 1
57 = 55 + 2
58 = 55 + 3
59 = 55 + 3 + 1
60 = 55 + 5
61 = 55 + 5 + 1
62 = 55 + 5 + 2
63 = 55 + 8
64 = 55 + 8 + 1
65 = 55 + 8 + 2
66 = 55 + 8 + 3
67 = 55 + 8 + 3 + 1
68 = 55 + 13
69 = 55 + 13 + 1
70 = 55 + 13 + 2
71 = 55 + 13 + 3
72 = 55 + 13 + 3 + 1
73 = 55 + 13 + 5
74 = 55 + 13 + 5 + 1
75 = 55 + 13 + 5 + 2
76 = 55 + 21
77 = 55 + 21 + 1
78 = 55 + 21 + 2
79 = 55 + 21 + 3
80 = 55 + 21 + 3 + 1
81 = 55 + 21 + 5
82 = 55 + 21 + 5 + 1
83 = 55 + 21 + 5 + 2
84 = 55 + 21 + 8
85 = 55 + 21 + 8 + 1
86 = 55 + 21 + 8 + 2
87 = 55 + 21 + 8 + 3
88 = 55 + 21 + 8 + 3 + 1
89 = 89
90 = 89 + 1
91 = 89 + 2
92 = 89 + 3
93 = 89 + 3 + 1
94 = 89 + 5
95 = 89 + 5 + 1
96 = 89 + 5 + 2
97 = 89 + 8
98 = 89 + 8 + 1
99 = 89 + 8 + 2
100 = 89 + 8 + 3
101 = 89 + 8 + 3 + 1
102 = 89 + 13
103 = 89 + 13 + 1
104 = 89 + 13 + 2
105 = 89 + 13 + 3
106 = 89 + 13 + 3 + 1
107 = 89 + 13 + 5
108 = 89 + 13 + 5 + 1
109 = 89 + 13 + 5 + 2
110 = 89 + 21
111 = 89 + 21 + 1
112 = 89 + 21 + 2
113 = 89 + 21 + 3
114 = 89 + 21 + 3 + 1
115 = 89 + 21 + 5
116 = 89 + 21 + 5 + 1
117 = 89 + 21 + 5 + 2
118 = 89 + 21 + 8
119 = 89 + 21 + 8 + 1
120 = 89 + 21 + 8 + 2
121 = 89 + 21 + 8 + 3
122 = 89 + 21 + 8 + 3 + 1
123 = 89 + 34
124 = 89 + 34 + 1
125 = 89 + 34 + 2
126 = 89 + 34 + 3
127 = 89 + 34 + 3 + 1
128 = 89 + 34 + 5
129 = 89 + 34 + 5 + 1
130 = 89 + 34 + 5 + 2
131 = 89 + 34 + 8
132 = 89 + 34 + 8 + 1
133 = 89 + 34 + 8 + 2
134 = 89 + 34 + 8 + 3
135 = 89 + 34 + 8 + 3 + 1
136 = 89 + 34 + 13
137 = 89 + 34 + 13 + 1
138 = 89 + 34 + 13 + 2
139 = 89 + 34 + 13 + 3
140 = 89 + 34 + 13 + 3 + 1
141 = 89 + 34 + 13 + 5
142 = 89 + 34 + 13 + 5 + 1
143 = 89 + 34 + 13 + 5 + 2
144 = 144
145 = 144 + 1
146 = 144 + 2
147 = 144 + 3
148 = 144 + 3 + 1
149 = 144 + 5
150 = 144 + 5 + 1
151 = 144 + 5 + 2
152 = 144 + 8
153 = 144 + 8 + 1
154 = 144 + 8 + 2
155 = 144 + 8 + 3
156 = 144 + 8 + 3 + 1
157 = 144 + 13
158 = 144 + 13 + 1
159 = 144 + 13 + 2
160 = 144 + 13 + 3
161 = 144 + 13 + 3 + 1
162 = 144 + 13 + 5
163 = 144 + 13 + 5 + 1
164 = 144 + 13 + 5 + 2
165 = 144 + 21
166 = 144 + 21 + 1
167 = 144 + 21 + 2
168 = 144 + 21 + 3
169 = 144 + 21 + 3 + 1
170 = 144 + 21 + 5
171 = 144 + 21 + 5 + 1
172 = 144 + 21 + 5 + 2
173 = 144 + 21 + 8
174 = 144 + 21 + 8 + 1
175 = 144 + 21 + 8 + 2
176 = 144 + 21 + 8 + 3
177 = 144 + 21 + 8 + 3 + 1
178 = 144 + 34
179 = 144 + 34 + 1
180 = 144 + 34 + 2
181 = 144 + 34 + 3
182 = 144 + 34 + 3 + 1
183 = 144 + 34 + 5
184 = 144 + 34 + 5 + 1
185 = 144 + 34 + 5 + 2
186 = 144 + 34 + 8
187 = 144 + 34 + 8 + 1
188 = 144 + 34 + 8 + 2
189 = 144 + 34 + 8 + 3
190 = 144 + 34 + 8 + 3 + 1
191 = 144 + 34 + 13
192 = 144 + 34 + 13 + 1
193 = 144 + 34 + 13 + 2
194 = 144 + 34 + 13 + 3
195 = 144 + 34 + 13 + 3 + 1
196 = 144 + 34 + 13 + 5
197 = 144 + 34 + 13 + 5 + 1
198 = 144 + 34 + 13 + 5 + 2
199 = 144 + 55
200 = 144 + 55 + 1

200 rows selected.

Elapsed: 00:01:28.71

Posted in fun, sql | Tagged: , | 6 Comments »

Overview of all time changes this year via SQL

Posted by Matthias Rogel on 30. March 2015

inspired by Laurent Schneider’s remark concerning special time changes in Lord Howe Island


with dates as
(
select
trunc(sysdate, 'year') + level - 1 as day
from
dual
connect by
extract(year from trunc(sysdate, 'year') + level - 1) = extract(year from trunc(sysdate, 'year'))
),

timezones as
(
select
vtn.TZNAME, listagg(vtn.TZABBREV, ', ') within group(order by vtn.tzabbrev) tzabbrevs
from
v$timezone_names vtn
group by
vtn.TZNAME
),

offsets as
(
select
v.*, d.day,
24 * (cast(from_tz(cast(d.day as timestamp), 'UTC') at time zone v.TZNAME as date) - d.day) as offset
from
timezones v, dates d
),

changes as
(
select
d.*, d.loffset - d.offset offset_change,
case when d.loffset > d.offset then 'DST start' else 'DST end' end as time_change
from
(
select
o.*, lead(o.offset) over(partition by o.tzname order by o.day) loffset
from offsets o
) d
where d.offset != d.loffset
)
select
c.tzname,
max(case c.time_change when 'DST start' then c.day end) as DST_start,
rtrim(to_char(max(case c.time_change when 'DST start' then c.offset_change end), 'S90.99'), '0.') || ' hour' as time_change_DST_start,
'UTC' || rtrim(to_char(max(case time_change when 'DST start' then c.loffset end), 'S90.99'), '0.') || ' hour' as offset_after_DST_Start,
max(case c.time_change when 'DST end' then c.day end) as DST_end,
rtrim(to_char(max(case c.time_change when 'DST end' then c.offset_change end), 'S90.99'), '0.') || ' hour' as time_change_DST_end,
'UTC' || rtrim(to_char(max(case time_change when 'DST end' then c.loffset end), 'S90.99'), '0.') || ' hour' as offset_after_DST_end,
c.tzabbrevs
from
changes c
group by
c.tzname, c.tzabbrevs
order by
dst_start, c.tzname

Posted in Allgemein | Tagged: | Leave a Comment »

Why is it not possible to raise an exception when handling no_data_needed ?

Posted by Matthias Rogel on 8. November 2014

It seems impossible to raise an exception when handling no_data_needed.

See

create or replace function demo return sys.odciNumberList pipelined
as
begin
  pipe row(1);
  pipe row(1/0);
exception when others then
  dbms_output.put_line('in exception handler, sqlcode: ' || sqlcode);
  raise program_error;
end;
/

sokrates@11.2 > select * from table(demo());
ERROR:
ORA-06501: PL/SQL: program error
ORA-06512: at "SOKRATES.DEMO", line 8
ORA-01476: divisor is equal to zero



no rows selected

in exception handler, sqlcode: -1476

As expected, we handle exception raised by division by zero, there we dbms_output some info and then raise program error.

But now:

sokrates@11.2 > select * from table(demo()) where rownum=1;

COLUMN_VALUE
------------
           1

in exception handler, sqlcode: -6548
sokrates@11.2 >

oops – not expected.
“where rownum=1” causes ORA-06548 been raised and thus we again handle that. We dbms_output some info and then – no error is raised !

Why ?
I have no idea and couldn’t find any in docs either.

Update 2014/11/09:

I found the answer in Bug 13088409 – RAISE_APPLICATION_ERROR ignored in a WHEN OTHERS / WHEN NO_DATA_FOUND exception handler of a pipe-lined table function (Doc ID 13088409.8)

The point of the bug is that an exception handler

procedure h;

just behaves like

begin
   h;
exception when others then null;
end;

, when it is handling NO_DATA_NEEDED raised by a calling SQL.
h might be called either from a WHEN NO_DATA_NEEDED or a WHEN OTHERS – block.

The note says
… Versions confirmed as being affected
11.2.0.2

The fix for 13088409 is first included in
12.1.0.1 (Base Release)
11.2.0.4 (Server Patch Set)

My test case was on 11.2.0.3

Posted in PL/SQL | 7 Comments »

PL/SQL oddity

Posted by Matthias Rogel on 12. May 2014

sokrates@12.1 > create procedure p is begin null; end this_does_not_compile;
  2  /

Warning: Procedure created with compilation errors.

sokrates@12.1 > show errors
Errors for PROCEDURE P:

LINE/COL ERROR
-------- -----------------------------------------------------------------
1/32	 PLS-00113: END identifier 'THIS_DOES_NOT_COMPILE' must match 'P'
	 at line 1, column 11

sokrates@12.1 > REM expected
sokrates@12.1 > create function f return number is begin return null; end this_does_not_compile;
  2  /

Warning: Function created with compilation errors.

sokrates@12.1 > show errors
Errors for FUNCTION F:

LINE/COL ERROR
-------- -----------------------------------------------------------------
1/52	 PLS-00113: END identifier 'THIS_DOES_NOT_COMPILE' must match 'F'
	 at line 1, column 10

sokrates@12.1 > REM expected
sokrates@12.1 > create package pk is end this_does_not_compile;
  2  /

Warning: Package created with compilation errors.

sokrates@12.1 > show errors
Errors for PACKAGE PK:

LINE/COL ERROR
-------- -----------------------------------------------------------------
1/19	 PLS-00113: END identifier 'THIS_DOES_NOT_COMPILE' must match 'PK'
	 at line 1, column 9

sokrates@12.1 > REM expected
sokrates@12.1 > REM 
sokrates@12.1 > REM but now:
sokrates@12.1 > REM 
sokrates@12.1 > create table t ( i int );

Table created.

sokrates@12.1 > create trigger tr before insert on t begin null; end funny_this_DOES_COMPILE;
  2  /

Trigger created.

sokrates@12.1 > show errors
No errors.

Posted in 12c, PL/SQL | 4 Comments »

Yet Another Elementary SQL Bug

Posted by Matthias Rogel on 20. February 2014

Environment

sokrates@12.1 > select banner from v$version;

BANNER
--------------------------------------------------------------------------------
Oracle Database 12c Enterprise Edition Release 12.1.0.1.0 - 64bit Production
PL/SQL Release 12.1.0.1.0 - Production
CORE	12.1.0.1.0	Production
TNS for Linux: Version 12.1.0.1.0 - Production
NLSRTL Version 12.1.0.1.0 - Production

sokrates@12.1 > select value from nls_database_parameters where parameter='NLS_CHARACTERSET';

VALUE
--------------------------------------------------------------------------------
AL32UTF8
sokrates@12.1 > !echo $NLS_LANG
american_america.UTF8

Setup is

create table t ( r varchar2(1 char));
insert into t values('£');
commit;

alter session set nls_length_semantics=BYTE;
alter table t add( v as ( cast(r as varchar2(1))));

alter session set nls_length_semantics=CHAR;
create index t_idx on t(v);

exec dbms_stats.set_table_stats(null, 'T', numrows => 1e7)

We get different result for count(v) when using length-semantics BYTE, depending if a table scan or an index scan is used:

sokrates@12.1 > alter session set nls_length_semantics=BYTE;

Session altered.

sokrates@12.1 > select /* index full scan used */ count(v) from t;

  COUNT(V)
----------
	 1

sokrates@12.1 > select /* full table scan used */ count(*), count(v) from t;

  COUNT(*)   COUNT(V)
---------- ----------
	 1	    0

Same behaviour was observed on 11.2

Posted in 11.2, 12c, Bug, sql | 4 Comments »

How 2 Bytes can fit into 1 Byte

Posted by Matthias Rogel on 20. February 2014

Chris Saxon posted a nice quiz regarding a pitfall when creating tables with VARCHAR2-columns: when you are not explicit in specifying the length-semantics ( CHAR or BYTE ), a session parameter, which may vary, is used.

This is a short follow-up of his story, which shows more pitfalls when creating views and selecting from those.
We end up in a structure which can – by definition – contain only 1 byte, but actually shows containing two bytes !

sokrates@11.2 > alter session set nls_length_semantics=CHAR;

Session altered.

sokrates@11.2 > create table i_can_insert (
  2    into_this varchar2(1)
  3  );

Table created.

sokrates@11.2 > insert into i_can_insert (into_this)
  2  values ('£');

1 row created.

sokrates@11.2 > create view i_can_select (from_that)
  2  as
  3  select cast(into_this as varchar2(1))
  4  from i_can_insert;

View created.

sokrates@11.2 > describe i_can_insert
 Name                                      Null?    Type
 ----------------------------------------- -------- ----------------------------
 INTO_THIS                                          VARCHAR2(1)

sokrates@11.2 > describe i_can_select
 Name                                      Null?    Type
 ----------------------------------------- -------- ----------------------------
 FROM_THAT                                          VARCHAR2(1)

sokrates@11.2 > select * from i_can_select;

FROM_THAT
----------
£

sokrates@11.2 > REM now we change the length semantics ...
sokrates@11.2 > alter session set nls_length_semantics=BYTE;

Session altered.

sokrates@11.2 > REM note that the output of describe changes !
sokrates@11.2 > describe i_can_insert
 Name                                      Null?    Type
 ----------------------------------------- -------- ----------------------------
 INTO_THIS                                          VARCHAR2(1 CHAR)

sokrates@11.2 > describe i_can_select
 Name                                      Null?    Type
 ----------------------------------------- -------- ----------------------------
 FROM_THAT                                          VARCHAR2(1 CHAR)

sokrates@11.2 > create view can_i_select (from_that)
  2  as
  3  select cast(into_this as varchar2(1))
  4  from i_can_insert;

View created.

sokrates@11.2 > describe can_i_select
 Name                                      Null?    Type
 ----------------------------------------- -------- ----------------------------
 FROM_THAT                                          VARCHAR2(1)

sokrates@11.2 > REM now, can I select ?
sokrates@11.2 > set null nada
sokrates@11.2 > select * from can_i_select;

FROM_THAT
----------
nada

sokrates@11.2 > REM no I cannot, output would be too long in my current semantics, so it is trimmed ( nothing left )
sokrates@11.2 >
sokrates@11.2 > REM now, can I select from i_can_select ?
sokrates@11.2 > select * from i_can_select;

FROM_THAT
----------
nada

sokrates@11.2 > REM no
sokrates@11.2 > select * from i_can_insert;

INTO_THIS
----------
£

sokrates@11.2 > REM but still from the table itself, I can select !
sokrates@11.2 >
sokrates@11.2 > REM let us change back the semantics
sokrates@11.2 > alter session set nls_length_semantics=CHAR;

Session altered.

sokrates@11.2 > describe can_i_select
 Name                                      Null?    Type
 ----------------------------------------- -------- ----------------------------
 FROM_THAT                                          VARCHAR2(1 BYTE)

sokrates@11.2 > select * from can_i_select;

FROM_THAT
----------
£

sokrates@11.2 > select lengthb(from_that) from can_i_select;

LENGTHB(FROM_THAT)
------------------
                 2

So, CAN_I_SELECT.FROM_THAT can only hold 1 byte, but the byte-length of its content is 2 !
-> looks like a bug to me.

Note, that USER_VIEWS.TEXT shows the same for both views, even DBMS_METADATA is not explicit , only COLS shows the difference

sokrates@11.2 > select text from user_views where view_name='CAN_I_SELECT';

TEXT
--------------------------------------------------------------------------------
select cast(into_this as varchar2(1))
from i_can_insert


sokrates@11.2 > select text from user_views where view_name='I_CAN_SELECT';

TEXT
--------------------------------------------------------------------------------
select cast(into_this as varchar2(1))
from i_can_insert


sokrates@11.2 > select dbms_metadata.get_ddl('VIEW', 'CAN_I_SELECT') from dual;

DBMS_METADATA.GET_DDL('VIEW','CAN_I_SELECT')
--------------------------------------------------------------------------------

  CREATE OR REPLACE FORCE VIEW "SOKRATES"."CAN_I_SELECT" ("FROM_THAT") AS
  select cast(into_this as varchar2(1))
from i_can_insert


sokrates@11.2 > select dbms_metadata.get_ddl('VIEW', 'I_CAN_SELECT') from dual;

DBMS_METADATA.GET_DDL('VIEW','I_CAN_SELECT')
--------------------------------------------------------------------------------

  CREATE OR REPLACE FORCE VIEW "SOKRATES"."I_CAN_SELECT" ("FROM_THAT") AS
  select cast(into_this as varchar2(1))
from i_can_insert


sokrates@11.2 > select table_name, column_name, data_length from cols where table_name in ('I_CAN_SELECT', 'CAN_I_SELECT');

TABLE_NAME                     COLUMN_NAME                    DATA_LENGTH
------------------------------ ------------------------------ -----------
CAN_I_SELECT                   FROM_THAT                                1
I_CAN_SELECT                   FROM_THAT                                4

Posted in sql | 4 Comments »