├── 9781430262985.jpg ├── LICENSE.txt ├── README.md ├── contributing.md └── scripts ├── ch00 ├── README.txt ├── big_table.sql ├── creeoda.sql ├── crescott.sql ├── demo01.sql ├── demo02.sql ├── demobld.sql ├── login.old.sql ├── login.sql ├── mystat.sql ├── mystat2.sql ├── ru.sql ├── runstats.sql ├── show_space.sql ├── tk.sql └── unload.sql ├── ch01 ├── demo01.sql ├── demo02.sql ├── demo03.sql ├── demo04.sql ├── demo05.sql ├── demo06.sql ├── demo07.sql ├── demo08.sql ├── demo09.sql ├── demo10.sql ├── demo11.sql └── demo12.sql ├── ch02 └── README.txt ├── ch03 ├── demo01.sql ├── demo02.sql ├── demo03.sql ├── demo04.sql ├── demo05.sql ├── demo06.sql ├── demo07.sql └── demo08.sql ├── ch04 ├── demo01.sql ├── demo02.sql ├── demo03.sql ├── demo04.sql ├── demo05.sql ├── demo06.sql ├── gen_load.sh ├── gen_load.sql ├── report.sql ├── reset_stat.sql ├── run.sql ├── run_query.sql ├── single_load.sql ├── stats.sql ├── stop.sql ├── watch_stat.sql └── what_if.sql ├── ch05 ├── demo01.sql ├── demo02.sql ├── demo03.sql ├── demo04.sql └── demo05.sql ├── ch06 ├── binds │ ├── demo13.sql │ ├── instest.java │ └── run.sql ├── demo01.sql ├── demo02.sql ├── demo03.sql ├── demo04.sql ├── demo05.sql ├── demo06.sql ├── demo07.sql ├── demo08.sql ├── demo09.sql ├── demo10.sql ├── demo11.sql ├── initrans.sql └── nobinds │ ├── demo13.sql │ ├── instest.java │ └── run.sql ├── ch07 ├── demo01.sql ├── demo02.sql ├── demo03.sql ├── demo04.sql ├── demo05.sql └── demo06.sql ├── ch08 ├── demo01.sql ├── demo02.sql ├── demo03.sql ├── demo04.sql ├── demo05.sql ├── demo06.sql ├── demo07.sql ├── demo08.sql ├── demo09.sql ├── demo10.sql ├── demo11.sql └── demo12.sql ├── ch09 ├── demo01.sql ├── demo02.sql ├── demo03.sql ├── demo04.sql ├── demo05.sql ├── demo06.sql ├── demo07.sql ├── demo08.sql ├── demo09.sql ├── demo10.sql ├── demo11.sql ├── getstat.sql ├── perftest.java ├── perftest.sql ├── run.sh └── test2.sql ├── ch10 ├── demo01.sql ├── demo02.sql ├── demo03.sql ├── demo04.sql ├── demo05.sql ├── demo06.sql ├── demo07.sql ├── demo08.sql ├── demo09.sql ├── demo10.sql ├── demo11.sql ├── demo12.sql ├── demo13.sql ├── demo14.sql ├── demo15.sql ├── demo16.sql ├── demo17.sql ├── demo18.sql ├── demo19.sql ├── demo20.sql ├── demo21.sql ├── demo22.sql ├── demo23.sql ├── demo24.sql ├── demo25.sql ├── demo26.sql ├── demo27.sql ├── demo28.sql ├── demo29.sql ├── demo30.sql ├── demo31.sql ├── demo32.sql ├── demo33.sql ├── demo34.sql ├── demo35.sql ├── demo36.sql ├── demo37.sql └── demo38.sql ├── ch11 ├── demo01.sql ├── demo02.sql ├── demo04.sql ├── demo05.sql ├── demo06.sql ├── demo07.sql ├── demo08.sql ├── demo09.sql ├── demo10.sql ├── demo11.sql ├── demo12.sql ├── demo13.sql ├── demo14.sql ├── demo15.sql ├── demo16.sql ├── demo17.sql ├── demo18.sql ├── demo19.sql ├── demo20.sql ├── demo21.sql ├── demo22.sql ├── demo23.sql ├── demo24.sql ├── demo25.sql ├── demo26.sql ├── demo27.sql ├── demo3.sql ├── demo3_creates.sql ├── demo3_plsql.sh ├── demo3_proc.sh ├── demo3_run.sql ├── t.pc ├── tk.prf └── tk.sql ├── ch12 ├── demo01.sql ├── demo02.sql ├── demo03.sql ├── demo04.sql ├── demo05.sql ├── demo06.sql ├── demo07.sql ├── demo08.sql ├── demo09.sql ├── demo10.sql ├── demo11.sql ├── demo12.sql ├── demo13.sql ├── demo14.sql ├── demo15.sql ├── demo16.sql ├── demo17.sql ├── demo18.sql ├── demo19.sql ├── demo20.sql ├── demo21.sql ├── demo22.sql ├── demo23.sql ├── demo24.sql ├── demo25.sql ├── demo26.sql ├── demo27.sql ├── demo28.sql ├── demo29.sql ├── demo30.sql └── demo31.sql ├── ch13 ├── demo01.sql ├── demo02.sql ├── demo03.sql ├── demo04.sql ├── demo05.sql ├── demo06.sql ├── demo07.sql ├── demo08.sql ├── demo09.sql ├── demo10.sql ├── demo11.sql ├── demo12.sql ├── demo13.sql ├── demo14.sql ├── demo15.sql ├── demo16.sql ├── demo17.sql ├── demo18.sql ├── demo19.sql ├── demo20.sql ├── demo21.sql ├── demo22.sql ├── demo23.sql └── demo24.sql ├── ch14 ├── big_table.ctl ├── big_table.sql ├── demo01.sql ├── demo02.sql ├── demo03.sql ├── demo04.sql ├── demo05.sql ├── demo06.sql ├── demo07.sql └── demo08.sql └── ch15 ├── demo.bad ├── demo.control_files ├── demo.ctl ├── demo01.sql ├── demo02.sql ├── demo03.sql ├── demo04.sql ├── demo05.sql ├── demo06.sql ├── demo07.sql ├── demo08.sql ├── demo09.sql ├── demo1.ctl ├── demo1.log ├── demo10.sql ├── demo11.sql ├── demo2.ctl ├── dept.dat ├── dept.log ├── flf.bsh ├── lob_demo.sql ├── run_df.sh ├── run_sed.bsh ├── search_dir.bsh └── search_dir2.bsh /9781430262985.jpg: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/Apress/exp-oracle-db-architecture-14/204c8cdc110210a1254de6f5c3ab5fbfea5974a7/9781430262985.jpg -------------------------------------------------------------------------------- /LICENSE.txt: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/Apress/exp-oracle-db-architecture-14/204c8cdc110210a1254de6f5c3ab5fbfea5974a7/LICENSE.txt -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # Apress Source Code 2 | 3 | This repository accompanies [*Expert Oracle Database Architecture*](http://www.apress.com/9781430262985) by Thomas Kyte and Darl Kuhn (Apress, 2014). 4 | 5 | ![Cover image](9781430262985.jpg) 6 | 7 | Download the files as a zip using the green button, or clone the repository to your machine using Git. 8 | 9 | ## Releases 10 | 11 | Release v1.0 corresponds to the code in the published book, without corrections or updates. 12 | 13 | ## Contributions 14 | 15 | See the file Contributing.md for more information on how you can contribute to this repository. 16 | -------------------------------------------------------------------------------- /contributing.md: -------------------------------------------------------------------------------- 1 | # Contributing to Apress Source Code 2 | 3 | Copyright for Apress source code belongs to the author(s). However, under fair use you are encouraged to fork and contribute minor corrections and updates for the benefit of the author(s) and other readers. 4 | 5 | ## How to Contribute 6 | 7 | 1. Make sure you have a GitHub account. 8 | 2. Fork the repository for the relevant book. 9 | 3. Create a new branch on which to make your change, e.g. 10 | `git checkout -b my_code_contribution` 11 | 4. Commit your change. Include a commit message describing the correction. Please note that if your commit message is not clear, the correction will not be accepted. 12 | 5. Submit a pull request. 13 | 14 | Thank you for your contribution! -------------------------------------------------------------------------------- /scripts/ch00/README.txt: -------------------------------------------------------------------------------- 1 | The ch00 folder contains scripts used throughout the book. 2 | 3 | For exampe: 4 | * creeoda.sql creates the EODA user used in the examples and grants it required privileges. 5 | * login.sql sets the SQL prompt. 6 | * big_table.sql creates the BIG_TABLE table. 7 | * crescott.sql creates the SCOTT schema (if you don't already have that schema). 8 | * tk.sql runs tkprof on a trace file and opens the trace file for editing. 9 | 10 | And so on. 11 | -------------------------------------------------------------------------------- /scripts/ch00/big_table.sql: -------------------------------------------------------------------------------- 1 | define numrows=10000000 2 | drop table big_table purge; 3 | 4 | create table big_table 5 | as 6 | select rownum id, OWNER, OBJECT_NAME, SUBOBJECT_NAME, OBJECT_ID, 7 | DATA_OBJECT_ID, OBJECT_TYPE, CREATED, LAST_DDL_TIME, TIMESTAMP, 8 | STATUS, TEMPORARY, GENERATED, SECONDARY, NAMESPACE, EDITION_NAME 9 | from all_objects 10 | where 1=0 11 | / 12 | 13 | alter table big_table nologging; 14 | 15 | declare 16 | l_cnt number; 17 | l_rows number := &numrows; 18 | begin 19 | insert /*+ append */ 20 | into big_table 21 | select rownum id, OWNER, OBJECT_NAME, SUBOBJECT_NAME, OBJECT_ID, 22 | DATA_OBJECT_ID, OBJECT_TYPE, CREATED, LAST_DDL_TIME, TIMESTAMP, 23 | STATUS, TEMPORARY, GENERATED, SECONDARY, NAMESPACE, EDITION_NAME 24 | from all_objects 25 | where rownum <= &numrows; 26 | -- 27 | l_cnt := sql%rowcount; 28 | commit; 29 | while (l_cnt < l_rows) 30 | loop 31 | insert /*+ APPEND */ into big_table 32 | select rownum+l_cnt,OWNER, OBJECT_NAME, SUBOBJECT_NAME, OBJECT_ID, 33 | DATA_OBJECT_ID, OBJECT_TYPE, CREATED, LAST_DDL_TIME, TIMESTAMP, 34 | STATUS, TEMPORARY, GENERATED, SECONDARY, NAMESPACE, EDITION_NAME 35 | from big_table a 36 | where rownum <= l_rows-l_cnt; 37 | l_cnt := l_cnt + sql%rowcount; 38 | commit; 39 | end loop; 40 | end; 41 | / 42 | 43 | alter table big_table add constraint 44 | big_table_pk primary key(id); 45 | 46 | exec dbms_stats.gather_table_stats( user, 'BIG_TABLE', estimate_percent=> 1); 47 | -------------------------------------------------------------------------------- /scripts/ch00/creeoda.sql: -------------------------------------------------------------------------------- 1 | connect / as sysdba 2 | define username=eoda 3 | define usernamepwd=foo 4 | create user &&username identified by &&usernamepwd; 5 | grant dba to &&username; 6 | grant execute on dbms_stats to &&username; 7 | grant select on V_$STATNAME to &&username; 8 | grant select on V_$MYSTAT to &&username; 9 | grant select on V_$LATCH to &&username; 10 | grant select on V_$TIMER to &&username; 11 | conn &&username/&&usernamepwd 12 | -------------------------------------------------------------------------------- /scripts/ch00/crescott.sql: -------------------------------------------------------------------------------- 1 | conn / as sysdba 2 | @?/rdbms/admin/utlsampl.sql 3 | -------------------------------------------------------------------------------- /scripts/ch00/demo01.sql: -------------------------------------------------------------------------------- 1 | -- Runstats example 2 | 3 | drop table t1 purge; 4 | drop table t2 purge; 5 | 6 | create table t1 7 | as 8 | select * from big_table 9 | where 1=0; 10 | 11 | create table t2 12 | as 13 | select * from big_table 14 | where 1=0; 15 | 16 | exec runstats_pkg.rs_start; 17 | 18 | insert into t1 19 | select * 20 | from big_table 21 | where rownum <= 1000000; 22 | 23 | commit; 24 | 25 | exec runstats_pkg.rs_middle; 26 | 27 | begin 28 | for x in ( select * 29 | from big_table 30 | where rownum <= 1000000 ) 31 | loop 32 | insert into t2 values X; 33 | end loop; 34 | commit; 35 | end; 36 | / 37 | 38 | exec runstats_pkg.rs_stop(1000000) 39 | -------------------------------------------------------------------------------- /scripts/ch00/demo02.sql: -------------------------------------------------------------------------------- 1 | -- Mystat example 2 | 3 | column name form a30 4 | 5 | @mystat "redo size" 6 | 7 | update big_table set owner = lower(owner) 8 | where rownum <= 1000; 9 | 10 | @mystat2 11 | -------------------------------------------------------------------------------- /scripts/ch00/login.old.sql: -------------------------------------------------------------------------------- 1 | define _editor=vi 2 | set serveroutput on size 1000000 3 | set trimspool on 4 | set long 5000 5 | set linesize 100 6 | set pagesize 9999 7 | column plan_plus_exp format a80 8 | set termout off 9 | define gname=idle 10 | column global_name new_value gname 11 | select lower(user) || '@' || substr( global_name, 1, decode( dot, 0, length(global_name), dot-1) ) global_name 12 | from (select global_name, instr(global_name,'.') dot from global_name ); 13 | set sqlprompt '&gname> ' 14 | set termout on 15 | -------------------------------------------------------------------------------- /scripts/ch00/login.sql: -------------------------------------------------------------------------------- 1 | define _editor=vi 2 | set serveroutput on size 1000000 3 | set trimspool on 4 | set long 5000 5 | set linesize 100 6 | set pagesize 9999 7 | column plan_plus_exp format a80 8 | set sqlprompt '&_user.@&_connect_identifier.> ' 9 | -------------------------------------------------------------------------------- /scripts/ch00/mystat.sql: -------------------------------------------------------------------------------- 1 | set echo off 2 | set verify off 3 | column value new_val V 4 | define S="&1" 5 | 6 | set autotrace off 7 | select a.name, b.value 8 | from v$statname a, v$mystat b 9 | where a.statistic# = b.statistic# 10 | and lower(a.name) = lower('&S') 11 | / 12 | set echo on 13 | -------------------------------------------------------------------------------- /scripts/ch00/mystat2.sql: -------------------------------------------------------------------------------- 1 | set echo off 2 | set verify off 3 | select a.name, b.value V, to_char(b.value-&V,'999,999,999,999') diff 4 | from v$statname a, v$mystat b 5 | where a.statistic# = b.statistic# 6 | and lower(a.name) = lower('&S') 7 | / 8 | set echo on 9 | -------------------------------------------------------------------------------- /scripts/ch00/ru.sql: -------------------------------------------------------------------------------- 1 | SET LINESIZE 150; 2 | SET SERVEROUTPUT on SIZE 1000000 FORMAT WRAPPED; 3 | -- 4 | declare 5 | -- 6 | l_rows number; 7 | -- 8 | begin 9 | l_rows := unloader.run 10 | ( p_cols => '*', 11 | p_town => 'EODA', 12 | p_tname => 'BIG_TABLE', 13 | p_mode => 'truncate', 14 | p_dbdir => 'UNLOADER', 15 | p_filename => 'unload_file', 16 | p_separator => ',', 17 | p_enclosure => '"', 18 | p_terminator => '|', 19 | p_ctl => 'YES', 20 | p_header => 'NO' ); 21 | -- 22 | dbms_output.put_line( to_char(l_rows) || ' rows extracted to ascii file' ); 23 | -- 24 | end; 25 | / 26 | -------------------------------------------------------------------------------- /scripts/ch00/tk.sql: -------------------------------------------------------------------------------- 1 | column trace new_val TRACE 2 | 3 | select c.value || '/' || d.instance_name || '_ora_' || a.spid || '.trc' trace 4 | from v$process a, v$session b, v$parameter c, v$instance d 5 | where a.addr = b.paddr 6 | and b.audsid = userenv('sessionid') 7 | and c.name = 'user_dump_dest' 8 | / 9 | 10 | disconnect 11 | !tkprof &TRACE ./tk.prf &1 12 | -- connect / 13 | connect eoda/foo 14 | edit tk.prf 15 | -------------------------------------------------------------------------------- /scripts/ch01/demo01.sql: -------------------------------------------------------------------------------- 1 | -- The Black Box Approach 2 | 3 | drop table t purge; 4 | 5 | set echo on 6 | 7 | create table t 8 | ( processed_flag varchar2(1) 9 | ); 10 | 11 | create bitmap index 12 | t_idx on t(processed_flag); 13 | 14 | insert into t values ( 'N' ); 15 | 16 | declare 17 | pragma autonomous_transaction; 18 | begin 19 | insert into t values ( 'N' ); 20 | commit; 21 | end; 22 | / 23 | -------------------------------------------------------------------------------- /scripts/ch01/demo03.sql: -------------------------------------------------------------------------------- 1 | -- Use Bind Variables 2 | 3 | drop table t purge; 4 | 5 | set echo on 6 | 7 | create table t ( x int ); 8 | 9 | create or replace procedure proc1 10 | as 11 | begin 12 | for i in 1 .. 10000 13 | loop 14 | execute immediate 15 | 'insert into t values ( :x )' using i; 16 | end loop; 17 | end; 18 | / 19 | 20 | create or replace procedure proc2 21 | as 22 | begin 23 | for i in 1 .. 10000 24 | loop 25 | execute immediate 26 | 'insert into t values ( '||i||')'; 27 | end loop; 28 | end; 29 | / 30 | 31 | set serveroutput on 32 | 33 | exec runstats_pkg.rs_start 34 | exec proc1 35 | exec runstats_pkg.rs_middle 36 | exec proc2 37 | exec runstats_pkg.rs_stop(9500) 38 | -------------------------------------------------------------------------------- /scripts/ch01/demo05.sql: -------------------------------------------------------------------------------- 1 | -- Preventing Lost Updates 2 | 3 | drop table schedules purge; 4 | drop table resources purge; 5 | 6 | set echo on 7 | 8 | create table resources 9 | ( resource_name varchar2(25) primary key, 10 | other_data varchar2(25) 11 | ); 12 | create table schedules 13 | ( resource_name varchar2(25) references resources, 14 | start_time date, 15 | end_time date 16 | ); 17 | 18 | insert into resources 19 | ( resource_name, other_data ) 20 | values 21 | ( 'conference room', 'xxx' ); 22 | insert into schedules 23 | ( resource_name, start_time, end_time ) 24 | values 25 | ( 'conference room', 26 | to_date( '01-jan-2014 9am', 'dd-mon-yyyy hham' ), 27 | to_date( '01-jan-2014 10am', 'dd-mon-yyyy hham' ) 28 | ); 29 | 30 | variable resource_name varchar2(25) 31 | variable new_start_time varchar2(30) 32 | variable new_end_time varchar2(30) 33 | 34 | set autoprint on 35 | alter session set nls_date_format = 'dd-mon-yyyy hh:miam'; 36 | begin 37 | :resource_name := 'conference room'; 38 | :new_start_time := to_date( '01-jan-2014 9:30am', 'dd-mon-yyyy hh:miam' ); 39 | :new_end_time := to_date( '01-jan-2014 10:00am', 'dd-mon-yyyy hh:miam' ); 40 | end; 41 | / 42 | 43 | select count(*) 44 | from schedules 45 | where resource_name = :resource_name 46 | and (start_time < :new_end_time) 47 | AND (end_time > :new_start_time) 48 | / 49 | 50 | insert into schedules 51 | ( resource_name, start_time, end_time ) 52 | values 53 | ( :resource_name, 54 | to_date( :new_start_time ), 55 | to_date( :new_end_time ) 56 | ); 57 | 58 | select count(*) 59 | from schedules 60 | where resource_name = :resource_name 61 | and (start_time < :new_end_time) 62 | AND (end_time > :new_start_time) 63 | / 64 | 65 | select * from schedules; 66 | -------------------------------------------------------------------------------- /scripts/ch01/demo06.sql: -------------------------------------------------------------------------------- 1 | -- Multi-versioning 2 | 3 | drop table t purge; 4 | 5 | set echo on 6 | 7 | create table t 8 | as 9 | select username, created 10 | from all_users 11 | / 12 | 13 | set autoprint off 14 | variable x refcursor; 15 | begin 16 | open :x for select * from t; 17 | end; 18 | / 19 | 20 | declare 21 | pragma autonomous_transaction; 22 | -- you could do this in another 23 | -- sqlplus session as well, the 24 | -- effect would be identical 25 | begin 26 | delete from t; 27 | commit; 28 | end; 29 | / 30 | 31 | column username format a20 32 | column created format a20 33 | print x 34 | -------------------------------------------------------------------------------- /scripts/ch01/demo07.sql: -------------------------------------------------------------------------------- 1 | -- Flashback 2 | 3 | conn / as sysdba 4 | grant execute on dbms_flashback to scott; 5 | 6 | conn scott/tiger 7 | 8 | set echo on 9 | 10 | variable scn number 11 | exec :scn := dbms_flashback.get_system_change_number; 12 | print scn 13 | 14 | select count(*) from emp; 15 | 16 | delete from emp; 17 | 18 | select count(*) from emp; 19 | 20 | select count(*), 21 | :scn then_scn, 22 | dbms_flashback.get_system_change_number now_scn 23 | from emp as of scn :scn; 24 | 25 | alter table emp enable row movement; 26 | flashback table emp to scn :scn; 27 | 28 | select cnt_now, cnt_then, 29 | :scn then_scn, 30 | dbms_flashback.get_system_change_number now_scn 31 | from (select count(*) cnt_now from emp), 32 | (select count(*) cnt_then from emp as of scn :scn) 33 | / 34 | -------------------------------------------------------------------------------- /scripts/ch01/demo08.sql: -------------------------------------------------------------------------------- 1 | -- Database Independence 2 | 3 | set echo on 4 | 5 | select * from dual where null=null; 6 | select * from dual where null <> null; 7 | select * from dual where null is null; 8 | -------------------------------------------------------------------------------- /scripts/ch01/demo09.sql: -------------------------------------------------------------------------------- 1 | -- Make Sure You Can Adapt 2 | 3 | drop table id_table purge; 4 | 5 | set echo on 6 | 7 | create table id_table 8 | ( id_name varchar2(30) primary key, 9 | id_value number ); 10 | 11 | insert into id_table values ( 'MY_KEY', 0 ); 12 | 13 | commit; 14 | 15 | update id_table 16 | set id_value = id_value+1 17 | where id_name = 'MY_KEY'; 18 | 19 | select id_value 20 | from id_table 21 | where id_name = 'MY_KEY'; 22 | 23 | commit; 24 | 25 | set transaction isolation level serializable; 26 | 27 | update id_table 28 | set id_value = id_value+1 29 | where id_name = 'MY_KEY'; 30 | 31 | -- From a 2nd session 32 | 33 | set transaction isolation level serializable; 34 | 35 | update id_table 36 | set id_value = id_value+1 37 | where id_name = 'MY_KEY'; 38 | 39 | -- In 1st session 40 | commit; 41 | 42 | -- In 2nd session, should throw an error 43 | -------------------------------------------------------------------------------- /scripts/ch01/demo10.sql: -------------------------------------------------------------------------------- 1 | -- Make Sure You Can Adapt, automatic population of column 2 | 3 | drop sequence s; 4 | drop table t purge; 5 | 6 | set echo on 7 | 8 | create sequence s; 9 | 10 | create table t 11 | ( x number 12 | default s.nextval 13 | constraint t_pk primary key, 14 | other_data varchar2(20) 15 | ) 16 | / 17 | 18 | drop table t purge; 19 | create table t 20 | ( x number 21 | generated as identity 22 | constraint t_pk primary key, 23 | other_data varchar2(20) 24 | ) 25 | / 26 | 27 | drop table t purge; 28 | 29 | create table t 30 | ( pk number primary key, 31 | other_data varchar2(20) 32 | ) 33 | / 34 | 35 | create sequence t_seq; 36 | 37 | create trigger t before insert on t 38 | for each row 39 | begin 40 | :new.pk := t_seq.nextval; 41 | end; 42 | / 43 | -------------------------------------------------------------------------------- /scripts/ch01/demo11.sql: -------------------------------------------------------------------------------- 1 | -- Solving Problems Simply 2 | 3 | set echo on 4 | 5 | drop profile one_session; 6 | 7 | create profile one_session limit sessions_per_user 1; 8 | 9 | alter user scott profile one_session; 10 | 11 | alter system set resource_limit=true; 12 | 13 | connect scott/tiger 14 | 15 | host sqlplus scott/tiger 16 | -------------------------------------------------------------------------------- /scripts/ch01/demo12.sql: -------------------------------------------------------------------------------- 1 | -- How Do I Make It Run Faster 2 | 3 | set echo on 4 | 5 | select /* TAG */ substr( username, 1, 1 ) 6 | from all_users au1 7 | where rownum = 1; 8 | 9 | alter session set cursor_sharing=force; 10 | 11 | select /* TAG */ substr( username, 1, 1 ) 12 | from all_users au2 13 | where rownum = 1; 14 | 15 | select sql_text from v$sql where sql_text like 'select /* TAG */ %'; 16 | -------------------------------------------------------------------------------- /scripts/ch02/README.txt: -------------------------------------------------------------------------------- 1 | There are no SQL files with this chapter. 2 | -------------------------------------------------------------------------------- /scripts/ch03/demo01.sql: -------------------------------------------------------------------------------- 1 | -- What are Parameters? 2 | 3 | select value 4 | from v$parameter 5 | where name = 'db_block_size' 6 | / 7 | 8 | show parameter db_block_s 9 | 10 | connect scott/tiger 11 | 12 | create or replace 13 | function get_param( p_name in varchar2 ) 14 | return varchar2 15 | as 16 | l_param_type number; 17 | l_intval binary_integer; 18 | l_strval varchar2(256); 19 | invalid_parameter exception; 20 | pragma exception_init( invalid_parameter, -20000 ); 21 | begin 22 | begin 23 | l_param_type := 24 | dbms_utility.get_parameter_value 25 | ( parnam => p_name, 26 | intval => l_intval, 27 | strval => l_strval ); 28 | exception 29 | when invalid_parameter 30 | then 31 | return '*access denied*'; 32 | end; 33 | if ( l_param_type = 0 ) 34 | then 35 | l_strval := to_char(l_intval); 36 | end if; 37 | return l_strval; 38 | end get_param; 39 | / 40 | 41 | exec dbms_output.put_line( get_param( 'db_block_size' ) ); 42 | 43 | connect eoda/foo 44 | 45 | col name form a30 46 | col val form a15 47 | 48 | select name, scott.get_param( name ) val 49 | from v$parameter 50 | where scott.get_param( name ) = '*access denied*'; 51 | -------------------------------------------------------------------------------- /scripts/ch03/demo02.sql: -------------------------------------------------------------------------------- 1 | -- Setting Values in SPFILEs 2 | 3 | set echo on 4 | 5 | select name 6 | from v$parameter 7 | where issys_modifiable='DEFERRED' 8 | / 9 | 10 | alter system set sort_area_size = 65536; 11 | 12 | alter system set sort_area_size = 65536 deferred; 13 | 14 | alter system set pga_aggregate_target=512m; 15 | 16 | alter system set pga_aggregate_target=512m 17 | comment = 'Changed 14-aug-2013, AWR recommendation'; 18 | 19 | column value format a20 20 | column update_comment format a50 21 | 22 | select value, update_comment 23 | from v$parameter 24 | where name = 'pga_aggregate_target' 25 | / 26 | 27 | -- Unsetting Values in SPFILEs 28 | 29 | alter system reset sort_area_size scope=spfile ; 30 | 31 | connect / as sysoper; 32 | create pfile='/tmp/pfile.tst' from spfile; 33 | 34 | -- Creating PFILEs from SPFILEs 35 | 36 | connect / as sysdba 37 | 38 | create pfile='init_14_aug_2013_ora12cr1.ora' from spfile; 39 | 40 | alter system set pga_aggregate_target=512m 41 | comment = 'Changed 14-aug-2013, AWR recommendation'; 42 | -------------------------------------------------------------------------------- /scripts/ch03/demo03.sql: -------------------------------------------------------------------------------- 1 | -- File Locations 2 | 3 | set echo on 4 | 5 | show parameter dump_dest 6 | 7 | select name, value 8 | from v$parameter 9 | where name like '%dump_dest%'; 10 | 11 | select name, value 12 | from v$parameter 13 | where name like '%dump_dest%'; 14 | 15 | set serveroutput on 16 | exec dbms_output.put_line( scott.get_param( 'user_dump_dest' ) ) 17 | 18 | column name format a22 19 | column value format a40 20 | with home 21 | as 22 | (select value home 23 | from v$diag_info 24 | where name = 'ADR Home' 25 | ) 26 | select name, 27 | case when value <> home.home 28 | then replace(value,home.home,'$home$') 29 | else value 30 | end value 31 | from v$diag_info, home 32 | / 33 | 34 | column trace new_val TRACE format a100 35 | 36 | select c.value || '/' || d.instance_name || '_ora_' || a.spid || '.trc' trace 37 | from v$process a, v$session b, v$parameter c, v$instance d 38 | where a.addr = b.paddr 39 | and b.audsid = userenv('sessionid') 40 | and c.name = 'user_dump_dest' 41 | / 42 | 43 | exec dbms_monitor.session_trace_enable 44 | !ls &TRACE 45 | -------------------------------------------------------------------------------- /scripts/ch03/demo04.sql: -------------------------------------------------------------------------------- 1 | -- Tagging Trace Files 2 | 3 | alter session set tracefile_identifier = 'Look_For_Me'; 4 | exec dbms_output.put_line( scott.get_param( 'user_dump_dest' ) ) 5 | !ls /home/ora12cr1/app/ora12cr1/diag/rdbms/ora12cr1/ora12cr1/trace/*Look_For_Me* 6 | -------------------------------------------------------------------------------- /scripts/ch03/demo05.sql: -------------------------------------------------------------------------------- 1 | -- Alert Log 2 | 3 | create or replace 4 | directory data_dir 5 | as 6 | '/orahome/app/oracle/diag/rdbms/ora12cr1/ORA12CR1/trace/' 7 | / 8 | 9 | drop table alert_log; 10 | 11 | CREATE TABLE alert_log 12 | ( 13 | text_line varchar2(4000) 14 | ) 15 | ORGANIZATION EXTERNAL 16 | ( 17 | TYPE ORACLE_LOADER 18 | DEFAULT DIRECTORY data_dir 19 | ACCESS PARAMETERS 20 | ( 21 | records delimited by newline 22 | fields 23 | ) 24 | LOCATION 25 | ( 26 | 'alert_ORA12CR1.log' 27 | ) 28 | ) 29 | reject limit unlimited 30 | / 31 | 32 | select to_char(last_time,'dd-mon-yyyy hh24:mi') shutdown, 33 | to_char(start_time,'dd-mon-yyyy hh24:mi') startup, 34 | round((start_time-last_time)*24*60,2) mins_down, 35 | round((last_time-lag(start_time) over (order by r)),2) days_up, 36 | case when (lead(r) over (order by r) is null ) 37 | then round((sysdate-start_time),2) 38 | end days_still_up 39 | from ( 40 | select r, 41 | to_date(last_time, 'Dy Mon DD HH24:MI:SS YYYY') last_time, 42 | to_date(start_time,'Dy Mon DD HH24:MI:SS YYYY') start_time 43 | from ( 44 | select r, 45 | text_line, 46 | lag(text_line,1) over (order by r) start_time, 47 | lag(text_line,2) over (order by r) last_time 48 | from ( 49 | select rownum r, text_line 50 | from alert_log 51 | where text_line like '___ ___ __ __:__:__ 20__' 52 | or text_line like 'Starting ORACLE instance %' 53 | ) 54 | ) 55 | where text_line like 'Starting ORACLE instance %' 56 | ) 57 | / 58 | 59 | column value new_val V 60 | 61 | select value from v$diag_info where name = 'Diag Alert'; 62 | -------------------------------------------------------------------------------- /scripts/ch03/demo06.sql: -------------------------------------------------------------------------------- 1 | -- Dictionary-Managed and Locally-Managed Tablespaces 2 | 3 | create tablespace dmt 4 | datafile '/tmp/dmt.dbf' size 2m 5 | extent management dictionary; 6 | 7 | !oerr ora 12913 8 | -------------------------------------------------------------------------------- /scripts/ch03/demo07.sql: -------------------------------------------------------------------------------- 1 | -- Temp Files 2 | 3 | !df -h /tmp 4 | 5 | drop tablespace temp_huge including contents and datafiles; 6 | 7 | create temporary tablespace temp_huge 8 | tempfile '/tmp/temp_huge.dbf' size 2g; 9 | 10 | !df -h /tmp 11 | 12 | !ls -l /tmp/temp_huge.dbf 13 | 14 | !cp --sparse=never /tmp/temp_huge.dbf /tmp/temp_huge_not_sparse.dbf 15 | 16 | !df -h /tmp 17 | 18 | drop tablespace temp_huge including contents and datafiles; 19 | 20 | create temporary tablespace temp_huge 21 | tempfile '/tmp/temp_huge_not_sparse.dbf' reuse; 22 | -------------------------------------------------------------------------------- /scripts/ch03/demo08.sql: -------------------------------------------------------------------------------- 1 | -- Data Pump Files 2 | 3 | drop table t purge; 4 | drop table all_objects_unload; 5 | 6 | set echo on 7 | 8 | create or replace directory tmp as '/tmp'; 9 | 10 | create table all_objects_unload 11 | organization external 12 | ( type oracle_datapump 13 | default directory TMP 14 | location( 'allobjects.dat' ) 15 | ) 16 | as 17 | select * from all_objects 18 | / 19 | 20 | create table t 21 | ( OWNER VARCHAR2(30), 22 | OBJECT_NAME VARCHAR2(30), 23 | SUBOBJECT_NAME VARCHAR2(30), 24 | OBJECT_ID NUMBER, 25 | DATA_OBJECT_ID NUMBER, 26 | OBJECT_TYPE VARCHAR2 (19), 27 | CREATED DATE , 28 | LAST_DDL_TIME DATE, 29 | TIMESTAMP VARCHAR2(19), 30 | STATUS VARCHAR2(7), 31 | TEMPORARY VARCHAR2(1), 32 | GENERATED VARCHAR2(1), 33 | SECONDARY VARCHAR2(1) 34 | ) 35 | organization external 36 | ( type oracle_datapump 37 | default directory TMP 38 | location( 'allobjects.dat' ) 39 | ); 40 | -------------------------------------------------------------------------------- /scripts/ch04/demo01.sql: -------------------------------------------------------------------------------- 1 | -- Manual PGA Memory Management, setup 2 | 3 | drop table t purge; 4 | 5 | set echo on 6 | 7 | create table t as select * from all_objects; 8 | 9 | exec dbms_stats.gather_table_stats( user, 'T' ); 10 | -------------------------------------------------------------------------------- /scripts/ch04/demo02.sql: -------------------------------------------------------------------------------- 1 | -- Using PGA_AGGREGATE_TARGET to Control Memory Allocation 2 | 3 | set echo on 4 | 5 | create or replace package demo_pkg 6 | as 7 | type array is table of char(2000) index by binary_integer; 8 | g_data array; 9 | end; 10 | / 11 | 12 | column name format a30 13 | 14 | select a.name, to_char(b.value, '999,999,999') bytes, 15 | to_char(round(b.value/1024/1024,1), '99,999.9' ) mbytes 16 | from v$statname a, v$mystat b 17 | where a.statistic# = b.statistic# 18 | and a.name like '%ga memory%'; 19 | 20 | set autotrace traceonly statistics; 21 | select * from t order by 1,2,3,4; 22 | set autotrace off; 23 | 24 | select a.name, to_char(b.value, '999,999,999') bytes, 25 | to_char(round(b.value/1024/1024,1), '99,999.9' ) mbytes 26 | from v$statname a, v$mystat b 27 | where a.statistic# = b.statistic# 28 | and a.name like '%ga memory%'; 29 | 30 | begin 31 | for i in 1 .. 200000 32 | loop 33 | demo_pkg.g_data(i) := 'x'; 34 | end loop; 35 | end; 36 | / 37 | 38 | select a.name, to_char(b.value, '999,999,999') bytes, 39 | to_char(round(b.value/1024/1024,1), '99,999.9' ) mbytes 40 | from v$statname a, v$mystat b 41 | where a.statistic# = b.statistic# 42 | and a.name like '%ga memory%'; 43 | 44 | set autotrace traceonly statistics; 45 | select * from t order by 1,2,3,4; 46 | set autotrace off; 47 | -------------------------------------------------------------------------------- /scripts/ch04/demo03.sql: -------------------------------------------------------------------------------- 1 | -- The System Global Area 2 | 3 | set echo on 4 | 5 | compute sum of bytes on pool 6 | break on pool skip 1 7 | 8 | select pool, name, bytes 9 | from v$sgastat 10 | order by pool, name; 11 | 12 | show parameter sga_target 13 | 14 | select component, granule_size from v$sga_dynamic_components; 15 | -------------------------------------------------------------------------------- /scripts/ch04/demo04.sql: -------------------------------------------------------------------------------- 1 | -- Managing Blocks in the Buffer Cache 2 | 3 | conn / as sysdba 4 | 5 | set echo on 6 | 7 | column what form a30 8 | 9 | select tch, file#, dbablk, 10 | case when obj = 4294967295 11 | then 'rbs/compat segment' 12 | else (select max( '('||object_type||') ' || 13 | owner || '.' || object_name ) || 14 | decode( count(*), 1, '', ' maybe!' ) 15 | from dba_objects 16 | where data_object_id = X.OBJ ) 17 | end what 18 | from ( 19 | select tch, file#, dbablk, obj 20 | from x$bh 21 | where state <> 0 22 | order by tch desc 23 | ) x 24 | where rownum <= 5 25 | / 26 | 27 | select data_object_id, count(*) 28 | from dba_objects 29 | where data_object_id is not null 30 | group by data_object_id 31 | having count(*) > 1; 32 | 33 | select tch, file#, dbablk, DUMMY 34 | from x$bh, (select dummy from dual) 35 | where obj = (select data_object_id 36 | from dba_objects 37 | where object_name = 'DUAL' 38 | and data_object_id is not null) 39 | / 40 | 41 | exec dbms_lock.sleep(3.2); 42 | / 43 | exec dbms_lock.sleep(3.2); 44 | / 45 | exec dbms_lock.sleep(3.2); 46 | / 47 | exec dbms_lock.sleep(3.2); 48 | / 49 | exec dbms_lock.sleep(3.2); 50 | / 51 | -------------------------------------------------------------------------------- /scripts/ch04/demo05.sql: -------------------------------------------------------------------------------- 1 | -- Multiple Block Sizes 2 | 3 | set echo on 4 | 5 | create tablespace ts_16k 6 | datafile '/tmp/ts_16k.dbf' 7 | size 5m 8 | blocksize 16k; 9 | 10 | show parameter 16k 11 | 12 | alter system set sga_target=300m scope=spfile; 13 | alter system set db_16k_cache_size = 16m scope=spfile; 14 | connect / as sysdba 15 | startup force 16 | 17 | show parameter 16k 18 | -------------------------------------------------------------------------------- /scripts/ch04/demo06.sql: -------------------------------------------------------------------------------- 1 | -- Manual SGA Memory Management 2 | 3 | conn / as sysdba 4 | @?/rdbms/admin/dbmspool 5 | grant execute on dbms_shared_pool to eoda; 6 | 7 | conn eoda/foo 8 | 9 | set echo on 10 | 11 | declare 12 | k varchar2(30); 13 | ss varchar2(2000); 14 | begin 15 | for i in 1 .. 100000 loop 16 | ss := 'create or replace procedure SP' || i || ' is 17 | a number; 18 | begin 19 | a := 123456789012345678901234567890; 20 | a := 123456789012345678901234567890; 21 | a := 123456789012345678901234567890; 22 | a := 123456789012345678901234567890; 23 | a := 123456789012345678901234567890; 24 | a := 123456789012345678901234567890; 25 | a := 123456789012345678901234567890; 26 | a := 123456789012345678901234567890; 27 | a := 123456789012345678901234567890; 28 | a := 123456789012345678901234567890; 29 | a := 123456789012345678901234567890; 30 | a := 123456789012345678901234567890; 31 | a := 123456789012345678901234567890; 32 | a := 123456789012345678901234567890; 33 | a := 123456789012345678901234567890; 34 | end;'; 35 | execute immediate ss; 36 | k := 'SP' || i; 37 | sys.dbms_shared_pool.keep(k); 38 | end loop; 39 | end; 40 | / 41 | 42 | select component, parameter, oper_type, oper_mode from v$memory_resize_ops; 43 | -------------------------------------------------------------------------------- /scripts/ch04/gen_load.sh: -------------------------------------------------------------------------------- 1 | #!/bin/bash 2 | for i in {1..25} 3 | do 4 | sqlplus eoda/foo @gen_load.sql & 5 | done 6 | -------------------------------------------------------------------------------- /scripts/ch04/gen_load.sql: -------------------------------------------------------------------------------- 1 | declare 2 | l_msg long; 3 | l_status number; 4 | begin 5 | dbms_alert.register( 'WAITING' ); 6 | for i in 1 .. 999999 loop 7 | dbms_application_info.set_client_info( i ); 8 | dbms_alert.waitone( 'WAITING', l_msg, l_status, 0 ); 9 | exit when l_status = 0; 10 | for x in ( select * from t order by 1, 2, 3, 4 ) 11 | loop 12 | null; 13 | end loop; 14 | end loop; 15 | end; 16 | / 17 | exit 18 | -------------------------------------------------------------------------------- /scripts/ch04/reset_stat.sql: -------------------------------------------------------------------------------- 1 | drop table sess_stats; 2 | 3 | create table sess_stats 4 | ( name varchar2(64), value number, diff number ); 5 | 6 | variable sid number 7 | exec :sid := &1 8 | -------------------------------------------------------------------------------- /scripts/ch04/run.sql: -------------------------------------------------------------------------------- 1 | @stats 2 | @single_load 3 | !gen_load.sh 4 | exec dbms_lock.sleep(60) 5 | @single_load 6 | !gen_load.sh 7 | exec dbms_lock.sleep(60) 8 | @single_load 9 | !gen_load.sh 10 | exec dbms_lock.sleep(60) 11 | @single_load 12 | !gen_load.sh 13 | exec dbms_lock.sleep(60) 14 | @single_load 15 | !gen_load.sh 16 | exec dbms_lock.sleep(60) 17 | @single_load 18 | !gen_load.sh 19 | exec dbms_lock.sleep(60) 20 | @single_load 21 | !gen_load.sh 22 | exec dbms_lock.sleep(60) 23 | @single_load 24 | !gen_load.sh 25 | exec dbms_lock.sleep(60) 26 | @single_load 27 | !gen_load.sh 28 | exec dbms_lock.sleep(60) 29 | @single_load 30 | !gen_load.sh 31 | exec dbms_lock.sleep(60) 32 | @single_load 33 | !gen_load.sh 34 | exec dbms_lock.sleep(60) 35 | @single_load 36 | !gen_load.sh 37 | exec dbms_lock.sleep(60) 38 | @single_load 39 | @stop 40 | -------------------------------------------------------------------------------- /scripts/ch04/run_query.sql: -------------------------------------------------------------------------------- 1 | connect eoda/foo 2 | set serveroutput off 3 | set echo on 4 | column sid new_val SID 5 | select sid from v$mystat where rownum = 1; 6 | alter session set workarea_size_policy=manual; 7 | alter session set sort_area_size = &1; 8 | prompt run @reset_stat &SID and @watch_stat in another session here! 9 | pause 10 | set termout off 11 | select * from t order by 1, 2, 3, 4; 12 | set termout on 13 | prompt run @watch_stat in another session here! 14 | pause 15 | -------------------------------------------------------------------------------- /scripts/ch04/single_load.sql: -------------------------------------------------------------------------------- 1 | connect eoda/foo 2 | set echo on 3 | declare 4 | l_first_time boolean default true; 5 | begin 6 | for x in ( select * from t order by 1, 2, 3, 4 ) 7 | loop 8 | if ( l_first_time ) 9 | then 10 | insert into sess_stats 11 | ( name, value, active ) 12 | select name, value, 13 | (select count(*) 14 | from v$session 15 | where status = 'ACTIVE' 16 | and username is not null) 17 | from 18 | ( 19 | select a.name, b.value 20 | from v$statname a, v$sesstat b 21 | where a.statistic# = b.statistic# 22 | and b.sid = (select sid from v$mystat where rownum=1) 23 | and (a.name like '%ga %' 24 | or a.name like '%direct temp%') 25 | union all 26 | select 'total: ' || a.name, sum(b.value) 27 | from v$statname a, v$sesstat b, v$session c 28 | where a.statistic# = b.statistic# 29 | and (a.name like '%ga %' 30 | or a.name like '%direct temp%') 31 | and b.sid = c.sid 32 | and c.username is not null 33 | group by 'total: ' || a.name 34 | ); 35 | l_first_time := false; 36 | end if; 37 | end loop; 38 | end; 39 | / 40 | commit; 41 | 42 | -------------------------------------------------------------------------------- /scripts/ch04/stats.sql: -------------------------------------------------------------------------------- 1 | -- Automatic PGA Memory Management, Determining How the Memory Is Allocated 2 | 3 | drop table sess_stats; 4 | create table sess_stats 5 | as 6 | select name, value, 0 active 7 | from 8 | ( 9 | select a.name, b.value 10 | from v$statname a, v$sesstat b 11 | where a.statistic# = b.statistic# 12 | and b.sid = (select sid from v$mystat where rownum=1) 13 | and (a.name like '%ga %' 14 | or a.name like '%direct temp%') 15 | union all 16 | select 'total: ' || a.name, sum(b.value) 17 | from v$statname a, v$sesstat b, v$session c 18 | where a.statistic# = b.statistic# 19 | and (a.name like '%ga %' 20 | or a.name like '%direct temp%') 21 | and b.sid = c.sid 22 | and c.username is not null 23 | group by 'total: ' || a.name 24 | ); 25 | -------------------------------------------------------------------------------- /scripts/ch04/stop.sql: -------------------------------------------------------------------------------- 1 | begin 2 | dbms_alert.signal( 'WAITING', '' ); 3 | commit; 4 | end; 5 | / 6 | -------------------------------------------------------------------------------- /scripts/ch04/watch_stat.sql: -------------------------------------------------------------------------------- 1 | merge into sess_stats 2 | using 3 | ( 4 | select a.name, b.value 5 | from v$statname a, v$sesstat b 6 | where a.statistic# = b.statistic# 7 | and b.sid = :sid 8 | and (a.name like '%ga %' 9 | or a.name like '%direct temp%') 10 | ) curr_stats 11 | on (sess_stats.name = curr_stats.name) 12 | when matched then 13 | update set diff = curr_stats.value - sess_stats.value, 14 | value = curr_stats.value 15 | when not matched then 16 | insert ( name, value, diff ) 17 | values 18 | ( curr_stats.name, curr_stats.value, null ) 19 | / 20 | 21 | column name format a50 22 | 23 | select name, 24 | case when name like '%ga %' 25 | then round(value/1024,0) 26 | else value 27 | end kbytes_writes, 28 | case when name like '%ga %' 29 | then round(diff /1024,0) 30 | else value 31 | end diff_kbytes_writes 32 | from sess_stats 33 | order by name; 34 | -------------------------------------------------------------------------------- /scripts/ch04/what_if.sql: -------------------------------------------------------------------------------- 1 | with data(users) 2 | as 3 | (select 1 users from dual 4 | union all 5 | select users+25 from data where users+25 <= 275) 6 | select users, 7 my_pga, 7*users total_pga 7 | from data 8 | order by users 9 | / 10 | -------------------------------------------------------------------------------- /scripts/ch05/demo01.sql: -------------------------------------------------------------------------------- 1 | -- Dedicated Server Connections 2 | 3 | set echo on 4 | 5 | select a.spid dedicated_server, b.process clientpid 6 | from v$process a, v$session b 7 | where a.addr = b.paddr 8 | and b.sid = sys_context('userenv','sid'); 9 | 10 | /* -- alternate way of selecting 11 | select 12 | a.spid dedicated_server 13 | ,b.process clientpid 14 | from v$process a -- shows dedicated server process ID 15 | ,v$session b -- shows client process ID 16 | where a.addr = b.paddr 17 | and b.sid = (select sid from v$mystat where rownum=1); 18 | */ 19 | -------------------------------------------------------------------------------- /scripts/ch05/demo02.sql: -------------------------------------------------------------------------------- 1 | -- Connections vs. Sessions, part 1 2 | 3 | set echo on 4 | 5 | column username format a15 6 | 7 | select username, sid, serial#, server, paddr, status 8 | from v$session 9 | where username = USER 10 | / 11 | 12 | set autotrace on statistics 13 | 14 | select username, sid, serial#, server, paddr, status 15 | from v$session 16 | where username = USER 17 | / 18 | 19 | set autotrace off 20 | -------------------------------------------------------------------------------- /scripts/ch05/demo03.sql: -------------------------------------------------------------------------------- 1 | -- Connections vs. Sessions, part 2 2 | 3 | set echo on 4 | 5 | select * from v$session where username = 'EODA'; 6 | 7 | select username, program 8 | from v$process 9 | where addr = hextoraw( '00000000727FE9B0' ); 10 | 11 | select username, sid, serial#, server, paddr, status 12 | from v$session 13 | where username = USER; 14 | 15 | -------------------------------------------------------------------------------- /scripts/ch05/demo04.sql: -------------------------------------------------------------------------------- 1 | -- Shared Server connections 2 | 3 | set echo on 4 | 5 | column username format a9 6 | column sid format 99999 7 | column serial# format 9999999 8 | column program format a21 9 | 10 | select a.username, a.sid, a.serial#, a.server, 11 | a.paddr, a.status, b.program 12 | from v$session a left join v$process b 13 | on (a.paddr = b.addr) 14 | where a.username = 'EODA' 15 | / 16 | -------------------------------------------------------------------------------- /scripts/ch05/demo05.sql: -------------------------------------------------------------------------------- 1 | -- Background processes 2 | 3 | set echo on 4 | 5 | column name format a4 6 | column description format a40 7 | 8 | select paddr, name, description 9 | from v$bgprocess 10 | order by paddr desc 11 | / 12 | 13 | select paddr, name, description 14 | from v$bgprocess 15 | where paddr <> '00' 16 | order by paddr desc 17 | / 18 | -------------------------------------------------------------------------------- /scripts/ch06/binds/demo13.sql: -------------------------------------------------------------------------------- 1 | set echo on 2 | define NumUsers=&1 3 | 4 | connect scott/tiger 5 | 6 | begin 7 | for i in 1 .. 10 8 | loop 9 | for x in (select * from user_tables where table_name = 'T'||i ) 10 | loop 11 | execute immediate 'drop table ' || x.table_name; 12 | end loop; 13 | execute immediate 'create table t' || i || ' ( x int )'; 14 | end loop; 15 | end; 16 | / 17 | 18 | connect eoda/foo 19 | set echo off 20 | set verify off 21 | set feedback off 22 | spool temp.sh 23 | begin 24 | dbms_output.put_line( 'echo exec statspack.snap | sqlplus eoda/foo' ); 25 | for i in 1 .. &NumUsers 26 | loop 27 | dbms_output.put_line( 'java instest t' || i ||' ' || chr(38) ); 28 | end loop; 29 | dbms_output.put_line( 'wait' ); 30 | dbms_output.put_line( 'echo exec statspack.snap | sqlplus eoda/foo' ); 31 | end; 32 | / 33 | spool off 34 | set echo on 35 | set verify on 36 | set feedback on 37 | host /bin/bash temp.sh 38 | 39 | column b new_val begin_snap 40 | column e new_val end_snap 41 | define report_name=multiuser_&NumUsers. 42 | select max(decode(rn,1,snap_id)) e, 43 | max(decode(rn,2,snap_id)) b 44 | from ( 45 | select snap_id, row_number() over (order by snap_id desc) rn 46 | from perfstat.stats$snapshot 47 | ) 48 | where rn <= 2 49 | / 50 | 51 | insert into perfstat.STATS$IDLE_EVENT ( event ) 52 | select 'PL/SQL lock timer' 53 | from dual 54 | where not exists 55 | (select null from perfstat.STATS$IDLE_EVENT where event = 'PL/SQL lock timer') 56 | / 57 | commit; 58 | 59 | @?/rdbms/admin/spreport 60 | -------------------------------------------------------------------------------- /scripts/ch06/binds/instest.java: -------------------------------------------------------------------------------- 1 | import java.sql.*; 2 | import java.sql.DriverManager; 3 | import java.sql.Connection; 4 | import java.sql.SQLException; 5 | import java.io.*; 6 | 7 | public class instest 8 | { 9 | static public void main(String args[]) throws Exception 10 | { 11 | System.out.println( "start" ); 12 | DriverManager.registerDriver(new oracle.jdbc.driver.OracleDriver()); 13 | Connection 14 | conn = DriverManager.getConnection 15 | ("jdbc:oracle:thin:@heesta:1521:ORA12CR1", 16 | "scott", "tiger"); 17 | conn.setAutoCommit( false ); 18 | PreparedStatement pstmt = 19 | conn.prepareStatement 20 | ("insert into "+ args[0] + " (x) values(?)" ); 21 | for( int i = 0; i < 25000; i++ ) 22 | { 23 | pstmt.setInt( 1, i ); 24 | pstmt.executeUpdate(); 25 | } 26 | conn.commit(); 27 | conn.close(); 28 | System.out.println( "done" ); 29 | } 30 | } 31 | 32 | -------------------------------------------------------------------------------- /scripts/ch06/binds/run.sql: -------------------------------------------------------------------------------- 1 | @demo13 3 2 | @demo13 4 3 | @demo13 5 4 | @demo13 6 5 | @demo13 7 6 | @demo13 8 7 | @demo13 9 8 | @demo13 10 9 | -------------------------------------------------------------------------------- /scripts/ch06/demo01.sql: -------------------------------------------------------------------------------- 1 | -- Pessimistic Locking 2 | 3 | set echo on 4 | 5 | connect scott/tiger 6 | 7 | select empno, ename, sal from emp where deptno = 10; 8 | variable empno number 9 | variable ename varchar2(20) 10 | variable sal number 11 | exec :empno := 7934; :ename := 'MILLER'; :sal := 1300; 12 | 13 | select empno, ename, sal 14 | from emp 15 | where empno = :empno 16 | and decode( ename, :ename, 1 ) = 1 17 | and decode( sal, :sal, 1 ) = 1 18 | for update nowait 19 | / 20 | 21 | update emp 22 | set ename = :ename, sal = :sal 23 | where empno = :empno; 24 | commit; 25 | -------------------------------------------------------------------------------- /scripts/ch06/demo02.sql: -------------------------------------------------------------------------------- 1 | -- Optimistic Locking Using a Version Column 2 | 3 | drop table dept purge; 4 | set echo on 5 | 6 | create table dept 7 | ( deptno number(2), 8 | dname varchar2(14), 9 | loc varchar2(13), 10 | last_mod timestamp with time zone 11 | default systimestamp 12 | not null, 13 | constraint dept_pk primary key(deptno) 14 | ) 15 | / 16 | 17 | insert into dept( deptno, dname, loc ) 18 | select deptno, dname, loc 19 | from scott.dept; 20 | 21 | commit; 22 | 23 | variable deptno number 24 | variable dname varchar2(14) 25 | variable loc varchar2(13) 26 | variable last_mod varchar2(50) 27 | 28 | begin 29 | :deptno := 10; 30 | select dname, loc, to_char( last_mod, 'DD-MON-YYYY HH.MI.SSXFF AM TZR' ) 31 | into :dname,:loc,:last_mod 32 | from dept 33 | where deptno = :deptno; 34 | end; 35 | / 36 | 37 | column dno format 999999 38 | column dname format a12 39 | column loc format a10 40 | column lm format a40 41 | 42 | select :deptno dno, :dname dname, :loc loc, :last_mod lm 43 | from dual; 44 | 45 | update dept 46 | set dname = initcap(:dname), 47 | last_mod = systimestamp 48 | where deptno = :deptno 49 | and last_mod = to_timestamp_tz(:last_mod, 'DD-MON-YYYY HH.MI.SSXFF AM TZR' ); 50 | 51 | update dept 52 | set dname = upper(:dname), 53 | last_mod = systimestamp 54 | where deptno = :deptno 55 | and last_mod = to_timestamp_tz(:last_mod, 'DD-MON-YYYY HH.MI.SSXFF AM TZR' ); 56 | -------------------------------------------------------------------------------- /scripts/ch06/demo03.sql: -------------------------------------------------------------------------------- 1 | -- Optimistic Locking Using a Checksum 2 | 3 | set echo on 4 | 5 | alter table dept drop column last_mod; 6 | 7 | variable deptno number 8 | variable dname varchar2(14) 9 | variable loc varchar2(13) 10 | variable hash number 11 | 12 | begin 13 | select deptno, dname, loc, 14 | ora_hash( dname || '/' || loc ) hash 15 | into :deptno, :dname, :loc, :hash 16 | from dept 17 | where deptno = 10; 18 | end; 19 | / 20 | 21 | column ":deptno" format 99999999 22 | column ":dname" format a15 23 | column ":loc" format a20 24 | 25 | select :deptno, :dname, :loc, :hash 26 | from dual; 27 | 28 | exec :dname := lower(:dname); 29 | 30 | update dept 31 | set dname = :dname 32 | where deptno = :deptno 33 | and ora_hash( dname || '/' || loc ) = :hash 34 | / 35 | 36 | select dept.*, 37 | ora_hash( dname || '/' || loc ) hash 38 | from dept 39 | where deptno = :deptno; 40 | 41 | update dept 42 | set dname = :dname 43 | where deptno = :deptno 44 | and ora_hash( dname || '/' || loc ) = :hash 45 | / 46 | 47 | alter table dept 48 | add hash as 49 | ( ora_hash(dname || '/' || loc ) ); 50 | 51 | select * 52 | from dept 53 | where deptno = :deptno; 54 | -------------------------------------------------------------------------------- /scripts/ch06/demo04.sql: -------------------------------------------------------------------------------- 1 | -- Blocked Inserts 2 | 3 | connect scott/tiger 4 | set echo on 5 | 6 | drop table demo purge; 7 | create table demo ( x int primary key ); 8 | 9 | create or replace trigger demo_bifer 10 | before insert on demo 11 | for each row 12 | declare 13 | l_lock_id number; 14 | resource_busy exception; 15 | pragma exception_init( resource_busy, -54 ); 16 | begin 17 | l_lock_id := 18 | dbms_utility.get_hash_value( to_char( :new.x ), 0, 1024 ); 19 | if ( dbms_lock.request 20 | ( id => l_lock_id, 21 | lockmode => dbms_lock.x_mode, 22 | timeout => 0, 23 | release_on_commit => TRUE ) not in (0,4) ) 24 | then 25 | raise resource_busy; 26 | end if; 27 | end; 28 | / 29 | 30 | insert into demo(x) values (1); 31 | 32 | declare 33 | pragma autonomous_transaction; 34 | begin 35 | insert into demo(x) values (1); 36 | commit; 37 | end; 38 | / 39 | -------------------------------------------------------------------------------- /scripts/ch06/demo05.sql: -------------------------------------------------------------------------------- 1 | -- Deadlocks 2 | 3 | set echo on 4 | 5 | drop table c purge; 6 | drop table p purge; 7 | 8 | create table p ( x int primary key ); 9 | create table c ( x references p ); 10 | insert into p values ( 1 ); 11 | insert into p values ( 2 ); 12 | commit; 13 | 14 | insert into c values ( 2 ); 15 | 16 | set echo off 17 | 18 | prompt in another session issue: 19 | prompt delete from p where x = 1;; 20 | -------------------------------------------------------------------------------- /scripts/ch06/demo08.sql: -------------------------------------------------------------------------------- 1 | -- TX locks 2 | 3 | set echo on 4 | 5 | drop table t purge; 6 | 7 | create table t 8 | ( x int primary key, 9 | y varchar2(4000) 10 | ) 11 | / 12 | 13 | insert into t (x,y) 14 | select rownum, rpad('*',148,'*') 15 | from dual 16 | connect by level <= 46; 17 | 18 | select length(y), 19 | dbms_rowid.rowid_block_number(rowid) blk, 20 | count(*), min(x), max(x) 21 | from t 22 | group by length(y), dbms_rowid.rowid_block_number(rowid); 23 | 24 | create or replace procedure do_update( p_n in number ) 25 | as 26 | pragma autonomous_transaction; 27 | l_rec t%rowtype; 28 | resource_busy exception; 29 | pragma exception_init( resource_busy, -54 ); 30 | begin 31 | select * 32 | into l_rec 33 | from t 34 | where x = p_n 35 | for update NOWAIT; 36 | 37 | do_update( p_n+1 ); 38 | commit; 39 | exception 40 | when resource_busy 41 | then 42 | dbms_output.put_line( 'locked out trying to select row ' || p_n ); 43 | commit; 44 | when no_data_found 45 | then 46 | dbms_output.put_line( 'we finished - no problems' ); 47 | commit; 48 | end; 49 | / 50 | 51 | exec do_update(1); 52 | 53 | pause 54 | 55 | truncate table t; 56 | 57 | insert into t (x,y) 58 | select rownum, rpad('*',147,'*') 59 | from dual 60 | connect by level <= 46; 61 | 62 | select length(y), 63 | dbms_rowid.rowid_block_number(rowid) blk, 64 | count(*), min(x), max(x) 65 | from t 66 | group by length(y), dbms_rowid.rowid_block_number(rowid); 67 | 68 | exec do_update(1); 69 | -------------------------------------------------------------------------------- /scripts/ch06/demo09.sql: -------------------------------------------------------------------------------- 1 | -- TM (DML Enqueue) Locks 2 | 3 | drop table t1 purge; 4 | drop table t2 purge; 5 | 6 | set echo on 7 | 8 | create table t1 ( x int ); 9 | create table t2 ( x int ); 10 | 11 | insert into t1 values ( 1 ); 12 | 13 | insert into t2 values ( 1 ); 14 | 15 | col username form a15 16 | 17 | select (select username 18 | from v$session 19 | where sid = v$lock.sid) username, 20 | sid, 21 | id1, 22 | id2, 23 | lmode, 24 | request, block, v$lock.type 25 | from v$lock 26 | where sid = sys_context('userenv','sid'); 27 | 28 | column object_name form a15 29 | 30 | select object_name, object_id 31 | from user_objects 32 | where object_name in ('T1','T2'); 33 | -------------------------------------------------------------------------------- /scripts/ch06/demo10.sql: -------------------------------------------------------------------------------- 1 | -- DDL locks 2 | 3 | set echo on 4 | 5 | drop table t purge; 6 | create table t as select * from all_objects; 7 | 8 | select object_id from user_objects where object_name = 'T'; 9 | 10 | create index t_idx on t(owner,object_type,object_name) ONLINE; 11 | 12 | -- Run this from another session while the index is being built. 13 | select (select username 14 | from v$session 15 | where sid = v$lock.sid) username, 16 | sid, 17 | id1, 18 | id2, 19 | lmode, 20 | request, block, v$lock.type 21 | from v$lock 22 | where id1 = &&your_object_id 23 | / 24 | -------------------------------------------------------------------------------- /scripts/ch06/demo11.sql: -------------------------------------------------------------------------------- 1 | -- DDL Locks 2 | 3 | connect eoda/foo 4 | 5 | column owner format a8 6 | column sid format 99999 7 | column name format a21 8 | column held format a10 9 | column request format a8 10 | column type format a20 11 | 12 | set linesize 1000 13 | select session_id sid, owner, name, type, 14 | mode_held held, mode_requested request 15 | from dba_ddl_locks 16 | where session_id = (select sid from v$mystat where rownum=1) 17 | / 18 | 19 | create or replace procedure p 20 | as 21 | begin 22 | null; 23 | end; 24 | / 25 | 26 | exec p 27 | 28 | select session_id sid, owner, name, type, 29 | mode_held held, mode_requested request 30 | from dba_ddl_locks 31 | where session_id = (select sid from v$mystat where rownum=1) 32 | / 33 | 34 | alter procedure p compile; 35 | 36 | select session_id sid, owner, name, type, 37 | mode_held held, mode_requested request 38 | from dba_ddl_locks 39 | where session_id = (select sid from v$mystat where rownum=1) 40 | / 41 | -------------------------------------------------------------------------------- /scripts/ch06/initrans.sql: -------------------------------------------------------------------------------- 1 | -- Initial Transaction Slots, 1 or 2? 2 | 3 | connect eoda/foo 4 | drop table t purge; 5 | 6 | set echo on 7 | 8 | create table t ( x int ); 9 | select ini_trans from user_tables where table_name = 'T'; 10 | 11 | insert into t values ( 1 ); 12 | 13 | column b new_val B 14 | column f new_val F 15 | 16 | select dbms_rowid.ROWID_BLOCK_NUMBER(rowid) B, 17 | dbms_rowid.ROWID_TO_ABSOLUTE_FNO( rowid, user, 'T' ) F 18 | from t; 19 | 20 | alter system dump datafile &F block &B; 21 | 22 | column trace new_val TRACE 23 | 24 | select c.value || '/' || d.instance_name || '_ora_' || a.spid || '.trc' trace 25 | from v$process a, v$session b, v$parameter c, v$instance d 26 | where a.addr = b.paddr 27 | and b.audsid = userenv('sessionid') 28 | and c.name = 'user_dump_dest' 29 | / 30 | 31 | disconnect 32 | edit &TRACE 33 | connect eoda/foo 34 | -------------------------------------------------------------------------------- /scripts/ch06/nobinds/demo13.sql: -------------------------------------------------------------------------------- 1 | set echo on 2 | define NumUsers=&1 3 | 4 | connect scott/tiger 5 | 6 | begin 7 | for i in 1 .. 10 8 | loop 9 | for x in (select * from user_tables where table_name = 'T'||i ) 10 | loop 11 | execute immediate 'drop table ' || x.table_name; 12 | end loop; 13 | execute immediate 'create table t' || i || ' ( x int )'; 14 | end loop; 15 | end; 16 | / 17 | 18 | connect eoda/foo 19 | set echo off 20 | set verify off 21 | set feedback off 22 | spool temp.sh 23 | begin 24 | dbms_output.put_line( 'echo exec statspack.snap | sqlplus eoda/foo' ); 25 | for i in 1 .. &NumUsers 26 | loop 27 | dbms_output.put_line( 'java instest t' || i ||' ' || chr(38) ); 28 | end loop; 29 | dbms_output.put_line( 'wait' ); 30 | dbms_output.put_line( 'echo exec statspack.snap | sqlplus eoda/foo' ); 31 | end; 32 | / 33 | spool off 34 | set echo on 35 | set verify on 36 | set feedback on 37 | host /bin/bash temp.sh 38 | 39 | column b new_val begin_snap 40 | column e new_val end_snap 41 | define report_name=multiuser_&NumUsers. 42 | select max(decode(rn,1,snap_id)) e, 43 | max(decode(rn,2,snap_id)) b 44 | from ( 45 | select snap_id, row_number() over (order by snap_id desc) rn 46 | from perfstat.stats$snapshot 47 | ) 48 | where rn <= 2 49 | / 50 | 51 | insert into perfstat.STATS$IDLE_EVENT ( event ) 52 | select 'PL/SQL lock timer' 53 | from dual 54 | where not exists 55 | (select null from perfstat.STATS$IDLE_EVENT where event = 'PL/SQL lock timer') 56 | / 57 | commit; 58 | 59 | @?/rdbms/admin/spreport 60 | -------------------------------------------------------------------------------- /scripts/ch06/nobinds/instest.java: -------------------------------------------------------------------------------- 1 | import java.sql.*; 2 | import java.sql.DriverManager; 3 | import java.sql.Connection; 4 | import java.sql.SQLException; 5 | import java.io.*; 6 | 7 | public class instest 8 | { 9 | static public void main(String args[]) throws Exception 10 | { 11 | System.out.println( "start" ); 12 | DriverManager.registerDriver(new oracle.jdbc.driver.OracleDriver()); 13 | Connection 14 | conn = DriverManager.getConnection 15 | ("jdbc:oracle:thin:@heesta:1521:ORA12CR1", "scott", "tiger"); 16 | conn.setAutoCommit( false ); 17 | Statement stmt = conn.createStatement(); 18 | for( int i = 0; i < 25000; i++ ) 19 | { 20 | stmt.execute 21 | ("insert into "+ args[0] + 22 | " (x) values(" + i + ")" ); 23 | } 24 | conn.commit(); 25 | conn.close(); 26 | System.out.println( "done" ); 27 | } 28 | } 29 | -------------------------------------------------------------------------------- /scripts/ch06/nobinds/run.sql: -------------------------------------------------------------------------------- 1 | @demo13 3 2 | @demo13 4 3 | @demo13 5 4 | @demo13 6 5 | @demo13 7 6 | @demo13 8 7 | @demo13 9 8 | @demo13 10 9 | -------------------------------------------------------------------------------- /scripts/ch07/demo01.sql: -------------------------------------------------------------------------------- 1 | -- SERIALIZABLE Transaction Example 2 | 3 | drop table a; 4 | drop table b; 5 | 6 | set echo on 7 | 8 | create table a ( x int ); 9 | create table b ( x int ); 10 | alter session set isolation_level = serializable; 11 | 12 | set echo off 13 | prompt in another session execute: 14 | prompt alter session set isolation_level = serializable;; 15 | pause 16 | set echo on 17 | 18 | insert into a select count(*) from b; 19 | set echo off 20 | prompt in another session execute: 21 | prompt insert into b select count(*) from a;; 22 | pause 23 | set echo on 24 | 25 | commit; 26 | set echo off 27 | prompt in another session execute: 28 | prompt commit;; 29 | pause 30 | set echo on 31 | 32 | commit; 33 | select * from a; 34 | select * from b; 35 | -------------------------------------------------------------------------------- /scripts/ch07/demo02.sql: -------------------------------------------------------------------------------- 1 | -- An Explanation for Higher Than Expected I/O on Hot Tables 2 | 3 | drop table t purge; 4 | 5 | set echo on 6 | 7 | create table t ( x int ); 8 | insert into t values ( 1 ); 9 | exec dbms_stats.gather_table_stats( user, 'T' ); 10 | select * from t; 11 | 12 | alter session set isolation_level=serializable; 13 | set autotrace on statistics 14 | select * from t; 15 | 16 | set echo off 17 | prompt in another session: 18 | prompt begin 19 | prompt for i in 1 .. 10000 20 | prompt loop 21 | prompt update t set x = x+1;; 22 | prompt commit;; 23 | prompt end loop;; 24 | prompt end;; 25 | prompt / 26 | pause 27 | set echo on 28 | 29 | select * from t; 30 | set autotrace off 31 | -------------------------------------------------------------------------------- /scripts/ch07/demo03.sql: -------------------------------------------------------------------------------- 1 | -- Consistent Reads and Current Reads 2 | 3 | set echo on 4 | 5 | exec dbms_monitor.session_trace_enable 6 | 7 | select * from t; 8 | 9 | update t t1 set x = x+1; 10 | update t t2 set x = x+1; 11 | 12 | -- tk.sql is in the ch00 folder 13 | @tk "sys=no" 14 | -------------------------------------------------------------------------------- /scripts/ch07/demo04.sql: -------------------------------------------------------------------------------- 1 | -- Seeing a Restart, first example 2 | 3 | drop table t purge; 4 | 5 | set echo on 6 | 7 | create table t ( x int, y int ); 8 | 9 | insert into t values ( 1, 1 ); 10 | 11 | commit; 12 | 13 | create or replace trigger t_bufer 14 | before update on t for each row 15 | begin 16 | dbms_output.put_line 17 | ( 'old.x = ' || :old.x || 18 | ', old.y = ' || :old.y ); 19 | dbms_output.put_line 20 | ( 'new.x = ' || :new.x || 21 | ', new.y = ' || :new.y ); 22 | end; 23 | / 24 | 25 | set serveroutput on 26 | update t set x = x+1; 27 | 28 | set echo off 29 | prompt in another session: 30 | prompt set serveroutput on 31 | prompt update t set x = x+1 where x > 0;; 32 | pause 33 | set echo on 34 | commit; 35 | -------------------------------------------------------------------------------- /scripts/ch07/demo05.sql: -------------------------------------------------------------------------------- 1 | -- Seeing a Restart, second example 2 | 3 | drop table t purge; 4 | 5 | set echo on 6 | 7 | create table t ( x int, y int ); 8 | insert into t values ( 1, 1 ); 9 | commit; 10 | 11 | create or replace trigger t_bufer 12 | before update on t for each row 13 | begin 14 | dbms_output.put_line 15 | ( 'old.x = ' || :old.x || 16 | ', old.y = ' || :old.y ); 17 | dbms_output.put_line 18 | ( 'new.x = ' || :new.x || 19 | ', new.y = ' || :new.y ); 20 | end; 21 | / 22 | update t set x = x+1; 23 | 24 | set echo off 25 | prompt in another session: 26 | prompt set serveroutput on 27 | prompt update t set x = x+1 where y > 0;; 28 | pause 29 | set echo on 30 | commit; 31 | -------------------------------------------------------------------------------- /scripts/ch07/demo06.sql: -------------------------------------------------------------------------------- 1 | -- Seeing a Restart, third example 2 | 3 | drop table t purge; 4 | 5 | set echo on 6 | 7 | create table t ( x int, y int ); 8 | insert into t values ( 1, 1 ); 9 | commit; 10 | 11 | create or replace trigger t_bufer 12 | before update on t for each row 13 | begin 14 | dbms_output.put_line( 'fired' ); 15 | end; 16 | / 17 | 18 | update t set x = x+1; 19 | 20 | set echo off 21 | prompt in another session: 22 | prompt set serveroutput on 23 | prompt update t set x = x+1 where y > 0;; 24 | pause 25 | set echo on 26 | commit; 27 | 28 | -------------------------------------------------------------------------------- /scripts/ch08/demo01.sql: -------------------------------------------------------------------------------- 1 | -- Statement-Level Atomicity 2 | 3 | drop table t2 purge; 4 | drop table t purge; 5 | 6 | set echo on 7 | 8 | create table t2 ( cnt int ); 9 | 10 | insert into t2 values ( 0 ); 11 | 12 | commit; 13 | 14 | create table t ( x int check ( x>0 ) ); 15 | 16 | create trigger t_trigger 17 | before insert or delete on t for each row 18 | begin 19 | if ( inserting ) then 20 | update t2 set cnt = cnt +1; 21 | else 22 | update t2 set cnt = cnt -1; 23 | end if; 24 | dbms_output.put_line( 'I fired and updated ' || 25 | sql%rowcount || ' rows' ); 26 | end; 27 | / 28 | 29 | set serveroutput on 30 | insert into t values (1); 31 | 32 | insert into t values(-1); 33 | 34 | select * from t2; 35 | -------------------------------------------------------------------------------- /scripts/ch08/demo02.sql: -------------------------------------------------------------------------------- 1 | -- Procedure-Level Atomicity 2 | 3 | create or replace procedure p 4 | as 5 | begin 6 | insert into t values ( 1 ); 7 | insert into t values (-1 ); 8 | end; 9 | / 10 | 11 | delete from t; 12 | 13 | update t2 set cnt = 0; 14 | 15 | commit; 16 | 17 | select * from t; 18 | 19 | select * from t2; 20 | 21 | begin 22 | p; 23 | end; 24 | / 25 | 26 | select * from t; 27 | select * from t2; 28 | 29 | begin 30 | p; 31 | exception 32 | when others then 33 | dbms_output.put_line( 'Error!!!! ' || sqlerrm ); 34 | end; 35 | / 36 | 37 | select * from t; 38 | select * from t2; 39 | rollback; 40 | 41 | begin 42 | savepoint sp; 43 | p; 44 | exception 45 | when others then 46 | rollback to sp; 47 | dbms_output.put_line( 'Error!!!! ' || sqlerrm ); 48 | end; 49 | / 50 | 51 | select * from t; 52 | select * from t2; 53 | -------------------------------------------------------------------------------- /scripts/ch08/demo03.sql: -------------------------------------------------------------------------------- 1 | -- THE "WHEN OTHERS" CLAUSE 2 | 3 | set echo on 4 | 5 | set linesize 1000 6 | clear screen 7 | 8 | alter session set 9 | PLSQL_Warnings = 'enable:all' 10 | / 11 | 12 | create or replace procedure some_proc( p_str in varchar2 ) 13 | as 14 | begin 15 | dbms_output.put_line( p_str ); 16 | exception 17 | when others 18 | then 19 | -- call some log_error() routine 20 | null; 21 | end; 22 | / 23 | 24 | show errors procedure some_proc 25 | 26 | -------------------------------------------------------------------------------- /scripts/ch08/demo04.sql: -------------------------------------------------------------------------------- 1 | -- COMMITS in a Non-Distributed PL/SQL Block 2 | 3 | drop table t purge; 4 | 5 | set echo on 6 | 7 | create table t 8 | as 9 | select * 10 | from all_objects 11 | where 1=0 12 | / 13 | 14 | create or replace procedure p 15 | as 16 | begin 17 | for x in ( select * from all_objects ) 18 | loop 19 | insert into t values X; 20 | commit; 21 | end loop; 22 | end; 23 | / 24 | 25 | create or replace procedure p 26 | as 27 | begin 28 | for x in ( select * from all_objects ) 29 | loop 30 | insert into t values X; 31 | commit write NOWAIT; 32 | end loop; 33 | 34 | -- make internal call here to ensure 35 | -- redo was written by LGWR 36 | end; 37 | / 38 | -------------------------------------------------------------------------------- /scripts/ch08/demo05.sql: -------------------------------------------------------------------------------- 1 | -- IMMEDIATE Constraints 2 | 3 | drop table t purge; 4 | 5 | set echo on 6 | 7 | create table t ( x int unique ); 8 | 9 | insert into t values ( 1 ); 10 | 11 | insert into t values ( 2 ); 12 | 13 | commit; 14 | 15 | update t set x=x-1; 16 | -------------------------------------------------------------------------------- /scripts/ch08/demo06.sql: -------------------------------------------------------------------------------- 1 | -- DEFERRABLE Constraints and Cascading Updates, example 1 2 | 3 | drop table child purge; 4 | drop table parent purge; 5 | 6 | set echo on 7 | 8 | create table parent 9 | ( pk int primary key ) 10 | / 11 | 12 | create table child 13 | ( fk constraint child_fk_parent 14 | references parent(pk) 15 | deferrable 16 | initially immediate 17 | ) 18 | / 19 | 20 | insert into parent values ( 1 ); 21 | 22 | insert into child values ( 1 ); 23 | 24 | update parent set pk = 2; 25 | set constraint child_fk_parent deferred; 26 | update parent set pk = 2; 27 | set constraint child_fk_parent immediate; 28 | update child set fk = 2; 29 | set constraint child_fk_parent immediate; 30 | commit; 31 | -------------------------------------------------------------------------------- /scripts/ch08/demo07.sql: -------------------------------------------------------------------------------- 1 | -- DEFERRABLE Constraints and Cascading Updates, example 2 2 | 3 | drop table t purge; 4 | 5 | set echo on 6 | 7 | create table t 8 | ( x int constraint x_not_null not null deferrable, 9 | y int constraint y_not_null not null, 10 | z varchar2(30) 11 | ); 12 | 13 | insert into t(x,y,z) 14 | select rownum, rownum, rpad('x',30,'x') 15 | from all_users; 16 | 17 | exec dbms_stats.gather_table_stats( user, 'T' ); 18 | create index t_idx on t(y); 19 | 20 | explain plan for select count(*) from t; 21 | select * from table(dbms_xplan.display(null,null,'BASIC')); 22 | 23 | drop index t_idx; 24 | create index t_idx on t(x); 25 | 26 | explain plan for select count(*) from t; 27 | select * from table(dbms_xplan.display(null,null,'BASIC')); 28 | 29 | alter table t drop constraint x_not_null; 30 | alter table t modify x constraint x_not_null not null; 31 | 32 | explain plan for select count(*) from t; 33 | select * from table(dbms_xplan.display(null,null,'BASIC')); 34 | -------------------------------------------------------------------------------- /scripts/ch08/demo08.sql: -------------------------------------------------------------------------------- 1 | -- Committing in Loop, Performance Implications 2 | 3 | set echo on 4 | 5 | drop table t purge; 6 | 7 | create table t as select * from all_objects; 8 | 9 | exec dbms_stats.gather_table_stats( user, 'T' ); 10 | 11 | variable n number 12 | 13 | exec :n := dbms_utility.get_cpu_time; 14 | 15 | update t set object_name = lower(object_name); 16 | 17 | exec dbms_output.put_line( (dbms_utility.get_cpu_time-:n)|| ' cpu hsecs...' ); 18 | 19 | exec :n := dbms_utility.get_cpu_time; 20 | 21 | begin 22 | for x in ( select rowid rid, object_name, rownum r 23 | from t ) 24 | loop 25 | update t 26 | set object_name = lower(x.object_name) 27 | where rowid = x.rid; 28 | if ( mod(x.r,100) = 0 ) then 29 | commit; 30 | end if; 31 | end loop; 32 | commit; 33 | end; 34 | / 35 | 36 | exec dbms_output.put_line((dbms_utility.get_cpu_time-:n)||' cpu hsecs...' ); 37 | 38 | exec :n := dbms_utility.get_cpu_time; 39 | 40 | declare 41 | type ridArray is table of rowid; 42 | type vcArray is table of t.object_name%type; 43 | 44 | l_rids ridArray; 45 | l_names vcArray; 46 | 47 | cursor c is select rowid, object_name from t; 48 | begin 49 | open c; 50 | loop 51 | fetch c bulk collect into l_rids, l_names LIMIT 100; 52 | forall i in 1 .. l_rids.count 53 | update t 54 | set object_name = lower(l_names(i)) 55 | where rowid = l_rids(i); 56 | commit; 57 | exit when c%notfound; 58 | end loop; 59 | close c; 60 | end; 61 | / 62 | 63 | exec dbms_output.put_line( (dbms_utility.get_cpu_time-:n)||' cpu hsecs...' ); 64 | -------------------------------------------------------------------------------- /scripts/ch08/demo09.sql: -------------------------------------------------------------------------------- 1 | -- Snapshot Too Old Error 2 | 3 | set echo on 4 | 5 | drop table t purge; 6 | 7 | create table t as select * from all_objects; 8 | 9 | create index t_idx on t(object_name); 10 | 11 | exec dbms_stats.gather_table_stats( user, 'T', cascade=>true ); 12 | 13 | create undo tablespace undo_small 14 | datafile '/u01/dbfile/ORA12CR1/undo_small.dbf' 15 | size 10m reuse 16 | autoextend off 17 | / 18 | 19 | alter system set undo_tablespace = undo_small; 20 | 21 | begin 22 | for x in ( select /*+ INDEX(t t_idx) */ rowid rid, object_name, rownum r 23 | from t 24 | where object_name > ' ' ) 25 | loop 26 | update t 27 | set object_name = lower(x.object_name) 28 | where rowid = x.rid; 29 | if ( mod(x.r,100) = 0 ) then 30 | commit; 31 | end if; 32 | end loop; 33 | commit; 34 | end; 35 | / 36 | 37 | alter system set undo_tablespace = UNDOTBS1; 38 | drop tablespace undo_small; 39 | -------------------------------------------------------------------------------- /scripts/ch08/demo10.sql: -------------------------------------------------------------------------------- 1 | -- Restartable Processes Require Complex Logic 2 | 3 | drop table to_do purge; 4 | 5 | set echo on 6 | 7 | create table to_do 8 | as 9 | select distinct substr( object_name, 1,1 ) first_char 10 | from T 11 | / 12 | 13 | begin 14 | for x in ( select * from to_do ) 15 | loop 16 | update t set last_ddl_time = last_ddl_time+1 17 | where object_name like x.first_char || '%'; 18 | 19 | dbms_output.put_line( sql%rowcount || ' rows updated' ); 20 | delete from to_do where first_char = x.first_char; 21 | 22 | commit; 23 | end loop; 24 | end; 25 | / 26 | -------------------------------------------------------------------------------- /scripts/ch08/demo11.sql: -------------------------------------------------------------------------------- 1 | -- How Autonomous Transactions Work 2 | 3 | drop table t purge; 4 | 5 | set echo on; 6 | 7 | create table t ( msg varchar2(25) ); 8 | 9 | create or replace procedure Autonomous_Insert 10 | as 11 | pragma autonomous_transaction; 12 | begin 13 | insert into t values ( 'Autonomous Insert' ); 14 | commit; 15 | end; 16 | / 17 | 18 | create or replace procedure NonAutonomous_Insert 19 | as 20 | begin 21 | insert into t values ( 'NonAutonomous Insert' ); 22 | commit; 23 | end; 24 | / 25 | 26 | begin 27 | insert into t values ( 'Anonymous Block' ); 28 | NonAutonomous_Insert; 29 | rollback; 30 | end; 31 | / 32 | 33 | select * from t; 34 | 35 | delete from t; 36 | 37 | commit; 38 | 39 | begin 40 | insert into t values ( 'Anonymous Block' ); 41 | Autonomous_Insert; 42 | rollback; 43 | end; 44 | / 45 | 46 | select * from t; 47 | -------------------------------------------------------------------------------- /scripts/ch08/demo12.sql: -------------------------------------------------------------------------------- 1 | -- When to Use Autonomous Transactions 2 | 3 | drop table error_log purge; 4 | drop table t purge; 5 | 6 | set echo on 7 | 8 | create table error_log 9 | ( ts timestamp, 10 | err1 clob, 11 | err2 clob ) 12 | / 13 | 14 | create or replace 15 | procedure log_error 16 | ( p_err1 in varchar2, p_err2 in varchar2 ) 17 | as 18 | pragma autonomous_transaction; 19 | begin 20 | insert into error_log( ts, err1, err2 ) 21 | values ( systimestamp, p_err1, p_err2 ); 22 | commit; 23 | end; 24 | / 25 | 26 | create table t ( x int check (x>0) ); 27 | 28 | create or replace procedure p1( p_n in number ) 29 | as 30 | begin 31 | -- some code here 32 | insert into t (x) values ( p_n ); 33 | end; 34 | / 35 | 36 | create or replace procedure p2( p_n in number ) 37 | as 38 | begin 39 | -- code 40 | -- code 41 | p1(p_n); 42 | end; 43 | / 44 | 45 | begin 46 | p2( 1 ); 47 | p2( 2 ); 48 | p2( -1); 49 | exception 50 | when others 51 | then 52 | log_error( sqlerrm, dbms_utility.format_error_backtrace ); 53 | RAISE; 54 | end; 55 | / 56 | 57 | 58 | select * from t; 59 | rollback; 60 | select * from error_log; 61 | -------------------------------------------------------------------------------- /scripts/ch09/demo01.sql: -------------------------------------------------------------------------------- 1 | -- What is Undo?, example 1 2 | 3 | drop table t purge; 4 | 5 | set echo on 6 | 7 | create table t 8 | as 9 | select * 10 | from all_objects 11 | where 1=0; 12 | 13 | select * from t; 14 | 15 | set autotrace traceonly statistics 16 | select * from t; 17 | set autotrace off 18 | 19 | insert into t select * from all_objects; 20 | rollback; 21 | select * from t; 22 | set autotrace traceonly statistics 23 | select * from t; 24 | set autotrace off 25 | -------------------------------------------------------------------------------- /scripts/ch09/demo02.sql: -------------------------------------------------------------------------------- 1 | -- What Is Undo?, example 2 2 | 3 | drop table t purge; 4 | 5 | set echo on 6 | 7 | create table t ( x int ) 8 | segment creation deferred; 9 | 10 | select extent_id, bytes, blocks 11 | from user_extents 12 | where segment_name = 'T' 13 | order by extent_id; 14 | 15 | insert into t(x) values (1); 16 | rollback; 17 | 18 | select extent_id, bytes, blocks 19 | from user_extents 20 | where segment_name = 'T' 21 | order by extent_id; 22 | -------------------------------------------------------------------------------- /scripts/ch09/demo03.sql: -------------------------------------------------------------------------------- 1 | -- What Does a COMMIT Do? PL/SQL example 2 | 3 | drop table big_table purge; 4 | drop table t purge; 5 | 6 | @big_table 100000 7 | 8 | set echo on 9 | 10 | create table t 11 | as 12 | select * 13 | from big_table 14 | where 1=0; 15 | 16 | declare 17 | l_redo number; 18 | l_cpu number; 19 | l_ela number; 20 | begin 21 | dbms_output.put_line 22 | ( '-' || ' Rows' || ' Redo' || 23 | ' CPU' || ' Elapsed' ); 24 | for i in 1 .. 6 25 | loop 26 | l_redo := get_stat_val( 'redo size' ); 27 | insert into t select * from big_table where rownum <= power(10,i); 28 | l_cpu := dbms_utility.get_cpu_time; 29 | l_ela := dbms_utility.get_time; 30 | --commit work write wait; 31 | rollback; 32 | dbms_output.put_line 33 | ( '-' || 34 | to_char( power( 10, i ), '9,999,999') || 35 | to_char( (get_stat_val('redo size')-l_redo), '999,999,999' ) || 36 | to_char( (dbms_utility.get_cpu_time-l_cpu), '999,999' ) || 37 | to_char( (dbms_utility.get_time-l_ela), '999,999' ) ); 38 | end loop; 39 | end; 40 | / 41 | -------------------------------------------------------------------------------- /scripts/ch09/demo04.sql: -------------------------------------------------------------------------------- 1 | -- Measuring Redo 2 | 3 | set echo on 4 | 5 | set autotrace traceonly statistics; 6 | truncate table t; 7 | -- 8 | insert into t 9 | select * from big_table; 10 | 11 | truncate table t; 12 | 13 | insert /*+ APPEND */ into t 14 | select * from big_table; 15 | -------------------------------------------------------------------------------- /scripts/ch09/demo05.sql: -------------------------------------------------------------------------------- 1 | -- Setting NOLOGGING in SQL 2 | 3 | select log_mode from v$database; 4 | 5 | set echo on 6 | set serverout on 7 | 8 | drop table t purge; 9 | 10 | variable redo number 11 | exec :redo := get_stat_val( 'redo size' ); 12 | 13 | create table t 14 | as 15 | select * from all_objects; 16 | 17 | exec dbms_output.put_line( (get_stat_val('redo size')-:redo) || ' bytes of redo generated...' ); 18 | 19 | drop table t purge; 20 | 21 | variable redo number 22 | exec :redo := get_stat_val( 'redo size' ); 23 | 24 | create table t 25 | NOLOGGING 26 | as 27 | select * from all_objects; 28 | 29 | exec dbms_output.put_line( (get_stat_val('redo size')-:redo) || ' bytes of redo generated...' ); 30 | -------------------------------------------------------------------------------- /scripts/ch09/demo06.sql: -------------------------------------------------------------------------------- 1 | -- Setting NOLOGGING on an Index 2 | 3 | set echo on 4 | 5 | select log_mode from v$database; 6 | create index t_idx on t(object_name); 7 | 8 | variable redo number 9 | exec :redo := get_stat_val( 'redo size' ); 10 | 11 | alter index t_idx rebuild; 12 | 13 | exec dbms_output.put_line( (get_stat_val('redo size')-:redo) || ' bytes of redo generated...'); 14 | 15 | alter index t_idx nologging; 16 | 17 | exec :redo := get_stat_val( 'redo size' ); 18 | 19 | alter index t_idx rebuild; 20 | 21 | exec dbms_output.put_line( (get_stat_val('redo size')-:redo) || ' bytes of redo generated...'); 22 | -------------------------------------------------------------------------------- /scripts/ch09/demo07.sql: -------------------------------------------------------------------------------- 1 | -- Block Cleanout 2 | 3 | set echo on 4 | 5 | drop table t purge; 6 | 7 | create table t 8 | ( id number primary key, 9 | x char(2000), 10 | y char(2000), 11 | z char(2000) 12 | ) 13 | / 14 | 15 | exec dbms_stats.set_table_stats( user, 'T', numrows=>10000, numblks=>10000 ); 16 | 17 | declare 18 | l_rec t%rowtype; 19 | begin 20 | for i in 1 .. 10000 21 | loop 22 | select * into l_rec from t where id=i; 23 | end loop; 24 | end; 25 | / 26 | 27 | insert into t 28 | select rownum, 'x', 'y', 'z' 29 | from all_objects 30 | where rownum <= 10000; 31 | 32 | commit; 33 | 34 | variable redo number 35 | exec :redo := get_stat_val( 'redo size' ); 36 | 37 | declare 38 | l_rec t%rowtype; 39 | begin 40 | for i in 1 .. 10000 41 | loop 42 | select * into l_rec from t where id=i; 43 | end loop; 44 | end; 45 | / 46 | 47 | exec dbms_output.put_line( (get_stat_val('redo size')-:redo) || ' bytes of redo generated...'); 48 | 49 | 50 | exec :redo := get_stat_val( 'redo size' ); 51 | 52 | declare 53 | l_rec t%rowtype; 54 | begin 55 | for i in 1 .. 10000 56 | loop 57 | select * into l_rec from t where id=i; 58 | end loop; 59 | end; 60 | / 61 | 62 | exec dbms_output.put_line( (get_stat_val('redo size')-:redo) || ' bytes of redo generated...'); 63 | 64 | -------------------------------------------------------------------------------- /scripts/ch09/demo09.sql: -------------------------------------------------------------------------------- 1 | -- What Generates the Most and Least Undo? 2 | 3 | drop table t purge; 4 | 5 | set echo on 6 | 7 | create table t 8 | as 9 | select object_name unindexed, 10 | object_name indexed 11 | from all_objects 12 | / 13 | 14 | create index t_idx on t(indexed); 15 | 16 | exec dbms_stats.gather_table_stats(user,'T'); 17 | 18 | select used_ublk 19 | from v$transaction 20 | where addr = (select taddr 21 | from v$session 22 | where sid = (select sid 23 | from v$mystat 24 | where rownum = 1 25 | ) 26 | ) 27 | / 28 | 29 | update t set unindexed = lower(unindexed); 30 | 31 | select used_ublk 32 | from v$transaction 33 | where addr = (select taddr 34 | from v$session 35 | where sid = (select sid 36 | from v$mystat 37 | where rownum = 1 38 | ) 39 | ) 40 | / 41 | 42 | update t set indexed = lower(indexed); 43 | 44 | select used_ublk 45 | from v$transaction 46 | where addr = (select taddr 47 | from v$session 48 | where sid = (select sid 49 | from v$mystat 50 | where rownum = 1 51 | ) 52 | ) 53 | / 54 | -------------------------------------------------------------------------------- /scripts/ch09/demo11.sql: -------------------------------------------------------------------------------- 1 | -- Delayed Block Cleanout 2 | 3 | set echo on 4 | 5 | create undo tablespace undo_small 6 | datafile '/tmp/undo.dbf' size 2m 7 | autoextend off 8 | / 9 | 10 | drop table big purge; 11 | 12 | create table big 13 | as 14 | select a.*, rpad('*',1000,'*') data 15 | from all_objects a; 16 | 17 | alter table big add constraint big_pk 18 | primary key(object_id); 19 | 20 | exec dbms_stats.gather_table_stats( user, 'BIG' ); 21 | 22 | create table small ( x int, y char(500) ); 23 | 24 | insert into small select rownum, 'x' from all_users; 25 | 26 | commit; 27 | 28 | exec dbms_stats.gather_table_stats( user, 'SMALL' ); 29 | 30 | alter system set undo_tablespace = undo_small; 31 | 32 | update big 33 | set temporary = temporary 34 | where rowid in 35 | ( 36 | select r 37 | from ( 38 | select rowid r, row_number() over 39 | (partition by dbms_rowid.rowid_block_number(rowid) order by rowid) rn 40 | from big 41 | ) 42 | where rn = 1 43 | ) 44 | / 45 | 46 | commit; 47 | 48 | variable x refcursor 49 | exec open :x for select * from big where object_id < 100; 50 | 51 | !./run.sh 52 | print x 53 | 54 | /* After finished, drop the small undo tablespace. 55 | disconnect 56 | connect eoda/foo 57 | alter system set undo_tablespace = UNDOTBS1; 58 | disconnect 59 | connect eoda/foo 60 | drop tablespace undo_small including contents and datafiles; 61 | */ 62 | -------------------------------------------------------------------------------- /scripts/ch09/getstat.sql: -------------------------------------------------------------------------------- 1 | create or replace function get_stat_val( p_name in varchar2 ) return number 2 | as 3 | l_val number; 4 | begin 5 | select b.value 6 | into l_val 7 | from v$statname a, v$mystat b 8 | where a.statistic# = b.statistic# 9 | and a.name = p_name; 10 | 11 | return l_val; 12 | end; 13 | / 14 | -------------------------------------------------------------------------------- /scripts/ch09/perftest.java: -------------------------------------------------------------------------------- 1 | import java.sql.*; 2 | import java.sql.DriverManager; 3 | import java.sql.Connection; 4 | import java.sql.SQLException; 5 | import java.io.*; 6 | 7 | public class perftest 8 | { 9 | public static void main (String arr[]) throws Exception 10 | { 11 | DriverManager.registerDriver(new oracle.jdbc.OracleDriver()); 12 | Connection con = DriverManager.getConnection 13 | ("jdbc:oracle:thin:@csxdev:1521:ORA12CR1", "scott", "tiger"); 14 | Integer iters = new Integer(arr[0]); 15 | Integer commitCnt = new Integer(arr[1]); 16 | con.setAutoCommit(false); 17 | doInserts( con, 1, 1 ); 18 | Statement stmt = con.createStatement (); 19 | stmt.execute( "begin dbms_monitor.session_trace_enable(waits=>true); end;" ); 20 | doInserts( con, iters.intValue(), commitCnt.intValue() ); 21 | con.close(); 22 | } 23 | static void doInserts(Connection con, int count, int commitCount ) 24 | throws Exception 25 | { 26 | PreparedStatement ps = 27 | con.prepareStatement 28 | ("insert into test " + 29 | "(id, code, descr, insert_user, insert_date)" 30 | + " values (?,?,?, user, sysdate)"); 31 | int rowcnt = 0; 32 | int committed = 0; 33 | for (int i = 0; i < count; i++ ) 34 | { 35 | ps.setInt(1,i); 36 | ps.setString(2,"PS - code" + i); 37 | ps.setString(3,"PS - desc" + i); 38 | ps.executeUpdate(); 39 | rowcnt++; 40 | if ( rowcnt == commitCount ) 41 | { 42 | con.commit(); 43 | rowcnt = 0; 44 | committed++; 45 | } 46 | } 47 | con.commit(); 48 | System.out.println 49 | ("pstatement rows/commitcnt = " + count + " / " + committed ); 50 | } 51 | } 52 | -------------------------------------------------------------------------------- /scripts/ch09/perftest.sql: -------------------------------------------------------------------------------- 1 | -- What Does a COMMIT Do? 2 | drop table test purge; 3 | 4 | create table test 5 | ( id number, 6 | code varchar2(20), 7 | descr varchar2(20), 8 | insert_user varchar2(30), 9 | insert_date date 10 | ) 11 | / 12 | -------------------------------------------------------------------------------- /scripts/ch09/run.sh: -------------------------------------------------------------------------------- 1 | $ORACLE_HOME/bin/sqlplus eoda/foo @test2 1 & 2 | $ORACLE_HOME/bin/sqlplus eoda/foo @test2 2 & 3 | $ORACLE_HOME/bin/sqlplus eoda/foo @test2 3 & 4 | $ORACLE_HOME/bin/sqlplus eoda/foo @test2 4 & 5 | $ORACLE_HOME/bin/sqlplus eoda/foo @test2 5 & 6 | $ORACLE_HOME/bin/sqlplus eoda/foo @test2 6 & 7 | $ORACLE_HOME/bin/sqlplus eoda/foo @test2 7 & 8 | $ORACLE_HOME/bin/sqlplus eoda/foo @test2 8 & 9 | $ORACLE_HOME/bin/sqlplus eoda/foo @test2 9 & 10 | -------------------------------------------------------------------------------- /scripts/ch09/test2.sql: -------------------------------------------------------------------------------- 1 | begin 2 | for i in 1 .. 5000 3 | loop 4 | update small set y = i where x= &1; 5 | commit; 6 | end loop; 7 | end; 8 | / 9 | exit 10 | -------------------------------------------------------------------------------- /scripts/ch10/demo01.sql: -------------------------------------------------------------------------------- 1 | -- Segment 2 | 3 | drop table t purge; 4 | 5 | create table t ( x int primary key, y clob, z blob ); 6 | select segment_name, segment_type from user_segments; 7 | 8 | -- Segment, example 2 9 | 10 | drop table t purge; 11 | 12 | create table t 13 | ( x int primary key, 14 | y clob, 15 | z blob ) 16 | SEGMENT CREATION IMMEDIATE; 17 | 18 | column segment_name format a30 19 | column segment_type format a20 20 | 21 | select segment_name, segment_type 22 | from user_segments; 23 | -------------------------------------------------------------------------------- /scripts/ch10/demo02.sql: -------------------------------------------------------------------------------- 1 | -- Freelists 2 | 3 | set echo on 4 | 5 | -- You may have to modify these two create tablespace statements for your 6 | -- environment. These assume OMF are being used. 7 | 8 | create tablespace mssm 9 | datafile size 1m autoextend on next 1m 10 | segment space management manual; 11 | 12 | create tablespace assm 13 | datafile size 1m autoextend on next 1m 14 | segment space management auto; 15 | 16 | drop table t purge; 17 | 18 | create table t ( x int, y char(50) ) 19 | -- storage( freelists 5 ) 20 | -- tablespace mssm; 21 | tablespace assm; 22 | 23 | set ech off 24 | !echo begin for i in 1 .. 100000 loop insert into t values \(i,\'x\'\)\; end loop\; commit\; end\; > test.sql 25 | !echo / >> test.sql 26 | !echo exit >> test.sql 27 | 28 | !echo \#\!/bin/bash > test.sh 29 | !echo sqlplus eoda/foo @test.sql \&>> test.sh 30 | !echo sqlplus eoda/foo @test.sql \&>> test.sh 31 | !echo sqlplus eoda/foo @test.sql \&>> test.sh 32 | !echo sqlplus eoda/foo @test.sql \&>> test.sh 33 | !echo sqlplus eoda/foo @test.sql \&>> test.sh 34 | !echo wait >> test.sh 35 | set echo on 36 | 37 | !chmod 755 test.sh 38 | 39 | exec statspack.snap 40 | !/bin/bash ./test.sh 41 | exec statspack.snap 42 | @?/rdbms/admin/spreport 43 | -------------------------------------------------------------------------------- /scripts/ch10/demo03.sql: -------------------------------------------------------------------------------- 1 | -- Heap Organized Tables, example 1 2 | 3 | drop table t purge; 4 | 5 | set echo on 6 | 7 | create table t 8 | ( a int, 9 | b varchar2(4000) default rpad('*',4000,'*'), 10 | c varchar2(3000) default rpad('*',3000,'*') 11 | ) 12 | / 13 | 14 | insert into t (a) values ( 1); 15 | insert into t (a) values ( 2); 16 | insert into t (a) values ( 3); 17 | select a from t; 18 | delete from t where a = 2 ; 19 | insert into t (a) values ( 4); 20 | select a from t; 21 | -------------------------------------------------------------------------------- /scripts/ch10/demo04.sql: -------------------------------------------------------------------------------- 1 | -- Heap Organized Tables, example 2 2 | 3 | drop table t purge; 4 | 5 | set echo on 6 | 7 | create table t 8 | ( x int primary key, 9 | y date, 10 | z clob 11 | ) 12 | / 13 | 14 | select dbms_metadata.get_ddl( 'TABLE', 'T' ) from dual; 15 | -------------------------------------------------------------------------------- /scripts/ch10/demo06.sql: -------------------------------------------------------------------------------- 1 | -- Index Organized Tables, example 2 2 | 3 | set echo on 4 | 5 | exec dbms_monitor.session_trace_enable; 6 | begin 7 | for x in ( select empno from emp ) 8 | loop 9 | for y in ( select emp.ename, a.street, a.city, a.state, a.zip 10 | from emp, heap_addresses a 11 | where emp.empno = a.empno 12 | and emp.empno = x.empno ) 13 | loop 14 | null; 15 | end loop; 16 | end loop; 17 | end; 18 | / 19 | 20 | begin 21 | for x in ( select empno from emp ) 22 | loop 23 | for y in ( select emp.ename, a.street, a.city, a.state, a.zip 24 | from emp, iot_addresses a 25 | where emp.empno = a.empno 26 | and emp.empno = x.empno ) 27 | loop 28 | null; 29 | end loop; 30 | end loop; 31 | end; 32 | / 33 | exec dbms_monitor.session_trace_disable; 34 | -- tk.sql is in the ch00 directory 35 | @tk.sql "sys=no" 36 | 37 | exec runStats_pkg.rs_start; 38 | begin 39 | for x in ( select empno from emp ) 40 | loop 41 | for y in ( select emp.ename, a.street, a.city, a.state, a.zip 42 | from emp, heap_addresses a 43 | where emp.empno = a.empno 44 | and emp.empno = x.empno ) 45 | loop 46 | null; 47 | end loop; 48 | end loop; 49 | end; 50 | / 51 | exec runStats_pkg.rs_middle; 52 | begin 53 | for x in ( select empno from emp ) 54 | loop 55 | for y in ( select emp.ename, a.street, a.city, a.state, a.zip 56 | from emp, iot_addresses a 57 | where emp.empno = a.empno 58 | and emp.empno = x.empno ) 59 | loop 60 | null; 61 | end loop; 62 | end loop; 63 | end; 64 | / 65 | exec runStats_pkg.rs_stop; 66 | -------------------------------------------------------------------------------- /scripts/ch10/demo07.sql: -------------------------------------------------------------------------------- 1 | -- Index Organized Tables, example 3 2 | 3 | set echo on 4 | 5 | drop table t1 purge; 6 | drop table t2 purge; 7 | drop table t3 purge; 8 | 9 | set echo on 10 | 11 | create table t1 12 | ( x int primary key, 13 | y varchar2(25), 14 | z date 15 | ) 16 | organization index; 17 | 18 | create table t2 19 | ( x int primary key, 20 | y varchar2(25), 21 | z date 22 | ) 23 | organization index 24 | OVERFLOW; 25 | 26 | create table t3 27 | ( x int primary key, 28 | y varchar2(25), 29 | z date 30 | ) 31 | organization index 32 | overflow INCLUDING y; 33 | 34 | select dbms_metadata.get_ddl( 'TABLE', 'T1' ) from dual; 35 | -------------------------------------------------------------------------------- /scripts/ch10/demo08.sql: -------------------------------------------------------------------------------- 1 | -- Index Organized Tables, example 4 2 | 3 | set echo on 4 | 5 | drop table iot purge; 6 | 7 | create table iot 8 | ( owner, object_type, object_name, 9 | primary key(owner,object_type,object_name) 10 | ) 11 | organization index 12 | NOCOMPRESS 13 | as 14 | select distinct owner, object_type, object_name from all_objects 15 | / 16 | -------------------------------------------------------------------------------- /scripts/ch10/demo09.sql: -------------------------------------------------------------------------------- 1 | -- Index Organized Tables, example 5 2 | 3 | set echo on 4 | 5 | drop table iot purge; 6 | 7 | create table iot 8 | ( owner, object_type, object_name, 9 | constraint iot_pk primary key(owner,object_type,object_name) 10 | ) 11 | organization index 12 | NOCOMPRESS 13 | as 14 | select distinct owner, object_type, object_name 15 | from all_objects 16 | / 17 | 18 | analyze index iot_pk validate structure; 19 | 20 | select lf_blks, br_blks, used_space, opt_cmpr_count, opt_cmpr_pctsave 21 | from index_stats; 22 | 23 | alter table iot move compress 1; 24 | analyze index iot_pk validate structure; 25 | 26 | select lf_blks, br_blks, used_space, 27 | opt_cmpr_count, opt_cmpr_pctsave 28 | from index_stats; 29 | 30 | alter table iot move compress 2; 31 | 32 | analyze index iot_pk validate structure; 33 | 34 | select lf_blks, br_blks, used_space, 35 | opt_cmpr_count, opt_cmpr_pctsave 36 | from index_stats; 37 | -------------------------------------------------------------------------------- /scripts/ch10/demo10.sql: -------------------------------------------------------------------------------- 1 | -- Index Organized Tables, example 6 2 | 3 | set echo on 4 | 5 | begin 6 | dbms_metadata.set_transform_param 7 | ( DBMS_METADATA.SESSION_TRANSFORM, 'STORAGE', false ); 8 | end; 9 | / 10 | 11 | select dbms_metadata.get_ddl( 'TABLE', 'T2' ) from dual; 12 | 13 | select dbms_metadata.get_ddl( 'TABLE', 'T3' ) from dual; 14 | -------------------------------------------------------------------------------- /scripts/ch10/demo11.sql: -------------------------------------------------------------------------------- 1 | -- Index Organized Tables, example 7 2 | 3 | drop table iot; 4 | 5 | set echo on 6 | 7 | create table iot 8 | ( x int, 9 | y date, 10 | z varchar2(2000), 11 | constraint iot_pk primary key (x) 12 | ) 13 | organization index 14 | pctthreshold 10 15 | overflow 16 | / 17 | 18 | drop table iot; 19 | 20 | create table iot 21 | ( x int, 22 | y date, 23 | z varchar2(2000), 24 | constraint iot_pk primary key (x) 25 | ) 26 | organization index 27 | including y 28 | overflow 29 | / 30 | -------------------------------------------------------------------------------- /scripts/ch10/demo12.sql: -------------------------------------------------------------------------------- 1 | -- Index Clustered Tables, example 1 2 | 3 | drop table dept cascade constraints; 4 | drop table emp cascade constraints; 5 | drop cluster emp_dept_cluster; 6 | 7 | set echo on 8 | 9 | create cluster emp_dept_cluster 10 | ( deptno number(2) ) 11 | size 1024 12 | / 13 | 14 | create index emp_dept_cluster_idx 15 | on cluster emp_dept_cluster 16 | / 17 | 18 | create table dept 19 | ( deptno number(2) primary key, 20 | dname varchar2(14), 21 | loc varchar2(13) 22 | ) 23 | cluster emp_dept_cluster(deptno) 24 | / 25 | 26 | create table emp 27 | ( empno number primary key, 28 | ename varchar2(10), 29 | job varchar2(9), 30 | mgr number, 31 | hiredate date, 32 | sal number, 33 | comm number, 34 | deptno number(2) references dept(deptno) 35 | ) 36 | cluster emp_dept_cluster(deptno) 37 | / 38 | 39 | insert into dept 40 | ( deptno, dname, loc ) 41 | select deptno+r, dname, loc 42 | from scott.dept, 43 | (select level r from dual connect by level < 10); 44 | 45 | insert into emp 46 | (empno, ename, job, mgr, hiredate, sal, comm, deptno) 47 | select rownum, ename, job, mgr, hiredate, sal, comm, deptno+r 48 | from scott.emp, 49 | (select level r from dual connect by level < 10); 50 | 51 | select min(count(*)), max(count(*)), avg(count(*)) 52 | from dept 53 | group by dbms_rowid.rowid_block_number(rowid) 54 | / 55 | 56 | select * 57 | from ( 58 | select dept_blk, emp_blk, 59 | case when dept_blk <> emp_blk then '*' end flag, 60 | deptno 61 | from ( 62 | select dbms_rowid.rowid_block_number(dept.rowid) dept_blk, 63 | dbms_rowid.rowid_block_number(emp.rowid) emp_blk, 64 | dept.deptno 65 | from emp, dept 66 | where emp.deptno = dept.deptno 67 | ) 68 | ) 69 | where flag = '*' 70 | order by deptno 71 | / 72 | 73 | -------------------------------------------------------------------------------- /scripts/ch10/demo13.sql: -------------------------------------------------------------------------------- 1 | -- Index Clustered Tables, example 2 2 | 3 | delete from emp; 4 | delete from dept; 5 | 6 | set echo on 7 | 8 | insert into dept 9 | ( deptno, dname, loc ) 10 | select deptno+r, dname, loc 11 | from scott.dept, 12 | (select level r from dual connect by level < 10); 13 | 14 | insert into emp 15 | (empno, ename, job, mgr, hiredate, sal, comm, deptno) 16 | select rownum, ename, job, mgr, hiredate, sal, comm, deptno+r 17 | from scott.emp, 18 | (select level r from dual connect by level < 10), 19 | (select level r2 from dual connect by level < 8); 20 | 21 | select min(count(*)), max(count(*)), avg(count(*)) 22 | from dept 23 | group by dbms_rowid.rowid_block_number(rowid) 24 | / 25 | 26 | select * 27 | from ( 28 | select dept_blk, emp_blk, 29 | case when dept_blk <> emp_blk then '*' end flag, 30 | deptno 31 | from ( 32 | select dbms_rowid.rowid_block_number(dept.rowid) dept_blk, 33 | dbms_rowid.rowid_block_number(emp.rowid) emp_blk, 34 | dept.deptno 35 | from emp, dept 36 | where emp.deptno = dept.deptno 37 | ) 38 | ) 39 | where flag = '*' 40 | order by deptno 41 | / 42 | -------------------------------------------------------------------------------- /scripts/ch10/demo14.sql: -------------------------------------------------------------------------------- 1 | -- Index Clustered Tables, example 3 2 | 3 | -- Size of 1200 4 | drop table dept cascade constraints; 5 | drop table emp cascade constraints; 6 | drop cluster emp_dept_cluster; 7 | 8 | set echo on 9 | 10 | create cluster emp_dept_cluster 11 | ( deptno number(2) ) 12 | size 1200 13 | / 14 | 15 | create index emp_dept_cluster_idx 16 | on cluster emp_dept_cluster 17 | / 18 | 19 | create table dept 20 | ( deptno number(2) primary key, 21 | dname varchar2(14), 22 | loc varchar2(13) 23 | ) 24 | cluster emp_dept_cluster(deptno) 25 | / 26 | 27 | create table emp 28 | ( empno number primary key, 29 | ename varchar2(10), 30 | job varchar2(9), 31 | mgr number, 32 | hiredate date, 33 | sal number, 34 | comm number, 35 | deptno number(2) references dept(deptno) 36 | ) 37 | cluster emp_dept_cluster(deptno) 38 | / 39 | 40 | insert into dept 41 | ( deptno, dname, loc ) 42 | select deptno+r, dname, loc 43 | from scott.dept, 44 | (select level r from dual connect by level < 10); 45 | 46 | insert into emp 47 | (empno, ename, job, mgr, hiredate, sal, comm, deptno) 48 | select rownum, ename, job, mgr, hiredate, sal, comm, deptno+r 49 | from scott.emp, 50 | (select level r from dual connect by level < 10); 51 | 52 | select min(count(*)), max(count(*)), avg(count(*)) 53 | from dept 54 | group by dbms_rowid.rowid_block_number(rowid) 55 | / 56 | 57 | select * 58 | from ( 59 | select dept_blk, emp_blk, 60 | case when dept_blk <> emp_blk then '*' end flag, 61 | deptno 62 | from ( 63 | select dbms_rowid.rowid_block_number(dept.rowid) dept_blk, 64 | dbms_rowid.rowid_block_number(emp.rowid) emp_blk, 65 | dept.deptno 66 | from emp, dept 67 | where emp.deptno = dept.deptno 68 | ) 69 | ) 70 | where flag = '*' 71 | order by deptno 72 | / 73 | -------------------------------------------------------------------------------- /scripts/ch10/demo15.sql: -------------------------------------------------------------------------------- 1 | -- Index Clustered Tables, example 3 2 | 3 | set echo on 4 | 5 | select rowid from emp 6 | intersect 7 | select rowid from dept; 8 | -------------------------------------------------------------------------------- /scripts/ch10/demo16.sql: -------------------------------------------------------------------------------- 1 | -- Index Clustered Tables, example 4 2 | 3 | set echo on 4 | 5 | -- Run this query as SYS 6 | -- 7 | col cluster_name form a30 8 | col table_name form a30 9 | -- 10 | break on cluster_name 11 | -- 12 | select cluster_name, table_name 13 | from user_tables 14 | where cluster_name is not null 15 | order by 1; 16 | -------------------------------------------------------------------------------- /scripts/ch10/demo17.sql: -------------------------------------------------------------------------------- 1 | -- Hash Clustered Tables, example 1 2 | 3 | set echo on 4 | 5 | drop cluster hash_cluster; 6 | 7 | create cluster hash_cluster 8 | ( hash_key number ) 9 | hashkeys 1000 10 | size 8192 11 | tablespace mssm 12 | / 13 | 14 | exec show_space( 'HASH_CLUSTER', user, 'CLUSTER' ) 15 | -------------------------------------------------------------------------------- /scripts/ch10/demo18.sql: -------------------------------------------------------------------------------- 1 | -- Hash Clustered Tables, example 2 2 | 3 | set echo on 4 | 5 | drop table hashed_table; 6 | 7 | create table hashed_table 8 | ( x number, data1 varchar2(4000), data2 varchar2(4000) ) 9 | cluster hash_cluster(x); 10 | -------------------------------------------------------------------------------- /scripts/ch10/demo21.sql: -------------------------------------------------------------------------------- 1 | -- Sorted Hash Clustered Tables 2 | 3 | set echo on 4 | 5 | drop table cust_orders; 6 | drop cluster shc; 7 | 8 | CREATE CLUSTER shc 9 | ( 10 | cust_id NUMBER, 11 | order_dt timestamp SORT 12 | ) 13 | HASHKEYS 10000 14 | HASH IS cust_id 15 | SIZE 8192 16 | / 17 | 18 | CREATE TABLE cust_orders 19 | ( cust_id number, 20 | order_dt timestamp SORT, 21 | order_number number, 22 | username varchar2(30), 23 | ship_addr number, 24 | bill_addr number, 25 | invoice_num number 26 | ) 27 | CLUSTER shc ( cust_id, order_dt ) 28 | / 29 | 30 | set autotrace traceonly explain 31 | variable x number 32 | -- 33 | select cust_id, order_dt, order_number 34 | from cust_orders 35 | where cust_id = :x 36 | order by order_dt; 37 | 38 | select job, hiredate, empno 39 | from scott.emp 40 | where job = 'CLERK' 41 | order by hiredate; 42 | 43 | set autotrace off 44 | -------------------------------------------------------------------------------- /scripts/ch10/demo22.sql: -------------------------------------------------------------------------------- 1 | -- Nested Tables Syntax, example 1 2 | 3 | set echo on 4 | 5 | drop table emp cascade constraints; 6 | drop table dept cascade constraints; 7 | drop table dept_and_emp; 8 | drop type emp_tab_type; 9 | drop type emp_type; 10 | 11 | create table dept 12 | (deptno number(2) primary key, 13 | dname varchar2(14), 14 | loc varchar2(13) 15 | ); 16 | 17 | create table emp 18 | (empno number(4) primary key, 19 | ename varchar2(10), 20 | job varchar2(9), 21 | mgr number(4) references emp, 22 | hiredate date, 23 | sal number(7, 2), 24 | comm number(7, 2), 25 | deptno number(2) references dept 26 | ); 27 | 28 | create or replace type emp_type 29 | as object 30 | (empno number(4), 31 | ename varchar2(10), 32 | job varchar2(9), 33 | mgr number(4), 34 | hiredate date, 35 | sal number(7, 2), 36 | comm number(7, 2) 37 | ); 38 | / 39 | 40 | create or replace type emp_tab_type 41 | as table of emp_type 42 | / 43 | 44 | create table dept_and_emp 45 | (deptno number(2) primary key, 46 | dname varchar2(14), 47 | loc varchar2(13), 48 | emps emp_tab_type 49 | ) 50 | nested table emps store as emps_nt; 51 | 52 | alter table emps_nt add constraint 53 | emps_empno_unique unique(empno) 54 | / 55 | 56 | insert into dept_and_emp 57 | select dept.*, 58 | CAST( multiset( select empno, ename, job, mgr, hiredate, sal, comm 59 | from SCOTT.EMP 60 | where emp.deptno = dept.deptno ) AS emp_tab_type ) 61 | from SCOTT.DEPT 62 | / 63 | -------------------------------------------------------------------------------- /scripts/ch10/demo23.sql: -------------------------------------------------------------------------------- 1 | -- Nested Tables Syntax, example 2 2 | 3 | set echo on 4 | 5 | select deptno, dname, loc, d.emps AS employees 6 | from dept_and_emp d 7 | where deptno = 10 8 | / 9 | 10 | select d.deptno, d.dname, emp.* 11 | from dept_and_emp D, table(d.emps) emp 12 | / 13 | 14 | select d.deptno, d.dname, emp.* from dept_and_emp D, table(d.emps) emp; 15 | 16 | update 17 | table( select emps 18 | from dept_and_emp 19 | where deptno = 10 20 | ) 21 | set comm = 100 22 | / 23 | 24 | -- should throw an error 25 | update 26 | table( select emps 27 | from dept_and_emp 28 | where deptno = 1 29 | ) 30 | set comm = 100 31 | / 32 | 33 | -- should throw an error 34 | update 35 | table( select emps 36 | from dept_and_emp 37 | where deptno > 1 38 | ) 39 | set comm = 100 40 | / 41 | 42 | insert into table 43 | ( select emps from dept_and_emp where deptno = 10 ) 44 | values 45 | ( 1234, 'NewEmp', 'CLERK', 7782, sysdate, 1200, null ); 46 | 47 | delete from table 48 | ( select emps from dept_and_emp where deptno = 20 ) 49 | where ename = 'SCOTT'; 50 | 51 | select d.dname, e.empno, ename, deptno 52 | from dept_and_emp d, table(d.emps) e 53 | where d.deptno in ( 10, 20 ); 54 | -------------------------------------------------------------------------------- /scripts/ch10/demo24.sql: -------------------------------------------------------------------------------- 1 | -- Nested Tables Syntax, example 3 2 | 3 | set echo on 4 | 5 | SELECT /*+NESTED_TABLE_GET_REFS+*/ NESTED_TABLE_ID,SYS_NC_ROWINFO$ FROM "EODA"."EMPS_NT"; 6 | 7 | select name 8 | from sys.col$ 9 | where obj# = ( select object_id 10 | from dba_objects 11 | where object_name = 'DEPT_AND_EMP' 12 | and owner = 'EODA' ) 13 | / 14 | 15 | select /*+ nested_table_get_refs */ empno, ename 16 | from emps_nt where ename like '%A%'; 17 | 18 | update /*+ nested_table_get_refs */ emps_nt set ename = initcap(ename); 19 | 20 | select /*+ nested_table_get_refs */ empno, ename 21 | from emps_nt where ename like '%a%'; 22 | 23 | select d.deptno, d.dname, emp.* 24 | from dept_and_emp D, table(d.emps) emp 25 | / 26 | 27 | -------------------------------------------------------------------------------- /scripts/ch10/demo25.sql: -------------------------------------------------------------------------------- 1 | -- Nested Table Storage 2 | 3 | set echo on 4 | 5 | drop table dept_and_emp; 6 | 7 | create table dept_and_emp 8 | (deptno number(2) primary key, 9 | dname varchar2(14), 10 | loc varchar2(13), 11 | emps emp_tab_type 12 | ) 13 | nested table emps store as emps_nt; 14 | 15 | alter table emps_nt add constraint 16 | emps_empno_unique unique(empno) 17 | / 18 | 19 | begin 20 | dbms_metadata.set_transform_param 21 | ( DBMS_METADATA.SESSION_TRANSFORM, 'STORAGE', false ); 22 | end; 23 | / 24 | 25 | select dbms_metadata.get_ddl( 'TABLE', 'DEPT_AND_EMP' ) from dual; 26 | 27 | drop table dept_and_emp; 28 | 29 | CREATE TABLE "EODA"."DEPT_AND_EMP" 30 | ("DEPTNO" NUMBER(2, 0), 31 | "DNAME" VARCHAR2(14), 32 | "LOC" VARCHAR2(13), 33 | "EMPS" "EMP_TAB_TYPE") 34 | PCTFREE 10 PCTUSED 40 INITRANS 1 MAXTRANS 255 LOGGING 35 | TABLESPACE "USERS" 36 | NESTED TABLE "EMPS" 37 | STORE AS "EMPS_NT" 38 | ((empno NOT NULL, unique (empno), primary key(nested_table_id,empno)) 39 | organization index compress 1 ) 40 | RETURN AS VALUE; 41 | -------------------------------------------------------------------------------- /scripts/ch10/demo26.sql: -------------------------------------------------------------------------------- 1 | -- Temporary Tables, example 1 2 | 3 | set echo on 4 | 5 | create global temporary table temp_table_session 6 | on commit preserve rows 7 | as 8 | select * from scott.emp where 1=0 9 | / 10 | 11 | create global temporary table temp_table_transaction 12 | on commit delete rows 13 | as 14 | select * from scott.emp where 1=0 15 | / 16 | 17 | insert into temp_table_session select * from scott.emp; 18 | insert into temp_table_transaction select * from scott.emp; 19 | 20 | select session_cnt, transaction_cnt 21 | from ( select count(*) session_cnt from temp_table_session ), 22 | ( select count(*) transaction_cnt from temp_table_transaction ); 23 | 24 | commit; 25 | 26 | select session_cnt, transaction_cnt 27 | from ( select count(*) session_cnt from temp_table_session ), 28 | ( select count(*) transaction_cnt from temp_table_transaction ); 29 | 30 | column table_name format a25 31 | column duration format a15 32 | select table_name, temporary, duration from user_tables; 33 | -------------------------------------------------------------------------------- /scripts/ch10/demo27.sql: -------------------------------------------------------------------------------- 1 | -- Temporary Tables, example 2 2 | 3 | set echo on 4 | 5 | create global temporary table gtt 6 | as 7 | select * from scott.emp where 1=0; 8 | 9 | insert into gtt select * from scott.emp; 10 | 11 | set autotrace traceonly explain 12 | select /*+ first_rows */ * from gtt; 13 | select /*+ first_rows dynamic_sampling(gtt 2) */ * from gtt; 14 | 15 | set autotrace off 16 | -------------------------------------------------------------------------------- /scripts/ch10/demo28.sql: -------------------------------------------------------------------------------- 1 | -- Temporary Tables, example 3 2 | 3 | set echo on 4 | 5 | drop table gtt; 6 | 7 | create global temporary table gtt 8 | as 9 | select * from scott.emp where 1=0; 10 | 11 | insert into gtt select * from scott.emp; 12 | 13 | set autotrace traceonly explain 14 | select * from gtt; 15 | 16 | set autotrace off; 17 | -------------------------------------------------------------------------------- /scripts/ch10/demo29.sql: -------------------------------------------------------------------------------- 1 | -- Temporary Tables, example 4 2 | 3 | set echo on 4 | 5 | drop table emp cascade constraints; 6 | drop table gtt1; 7 | drop table gtt2; 8 | 9 | create table emp as select * from scott.emp; 10 | 11 | create global temporary table gtt1 ( x number ) 12 | on commit preserve rows; 13 | 14 | create global temporary table gtt2 ( x number ) 15 | on commit delete rows; 16 | 17 | insert into gtt1 select user_id from all_users; 18 | 19 | insert into gtt2 select user_id from all_users; 20 | 21 | exec dbms_stats.gather_schema_stats( user ); 22 | 23 | column table_name format a30 24 | column last_analyzed format a14 25 | 26 | select table_name, last_analyzed, num_rows from user_tables; 27 | 28 | insert into gtt2 select user_id from all_users; 29 | 30 | exec dbms_stats.gather_schema_stats( user, gather_temp=>TRUE ); 31 | 32 | select table_name, last_analyzed, num_rows from user_tables; 33 | -------------------------------------------------------------------------------- /scripts/ch10/demo30.sql: -------------------------------------------------------------------------------- 1 | -- Temporary Tables, example 5 2 | 3 | set echo on 4 | 5 | drop table t; 6 | 7 | create global temporary table t ( x int, y varchar2(100) ); 8 | --on commit preserve rows; 9 | 10 | begin 11 | dbms_stats.set_table_stats( ownname => USER, 12 | tabname => 'T', 13 | numrows => 500, 14 | numblks => 7, 15 | avgrlen => 100 ); 16 | end; 17 | / 18 | 19 | column table_name format a10 20 | 21 | select table_name, num_rows, blocks, avg_row_len 22 | from user_tables 23 | where table_name = 'T'; 24 | 25 | select table_name, temporary, duration from user_tables where table_name='T'; 26 | -------------------------------------------------------------------------------- /scripts/ch10/demo31.sql: -------------------------------------------------------------------------------- 1 | -- Temporary Tables, Session Statistics 2 | 3 | set echo on 4 | 5 | drop table gt; 6 | 7 | create global temporary table gt(x number) on commit preserve rows; 8 | 9 | insert into gt select user_id from all_users; 10 | 11 | exec dbms_stats.gather_table_stats(user,'GT'); 12 | 13 | column table_name format a25 14 | column last_analyzed format a14 15 | 16 | select table_name, num_rows, last_analyzed, scope 17 | from user_tab_statistics 18 | where table_name like 'GT'; 19 | 20 | set autotrace on; 21 | 22 | select count(*) from gt; 23 | 24 | set autotrace off; 25 | -------------------------------------------------------------------------------- /scripts/ch10/demo32.sql: -------------------------------------------------------------------------------- 1 | -- Shared Statistics 2 | 3 | set echo on 4 | 5 | drop table gt; 6 | 7 | create global temporary table gt(x number) on commit preserve rows; 8 | 9 | insert into gt select user_id from all_users; 10 | 11 | exec dbms_stats.set_table_prefs(user, 'GT','GLOBAL_TEMP_TABLE_STATS','SHARED'); 12 | 13 | exec dbms_stats.gather_table_stats( user, 'GT' ); 14 | 15 | column table_name format a20 16 | 17 | select table_name, num_rows, last_analyzed, scope 18 | from user_tab_statistics 19 | where table_name like 'GT'; 20 | 21 | pause 22 | 23 | exec dbms_stats.delete_table_stats( user, 'GT' ); 24 | 25 | select table_name, num_rows, last_analyzed, scope 26 | from user_tab_statistics 27 | where table_name like 'GT'; 28 | -------------------------------------------------------------------------------- /scripts/ch10/demo33.sql: -------------------------------------------------------------------------------- 1 | -- Statistics for On Commit Delete Rows 2 | 3 | set echo on 4 | 5 | drop table gt; 6 | 7 | create global temporary table gt(x number) on commit delete rows; 8 | 9 | insert into gt select user_id from all_users; 10 | 11 | exec dbms_stats.gather_table_stats(user,'GT'); 12 | 13 | select count(*) from gt; 14 | 15 | column table_name format a20 16 | 17 | select table_name, num_rows, last_analyzed, scope 18 | from user_tab_statistics 19 | where table_name like 'GT'; 20 | 21 | -------------------------------------------------------------------------------- /scripts/ch10/demo34.sql: -------------------------------------------------------------------------------- 1 | -- Bulk Load Automatic Statistics Gathering 2 | 3 | set echo on 4 | 5 | drop table gt; 6 | 7 | create global temporary table gt on commit preserve rows 8 | as select * from all_users; 9 | 10 | column table_name format a20 11 | 12 | select table_name, num_rows, last_analyzed, scope 13 | from user_tab_statistics 14 | where table_name like 'GT'; 15 | -------------------------------------------------------------------------------- /scripts/ch10/demo35.sql: -------------------------------------------------------------------------------- 1 | -- Object Tables, example 1 2 | 3 | set echo on 4 | 5 | drop table people; 6 | drop type person_type; 7 | drop type address_type; 8 | 9 | create or replace type address_type 10 | as object 11 | ( city varchar2(30), 12 | street varchar2(30), 13 | state varchar2(2), 14 | zip number 15 | ) 16 | / 17 | 18 | create or replace type person_type 19 | as object 20 | ( name varchar2(30), 21 | dob date, 22 | home_address address_type, 23 | work_address address_type 24 | ) 25 | / 26 | 27 | create table people of person_type 28 | / 29 | 30 | insert into people values ( 'Tom', '15-mar-1965', 31 | address_type( 'Denver', '123 Main Street', 'Co', '80202' ), 32 | address_type( 'Redwood', '1 Oracle Way', 'Ca', '23456' ) ); 33 | 34 | 35 | select name, dob, p.home_address Home, p.work_address work 36 | from people p; 37 | 38 | select name, p.home_address.city from people p; 39 | 40 | column name format a20 41 | 42 | select name, segcollength 43 | from sys.col$ 44 | where obj# = ( select object_id 45 | from user_objects 46 | where object_name = 'PEOPLE' ) 47 | / 48 | 49 | select dbms_metadata.get_ddl('TABLE','PEOPLE') from dual; 50 | 51 | select sys_nc_rowinfo$ from people; 52 | -------------------------------------------------------------------------------- /scripts/ch10/demo36.sql: -------------------------------------------------------------------------------- 1 | -- Object Tables, example 2 2 | 3 | set echo on 4 | 5 | drop table people; 6 | 7 | create table people of person_type 8 | / 9 | 10 | select name, type#, segcollength 11 | from sys.col$ 12 | where obj# = ( select object_id 13 | from user_objects 14 | where object_name = 'PEOPLE' ) 15 | and name like 'SYS\_NC\_%' escape '\' 16 | / 17 | 18 | 19 | insert into people(name) 20 | select rownum from all_objects; 21 | 22 | exec dbms_stats.gather_table_stats( user, 'PEOPLE' ); 23 | 24 | column table_name format a20 25 | 26 | select table_name, avg_row_len from user_object_tables; 27 | -------------------------------------------------------------------------------- /scripts/ch10/demo37.sql: -------------------------------------------------------------------------------- 1 | Object Tables, example 3 2 | 3 | set echo on 4 | 5 | drop table people; 6 | 7 | CREATE TABLE "PEOPLE" 8 | OF "PERSON_TYPE" 9 | ( constraint people_pk primary key(name) ) 10 | object identifier is PRIMARY KEY 11 | / 12 | 13 | select name, type#, segcollength 14 | from sys.col$ 15 | where obj# = ( select object_id 16 | from user_objects 17 | where object_name = 'PEOPLE' ) 18 | and name like 'SYS\_NC\_%' escape '\' 19 | / 20 | 21 | insert into people (name) values ( 'Hello World!' ); 22 | 23 | select sys_nc_oid$ from people p; 24 | 25 | select utl_raw.cast_to_raw( 'Hello World!' ) data from dual; 26 | 27 | select utl_raw.cast_to_varchar2(sys_nc_oid$) data from people; 28 | -------------------------------------------------------------------------------- /scripts/ch10/demo38.sql: -------------------------------------------------------------------------------- 1 | -- Object Tables, example 4 2 | 3 | set echo on 4 | 5 | drop table people_tab; 6 | 7 | create table people_tab 8 | ( name varchar2(30) primary key, 9 | dob date, 10 | home_city varchar2(30), 11 | home_street varchar2(30), 12 | home_state varchar2(2), 13 | home_zip number, 14 | work_city varchar2(30), 15 | work_street varchar2(30), 16 | work_state varchar2(2), 17 | work_zip number 18 | ) 19 | / 20 | 21 | create view people of person_type 22 | with object identifier (name) 23 | as 24 | select name, dob, 25 | address_type(home_city,home_street,home_state,home_zip) home_adress, 26 | address_type(work_city,work_street,work_state,work_zip) work_adress 27 | from people_tab 28 | / 29 | 30 | insert into people values ( 'Tom', '15-mar-1965', 31 | address_type( 'Denver', '123 Main Street', 'Co', '80202' ), 32 | address_type( 'Redwood', '1 Oracle Way', 'Ca', '23456' ) ); 33 | 34 | column name format a20 35 | 36 | select name, p.home_address.city from people p; 37 | -------------------------------------------------------------------------------- /scripts/ch11/demo01.sql: -------------------------------------------------------------------------------- 1 | -- B*tree indexes 2 | 3 | set echo on 4 | 5 | col index_name format a20 6 | 7 | select index_name, blevel, num_rows 8 | from user_indexes 9 | where table_name = 'BIG_TABLE'; 10 | 11 | set autotrace on 12 | 13 | select id from big_table where id = 42; 14 | select id from big_table where id = 12345; 15 | select id from big_table where id = 1234567; 16 | 17 | set autotrace off; 18 | -------------------------------------------------------------------------------- /scripts/ch11/demo02.sql: -------------------------------------------------------------------------------- 1 | -- Index Key Compression 2 | 3 | set echo on 4 | 5 | drop table t; 6 | drop table idx_stats; 7 | 8 | create table t 9 | as 10 | select * from all_objects 11 | where rownum <= 50000; 12 | 13 | create index t_idx on 14 | t(owner,object_type,object_name); 15 | 16 | analyze index t_idx validate structure; 17 | 18 | create table idx_stats 19 | as 20 | select 'noncompressed' what, a.* 21 | from index_stats a; 22 | 23 | ----------------------------------------------- 24 | -- Run this section of code with values 1, 2, and 3 25 | drop index t_idx; 26 | create index t_idx on 27 | t(owner,object_type,object_name) 28 | compress &1; 29 | analyze index t_idx validate structure; 30 | insert into idx_stats 31 | select 'compress &1', a.* 32 | from index_stats a; 33 | ----------------------------------------------- 34 | 35 | select what, height, lf_blks, br_blks, 36 | btree_space, opt_cmpr_count, opt_cmpr_pctsave 37 | from idx_stats 38 | / 39 | 40 | -- Reverse Key Indexes 41 | 42 | select 90101, dump(90101,16) from dual 43 | union all 44 | select 90102, dump(90102,16) from dual 45 | union all 46 | select 90103, dump(90103,16) from dual 47 | / 48 | -------------------------------------------------------------------------------- /scripts/ch11/demo04.sql: -------------------------------------------------------------------------------- 1 | -- Descending Indexes 2 | 3 | drop table t purge; 4 | 5 | set echo on 6 | 7 | create table t 8 | as 9 | select * 10 | from all_objects 11 | / 12 | 13 | create index t_idx on t(owner,object_type,object_name); 14 | 15 | begin 16 | dbms_stats.gather_table_stats 17 | ( user, 'T', method_opt=>'for all indexed columns' ); 18 | end; 19 | / 20 | 21 | set autotrace traceonly explain 22 | 23 | select owner, object_type 24 | from t 25 | where owner between 'T' and 'Z' 26 | and object_type is not null 27 | order by owner DESC, object_type DESC; 28 | 29 | select owner, object_type 30 | from t 31 | where owner between 'T' and 'Z' 32 | and object_type is not null 33 | order by owner DESC, object_type ASC; 34 | 35 | create index desc_t_idx on t(owner desc,object_type asc); 36 | 37 | select owner, object_type 38 | from t 39 | where owner between 'T' and 'Z' 40 | and object_type is not null 41 | order by owner DESC, object_type ASC; 42 | -------------------------------------------------------------------------------- /scripts/ch11/demo05.sql: -------------------------------------------------------------------------------- 1 | -- When should you used a B*tree Index 2 | 3 | set echo on 4 | 5 | set autotrace traceonly explain 6 | 7 | select owner, status 8 | from t 9 | where owner = USER; 10 | 11 | select count(*) 12 | from t 13 | where owner = user; 14 | -------------------------------------------------------------------------------- /scripts/ch11/demo07.sql: -------------------------------------------------------------------------------- 1 | -- Bitmap Indexes 2 | 3 | set echo on 4 | 5 | create BITMAP index job_idx on emp(job); 6 | 7 | select count(*) from emp where job = 'CLERK' or job = 'MANAGER'; 8 | 9 | select * from emp where job = 'CLERK' or job = 'MANAGER'; 10 | -------------------------------------------------------------------------------- /scripts/ch11/demo08.sql: -------------------------------------------------------------------------------- 1 | -- When Should You Use a Bitmap Index? 2 | 3 | drop table t purge; 4 | 5 | set echo on 6 | 7 | create table t 8 | ( gender not null, 9 | location not null, 10 | age_group not null, 11 | data 12 | ) 13 | as 14 | select decode( round(dbms_random.value(1,2)), 15 | 1, 'M', 16 | 2, 'F' ) gender, 17 | ceil(dbms_random.value(1,50)) location, 18 | decode( round(dbms_random.value(1,5)), 19 | 1,'18 and under', 20 | 2,'19-25', 21 | 3,'26-30', 22 | 4,'31-40', 23 | 5,'41 and over'), 24 | rpad( '*', 20, '*') 25 | from dual connect by level <=100000; 26 | 27 | create bitmap index gender_idx on t(gender); 28 | create bitmap index location_idx on t(location); 29 | create bitmap index age_group_idx on t(age_group); 30 | 31 | exec dbms_stats.gather_table_stats( user, 'T'); 32 | 33 | set lines 132 34 | set autotrace traceonly explain 35 | 36 | select count(*) 37 | from t 38 | where gender = 'M' 39 | and location in ( 1, 10, 30 ) 40 | and age_group = '41 and over'; 41 | 42 | select * 43 | from t 44 | where (( gender = 'M' and location = 20 ) 45 | or ( gender = 'F' and location = 22 )) 46 | and age_group = '18 and under'; 47 | -------------------------------------------------------------------------------- /scripts/ch11/demo09.sql: -------------------------------------------------------------------------------- 1 | -- Bitmap Join Indexes 2 | 3 | drop table dept; 4 | drop table emp; 5 | 6 | set echo on 7 | 8 | create table emp as select * from scott.emp; 9 | create table dept as select * from scott.dept; 10 | alter table dept add constraint dept_pk primary key(deptno); 11 | 12 | create bitmap index emp_bm_idx 13 | on emp( d.dname ) 14 | from emp e, dept d 15 | where e.deptno = d.deptno 16 | / 17 | 18 | begin 19 | dbms_stats.set_table_stats( user, 'EMP', 20 | numrows => 10000000, numblks => 300000 ); 21 | dbms_stats.set_table_stats( user, 'DEPT', 22 | numrows => 100000, numblks => 30000 ); 23 | dbms_stats.delete_index_stats( user, 'EMP_BM_IDX' ); 24 | end; 25 | / 26 | 27 | set lines 132 28 | set autotrace traceonly explain 29 | 30 | select count(*) 31 | from emp, dept 32 | where emp.deptno = dept.deptno 33 | and dept.dname = 'SALES' 34 | / 35 | 36 | select emp.* 37 | from emp, dept 38 | where emp.deptno = dept.deptno 39 | and dept.dname = 'SALES' 40 | / 41 | 42 | set autotrace off 43 | set lines 80 44 | -------------------------------------------------------------------------------- /scripts/ch11/demo10.sql: -------------------------------------------------------------------------------- 1 | -- A Simple Function-Based Index Example 2 | 3 | drop table emp purge; 4 | 5 | set echo on 6 | 7 | create table emp 8 | as 9 | select * 10 | from scott.emp 11 | where 1=0; 12 | 13 | insert into emp 14 | (empno,ename,job,mgr,hiredate,sal,comm,deptno) 15 | select rownum empno, 16 | initcap(substr(object_name,1,10)) ename, 17 | substr(object_type,1,9) JOB, 18 | rownum MGR, 19 | created hiredate, 20 | rownum SAL, 21 | rownum COMM, 22 | (mod(rownum,4)+1)*10 DEPTNO 23 | from all_objects 24 | where rownum < 10000; 25 | 26 | create index emp_upper_idx on emp(upper(ename)); 27 | 28 | begin 29 | dbms_stats.gather_table_stats 30 | (user,'EMP',cascade=>true); 31 | end; 32 | / 33 | 34 | set lines 132 35 | set autotrace traceonly explain 36 | 37 | select * 38 | from emp 39 | where upper(ename) = 'KING'; 40 | 41 | set autotrace off 42 | set lines 80 43 | -------------------------------------------------------------------------------- /scripts/ch11/demo11.sql: -------------------------------------------------------------------------------- 1 | -- MY_SOUNDEX example 2 | 3 | -- May need to "drop view stats" if created previously. 4 | 5 | set echo on 6 | 7 | create or replace package stats 8 | as 9 | cnt number default 0; 10 | end; 11 | / 12 | 13 | create or replace 14 | function my_soundex( p_string in varchar2 ) return varchar2 15 | deterministic 16 | as 17 | l_return_string varchar2(6) default substr( p_string, 1, 1 ); 18 | l_char varchar2(1); 19 | l_last_digit number default 0; 20 | 21 | type vcArray is table of varchar2(10) index by binary_integer; 22 | l_code_table vcArray; 23 | begin 24 | stats.cnt := stats.cnt+1; 25 | l_code_table(1) := 'BPFV'; 26 | l_code_table(2) := 'CSKGJQXZ'; 27 | l_code_table(3) := 'DT'; 28 | l_code_table(4) := 'L'; 29 | l_code_table(5) := 'MN'; 30 | l_code_table(6) := 'R'; 31 | for i in 1 .. length(p_string) 32 | loop 33 | exit when (length(l_return_string) = 6); 34 | l_char := upper(substr( p_string, i, 1 ) ); 35 | 36 | for j in 1 .. l_code_table.count 37 | loop 38 | if (instr(l_code_table(j), l_char ) > 0 AND j <> l_last_digit) 39 | then 40 | l_return_string := l_return_string || to_char(j,'fm9'); 41 | l_last_digit := j; 42 | end if; 43 | end loop; 44 | end loop; 45 | return rpad( l_return_string, 6, '0' ); 46 | end; 47 | / 48 | 49 | 50 | variable cpu number 51 | exec :cpu := dbms_utility.get_cpu_time 52 | 53 | set autotrace on explain 54 | 55 | select ename, hiredate 56 | from emp 57 | where my_soundex(ename) = my_soundex('Kings') 58 | / 59 | 60 | set autotrace off 61 | 62 | begin 63 | dbms_output.put_line 64 | ( 'cpu time = ' || round((dbms_utility.get_cpu_time-:cpu)/100,2) ); 65 | dbms_output.put_line( 'function was called: ' || stats.cnt ); 66 | end; 67 | / 68 | -------------------------------------------------------------------------------- /scripts/ch11/demo12.sql: -------------------------------------------------------------------------------- 1 | -- MY_SOUNDEX, 2nd example 2 | 3 | exec dbms_monitor.session_trace_enable; 4 | 5 | insert into emp NO_INDEX 6 | (empno,ename,job,mgr,hiredate,sal,comm,deptno) 7 | select rownum empno, 8 | initcap(substr(object_name,1,10)) ename, 9 | substr(object_type,1,9) JOB, 10 | rownum MGR, 11 | created hiredate, 12 | rownum SAL, 13 | rownum COMM, 14 | (mod(rownum,4)+1)*10 DEPTNO 15 | from all_objects 16 | where rownum < 10000; 17 | 18 | exec dbms_monitor.session_trace_disable; 19 | @tk "sys=no" 20 | pause 21 | 22 | disconnect 23 | connect eoda/foo 24 | 25 | create index emp_soundex_idx on 26 | emp( substr(my_soundex(ename),1,6) ) 27 | / 28 | 29 | exec dbms_monitor.session_trace_enable; 30 | 31 | insert into emp WITH_INDEX 32 | (empno,ename,job,mgr,hiredate,sal,comm,deptno) 33 | select rownum empno, 34 | initcap(substr(object_name,1,10)) ename, 35 | substr(object_type,1,9) JOB, 36 | rownum MGR, 37 | created hiredate, 38 | rownum SAL, 39 | rownum COMM, 40 | (mod(rownum,4)+1)*10 DEPTNO 41 | from all_objects 42 | where rownum < 10000; 43 | 44 | exec dbms_monitor.session_trace_disable; 45 | @tk "sys=no" 46 | -------------------------------------------------------------------------------- /scripts/ch11/demo13.sql: -------------------------------------------------------------------------------- 1 | -- MY_SOUNDEX, 3rd example 2 | 3 | exec stats.cnt := 0 4 | 5 | variable cpu number 6 | exec :cpu := dbms_utility.get_cpu_time 7 | 8 | set lines 132 9 | set autotrace on explain 10 | 11 | select ename, hiredate 12 | from emp 13 | where substr(my_soundex(ename),1,6) = my_soundex('Kings') 14 | / 15 | 16 | set autotrace off 17 | set lines 80 18 | 19 | begin 20 | dbms_output.put_line 21 | ( 'cpu time = ' || round((dbms_utility.get_cpu_time-:cpu)/100,2) ); 22 | dbms_output.put_line( 'function was called: ' || stats.cnt ); 23 | end; 24 | / 25 | -------------------------------------------------------------------------------- /scripts/ch11/demo14.sql: -------------------------------------------------------------------------------- 1 | -- MY_SOUNDEX, view example 2 | 3 | set echo on 4 | 5 | create or replace view emp_v 6 | as 7 | select ename, substr(my_soundex(ename),1,6) ename_soundex, hiredate 8 | from emp 9 | / 10 | 11 | exec stats.cnt := 0; 12 | exec :cpu := dbms_utility.get_cpu_time 13 | 14 | select ename, hiredate 15 | from emp_v 16 | where ename_soundex = my_soundex('Kings') 17 | / 18 | 19 | begin 20 | dbms_output.put_line 21 | ( 'cpu time = ' || round((dbms_utility.get_cpu_time-:cpu)/100,2) ); 22 | dbms_output.put_line( 'function was called: ' || stats.cnt ); 23 | end; 24 | / 25 | -------------------------------------------------------------------------------- /scripts/ch11/demo15.sql: -------------------------------------------------------------------------------- 1 | -- MY_SOUNDEX, function example 2 | 3 | set echo on 4 | 5 | drop index emp_soundex_idx; 6 | 7 | alter table emp 8 | add 9 | ename_soundex as 10 | (substr(my_soundex(ename),1,6)) 11 | / 12 | 13 | create index emp_soundex_idx 14 | on emp(ename_soundex); 15 | 16 | exec stats.cnt := 0; 17 | 18 | exec :cpu := dbms_utility.get_cpu_time 19 | 20 | select ename, hiredate 21 | from emp 22 | where ename_soundex = my_soundex('Kings') 23 | / 24 | 25 | begin 26 | dbms_output.put_line 27 | ( 'cpu time = ' || round((dbms_utility.get_cpu_time-:cpu)/100,2) ); 28 | dbms_output.put_line( 'function was called: ' || stats.cnt ); 29 | end; 30 | / 31 | -------------------------------------------------------------------------------- /scripts/ch11/demo16.sql: -------------------------------------------------------------------------------- 1 | -- Indexing Only Some of the Rows 2 | 3 | set echo on 4 | 5 | update big_table set temporary = decode(temporary,'N','Y','N'); 6 | 7 | select temporary, cnt, 8 | round( (ratio_to_report(cnt) over ()) * 100, 2 ) rtr 9 | from ( 10 | select temporary, count(*) cnt 11 | from big_table 12 | group by temporary 13 | ) 14 | / 15 | 16 | create index processed_flag_idx 17 | on big_table(temporary); 18 | 19 | analyze index processed_flag_idx 20 | validate structure; 21 | 22 | select name, btree_space, lf_rows, height from index_stats; 23 | 24 | drop index processed_flag_idx; 25 | 26 | create index processed_flag_idx 27 | on big_table( case temporary when 'N' then 'N' end ); 28 | 29 | analyze index processed_flag_idx validate structure; 30 | 31 | select name, btree_space, lf_rows, height from index_stats; 32 | -------------------------------------------------------------------------------- /scripts/ch11/demo17.sql: -------------------------------------------------------------------------------- 1 | -- Invisible Indexes 2 | 3 | drop table t purge; 4 | 5 | set echo on 6 | 7 | create table t(x int); 8 | 9 | insert into t select round(dbms_random.value(1,10000)) from dual 10 | connect by level <=10000; 11 | 12 | exec dbms_stats.gather_table_stats(user,'T'); 13 | 14 | create index ti on t(x) invisible; 15 | 16 | set autotrace traceonly explain 17 | select * from t where x=5; 18 | 19 | alter session set optimizer_use_invisible_indexes=true; 20 | 21 | select * from t where x=5; 22 | 23 | set autotrace off 24 | -------------------------------------------------------------------------------- /scripts/ch11/demo18.sql: -------------------------------------------------------------------------------- 1 | -- Indexing Extended Columns, Virtual Column 2 | 3 | drop table t purge; 4 | 5 | set echo on 6 | 7 | create table t(x varchar2(32767)); 8 | 9 | create index ti on t(x); 10 | 11 | insert into t select to_char(level)|| rpad('abc',10000,'xyz') 12 | from dual connect by level < 1001 13 | union 14 | select to_char(level) 15 | from dual connect by level < 1001; 16 | 17 | alter table t add (xv as (substr(x,1,10))); 18 | create index te on t(xv); 19 | exec dbms_stats.gather_table_stats(user,'T'); 20 | 21 | set autotrace traceonly explain 22 | select count(*) from t where x = '800'; 23 | select count(*) from t where x >'800' and x<'900'; 24 | 25 | set autotrace off; 26 | 27 | drop table t purge; 28 | 29 | create table t(x varchar2(32767)); 30 | 31 | insert into t select to_char(level)|| rpad('abc',10000,'xyz') 32 | from dual connect by level < 1001 33 | union 34 | select to_char(level) 35 | from dual connect by level < 1001; 36 | 37 | alter table t add (xv as (standard_hash(x))); 38 | create index te on t(xv); 39 | exec dbms_stats.gather_table_stats(user,'T'); 40 | 41 | set autotrace traceonly explain 42 | select count(*) from t where x='300'; 43 | select count(*) from t where x >'800' and x<'900'; 44 | set autotrace off 45 | -------------------------------------------------------------------------------- /scripts/ch11/demo19.sql: -------------------------------------------------------------------------------- 1 | -- Indexing Extended Columns, Function Based Index 2 | 3 | drop table t purge; 4 | 5 | set echo on 6 | 7 | create table t(x varchar2(32767)); 8 | 9 | insert into t 10 | select to_char(level)|| rpad('abc',10000,'xyz') 11 | from dual connect by level < 1001 12 | union 13 | select to_char(level) 14 | from dual connect by level < 1001; 15 | 16 | create index te on t(substr(x,1,10)); 17 | 18 | exec dbms_stats.gather_table_stats(user,'T'); 19 | 20 | set autotrace traceonly explain 21 | select count(*) from t where x = '800'; 22 | select count(*) from t where x>'200' and x<'400'; 23 | set autotrace off; 24 | 25 | drop table t purge; 26 | 27 | create table t(x varchar2(32767)); 28 | 29 | insert into t 30 | select to_char(level)|| rpad('abc',10000,'xyz') 31 | from dual connect by level < 1001 32 | union 33 | select to_char(level) 34 | from dual connect by level < 1001; 35 | 36 | create index te on t(standard_hash(x)); 37 | 38 | set autotrace traceonly explain 39 | select count(*) from t where x = '800'; 40 | set autotrace off 41 | -------------------------------------------------------------------------------- /scripts/ch11/demo20.sql: -------------------------------------------------------------------------------- 1 | -- Do Nulls and Indexes Work Together? 2 | 3 | drop table t purge; 4 | 5 | set echo on 6 | 7 | create table t ( x int, y int ); 8 | create unique index t_idx on t(x,y); 9 | insert into t values ( 1, 1 ); 10 | insert into t values ( 1, NULL ); 11 | insert into t values ( NULL, 1 ); 12 | insert into t values ( NULL, NULL ); 13 | analyze index t_idx validate structure; 14 | 15 | column name format a25 16 | 17 | select name, lf_rows from index_stats; 18 | 19 | insert into t values ( NULL, NULL ); 20 | insert into t values ( NULL, 1 ); 21 | insert into t values ( 1, NULL ); 22 | 23 | select x, y, count(*) 24 | from t 25 | group by x,y 26 | having count(*) > 1; 27 | -------------------------------------------------------------------------------- /scripts/ch11/demo21.sql: -------------------------------------------------------------------------------- 1 | -- Do Nulls and Indexes Work Together? 2 | 3 | drop table t purge; 4 | 5 | set echo on 6 | 7 | create table t ( x int, y int NOT NULL ); 8 | create unique index t_idx on t(x,y); 9 | insert into t values ( 1, 1 ); 10 | insert into t values ( NULL, 1 ); 11 | 12 | begin 13 | dbms_stats.gather_table_stats(user,'T'); 14 | end; 15 | / 16 | 17 | set autotrace on 18 | select * from t where x is null; 19 | set autotrace off 20 | -------------------------------------------------------------------------------- /scripts/ch11/demo22.sql: -------------------------------------------------------------------------------- 1 | -- Why Isn't My Index Getting Used? 2 | -- Case 1 3 | 4 | drop table t purge; 5 | 6 | set echo on 7 | 8 | create table t 9 | as 10 | select decode(mod(rownum,2), 0, 'M', 'F' ) gender, all_objects.* 11 | from all_objects 12 | / 13 | 14 | create index t_idx on t(gender,object_id); 15 | exec dbms_stats.gather_table_stats( user, 'T' ); 16 | 17 | set autotrace traceonly explain 18 | select * from t t1 where object_id = 42; 19 | set autotrace off 20 | 21 | update t set gender = chr(mod(rownum,256)); 22 | exec dbms_stats.gather_table_stats( user, 'T', cascade=>TRUE ); 23 | 24 | set autotrace traceonly explain 25 | select * from t t1 where object_id = 42; 26 | set autotrace off 27 | 28 | -------------------------------------------------------------------------------- /scripts/ch11/demo23.sql: -------------------------------------------------------------------------------- 1 | -- Why Isn't My Index Getting Used? 2 | -- Case 4 3 | 4 | drop table t purge; 5 | 6 | create table t ( x char(1) constraint t_pk primary key, y date ); 7 | 8 | insert into t values ( '5', sysdate ); 9 | 10 | delete from plan_table; 11 | explain plan for select * from t where x = 5; 12 | select * from table(dbms_xplan.display); 13 | 14 | delete from plan_table; 15 | explain plan for select /*+ INDEX(t t_pk) */ * from t where x = 5; 16 | select * from table(dbms_xplan.display); 17 | 18 | delete from plan_table; 19 | explain plan for select * from t where x = '5'; 20 | select * from table(dbms_xplan.display); 21 | 22 | -------------------------------------------------------------------------------- /scripts/ch11/demo24.sql: -------------------------------------------------------------------------------- 1 | -- Why Isn't My Index Getting Used? 2 | -- Case 5 3 | 4 | drop table t purge; 5 | 6 | set echo on 7 | 8 | create table t(x int); 9 | 10 | insert into t select rownum from dual connect by level < 1000000; 11 | 12 | create index ti on t(x); 13 | exec dbms_stats.gather_table_stats(user,'T'); 14 | 15 | set autotrace trace explain; 16 | select count(*) from t where x < 50; 17 | select count(*) from t where x < 1000000; 18 | -------------------------------------------------------------------------------- /scripts/ch11/demo25.sql: -------------------------------------------------------------------------------- 1 | -- Myth: Space Is Never Reused in an Index 2 | 3 | drop table t purge; 4 | 5 | set echo on 6 | 7 | create table t ( x int, constraint t_pk primary key(x) ); 8 | 9 | insert into t values (1); 10 | 11 | insert into t values (2); 12 | 13 | insert into t values (9999999999); 14 | 15 | analyze index t_pk validate structure; 16 | 17 | select lf_blks, br_blks, btree_space from index_stats; 18 | 19 | begin 20 | for i in 2 .. 999999 21 | loop 22 | delete from t where x = i; 23 | commit; 24 | insert into t values (i+1); 25 | commit; 26 | end loop; 27 | end; 28 | / 29 | 30 | analyze index t_pk validate structure; 31 | select lf_blks, br_blks, btree_space from index_stats; 32 | 33 | -------------------------------------------------------------------------------- /scripts/ch11/demo26.sql: -------------------------------------------------------------------------------- 1 | -- Myth: Space Is Never Reused in an Index 2 | 3 | set echo on 4 | 5 | select count(*) from big_table; 6 | 7 | declare 8 | l_freelist_blocks number; 9 | begin 10 | dbms_space.free_blocks 11 | (segment_owner => user, 12 | segment_name => 'BIG_TABLE_PK', 13 | segment_type => 'INDEX', 14 | freelist_group_id => 0, 15 | free_blks => l_freelist_blocks ); 16 | dbms_output.put_line( 'blocks on freelist = ' || l_freelist_blocks ); 17 | end; 18 | / 19 | 20 | select leaf_blocks from user_indexes where index_name = 'BIG_TABLE_PK'; 21 | 22 | delete from big_table where id <= 250000; 23 | commit; 24 | 25 | declare 26 | l_freelist_blocks number; 27 | begin 28 | dbms_space.free_blocks 29 | ( segment_owner => user, 30 | segment_name => 'BIG_TABLE_PK', 31 | segment_type => 'INDEX', 32 | freelist_group_id => 0, 33 | free_blks => l_freelist_blocks ); 34 | dbms_output.put_line( 'blocks on freelist = ' || l_freelist_blocks ); 35 | dbms_stats.gather_index_stats ( user, 'BIG_TABLE_PK' ); 36 | end; 37 | / 38 | 39 | select leaf_blocks from user_indexes where index_name = 'BIG_TABLE_PK'; 40 | -------------------------------------------------------------------------------- /scripts/ch11/demo27.sql: -------------------------------------------------------------------------------- 1 | -- Myth: Most Discriminating Elements Should Be First 2 | 3 | drop table t purge; 4 | 5 | set echo on 6 | 7 | create table t as select * from all_objects; 8 | create index t_idx_1 on t(owner,object_type,object_name); 9 | create index t_idx_2 on t(object_name,object_type,owner); 10 | 11 | select count(distinct owner), count(distinct object_type), 12 | count(distinct object_name ), count(*) 13 | from t; 14 | 15 | analyze index t_idx_1 validate structure; 16 | 17 | select btree_space, pct_used, opt_cmpr_count, opt_cmpr_pctsave 18 | from index_stats; 19 | 20 | analyze index t_idx_2 validate structure; 21 | 22 | select btree_space, pct_used, opt_cmpr_count, opt_cmpr_pctsave 23 | from index_stats; 24 | 25 | exec dbms_stats.gather_table_stats(user,'T'); 26 | 27 | alter session set sql_trace=true; 28 | declare 29 | cnt int; 30 | begin 31 | for x in ( select /*+FULL(t)*/ owner, object_type, object_name from t ) 32 | loop 33 | select /*+ INDEX( t t_idx_1 ) */ count(*) into cnt 34 | from t 35 | where object_name = x.object_name 36 | and object_type = x.object_type 37 | and owner = x.owner; 38 | 39 | select /*+ INDEX( t t_idx_2 ) */ count(*) into cnt 40 | from t 41 | where object_name = x.object_name 42 | and object_type = x.object_type 43 | and owner = x.owner; 44 | end loop; 45 | end; 46 | / 47 | alter session set sql_trace=false; 48 | 49 | @tk "sys=no" 50 | -------------------------------------------------------------------------------- /scripts/ch11/demo3.sql: -------------------------------------------------------------------------------- 1 | @demo3_run 1 plsql nosort 2 | @demo3_run 2 plsql nosort 3 | @demo3_run 5 plsql nosort 4 | @demo3_run 10 plsql nosort 5 | 6 | @demo3_run 1 proc nosort 7 | @demo3_run 2 proc nosort 8 | @demo3_run 5 proc nosort 9 | @demo3_run 10 proc nosort 10 | 11 | @demo3_run 1 plsql reverse 12 | @demo3_run 2 plsql reverse 13 | @demo3_run 5 plsql reverse 14 | @demo3_run 10 plsql reverse 15 | 16 | @demo3_run 1 proc reverse 17 | @demo3_run 2 proc reverse 18 | @demo3_run 5 proc reverse 19 | @demo3_run 10 proc reverse 20 | -------------------------------------------------------------------------------- /scripts/ch11/demo3_creates.sql: -------------------------------------------------------------------------------- 1 | drop table t purge; 2 | drop sequence s; 3 | 4 | create table t tablespace assm 5 | as 6 | select 0 id, owner, object_name, subobject_name, 7 | object_id, data_object_id, object_type, created, 8 | last_ddl_time, timestamp, status, temporary, 9 | generated, secondary 10 | from all_objects a 11 | where 1=0; 12 | 13 | alter table t 14 | add constraint t_pk 15 | primary key (id) 16 | using index (create index t_pk on t(id) &1 tablespace assm); 17 | 18 | create sequence s cache 1000; 19 | 20 | create or replace procedure do_sql 21 | as 22 | begin 23 | for x in ( select rownum r, OWNER, OBJECT_NAME, SUBOBJECT_NAME, 24 | OBJECT_ID, DATA_OBJECT_ID, OBJECT_TYPE, CREATED, 25 | LAST_DDL_TIME, TIMESTAMP, STATUS, TEMPORARY, 26 | GENERATED, SECONDARY from all_objects ) 27 | loop 28 | insert into t 29 | ( id, OWNER, OBJECT_NAME, SUBOBJECT_NAME, 30 | OBJECT_ID, DATA_OBJECT_ID, OBJECT_TYPE, CREATED, 31 | LAST_DDL_TIME, TIMESTAMP, STATUS, TEMPORARY, 32 | GENERATED, SECONDARY ) 33 | values 34 | ( s.nextval, x.OWNER, x.OBJECT_NAME, x.SUBOBJECT_NAME, 35 | x.OBJECT_ID, x.DATA_OBJECT_ID, x.OBJECT_TYPE, x.CREATED, 36 | x.LAST_DDL_TIME, x.TIMESTAMP, x.STATUS, x.TEMPORARY, 37 | x.GENERATED, x.SECONDARY ); 38 | if ( mod(x.r,100) = 0 ) 39 | then 40 | commit; 41 | end if; 42 | end loop; 43 | commit; 44 | end; 45 | / 46 | -------------------------------------------------------------------------------- /scripts/ch11/demo3_plsql.sh: -------------------------------------------------------------------------------- 1 | #!/bin/bash 2 | 3 | for i in `seq 1 $*` 4 | do 5 | echo 'exec do_sql' | sqlplus eoda/foo & 6 | done 7 | wait 8 | -------------------------------------------------------------------------------- /scripts/ch11/demo3_proc.sh: -------------------------------------------------------------------------------- 1 | #!/bin/bash 2 | 3 | for i in `seq 1 $*` 4 | do 5 | ./t & 6 | done 7 | wait 8 | -------------------------------------------------------------------------------- /scripts/ch11/demo3_run.sql: -------------------------------------------------------------------------------- 1 | set echo on 2 | 3 | define NumUsers=&1 4 | define Which=&2 5 | 6 | @demo3_creates &3 7 | 8 | exec statspack.snap 9 | !./demo3_&Which..sh &NumUsers 10 | exec statspack.snap 11 | 12 | column b new_val begin_snap 13 | column e new_val end_snap 14 | define report_name=multiuser_&NumUsers._&Which._&3 15 | select max(decode(rn,1,snap_id)) e, 16 | max(decode(rn,2,snap_id)) b 17 | from ( 18 | select snap_id, row_number() over (order by snap_id desc) rn 19 | from perfstat.stats$snapshot 20 | ) 21 | where rn <= 2 22 | / 23 | 24 | insert into perfstat.STATS$IDLE_EVENT ( event ) 25 | select 'PL/SQL lock timer' 26 | from dual 27 | where not exists 28 | (select null from perfstat.STATS$IDLE_EVENT where event = 'PL/SQL lock timer') 29 | / 30 | commit; 31 | 32 | @?/rdbms/admin/spreport 33 | -------------------------------------------------------------------------------- /scripts/ch11/tk.sql: -------------------------------------------------------------------------------- 1 | column trace new_val TRACE 2 | 3 | select c.value || '/' || d.instance_name || '_ora_' || a.spid || '.trc' trace 4 | from v$process a, v$session b, v$parameter c, v$instance d 5 | where a.addr = b.paddr 6 | and b.audsid = userenv('sessionid') 7 | and c.name = 'user_dump_dest' 8 | / 9 | 10 | disconnect 11 | !tkprof &TRACE ./tk.prf &1 12 | -- connect / 13 | connect eoda/foo 14 | edit tk.prf 15 | -------------------------------------------------------------------------------- /scripts/ch12/demo01.sql: -------------------------------------------------------------------------------- 1 | -- NLS overview 2 | 3 | drop table t purge; 4 | 5 | set echo on 6 | 7 | col parameter form a20 8 | col value form a30 9 | -- 10 | select * 11 | from nls_database_parameters 12 | where parameter = 'NLS_CHARACTERSET'; 13 | 14 | host echo $NLS_LANG 15 | 16 | create table t ( data varchar2(1) ); 17 | insert into t values ( chr(224) ); 18 | insert into t values ( chr(225) ); 19 | insert into t values ( chr(226) ); 20 | select data, dump(data) dump 21 | from t; 22 | commit; 23 | 24 | prompt need another window for next bit 25 | pause 26 | 27 | variable d varchar2(1) 28 | variable r varchar2(20) 29 | begin 30 | select data, rowid into :d, :r from t where rownum = 1; 31 | end; 32 | / 33 | 34 | update t set data = :d where rowid = chartorowid(:r); 35 | commit; 36 | 37 | prompt back to first window for next bit 38 | pause 39 | 40 | select data, dump(data) dump 41 | from t; 42 | -------------------------------------------------------------------------------- /scripts/ch12/demo02.sql: -------------------------------------------------------------------------------- 1 | -- Character Strings 2 | 3 | drop table t purge; 4 | 5 | set echo on 6 | 7 | create table t 8 | ( char_column char(20), 9 | varchar2_column varchar2(20) 10 | ) 11 | / 12 | 13 | insert into t values ( 'Hello World', 'Hello World' ); 14 | select * from t; 15 | select * from t where char_column = 'Hello World'; 16 | select * from t where varchar2_column = 'Hello World'; 17 | select * from t where char_column = varchar2_column; 18 | select * from t where trim(char_column) = varchar2_column; 19 | select * from t where char_column = rpad( varchar2_column, 20 ); 20 | -- 21 | variable varchar2_bv varchar2(20) 22 | exec :varchar2_bv := 'Hello World'; 23 | select * from t where char_column = :varchar2_bv; 24 | select * from t where varchar2_column = :varchar2_bv; 25 | -- 26 | variable char_bv char(20) 27 | exec :char_bv := 'Hello World'; 28 | select * from t where char_column = :char_bv; 29 | select * from t where varchar2_column = :char_bv; 30 | -------------------------------------------------------------------------------- /scripts/ch12/demo03.sql: -------------------------------------------------------------------------------- 1 | -- Bytes or Characters 2 | 3 | drop table t purge; 4 | 5 | set echo on 6 | 7 | create table t 8 | ( a varchar2(1), 9 | b varchar2(1 char), 10 | c varchar2(4000 char) 11 | ) 12 | / 13 | 14 | insert into t (a) values (unistr('\00d6')); 15 | insert into t (b) values (unistr('\00d6')); 16 | select length(b), lengthb(b), dump(b) dump from t; 17 | 18 | declare 19 | l_data varchar2(4000 char); 20 | l_ch varchar2(1 char) := unistr( '\00d6' ); 21 | begin 22 | l_data := rpad( l_ch, 4000, l_ch ); 23 | insert into t ( c ) values ( l_data ); 24 | end; 25 | / 26 | 27 | declare 28 | l_data varchar2(4000 char); 29 | l_ch varchar2(1 char) := unistr( '\00d6' ); 30 | begin 31 | l_data := rpad( l_ch, 2000, l_ch ); 32 | insert into t ( c ) values ( l_data ); 33 | end; 34 | / 35 | 36 | select length( c ), lengthb( c ) 37 | from t 38 | where c is not null; 39 | -------------------------------------------------------------------------------- /scripts/ch12/demo04.sql: -------------------------------------------------------------------------------- 1 | -- Binary Strings: RAW Types 2 | 3 | drop table t purge; 4 | 5 | set echo on 6 | 7 | create table t ( raw_data raw(16) ); 8 | insert into t values ( sys_guid() ); 9 | select * from t; 10 | select dump(raw_data,16) from t; 11 | insert into t values ( 'abcdef' ); 12 | insert into t values ( 'abcdefgh' ); 13 | select rawtohex(raw_data) from t; 14 | insert into t values ( hextoraw('abcdef') ); 15 | -------------------------------------------------------------------------------- /scripts/ch12/demo05.sql: -------------------------------------------------------------------------------- 1 | -- Extended Datatypes 2 | 3 | drop table t purge; 4 | drop table c purge; 5 | 6 | set echo on 7 | 8 | create table t(et varchar2(32727)) tablespace users; 9 | -- 10 | insert into t values(rpad('abc',10000,'abc')); 11 | select substr(et,9500,10) from t where UPPER(et) like 'ABC%'; 12 | -- 13 | select table_name, column_name, segment_name, tablespace_name, in_row 14 | from user_lobs where table_name='T'; 15 | -- 16 | create table c(c clob); 17 | -------------------------------------------------------------------------------- /scripts/ch12/demo06.sql: -------------------------------------------------------------------------------- 1 | -- Number Types 2 | 3 | drop table t purge; 4 | 5 | set echo on 6 | 7 | create table t 8 | ( num_col number, 9 | float_col binary_float, 10 | dbl_col binary_double 11 | ) 12 | / 13 | 14 | insert into t ( num_col, float_col, dbl_col ) 15 | values ( 1234567890.0987654321, 16 | 1234567890.0987654321, 17 | 1234567890.0987654321 ); 18 | 19 | set numformat 99999999999.99999999999 20 | select * from t; 21 | 22 | delete from t; 23 | 24 | insert into t ( num_col, float_col, dbl_col ) 25 | values ( 9999999999.9999999999, 26 | 9999999999.9999999999, 27 | 9999999999.9999999999 ); 28 | 29 | select * from t; 30 | delete from t; 31 | 32 | insert into t ( num_col ) 33 | values ( 123 * 1e20 + 123*1e-20 ) ; 34 | 35 | set numformat 999999999999999999999999.999999999999999999999999 36 | select num_col, 123*1e20, 123*1e-20 from t; 37 | 38 | select num_col from t where num_col = 123*1e20; 39 | 40 | 41 | -------------------------------------------------------------------------------- /scripts/ch12/demo07.sql: -------------------------------------------------------------------------------- 1 | -- NUMBER Type Syntax and Usage 2 | 3 | drop table t purge; 4 | 5 | set echo on 6 | 7 | create table t ( num_col number(5,0) ); 8 | insert into t (num_col) values ( 12345 ); 9 | insert into t (num_col) values ( 123456 ); 10 | -------------------------------------------------------------------------------- /scripts/ch12/demo08.sql: -------------------------------------------------------------------------------- 1 | -- NUMBER Type Syntax and Usage, second example 2 | 3 | drop table t purge; 4 | 5 | set echo on 6 | 7 | create table t ( msg varchar2(10), num_col number(5,2) ); 8 | insert into t (msg,num_col) values ( '123.45', 123.45 ); 9 | insert into t (msg,num_col) values ( '123.456', 123.456 ); 10 | select * from t; 11 | 12 | insert into t (msg,num_col) values ( '1234', 1234 ); 13 | -------------------------------------------------------------------------------- /scripts/ch12/demo09.sql: -------------------------------------------------------------------------------- 1 | -- NUMBER Type Syntax and Usage, third example 2 | 3 | drop table t purge; 4 | 5 | set echo on 6 | 7 | create table t ( msg varchar2(10), num_col number(5,-2) ); 8 | insert into t (msg,num_col) values ( '123.45', 123.45 ); 9 | insert into t (msg,num_col) values ( '123.456', 123.456 ); 10 | select * from t; 11 | insert into t (msg,num_col) values ( '1234567', 1234567 ); 12 | select * from t; 13 | insert into t (msg,num_col) values ( '12345678', 12345678 ); 14 | -------------------------------------------------------------------------------- /scripts/ch12/demo10.sql: -------------------------------------------------------------------------------- 1 | -- NUMBER Type Syntax and Usage, fourth example 2 | 3 | drop table t purge; 4 | 5 | set echo on 6 | 7 | create table t ( x number, y number ); 8 | insert into t ( x ) 9 | 10 | insert into t (x) 11 | select to_number(rpad('9',rownum*2,'9')) 12 | from all_objects 13 | where rownum <= 14; 14 | 15 | update t set y = x+1; 16 | 17 | set numformat 99999999999999999999999999999 18 | column v1 format 99 19 | column v2 format 99 20 | select x, y, vsize(x) v1, vsize(y) v2 21 | from t order by x; 22 | 23 | -------------------------------------------------------------------------------- /scripts/ch12/demo11.sql: -------------------------------------------------------------------------------- 1 | -- BINARY_FLOAT/BINARY_DOUBLE Type Syntax and Usage 2 | 3 | select to_char( 0.3f + 0.1f, '0.99999999999999' ) from dual; 4 | -------------------------------------------------------------------------------- /scripts/ch12/demo12.sql: -------------------------------------------------------------------------------- 1 | -- Performance Considerations 2 | 3 | drop table t purge; 4 | 5 | set echo on 6 | 7 | create table t 8 | ( num_type number, 9 | float_type binary_float, 10 | double_type binary_double 11 | ) 12 | / 13 | 14 | insert /*+ APPEND */ into t 15 | select rownum, rownum, rownum 16 | from all_objects; 17 | 18 | commit; 19 | select sum(ln(num_type)) from t; 20 | select sum(ln(float_type)) from t; 21 | select sum(ln(double_type)) from t; 22 | 23 | set numformat 999999.9999999999999999 24 | select sum(ln(num_type)) from t; 25 | select sum(ln(double_type)) from t; 26 | select sum(ln(cast( num_type as binary_double ) )) from t; 27 | -------------------------------------------------------------------------------- /scripts/ch12/demo13.sql: -------------------------------------------------------------------------------- 1 | -- Coping with Legacy LONG Types 2 | 3 | set echo on 4 | 5 | select * 6 | from all_views 7 | where text like '%HELLO%'; 8 | 9 | col table_name form a30 10 | col column_name form a30 11 | select table_name, column_name 12 | from dba_tab_columns 13 | where data_type in ( 'LONG', 'LONG RAW' ) 14 | and owner = 'SYS' 15 | and table_name like 'DBA%' 16 | order by table_name; 17 | -------------------------------------------------------------------------------- /scripts/ch12/demo15.sql: -------------------------------------------------------------------------------- 1 | -- DATE Type 2 | 3 | drop table t purge; 4 | 5 | set echo on 6 | 7 | create table t ( x date ); 8 | 9 | insert into t (x) values 10 | ( to_date( '25-jun-2005 12:01:00', 11 | 'dd-mon-yyyy hh24:mi:ss' ) ); 12 | 13 | column d format a40 14 | 15 | select x, dump(x,10) d from t; 16 | 17 | insert into t (x) values 18 | ( to_date( '01-jan-4712bc', 19 | 'dd-mon-yyyybc hh24:mi:ss' ) ); 20 | 21 | select x, dump(x,10) d from t; 22 | 23 | insert into t (x) values 24 | ( to_date( '01-jan-4710bc', 25 | 'dd-mon-yyyybc hh24:mi:ss' ) ); 26 | 27 | select x, dump(x,10) d from t; 28 | -------------------------------------------------------------------------------- /scripts/ch12/demo16.sql: -------------------------------------------------------------------------------- 1 | -- DATE Type, second example 2 | 3 | drop table t purge; 4 | 5 | set echo on 6 | 7 | create table t ( what varchar2(10), x date ); 8 | 9 | insert into t (what, x) values 10 | ( 'orig', 11 | to_date( '25-jun-2005 12:01:00', 12 | 'dd-mon-yyyy hh24:mi:ss' ) ); 13 | 14 | insert into t (what, x) 15 | select 'minute', trunc(x,'mi') from t 16 | union all 17 | select 'day', trunc(x,'dd') from t 18 | union all 19 | select 'month', trunc(x,'mm') from t 20 | union all 21 | select 'year', trunc(x,'y') from t 22 | / 23 | 24 | column d format a40 25 | select what, x, dump(x,10) d from t; 26 | -------------------------------------------------------------------------------- /scripts/ch12/demo17.sql: -------------------------------------------------------------------------------- 1 | -- Adding or Subtracking Time from a DATE 2 | 3 | set echo on 4 | 5 | alter session set nls_date_format = 'dd-mon-yyyy hh24:mi:ss'; 6 | 7 | select dt, add_months(dt,1) 8 | from (select to_date('29-feb-2000','dd-mon-yyyy') dt from dual ) 9 | / 10 | 11 | select dt, add_months(dt,1) 12 | from (select to_date('28-feb-2001','dd-mon-yyyy') dt from dual ) 13 | / 14 | 15 | select dt, add_months(dt,1) 16 | from (select to_date('30-jan-2001','dd-mon-yyyy') dt from dual ) 17 | / 18 | 19 | select dt, add_months(dt,1) 20 | from (select to_date('30-jan-2000','dd-mon-yyyy') dt from dual ) 21 | / 22 | 23 | select dt, dt+numtoyminterval(1,'month') 24 | from (select to_date('29-feb-2000','dd-mon-yyyy') dt from dual ) 25 | / 26 | 27 | select dt, dt+numtoyminterval(1,'month') 28 | from (select to_date('28-feb-2001','dd-mon-yyyy') dt from dual ) 29 | / 30 | 31 | select dt, dt+numtoyminterval(1,'month') 32 | from (select to_date('30-jan-2001','dd-mon-yyyy') dt from dual ) 33 | / 34 | 35 | select dt, dt+numtoyminterval(1,'month') 36 | from (select to_date('30-jan-2000','dd-mon-yyyy') dt from dual ) 37 | / 38 | -------------------------------------------------------------------------------- /scripts/ch12/demo18.sql: -------------------------------------------------------------------------------- 1 | -- Getting the Difference Between Two DATEs 2 | 3 | set lines 132 4 | col dt2-dt1 form 99999999999.999999999 5 | col months_btwn form 9999999999.99999999 6 | col days form a30 7 | col months form a30 8 | 9 | set echo on 10 | 11 | select dt2-dt1 , 12 | months_between(dt2,dt1) months_btwn, 13 | numtodsinterval(dt2-dt1,'day') days, 14 | numtoyminterval(trunc(months_between(dt2,dt1)),'month') months 15 | from (select to_date('29-feb-2000 01:02:03','dd-mon-yyyy hh24:mi:ss') dt1, 16 | to_date('15-mar-2001 11:22:33','dd-mon-yyyy hh24:mi:ss') dt2 17 | from dual ) 18 | / 19 | 20 | column years_months form a30 21 | column days_hours form a30 22 | 23 | select numtoyminterval 24 | (trunc(months_between(dt2,dt1)),'month') 25 | years_months, 26 | numtodsinterval 27 | (dt2-add_months( dt1, trunc(months_between(dt2,dt1)) ), 28 | 'day' ) 29 | days_hours 30 | from (select to_date('29-feb-2000 01:02:03','dd-mon-yyyy hh24:mi:ss') dt1, 31 | to_date('15-mar-2001 11:22:33','dd-mon-yyyy hh24:mi:ss') dt2 32 | from dual ) 33 | / 34 | -------------------------------------------------------------------------------- /scripts/ch12/demo19.sql: -------------------------------------------------------------------------------- 1 | -- TIMESTAMP 2 | 3 | drop table t purge; 4 | 5 | set echo on 6 | 7 | create table t 8 | ( dt date, 9 | ts timestamp(0) 10 | ) 11 | / 12 | 13 | insert into t values ( sysdate, systimestamp ); 14 | 15 | col dump form a45 16 | 17 | select dump(dt,10) dump, dump(ts,10) dump from t; 18 | -------------------------------------------------------------------------------- /scripts/ch12/demo20.sql: -------------------------------------------------------------------------------- 1 | -- TIMESTAMP, example 2 2 | 3 | drop table t purge; 4 | 5 | set echo on 6 | 7 | create table t 8 | ( dt date, 9 | ts timestamp(9) 10 | ) 11 | / 12 | 13 | insert into t values ( sysdate, systimestamp ); 14 | 15 | select dump(dt,10) dump, dump(ts,10) dump 16 | from t; 17 | 18 | alter session set nls_date_format = 'dd-mon-yyyy hh24:mi:ss'; 19 | 20 | select * from t; 21 | 22 | select dump(ts,16) dump from t; 23 | 24 | select * from t; 25 | select dump(ts,16) dump from t; 26 | 27 | select to_number('3537ac28', 'xxxxxxxx' ) from dual; 28 | 29 | select * from t; 30 | -------------------------------------------------------------------------------- /scripts/ch12/demo21.sql: -------------------------------------------------------------------------------- 1 | -- Adding or Subtracting Time to/from a TIMESTAMP 2 | 3 | set echo on 4 | 5 | alter session set nls_date_format = 'dd-mon-yyyy hh24:mi:ss'; 6 | 7 | col ts form a40 8 | col dt form a40 9 | select systimestamp ts, systimestamp+1 dt 10 | from dual; 11 | 12 | select systimestamp ts, systimestamp +numtodsinterval(1,'day') dt 13 | from dual; 14 | -------------------------------------------------------------------------------- /scripts/ch12/demo22.sql: -------------------------------------------------------------------------------- 1 | -- Getting the Difference Between Two TIMESTAMPs 2 | 3 | set echo on 4 | 5 | select dt2-dt1 6 | from (select to_timestamp('29-feb-2000 01:02:03.122000', 7 | 'dd-mon-yyyy hh24:mi:ss.ff') dt1, 8 | to_timestamp('15-mar-2001 11:22:33.000000', 9 | 'dd-mon-yyyy hh24:mi:ss.ff') dt2 10 | from dual ) 11 | / 12 | 13 | select numtoyminterval 14 | (trunc(months_between(dt2,dt1)),'month') 15 | years_months, 16 | dt2-add_months(dt1,trunc(months_between(dt2,dt1))) 17 | days_hours 18 | from (select to_timestamp('29-feb-2000 01:02:03.122000', 19 | 'dd-mon-yyyy hh24:mi:ss.ff') dt1, 20 | to_timestamp('15-mar-2001 11:22:33.000000', 21 | 'dd-mon-yyyy hh24:mi:ss.ff') dt2 22 | from dual ) 23 | / 24 | 25 | 26 | select numtoyminterval 27 | (trunc(months_between(dt2,dt1)),'month') 28 | years_months, 29 | dt2-(dt1 + numtoyminterval( trunc(months_between(dt2,dt1)),'month' )) 30 | days_hours 31 | from (select to_timestamp('29-feb-2000 01:02:03.122000', 32 | 'dd-mon-yyyy hh24:mi:ss.ff') dt1, 33 | to_timestamp('15-mar-2001 11:22:33.000000', 34 | 'dd-mon-yyyy hh24:mi:ss.ff') dt2 35 | from dual ) 36 | / 37 | 38 | -------------------------------------------------------------------------------- /scripts/ch12/demo23.sql: -------------------------------------------------------------------------------- 1 | -- TIMESTAMP WITH TIME ZONE Type 2 | 3 | drop table t purge; 4 | 5 | set echo on 6 | 7 | create table t 8 | ( 9 | ts timestamp, 10 | ts_tz timestamp with time zone 11 | ) 12 | / 13 | 14 | insert into t ( ts, ts_tz ) 15 | values ( systimestamp, systimestamp ); 16 | 17 | set lines 132 18 | col ts form a35 19 | col ts_tz form a35 20 | 21 | select * from t; 22 | 23 | col dump format a60 24 | 25 | select dump(ts) dump, dump(ts_tz) dump from t; 26 | -------------------------------------------------------------------------------- /scripts/ch12/demo24.sql: -------------------------------------------------------------------------------- 1 | -- TIMESTAMP WITH TIME ZONE Type, second example 2 | 3 | drop table t purge; 4 | 5 | set echo on 6 | 7 | create table t 8 | ( ts1 timestamp with time zone, 9 | ts2 timestamp with time zone 10 | ) 11 | / 12 | 13 | insert into t (ts1, ts2) 14 | values ( timestamp'2014-02-27 16:02:32.212 US/Eastern', 15 | timestamp'2014-02-27 16:02:32.212 US/Pacific' ); 16 | 17 | select ts1-ts2 from t; 18 | -------------------------------------------------------------------------------- /scripts/ch12/demo25.sql: -------------------------------------------------------------------------------- 1 | -- TIMESTAMP WITH LOCAL TIME ZONE Type 2 | 3 | drop table t purge; 4 | 5 | set echo on 6 | 7 | create table t 8 | ( dt date, 9 | ts1 timestamp with time zone, 10 | ts2 timestamp with local time zone 11 | ) 12 | / 13 | 14 | insert into t (dt, ts1, ts2) 15 | values ( timestamp'2014-02-27 16:02:32.212 US/Pacific', 16 | timestamp'2014-02-27 16:02:32.212 US/Pacific', 17 | timestamp'2014-02-27 16:02:32.212 US/Pacific' ); 18 | 19 | col dbtimezone form a12 20 | select dbtimezone from dual; 21 | 22 | select dump(dt), dump(ts1), dump(ts2) from t; 23 | -------------------------------------------------------------------------------- /scripts/ch12/demo26.sql: -------------------------------------------------------------------------------- 1 | -- INTERVAL Type 2 | 3 | set echo on 4 | 5 | select dt2-dt1 6 | from (select to_timestamp('29-feb-2000 01:02:03.122000', 7 | 'dd-mon-yyyy hh24:mi:ss.ff') dt1, 8 | to_timestamp('15-mar-2001 11:22:33.000000', 9 | 'dd-mon-yyyy hh24:mi:ss.ff') dt2 10 | from dual ) 11 | / 12 | 13 | select extract( day from dt2-dt1 ) day, 14 | extract( hour from dt2-dt1 ) hour, 15 | extract( minute from dt2-dt1 ) minute, 16 | extract( second from dt2-dt1 ) second 17 | from (select to_timestamp('29-feb-2000 01:02:03.122000', 18 | 'dd-mon-yyyy hh24:mi:ss.ff') dt1, 19 | to_timestamp('15-mar-2001 11:22:33.000000', 20 | 'dd-mon-yyyy hh24:mi:ss.ff') dt2 21 | from dual ) 22 | / 23 | 24 | 25 | -- INTERVAL YEAR TO MONTH 26 | 27 | select numtoyminterval(5,'year')+numtoyminterval(2,'month') from dual; 28 | select numtoyminterval(5*12+2,'month') from dual; 29 | select to_yminterval( '5-2' ) from dual; 30 | select interval '5-2' year to month from dual; 31 | 32 | -- INTERVAL DAY TO SECOND 33 | 34 | select numtodsinterval( 10, 'day' )+ 35 | numtodsinterval( 2, 'hour' )+ 36 | numtodsinterval( 3, 'minute' )+ 37 | numtodsinterval( 2.3312, 'second' ) 38 | from dual; 39 | 40 | select numtodsinterval( 10*86400+2*3600+3*60+2.3312, 'second' ) from dual; 41 | select to_dsinterval( '10 02:03:02.3312' ) from dual; 42 | select interval '10 02:03:02.3312' day to second from dual; 43 | -------------------------------------------------------------------------------- /scripts/ch12/demo27.sql: -------------------------------------------------------------------------------- 1 | -- Creating a SecureFiles LOB 2 | 3 | drop table t purge; 4 | 5 | set echo on 6 | 7 | create table t 8 | ( id int primary key, 9 | txt clob 10 | ) 11 | segment creation immediate 12 | / 13 | 14 | column column_name form a12 15 | column securefile form a12 16 | 17 | select column_name, securefile from user_lobs where table_name='T'; 18 | 19 | set long 10000 20 | select dbms_metadata.get_ddl( 'TABLE', 'T' ) from dual; 21 | 22 | col segment_name form a30 23 | col segment_type form a10 24 | 25 | select segment_name, segment_type from user_segments; 26 | -------------------------------------------------------------------------------- /scripts/ch12/demo28.sql: -------------------------------------------------------------------------------- 1 | -- IN ROW Clause 2 | 3 | drop table t purge; 4 | 5 | set echo on 6 | 7 | create table t 8 | ( id int primary key, 9 | in_row clob, 10 | out_row clob 11 | ) 12 | lob (in_row) store as ( enable storage in row ) 13 | lob (out_row) store as ( disable storage in row ) 14 | / 15 | 16 | insert into t 17 | select rownum, 18 | owner || ' ' || object_name || ' ' || object_type || ' ' || status, 19 | owner || ' ' || object_name || ' ' || object_type || ' ' || status 20 | from all_objects 21 | / 22 | 23 | commit; 24 | 25 | alter session set tracefile_identifier='tk'; 26 | EXEC DBMS_MONITOR.session_trace_enable; 27 | 28 | declare 29 | l_cnt number; 30 | l_data varchar2(32765); 31 | begin 32 | select count(*) 33 | into l_cnt 34 | from t; 35 | 36 | dbms_monitor.session_trace_enable; 37 | for i in 1 .. l_cnt 38 | loop 39 | select in_row into l_data from t where id = i; 40 | select out_row into l_data from t where id = i; 41 | end loop; 42 | end; 43 | / 44 | 45 | EXEC DBMS_MONITOR.session_trace_disable; 46 | -------------------------------------------------------------------------------- /scripts/ch12/demo29.sql: -------------------------------------------------------------------------------- 1 | -- IN ROW Clause, second example 2 | 3 | set echo on 4 | 5 | create sequence s start with 100000; 6 | 7 | alter session set tracefile_identifier='tk'; 8 | 9 | declare 10 | l_cnt number; 11 | l_data varchar2(32765); 12 | begin 13 | dbms_monitor.session_trace_enable; 14 | for i in 1 .. 100 15 | loop 16 | update t set in_row = 17 | to_char(sysdate,'dd-mon-yyyy hh24:mi:ss') where id = i; 18 | update t set out_row = 19 | to_char(sysdate,'dd-mon-yyyy hh24:mi:ss') where id = i; 20 | insert into t (id, in_row) values ( s.nextval, 'Hello World' ); 21 | insert into t (id,out_row) values ( s.nextval, 'Hello World' ); 22 | end loop; 23 | end; 24 | / 25 | 26 | EXEC DBMS_MONITOR.session_trace_disable; 27 | -------------------------------------------------------------------------------- /scripts/ch12/demo30.sql: -------------------------------------------------------------------------------- 1 | -- Read Consistency for LOBs 2 | 3 | drop table t purge; 4 | 5 | set echo on 6 | 7 | create table t 8 | ( id int primary key, 9 | txt clob 10 | ) 11 | lob( txt) store as ( disable storage in row ) 12 | / 13 | 14 | insert into t values ( 1, 'hello world' ); 15 | 16 | commit; 17 | 18 | declare 19 | l_clob clob; 20 | cursor c is select id from t; 21 | l_id number; 22 | begin 23 | select txt into l_clob from t; 24 | open c; 25 | update t set id = 2, txt = 'Goodbye'; 26 | commit; 27 | dbms_output.put_line( dbms_lob.substr( l_clob, 100, 1 ) ); 28 | fetch c into l_id; 29 | dbms_output.put_line( 'id = ' || l_id ); 30 | close c; 31 | end; 32 | / 33 | 34 | select * from t; 35 | -------------------------------------------------------------------------------- /scripts/ch12/demo31.sql: -------------------------------------------------------------------------------- 1 | -- BFILEs 2 | 3 | drop table t purge; 4 | 5 | set echo on 6 | 7 | create table t 8 | ( id int primary key, 9 | os_file bfile 10 | ) 11 | / 12 | -------------------------------------------------------------------------------- /scripts/ch13/demo01.sql: -------------------------------------------------------------------------------- 1 | -- Increased Availability 2 | 3 | drop table emp purge; 4 | 5 | set echo on 6 | 7 | -- This example uses Oracle Managed Files, adjust if you don't use OMF. 8 | 9 | alter system set db_create_file_dest='/u01/dbfile/ORA12CR1'; 10 | 11 | drop tablespace p1 including contents and datafiles; 12 | drop tablespace p2 including contents and datafiles; 13 | 14 | create tablespace p1 datafile size 1m autoextend on next 1m; 15 | create tablespace p2 datafile size 1m autoextend on next 1m; 16 | 17 | CREATE TABLE emp 18 | ( empno int, 19 | ename varchar2(20) 20 | ) 21 | PARTITION BY HASH (empno) 22 | ( partition part_1 tablespace p1, 23 | partition part_2 tablespace p2 24 | ) 25 | / 26 | 27 | insert into emp select empno, ename from scott.emp; 28 | 29 | select * from emp partition(part_1); 30 | select * from emp partition(part_2); 31 | 32 | alter tablespace p1 offline; 33 | select * from emp; 34 | 35 | variable n number 36 | exec :n := 7844; 37 | select * from emp where empno = :n; 38 | 39 | alter tablespace p1 online; 40 | -------------------------------------------------------------------------------- /scripts/ch13/demo03.sql: -------------------------------------------------------------------------------- 1 | -- Range Partitioning 2 | 3 | drop table range_example purge; 4 | 5 | set echo on 6 | 7 | CREATE TABLE range_example 8 | ( range_key_column date NOT NULL, 9 | data varchar2(20) 10 | ) 11 | PARTITION BY RANGE (range_key_column) 12 | ( PARTITION part_1 VALUES LESS THAN 13 | (to_date('01/01/2014','dd/mm/yyyy')), 14 | PARTITION part_2 VALUES LESS THAN 15 | (to_date('01/01/2015','dd/mm/yyyy')) 16 | ) 17 | / 18 | 19 | insert into range_example 20 | ( range_key_column, data ) 21 | values 22 | ( to_date( '15-dec-2013 00:00:00', 23 | 'dd-mon-yyyy hh24:mi:ss' ), 24 | 'application data...' ); 25 | 26 | insert into range_example 27 | ( range_key_column, data ) 28 | values 29 | ( to_date( '31-dec-2013 23:59:59', 30 | 'dd-mon-yyyy hh24:mi:ss' ), 31 | 'application data...' ); 32 | 33 | insert into range_example 34 | ( range_key_column, data ) 35 | values 36 | ( to_date( '01-jan-2014 00:00:00', 37 | 'dd-mon-yyyy hh24:mi:ss' ), 38 | 'application data...' ); 39 | 40 | insert into range_example 41 | ( range_key_column, data ) 42 | values 43 | ( to_date( '31-dec-2014 23:59:59', 44 | 'dd-mon-yyyy hh24:mi:ss' ), 45 | 'application data...' ); 46 | 47 | -- should throw an error 48 | insert into range_example 49 | ( range_key_column, data ) 50 | values 51 | ( to_date( '01-jan-2015 00:00:00', 52 | 'dd-mon-yyyy hh24:mi:ss' ), 53 | 'application data...' ); 54 | 55 | select to_char(range_key_column,'dd-mon-yyyy hh24:mi:ss') 56 | from range_example partition (part_1); 57 | 58 | select to_char(range_key_column,'dd-mon-yyyy hh24:mi:ss') 59 | from range_example partition (part_2); 60 | 61 | drop table range_example purge; 62 | 63 | CREATE TABLE range_example 64 | ( range_key_column date , 65 | data varchar2(20) 66 | ) 67 | PARTITION BY RANGE (range_key_column) 68 | ( PARTITION part_1 VALUES LESS THAN 69 | (to_date('01/01/2014','dd/mm/yyyy')), 70 | PARTITION part_2 VALUES LESS THAN 71 | (to_date('01/01/2015','dd/mm/yyyy')), 72 | PARTITION part_3 VALUES LESS THAN 73 | (MAXVALUE) 74 | ) 75 | / 76 | -------------------------------------------------------------------------------- /scripts/ch13/demo05.sql: -------------------------------------------------------------------------------- 1 | -- List Partitioning 2 | 3 | drop table list_example purge; 4 | 5 | set echo on 6 | 7 | create table list_example 8 | ( state_cd varchar2(2), 9 | data varchar2(20) 10 | ) 11 | partition by list(state_cd) 12 | ( partition part_1 values ( 'ME', 'NH', 'VT', 'MA' ), 13 | partition part_2 values ( 'CT', 'RI', 'NY' ) 14 | ) 15 | / 16 | 17 | insert into list_example (state_cd, data) 18 | values ('CT', 'application data...'); 19 | insert into list_example (state_cd, data) 20 | values ('MA', 'application data...'); 21 | insert into list_example (state_cd, data) 22 | values ('ME', 'application data...'); 23 | insert into list_example (state_cd, data) 24 | values ('NH', 'application data...'); 25 | insert into list_example (state_cd, data) 26 | values ('NY', 'application data...'); 27 | insert into list_example (state_cd, data) 28 | values ('RI', 'application data...'); 29 | insert into list_example (state_cd, data) 30 | values ('VT', 'application data...'); 31 | 32 | insert into list_example values ( 'VA', 'data' ); 33 | 34 | alter table list_example 35 | add partition 36 | part_3 values ( DEFAULT ); 37 | 38 | insert into list_example values ( 'VA', 'data' ); 39 | 40 | alter table list_example 41 | add partition 42 | part_4 values( 'CA', 'NM' ); 43 | -------------------------------------------------------------------------------- /scripts/ch13/demo08.sql: -------------------------------------------------------------------------------- 1 | -- Interval Reference partitioning 2 | 3 | drop table order_line_items; 4 | drop table orders; 5 | 6 | set echo on 7 | 8 | create table orders 9 | (order# number primary key, 10 | order_date timestamp, 11 | data varchar2(30)) 12 | PARTITION BY RANGE (order_date) 13 | INTERVAL (numtoyminterval(1,'year')) 14 | (PARTITION part_2014 VALUES LESS THAN (to_date('01-01-2015','dd-mm-yyyy')) , 15 | PARTITION part_2015 VALUES LESS THAN (to_date('01-01-2016','dd-mm-yyyy'))); 16 | 17 | create table order_line_items 18 | ( order# number, 19 | line# number, 20 | data varchar2(30), 21 | constraint c1_pk primary key(order#,line#), 22 | constraint c1_fk_p foreign key(order#) references orders) 23 | partition by reference(c1_fk_p); 24 | 25 | insert into orders values (1, to_date('01-jun-2014', 'dd-mon-yyyy'), 'xxx'); 26 | insert into orders values (2, to_date('01-jun-2015', 'dd-mon-yyyy'), 'xxx'); 27 | insert into order_line_items values (1, 1, 'yyy'); 28 | insert into order_line_items values (2, 1, 'yyy'); 29 | 30 | column table_name format a25 31 | column partition_name format a20 32 | 33 | select table_name, partition_name from user_tab_partitions 34 | where table_name in ( 'ORDERS', 'ORDER_LINE_ITEMS' ) 35 | order by table_name, partition_name; 36 | 37 | insert into orders values (3, to_date( '01-jun-2016', 'dd-mon-yyyy' ), 'xxx'); 38 | insert into order_line_items values (3, 1, 'yyy'); 39 | 40 | column partition_name format a10 41 | column table_name format a16 42 | column interval format a25 43 | column high_value format a31 44 | 45 | select a.table_name, a.partition_name, a.high_value, 46 | decode( a.interval, 'YES', b.interval ) interval 47 | from user_tab_partitions a, user_part_tables b 48 | where a.table_name IN ('ORDERS', 'ORDER_LINE_ITEMS') 49 | and a.table_name = b.table_name 50 | order by a.table_name; 51 | -------------------------------------------------------------------------------- /scripts/ch13/demo09.sql: -------------------------------------------------------------------------------- 1 | -- Virtual Column Partitioning 2 | 3 | drop table res purge; 4 | 5 | set echo on 6 | 7 | create table res(reservation_code varchar2(30)); 8 | 9 | insert into res 10 | select chr(64+(round(dbms_random.value(1,4)))) || level 11 | from dual connect by level < 100000; 12 | 13 | drop table res; 14 | 15 | create table res( 16 | reservation_code varchar2(30), 17 | region as (substr(reservation_code,1,1)) 18 | ) 19 | partition by list (region) 20 | (partition p1 values('A'), 21 | partition p2 values('B'), 22 | partition p3 values('C'), 23 | partition p4 values('D')); 24 | 25 | create index r1 on res(reservation_code) local; 26 | 27 | insert into res (reservation_code) 28 | select chr(64+(round(dbms_random.value(1,4)))) || level 29 | from dual connect by level < 100000; 30 | 31 | exec dbms_stats.gather_table_stats(user,'RES'); 32 | 33 | explain plan for select count(*) from res where reservation_code='A'; 34 | select * from table(dbms_xplan.display(null, null, 'BASIC +PARTITION')); 35 | -------------------------------------------------------------------------------- /scripts/ch13/demo10.sql: -------------------------------------------------------------------------------- 1 | -- Composite Partitioning 2 | 3 | drop table composite_example; 4 | 5 | set echo on 6 | 7 | CREATE TABLE composite_example 8 | ( range_key_column date, 9 | hash_key_column int, 10 | data varchar2(20) 11 | ) 12 | PARTITION BY RANGE (range_key_column) 13 | subpartition by hash(hash_key_column) subpartitions 2 14 | ( 15 | PARTITION part_1 16 | VALUES LESS THAN(to_date('01/01/2014','dd/mm/yyyy')) 17 | (subpartition part_1_sub_1, 18 | subpartition part_1_sub_2 19 | ), 20 | PARTITION part_2 21 | VALUES LESS THAN(to_date('01/01/2015','dd/mm/yyyy')) 22 | (subpartition part_2_sub_1, 23 | subpartition part_2_sub_2 24 | ) 25 | ) 26 | / 27 | 28 | insert into composite_example 29 | ( range_key_column, hash_key_column, data ) 30 | values 31 | ( to_date('23-feb-2013','dd-mon-yyyy'),123,'app data' ); 32 | 33 | insert into composite_example 34 | ( range_key_column, hash_key_column, data ) 35 | values 36 | ( to_date('27-feb-2014','dd-mon-yyyy'),456,'app data' ); 37 | 38 | drop table composite_range_list_example; 39 | 40 | CREATE TABLE composite_range_list_example 41 | ( range_key_column date, 42 | code_key_column int, 43 | data varchar2(20) 44 | ) 45 | PARTITION BY RANGE (range_key_column) 46 | subpartition by list(code_key_column) 47 | ( 48 | PARTITION part_1 49 | VALUES LESS THAN(to_date('01/01/2014','dd/mm/yyyy')) 50 | (subpartition part_1_sub_1 values( 1, 3, 5, 7 ), 51 | subpartition part_1_sub_2 values( 2, 4, 6, 8 ) 52 | ), 53 | PARTITION part_2 54 | VALUES LESS THAN(to_date('01/01/2015','dd/mm/yyyy')) 55 | (subpartition part_2_sub_1 values ( 1, 3 ), 56 | subpartition part_2_sub_2 values ( 5, 7 ), 57 | subpartition part_2_sub_3 values ( 2, 4, 6, 8 ) 58 | ) 59 | ) 60 | / 61 | 62 | -------------------------------------------------------------------------------- /scripts/ch13/demo11.sql: -------------------------------------------------------------------------------- 1 | -- Row Movement 2 | 3 | drop table range_example purge; 4 | 5 | set echo on 6 | 7 | CREATE TABLE range_example 8 | ( range_key_column date , 9 | data varchar2(20) 10 | ) 11 | PARTITION BY RANGE (range_key_column) 12 | ( PARTITION part_1 VALUES LESS THAN 13 | (to_date('01/01/2014','dd/mm/yyyy')), 14 | PARTITION part_2 VALUES LESS THAN 15 | (to_date('01/01/2015','dd/mm/yyyy')) 16 | ) 17 | / 18 | 19 | insert into range_example 20 | ( range_key_column, data ) 21 | values 22 | ( to_date( '15-dec-2013 00:00:00', 23 | 'dd-mon-yyyy hh24:mi:ss' ), 24 | 'application data...' ); 25 | 26 | insert into range_example 27 | ( range_key_column, data ) 28 | values 29 | ( to_date( '01-jan-2014 00:00:00', 30 | 'dd-mon-yyyy hh24:mi:ss' )-1/24/60/60, 31 | 'application data...' ); 32 | 33 | select * from range_example partition(part_1); 34 | 35 | update range_example 36 | set range_key_column = trunc(range_key_column) 37 | where range_key_column = 38 | to_date( '31-dec-2013 23:59:59', 39 | 'dd-mon-yyyy hh24:mi:ss' ); 40 | 41 | update range_example 42 | set range_key_column = to_date('01-jan-2014','dd-mon-yyyy') 43 | where range_key_column = to_date('31-dec-2013','dd-mon-yyyy'); 44 | 45 | select rowid 46 | from range_example 47 | where range_key_column = to_date('31-dec-2013','dd-mon-yyyy'); 48 | 49 | alter table range_example enable row movement; 50 | 51 | update range_example 52 | set range_key_column = to_date('01-jan-2014','dd-mon-yyyy') 53 | where range_key_column = to_date('31-dec-2013','dd-mon-yyyy'); 54 | 55 | select rowid 56 | from range_example 57 | where range_key_column = to_date('01-jan-2014','dd-mon-yyyy'); 58 | -------------------------------------------------------------------------------- /scripts/ch13/demo12.sql: -------------------------------------------------------------------------------- 1 | -- Partition Elimination Behavior 2 | 3 | drop table partitioned_table purge; 4 | 5 | set echo on 6 | 7 | CREATE TABLE partitioned_table 8 | ( a int, 9 | b int, 10 | data char(20) 11 | ) 12 | PARTITION BY RANGE (a) 13 | ( 14 | PARTITION part_1 VALUES LESS THAN(2) tablespace p1, 15 | PARTITION part_2 VALUES LESS THAN(3) tablespace p2 16 | ) 17 | / 18 | 19 | create index local_prefixed on partitioned_table (a,b) local; 20 | create index local_nonprefixed on partitioned_table (b) local; 21 | 22 | insert into partitioned_table 23 | select mod(rownum-1,2)+1, rownum, 'x' 24 | from dual connect by level <= 70000; 25 | 26 | begin 27 | dbms_stats.gather_table_stats 28 | ( user, 29 | 'PARTITIONED_TABLE', 30 | cascade=>TRUE ); 31 | end; 32 | / 33 | 34 | alter tablespace p2 offline; 35 | 36 | select * from partitioned_table where a = 1 and b = 1; 37 | explain plan for select * from partitioned_table where a = 1 and b = 1; 38 | set lines 132 39 | select * from table(dbms_xplan.display(null,null,'BASIC +PARTITION')); 40 | 41 | explain plan for select * from partitioned_table where b = 1; 42 | select * from table(dbms_xplan.display(null,null,'BASIC +PARTITION')); 43 | 44 | drop index local_prefixed; 45 | 46 | explain plan for select * from partitioned_table where a = 1 and b = 1; 47 | select * from table(dbms_xplan.display(null,null,'BASIC +PARTITION')); 48 | 49 | alter tablespace p2 online; 50 | -------------------------------------------------------------------------------- /scripts/ch13/demo13.sql: -------------------------------------------------------------------------------- 1 | -- Local Indexes and Unique Constraints 2 | 3 | drop table partitioned purge; 4 | 5 | set echo on 6 | 7 | CREATE TABLE partitioned 8 | ( timestamp date, 9 | id int, 10 | constraint partitioned_pk primary key(id) 11 | ) 12 | PARTITION BY RANGE (timestamp) 13 | ( 14 | PARTITION part_1 VALUES LESS THAN 15 | ( to_date('01/01/2014','dd/mm/yyyy') ) , 16 | PARTITION part_2 VALUES LESS THAN 17 | ( to_date('01/01/2015','dd/mm/yyyy') ) 18 | ) 19 | / 20 | 21 | 22 | insert into partitioned values(to_date('01/01/2013','dd/mm/yyyy'),1); 23 | insert into partitioned values(to_date('01/01/2014','dd/mm/yyyy'),2); 24 | 25 | column segment_name format a25 26 | column partition_name format a25 27 | column segment_type form a15 28 | 29 | select segment_name, partition_name, segment_type 30 | from user_segments; 31 | 32 | drop table partitioned purge; 33 | 34 | CREATE TABLE partitioned 35 | ( timestamp date, 36 | id int 37 | ) 38 | PARTITION BY RANGE (timestamp) 39 | ( 40 | PARTITION part_1 VALUES LESS THAN 41 | ( to_date('01-jan-2014','dd-mon-yyyy') ) , 42 | PARTITION part_2 VALUES LESS THAN 43 | ( to_date('01-jan-2015','dd-mon-yyyy') ) 44 | ) 45 | / 46 | 47 | create index partitioned_idx on partitioned(id) local; 48 | 49 | insert into partitioned values(to_date('01/01/2013','dd/mm/yyyy'),1); 50 | insert into partitioned values(to_date('01/01/2014','dd/mm/yyyy'),2); 51 | 52 | select segment_name, partition_name, segment_type 53 | from user_segments; 54 | 55 | alter table partitioned 56 | add constraint 57 | partitioned_pk 58 | primary key(id) 59 | / 60 | -------------------------------------------------------------------------------- /scripts/ch13/demo14.sql: -------------------------------------------------------------------------------- 1 | -- Global Indexes 2 | 3 | drop table partitioned purge; 4 | 5 | set echo on 6 | 7 | CREATE TABLE partitioned 8 | ( timestamp date, 9 | id int 10 | ) 11 | PARTITION BY RANGE (timestamp) 12 | ( 13 | PARTITION part_1 VALUES LESS THAN 14 | ( to_date('01-jan-2014','dd-mon-yyyy') ) , 15 | PARTITION part_2 VALUES LESS THAN 16 | ( to_date('01-jan-2015','dd-mon-yyyy') ) 17 | ) 18 | / 19 | 20 | create index partitioned_index 21 | on partitioned(id) 22 | GLOBAL 23 | partition by range(id) 24 | ( 25 | partition part_1 values less than(1000), 26 | partition part_2 values less than (MAXVALUE) 27 | ) 28 | / 29 | 30 | alter table partitioned add constraint 31 | partitioned_pk 32 | primary key(id) 33 | / 34 | 35 | -- should throw an error 36 | drop index partitioned_index; 37 | 38 | -- should throw an error 39 | create index partitioned_index2 40 | on partitioned(timestamp,id) 41 | GLOBAL 42 | partition by range(id) 43 | ( 44 | partition part_1 values less than(1000), 45 | partition part_2 values less than (MAXVALUE) 46 | ) 47 | / 48 | -------------------------------------------------------------------------------- /scripts/ch13/demo17.sql: -------------------------------------------------------------------------------- 1 | -- Asynchronous Global Index Maintenance 2 | 3 | drop table partitioned purge; 4 | 5 | set echo on 6 | 7 | CREATE TABLE partitioned 8 | ( timestamp date, 9 | id int 10 | ) 11 | PARTITION BY RANGE (timestamp) 12 | (PARTITION fy_2014 VALUES LESS THAN 13 | (to_date('01-jan-2015','dd-mon-yyyy')), 14 | PARTITION fy_2015 VALUES LESS THAN 15 | (to_date('01-jan-2016','dd-mon-yyyy'))); 16 | 17 | insert into partitioned partition(fy_2014) 18 | select to_date('31-dec-2014','dd-mon-yyyy')-mod(rownum,364), rownum 19 | from dual connect by level < 100000; 20 | 21 | insert into partitioned partition(fy_2015) 22 | select to_date('31-dec-2015','dd-mon-yyyy')-mod(rownum,364), rownum 23 | from dual connect by level < 100000; 24 | 25 | create index partitioned_idx_global 26 | on partitioned(timestamp) 27 | GLOBAL; 28 | 29 | col r1 new_value r2 30 | col b1 new_value b2 31 | select * from 32 | (select b.value r1 33 | from v$statname a, v$mystat b 34 | where a.statistic# = b.statistic# 35 | and a.name = 'redo size'), 36 | (select b.value b1 37 | from v$statname a, v$mystat b 38 | where a.statistic# = b.statistic# 39 | and a.name = 'db block gets'); 40 | 41 | alter table partitioned drop partition fy_2014 update global indexes; 42 | 43 | select * from 44 | (select b.value - &r2 redo_gen 45 | from v$statname a, v$mystat b 46 | where a.statistic# = b.statistic# 47 | and a.name = 'redo size'), 48 | (select b.value - &b2 db_block_gets 49 | from v$statname a, v$mystat b 50 | where a.statistic# = b.statistic# 51 | and a.name = 'db block gets'); 52 | 53 | column index_name format a25 54 | 55 | select index_name, orphaned_entries, status from user_indexes 56 | where table_name='PARTITIONED'; 57 | 58 | exec dbms_part.cleanup_gidx; 59 | -------------------------------------------------------------------------------- /scripts/ch13/demo19.sql: -------------------------------------------------------------------------------- 1 | -- Partial Indexes 2 | 3 | drop table p_table purge; 4 | 5 | set echo on 6 | 7 | CREATE TABLE p_table (a int) 8 | PARTITION BY RANGE (a) 9 | (PARTITION part_1 VALUES LESS THAN(1000) INDEXING ON, 10 | PARTITION part_2 VALUES LESS THAN(2000) INDEXING OFF); 11 | 12 | create index pi1 on p_table(a) local indexing partial; 13 | 14 | col index_name form a25 15 | col partition_name form a25 16 | 17 | select a.index_name, a.partition_name, a.status 18 | from user_ind_partitions a, user_indexes b 19 | where b.table_name = 'P_TABLE' 20 | and a.index_name = b.index_name; 21 | 22 | insert into p_table select rownum from dual connect by level < 2000; 23 | 24 | exec dbms_stats.gather_table_stats(user,'P_TABLE'); 25 | 26 | explain plan for select * from p_table where a = 20; 27 | select * from table(dbms_xplan.display(null,null,'BASIC +PARTITION')); 28 | 29 | explain plan for select * from p_table where a = 1500; 30 | select * from table(dbms_xplan.display(null,null,'BASIC +PARTITION')); 31 | 32 | alter index pi1 rebuild partition part_2; 33 | 34 | explain plan for select * from p_table where a = 1500; 35 | select * from table(dbms_xplan.display(null,null,'BASIC +PARTITION')); 36 | -------------------------------------------------------------------------------- /scripts/ch13/demo20.sql: -------------------------------------------------------------------------------- 1 | -- Partitioning and Performance, Revisited 2 | 3 | drop table t purge; 4 | 5 | set echo on 6 | 7 | create table t 8 | ( OWNER, OBJECT_NAME, SUBOBJECT_NAME, OBJECT_ID, DATA_OBJECT_ID, 9 | OBJECT_TYPE, CREATED, LAST_DDL_TIME, TIMESTAMP, STATUS, 10 | TEMPORARY, GENERATED, SECONDARY ) 11 | /* 12 | partition by hash(object_id) 13 | partitions 16 14 | */ 15 | as 16 | select OWNER, OBJECT_NAME, SUBOBJECT_NAME, OBJECT_ID, DATA_OBJECT_ID, 17 | OBJECT_TYPE, CREATED, LAST_DDL_TIME, TIMESTAMP, STATUS, 18 | TEMPORARY, GENERATED, SECONDARY 19 | from all_objects; 20 | 21 | create index t_idx 22 | on t(owner,object_type,object_name) 23 | /* 24 | LOCAL 25 | */ 26 | / 27 | 28 | 29 | exec dbms_stats.gather_table_stats( user, 'T' ); 30 | 31 | exec dbms_monitor.session_trace_enable; 32 | 33 | variable o varchar2(30) 34 | variable t varchar2(30) 35 | variable n varchar2(30) 36 | 37 | exec :o := 'SCOTT'; :t := 'TABLE'; :n := 'EMP'; 38 | 39 | select * 40 | from t 41 | where owner = :o 42 | and object_type = :t 43 | and object_name = :n 44 | / 45 | select * 46 | from t 47 | where owner = :o 48 | and object_type = :t 49 | / 50 | select * 51 | from t 52 | where owner = :o 53 | / 54 | 55 | exec dbms_monitor.session_trace_disable; 56 | @tk "sys=no" 57 | 58 | drop index t_idx 59 | 60 | create index t_idx 61 | on t(owner,object_type,object_name) 62 | global 63 | partition by hash(owner) 64 | partitions 16 65 | / 66 | 67 | exec dbms_monitor.session_trace_enable; 68 | 69 | variable o varchar2(30) 70 | variable t varchar2(30) 71 | variable n varchar2(30) 72 | 73 | exec :o := 'SCOTT'; :t := 'TABLE'; :n := 'EMP'; 74 | 75 | select * 76 | from t 77 | where owner = :o 78 | and object_type = :t 79 | and object_name = :n 80 | / 81 | select * 82 | from t 83 | where owner = :o 84 | and object_type = :t 85 | / 86 | select * 87 | from t 88 | where owner = :o 89 | / 90 | 91 | exec dbms_monitor.session_trace_disable; 92 | @tk "sys=no" 93 | -------------------------------------------------------------------------------- /scripts/ch13/demo21.sql: -------------------------------------------------------------------------------- 1 | -- USING ORDER BY 2 | 3 | drop table t purge; 4 | 5 | set echo on 6 | 7 | create table t 8 | as 9 | select * 10 | from all_users 11 | / 12 | 13 | create index t_idx 14 | on t(user_id) 15 | global 16 | partition by hash(user_id) 17 | partitions 4 18 | / 19 | 20 | set autotrace on explain 21 | select /*+ index( t t_idx ) */ user_id 22 | from t 23 | where user_id > 0 24 | / 25 | 26 | set autotrace off 27 | 28 | -------------------------------------------------------------------------------- /scripts/ch13/demo23.sql: -------------------------------------------------------------------------------- 1 | -- Cascade Truncate 2 | 3 | drop table order_line_items purge; 4 | drop table orders purge; 5 | 6 | set echo on 7 | 8 | create table orders 9 | ( 10 | order# number primary key, 11 | order_date date, 12 | data varchar2(30) 13 | ) 14 | PARTITION BY RANGE (order_date) 15 | ( 16 | PARTITION part_2014 VALUES LESS THAN (to_date('01-01-2015','dd-mm-yyyy')) , 17 | PARTITION part_2015 VALUES LESS THAN (to_date('01-01-2016','dd-mm-yyyy')) 18 | ) 19 | / 20 | 21 | insert into orders values 22 | ( 1, to_date( '01-jun-2014', 'dd-mon-yyyy' ), 'xyz' ); 23 | 24 | insert into orders values 25 | ( 2, to_date( '01-jun-2015', 'dd-mon-yyyy' ), 'xyz' ); 26 | 27 | create table order_line_items 28 | ( 29 | order# number, 30 | line# number, 31 | data varchar2(30), 32 | constraint c1_pk primary key(order#,line#), 33 | constraint c1_fk_p foreign key(order#) references orders on delete cascade 34 | ) partition by reference(c1_fk_p) 35 | / 36 | 37 | insert into order_line_items values ( 1, 1, 'yyy' ); 38 | insert into order_line_items values ( 2, 1, 'yyy' ); 39 | 40 | alter table orders truncate partition PART_2014 cascade; 41 | -------------------------------------------------------------------------------- /scripts/ch13/demo24.sql: -------------------------------------------------------------------------------- 1 | -- Cascade Exchange 2 | 3 | drop table c_2016 purge; 4 | drop table part_2016 purge; 5 | 6 | drop table order_line_items purge; 7 | drop table orders purge; 8 | 9 | set echo on 10 | 11 | create table orders 12 | ( order# number primary key, 13 | order_date date, 14 | data varchar2(30)) 15 | PARTITION BY RANGE (order_date) 16 | (PARTITION part_2014 VALUES LESS THAN (to_date('01-01-2015','dd-mm-yyyy')) , 17 | PARTITION part_2015 VALUES LESS THAN (to_date('01-01-2016','dd-mm-yyyy'))); 18 | 19 | insert into orders values (1, to_date( '01-jun-2014', 'dd-mon-yyyy' ), 'xyz'); 20 | insert into orders values (2, to_date( '01-jun-2015', 'dd-mon-yyyy' ), 'xyz'); 21 | 22 | create table order_line_items 23 | (order# number, 24 | line# number, 25 | data varchar2(30), 26 | constraint c1_pk primary key(order#,line#), 27 | constraint c1_fk_p foreign key(order#) references orders 28 | ) partition by reference(c1_fk_p); 29 | 30 | insert into order_line_items values ( 1, 1, 'yyy' ); 31 | insert into order_line_items values ( 2, 1, 'yyy' ); 32 | 33 | alter table orders add partition part_2016 34 | values less than (to_date('01-01-2017','dd-mm-yyyy')); 35 | 36 | create table part_2016 37 | ( order# number primary key, 38 | order_date date, 39 | data varchar2(30)); 40 | 41 | insert into part_2016 values (3, to_date('01-jun-2016', 'dd-mon-yyyy' ), 'xyz'); 42 | 43 | create table c_2016 44 | (order# number, 45 | line# number, 46 | data varchar2(30), 47 | constraint ce1_pk primary key(order#,line#), 48 | constraint ce1_fk_p foreign key(order#) references part_2016); 49 | 50 | insert into c_2016 values(3, 1, 'xyz'); 51 | 52 | alter table orders 53 | exchange partition part_2016 54 | with table part_2016 55 | without validation 56 | CASCADE 57 | update global indexes; 58 | -------------------------------------------------------------------------------- /scripts/ch14/big_table.ctl: -------------------------------------------------------------------------------- 1 | LOAD DATA 2 | INFILE '/tmp/big_table.dat' 3 | INTO TABLE big_table 4 | REPLACE 5 | FIELDS TERMINATED BY '|' 6 | ( id ,owner ,object_name ,subobject_name ,object_id 7 | ,data_object_id ,object_type ,created ,last_ddl_time 8 | ,timestamp ,status ,temporary ,generated ,secondary 9 | ,namespace ,edition_name 10 | ) 11 | -------------------------------------------------------------------------------- /scripts/ch14/big_table.sql: -------------------------------------------------------------------------------- 1 | drop table big_table_et; 2 | 3 | CREATE TABLE BIG_TABLE_ET 4 | ( 5 | "ID" NUMBER, 6 | "OWNER" VARCHAR2(128), 7 | "OBJECT_NAME" VARCHAR2(128), 8 | "SUBOBJECT_NAME" VARCHAR2(128), 9 | "OBJECT_ID" NUMBER, 10 | "DATA_OBJECT_ID" NUMBER, 11 | "OBJECT_TYPE" VARCHAR2(23) 12 | ) 13 | ORGANIZATION external 14 | ( 15 | TYPE oracle_loader 16 | DEFAULT DIRECTORY dir2 17 | ACCESS PARAMETERS 18 | ( 19 | RECORDS DELIMITED BY NEWLINE CHARACTERSET US7ASCII 20 | READSIZE 1048576 21 | FIELDS TERMINATED BY "|" LDRTRIM 22 | REJECT ROWS WITH ALL NULL FIELDS 23 | ( 24 | "ID" CHAR(255) 25 | TERMINATED BY "|", 26 | "OWNER" CHAR(255) 27 | TERMINATED BY "|", 28 | "OBJECT_NAME" CHAR(255) 29 | TERMINATED BY "|", 30 | "SUBOBJECT_NAME" CHAR(255) 31 | TERMINATED BY "|", 32 | "OBJECT_ID" CHAR(255) 33 | TERMINATED BY "|", 34 | "DATA_OBJECT_ID" CHAR(255) 35 | TERMINATED BY "|", 36 | "OBJECT_TYPE" CHAR(255) 37 | TERMINATED BY "|" 38 | ) 39 | ) 40 | location 41 | ( 42 | 'big_table.dat' 43 | ) 44 | )REJECT LIMIT UNLIMITED parallel; 45 | -------------------------------------------------------------------------------- /scripts/ch14/demo01.sql: -------------------------------------------------------------------------------- 1 | -- Parallel Query 2 | 3 | set echo on 4 | 5 | select count(status) from big_table; 6 | 7 | explain plan for select count(status) from big_table; 8 | 9 | select * from table(dbms_xplan.display(null, null, 10 | 'TYPICAL -ROWS -BYTES -COST')); 11 | 12 | alter table big_table parallel 4; 13 | alter table big_table parallel; 14 | 15 | explain plan for select count(status) from big_table; 16 | 17 | select * from table(dbms_xplan.display(null, null, 18 | 'TYPICAL -ROWS -BYTES -COST')); 19 | 20 | select sid from v$mystat where rownum = 1; 21 | 22 | select sid, qcsid, server#, degree 23 | from v$px_session 24 | where qcsid = 258 25 | / 26 | 27 | select sid, username, program 28 | from v$session 29 | where sid in ( select sid 30 | from v$px_session 31 | where qcsid = 258 ) 32 | / 33 | 34 | 35 | -------------------------------------------------------------------------------- /scripts/ch14/demo02.sql: -------------------------------------------------------------------------------- 1 | -- Parallel DML 2 | 3 | set echo on 4 | 5 | alter session enable parallel dml; 6 | 7 | select pdml_enabled from v$session 8 | where sid= sys_context('userenv','sid'); 9 | 10 | update big_table set status = 'done'; 11 | 12 | column program format a30 13 | column trans_id form a20 14 | 15 | select a.sid, a.program, b.start_time, b.used_ublk, 16 | b.xidusn ||'.'|| b.xidslot || '.' || b.xidsqn trans_id 17 | from v$session a, v$transaction b 18 | where a.taddr = b.addr 19 | and a.sid in ( select sid 20 | from v$px_session 21 | where qcsid = 258) 22 | order by sid 23 | / 24 | 25 | explain plan for update big_table set status = 'done'; 26 | select * from table(dbms_xplan.display(null,null,'BASIC +PARALLEL')); 27 | 28 | select name, value from v$statname a, v$mystat b 29 | where a.statistic# = b.statistic# and name like '%parallel%'; 30 | -------------------------------------------------------------------------------- /scripts/ch14/demo03.sql: -------------------------------------------------------------------------------- 1 | -- Parallel DDL and Data Loading Using External Tables 2 | 3 | drop table user_info purge; 4 | drop table new_table purge; 5 | 6 | set echo on; 7 | 8 | create table user_info as select * from all_users; 9 | 10 | alter table user_info parallel; 11 | 12 | exec dbms_stats.gather_table_stats( user, 'USER_INFO' ); 13 | 14 | create table new_table parallel 15 | as 16 | select a.*, b.user_id, b.created user_created 17 | from big_table a, user_info b 18 | where a.owner = b.username; 19 | 20 | explain plan for 21 | create table new_table parallel 22 | as 23 | select a.*, b.user_id, b.created user_created 24 | from big_table a, user_info b 25 | where a.owner = b.username; 26 | 27 | select * from table(dbms_xplan.display(null,null,'TYPICAL -COST -ROWS -BYTES')); 28 | -------------------------------------------------------------------------------- /scripts/ch14/demo04.sql: -------------------------------------------------------------------------------- 1 | -- Setting Up for Locally-Managed Tablespaces 2 | -- Run from command line: 3 | -- sqlldr eoda/foo big_table.ctl external_table=generate_only 4 | -- 5 | 6 | create or replace directory my_dir as '/tmp/'; 7 | 8 | drop table big_table_et; 9 | 10 | CREATE TABLE "BIG_TABLE_ET" 11 | ( 12 | "ID" NUMBER, 13 | "OWNER" VARCHAR2(128), 14 | "OBJECT_NAME" VARCHAR2(128), 15 | "SUBOBJECT_NAME" VARCHAR2(128), 16 | "OBJECT_ID" NUMBER, 17 | "DATA_OBJECT_ID" NUMBER, 18 | "OBJECT_TYPE" VARCHAR2(23), 19 | "CREATED" VARCHAR2(20), 20 | "LAST_DDL_TIME" VARCHAR2(20), 21 | "TIMESTAMP" VARCHAR2(19), 22 | "STATUS" VARCHAR2(7), 23 | "TEMPORARY" VARCHAR2(5), 24 | "GENERATED" VARCHAR2(5), 25 | "SECONDARY" VARCHAR2(5), 26 | "NAMESPACE" NUMBER, 27 | "EDITION_NAME" VARCHAR2(128) 28 | ) 29 | ORGANIZATION external 30 | ( 31 | TYPE oracle_loader 32 | DEFAULT DIRECTORY my_dir 33 | ACCESS PARAMETERS 34 | ( 35 | records delimited by newline 36 | fields terminated by ',' 37 | missing field values are null 38 | ) 39 | location 40 | ( 41 | 'big_table.dat' 42 | ) 43 | )REJECT LIMIT UNLIMITED 44 | / 45 | 46 | alter table big_table_et PARALLEL; 47 | 48 | select count(*) from big_table_et; 49 | -------------------------------------------------------------------------------- /scripts/ch14/demo05.sql: -------------------------------------------------------------------------------- 1 | --Extent Trimming with UNIFORM vs. AUTOALLOCATE Locally-Managed Tablespaces 2 | 3 | drop tablespace lmt_auto including contents and datafiles; 4 | drop tablespace lmt_uniform including contents and datafiles; 5 | 6 | create tablespace lmt_uniform 7 | datafile '/u01/dbfile/ORA12CR1/lmt_uniform.dbf' size 1048640K reuse 8 | autoextend on next 100m 9 | extent management local 10 | UNIFORM SIZE 100m; 11 | 12 | create tablespace lmt_auto 13 | datafile '/u01/dbfile/ORA12CR1/lmt_auto.dbf' size 1048640K reuse 14 | autoextend on next 100m 15 | extent management local 16 | AUTOALLOCATE; 17 | 18 | create table uniform_test 19 | parallel 20 | tablespace lmt_uniform 21 | as 22 | select * from big_table_et; 23 | 24 | create table autoallocate_test 25 | parallel 26 | tablespace lmt_auto 27 | as 28 | select * from big_table_et; 29 | 30 | select sid, serial#, qcsid, qcserial#, degree from v$px_session; 31 | 32 | column segment_name format a20 33 | 34 | select segment_name, blocks, extents 35 | from user_segments 36 | where segment_name in ( 'UNIFORM_TEST', 'AUTOALLOCATE_TEST' ); 37 | 38 | exec show_space( 'UNIFORM_TEST' ); 39 | exec show_space( 'AUTOALLOCATE_TEST' ); 40 | 41 | select segment_name, extent_id, blocks 42 | from user_extents where segment_name = 'UNIFORM_TEST'; 43 | 44 | select segment_name, blocks, count(*) 45 | from user_extents 46 | where segment_name = 'AUTOALLOCATE_TEST' 47 | group by segment_name, blocks 48 | order by blocks; 49 | 50 | alter session enable parallel dml; 51 | 52 | insert /*+ append */ into UNIFORM_TEST 53 | select * from big_table_et; 54 | 55 | insert /*+ append */ into AUTOALLOCATE_TEST 56 | select * from big_table_et; 57 | 58 | commit; 59 | 60 | exec show_space( 'UNIFORM_TEST' ); 61 | exec show_space( 'AUTOALLOCATE_TEST' ); 62 | -------------------------------------------------------------------------------- /scripts/ch14/demo06.sql: -------------------------------------------------------------------------------- 1 | -- Parallel Pipelined Functions 2 | 3 | set feedback on echo on 4 | 5 | drop table t1 purge; 6 | drop table t2 purge; 7 | drop type t2_tab_type; 8 | drop type t2_type; 9 | 10 | create table t1 11 | as 12 | select object_id id, object_name text 13 | from all_objects; 14 | 15 | begin 16 | dbms_stats.set_table_stats 17 | ( user, 'T1', numrows=>10000000,numblks=>100000 ); 18 | end; 19 | / 20 | 21 | create table t2 22 | as 23 | select t1.*, 0 session_id 24 | from t1 25 | where 1=0; 26 | 27 | CREATE OR REPLACE TYPE t2_type 28 | AS OBJECT ( 29 | id number, 30 | text varchar2(30), 31 | session_id number 32 | ) 33 | / 34 | 35 | create or replace type t2_tab_type 36 | as table of t2_type 37 | / 38 | 39 | create or replace 40 | function parallel_pipelined( l_cursor in sys_refcursor ) 41 | return t2_tab_type 42 | pipelined 43 | parallel_enable ( partition l_cursor by any ) 44 | is 45 | l_session_id number; 46 | l_rec t1%rowtype; 47 | begin 48 | select sid into l_session_id 49 | from v$mystat 50 | where rownum =1; 51 | loop 52 | fetch l_cursor into l_rec; 53 | exit when l_cursor%notfound; 54 | -- complex process here 55 | pipe row(t2_type(l_rec.id,l_rec.text,l_session_id)); 56 | end loop; 57 | close l_cursor; 58 | return; 59 | end; 60 | / 61 | 62 | alter session enable parallel dml; 63 | 64 | insert /*+ append */ 65 | into t2(id,text,session_id) 66 | select * 67 | from table(parallel_pipelined 68 | (CURSOR(select /*+ parallel(t1) */ * 69 | from t1 ) 70 | )) 71 | / 72 | 73 | commit; 74 | 75 | select session_id, count(*) 76 | from t2 77 | group by session_id; 78 | -------------------------------------------------------------------------------- /scripts/ch14/demo07.sql: -------------------------------------------------------------------------------- 1 | -- Do-It-Yourself Parallelism 2 | 3 | set feedback on echo on 4 | 5 | drop table t2 purge; 6 | 7 | create table t2 8 | as 9 | select object_id id, object_name text, 0 session_id 10 | from big_table 11 | where 1=0; 12 | 13 | create or replace 14 | procedure serial( p_lo_rid in rowid, p_hi_rid in rowid ) 15 | is 16 | begin 17 | for x in ( select object_id id, object_name text 18 | from big_table 19 | where rowid between p_lo_rid 20 | and p_hi_rid ) 21 | loop 22 | -- complex process here 23 | insert into t2 (id, text, session_id ) 24 | values ( x.id, x.text, sys_context( 'userenv', 'sessionid' ) ); 25 | end loop; 26 | end; 27 | / 28 | 29 | begin 30 | dbms_parallel_execute.create_task('PROCESS BIG TABLE'); 31 | dbms_parallel_execute.create_chunks_by_rowid 32 | ( task_name => 'PROCESS BIG TABLE', 33 | table_owner => user, 34 | table_name => 'BIG_TABLE', 35 | by_row => false, 36 | chunk_size => 10000 ); 37 | end; 38 | / 39 | 40 | select * 41 | from ( 42 | select chunk_id, status, start_rowid, end_rowid 43 | from dba_parallel_execute_chunks 44 | where task_name = 'PROCESS BIG TABLE' 45 | order by chunk_id 46 | ) 47 | where rownum <= 5 48 | / 49 | 50 | begin 51 | dbms_parallel_execute.run_task 52 | ( task_name => 'PROCESS BIG TABLE', 53 | sql_stmt => 'begin serial( :start_id, :end_id ); end;', 54 | language_flag => DBMS_SQL.NATIVE, 55 | parallel_level => 4 ); 56 | end; 57 | / 58 | 59 | select * 60 | from ( 61 | select chunk_id, status, start_rowid, end_rowid 62 | from dba_parallel_execute_chunks 63 | where task_name = 'PROCESS BIG TABLE' 64 | order by chunk_id 65 | ) 66 | where rownum <= 5 67 | / 68 | 69 | begin 70 | dbms_parallel_execute.drop_task('PROCESS BIG TABLE' ); 71 | end; 72 | / 73 | 74 | select session_id, count(*) 75 | from t2 76 | group by session_id 77 | order by session_id; 78 | 79 | 80 | 81 | 82 | 83 | 84 | -------------------------------------------------------------------------------- /scripts/ch15/demo.bad: -------------------------------------------------------------------------------- 1 | -rw-r----- 1 oracle dba 1592 Jul 23 12:01 demo01.sql 2 | -rw-r----- 1 oracle dba 186 Jul 23 12:01 demo02.sql 3 | -rw-r----- 1 oracle dba 278 Jul 23 12:01 demo03.sql 4 | -rw-r----- 1 oracle dba 2269 Jul 23 12:01 demo04.sql 5 | -rw-r----- 1 oracle dba 972 Jul 23 12:01 demo05.sql 6 | -rw-r----- 1 oracle dba 863 Jul 23 12:01 demo06.sql 7 | -rw-r----- 1 oracle dba 584 Jul 23 12:01 demo07.sql 8 | -rw-r----- 1 oracle dba 361 Jul 23 12:02 demo09.sql 9 | -rw-r----- 1 oracle dba 1588 Jul 23 12:02 demo10.sql 10 | -rw-r----- 1 oracle dba 8976 Jul 23 12:02 demo11.sql 11 | -rw-r----- 1 oracle dba 127 Jul 23 12:05 lob_demo.sql 12 | -rw-r----- 1 oracle dba 223 Jul 23 12:08 t.log 13 | -rw-r----- 1 oracle dba 18 Jul 23 12:09 demo08.sql 14 | -------------------------------------------------------------------------------- /scripts/ch15/demo.ctl: -------------------------------------------------------------------------------- 1 | LOAD DATA 2 | INFILE * 3 | REPLACE 4 | INTO TABLE LOB_DEMO 5 | ( owner position(14:19), 6 | time_stamp position(31:42) date "Mon DD HH24:MI", 7 | filename position(44:100), 8 | data LOBFILE(filename) TERMINATED BY EOF 9 | ) 10 | BEGINDATA 11 | -rwxr-xr-x 1 oracle dba 14889 Jul 22 22:01 demo1.log_xt 12 | -rwxr-xr-x 1 oracle dba 123 Jul 22 20:07 demo2.ctl 13 | -rwxr-xr-x 1 oracle dba 712 Jul 23 12:11 demo.bad 14 | -rwxr-xr-x 1 oracle dba 8136 Mar 9 12:36 demo.control_files 15 | -rwxr-xr-x 1 oracle dba 825 Jul 23 12:26 demo.ctl 16 | -rwxr-xr-x 1 oracle dba 1681 Jul 23 12:26 demo.log 17 | -rw-r----- 1 oracle dba 118 Jul 23 12:52 dl.sql 18 | -rwxr-xr-x 1 oracle dba 127 Jul 23 12:05 lob_demo.sql 19 | -rwxr-xr-x 1 oracle dba 171 Mar 10 13:53 p.bsh 20 | -rwxr-xr-x 1 oracle dba 327 Mar 10 11:10 prime.bsh 21 | -rwxr-xr-x 1 oracle dba 24 Mar 6 12:09 run_df.sh 22 | -------------------------------------------------------------------------------- /scripts/ch15/demo01.sql: -------------------------------------------------------------------------------- 1 | -- Executing SQLLDR with the EXTERNAL_TABLE Parameter 2 | 3 | set echo on 4 | 5 | drop table dept purge; 6 | 7 | create table dept 8 | ( deptno number(2) constraint dept_pk primary key, 9 | dname varchar2(14), 10 | loc varchar2(13) 11 | ) 12 | / 13 | 14 | drop table "SYS_SQLLDR_X_EXT_DEPT"; 15 | 16 | CREATE TABLE "SYS_SQLLDR_X_EXT_DEPT" 17 | ( 18 | "DEPTNO" NUMBER(2), 19 | "DNAME" VARCHAR2(14), 20 | "LOC" VARCHAR2(13) 21 | ) 22 | ORGANIZATION external 23 | ( 24 | TYPE oracle_loader 25 | DEFAULT DIRECTORY SYS_SQLLDR_XT_TMPDIR_00000 26 | ACCESS PARAMETERS 27 | ( 28 | RECORDS DELIMITED BY NEWLINE CHARACTERSET US7ASCII 29 | BADFILE 'SYS_SQLLDR_XT_TMPDIR_00000':'demo1.bad' 30 | LOGFILE 'demo1.log_xt' 31 | READSIZE 1048576 32 | SKIP 6 33 | FIELDS TERMINATED BY "," LDRTRIM 34 | REJECT ROWS WITH ALL NULL FIELDS 35 | ( 36 | "DEPTNO" CHAR(255) 37 | TERMINATED BY ",", 38 | "DNAME" CHAR(255) 39 | TERMINATED BY ",", 40 | "LOC" CHAR(255) 41 | TERMINATED BY "," 42 | ) 43 | ) 44 | location 45 | ( 46 | 'demo1.ctl' 47 | ) 48 | )REJECT LIMIT UNLIMITED 49 | / 50 | 51 | INSERT /*+ append */ INTO DEPT 52 | ( 53 | DEPTNO, 54 | DNAME, 55 | LOC 56 | ) 57 | SELECT 58 | "DEPTNO", 59 | "DNAME", 60 | "LOC" 61 | FROM "SYS_SQLLDR_X_EXT_DEPT" 62 | / 63 | 64 | -- Dealing with Errors 65 | 66 | drop table et_bad; 67 | 68 | create table et_bad 69 | ( text1 varchar2(4000) , 70 | text2 varchar2(4000) , 71 | text3 varchar2(4000) 72 | ) 73 | organization external 74 | (type oracle_loader 75 | default directory SYS_SQLLDR_XT_TMPDIR_00000 76 | access parameters 77 | ( 78 | records delimited by newline 79 | fields 80 | missing field values are null 81 | ( text1 position(1:4000), 82 | text2 position(4001:8000), 83 | text3 position(8001:12000) 84 | ) 85 | ) 86 | location ('demo1.bad') 87 | ) 88 | / 89 | -------------------------------------------------------------------------------- /scripts/ch15/demo02.sql: -------------------------------------------------------------------------------- 1 | -- Running SQLLDR in Express Mode 2 | 3 | drop table dept purge; 4 | 5 | create table dept 6 | ( deptno number(2) constraint dept_pk primary key, 7 | dname varchar2(14), 8 | loc varchar2(13) 9 | ) 10 | / 11 | -------------------------------------------------------------------------------- /scripts/ch15/demo03.sql: -------------------------------------------------------------------------------- 1 | -- ALTER TABLE T PROJECT COLUMN REFERENCED|ALL 2 | 3 | select dname from SYS_SQLLDR_X_EXT_DEPT; 4 | select deptno from SYS_SQLLDR_X_EXT_DEPT; 5 | 6 | alter table SYS_SQLLDR_X_EXT_DEPT 7 | project column referenced 8 | / 9 | 10 | select dname from SYS_SQLLDR_X_EXT_DEPT; 11 | select deptno from SYS_SQLLDR_X_EXT_DEPT; 12 | -------------------------------------------------------------------------------- /scripts/ch15/demo04.sql: -------------------------------------------------------------------------------- 1 | -- Monitoring the Filesystem through SQL 2 | 3 | create or replace directory exec_dir as '/orahome/oracle/bin'; 4 | 5 | grant execute on directory exec_dir to eoda; 6 | 7 | drop table df purge; 8 | 9 | create table df 10 | ( 11 | fsname varchar2(100), 12 | blocks number, 13 | used number, 14 | avail number, 15 | capacity varchar2(10), 16 | mount varchar2(100) 17 | ) 18 | organization external 19 | ( 20 | type oracle_loader 21 | default directory exec_dir 22 | access parameters 23 | ( 24 | records delimited 25 | by newline 26 | preprocessor 27 | exec_dir:'run_df.bsh' 28 | skip 1 29 | fields terminated by 30 | whitespace ldrtrim 31 | ) 32 | location 33 | ( 34 | exec_dir:'run_df.bsh' 35 | ) 36 | ) 37 | / 38 | 39 | set lines 132 40 | column fsname format a35 41 | column mount format a10 42 | column file_name format a40 43 | column mbytes format 999,999,999 44 | column tot_mbytes format 999,999,999 45 | column avail_mbytes format 999,999,999 46 | column status format A6 47 | 48 | select * from df; 49 | 50 | with fs_data 51 | as 52 | (select /*+ materialize */ * 53 | from df 54 | ) 55 | select mount, 56 | file_name, 57 | bytes/1024/1024 mbytes, 58 | tot_bytes/1024/1024 tot_mbytes, 59 | avail_bytes/1024/1024 avail_mbytes, 60 | case 61 | when 0.2 * tot_bytes < avail_bytes 62 | then 'OK' 63 | else 'Short on disk space' 64 | end status 65 | from ( 66 | select file_name, mount, avail_bytes, bytes, 67 | sum(bytes) over 68 | (partition by mount) tot_bytes 69 | from ( 70 | select a.file_name, 71 | b.mount, 72 | b.avail*1024 avail_bytes, a.bytes, 73 | row_number() over 74 | (partition by a.file_name 75 | order by length(b.mount) DESC) rn 76 | from dba_data_files a, 77 | fs_data b 78 | where a.file_name 79 | like b.mount || '%' 80 | ) 81 | where rn = 1 82 | ) 83 | order by mount, file_name 84 | / 85 | -------------------------------------------------------------------------------- /scripts/ch15/demo05.sql: -------------------------------------------------------------------------------- 1 | -- Reading and Filtering Compressed Files in a Directory Tree, search_dir.bsh 2 | 3 | host mkdir /tmp/base 4 | host mkdir /tmp/base/base2a 5 | host mkdir /tmp/base/base2b 6 | 7 | host echo 'base col1,base col2' | gzip > /tmp/base/filebase.csv.gz 8 | host echo 'base2a col1,base2a col2' | gzip > /tmp/base/base2a/filebase2a.csv.gz 9 | host echo 'base2b col1,base2b col2' | gzip > /tmp/base/base2b/filebase2b.csv.gz 10 | 11 | create or replace directory exec_dir as '/orahome/oracle/bin'; 12 | create or replace directory data_dir as '/tmp'; 13 | 14 | drop table csv; 15 | 16 | create table csv 17 | ( col1 varchar2(20) 18 | ) 19 | organization external 20 | ( 21 | type oracle_loader 22 | default directory data_dir 23 | access parameters 24 | ( 25 | records delimited by newline 26 | preprocessor exec_dir:'search_dir.bsh' 27 | fields terminated by ',' ldrtrim 28 | ) 29 | location 30 | ( 31 | data_dir:'base' 32 | ) 33 | ) 34 | / 35 | 36 | select * from csv; 37 | 38 | create or replace directory data_dir as '/tmp/base'; 39 | alter table csv location( 'base2a' ); 40 | 41 | select * from csv; 42 | 43 | -- Finding largest files 44 | create or replace directory exec_dir as '/orahome/oracle/bin'; 45 | create or replace directory data_dir as '/'; 46 | 47 | create table flf (fname varchar2(200), bytes number) 48 | organization external ( 49 | type oracle_loader 50 | default directory exec_dir 51 | access parameters 52 | ( records delimited by newline 53 | preprocessor exec_dir:'flf.bsh' 54 | fields terminated by whitespace ldrtrim) 55 | location (data_dir:'u01')); 56 | 57 | -------------------------------------------------------------------------------- /scripts/ch15/demo06.sql: -------------------------------------------------------------------------------- 1 | -- Reading and Filtering Compressed Files in a Directory Tree, search_dir2.bsh 2 | 3 | !mkdir /tmp/base 4 | !mkdir /tmp/base/base2a 5 | !mkdir /tmp/base/base2b 6 | 7 | !echo 'base col1,base col2' | gzip > /tmp/base/filebase.csv.gz 8 | !echo 'base2a col1,base2a col2' | gzip > /tmp/base/base2a/filebase2a.csv.gz 9 | !echo 'base2b col1,base2b col2' | gzip > /tmp/base/base2b/filebase2b.csv.gz 10 | 11 | create or replace directory exec_dir as '/orahome/oracle/bin'; 12 | create or replace directory data_dir as '/tmp'; 13 | 14 | drop table csv2; 15 | 16 | create table csv2 17 | ( col1 varchar2(20) 18 | ,col2 varchar2(20) 19 | ) 20 | organization external 21 | ( 22 | type oracle_loader 23 | default directory data_dir 24 | access parameters 25 | ( 26 | records delimited by newline 27 | preprocessor exec_dir:'search_dir2.bsh' 28 | fields terminated by ',' ldrtrim 29 | ) 30 | location 31 | ( 32 | data_dir:'base' 33 | ) 34 | ) 35 | / 36 | 37 | select * from csv2; 38 | -------------------------------------------------------------------------------- /scripts/ch15/demo07.sql: -------------------------------------------------------------------------------- 1 | -- Trimming Characters Out of a File 2 | 3 | set echo on 4 | 5 | create or replace directory data_dir as '/tmp'; 6 | 7 | create or replace directory exec_dir as '/orahome/oracle/bin'; 8 | 9 | drop table csv3; 10 | 11 | create table csv3 12 | ( col1 varchar2(20) 13 | ,col2 varchar2(20) 14 | ) 15 | organization external 16 | ( 17 | type oracle_loader 18 | default directory data_dir 19 | access parameters 20 | ( 21 | records delimited by newline 22 | preprocessor exec_dir:'run_sed.bsh' 23 | fields terminated by '|' ldrtrim 24 | ) 25 | location 26 | ( 27 | data_dir:'load.csv' 28 | ) 29 | ) 30 | / 31 | 32 | select * from csv3; 33 | select length(col2) from csv3; 34 | -------------------------------------------------------------------------------- /scripts/ch15/demo08.sql: -------------------------------------------------------------------------------- 1 | -- Tip, consider using dos2unix to remove unwanted characters 2 | 3 | host dos2unix /tmp/load.csv 4 | -------------------------------------------------------------------------------- /scripts/ch15/demo09.sql: -------------------------------------------------------------------------------- 1 | -- Data Pump Unload 2 | 3 | create or replace directory tmp as '/tmp'; 4 | 5 | drop table all_objects_unload purge; 6 | 7 | create table all_objects_unload 8 | organization external 9 | ( type oracle_datapump 10 | default directory TMP 11 | location( 'allobjects.dat' ) 12 | ) 13 | as 14 | select 15 | * 16 | from all_objects 17 | / 18 | 19 | select dbms_metadata.get_ddl( 'TABLE', 'ALL_OBJECTS_UNLOAD' ) 20 | from dual; 21 | 22 | -------------------------------------------------------------------------------- /scripts/ch15/demo1.ctl: -------------------------------------------------------------------------------- 1 | LOAD DATA 2 | INFILE * 3 | INTO TABLE DEPT 4 | FIELDS TERMINATED BY ',' 5 | (DEPTNO, DNAME, LOC ) 6 | BEGINDATA 7 | 10,Sales,Virginia 8 | 20,Accounting,Virginia 9 | 30,Consulting,Virginia 10 | 40,Finance,Virginia 11 | -------------------------------------------------------------------------------- /scripts/ch15/demo1.log: -------------------------------------------------------------------------------- 1 | 2 | SQL*Loader: Release 12.1.0.1.0 - Production on Thu Jul 24 10:01:46 2014 3 | 4 | Copyright (c) 1982, 2013, Oracle and/or its affiliates. All rights reserved. 5 | 6 | Control File: demo1.ctl 7 | Data File: demo1.ctl 8 | Bad File: demo1.bad 9 | Discard File: none specified 10 | 11 | (Allow all discards) 12 | 13 | Number to load: ALL 14 | Number to skip: 0 15 | Errors allowed: 50 16 | Bind array: 64 rows, maximum of 256000 bytes 17 | Continuation: none specified 18 | Path used: Conventional 19 | 20 | Table DEPT, loaded from every logical record. 21 | Insert option in effect for this table: INSERT 22 | 23 | Column Name Position Len Term Encl Datatype 24 | ------------------------------ ---------- ----- ---- ---- --------------------- 25 | DEPTNO FIRST * , CHARACTER 26 | DNAME NEXT * , CHARACTER 27 | LOC NEXT * , CHARACTER 28 | 29 | SQL*Loader-601: For INSERT option, table must be empty. Error on table DEPT 30 | -------------------------------------------------------------------------------- /scripts/ch15/demo10.sql: -------------------------------------------------------------------------------- 1 | -- How Do I Load Lobs? Loading a LOB via PL/SQL 2 | 3 | create or replace directory dir1 as '/tmp/'; 4 | create or replace directory "dir2" as '/tmp/'; 5 | 6 | drop table demo purge; 7 | 8 | set echo on 9 | 10 | create table demo 11 | ( id int primary key, 12 | theClob clob 13 | ) 14 | / 15 | 16 | host echo 'Hello World!' > /tmp/test.txt 17 | 18 | declare 19 | l_clob clob; 20 | l_bfile bfile; 21 | begin 22 | insert into demo values ( 1, empty_clob() ) 23 | returning theclob into l_clob; 24 | 25 | l_bfile := bfilename( 'DIR1', 'test.txt' ); 26 | dbms_lob.fileopen( l_bfile ); 27 | 28 | dbms_lob.loadfromfile( l_clob, l_bfile, dbms_lob.getlength( l_bfile ) ); 29 | 30 | dbms_lob.fileclose( l_bfile ); 31 | end; 32 | / 33 | 34 | column theclob format a30 35 | select dbms_lob.getlength(theClob), theClob from demo 36 | / 37 | 38 | -- If you get ??? in the output, character set adjustment 39 | drop table demo purge; 40 | 41 | create table demo 42 | ( id int primary key, 43 | theClob clob 44 | ) 45 | / 46 | 47 | host echo 'Hello World!' > /tmp/test.txt 48 | 49 | declare 50 | l_clob clob; 51 | l_bfile bfile; 52 | dest_offset integer := 1; 53 | src_offset integer := 1; 54 | src_csid number := NLS_CHARSET_ID('WE8ISO8859P1'); 55 | lang_context integer := dbms_lob.default_lang_ctx; 56 | warning integer; 57 | begin 58 | insert into demo values ( 1, empty_clob() ) 59 | returning theclob into l_clob; 60 | l_bfile := bfilename( 'dir2', 'test.txt' ); 61 | dbms_lob.fileopen( l_bfile ); 62 | dbms_lob.loadclobfromfile( l_clob, l_bfile, dbms_lob.getlength( l_bfile ), dest_offset, src_offset, src_csid, lang_context,warning ); 63 | dbms_lob.fileclose( l_bfile ); 64 | end; 65 | / 66 | 67 | select dbms_lob.getlength(theClob), theClob from demo 68 | / 69 | -------------------------------------------------------------------------------- /scripts/ch15/demo2.ctl: -------------------------------------------------------------------------------- 1 | 60,dfas,Virginia 2 | 70,Accounting,Virginia 3 | 80,Consulting,Virginia 4 | 90,Finance,Virginia 5 | 90,Finance,Virginia,adfsklj 6 | 7 | foo,foo,11 8 | -------------------------------------------------------------------------------- /scripts/ch15/dept.dat: -------------------------------------------------------------------------------- 1 | 10,Sales,Virginia 2 | 20,Accounting,Virginia 3 | 30,Consulting,Virginia 4 | 40,Finance,Virginia 5 | -------------------------------------------------------------------------------- /scripts/ch15/flf.bsh: -------------------------------------------------------------------------------- 1 | #!/bin/bash 2 | /usr/bin/find $1 -ls|/bin/sort -nrk7|/usr/bin/head -10|/bin/awk '{print $11,$7}' 3 | -------------------------------------------------------------------------------- /scripts/ch15/lob_demo.sql: -------------------------------------------------------------------------------- 1 | create table lob_demo 2 | ( owner varchar2(255), 3 | time_stamp date, 4 | filename varchar2(255), 5 | data blob 6 | ) 7 | / 8 | -------------------------------------------------------------------------------- /scripts/ch15/run_df.sh: -------------------------------------------------------------------------------- 1 | #!/bin/bash 2 | /bin/df -Pl 3 | -------------------------------------------------------------------------------- /scripts/ch15/run_sed.bsh: -------------------------------------------------------------------------------- 1 | #!/bin/bash 2 | /bin/sed -e 's/ //g' $* 3 | -------------------------------------------------------------------------------- /scripts/ch15/search_dir.bsh: -------------------------------------------------------------------------------- 1 | #!/bin/bash 2 | /usr/bin/find $* -name "*.gz" -exec /bin/zcat {} \; | /usr/bin/cut -f1 -d, 3 | -------------------------------------------------------------------------------- /scripts/ch15/search_dir2.bsh: -------------------------------------------------------------------------------- 1 | #!/bin/bash 2 | /usr/bin/find $* -name "*.gz" -print0 | /usr/bin/xargs -0 -I {} /usr/bin/zgrep "base2" {} 3 | --------------------------------------------------------------------------------