Oracle SQL
  • LICENSE

Category Archives: SQL*PLus tips

SQL*Plus tips. #2

Posted on April 2, 2013 by Sayan Malakshinov Posted in oracle, SQL*Plus, SQL*PLus tips 3,516 Page views 10 Comments

I think you know the famous print_table procedure by Tom Kyte. It is really great, but a little hard(it requires create procedure or place it in anonymous block) and in last oracle versions we can do same with one simple query with xmltable/xmlsequence:

SQL> select *
  2  from
  3     xmltable( '/ROWSET/ROW/*'
  4               passing xmltype(cursor(select * from hr.employees where rownum<3))
  5               columns
  6                  col varchar2(100) path 'name()'
  7                 ,val varchar2(100) path '.'
  8        );

COL                            VAL
------------------------------ ------------------------------------------------------
EMPLOYEE_ID                    198
FIRST_NAME                     Donald
LAST_NAME                      OConnell
EMAIL                          DOCONNEL
PHONE_NUMBER                   650.507.9833
HIRE_DATE                      21-JUN-07
JOB_ID                         SH_CLERK
SALARY                         2600
MANAGER_ID                     124
DEPARTMENT_ID                  50
EMPLOYEE_ID                    199
FIRST_NAME                     Douglas
LAST_NAME                      Grant
EMAIL                          DGRANT
PHONE_NUMBER                   650.507.9844
HIRE_DATE                      13-JAN-08
JOB_ID                         SH_CLERK
SALARY                         2600
MANAGER_ID                     124
DEPARTMENT_ID                  50

20 rows selected.

It is very easy, but for conveniency we need to add “rownum”:

