Skip to content

Commit

Permalink
First commit
Browse files Browse the repository at this point in the history
  • Loading branch information
Apress committed Oct 18, 2016
0 parents commit 3f2dacc
Show file tree
Hide file tree
Showing 273 changed files with 11,474 additions and 0 deletions.
10 changes: 10 additions & 0 deletions scripts/ch00/README.txt
@@ -0,0 +1,10 @@
The ch00 folder contains scripts used throughout the book.

For exampe:
* creeoda.sql creates the EODA user used in the examples and grants it required privileges.
* login.sql sets the SQL prompt.
* big_table.sql creates the BIG_TABLE table.
* crescott.sql creates the SCOTT schema (if you don't already have that schema).
* tk.sql runs tkprof on a trace file and opens the trace file for editing.

And so on.
46 changes: 46 additions & 0 deletions scripts/ch00/big_table.sql
@@ -0,0 +1,46 @@
define numrows=10000000
drop table big_table purge;

create table big_table
as
select rownum id, OWNER, OBJECT_NAME, SUBOBJECT_NAME, OBJECT_ID,
DATA_OBJECT_ID, OBJECT_TYPE, CREATED, LAST_DDL_TIME, TIMESTAMP,
STATUS, TEMPORARY, GENERATED, SECONDARY, NAMESPACE, EDITION_NAME
from all_objects
where 1=0
/

alter table big_table nologging;

declare
l_cnt number;
l_rows number := &numrows;
begin
insert /*+ append */
into big_table
select rownum id, OWNER, OBJECT_NAME, SUBOBJECT_NAME, OBJECT_ID,
DATA_OBJECT_ID, OBJECT_TYPE, CREATED, LAST_DDL_TIME, TIMESTAMP,
STATUS, TEMPORARY, GENERATED, SECONDARY, NAMESPACE, EDITION_NAME
from all_objects
where rownum <= &numrows;
--
l_cnt := sql%rowcount;
commit;
while (l_cnt < l_rows)
loop
insert /*+ APPEND */ into big_table
select rownum+l_cnt,OWNER, OBJECT_NAME, SUBOBJECT_NAME, OBJECT_ID,
DATA_OBJECT_ID, OBJECT_TYPE, CREATED, LAST_DDL_TIME, TIMESTAMP,
STATUS, TEMPORARY, GENERATED, SECONDARY, NAMESPACE, EDITION_NAME
from big_table a
where rownum <= l_rows-l_cnt;
l_cnt := l_cnt + sql%rowcount;
commit;
end loop;
end;
/

alter table big_table add constraint
big_table_pk primary key(id);

exec dbms_stats.gather_table_stats( user, 'BIG_TABLE', estimate_percent=> 1);
11 changes: 11 additions & 0 deletions scripts/ch00/creeoda.sql
@@ -0,0 +1,11 @@
connect / as sysdba
define username=eoda
define usernamepwd=foo
create user &&username identified by &&usernamepwd;
grant dba to &&username;
grant execute on dbms_stats to &&username;
grant select on V_$STATNAME to &&username;
grant select on V_$MYSTAT to &&username;
grant select on V_$LATCH to &&username;
grant select on V_$TIMER to &&username;
conn &&username/&&usernamepwd
2 changes: 2 additions & 0 deletions scripts/ch00/crescott.sql
@@ -0,0 +1,2 @@
conn / as sysdba
@?/rdbms/admin/utlsampl.sql
38 changes: 38 additions & 0 deletions scripts/ch00/demo01.sql
@@ -0,0 +1,38 @@
-- Runstats example

drop table t1 purge;
drop table t2 purge;

create table t1
as
select * from big_table
where 1=0;

create table t2
as
select * from big_table
where 1=0;

exec runstats_pkg.rs_start;

insert into t1
select *
from big_table
where rownum <= 1000000;

commit;

exec runstats_pkg.rs_middle;

begin
for x in ( select *
from big_table
where rownum <= 1000000 )
loop
insert into t2 values X;
end loop;
commit;
end;
/

exec runstats_pkg.rs_stop(1000000)
10 changes: 10 additions & 0 deletions scripts/ch00/demo02.sql
@@ -0,0 +1,10 @@
-- Mystat example

column name form a30

@mystat "redo size"

update big_table set owner = lower(owner)
where rownum <= 1000;

@mystat2
50 changes: 50 additions & 0 deletions scripts/ch00/demobld.sql
@@ -0,0 +1,50 @@
CREATE TABLE EMP
(EMPNO NUMBER(4) NOT NULL,
ENAME VARCHAR2(10),
JOB VARCHAR2(9),
MGR NUMBER(4),
HIREDATE DATE,
SAL NUMBER(7, 2),
COMM NUMBER(7, 2),
DEPTNO NUMBER(2)
);

INSERT INTO EMP VALUES (7369, 'SMITH', 'CLERK', 7902,
TO_DATE('17-DEC-1980', 'DD-MON-YYYY'), 800, NULL, 20);
INSERT INTO EMP VALUES (7499, 'ALLEN', 'SALESMAN', 7698,
TO_DATE('20-FEB-1981', 'DD-MON-YYYY'), 1600, 300, 30);
INSERT INTO EMP VALUES (7521, 'WARD', 'SALESMAN', 7698,
TO_DATE('22-FEB-1981', 'DD-MON-YYYY'), 1250, 500, 30);
INSERT INTO EMP VALUES (7566, 'JONES', 'MANAGER', 7839,
TO_DATE('2-APR-1981', 'DD-MON-YYYY'), 2975, NULL, 20);
INSERT INTO EMP VALUES (7654, 'MARTIN', 'SALESMAN', 7698,
TO_DATE('28-SEP-1981', 'DD-MON-YYYY'), 1250, 1400, 30);
INSERT INTO EMP VALUES (7698, 'BLAKE', 'MANAGER', 7839,
TO_DATE('1-MAY-1981', 'DD-MON-YYYY'), 2850, NULL, 30);
INSERT INTO EMP VALUES (7782, 'CLARK', 'MANAGER', 7839,
TO_DATE('9-JUN-1981', 'DD-MON-YYYY'), 2450, NULL, 10);
INSERT INTO EMP VALUES (7788, 'SCOTT', 'ANALYST', 7566,
TO_DATE('09-DEC-1982', 'DD-MON-YYYY'), 3000, NULL, 20);
INSERT INTO EMP VALUES (7839, 'KING', 'PRESIDENT', NULL,
TO_DATE('17-NOV-1981', 'DD-MON-YYYY'), 5000, NULL, 10);
INSERT INTO EMP VALUES (7844, 'TURNER', 'SALESMAN', 7698,
TO_DATE('8-SEP-1981', 'DD-MON-YYYY'), 1500, 0, 30);
INSERT INTO EMP VALUES (7876, 'ADAMS', 'CLERK', 7788,
TO_DATE('12-JAN-1983', 'DD-MON-YYYY'), 1100, NULL, 20);
INSERT INTO EMP VALUES (7900, 'JAMES', 'CLERK', 7698,
TO_DATE('3-DEC-1981', 'DD-MON-YYYY'), 950, NULL, 30);
INSERT INTO EMP VALUES (7902, 'FORD', 'ANALYST', 7566,
TO_DATE('3-DEC-1981', 'DD-MON-YYYY'), 3000, NULL, 20);
INSERT INTO EMP VALUES (7934, 'MILLER', 'CLERK', 7782,
TO_DATE('23-JAN-1982', 'DD-MON-YYYY'), 1300, NULL, 10);

CREATE TABLE DEPT
(DEPTNO NUMBER(2),
DNAME VARCHAR2(14),
LOC VARCHAR2(13)
);

INSERT INTO DEPT VALUES (10, 'ACCOUNTING', 'NEW YORK');
INSERT INTO DEPT VALUES (20, 'RESEARCH', 'DALLAS');
INSERT INTO DEPT VALUES (30, 'SALES', 'CHICAGO');
INSERT INTO DEPT VALUES (40, 'OPERATIONS', 'BOSTON');
14 changes: 14 additions & 0 deletions scripts/ch00/login.old.sql
@@ -0,0 +1,14 @@
define _editor=vi
set serveroutput on size 1000000
set trimspool on
set long 5000
set linesize 100
set pagesize 9999
column plan_plus_exp format a80
set termout off
define gname=idle
column global_name new_value gname
select lower(user) || '@' || substr( global_name, 1, decode( dot, 0, length(global_name), dot-1) ) global_name
from (select global_name, instr(global_name,'.') dot from global_name );
set sqlprompt '&gname> '
set termout on
8 changes: 8 additions & 0 deletions scripts/ch00/login.sql
@@ -0,0 +1,8 @@
define _editor=vi
set serveroutput on size 1000000
set trimspool on
set long 5000
set linesize 100
set pagesize 9999
column plan_plus_exp format a80
set sqlprompt '&_user.@&_connect_identifier.> '
12 changes: 12 additions & 0 deletions scripts/ch00/mystat.sql
@@ -0,0 +1,12 @@
set echo off
set verify off
column value new_val V
define S="&1"

set autotrace off
select a.name, b.value
from v$statname a, v$mystat b
where a.statistic# = b.statistic#
and lower(a.name) = lower('&S')
/
set echo on
8 changes: 8 additions & 0 deletions scripts/ch00/mystat2.sql
@@ -0,0 +1,8 @@
set echo off
set verify off
select a.name, b.value V, to_char(b.value-&V,'999,999,999,999') diff
from v$statname a, v$mystat b
where a.statistic# = b.statistic#
and lower(a.name) = lower('&S')
/
set echo on
25 changes: 25 additions & 0 deletions scripts/ch00/ru.sql
@@ -0,0 +1,25 @@
SET LINESIZE 150;
SET SERVEROUTPUT on SIZE 1000000 FORMAT WRAPPED;
--
declare
--
l_rows number;
--
begin
l_rows := unloader.run
( p_cols => '*',
p_town => 'EODA',
p_tname => 'BIG_TABLE',
p_mode => 'truncate',
p_dbdir => 'UNLOADER',
p_filename => 'unload_file',
p_separator => ',',
p_enclosure => '"',
p_terminator => '|',
p_ctl => 'YES',
p_header => 'NO' );
--
dbms_output.put_line( to_char(l_rows) || ' rows extracted to ascii file' );
--
end;
/
137 changes: 137 additions & 0 deletions scripts/ch00/runstats.sql
@@ -0,0 +1,137 @@
conn / as sysdba

grant select on v_$statname to eoda;
grant select on v_$mystat to eoda;
grant select on v_$latch to eoda;
grant select on v_$timer to eoda;

conn eoda/foo

drop table run_stats;
set echo on;

create or replace view stats
as select 'STAT...' || a.name name, b.value
from v$statname a, v$mystat b
where a.statistic# = b.statistic#
union all
select 'LATCH.' || name, gets
from v$latch
union all
select 'STAT...Elapsed Time', hsecs from v$timer;

create global temporary table run_stats
( runid varchar2(15),
name varchar2(80),
value int )
on commit preserve rows;

create or replace package runstats_pkg
as
procedure rs_start;
procedure rs_middle;
procedure rs_stop(p_difference_threshold in number default 0 );
end;
/

create or replace package body runstats_pkg
as

g_start number;
g_run1 number;
g_run2 number;

procedure rs_start
is
begin
delete from run_stats;

insert into run_stats
select 'before', stats.* from stats;

g_start := dbms_utility.get_cpu_time;
end;

procedure rs_middle
is
begin
g_run1 := (dbms_utility.get_cpu_time-g_start);

insert into run_stats
select 'after 1', stats.* from stats;

g_start := dbms_utility.get_cpu_time;
end;

procedure rs_stop(p_difference_threshold in number default 0)
is
begin
g_run2 := (dbms_utility.get_cpu_time-g_start);

dbms_output.put_line( 'Run1 ran in ' || g_run1 || ' cpu hsecs' );
dbms_output.put_line( 'Run2 ran in ' || g_run2 || ' cpu hsecs' );

if ( g_run2 <> 0 )
then
dbms_output.put_line
( 'run 1 ran in ' || round(g_run1/g_run2*100,2) ||
'% of the time' );
end if;
dbms_output.put_line( chr(9) );

insert into run_stats
select 'after 2', stats.* from stats;

dbms_output.put_line
( rpad( 'Name', 30 ) || lpad( 'Run1', 16 ) ||
lpad( 'Run2', 16 ) || lpad( 'Diff', 16 ) );

for x in
( select rpad( a.name, 30 ) ||
to_char( b.value-a.value, '999,999,999,999' ) ||
to_char( c.value-b.value, '999,999,999,999' ) ||
to_char( ( (c.value-b.value)-(b.value-a.value)),
'999,999,999,999' ) data
from run_stats a, run_stats b, run_stats c
where a.name = b.name
and b.name = c.name
and a.runid = 'before'
and b.runid = 'after 1'
and c.runid = 'after 2'

and abs( (c.value-b.value) - (b.value-a.value) )
> p_difference_threshold
order by abs( (c.value-b.value)-(b.value-a.value))
) loop
dbms_output.put_line( x.data );
end loop;

dbms_output.put_line( chr(9) );
dbms_output.put_line
( 'Run1 latches total versus runs -- difference and pct' );
dbms_output.put_line
( lpad( 'Run1', 14 ) || lpad( 'Run2', 19 ) ||
lpad( 'Diff', 18 ) || lpad( 'Pct', 11 ) );

for x in
( select to_char( run1, '9,999,999,999,999' ) ||
to_char( run2, '9,999,999,999,999' ) ||
to_char( diff, '9,999,999,999,999' ) ||
to_char( round( run1/decode( run2, 0, to_number(0), run2) *100,2 ), '99,999.99' ) || '%' data
from ( select sum(b.value-a.value) run1, sum(c.value-b.value) run2,
sum( (c.value-b.value)-(b.value-a.value)) diff
from run_stats a, run_stats b, run_stats c
where a.name = b.name
and b.name = c.name
and a.runid = 'before'
and b.runid = 'after 1'
and c.runid = 'after 2'
and a.name like 'LATCH%'
)
) loop
dbms_output.put_line( x.data );
end loop;
end;

end;
/

0 comments on commit 3f2dacc

Please sign in to comment.