Commit 1628a4ba authored by O'Reilly Media, Inc's avatar O'Reilly Media, Inc
Browse files

Initial commit

parents
CREATE OR REPLACE PACKAGE authors_pkg
IS
steven_authors strings_nt
:= strings_nt ('ROBIN HOBB'
, 'ROBERT HARRIS'
, 'DAVID BRIN'
, 'SHERI S. TEPPER'
, 'CHRISTOPHER ALEXANDER'
);
veva_authors strings_nt
:= strings_nt ('ROBIN HOBB'
, 'SHERI S. TEPPER'
, 'ANNE MCCAFFREY'
);
eli_authors strings_nt
:= strings_nt ( 'SHERI S. TEPPER'
, 'DAVID BRIN'
);
PROCEDURE show_authors (
title_in IN VARCHAR2
, authors_in IN strings_nt
);
END;
/
SHO ERR
CREATE OR REPLACE PACKAGE BODY authors_pkg
IS
PROCEDURE show_authors (
title_in IN VARCHAR2
, authors_in IN strings_nt
)
IS
BEGIN
DBMS_OUTPUT.put_line (title_in);
FOR indx IN authors_in.FIRST .. authors_in.LAST
LOOP
DBMS_OUTPUT.put_line (indx || ' = ' || authors_in (indx));
END LOOP;
DBMS_OUTPUT.put_line ('_');
END show_authors;
END;
/
SHO ERR
\ No newline at end of file
DECLARE
TYPE nested_tab_t IS TABLE OF INTEGER;
tab_1 nested_tab_t := nested_tab_t (1, 2, 3, 4, 5, 6, 7);
tab_2 nested_tab_t := nested_tab_t (7, 6, 5, 4, 3, 2, 1);
PROCEDURE tabs_equal (i_tab_1 IN nested_tab_t, i_tab_2 IN nested_tab_t)
IS
v_equal BOOLEAN := i_tab_1 = i_tab_2;
BEGIN
IF v_equal IS NULL
THEN
DBMS_OUTPUT.put_line ('null');
ELSIF v_equal
THEN
DBMS_OUTPUT.put_line ('equal');
ELSE
DBMS_OUTPUT.put_line ('not equal');
END IF;
END tabs_equal;
BEGIN
tabs_equal (tab_1, tab_2);
tab_1.EXTEND (1);
tabs_equal (tab_1, tab_2);
tab_2.EXTEND (1);
tabs_equal (tab_1, tab_2);
END;
DECLARE
TYPE clientele IS TABLE OF VARCHAR2 (64);
group1 clientele := clientele ('Customer 1', 'Customer 2');
group2 clientele := clientele ('Customer 1', 'Customer 3', NULL);
group3 clientele := clientele ('Customer 3', NULL, 'Customer 1');
BEGIN
IF group1 = group2
THEN
DBMS_OUTPUT.put_line ('Group 1 = Group 2');
ELSIF group1 != group2
THEN
DBMS_OUTPUT.put_line ('Group 1 != Group 2');
END IF;
IF group2 != group3
THEN
DBMS_OUTPUT.put_line ('Group 2 != Group 3');
ELSIF group2 = group3
THEN
DBMS_OUTPUT.put_line ('Group 2 = Group 3');
END IF;
END;
/
\ No newline at end of file
CREATE OR REPLACE PACKAGE emp_coll_pkg
IS
TYPE employee_tt IS TABLE OF employee%ROWTYPE;
FUNCTION equal (coll1_in IN employee_tt, coll2_in IN employee_tt)
RETURN BOOLEAN;
END emp_coll_pkg;
/
CREATE OR REPLACE PACKAGE BODY emp_coll_pkg
IS
FUNCTION equal (coll1_in IN employee_tt, coll2_in IN employee_tt)
RETURN BOOLEAN
IS
l_count1 PLS_INTEGER := coll1_in.COUNT;
l_count2 PLS_INTEGER := coll2_in.COUNT;
l_row PLS_INTEGER := coll1_in.FIRST;
retval BOOLEAN;
FUNCTION row_equal (
row1_in IN employee%ROWTYPE
, row2_in IN employee%ROWTYPE
)
RETURN BOOLEAN
IS
retval BOOLEAN;
BEGIN
retval :=
row1_in.employee_id = row2_in.employee_id
AND row1_in.last_name = row2_in.last_name
AND row1_in.first_name = row2_in.first_name
AND row1_in.middle_initial = row2_in.middle_initial
AND row1_in.job_id = row2_in.job_id
AND row1_in.manager_id = row2_in.manager_id
AND row1_in.hire_date = row2_in.hire_date
AND row1_in.salary = row2_in.salary
AND row1_in.commission = row2_in.commission
AND row1_in.department_id = row2_in.department_id
AND row1_in.empno = row2_in.empno
AND row1_in.ename = row2_in.ename
AND row1_in.created_by = row2_in.created_by
AND row1_in.created_on = row2_in.created_on
AND row1_in.changed_by = row2_in.changed_by
AND row1_in.changed_on = row2_in.changed_on;
RETURN retval;
END row_equal;
BEGIN
retval := l_count1 = l_count2;
IF retval
THEN
LOOP
EXIT WHEN l_row IS NULL OR NOT retval;
retval := row_equal (coll1_in (l_row), coll2_in (l_row));
l_row := coll1_in.NEXT (l_row);
END LOOP;
END IF;
RETURN retval;
END;
END emp_coll_pkg;
/
alter session set plsql_warnings='ENABLE:ALL'
\ No newline at end of file
DECLARE
our_favorites
strings_nt := strings_nt ();
BEGIN
our_favorites :=
authors_pkg.steven_authors
MULTISET UNION
authors_pkg.veva_authors;
authors_pkg.show_authors (
'STEVEN then VEVA', our_favorites);
END;
/
\ No newline at end of file
DECLARE
our_favorites
strings_nt := strings_nt ();
BEGIN
our_favorites :=
authors_pkg.veva_authors
MULTISET UNION
authors_pkg.steven_authors;
authors_pkg.show_authors (
'VEVA THEN STEVEN', our_favorites);
END;
/
DECLARE
our_favorites
strings_nt := strings_nt ();
BEGIN
our_favorites :=
authors_pkg.veva_authors
MULTISET UNION DISTINCT
authors_pkg.steven_authors;
authors_pkg.show_authors (
'VEVA THEN STEVEN DISTINCT', our_favorites);
END;
/
CREATE OR REPLACE PACKAGE authors_pkg
IS
steven_authors strings_nt
:= strings_nt ('ROBIN HOBB'
, 'ROBERT HARRIS'
, 'DAVID BRIN'
, 'SHERI S. TEPPER'
, 'CHRISTOPHER ALEXANDER'
);
veva_authors strings_nt
:= strings_nt ('ROBIN HOBB'
, 'SHERI S. TEPPER'
, 'ANNE MCCAFFREY'
);
eli_authors strings_nt
:= strings_nt ('PIERS ANTHONY'
, 'SHERI S. TEPPER'
, 'DAVID BRIN'
);
PROCEDURE show_authors (
title_in IN VARCHAR2
, authors_in IN strings_nt
);
END;
/
CREATE OR REPLACE PACKAGE BODY authors_pkg
IS
PROCEDURE show_authors (
title_in IN VARCHAR2
, authors_in IN strings_nt
)
IS
BEGIN
DBMS_OUTPUT.put_line (title_in);
FOR indx IN authors_in.FIRST .. authors_in.LAST
LOOP
DBMS_OUTPUT.put_line (indx || ' = ' || authors_in (indx));
END LOOP;
DBMS_OUTPUT.put_line ('_');
END show_authors;
END;
/
\ No newline at end of file
DROP TABLE favorites;
CREATE TABLE favorites (
flavor VARCHAR2(100),
NAME VARCHAR2(100));
DECLARE
TYPE favorites_tt IS TABLE OF favorites%ROWTYPE
INDEX BY PLS_INTEGER;
TYPE guide_tt IS TABLE OF PLS_INTEGER
INDEX BY PLS_INTEGER;
family favorites_tt;
guide guide_tt;
l_count INTEGER;
PROCEDURE cleanup IS
BEGIN
DELETE FROM favorites;
guide.DELETE;
END;
BEGIN
family (1).flavor := 'CHOCOLATE';
family (1).NAME := 'VEVA';
family (25).flavor := 'STRAWBERRY';
family (25).NAME := 'STEVEN';
family (500).flavor := 'VANILLA';
family (500).NAME := 'CHRIS';
family (5000).flavor := 'ROCKY ROAD';
family (5000).NAME := 'ELI';
family (5001).flavor := 'PINEAPPLE';
family (5001).NAME := 'MOSHE';
family (5002).flavor := 'EVERYTHING';
family (5002).NAME := 'MICA';
-- Just a subset of the family favorites...
guide (1) := 1;
guide (5000) := 2;
FORALL indx IN indices OF guide -- bewteen my_list.first .. my_first.last
INSERT INTO favorites
VALUES family (indx);
SELECT COUNT(*) into l_count FROM favorites;
DBMS_OUTPUT.PUT_LINE (l_count);
cleanup;
-- Insert nothing at all: no error raised!
FORALL indx IN indices of guide -- bewteen my_list.first .. my_first.last
INSERT INTO favorites
VALUES family (indx);
SELECT COUNT(*) into l_count FROM favorites;
DBMS_OUTPUT.PUT_LINE (l_count);
cleanup;
-- Use BETWEEN clause
guide (25) := 1;
guide (500) := 1;
guide (5000) := 1;
FORALL indx IN indices of guide BETWEEN guide.FIRST AND LEAST (guide.LAST, 500)
INSERT INTO favorites
VALUES family (indx);
SELECT COUNT(*) into l_count FROM favorites;
DBMS_OUTPUT.PUT_LINE (l_count);
cleanup;
-- Use BETWEEN clause with undefined row.
-- Does NOT raise NO_DATA_FOUND. Instead:
-- ORA-22160: element at index [7589] does not exist
-- But rows before that are inserted. Don't forget about SAVE EXCEPTIONS
guide (25) := 1;
guide (417) := 1; -- Undefined row
guide (500) := 1;
guide (5000) := 1;
BEGIN
FORALL indx IN indices of guide BETWEEN guide.FIRST AND LEAST (guide.LAST, 500)
INSERT INTO favorites
VALUES family (indx);
EXCEPTION
WHEN OTHERS
THEN
DBMS_OUTPUT.PUT_LINE (SQLERRM);
END;
SELECT COUNT(*) into l_count FROM favorites;
DBMS_OUTPUT.PUT_LINE (l_count);
cleanup;
-- Use VALUES OF
guide (-1000) := 1;
guide (1000) := 5001;
guide (10000) := 5002;
FORALL indx IN VALUES OF guide
INSERT INTO favorites
VALUES family (indx);
SELECT COUNT(*) into l_count FROM favorites;
DBMS_OUTPUT.PUT_LINE (l_count);
cleanup;
-- Use VALUES OF with undefined row
-- Does NOT raise NO_DATA_FOUND. Instead:
-- ORA-22160: element at index [7589] does not exist
-- But rows before that are inserted. Don't forget about SAVE EXCEPTIONS
guide (-1000) := 1;
guide (1000) := 7589;
guide (10000) := 5001;
BEGIN
FORALL indx IN VALUES OF guide
INSERT INTO favorites
VALUES family (indx);
EXCEPTION
WHEN OTHERS
THEN
DBMS_OUTPUT.PUT_LINE (SQLERRM);
END;
SELECT COUNT(*) into l_count FROM favorites;
DBMS_OUTPUT.PUT_LINE (l_count);
END;
/
SELECT employee_id FROM employee WHERE salary = 10000
/
DECLARE
TYPE employee_aat IS TABLE OF employees.employee_id%TYPE
INDEX BY PLS_INTEGER;
l_employees employee_aat;
TYPE boolean_aat IS TABLE OF BOOLEAN
INDEX BY PLS_INTEGER;
l_employee_indices boolean_aat;
BEGIN
l_employees (1) := 7839;
l_employees (100) := 7654;
l_employees (500) := 7950;
--
l_employee_indices (1) := TRUE;
l_employee_indices (500) := TRUE;
l_employee_indices (799) := TRUE;
--
FORALL l_index IN INDICES OF l_employee_indices
BETWEEN 1 AND 500
UPDATE employees
SET salary = 10000
WHERE employee_id = l_employees (l_index);
END;
/
SELECT employee_id FROM employees WHERE salary = 10000
/
ROLLBACK
/
\ No newline at end of file
CONNECT SYS/SYS AS SYSDBA
grant select on source$ to SCOTT
/
CONNECT SCOTT/TIGER
SET SERVEROUTPUT ON
--------------------------------------------------------------------------------
-- Put the code in place.
-- source$ is a convenient table with lots of rows.
create or replace procedure putline ( approach in varchar2 , ol pls_integer) is
t0 integer; t1 integer;
cursor cur is select * from sys.source$;
one_row cur%rowtype;
type t is table of cur%rowtype index by pls_integer; many_rows t;
begin
t0 := Dbms_Utility.Get_Cpu_Time();
case approach
when 'implicit for loop' then
for j in cur loop
null;
end loop;
when 'explicit open, fetch, close' then
open cur;
loop
fetch cur into one_row;
exit when cur%NotFound;
end loop;
close cur;
when 'bulk fetch' then
open cur;
loop
fetch cur bulk collect into many_rows limit 100;
exit when many_rows.Count() < 1;
end loop;
close cur;
end case;
t1 := Dbms_Utility.Get_Cpu_Time();
Dbms_Output.Put_Line ('Timing for ' || approach ||
' with opt level ' || TO_CHAR (ol) || ' = ' || TO_CHAR (t1-t0 ));
end putline;
/
SET FEEDBACK OFF
--------------------------------------------------------------------------------
-- Time it at optimize levels 1 and 2
--
-- Level 1
alter procedure putline compile plsql_optimize_level=1
/
call putline( 'implicit for loop' , 1) -- 2073
/
call putline( 'explicit open, fetch, close' , 1) -- 2063
/
call putline( 'bulk fetch' , 1) -- 252
/
--------------------------------------------------------------------------------
-- Level 2
alter procedure putline compile plsql_optimize_level=2
/
call putline( 'implicit for loop' , 2) -- 263 <<== NOTE THE CHANGE !
/
call putline( 'explicit open, fetch, close' , 2) -- as for level 1
/
call putline( 'bulk fetch' , 2) -- as for level 1
/
BEGIN
DBMS_OUTPUT.PUT_LINE (
q'[What's a quote among friends?]');
END;
/
BEGIN
DBMS_OUTPUT.PUT_LINE (
q'!What's a quote among friends?!');
END;
/
CREATE OR REPLACE FUNCTION qstring (str_in IN VARCHAR2, qchar_in VARCHAR2 := '|')
RETURN VARCHAR2
IS
-- Silly....
-- NOT a good use for encapsulation: still have to pass in the quote in the str_in!
--
retval VARCHAR2(32767);
BEGIN
EXECUTE IMMEDIATE
'BEGIN :var := q''' || qchar_in || str_in || qchar_in || '''; END;'
USING OUT retval;
RETURN retval;
END;
/
DECLARE
distinct_authors strings_nt := strings_nt ();
PROCEDURE bpl (val IN BOOLEAN, str IN VARCHAR2)
IS
BEGIN
IF val
THEN
DBMS_OUTPUT.put_line (str || '-TRUE');
ELSIF NOT val
THEN
DBMS_OUTPUT.put_line (str || '-FALSE');
ELSE
DBMS_OUTPUT.put_line (str || '-NULL');
END IF;
END;
BEGIN
-- Add a duplicate author to Steven's list
authors_pkg.steven_authors.EXTEND;
authors_pkg.steven_authors(authors_pkg.steven_authors.LAST) := 'ROBERT HARRIS';
distinct_authors :=
SET (authors_pkg.steven_authors);
authors_pkg.show_authors (
'FULL SET', authors_pkg.steven_authors);
bpl (authors_pkg.steven_authors IS A SET, 'My authors distinct?');
bpl (authors_pkg.steven_authors IS NOT A SET, 'My authors NOT distinct?');
DBMS_OUTPUT.PUT_LINE ('');
authors_pkg.show_authors (
'DISTINCT SET', distinct_authors);
bpl (distinct_authors IS A SET, 'SET of authors distinct?');
bpl (distinct_authors IS NOT A SET, 'SET of authors NOT distinct?');
DBMS_OUTPUT.PUT_LINE ('');
END;
/
\ No newline at end of file
DECLARE
TYPE nested_type IS TABLE OF NUMBER;
nt1 nested_type := nested_type(1,2,3);
nt2 nested_type := nested_type(3,2,1);
nt3 nested_type := nested_type(2,3,1,3);
nt4 nested_type := nested_type(1,2,4);
answer nested_type;
PROCEDURE show_answer (str IN VARCHAR2)
IS
l_row PLS_INTEGER;
BEGIN
DBMS_OUTPUT.put_line (str);
l_row := answer.FIRST;
WHILE (l_row IS NOT NULL)
LOOP
DBMS_OUTPUT.put_line (l_row || '=' || answer (l_row));
l_row := answer.NEXT (l_row);
END LOOP;
DBMS_OUTPUT.put_line ('');
END show_answer;
BEGIN
answer := nt1 MULTISET UNION nt4;
show_answer('nt1 MULTISET UNION nt4');
answer := nt1 MULTISET UNION nt3;
show_answer('nt1 MULTISET UNION nt3');
answer := nt1 MULTISET UNION DISTINCT nt3;
show_answer('nt1 MULTISET UNION DISTINCT nt3');
answer := nt2 MULTISET INTERSECT nt3;
show_answer('nt2 MULTISET INTERSECT nt3');
answer := nt2 MULTISET INTERSECT DISTINCT nt3;
show_answer('nt2 MULTISET INTERSECT DISTINCT nt3');
answer := SET(nt3);
show_answer('SET(nt3)');
answer := nt3 MULTISET EXCEPT nt2;
show_answer('nt3 MULTISET EXCEPT nt2');
answer := nt3 MULTISET EXCEPT DISTINCT nt2;
show_answer('nt3 MULTISET EXCEPT DISTINCT nt2');
END;
/
\ No newline at end of file
CREATE OR REPLACE TYPE strings_nt IS TABLE OF VARCHAR2(100);
/