SQL> select *
  2  from
  3     xmltable( 'for $a at $i in /ROWSET/ROW
  4                   ,$r in $a/*
  5                     return element ROW{
  6                                       element ROW_NUM{$i}
  7                                      ,element COL_NAME{$r/name()}
  8                                      ,element COL_VALUE{$r/text()}
  9                                      }'
 10               passing xmltype(cursor(select * from hr.employees where rownum<3))
 11               columns
 12                  row_num   int
 13                 ,col_name  varchar2(30)
 14                 ,col_value varchar2(100)
 15        );

   ROW_NUM COL_NAME                       COL_VALUE
---------- ------------------------------ ------------------------------------------
         1 EMPLOYEE_ID                    198
         1 FIRST_NAME                     Donald
         1 LAST_NAME                      OConnell
         1 EMAIL                          DOCONNEL
         1 PHONE_NUMBER                   650.507.9833
         1 HIRE_DATE                      21-JUN-07
         1 JOB_ID                         SH_CLERK
         1 SALARY                         2600
         1 MANAGER_ID                     124
         1 DEPARTMENT_ID                  50
         2 EMPLOYEE_ID                    199
         2 FIRST_NAME                     Douglas
         2 LAST_NAME                      Grant
         2 EMAIL                          DGRANT
         2 PHONE_NUMBER                   650.507.9844
         2 HIRE_DATE                      13-JAN-08
         2 JOB_ID                         SH_CLERK
         2 SALARY                         2600
         2 MANAGER_ID                     124
         2 DEPARTMENT_ID                  50

20 rows selected.

Now we can create simple script for it with formatting:

print_table.sql

[sourcecode language=”sql”]
— show output
set termout on
— but without echo
set echo off
— without newpage on start:
set embedded on
— scrolling control
set pause on
— two lines between rows:
set newpage 2
— text for prompt after each page:
set pause "Press Enter to view next row…"
— new page on new "row_num"
break on row_num skip page

— main query:
select *
from
xmltable( ‘for $a at $i in /ROWSET/ROW
,$r in $a/*
return element ROW{
element ROW_NUM{$i}
,element COL_NAME{$r/name()}
,element COL_VALUE{$r/text()}
}’
passing xmltype(cursor( &1 ))
columns
row_num int
,col_name varchar2(30)
,col_value varchar2(100)
);
— disabling pause and breaks:
set pause off
clear breaks
[/sourcecode]

[collapse]

Usage example:print_table example
As you see script works fine, but it is require to pass query as parameter, though sometimes it is not so convenient. For example if we want started query and later decided to show it with print_table. In that case we can create scripts with tricks from previous part:
print_last.sql

[sourcecode language=”sql”]
store set settings.sql replace
— saving previous query:
save tmp.sql replace

— OS-dependent removing trailing slash from file, choose one:
— 1. for *nix through head:
!head -1 tmp.sql >tmp2.sql

— 2. for for *nix through grep:
–!grep -v tmp.sql >tmp2.sql

— 3. for windows without grep and head:
— $cmd /C findstr /v /C:"/" tmp.sql > tmp2.sql

— 4. for windows with "head"(eg from cygwin)
–$cmd /C head -1 tmp.sql > tmp2.sql

— 5. for windows with "grep":
–$cmd /C grep -v "/" tmp.sql > tmp2.sql

— same setting as in print_table:
set termout on echo off embedded on pause on newpage 2
set pause "Press Enter to view next row…"
break on row_num skip page

— main query:
select *
from
xmltable( ‘for $a at $i in /ROWSET/ROW
,$r in $a/*
return element ROW{
element ROW_NUM{$i}
,element COL_NAME{$r/name()}
,element COL_VALUE{$r/text()}
}’
passing dbms_xmlgen.getxmltype(
q'[
@tmp2.sql
]’
)
columns
row_num int
,col_name varchar2(30)
,col_value varchar2(100)
);
— disabling pause and breaks:
set pause off
clear breaks
@settings.sql
[/sourcecode]

[collapse]

Example:

[sourcecode language=”sql”]
SQL> select * from hr.employees where rownum<3;

EMPLOYEE_ID FIRST_NAME LAST_NAME EMAIL PHONE_NUMBER HIRE_DATE JOB_ID SALARY COMMISSION_PCT MANAGER_ID DEPARTMENT_ID
———– ——————– ————————- ————————- ——————– ——— ———- ———- ————– ———- ————-
198 Donald OConnell DOCONNEL 650.507.9833 21-JUN-07 SH_CLERK 2600 124 50
199 Douglas Grant DGRANT 650.507.9844 13-JAN-08 SH_CLERK 2600 124 50

Elapsed: 00:00:00.01
SQL> @print_last
Wrote file settings.sql
Wrote file tmp.sql

ROW_NUM COL_NAME COL_VALUE
———- —————————— —————————————————————————————————-
1 EMPLOYEE_ID 198
FIRST_NAME Donald
LAST_NAME OConnell
EMAIL DOCONNEL
PHONE_NUMBER 650.507.9833
HIRE_DATE 21-JUN-07
JOB_ID SH_CLERK
SALARY 2600
MANAGER_ID 124
DEPARTMENT_ID 50
Press Enter to view next row…
[/sourcecode]

[collapse]

PS. if you will use xmltype(cursor(…)) on versions less that 11.2.0.3 you can get errors with xml rewriting. In this case you need to disable it:

alter session set events '19027 trace name context forever, level 0x1';

Update:
Vladimir Przyjalkowski rightly pointed out that such approach will be suboptimal in case of big amount of data:

A nice toy, but i’m sure it will not tolerate big data.

It is absolutely true, because at first, “xmltype(cursor(…))” aggregated data as xmltype, and only then xmltable returns data.
But I use print_table for small amount of data only, and in case of when i want to see sample of data, i usually add limitation by rownum, which also convenient because it automatically changes optimizer mode with enabled parameter “_optimizer_rownum_pred_based_fkr” (it is default):

SQL> @param_ rownum

NAME                               VALUE   DEFLT  TYPE     DESCRIPTION
---------------------------------- ------- ------ -------- ------------------------------------------------------
_optimizer_rownum_bind_default     10      TRUE   number   Default value to use for rownum bind
_optimizer_rownum_pred_based_fkr   TRUE    TRUE   boolean  enable the use of first K rows due to rownum predicate
_px_rownum_pd                      TRUE    TRUE   boolean  turn off/on parallel rownum pushdown optimization

However, we can easily change the our query to make it optimally with a lot of data too:

select row_num
      ,t2.*
from 
   (select rownum row_num
         , column_value x
    from table(xmlsequence(cursor( &1 )))
   ) t1
  ,xmltable( '/ROW/*'
             passing t1.x
             columns
                col_num for ordinality
               ,col_name  varchar2(30) path 'name()'
               ,col_value varchar2(100) path '.'
      )(+) t2;

Lets test it with pipelined function which will pipe rows infinitely and log count of fetched rows:

-- drop table xt_log purge;
-- drop function f_infinite;

create table xt_log(n int);

create function f_infinite 
   return sys.ku$_objnumset pipelined 
as
   i int:=0;
   pragma autonomous_transaction;
begin
   loop 
      i:=i+1;
      insert into xt_log values(i);
      commit;
      pipe row(i);
   end loop;

exception 
   when NO_DATA_NEEDED then
      commit;
end;
/

New version of print_table: print_table2.sql

[sourcecode language=”sql”]
— set arraysize for minimal value, so sqlplus did not fetch extra rows:
set arraysize 2
— show output
set termout on
— but without echo
set echo off
— without newpage on start:
set embedded on
— scrolling control
set pause on
— two lines between rows:
set newpage 2
— text for prompt after each page:
set pause "Press Enter to view next row…"
— new page on new "row_num"
break on row_num skip page

— main query:
select row_num
,t2.*
from
(select rownum row_num
, column_value x
from table(xmlsequence(cursor( &1 )))
) t1
,xmltable( ‘/ROW/*’
passing t1.x
columns
col_num for ordinality
,col_name varchar2(30) path ‘name()’
,col_value varchar2(100) path ‘.’
)(+) t2;
— disabling pause and breaks:
set pause off
clear breaks
[/sourcecode]

[collapse]

And look final test:

SQL> select * from xt_log;

no rows selected

SQL> @print_table2 "select * from table(f_infinite)"
Press Enter to view next row...


   ROW_NUM    COL_NUM COL_NAME                       COL_VALUE
---------- ---------- ------------------------------ -----------
         1          1 COLUMN_VALUE                   1
Press Enter to view next row...


   ROW_NUM    COL_NUM COL_NAME                       COL_VALUE
---------- ---------- ------------------------------ -----------
         2          1 COLUMN_VALUE                   2
Press Enter to view next row...


   ROW_NUM    COL_NUM COL_NAME                       COL_VALUE
---------- ---------- ------------------------------ -----------
         3          1 COLUMN_VALUE                   3
Press Enter to view next row...


   ROW_NUM    COL_NUM COL_NAME                       COL_VALUE
---------- ---------- ------------------------------ -----------
         4          1 COLUMN_VALUE                   4
Press Enter to view next row...

   ROW_NUM    COL_NUM COL_NAME                       COL_VALUE
         5          1 COLUMN_VALUE                   5
Press Enter to view next row...


6 rows selected.
-------------------------------
SQL> select * from xt_log;

         N
----------
         1
         2
         3
         4
         5
         6
         7

7 rows selected.

So we got what we wanted!

PS. Full scripts:
1. Simple: print_table.sql
2. For big queries: print_table2.sql

oracle SQL*Plus

SQL*Plus tips. #1

Posted on March 29, 2013 by Sayan Malakshinov Posted in oracle, SQL*Plus, SQL*PLus tips 3,709 Page views 5 Comments

If you are using SQL*Plus, you are likely to use the input parameters. And if you omit one of them, SQL*Plus will show prompt for it, like this:

SQL> get test.sql
  1  select 'Input variable 1 = &1' from dual
  2  union all
  3  select 'Input variable 2 = &2' from dual
  4  union all
  5* select 'Input variable 3 = &3' from dual
SQL> @test var1 var2
Enter value for 3:

'INPUTVARIABLE1=VAR1'
-----------------------
Input variable 1 = var1
Input variable 2 = var2
Input variable 3 =

Elapsed: 00:00:00.01

It is allright, if all variables are needed, but what if we don’t want to press enter for all omitted variables or specify they(especially if script can be start in silent, non interactive mode) and want to use default values for omitted variables or these variables can be unnecessary?
Strictly speaking, there are many different techniques for solving it, see some of them:

Comma-separated params

[sourcecode language=”sql”]
SQL> get test1
1 col var1 new_value var1 noprint
2 col var2 new_value var2 noprint
3 col var3 new_value var3 noprint
4 set termout off
5 with any_splitting_technique as (
6 select *
7 from xmltable(‘ora:tokenize(.,",")[position()>1]’
8 passing ‘,’||’&1′
9 columns
10 i for ordinality
11 ,"." varchar2(30)
12 )
13 )
14 select
15 nvl("1",’default1′) var1
16 ,nvl("2",’default2′) var2
17 ,nvl("3",’default3’) var3
18 from any_splitting_technique
19 pivot (max(".") for i in (1,2,3))
20 /
21 set termout on
22* prompt var1 = &var1, var2 = &var2, var3 = &var3;
SQL> @test1 1,2,3
var1 = 1, var2 = 2, var3 = 3
SQL> @test1 1,2
var1 = 1, var2 = 2, var3 = default3
[/sourcecode]

[collapse]

With SPOOL and DEFINE

[sourcecode language=”sql”]
SQL> get test2
1 set termout off
2 spool tmp.sql
3 def 1
4 def 2
5 def 3
6 spool off
7 col var1 new_value var1
8 col var2 new_value var2
9 col var3 new_value var3
10 with tmp as (
11 select ‘
12 @tmp.sql
13 ‘ params from dual
14 )
15 select
16 nvl(regexp_substr(params,’DEFINE 1\s+ = "([^"]*)’,1,1,’i’,1),’default1′) var1
17 , nvl(regexp_substr(params,’DEFINE 2\s+ = "([^"]*)’,1,1,’i’,1),’default2′) var2
18 , nvl(regexp_substr(params,’DEFINE 3\s+ = "([^"]*)’,1,1,’i’,1),’default3′) var3
19 from tmp
20 ;
21 col var1 clear;
22 col var2 clear;
23 col var3 clear;
24 set termout on
25 prompt var1 = &var1, var2 = &var2, var3 = &var3;
26 undef 1
27 undef 2
28* undef 3
29 .
SQL> @test2 1 2 3
var1 = 1, var2 = 2, var3 = 3
SQL> @test2 1 2
var1 = 1, var2 = 2, var3 = default3
[/sourcecode]

[collapse]

Last example also shows a very useful way to read file into a variable.
But i think, the best option for initializing parameters is the solution by Vladimir Begun:

SQL> get test3
  1  set termout off
  2  COLUMN 1 NEW_VALUE 1    noprint
  3  COLUMN 2 NEW_VALUE 2    noprint
  4  COLUMN 3 NEW_VALUE 3    noprint
  5  SELECT '' "1", '' "2", '' "3" FROM dual WHERE 1=0;
  6  SELECT nvl('&1','default1') "1"
  7       , nvl('&2','default2') "2"
  8       , nvl('&3','default3') "3"
  9    FROM dual;
 10  col var1 clear;
 11  col var2 clear;
 12  col var3 clear;
 13  set termout on
 14  prompt var1 = &1, var2 = &2, var3 = &3;
 15  undef 1
 16  undef 2
 17* undef 3
 18  .
SQL> @test3 1 2 3
var1 = 1, var2 = 2, var3 = 3
SQL> @test3 1 2
var1 = 1, var2 = 2, var3 = default3

So i can create 2 include files – for execution at the start and at the end of all scripts. I created directory “inc” for include files and files:

inc/s_begin.sql

[sourcecode language=”sql”]
store set splus_restore.sql replace
set termout off
COLUMN 1 NEW_VALUE 1 noprint
COLUMN 2 NEW_VALUE 2 noprint
COLUMN 4 NEW_VALUE 4 noprint
COLUMN 3 NEW_VALUE 3 noprint
COLUMN 5 NEW_VALUE 5 noprint
COLUMN 6 NEW_VALUE 6 noprint
COLUMN 7 NEW_VALUE 7 noprint
COLUMN 8 NEW_VALUE 8 noprint
COLUMN 9 NEW_VALUE 9 noprint
COLUMN 10 NEW_VALUE 10 noprint
COLUMN 11 NEW_VALUE 11 noprint
COLUMN 12 NEW_VALUE 12 noprint
COLUMN 13 NEW_VALUE 13 noprint
COLUMN 14 NEW_VALUE 14 noprint
COLUMN 15 NEW_VALUE 15 noprint
COLUMN 16 NEW_VALUE 16 noprint

SELECT ” "1", ” "5", ” "9", ” "13"
,” "2", ” "6", ” "10", ” "14"
,” "3", ” "7", ” "11", ” "15"
,” "4", ” "8", ” "12", ” "16"
FROM dual
WHERE 1=0;
set termout on;
[/sourcecode]

[collapse]

and
inc/s_end.sql

[sourcecode language=”sql”]
undef 1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16
@splus_restore;
[/sourcecode]

[collapse]
And for example get_index.sql:
get_index.sql

[sourcecode language=”sql”]
@inc/s_begin;
col table_owner format a12
col column_name format a30
col index_owner format a12
col index_name format a30

col "#" format 99
break on table_owner on table_name on index_owner on index_name on partition_name on mbytes on bytes on blocks
select
ic.table_owner
,ic.table_name
,ic.index_owner
,ic.index_name
,s.partition_name
,round(s.bytes/1024/1024) mbytes
,s.blocks
,ic.column_position "#"
,decode(ic.column_position,1,”,’ ,’)||ic.column_name column_name
from dba_ind_columns ic
,dba_segments s
where
upper(ic.table_name) like upper(‘&1’)
and upper(ic.table_owner) like nvl(upper(‘&2′),’%’)
and s.owner = ic.index_owner
and s.segment_name = ic.index_name
order by
1,2,3,4,8
/
clear break;
col "#" clear;
@inc/s_end;
[/sourcecode]

[collapse]

Sample output

[sourcecode language=”sql”]
SQL> @get_indexes wrh$%tab%stat xtender
Wrote file splus_restore.sql

no rows selected

Elapsed: 00:00:05.79
SQL> @get_indexes wrh$%undostat
Wrote file splus_restore.sql

TABLE_OWNER TABLE_NAME INDEX_OWNER INDEX_NAME PARTITION_NAME MBYTES BLOCKS # COLUMN_NAME
———— ————– ———— —————– ————– ——- ——- — ——————–
SYS WRH$_UNDOSTAT SYS WRH$_UNDOSTAT_PK 0 16 1 BEGIN_TIME
2 ,END_TIME
3 ,DBID
4 ,INSTANCE_NUMBER
[/sourcecode]

[collapse]
As you see i can omit owner parameter and in this case it will search in all schemas.

SQL*Plus
photo Sayan Malakshinov

Oracle ACE Pro Oracle ACE Pro Alumni

DEVVYOracle Database Developer Choice Award winner

Oracle performance tuning expert

UK / Cambridge

LinkedIn   Twitter
sayan@orasql.org

Recent Posts

  • Oracle Telegram Bot
  • Partition Pruning and Global Indexes
  • Interval Search: Part 4. Dynamic Range Segmentation – interval quantization
  • Interval Search Series: Simplified, Advanced, and Custom Solutions
  • Interval Search: Part 3. Dynamic Range Segmentation – Custom Domain Index

Popular posts

Recent Comments

  • Oracle SQL | Interval Search: Part 4. Dynamic Range Segmentation – interval quantization on Interval Search: Part 3. Dynamic Range Segmentation – Custom Domain Index
  • Oracle SQL | Interval Search: Part 4. Dynamic Range Segmentation – interval quantization on Interval Search: Part 2. Dynamic Range Segmentation – Simplified
  • Oracle SQL | Interval Search: Part 4. Dynamic Range Segmentation – interval quantization on Interval Search: Optimizing Date Range Queries – Part 1
  • Oracle SQL | Interval Search Series: Simplified, Advanced, and Custom Solutions on Interval Search: Part 2. Dynamic Range Segmentation – Simplified
  • Oracle SQL | Interval Search: Part 2. Dynamic Range Segmentation – Simplified on Interval Search: Part 3. Dynamic Range Segmentation – Custom Domain Index

Blogroll

  • Alex Fatkulin
  • Alexander Anokhin
  • Andrey Nikolaev
  • Charles Hooper
  • Christian Antognini
  • Coskan Gundogar
  • David Fitzjarrell
  • Igor Usoltsev
  • Jonathan Lewis
  • Karl Arao
  • Mark Bobak
  • Martin Bach
  • Martin Berger
  • Neil Chandler
  • Randolf Geist
  • Richard Foote
  • Riyaj Shamsudeen
  • Tanel Poder
  • Timur Akhmadeev
  • Valentin Nikotin
  • Prev
  • 1
  • 2
©Sayan Malakshinov. Oracle SQL